Chapter 8 code updates
This commit is contained in:
parent
9b8305ad6f
commit
d2165e4f81
@ -117,6 +117,7 @@ ON district_2020.id = district_2035.id
|
|||||||
WHERE district_2020.id IS NULL;
|
WHERE district_2020.id IS NULL;
|
||||||
|
|
||||||
-- Listing 7-10: Querying specific columns in a join
|
-- Listing 7-10: Querying specific columns in a join
|
||||||
|
|
||||||
SELECT district_2020.id,
|
SELECT district_2020.id,
|
||||||
district_2020.school_2020,
|
district_2020.school_2020,
|
||||||
district_2035.school_2035
|
district_2035.school_2035
|
||||||
@ -124,6 +125,7 @@ FROM district_2020 LEFT JOIN district_2035
|
|||||||
ON district_2020.id = district_2035.id;
|
ON district_2020.id = district_2035.id;
|
||||||
|
|
||||||
-- Listing 7-11: Simplifying code with table aliases
|
-- Listing 7-11: Simplifying code with table aliases
|
||||||
|
|
||||||
SELECT d20.id,
|
SELECT d20.id,
|
||||||
d20.school_2020,
|
d20.school_2020,
|
||||||
d35.school_2035
|
d35.school_2035
|
||||||
@ -131,6 +133,7 @@ FROM district_2020 AS d20 LEFT JOIN district_2035 AS d35
|
|||||||
ON d20.id = d35.id;
|
ON d20.id = d35.id;
|
||||||
|
|
||||||
-- Listing 7-12: Joining multiple tables
|
-- Listing 7-12: Joining multiple tables
|
||||||
|
|
||||||
CREATE TABLE district_2020_enrollment (
|
CREATE TABLE district_2020_enrollment (
|
||||||
id integer,
|
id integer,
|
||||||
enrollment integer
|
enrollment integer
|
||||||
@ -165,18 +168,21 @@ LEFT JOIN district_2020_grades AS gr
|
|||||||
ON d20.id = gr.id;
|
ON d20.id = gr.id;
|
||||||
|
|
||||||
-- Listing 7-13: Combining query results with UNION
|
-- Listing 7-13: Combining query results with UNION
|
||||||
|
|
||||||
SELECT * FROM district_2020
|
SELECT * FROM district_2020
|
||||||
UNION
|
UNION
|
||||||
SELECT * FROM district_2035
|
SELECT * FROM district_2035
|
||||||
ORDER BY id;
|
ORDER BY id;
|
||||||
|
|
||||||
-- Listing 7-14: Combining query results with UNION ALL
|
-- Listing 7-14: Combining query results with UNION ALL
|
||||||
|
|
||||||
SELECT * FROM district_2020
|
SELECT * FROM district_2020
|
||||||
UNION ALL
|
UNION ALL
|
||||||
SELECT * FROM district_2035
|
SELECT * FROM district_2035
|
||||||
ORDER BY id;
|
ORDER BY id;
|
||||||
|
|
||||||
-- Listing 7-15: Customizing a UNION query
|
-- Listing 7-15: Customizing a UNION query
|
||||||
|
|
||||||
SELECT '2020' AS year,
|
SELECT '2020' AS year,
|
||||||
school_2020 AS school
|
school_2020 AS school
|
||||||
FROM district_2020
|
FROM district_2020
|
||||||
@ -189,6 +195,7 @@ FROM district_2035
|
|||||||
ORDER BY school, year;
|
ORDER BY school, year;
|
||||||
|
|
||||||
-- Listing 7-16: Combining query results with INTERSECT and EXCEPT
|
-- Listing 7-16: Combining query results with INTERSECT and EXCEPT
|
||||||
|
|
||||||
SELECT * FROM district_2020
|
SELECT * FROM district_2020
|
||||||
INTERSECT
|
INTERSECT
|
||||||
SELECT * FROM district_2035
|
SELECT * FROM district_2035
|
||||||
@ -200,14 +207,15 @@ SELECT * FROM district_2035
|
|||||||
ORDER BY id;
|
ORDER BY id;
|
||||||
|
|
||||||
-- Listing 7-17: Performing math on joined Census population estimates tables
|
-- Listing 7-17: Performing math on joined Census population estimates tables
|
||||||
|
|
||||||
CREATE TABLE us_counties_pop_est_2010 (
|
CREATE TABLE us_counties_pop_est_2010 (
|
||||||
state_fips text, -- State FIPS code
|
state_fips text, -- State FIPS code
|
||||||
county_fips text, -- County FIPS code
|
county_fips text, -- County FIPS code
|
||||||
region smallint, -- Region
|
region smallint, -- Region
|
||||||
state_name text, -- State name
|
state_name text, -- State name
|
||||||
county_name text, -- County name
|
county_name text, -- County name
|
||||||
estimates_base_2010 integer, -- 4/1/2010 resident total population estimates base
|
estimates_base_2010 integer, -- 4/1/2010 resident total population estimates base
|
||||||
CONSTRAINT counties_2010_key PRIMARY KEY (state_fips, county_fips)
|
CONSTRAINT counties_2010_key PRIMARY KEY (state_fips, county_fips)
|
||||||
);
|
);
|
||||||
|
|
||||||
COPY us_counties_pop_est_2010
|
COPY us_counties_pop_est_2010
|
||||||
@ -220,7 +228,7 @@ SELECT c2019.county_name,
|
|||||||
c2010.estimates_base_2010 AS pop_2010,
|
c2010.estimates_base_2010 AS pop_2010,
|
||||||
c2019.pop_est_2019 - c2010.estimates_base_2010 AS raw_change,
|
c2019.pop_est_2019 - c2010.estimates_base_2010 AS raw_change,
|
||||||
round( (c2019.pop_est_2019::numeric - c2010.estimates_base_2010)
|
round( (c2019.pop_est_2019::numeric - c2010.estimates_base_2010)
|
||||||
/ c2010.estimates_base_2010 * 100, 1 ) AS pct_change
|
/ c2010.estimates_base_2010 * 100, 1 ) AS pct_change
|
||||||
FROM us_counties_pop_est_2019 AS c2019
|
FROM us_counties_pop_est_2019 AS c2019
|
||||||
JOIN us_counties_pop_est_2010 AS c2010
|
JOIN us_counties_pop_est_2010 AS c2010
|
||||||
ON c2019.state_fips = c2010.state_fips
|
ON c2019.state_fips = c2010.state_fips
|
||||||
|
|||||||
@ -1,20 +1,20 @@
|
|||||||
-- FIRST EDITION FILE; IGNORE
|
-- FIRST EDITION FILE; IGNORE
|
||||||
|
|
||||||
|
|
||||||
--------------------------------------------------------------
|
---------------------------------------------------------------------------
|
||||||
-- Practical SQL: A Beginner's Guide to Storytelling with Data
|
-- Practical SQL: A Beginner's Guide to Storytelling with Data, 2nd Edition
|
||||||
-- by Anthony DeBarros
|
-- by Anthony DeBarros
|
||||||
|
|
||||||
-- Chapter 8 Code Examples
|
-- Chapter 8 Code Examples
|
||||||
--------------------------------------------------------------
|
----------------------------------------------------------------------------
|
||||||
|
|
||||||
-- Listing 8-1: Declaring a single-column natural key as primary key
|
-- Listing 8-1: Declaring a single-column natural key as primary key
|
||||||
|
|
||||||
-- As a column constraint
|
-- As a column constraint
|
||||||
CREATE TABLE natural_key_example (
|
CREATE TABLE natural_key_example (
|
||||||
license_id varchar(10) CONSTRAINT license_key PRIMARY KEY,
|
license_id text CONSTRAINT license_key PRIMARY KEY,
|
||||||
first_name varchar(50),
|
first_name text,
|
||||||
last_name varchar(50)
|
last_name text
|
||||||
);
|
);
|
||||||
|
|
||||||
-- Drop the table before trying again
|
-- Drop the table before trying again
|
||||||
@ -22,88 +22,102 @@ DROP TABLE natural_key_example;
|
|||||||
|
|
||||||
-- As a table constraint
|
-- As a table constraint
|
||||||
CREATE TABLE natural_key_example (
|
CREATE TABLE natural_key_example (
|
||||||
license_id varchar(10),
|
license_id text,
|
||||||
first_name varchar(50),
|
first_name text,
|
||||||
last_name varchar(50),
|
last_name text,
|
||||||
CONSTRAINT license_key PRIMARY KEY (license_id)
|
CONSTRAINT license_key PRIMARY KEY (license_id)
|
||||||
);
|
);
|
||||||
|
|
||||||
-- Listing 8-2: Example of a primary key violation
|
-- Listing 8-2: Example of a primary key violation
|
||||||
INSERT INTO natural_key_example (license_id, first_name, last_name)
|
|
||||||
VALUES ('T229901', 'Lynn', 'Malero');
|
|
||||||
|
|
||||||
INSERT INTO natural_key_example (license_id, first_name, last_name)
|
INSERT INTO natural_key_example (license_id, first_name, last_name)
|
||||||
VALUES ('T229901', 'Sam', 'Tracy');
|
VALUES ('T229901', 'Gem', 'Godfrey');
|
||||||
|
|
||||||
|
INSERT INTO natural_key_example (license_id, first_name, last_name)
|
||||||
|
VALUES ('T229901', 'John', 'Mitchell');
|
||||||
|
|
||||||
-- Listing 8-3: Declaring a composite primary key as a natural key
|
-- Listing 8-3: Declaring a composite primary key as a natural key
|
||||||
|
|
||||||
CREATE TABLE natural_key_composite_example (
|
CREATE TABLE natural_key_composite_example (
|
||||||
student_id varchar(10),
|
student_id text,
|
||||||
school_day date,
|
school_day date,
|
||||||
present boolean,
|
present boolean,
|
||||||
CONSTRAINT student_key PRIMARY KEY (student_id, school_day)
|
CONSTRAINT student_key PRIMARY KEY (student_id, school_day)
|
||||||
);
|
);
|
||||||
|
|
||||||
-- Listing 8-4: Example of a composite primary key violation
|
-- Listing 8-4: Example of a composite primary key violation
|
||||||
|
INSERT INTO natural_key_composite_example (student_id, school_day, present)
|
||||||
|
VALUES(775, '1/22/2022', 'Y');
|
||||||
|
|
||||||
INSERT INTO natural_key_composite_example (student_id, school_day, present)
|
INSERT INTO natural_key_composite_example (student_id, school_day, present)
|
||||||
VALUES(775, '1/22/2017', 'Y');
|
VALUES(775, '1/23/2022', 'Y');
|
||||||
|
|
||||||
INSERT INTO natural_key_composite_example (student_id, school_day, present)
|
INSERT INTO natural_key_composite_example (student_id, school_day, present)
|
||||||
VALUES(775, '1/23/2017', 'Y');
|
VALUES(775, '1/23/2022', 'N');
|
||||||
|
|
||||||
INSERT INTO natural_key_composite_example (student_id, school_day, present)
|
-- Listing 8-5: Declaring a bigint column as a surrogate key using IDENTITY
|
||||||
VALUES(775, '1/23/2017', 'N');
|
|
||||||
|
|
||||||
-- Listing 8-5: Declaring a bigserial column as a surrogate key
|
|
||||||
|
|
||||||
CREATE TABLE surrogate_key_example (
|
CREATE TABLE surrogate_key_example (
|
||||||
order_number bigserial,
|
order_number bigint GENERATED ALWAYS AS IDENTITY,
|
||||||
product_name varchar(50),
|
product_name text,
|
||||||
order_date date,
|
order_time timestamp with time zone,
|
||||||
CONSTRAINT order_key PRIMARY KEY (order_number)
|
CONSTRAINT order_number_key PRIMARY KEY (order_number)
|
||||||
);
|
);
|
||||||
|
|
||||||
INSERT INTO surrogate_key_example (product_name, order_date)
|
INSERT INTO surrogate_key_example (product_name, order_time)
|
||||||
VALUES ('Beachball Polish', '2015-03-17'),
|
VALUES ('Beachball Polish', '2020-03-15 09:21-07'),
|
||||||
('Wrinkle De-Atomizer', '2017-05-22'),
|
('Wrinkle De-Atomizer', '2017-05-22 14:00-07'),
|
||||||
('Flux Capacitor', '1985-10-26');
|
('Flux Capacitor', '1985-10-26 01:18:00-07');
|
||||||
|
|
||||||
SELECT * FROM surrogate_key_example;
|
SELECT * FROM surrogate_key_example;
|
||||||
|
|
||||||
-- Listing 8-6: A foreign key example
|
-- Listing 8-6:
|
||||||
|
|
||||||
|
INSERT INTO surrogate_key_example
|
||||||
|
OVERRIDING SYSTEM VALUE
|
||||||
|
VALUES (4, 'Chicken Coop', '2021-09-03 10:33-07');
|
||||||
|
|
||||||
|
ALTER TABLE surrogate_key_example ALTER COLUMN order_number RESTART WITH 5;
|
||||||
|
|
||||||
|
INSERT INTO surrogate_key_example (product_name, order_time)
|
||||||
|
VALUES ('Aloe Plant', '2020-03-15 10:09-07');
|
||||||
|
|
||||||
|
SELECT * FROM surrogate_key_example;
|
||||||
|
|
||||||
|
-- Listing 8-7: A foreign key example
|
||||||
|
|
||||||
CREATE TABLE licenses (
|
CREATE TABLE licenses (
|
||||||
license_id varchar(10),
|
license_id text,
|
||||||
first_name varchar(50),
|
first_name text,
|
||||||
last_name varchar(50),
|
last_name text,
|
||||||
CONSTRAINT licenses_key PRIMARY KEY (license_id)
|
CONSTRAINT licenses_key PRIMARY KEY (license_id)
|
||||||
);
|
);
|
||||||
|
|
||||||
CREATE TABLE registrations (
|
CREATE TABLE registrations (
|
||||||
registration_id varchar(10),
|
registration_id text,
|
||||||
registration_date date,
|
registration_date timestamp with time zone,
|
||||||
license_id varchar(10) REFERENCES licenses (license_id),
|
license_id text REFERENCES licenses (license_id),
|
||||||
CONSTRAINT registration_key PRIMARY KEY (registration_id, license_id)
|
CONSTRAINT registration_key PRIMARY KEY (registration_id, license_id)
|
||||||
);
|
);
|
||||||
|
|
||||||
INSERT INTO licenses (license_id, first_name, last_name)
|
INSERT INTO licenses (license_id, first_name, last_name)
|
||||||
VALUES ('T229901', 'Lynn', 'Malero');
|
VALUES ('T229901', 'Steve', 'Rothery');
|
||||||
|
|
||||||
INSERT INTO registrations (registration_id, registration_date, license_id)
|
INSERT INTO registrations (registration_id, registration_date, license_id)
|
||||||
VALUES ('A203391', '3/17/2017', 'T229901');
|
VALUES ('A203391', '3/17/2022', 'T229901');
|
||||||
|
|
||||||
INSERT INTO registrations (registration_id, registration_date, license_id)
|
INSERT INTO registrations (registration_id, registration_date, license_id)
|
||||||
VALUES ('A75772', '3/17/2017', 'T000001');
|
VALUES ('A75772', '3/17/2022', 'T000001');
|
||||||
|
|
||||||
-- Listing 8-7: CHECK constraint examples
|
-- Listing 8-8: CHECK constraint examples
|
||||||
|
|
||||||
CREATE TABLE check_constraint_example (
|
CREATE TABLE check_constraint_example (
|
||||||
user_id bigserial,
|
user_id bigint GENERATED ALWAYS AS IDENTITY,
|
||||||
user_role varchar(50),
|
user_role text,
|
||||||
salary integer,
|
salary numeric(10,2),
|
||||||
CONSTRAINT user_id_key PRIMARY KEY (user_id),
|
CONSTRAINT user_id_key PRIMARY KEY (user_id),
|
||||||
CONSTRAINT check_role_in_list CHECK (user_role IN('Admin', 'Staff')),
|
CONSTRAINT check_role_in_list CHECK (user_role IN('Admin', 'Staff')),
|
||||||
CONSTRAINT check_salary_not_zero CHECK (salary > 0)
|
CONSTRAINT check_salary_not_below_zero CHECK (salary >= 0)
|
||||||
);
|
);
|
||||||
|
|
||||||
-- Both of these will fail:
|
-- Both of these will fail:
|
||||||
@ -111,15 +125,16 @@ INSERT INTO check_constraint_example (user_role)
|
|||||||
VALUES ('admin');
|
VALUES ('admin');
|
||||||
|
|
||||||
INSERT INTO check_constraint_example (salary)
|
INSERT INTO check_constraint_example (salary)
|
||||||
VALUES (0);
|
VALUES (-10000);
|
||||||
|
|
||||||
-- Listing 8-8: UNIQUE constraint example
|
-- Listing 8-9: UNIQUE constraint example
|
||||||
|
|
||||||
CREATE TABLE unique_constraint_example (
|
CREATE TABLE unique_constraint_example (
|
||||||
contact_id bigserial CONSTRAINT contact_id_key PRIMARY KEY,
|
contact_id bigint GENERATED ALWAYS AS IDENTITY,
|
||||||
first_name varchar(50),
|
first_name text,
|
||||||
last_name varchar(50),
|
last_name text,
|
||||||
email varchar(200),
|
email text,
|
||||||
|
CONSTRAINT contact_id_key PRIMARY KEY (contact_id),
|
||||||
CONSTRAINT email_unique UNIQUE (email)
|
CONSTRAINT email_unique UNIQUE (email)
|
||||||
);
|
);
|
||||||
|
|
||||||
@ -132,16 +147,16 @@ VALUES ('Betty', 'Diaz', 'bdiaz@example.org');
|
|||||||
INSERT INTO unique_constraint_example (first_name, last_name, email)
|
INSERT INTO unique_constraint_example (first_name, last_name, email)
|
||||||
VALUES ('Sasha', 'Lee', 'slee@example.org');
|
VALUES ('Sasha', 'Lee', 'slee@example.org');
|
||||||
|
|
||||||
-- Listing 8-9: NOT NULL constraint example
|
-- Listing 8-10: NOT NULL constraint example
|
||||||
|
|
||||||
CREATE TABLE not_null_example (
|
CREATE TABLE not_null_example (
|
||||||
student_id bigserial,
|
student_id bigint GENERATED ALWAYS AS IDENTITY,
|
||||||
first_name varchar(50) NOT NULL,
|
first_name text NOT NULL,
|
||||||
last_name varchar(50) NOT NULL,
|
last_name text NOT NULL,
|
||||||
CONSTRAINT student_id_key PRIMARY KEY (student_id)
|
CONSTRAINT student_id_key PRIMARY KEY (student_id)
|
||||||
);
|
);
|
||||||
|
|
||||||
-- Listing 8-10: Dropping and adding a primary key and a NOT NULL constraint
|
-- Listing 8-11: Dropping and adding a primary key and a NOT NULL constraint
|
||||||
|
|
||||||
-- Drop
|
-- Drop
|
||||||
ALTER TABLE not_null_example DROP CONSTRAINT student_id_key;
|
ALTER TABLE not_null_example DROP CONSTRAINT student_id_key;
|
||||||
@ -155,15 +170,15 @@ ALTER TABLE not_null_example ALTER COLUMN first_name DROP NOT NULL;
|
|||||||
-- Add
|
-- Add
|
||||||
ALTER TABLE not_null_example ALTER COLUMN first_name SET NOT NULL;
|
ALTER TABLE not_null_example ALTER COLUMN first_name SET NOT NULL;
|
||||||
|
|
||||||
-- Listing 8-11: Importing New York City address data
|
-- Listing 8-12: Importing New York City address data
|
||||||
|
|
||||||
CREATE TABLE new_york_addresses (
|
CREATE TABLE new_york_addresses (
|
||||||
longitude numeric(9,6),
|
longitude numeric(9,6),
|
||||||
latitude numeric(9,6),
|
latitude numeric(9,6),
|
||||||
street_number varchar(10),
|
street_number text,
|
||||||
street varchar(32),
|
street text,
|
||||||
unit varchar(7),
|
unit text,
|
||||||
postcode varchar(5),
|
postcode text,
|
||||||
id integer CONSTRAINT new_york_key PRIMARY KEY
|
id integer CONSTRAINT new_york_key PRIMARY KEY
|
||||||
);
|
);
|
||||||
|
|
||||||
@ -171,7 +186,7 @@ COPY new_york_addresses
|
|||||||
FROM 'C:\YourDirectory\city_of_new_york.csv'
|
FROM 'C:\YourDirectory\city_of_new_york.csv'
|
||||||
WITH (FORMAT CSV, HEADER);
|
WITH (FORMAT CSV, HEADER);
|
||||||
|
|
||||||
-- Listing 8-12: Benchmark queries for index performance
|
-- Listing 8-13: Benchmark queries for index performance
|
||||||
|
|
||||||
EXPLAIN ANALYZE SELECT * FROM new_york_addresses
|
EXPLAIN ANALYZE SELECT * FROM new_york_addresses
|
||||||
WHERE street = 'BROADWAY';
|
WHERE street = 'BROADWAY';
|
||||||
@ -182,6 +197,6 @@ WHERE street = '52 STREET';
|
|||||||
EXPLAIN ANALYZE SELECT * FROM new_york_addresses
|
EXPLAIN ANALYZE SELECT * FROM new_york_addresses
|
||||||
WHERE street = 'ZWICKY AVENUE';
|
WHERE street = 'ZWICKY AVENUE';
|
||||||
|
|
||||||
-- Listing 8-13: Creating a B-Tree index on the new_york_addresses table
|
-- Listing 8-14: Creating a B-Tree index on the new_york_addresses table
|
||||||
|
|
||||||
CREATE INDEX street_idx ON new_york_addresses (street);
|
CREATE INDEX street_idx ON new_york_addresses (street);
|
||||||
|
|||||||
@ -374,6 +374,101 @@ FROM us_counties_pop_est_2019 AS c2019
|
|||||||
JOIN us_counties_pop_est_2010 AS c2010
|
JOIN us_counties_pop_est_2010 AS c2010
|
||||||
ON c2019.state_fips = c2010.state_fips
|
ON c2019.state_fips = c2010.state_fips
|
||||||
AND c2019.county_fips = c2010.county_fips;
|
AND c2019.county_fips = c2010.county_fips;
|
||||||
|
|
||||||
|
|
||||||
|
----------------------------------------------------------------------------
|
||||||
|
-- Chapter 8: Table Design That Works for You
|
||||||
|
----------------------------------------------------------------------------
|
||||||
|
|
||||||
|
-- Consider the following two tables from a database you’re making to keep
|
||||||
|
-- track of your vinyl LP collection. Start by reviewing these CREATE TABLE
|
||||||
|
-- statements.
|
||||||
|
|
||||||
|
-- The albums table includes information specific to the overall collection
|
||||||
|
-- of songs on the disc. The songs table catalogs each track on the album.
|
||||||
|
-- Each song has a title and a column for its composers, who might be
|
||||||
|
-- different than the album artist.
|
||||||
|
|
||||||
|
CREATE TABLE albums (
|
||||||
|
album_id bigserial,
|
||||||
|
catalog_code varchar(100),
|
||||||
|
title text,
|
||||||
|
artist text,
|
||||||
|
release_date date,
|
||||||
|
genre varchar(40),
|
||||||
|
description text
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE TABLE songs (
|
||||||
|
song_id bigserial,
|
||||||
|
title text,
|
||||||
|
composers text,
|
||||||
|
album_id bigint
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Use the tables to answer these questions:
|
||||||
|
|
||||||
|
-- 1. Modify these CREATE TABLE statements to include primary and foreign keys
|
||||||
|
-- plus additional constraints on both tables. Explain why you made your
|
||||||
|
-- choices.
|
||||||
|
|
||||||
|
-- Answer (yours may vary slightly):
|
||||||
|
|
||||||
|
CREATE TABLE albums (
|
||||||
|
album_id bigint GENERATED ALWAYS AS IDENTITY,
|
||||||
|
catalog_code text NOT NULL,
|
||||||
|
title text NOT NULL,
|
||||||
|
artist text NOT NULL,
|
||||||
|
release_date date,
|
||||||
|
genre text,
|
||||||
|
description text,
|
||||||
|
CONSTRAINT album_id_key PRIMARY KEY (album_id),
|
||||||
|
CONSTRAINT release_date_check CHECK (release_date > '1/1/1925')
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE TABLE songs (
|
||||||
|
song_id bigint GENERATED ALWAYS AS IDENTITY,
|
||||||
|
title text NOT NULL,
|
||||||
|
composer text NOT NULL,
|
||||||
|
album_id bigint REFERENCES albums (album_id),
|
||||||
|
CONSTRAINT song_id_key PRIMARY KEY (song_id)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Answers:
|
||||||
|
-- a) Both tables get a primary key using surrogate key id values that are
|
||||||
|
-- auto-generated via IDENTITY.
|
||||||
|
|
||||||
|
-- b) The songs table references albums via a foreign key constraint.
|
||||||
|
|
||||||
|
-- c) In both tables, the title and artist/composer columns cannot be empty, which
|
||||||
|
-- is specified via a NOT NULL constraint. We assume that every album and
|
||||||
|
-- song should at minimum have that information.
|
||||||
|
|
||||||
|
-- d) In albums, the release_date column has a CHECK constraint
|
||||||
|
-- because it would be likely impossible for us to own an LP made before 1925.
|
||||||
|
|
||||||
|
|
||||||
|
-- 2. Instead of using album_id as a surrogate key for your primary key, are
|
||||||
|
-- there any columns in albums that could be useful as a natural key? What would
|
||||||
|
-- you have to know to decide?
|
||||||
|
|
||||||
|
-- Answer:
|
||||||
|
-- We could consider the catalog_code. We would have to answer yes to
|
||||||
|
-- these questions:
|
||||||
|
-- 1. Is it going to be unique across all albums released by all companies?
|
||||||
|
-- 2. Will an album always have a catelog code?
|
||||||
|
|
||||||
|
|
||||||
|
-- 3. To speed up queries, which columns are good candidates for indexes?
|
||||||
|
|
||||||
|
-- Answer:
|
||||||
|
-- Primary key columns get indexes by default, but we should add an index
|
||||||
|
-- to the album_id foreign key column in the songs table because we'll use
|
||||||
|
-- it in table joins. It's likely that we'll query these tables to search
|
||||||
|
-- by titles and artists, so those columns in both tables should get indexes
|
||||||
|
-- too. The release_date in albums also is a candidate if we expect
|
||||||
|
-- to perform many queries that include date ranges.
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|||||||
Loading…
x
Reference in New Issue
Block a user