Chapter 11 update per TR; start on Chapter 17 updates

This commit is contained in:
anthonydb 2021-04-04 12:14:56 -04:00
parent 343a695984
commit 24739bc282
2 changed files with 68 additions and 61 deletions

View File

@ -96,7 +96,8 @@ SELECT
widget_output, widget_output,
rank() OVER (ORDER BY widget_output DESC), rank() OVER (ORDER BY widget_output DESC),
dense_rank() OVER (ORDER BY widget_output DESC) dense_rank() OVER (ORDER BY widget_output DESC)
FROM widget_companies; FROM widget_companies
ORDER BY widget_output DESC;
-- Listing 11-7: Applying rank() within groups using PARTITION BY -- Listing 11-7: Applying rank() within groups using PARTITION BY
@ -124,7 +125,9 @@ SELECT
store, store,
unit_sales, unit_sales,
rank() OVER (PARTITION BY category ORDER BY unit_sales DESC) rank() OVER (PARTITION BY category ORDER BY unit_sales DESC)
FROM store_sales; FROM store_sales
ORDER BY category, rank() OVER (PARTITION BY category
ORDER BY unit_sales DESC);
-- Listing 11-8: Creating and filling a table for Census county business pattern data -- Listing 11-8: Creating and filling a table for Census county business pattern data
@ -144,7 +147,10 @@ COPY cbp_naics_72_establishments
FROM 'C:\YourDirectory\cbp_naics_72_establishments.csv' FROM 'C:\YourDirectory\cbp_naics_72_establishments.csv'
WITH (FORMAT CSV, HEADER); WITH (FORMAT CSV, HEADER);
SELECT * FROM cbp_naics_72_establishments LIMIT 5; SELECT *
FROM cbp_naics_72_establishments
ORDER BY state_fips, county_fips
LIMIT 5;
-- Listing 11-9: Finding business rates per thousand population in counties with 50,000 or more people -- Listing 11-9: Finding business rates per thousand population in counties with 50,000 or more people
@ -155,7 +161,7 @@ SELECT
pop.pop_est_2018, pop.pop_est_2018,
round( (cbp.establishments::numeric / pop.pop_est_2018) * 1000, 1 ) round( (cbp.establishments::numeric / pop.pop_est_2018) * 1000, 1 )
AS estabs_per_1000 AS estabs_per_1000
FROM cbp_naics_72_establishments cbp LEFT JOIN us_counties_pop_est_2019 pop FROM cbp_naics_72_establishments cbp JOIN us_counties_pop_est_2019 pop
ON cbp.state_fips = pop.state_fips ON cbp.state_fips = pop.state_fips
AND cbp.county_fips = pop.county_fips AND cbp.county_fips = pop.county_fips
WHERE pop.pop_est_2018 >= 50000 WHERE pop.pop_est_2018 >= 50000

View File

@ -1,57 +1,55 @@
-- FIRST EDITION FILE; IGNORE ---------------------------------------------------------------------------
-- Practical SQL: A Beginner's Guide to Storytelling with Data, 2nd Edition
--------------------------------------------------------------
-- Practical SQL: A Beginner's Guide to Storytelling with Data
-- by Anthony DeBarros -- by Anthony DeBarros
-- Chapter 17 Code Examples -- Chapter 17 Code Examples
-------------------------------------------------------------- ----------------------------------------------------------------------------
-- VIEWS -- VIEWS
-- Listing 17-1: Creating a view that displays Nevada 2010 counties -- Listing 17-1: Creating a view that displays Nevada 2019 counties
CREATE OR REPLACE VIEW nevada_counties_pop_2010 AS CREATE OR REPLACE VIEW nevada_counties_pop_2019 AS
SELECT geo_name, SELECT county_name,
state_fips, state_fips,
county_fips, county_fips,
p0010001 AS pop_2010 pop_est_2019
FROM us_counties_2010 FROM us_counties_pop_est_2019
WHERE state_us_abbreviation = 'NV' WHERE state_name = 'Nevada'
ORDER BY county_fips; ORDER BY county_fips;
-- Listing 17-2: Querying the nevada_counties_pop_2010 view -- Listing 17-2: Querying the nevada_counties_pop_2019 view
SELECT * SELECT *
FROM nevada_counties_pop_2010 FROM nevada_counties_pop_2019
LIMIT 5; LIMIT 5;
-- Listing 17-3: Creating a view showing population change for US counties -- Listing 17-3: Creating a view showing population change for US counties
CREATE OR REPLACE VIEW county_pop_change_2010_2000 AS CREATE OR REPLACE VIEW county_pop_change_2019_2010 AS
SELECT c2010.geo_name, SELECT c2019.county_name,
c2010.state_us_abbreviation AS st, c2019.state_name,
c2010.state_fips, c2019.state_fips,
c2010.county_fips, c2019.county_fips,
c2010.p0010001 AS pop_2010, c2019.pop_est_2019 AS pop_2019,
c2000.p0010001 AS pop_2000, c2010.estimates_base_2010 AS pop_2010,
round( (CAST(c2010.p0010001 AS numeric(8,1)) - c2000.p0010001) c2019.pop_est_2019 - c2010.estimates_base_2010 AS raw_change,
/ c2000.p0010001 * 100, 1 ) AS pct_change_2010_2000 round( (c2019.pop_est_2019::numeric - c2010.estimates_base_2010)
FROM us_counties_2010 c2010 INNER JOIN us_counties_2000 c2000 / c2010.estimates_base_2010 * 100, 1 ) AS pct_change_2019_2010
ON c2010.state_fips = c2000.state_fips FROM us_counties_pop_est_2019 AS c2019
AND c2010.county_fips = c2000.county_fips JOIN us_counties_pop_est_2010 AS c2010
ORDER BY c2010.state_fips, c2010.county_fips; ON c2019.state_fips = c2010.state_fips
AND c2019.county_fips = c2010.county_fips
ORDER BY c2019.state_fips, c2019.county_fips;
-- Listing 17-4: Selecting columns from the county_pop_change_2010_2000 view -- Listing 17-4: Selecting columns from the county_pop_change_2010_2000 view
SELECT geo_name, SELECT county_name,
st, state_name,
pop_2010, pop_2019,
pct_change_2010_2000 pct_change_2019_2010
FROM county_pop_change_2010_2000 FROM county_pop_change_2019_2010
WHERE st = 'NV' WHERE state_name = 'Nevada'
LIMIT 5; LIMIT 5;
-- Listing 17-5: Creating a view on the employees table -- Listing 17-5: Creating a view on the employees table
@ -67,14 +65,14 @@ CREATE OR REPLACE VIEW employees_tax_dept AS
WITH LOCAL CHECK OPTION; WITH LOCAL CHECK OPTION;
SELECT * FROM employees_tax_dept; SELECT * FROM employees_tax_dept;
-- SELECT * FROM employees;
-- Listing 17-6: Successful and rejected inserts via the employees_tax_dept view -- Listing 17-6: Successful and rejected inserts via the employees_tax_dept view
INSERT INTO employees_tax_dept (first_name, last_name, dept_id) INSERT INTO employees_tax_dept (emp_id, first_name, last_name, dept_id)
VALUES ('Suzanne', 'Legere', 1); VALUES (5, 'Suzanne', 'Legere', 1);
INSERT INTO employees_tax_dept (first_name, last_name, dept_id) INSERT INTO employees_tax_dept (emp_id, first_name, last_name, dept_id)
VALUES ('Jamil', 'White', 2); VALUES (6, 'Jamil', 'White', 2);
-- optional: -- optional:
SELECT * FROM employees_tax_dept; SELECT * FROM employees_tax_dept;
@ -124,15 +122,16 @@ SELECT percent_change(110, 108, 2);
-- Listing 17-11: Testing percent_change() on Census data -- Listing 17-11: Testing percent_change() on Census data
SELECT c2010.geo_name, SELECT c2019.county_name,
c2010.state_us_abbreviation AS st, c2019.state_name,
c2010.p0010001 AS pop_2010, c2019.pop_est_2019 AS pop_2019,
percent_change(c2010.p0010001, c2000.p0010001) AS pct_chg_func, percent_change(c2019.pop_est_2019, c2010.estimates_base_2010) AS pct_chg_func,
round( (CAST(c2010.p0010001 AS numeric(8,1)) - c2000.p0010001) round( (c2019.pop_est_2019::numeric - c2010.estimates_base_2010)
/ c2000.p0010001 * 100, 1 ) AS pct_chg_formula / c2010.estimates_base_2010 * 100, 1 ) AS pct_chg_formula
FROM us_counties_2010 c2010 INNER JOIN us_counties_2000 c2000 FROM us_counties_pop_est_2019 AS c2019
ON c2010.state_fips = c2000.state_fips JOIN us_counties_pop_est_2010 AS c2010
AND c2010.county_fips = c2000.county_fips ON c2019.state_fips = c2010.state_fips
AND c2019.county_fips = c2010.county_fips
ORDER BY pct_chg_func DESC ORDER BY pct_chg_func DESC
LIMIT 5; LIMIT 5;
@ -145,7 +144,7 @@ SELECT first_name,
hire_date, hire_date,
personal_days personal_days
FROM teachers; FROM teachers;
SELECT * FROM teachers;
-- Listing 17-13: Creating an update_personal_days() function -- Listing 17-13: Creating an update_personal_days() function
CREATE OR REPLACE FUNCTION update_personal_days() CREATE OR REPLACE FUNCTION update_personal_days()
@ -167,7 +166,8 @@ SELECT update_personal_days();
-- Listing 17-14: Enabling the PL/Python procedural language -- Listing 17-14: Enabling the PL/Python procedural language
CREATE EXTENSION plpythonu; CREATE EXTENSION plpythonu; -- doesn't work on macOS with PostgresApp
CREATE EXTENSION plpython3u; -- doesn't work on macOS with PostgresApp
-- Listing 17-15: Using PL/Python to create the trim_county() function -- Listing 17-15: Using PL/Python to create the trim_county() function
@ -194,8 +194,8 @@ LIMIT 5;
CREATE TABLE grades ( CREATE TABLE grades (
student_id bigint, student_id bigint,
course_id bigint, course_id bigint,
course varchar(30) NOT NULL, course text NOT NULL,
grade varchar(5) NOT NULL, grade text NOT NULL,
PRIMARY KEY (student_id, course_id) PRIMARY KEY (student_id, course_id)
); );
@ -210,9 +210,9 @@ CREATE TABLE grades_history (
student_id bigint NOT NULL, student_id bigint NOT NULL,
course_id bigint NOT NULL, course_id bigint NOT NULL,
change_time timestamp with time zone NOT NULL, change_time timestamp with time zone NOT NULL,
course varchar(30) NOT NULL, course text NOT NULL,
old_grade varchar(5) NOT NULL, old_grade text NOT NULL,
new_grade varchar(5) NOT NULL, new_grade text NOT NULL,
PRIMARY KEY (student_id, course_id, change_time) PRIMARY KEY (student_id, course_id, change_time)
); );
@ -274,15 +274,16 @@ FROM grades_history;
-- Listing 17-21: Creating a temperature_test table -- Listing 17-21: Creating a temperature_test table
CREATE TABLE temperature_test ( CREATE TABLE temperature_test (
station_name varchar(50), station_name text,
observation_date date, observation_date date,
max_temp integer, max_temp integer,
min_temp integer, min_temp integer,
max_temp_group varchar(40), max_temp_group text,
PRIMARY KEY (station_name, observation_date) PRIMARY KEY (station_name, observation_date)
); );
-- Listing 17-22: Creating the classify_max_temp() function -- Listing 17-22: Creating the classify_max_temp() function
-- CHECK AGAINST CATEGORIES USED PREVIOUSLY
CREATE OR REPLACE FUNCTION classify_max_temp() CREATE OR REPLACE FUNCTION classify_max_temp()
RETURNS trigger AS RETURNS trigger AS