first and final commit

This commit is contained in:
Regina Obe
2026-01-02 10:36:21 -05:00
commit 5c6bcdf190
17 changed files with 111437 additions and 0 deletions

18
README.txt Normal file
View File

@@ -0,0 +1,18 @@
The .sql is a plain text SQL backup
that should be restored with psql.
It consists of the census and staging schemas. As well as some other minor tables
Some of these are built as part of exercises in the book.
To restore:
CREATE DATABASE postgresql_book;
\connect postgresql_book
\i postgresql_book.sql
IMDB movies list comes from ftp://ftp.fu-berlin.de/pub/misc/movies/database/movies.list.gz
refer to copyright details in http://www.imdb.com/interfaces
Information courtesy of
IMDb
(http://www.imdb.com).
Used with permission.

View File

@@ -0,0 +1,73 @@
-- A lesson on dynamic inserts with DO
set search_path=census;
DROP TABLE IF EXISTS lu_fact_types;
CREATE TABLE lu_fact_types(fact_type_id serial
, category varchar(100)
, fact_subcats varchar(255)[], short_name varchar(50)
, CONSTRAINT pk_lu_fact_types PRIMARY KEY (fact_type_id) );
DO language plpgsql $$
DECLARE var_sql text;
BEGIN
var_sql := string_agg('INSERT INTO lu_fact_types( category,
fact_subcats, short_name )
SELECT ''Housing'', array_agg(s' || lpad(i::text,2,'0') || ') As fact_subcats
, ' || quote_literal('s' || lpad(i::text,2,'0') ) || ' As short_name
FROM staging.factfinder_import
WHERE s' || lpad(i::text,2,'0') || ' ~ ''^[a-zA-Z]+'' ', ';')
FROM generate_series(1,51) As i ;
var_sql := var_sql || ';' ||
string_agg('INSERT INTO lu_fact_types( category,
fact_subcats, short_name )
SELECT ''Population'', array_agg(d' || lpad(i::text,3,'0') || ') As fact_subcats
, ' || quote_literal('d' || lpad(i::text,3,'0') ) || ' As short_name
FROM staging.pop_import
WHERE d' || lpad(i::text,3,'0') || ' ~ ''^[a-zA-Z]+'' ', ';')
FROM generate_series(1,17) As i ;
RAISE NOTICE '%', var_sql;
EXECUTE var_sql;
END$$;
-- No longer in book Building Facts
set search_path=census;
DROP TABLE IF EXISTS facts;
CREATE TABLE IF NOT EXISTS facts(fact_type_id integer
, tract_id varchar(11)
, yr integer
,val numeric(12,3)
, perc numeric(6,2)
, CONSTRAINT pk_facts PRIMARY KEY (fact_type_id, tract_id, yr) );
DO language plpgsql $$
DECLARE var_sql text;
BEGIN
var_sql := string_agg('INSERT INTO facts(
fact_type_id, tract_id, yr, val, perc )
SELECT ' || ft.fact_type_id::text || ', geo_id2
, 2011, s' || lpad(i::text,2,'0') || '::integer As val
, CASE WHEN s' || lpad(i::text,2,'0')
|| '_perc LIKE ''(X%'' THEN NULL ELSE s' || lpad(i::text,2,'0')
|| '_perc END::numeric(5,2) As perc
FROM staging.factfinder_import AS ff
WHERE s' || lpad(i::text,2,'0') || ' ~ ''^[0-9]+'' ', ';')
FROM generate_series(1,51) As i
INNER JOIN lu_fact_types AS ft ON ( ('s' || lpad(i::text,2,'0')) = ft.short_name ) ;
var_sql := var_sql || ';' || string_agg('INSERT INTO facts(
fact_type_id, tract_id, yr, val)
SELECT ' || ft.fact_type_id::text || ', geo_id2
, 2011, d' || lpad(i::text,3,'0') || '::integer As val
FROM staging.pop_import AS ff
WHERE d' || lpad(i::text,3,'0') || ' ~ ''^[0-9]+'' ', ';')
FROM generate_series(1,17) As i
INNER JOIN lu_fact_types AS ft ON ( ('d' || lpad(i::text,3,'0')) = ft.short_name ) ;
EXECUTE var_sql;
END$$;
--builind lu_tracts --
set search_path=census;
CREATE TABLE IF NOT EXISTS lu_tracts(tract_id varchar(11), tract_long_id varchar(25)
, tract_name varchar(150)
, CONSTRAINT pk_lu_tracts PRIMARY KEY (tract_id));
INSERT INTO lu_tracts( tract_id, tract_long_id, tract_name)
SELECT geo_id2, geo_id, geo_display
FROM staging.factfinder_import
WHERE geo_id2 ~ '^[0-9]+';

11
ch03/DEC_10_SF1_QTH1.txt Normal file
View File

@@ -0,0 +1,11 @@
QT-H1
General Housing Characteristics: 2010
NOTE: For information on confidentiality protection, nonsampling error, and definitions, see http://www.census.gov/prod/cen2010/doc/sf1.pdf.
X Not applicable.
Source: U.S. Census Bureau, 2010 Census.
Summary File 1, Tables H3, H4, H5, and HCT1.

File diff suppressed because one or more lines are too long

3
ch03/README.txt Normal file
View File

@@ -0,0 +1,3 @@
Data was downloaded from factfinder2.census.gov
psqlrc.conf is an example psqlrc startup script.
If you are on a Unix environment rename to .psqlrc and place in your home directory.

8
ch03/build_stage.psql Normal file
View File

@@ -0,0 +1,8 @@
\a
\t
SELECT 'CREATE TABLE staging.factfinder_import(geo_id varchar(255)
, geo_id2 varchar(255), geo_display varchar(255)
, '|| array_to_string(array_agg('s' || lpad(i::text,2, '0')
|| ' varchar(255), s' || lpad(i::text,2, '0') || '_perc varchar(255) ' ), ',') || ');' As create_sql
FROM generate_series(1,51) As i \g create_script.sql
\i create_script.sql

9
ch03/psqlrc.conf Normal file
View File

@@ -0,0 +1,9 @@
\pset pager always
\pset null 'NULL'
\encoding latin1
\set PROMPT1 '%n@%M:%>%x %/# '
\set PROMPT2 ''
\timing on
\set qstats91 'SELECT usename, datname, substring(current_query, 1,100) || ''...'' As query FROM pg_stat_activity WHERE current_query != ''<IDLE>'';'
\set qstats92 'SELECT usename, datname, left(query,100) || ''...'' As query FROM pg_stat_activity WHERE state != ''idle'' ;'
\pset pager always

24
ch03/settings_report.psql Normal file
View File

@@ -0,0 +1,24 @@
\o settings_report.html
\T 'cellspacing=0 cellpadding=0'
\qecho '<html><head><style>H2{color:maroon}</style>'
\qecho '<title>PostgreSQL Settings</title></head><body>'
\qecho '<table><tr valign=''top''><td><h2>Planner Settings</h2>'
\x on
\t on
\pset format html
SELECT category, string_agg(name || '=' || setting, E'\n' ORDER BY name) As settings
FROM pg_settings
WHERE category LIKE '%Planner%' GROUP BY category ORDER BY category;
\H
\qecho '</td><td><h2>File Locations</h2>'
\x off
\t on
\pset format html
SELECT name, setting
FROM pg_settings
WHERE category = 'File Locations' ORDER BY name;
\qecho '<h2>Memory Settings</h2>'
SELECT name, setting, unit
FROM pg_settings WHERE category ILIKE '%memory%' ORDER BY name;
\qecho '</td></tr></table>'
\qecho '</body></html>'

61
ch04/ch04.pgs Normal file
View File

@@ -0,0 +1,61 @@
DECLARE @I, @labels, @tdef;
SET @I = 0;
--labels becomes a record variable because
-- it is the target of a SELECT
SET @labels = SELECT
quote_ident(replace(
replace(
lower(
COALESCE(fact_subcats[4], fact_subcats[3])), ' ', '_'),':'
,'')) As col_name, fact_type_id
FROM census.lu_fact_types
WHERE category = 'Population' AND fact_subcats[3] ILIKE 'Hispanic or Latino%'
ORDER BY short_name;
SET @tdef = 'census.hisp_pop(tract_id varchar(11) PRIMARY KEY ';
-- you loop thru rows of a record variable
-- using LINES pgScript function
WHILE @I < LINES(@labels)
BEGIN
SET @tdef = @tdef + ', ' + @labels[@I][0] + ' numeric(12,3) ';
SET @I = @I + 1;
END
SET @tdef = @tdef + ')';
PRINT @tdef;
CREATE TABLE IF NOT EXISTS @tdef;
--now we will populate our table
-- populate the table --
DECLARE @I, @labels, @tload, @tcols, @fact_types;
SET @I = 0;
SET @labels = SELECT
quote_ident(replace(
replace(
lower(
COALESCE(fact_subcats[4], fact_subcats[3])), ' ', '_'),':'
,'')) As col_name, fact_type_id
FROM census.lu_fact_types
WHERE category = 'Population' AND fact_subcats[3] ILIKE 'Hispanic or Latino%'
ORDER BY short_name;
SET @tload = 'tract_id';
SET @tcols = 'tract_id';
SET @fact_types = '-1';
WHILE @I < LINES(@labels)
BEGIN
SET @tcols = @tcols + ', ' + @labels[@I][0] ;
SET @tload = @tload + ', MAX(CASE WHEN fact_type_id = ' + CAST(@labels[@I][1] AS STRING) + ' THEN val ELSE NULL END)' ;
SET @fact_types = @fact_types + ', ' + CAST(@labels[@I][1] As STRING);
SET @I = @I + 1;
END
INSERT INTO census.hisp_pop(@tcols)
SELECT @tload
FROM census.facts
WHERE fact_type_id IN(@fact_types) AND yr=2011
GROUP BY tract_id;
-- graphical explain
SELECT substring(tract_id, 1,5) As county_code, SUM(hp.hispanic_or_latino) As tot
, SUM(hp.white_alone) As tot_white
, SUM(COALESCE(hp.hispanic_or_latino,0) - COALESCE(hp.white_alone,0)) AS non_white
FROM census.hisp_pop AS hp
GROUP BY county_code
ORDER BY county_code;

110
ch05/code05.sql Normal file
View File

@@ -0,0 +1,110 @@
--- JSON examples --
DROP TABLE IF EXISTS persons;
CREATE TABLE persons (id serial PRIMARY KEY, person json);
INSERT INTO persons (person)
VALUES (
'{
"name":"Sonia",
"spouse":
{
"name":"Alex",
"parents":
{
"father":"Rafael",
"mother":"Ofelia"
},
"phones":
[
{
"type":"work",
"number":"619-722-6719"
},
{
"type":"cell",
"number":"619-852-5083"
}
]
},
"children":
[
{
"name":"Brandon",
"gender":"M"
},
{
"name":"Azaleah",
"girl":true,
"phones": []
}
]
}'
);
SELECT person->'name' FROM persons;
SELECT person->'spouse'->'parents'->'father' FROM persons;
SELECT person#>array['spouse','parents','father'] FROM persons;
SELECT person->'children'->0->'name' FROM persons;
SELECT person#>array['children','0','name'] FROM persons;
SELECT person->'spouse'->'parents'->>'father' FROM persons;
SELECT person#>>array['children','0','name'] FROM persons;
SELECT json_array_elements(person->'children')->>'name' FROM persons;
CREATE TABLE persons (id serial PRIMARY KEY, person json);
INSERT INTO persons_b (person)
VALUES (
'{
"name":"Sonia",
"spouse":
{
"name":"Alex",
"parents":
{
"father":"Rafael",
"mother":"Ofelia"
},
"phones":
[
{
"type":"work",
"number":"619-722-6719"
},
{
"type":"cell",
"number":"619-852-5083"
}
]
},
"children":
[
{
"name":"Brandon",
"gender":"M"
},
{
"name":"Azaleah",
"girl":true,
"phones": []
}
]
}'
);
-- FULL text examples
--first load the film table
ALTER TABLE film ADD COLUMN fts tsvector;
UPDATE film SET fts = setweight( to_tsvector(COALESCE(title,'')), 'A') ||
setweight( to_tsvector(COALESCE(description,'')), 'B');

40
ch06/ch06.sql Normal file
View File

@@ -0,0 +1,40 @@
-- Example 6-1. Basic Create Table
CREATE TABLE logs(
log_id serial primary key
, user_name varchar(50)
, description text
, log_ts timestamp with time zone NOT NULL DEFAULT CURRENT_TIMESTAMP);
CREATE INDEX idx_logs_log_ts ON logs USING btree(log_ts);
-- Example 6-2. Defining an inherited table
CREATE TABLE logs_2011(primary key(log_id)) INHERITS (logs);
CREATE INDEX idx_logs_2011_log_ts ON logs USING btree(log_ts);
ALTER TABLE logs_2011
ADD CONSTRAINT chk_y2011 CHECK (log_ts BETWEEN '2011-01-01 00:00:00'::timestamptz AND
'2011-12-31 23:59:59'::timestamptz);
-- Example 6-3. Defining an unlogged table
CREATE UNLOGGED TABLE web_sessions(
session_id text PRIMARY KEY
, add_ts timestamp
, upd_ts timestamp
, session_state xml);
-- Example 6-4. Using multi-row consructor to insert data
INSERT INTO logs_2011(user_name, description, log_ts)
VALUES ('robe', 'logged in', '2011-01-10 10:15 AM'),
('lhsu', 'logged out', '2011-01-11 10:20 AM');
-- example: Creating lookup and insert non-numeric data
CREATE SCHEMA census;
set search_path=census;
CREATE TABLE lu_tracts(tract_id varchar(11)
, tract_long_id varchar(25)
, tract_name varchar(150)
, CONSTRAINT pk_lu_tracts PRIMARY KEY (tract_id)
);
INSERT INTO lu_tracts(
tract_id, tract_long_id, tract_name)
SELECT geo_id2, geo_id, geo_display
FROM staging.factfinder_import
WHERE geo_id2 ~ '^[0-9]+';

File diff suppressed because one or more lines are too long

22
ch10/devs.psv Normal file
View File

@@ -0,0 +1,22 @@
Dev|Company
Tom Lane|Crunchy Data
Bruce Momjian|EnterpriseDB
Simon Riggs|2ndQuadrant
Peter Eisentraut|F-Secure
Magnus Hagander|Redpill Linpro
Dave Page|EnterpriseDB
Andrew Dunstan|PostgreSQL Experts
Oleg Bartunov|SAI-MSU
Teodor Sigaev|
Jeff Davis|Aster Data
Devrim Gündüz|EnterpriseDb
Robert Haas|EnterpriseDb
Hiroshi Inoue|Fukui, Japan
Francisco Figueiredo|
Robert Treat|OmniTI
Greg Smith|2ndQuadrant
David Wheeler|PostgreSQL Experts
Pavel Stehule|
Marc Cave-Ayland|iLande Consulting
Selena Deckelmann|Prime Radiant
David Fetter|PostgreSQL Experts

1034
film.sql Normal file

File diff suppressed because it is too large Load Diff

34
game_throws.sql Normal file
View File

@@ -0,0 +1,34 @@
CREATE TABLE game_throws (
id serial,
player varchar(100) NOT NULL,
roll integer,
CONSTRAINT pk_game_throws PRIMARY KEY (id)
);
/** INSERT INTO game_throws(player,roll)
SELECT f.player, 1 + (random()*4)::integer
FROM (values ('regina'), ('leo'), ('sonia'), ('alex')) AS f(player)
, generate_series(1,4) As roll; **/
INSERT INTO game_throws (id, player, roll) VALUES (1, 'regina', 3);
INSERT INTO game_throws (id, player, roll) VALUES (2, 'leo', 2);
INSERT INTO game_throws (id, player, roll) VALUES (3, 'sonia', 1);
INSERT INTO game_throws (id, player, roll) VALUES (4, 'alex', 3);
INSERT INTO game_throws (id, player, roll) VALUES (5, 'regina', 2);
INSERT INTO game_throws (id, player, roll) VALUES (6, 'leo', 4);
INSERT INTO game_throws (id, player, roll) VALUES (7, 'sonia', 3);
INSERT INTO game_throws (id, player, roll) VALUES (8, 'alex', 3);
INSERT INTO game_throws (id, player, roll) VALUES (9, 'regina', 1);
INSERT INTO game_throws (id, player, roll) VALUES (10, 'leo', 2);
INSERT INTO game_throws (id, player, roll) VALUES (11, 'sonia', 3);
INSERT INTO game_throws (id, player, roll) VALUES (12, 'alex', 3);
INSERT INTO game_throws (id, player, roll) VALUES (13, 'regina', 3);
INSERT INTO game_throws (id, player, roll) VALUES (14, 'leo', 4);
INSERT INTO game_throws (id, player, roll) VALUES (15, 'sonia', 1);
INSERT INTO game_throws (id, player, roll) VALUES (16, 'alex', 3);
SELECT id, player, roll,
run_begin(roll,3) OVER (PARTITION BY player ORDER BY id) AS rb
FROM game_throws
ORDER BY player, id;

106978
postgresql_book.sql Normal file

File diff suppressed because one or more lines are too long

40
test_scores.sql Normal file
View File

@@ -0,0 +1,40 @@
CREATE TABLE test_scores (
student character varying(100) NOT NULL,
subject character varying(100) NOT NULL,
score numeric(5),
test_date date NOT NULL,
CONSTRAINT pk_test_scores PRIMARY KEY (student, subject, test_date)
);
INSERT INTO test_scores VALUES ('regina', 'algebra', 68, '2014-01-15');
INSERT INTO test_scores VALUES ('regina', 'physics', 83, '2014-01-15');
INSERT INTO test_scores VALUES ('regina', 'chemistry', 71, '2014-01-15');
INSERT INTO test_scores VALUES ('regina', 'calculus', 68, '2014-01-15');
INSERT INTO test_scores VALUES ('regina', 'economics', 90, '2015-01-15');
INSERT INTO test_scores VALUES ('leo', 'algebra', 84, '2014-01-15');
INSERT INTO test_scores VALUES ('leo', 'physics', 72, '2014-01-15');
INSERT INTO test_scores VALUES ('leo', 'chemistry', 71, '2014-01-15');
INSERT INTO test_scores VALUES ('leo', 'calculus', 69, '2014-01-15');
INSERT INTO test_scores VALUES ('alex', 'algebra', 74, '2014-01-15');
INSERT INTO test_scores VALUES ('alex', 'physics', 83, '2014-01-15');
INSERT INTO test_scores VALUES ('alex', 'chemistry', 80, '2014-01-15');
INSERT INTO test_scores VALUES ('alex', 'calculus', 70, '2014-01-15');
INSERT INTO test_scores VALUES ('sonia', 'algebra', 75, '2014-01-15');
INSERT INTO test_scores VALUES ('sonia', 'physics', 72, '2014-01-15');
INSERT INTO test_scores VALUES ('sonia', 'chemistry', 82, '2014-01-15');
INSERT INTO test_scores VALUES ('sonia', 'calculus', 65, '2014-01-15');
INSERT INTO test_scores VALUES ('regina', 'algebra', 77, '2014-01-29');
INSERT INTO test_scores VALUES ('regina', 'physics', 85, '2014-01-29');
INSERT INTO test_scores VALUES ('regina', 'chemistry', 76, '2014-01-29');
INSERT INTO test_scores VALUES ('regina', 'calculus', 61, '2014-01-29');
INSERT INTO test_scores VALUES ('leo', 'algebra', 80, '2014-01-29');
INSERT INTO test_scores VALUES ('leo', 'physics', 72, '2014-01-29');
INSERT INTO test_scores VALUES ('leo', 'chemistry', 80, '2014-01-29');
INSERT INTO test_scores VALUES ('leo', 'calculus', 62, '2014-01-29');
INSERT INTO test_scores VALUES ('alex', 'algebra', 74, '2014-01-29');
INSERT INTO test_scores VALUES ('alex', 'physics', 79, '2014-01-29');
INSERT INTO test_scores VALUES ('alex', 'chemistry', 84, '2014-01-29');
INSERT INTO test_scores VALUES ('alex', 'calculus', 77, '2014-01-29');
INSERT INTO test_scores VALUES ('sonia', 'algebra', 78, '2014-01-29');
INSERT INTO test_scores VALUES ('sonia', 'physics', 72, '2014-01-29');
INSERT INTO test_scores VALUES ('sonia', 'chemistry', 86, '2014-01-29');
INSERT INTO test_scores VALUES ('sonia', 'calculus', 70, '2014-01-29');