Chapter 17 updates

This commit is contained in:
anthonydb 2021-04-13 12:51:21 -04:00
parent 24739bc282
commit 48a564bc5d
2 changed files with 183 additions and 68 deletions

View File

@ -22,6 +22,7 @@ CREATE OR REPLACE VIEW nevada_counties_pop_2019 AS
SELECT *
FROM nevada_counties_pop_2019
ORDER BY county_fips
LIMIT 5;
-- Listing 17-3: Creating a view showing population change for US counties
@ -33,7 +34,6 @@ CREATE OR REPLACE VIEW county_pop_change_2019_2010 AS
c2019.county_fips,
c2019.pop_est_2019 AS pop_2019,
c2010.estimates_base_2010 AS pop_2010,
c2019.pop_est_2019 - c2010.estimates_base_2010 AS raw_change,
round( (c2019.pop_est_2019::numeric - c2010.estimates_base_2010)
/ c2010.estimates_base_2010 * 100, 1 ) AS pct_change_2019_2010
FROM us_counties_pop_est_2019 AS c2019
@ -42,7 +42,7 @@ CREATE OR REPLACE VIEW county_pop_change_2019_2010 AS
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_2019_2010 view
SELECT county_name,
state_name,
@ -50,9 +50,32 @@ SELECT county_name,
pct_change_2019_2010
FROM county_pop_change_2019_2010
WHERE state_name = 'Nevada'
ORDER BY county_fips
LIMIT 5;
-- Listing 17-5: Creating a view on the employees table
-- Listing 17-5: Creating a materialized view
DROP VIEW nevada_counties_pop_2019;
CREATE MATERIALIZED VIEW nevada_counties_pop_2019 AS
SELECT county_name,
state_fips,
county_fips,
pop_est_2019
FROM us_counties_pop_est_2019
WHERE state_name = 'Nevada'
ORDER BY county_fips;
-- Listing 17-6: Refreshing a materialized view
REFRESH MATERIALIZED VIEW nevada_counties_pop_2019;
-- Bonus: You can drop a materialized view using:
-- DROP MATERIALIZED VIEW nevada_counties_pop_2019;
SELECT * FROM employees ORDER BY emp_id;
-- Listing 17-7: Creating a view on the employees table
CREATE OR REPLACE VIEW employees_tax_dept AS
SELECT emp_id,
@ -64,9 +87,9 @@ CREATE OR REPLACE VIEW employees_tax_dept AS
ORDER BY emp_id
WITH LOCAL CHECK OPTION;
SELECT * FROM employees_tax_dept;
-- SELECT * FROM employees;
-- Listing 17-6: Successful and rejected inserts via the employees_tax_dept view
SELECT * FROM employees_tax_dept ORDER BY emp_id;
-- Listing 17-8: Successful and rejected inserts via the employees_tax_dept view
INSERT INTO employees_tax_dept (emp_id, first_name, last_name, dept_id)
VALUES (5, 'Suzanne', 'Legere', 1);
@ -74,34 +97,35 @@ VALUES (5, 'Suzanne', 'Legere', 1);
INSERT INTO employees_tax_dept (emp_id, first_name, last_name, dept_id)
VALUES (6, 'Jamil', 'White', 2);
-- optional:
SELECT * FROM employees_tax_dept;
SELECT * FROM employees_tax_dept ORDER BY emp_id;
SELECT * FROM employees;
SELECT * FROM employees ORDER BY emp_id;
-- Listing 17-7: Updating a row via the employees_tax_dept view
-- Listing 17-9: Updating a row via the employees_tax_dept view
UPDATE employees_tax_dept
SET last_name = 'Le Gere'
WHERE emp_id = 5;
SELECT * FROM employees_tax_dept;
SELECT * FROM employees_tax_dept ORDER BY emp_id;
-- Bonus: This will fail because the salary column is not in the view
UPDATE employees_tax_dept
SET salary = 100000
WHERE emp_id = 5;
-- Listing 17-8: Deleting a row via the employees_tax_dept view
-- Listing 17-10: Deleting a row via the employees_tax_dept view
DELETE FROM employees_tax_dept
WHERE emp_id = 5;
-- FUNCTIONS
-- https://www.postgresql.org/docs/current/static/plpgsql.html
-- FUNCTIONS AND PROCEDURES
-- https://www.postgresql.org/docs/current/sql-createfunction.html
-- https://www.postgresql.org/docs/current/sql-createprocedure.html
-- https://www.postgresql.org/docs/current/plpgsql.html
-- Listing 17-9: Creating a percent_change function
-- Listing 17-11: Creating a percent_change function
-- To delete this function: DROP FUNCTION percent_change(numeric,numeric,integer);
CREATE OR REPLACE FUNCTION
@ -109,23 +133,26 @@ percent_change(new_value numeric,
old_value numeric,
decimal_places integer DEFAULT 1)
RETURNS numeric AS
'SELECT round(
((new_value - old_value) / old_value) * 100, decimal_places
);'
$$
SELECT round(
((new_value - old_value) / old_value) * 100, decimal_places
);
$$
LANGUAGE SQL
IMMUTABLE
RETURNS NULL ON NULL INPUT;
-- Listing 17-10: Testing the percent_change() function
-- Listing 17-12: Testing the percent_change() function
SELECT percent_change(110, 108, 2);
-- Listing 17-11: Testing percent_change() on Census data
-- Listing 17-13: Testing percent_change() on Census data
SELECT c2019.county_name,
c2019.state_name,
c2019.pop_est_2019 AS pop_2019,
percent_change(c2019.pop_est_2019, c2010.estimates_base_2010) AS pct_chg_func,
percent_change(c2019.pop_est_2019,
c2010.estimates_base_2010) AS pct_chg_func,
round( (c2019.pop_est_2019::numeric - c2010.estimates_base_2010)
/ c2010.estimates_base_2010 * 100, 1 ) AS pct_chg_formula
FROM us_counties_pop_est_2019 AS c2019
@ -135,7 +162,7 @@ ON c2019.state_fips = c2010.state_fips
ORDER BY pct_chg_func DESC
LIMIT 5;
-- Listing 17-12: Adding a column to the teachers table and seeing the data
-- Listing 17-14: Adding a column to the teachers table and seeing the data
ALTER TABLE teachers ADD COLUMN personal_days integer;
@ -144,52 +171,56 @@ SELECT first_name,
hire_date,
personal_days
FROM teachers;
SELECT * FROM teachers;
-- Listing 17-13: Creating an update_personal_days() function
CREATE OR REPLACE FUNCTION update_personal_days()
RETURNS void AS $$
-- Listing 17-15: Creating an update_personal_days() procedure
CREATE OR REPLACE PROCEDURE update_personal_days()
LANGUAGE plpgsql
AS $$
BEGIN
UPDATE teachers
SET personal_days =
CASE WHEN (now() - hire_date) BETWEEN '5 years'::interval
AND '10 years'::interval THEN 4
WHEN (now() - hire_date) > '10 years'::interval THEN 5
CASE WHEN (now() - hire_date) >= '10 years'::interval
AND (now() - hire_date) < '15 years'::interval THEN 4
WHEN (now() - hire_date) >= '15 years'::interval
AND (now() - hire_date) < '20 years'::interval THEN 5
WHEN (now() - hire_date) >= '20 years'::interval
AND (now() - hire_date) < '25 years'::interval THEN 6
WHEN (now() - hire_date) >= '25 years'::interval THEN 7
ELSE 3
END;
RAISE NOTICE 'personal_days updated!';
END;
$$ LANGUAGE plpgsql;
END
$$;
-- To run the function:
SELECT update_personal_days();
-- To invoke the procedure:
CALL update_personal_days();
-- Listing 17-14: Enabling the PL/Python procedural language
-- Listing 17-16: Enabling the PL/Python procedural language
CREATE EXTENSION plpythonu; -- doesn't work on macOS with PostgresApp
CREATE EXTENSION plpython3u; -- doesn't work on macOS with PostgresApp
CREATE EXTENSION plpython3u;
-- Listing 17-15: Using PL/Python to create the trim_county() function
-- Listing 17-17: Using PL/Python to create the trim_county() function
CREATE OR REPLACE FUNCTION trim_county(input_string text)
RETURNS text AS $$
import re
cleaned = re.sub(r' County', '', input_string)
return cleaned
$$ LANGUAGE plpythonu;
$$ LANGUAGE plpython3u;
-- Listing 17-16: Testing the trim_county() function
-- Listing 17-18: Testing the trim_county() function
SELECT geo_name,
trim_county(geo_name)
FROM us_counties_2010
SELECT county_name,
trim_county(county_name)
FROM us_counties_pop_est_2019
ORDER BY state_fips, county_fips
LIMIT 5;
-- TRIGGERS
-- Listing 17-17: Creating the grades and grades_history tables
-- Listing 17-19: Creating the grades and grades_history tables
CREATE TABLE grades (
student_id bigint,
@ -216,7 +247,7 @@ CREATE TABLE grades_history (
PRIMARY KEY (student_id, course_id, change_time)
);
-- Listing 17-18: Creating the record_if_grade_changed() function
-- Listing 17-20: Creating the record_if_grade_changed() function
CREATE OR REPLACE FUNCTION record_if_grade_changed()
RETURNS trigger AS
@ -242,7 +273,7 @@ BEGIN
END;
$$ LANGUAGE plpgsql;
-- Listing 17-19: Creating the grades_update trigger
-- Listing 17-21: Creating the grades_update trigger
CREATE TRIGGER grades_update
AFTER UPDATE
@ -250,13 +281,13 @@ CREATE TRIGGER grades_update
FOR EACH ROW
EXECUTE PROCEDURE record_if_grade_changed();
-- Listing 17-20: Testing the grades_update trigger
-- Listing 17-22: Testing the grades_update trigger
-- Initially, there should be 0 records in the history
SELECT * FROM grades_history;
-- Check the grades
SELECT * FROM grades;
SELECT * FROM grades ORDER BY student_id, course_id;
-- Update a grade
UPDATE grades
@ -271,7 +302,7 @@ SELECT student_id,
new_grade
FROM grades_history;
-- Listing 17-21: Creating a temperature_test table
-- Listing 17-23: Creating a temperature_test table
CREATE TABLE temperature_test (
station_name text,
@ -282,7 +313,7 @@ CREATE TABLE temperature_test (
PRIMARY KEY (station_name, observation_date)
);
-- Listing 17-22: Creating the classify_max_temp() function
-- Listing 17-24: Creating the classify_max_temp() function
-- CHECK AGAINST CATEGORIES USED PREVIOUSLY
CREATE OR REPLACE FUNCTION classify_max_temp()
@ -292,21 +323,23 @@ BEGIN
CASE
WHEN NEW.max_temp >= 90 THEN
NEW.max_temp_group := 'Hot';
WHEN NEW.max_temp BETWEEN 70 AND 89 THEN
WHEN NEW.max_temp >= 70 AND NEW.max_temp < 90 THEN
NEW.max_temp_group := 'Warm';
WHEN NEW.max_temp BETWEEN 50 AND 69 THEN
WHEN NEW.max_temp >= 50 AND NEW.max_temp < 70 THEN
NEW.max_temp_group := 'Pleasant';
WHEN NEW.max_temp BETWEEN 33 AND 49 THEN
NEW.max_temp_group := 'Cold';
WHEN NEW.max_temp BETWEEN 20 AND 32 THEN
NEW.max_temp_group := 'Freezing';
ELSE NEW.max_temp_group := 'Inhumane';
WHEN NEW.max_temp >= 33 AND NEW.max_temp < 50 THEN
NEW.max_temp_group := 'Cold';
WHEN NEW.max_temp >= 20 AND NEW.max_temp < 33 THEN
NEW.max_temp_group := 'Frigid';
WHEN NEW.max_temp < 20 THEN
NEW.max_temp_group := 'Inhumane';
ELSE NEW.max_temp_group := 'No reading';
END CASE;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Listing 17-23: Creating the temperature_insert trigger
-- Listing 17-25: Creating the temperature_insert trigger
CREATE TRIGGER temperature_insert
BEFORE INSERT
@ -314,13 +347,14 @@ CREATE TRIGGER temperature_insert
FOR EACH ROW
EXECUTE PROCEDURE classify_max_temp();
-- Listing 17-24: Inserting rows to test the temperature_update trigger
-- Listing 17-26: Inserting rows to test the temperature_update trigger
INSERT INTO temperature_test (station_name, observation_date, max_temp, min_temp)
INSERT INTO temperature_test
VALUES
('North Station', '1/19/2019', 10, -3),
('North Station', '3/20/2019', 28, 19),
('North Station', '5/2/2019', 65, 42),
('North Station', '8/9/2019', 93, 74);
('North Station', '1/19/2023', 10, -3),
('North Station', '3/20/2023', 28, 19),
('North Station', '5/2/2023', 65, 42),
('North Station', '8/9/2023', 93, 74),
('North Station', '12/14/2023', NULL, NULL);
SELECT * FROM temperature_test;
SELECT * FROM temperature_test ORDER BY observation_date;

View File

@ -964,7 +964,7 @@ GROUP BY statefp
ORDER BY square_miles DESC;
-- 2. Using ST_Distance(), determine how many miles separate these two farmers
-- markets: the Oakleaf Greenmarket (9700 Argyle Forest Blvd, Jacksonville,
-- markets: The Oakleaf Greenmarket (9700 Argyle Forest Blvd, Jacksonville,
-- Florida) and Columbia Farmers Market (1701 West Ash Street, Columbia,
-- Missouri). Youll need to first find the coordinates for both in the
-- farmers_markets table.
@ -1132,8 +1132,89 @@ AS teachers_labs;
-- When writing a query such as this, it's helpful to work in chunks. Start with the
-- outermost query and add the subqueries one by one, testing as you go.
----------------------------------------------------------------------------
-- Chapter 17: Saving Time with Views, Functions, and Triggers
----------------------------------------------------------------------------
-- 1. Create a materialized view that displays the number of New York City
-- taxi trips per hour. Use the taxi data from Chapter 12 and the query in
-- Listing 12-8. How do you refresh the view if you need to?
-- Answer:
CREATE MATERIALIZED VIEW nyc_taxi_trips_per_hour AS
SELECT
date_part('hour', tpep_pickup_datetime) AS trip_hour,
count(*)
FROM nyc_yellow_taxi_trips
GROUP BY trip_hour
ORDER BY trip_hour;
SELECT * FROM nyc_taxi_trips_per_hour;
-- To refresh:
REFRESH MATERIALIZED VIEW nyc_taxi_trips_per_hour;
-- 2. In Chapter 11, you learned how to calculate rates per thousand. Turn that
-- formula into a rate_per_thousand() function that takes three arguments
-- to calculate the result: observed_number, base_number, and decimal_places.
-- Answer: This uses PL/pgSQL, but you could use a SQL function as well.
CREATE OR REPLACE FUNCTION
rate_per_thousand(observed_number numeric,
base_number numeric,
decimal_places integer DEFAULT 1)
RETURNS numeric(10,2) AS $$
BEGIN
RETURN
round(
(observed_number / base_number) * 1000, decimal_places
);
END;
$$ LANGUAGE plpgsql;
-- Test the function:
SELECT rate_per_thousand(50, 11000, 2);
-- 3. In Chapter 10, you worked with the meat_poultry_egg_establishments table that
-- listed food processing facilities. Write a trigger that automatically adds an
-- inspection deadline timestamp six months in the future whenever you insert a new
-- facility into the table. Use the inspection_deadline column added in Listing 10-19.
-- You should be able to describe the steps needed to implement a trigger and how
-- the steps relate to each other.
-- Answer:
-- a) You should have an inspection_deadline column already; if not, add it:
ALTER TABLE meat_poultry_egg_establishments ADD COLUMN inspection_deadline timestamp with time zone;
-- b) Create the function that the trigger will execute.
CREATE OR REPLACE FUNCTION add_inspection_deadline()
RETURNS trigger AS $$
BEGIN
NEW.inspection_deadline = now() + '6 months'::interval; -- Here, we set the inspection date to six months in the future
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- c) Create the trigger
CREATE TRIGGER inspection_deadline_update
BEFORE INSERT
ON meat_poultry_egg_establishments
FOR EACH ROW
EXECUTE PROCEDURE add_inspection_deadline();
-- d) Test the insertion of a company and examine the result
INSERT INTO meat_poultry_egg_establishments(establishment_number, company)
VALUES ('test123', 'testcompany');
SELECT * FROM meat_poultry_egg_establishments
WHERE company = 'testcompany';