From be15532f68e5391c60a032423fd2ddfde84f276c Mon Sep 17 00:00:00 2001 From: anthonydb Date: Thu, 13 May 2021 08:30:00 -0400 Subject: [PATCH] Updates to Chapter 16 per edit --- Chapter_16/Chapter_16.sql | 54 ++++++++++++++++++++------------------- 1 file changed, 28 insertions(+), 26 deletions(-) diff --git a/Chapter_16/Chapter_16.sql b/Chapter_16/Chapter_16.sql index 5e3739d..a03d96f 100644 --- a/Chapter_16/Chapter_16.sql +++ b/Chapter_16/Chapter_16.sql @@ -112,7 +112,7 @@ ORDER BY id; -- JSONB CONTAINMENT AND EXISTENCE OPERATORS --- Listing 16-6: Demonstrating containment operators +-- Listing 16-6: Demonstrating the @> containment operator -- Does the film JSON value contain the following key/value pair? SELECT id, film ->> 'title' AS title, @@ -120,19 +120,20 @@ SELECT id, film ->> 'title' AS title, FROM films ORDER BY id; --- Using the containment operator in WHERE +-- Listing 16-7: Using a containment operator in a WHERE clause + SELECT film ->> 'title' AS title, film ->> 'year' AS year FROM films WHERE film @> '{"title": "The Incredibles"}'::jsonb; --- Is the first JSON value contained in the second? +-- Listing 16-8: Demonstrating the <@ containment operator SELECT film ->> 'title' AS title, film ->> 'year' AS year FROM films WHERE '{"title": "The Incredibles"}'::jsonb <@ film; --- Listing 16-7: Demonstrating existence operators +-- Listing 16-9: Demonstrating existence operators -- Does the text string exist as a top-level key or array element within the JSON value? SELECT film ->> 'title' AS title @@ -156,7 +157,7 @@ WHERE film ?& '{rating, genre}'; -- ANALYZING EARTHQUAKE DATA --- Listing 16-8: JSON with data on one earthquake +-- Listing 16-10: JSON with data on one earthquake { "type": "Feature", @@ -195,7 +196,7 @@ WHERE film ?& '{rating, genre}'; "id": "av91018173" } --- Listing 16-9: Creating and loading an earthquakes table +-- Listing 16-11: Creating and loading an earthquakes table CREATE TABLE earthquakes ( id integer GENERATED ALWAYS AS IDENTITY PRIMARY KEY, @@ -209,14 +210,14 @@ CREATE INDEX idx_earthquakes ON earthquakes USING GIN (earthquake); SELECT * FROM earthquakes; --- Listing 16-10: Retrieving the earthquake time +-- Listing 16-12: Retrieving the earthquake time -- Note that the time is stored in epoch format SELECT id, earthquake #>> '{properties, time}' AS time FROM earthquakes ORDER BY id LIMIT 5; --- Listing 16-11: Converting the time value to a timestamp +-- Listing 16-13: Converting the time value to a timestamp SELECT id, earthquake #>> '{properties, time}' as time, to_timestamp( @@ -230,7 +231,7 @@ SHOW timezone; SET timezone TO 'US/Eastern'; SET timezone TO 'UTC'; --- Listing 16-12: Finding the minimum and maximum earthquake times +-- Listing 16-14: Finding the minimum and maximum earthquake times SELECT min(to_timestamp( (earthquake #>> '{properties, time}')::bigint / 1000 @@ -240,7 +241,7 @@ SELECT min(to_timestamp( )) AT TIME ZONE 'UTC' AS max_timestamp FROM earthquakes; --- Listing 16-13: Finding the five earthquakes with the largest magnitude +-- Listing 16-15: Finding the five earthquakes with the largest magnitude SELECT earthquake #>> '{properties, place}' AS place, to_timestamp((earthquake #>> '{properties, time}')::bigint / 1000) @@ -259,7 +260,7 @@ FROM earthquakes ORDER BY (earthquake #>> '{properties, mag}')::numeric DESC NULLS LAST LIMIT 5; --- Listing 16-14: Finding earthquakes with most Did You Feel It? reports +-- Listing 16-16: Finding earthquakes with most Did You Feel It? reports -- https://earthquake.usgs.gov/data/dyfi/ SELECT earthquake #>> '{properties, place}' AS place, @@ -271,7 +272,7 @@ FROM earthquakes ORDER BY (earthquake #>> '{properties, felt}')::integer DESC NULLS LAST LIMIT 5; --- Listing 16-15: Extracting the earthquake's location data +-- Listing 16-17: Extracting the earthquake's location data SELECT id, earthquake #>> '{geometry, coordinates}' AS coordinates, @@ -281,7 +282,7 @@ FROM earthquakes ORDER BY id LIMIT 5; --- Listing 16-16: Converting JSON location data to PostGIS geography +-- Listing 16-18: Converting JSON location data to PostGIS geography SELECT ST_SetSRID( ST_MakePoint( (earthquake #>> '{geometry, coordinates, 0}')::numeric, @@ -291,7 +292,7 @@ SELECT ST_SetSRID( FROM earthquakes ORDER BY id; --- Listing 16-17: Finding earthquakes within 50 miles of downtown Tulsa, Oklahoma +-- Listing 16-19: Converting JSON coordinates to a PostGIS geometry column -- Add a column of the geography data type ALTER TABLE earthquakes ADD COLUMN earthquake_point geography(POINT, 4326); @@ -308,7 +309,8 @@ SET earthquake_point = CREATE INDEX quake_pt_idx ON earthquakes USING GIST (earthquake_point); --- Earthquakes 50 miles from Tulsa +-- Listing 16-20: Finding earthquakes within 50 miles of downtown Tulsa, Oklahoma + SELECT earthquake #>> '{properties, place}' AS place, to_timestamp((earthquake -> 'properties' ->> 'time')::bigint / 1000) AT TIME ZONE 'UTC' AS time, @@ -322,29 +324,30 @@ ORDER BY time; -- GENERATING AND MANIPULATING JSON --- Listing 16-18: Turning query results into JSON with row_to_json() and json_agg() +-- Listing 16-21: Turning query results into JSON with to_json() -- Convert an entire row from the table SELECT to_json(employees) AS json_rows FROM employees; --- Selected columns from the table (returns key names as f1, f2, etc.) +-- Listing 16-22: Specifying columns to convert to JSON +-- Returns key names as f1, f2, etc. SELECT to_json(row(emp_id, last_name)) AS json_rows FROM employees; --- Generating key names with a subquery +-- Listing 16-23: Generating key names with a subquery SELECT to_json(employees) AS json_rows FROM ( SELECT emp_id, last_name AS ln FROM employees ) AS employees; --- Aggregating the rows and converting to JSON +-- Listing 16-24: Aggregating the rows and converting to JSON SELECT json_agg(to_json(employees)) AS json FROM ( SELECT emp_id, last_name AS ln FROM employees ) AS employees; --- Listing 16-19: Adding a top-level key/value pair via concatenation +-- Listing 16-25: Adding a top-level key/value pair via concatenation -- Two examples UPDATE films @@ -358,7 +361,7 @@ WHERE film @> '{"title": "The Incredibles"}'::jsonb; SELECT film FROM films -- check the updated data WHERE film @> '{"title": "The Incredibles"}'::jsonb; --- Listing 16-20: Setting an array value at a path +-- Listing 16-26: Setting an array value at a path UPDATE films SET film = jsonb_set(film, @@ -370,8 +373,7 @@ WHERE film @> '{"title": "Cinema Paradiso"}'::jsonb; SELECT film FROM films -- check the updated data WHERE film @> '{"title": "Cinema Paradiso"}'::jsonb; - --- Listing 16-21: Deleting values from JSON +-- Listing 16-27: Deleting values from JSON -- Removes the studio key/value pair from The Incredibles UPDATE films @@ -386,7 +388,7 @@ WHERE film @> '{"title": "Cinema Paradiso"}'::jsonb; -- JSON PROCESSING FUNCTIONS --- Listing 16-22: Finding the length of an array +-- Listing 16-28: Finding the length of an array SELECT id, film ->> 'title' AS title, @@ -394,7 +396,7 @@ SELECT id, FROM films ORDER BY id; --- Listing 16-23: Returning array elements as rows +-- Listing 16-29: Returning array elements as rows SELECT id, jsonb_array_elements(film -> 'genre') AS genre_jsonb, @@ -402,7 +404,7 @@ SELECT id, FROM films ORDER BY id; --- Listing 16-24: Returning key values from each item in an array +-- Listing 16-30: Returning key values from each item in an array SELECT id, jsonb_array_elements(film -> 'characters')