198 lines
5.7 KiB
SQL
198 lines
5.7 KiB
SQL
---------------------------------------------------------------------------
|
|
-- Practical SQL: A Beginner's Guide to Storytelling with Data, 2nd Edition
|
|
-- by Anthony DeBarros
|
|
|
|
-- Chapter 7 Code Examples
|
|
----------------------------------------------------------------------------
|
|
|
|
|
|
-- Listing 7-1: Creating the departments and employees tables
|
|
|
|
CREATE TABLE departments (
|
|
dept_id integer,
|
|
dept text,
|
|
city text,
|
|
CONSTRAINT dept_key PRIMARY KEY (dept_id),
|
|
CONSTRAINT dept_city_unique UNIQUE (dept, city)
|
|
);
|
|
|
|
CREATE TABLE employees (
|
|
emp_id integer,
|
|
first_name text,
|
|
last_name text,
|
|
salary numeric(10,2),
|
|
dept_id integer REFERENCES departments (dept_id),
|
|
CONSTRAINT emp_key PRIMARY KEY (emp_id),
|
|
CONSTRAINT emp_dept_unique UNIQUE (emp_id, dept_id)
|
|
);
|
|
|
|
INSERT INTO departments
|
|
VALUES
|
|
(1, 'Tax', 'Atlanta'),
|
|
(2, 'IT', 'Boston');
|
|
|
|
INSERT INTO employees
|
|
VALUES
|
|
(1, 'Julia', 'Reyes', 115300, 1),
|
|
(2, 'Janet', 'King', 98000, 1),
|
|
(3, 'Arthur', 'Pappas', 72700, 2),
|
|
(4, 'Michael', 'Taylor', 89500, 2);
|
|
|
|
-- Listing 7-2: Joining the employees and departments tables
|
|
|
|
SELECT *
|
|
FROM employees JOIN departments
|
|
ON employees.dept_id = departments.dept_id;
|
|
|
|
-- Listing 7-3: Creating two tables to explore JOIN types
|
|
|
|
CREATE TABLE schools_left (
|
|
id integer CONSTRAINT left_id_key PRIMARY KEY,
|
|
left_school varchar(30)
|
|
);
|
|
|
|
CREATE TABLE schools_right (
|
|
id integer CONSTRAINT right_id_key PRIMARY KEY,
|
|
right_school varchar(30)
|
|
);
|
|
|
|
INSERT INTO schools_left (id, left_school) VALUES
|
|
(1, 'Oak Street School'),
|
|
(2, 'Roosevelt High School'),
|
|
(5, 'Washington Middle School'),
|
|
(6, 'Jefferson High School');
|
|
|
|
INSERT INTO schools_right (id, right_school) VALUES
|
|
(1, 'Oak Street School'),
|
|
(2, 'Roosevelt High School'),
|
|
(3, 'Morrison Elementary'),
|
|
(4, 'Chase Magnet Academy'),
|
|
(6, 'Jefferson High School');
|
|
|
|
-- Listing 7-4: Using JOIN
|
|
|
|
SELECT *
|
|
FROM schools_left JOIN schools_right
|
|
ON schools_left.id = schools_right.id;
|
|
|
|
-- Bonus: Also can be specified as INNER JOIN
|
|
|
|
SELECT *
|
|
FROM schools_left INNER JOIN schools_right
|
|
ON schools_left.id = schools_right.id;
|
|
|
|
-- Listing 7-5: Using LEFT JOIN
|
|
|
|
SELECT *
|
|
FROM schools_left LEFT JOIN schools_right
|
|
ON schools_left.id = schools_right.id;
|
|
|
|
-- Listing 7-6: Using RIGHT JOIN
|
|
|
|
SELECT *
|
|
FROM schools_left RIGHT JOIN schools_right
|
|
ON schools_left.id = schools_right.id;
|
|
|
|
-- Listing 7-7: Using FULL OUTER JOIN
|
|
|
|
SELECT *
|
|
FROM schools_left FULL OUTER JOIN schools_right
|
|
ON schools_left.id = schools_right.id;
|
|
|
|
-- Listing 7-8: Using CROSS JOIN
|
|
|
|
SELECT *
|
|
FROM schools_left CROSS JOIN schools_right;
|
|
|
|
-- Listing 7-9: Filtering to show missing values with IS NULL
|
|
|
|
SELECT *
|
|
FROM schools_left LEFT JOIN schools_right
|
|
ON schools_left.id = schools_right.id
|
|
WHERE schools_right.id IS NULL;
|
|
|
|
-- Listing 7-10: Querying specific columns in a join
|
|
SELECT schools_left.id,
|
|
schools_left.left_school,
|
|
schools_right.right_school
|
|
FROM schools_left LEFT JOIN schools_right
|
|
ON schools_left.id = schools_right.id;
|
|
|
|
-- Listing 7-11: Simplifying code with table aliases
|
|
SELECT lt.id,
|
|
lt.left_school,
|
|
rt.right_school
|
|
FROM schools_left AS lt LEFT JOIN schools_right AS rt
|
|
ON lt.id = rt.id;
|
|
|
|
-- Listing 7-12: Joining multiple tables
|
|
CREATE TABLE schools_enrollment (
|
|
id integer,
|
|
enrollment integer
|
|
);
|
|
|
|
CREATE TABLE schools_grades (
|
|
id integer,
|
|
grades varchar(10)
|
|
);
|
|
|
|
INSERT INTO schools_enrollment (id, enrollment)
|
|
VALUES
|
|
(1, 360),
|
|
(2, 1001),
|
|
(5, 450),
|
|
(6, 927);
|
|
|
|
INSERT INTO schools_grades (id, grades)
|
|
VALUES
|
|
(1, 'K-3'),
|
|
(2, '9-12'),
|
|
(5, '6-8'),
|
|
(6, '9-12');
|
|
|
|
SELECT lt.id, lt.left_school, en.enrollment, gr.grades
|
|
FROM schools_left AS lt LEFT JOIN schools_enrollment AS en
|
|
ON lt.id = en.id
|
|
LEFT JOIN schools_grades AS gr
|
|
ON lt.id = gr.id;
|
|
|
|
-- Listing 7-13: Performing math on joined Census tables
|
|
-- Decennial Census 2000. Full data dictionary at https://www.census.gov/prod/cen2000/doc/pl94-171.pdf
|
|
-- Note: Some non-number columns have been given more descriptive names
|
|
|
|
CREATE TABLE us_counties_2000 (
|
|
geo_name varchar(90), -- County/state name,
|
|
state_us_abbreviation varchar(2), -- State/U.S. abbreviation
|
|
state_fips varchar(2), -- State FIPS code
|
|
county_fips varchar(3), -- County code
|
|
p0010001 integer, -- Total population
|
|
p0010002 integer, -- Population of one race:
|
|
p0010003 integer, -- White Alone
|
|
p0010004 integer, -- Black or African American alone
|
|
p0010005 integer, -- American Indian and Alaska Native alone
|
|
p0010006 integer, -- Asian alone
|
|
p0010007 integer, -- Native Hawaiian and Other Pacific Islander alone
|
|
p0010008 integer, -- Some Other Race alone
|
|
p0010009 integer, -- Population of two or more races
|
|
p0010010 integer, -- Population of two races
|
|
p0020002 integer, -- Hispanic or Latino
|
|
p0020003 integer -- Not Hispanic or Latino:
|
|
);
|
|
|
|
COPY us_counties_2000
|
|
FROM 'C:\YourDirectory\us_counties_2000.csv'
|
|
WITH (FORMAT CSV, HEADER);
|
|
|
|
SELECT c2010.geo_name,
|
|
c2010.state_us_abbreviation AS state,
|
|
c2010.p0010001 AS pop_2010,
|
|
c2000.p0010001 AS pop_2000,
|
|
c2010.p0010001 - c2000.p0010001 AS raw_change,
|
|
round( (CAST(c2010.p0010001 AS numeric(8,1)) - c2000.p0010001)
|
|
/ c2000.p0010001 * 100, 1 ) AS pct_change
|
|
FROM us_counties_2010 c2010 INNER JOIN us_counties_2000 c2000
|
|
ON c2010.state_fips = c2000.state_fips
|
|
AND c2010.county_fips = c2000.county_fips
|
|
AND c2010.p0010001 <> c2000.p0010001
|
|
ORDER BY pct_change DESC;
|