-------------------------------------------------------------- -- Practical SQL: A Beginner's Guide to Storytelling with Data -- by Anthony DeBarros -- Chapter 5 Code Examples -------------------------------------------------------------- -- Listing 5-1: Using COPY for data import -- This is example syntax only; running it will produce an error COPY table_name FROM 'C:\YourDirectory\your_file.csv' WITH (FORMAT CSV, HEADER); -- Listing 5-2: A CREATE TABLE statement for Census county data -- Full data dictionary available at: http://www.census.gov/prod/cen2010/doc/pl94-171.pdf -- Note: Some columns have been given more descriptive names CREATE TABLE us_counties_2010 ( geo_name varchar(90), -- Name of the geography state_us_abbreviation varchar(2), -- State/U.S. abbreviation summary_level varchar(3), -- Summary Level region smallint, -- Region division smallint, -- Division state_fips varchar(2), -- State FIPS code county_fips varchar(3), -- County code area_land bigint, -- Area (Land) in square meters area_water bigint, -- Area (Water) in square meters population_count_100_percent integer, -- Population count (100%) housing_unit_count_100_percent integer, -- Housing Unit count (100%) internal_point_lat numeric(10,7), -- Internal point (latitude) internal_point_lon numeric(10,7), -- Internal point (longitude) -- This section is referred to as P1. Race: 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: p0010011 integer, -- White; Black or African American p0010012 integer, -- White; American Indian and Alaska Native p0010013 integer, -- White; Asian p0010014 integer, -- White; Native Hawaiian and Other Pacific Islander p0010015 integer, -- White; Some Other Race p0010016 integer, -- Black or African American; American Indian and Alaska Native p0010017 integer, -- Black or African American; Asian p0010018 integer, -- Black or African American; Native Hawaiian and Other Pacific Islander p0010019 integer, -- Black or African American; Some Other Race p0010020 integer, -- American Indian and Alaska Native; Asian p0010021 integer, -- American Indian and Alaska Native; Native Hawaiian and Other Pacific Islander p0010022 integer, -- American Indian and Alaska Native; Some Other Race p0010023 integer, -- Asian; Native Hawaiian and Other Pacific Islander p0010024 integer, -- Asian; Some Other Race p0010025 integer, -- Native Hawaiian and Other Pacific Islander; Some Other Race p0010026 integer, -- Population of three races p0010047 integer, -- Population of four races p0010063 integer, -- Population of five races p0010070 integer, -- Population of six races -- This section is referred to as P2. HISPANIC OR LATINO, AND NOT HISPANIC OR LATINO BY RACE p0020001 integer, -- Total p0020002 integer, -- Hispanic or Latino p0020003 integer, -- Not Hispanic or Latino: p0020004 integer, -- Population of one race: p0020005 integer, -- White Alone p0020006 integer, -- Black or African American alone p0020007 integer, -- American Indian and Alaska Native alone p0020008 integer, -- Asian alone p0020009 integer, -- Native Hawaiian and Other Pacific Islander alone p0020010 integer, -- Some Other Race alone p0020011 integer, -- Two or More Races p0020012 integer, -- Population of two races p0020028 integer, -- Population of three races p0020049 integer, -- Population of four races p0020065 integer, -- Population of five races p0020072 integer, -- Population of six races -- This section is referred to as P3. RACE FOR THE POPULATION 18 YEARS AND OVER p0030001 integer, -- Total p0030002 integer, -- Population of one race: p0030003 integer, -- White alone p0030004 integer, -- Black or African American alone p0030005 integer, -- American Indian and Alaska Native alone p0030006 integer, -- Asian alone p0030007 integer, -- Native Hawaiian and Other Pacific Islander alone p0030008 integer, -- Some Other Race alone p0030009 integer, -- Two or More Races p0030010 integer, -- Population of two races p0030026 integer, -- Population of three races p0030047 integer, -- Population of four races p0030063 integer, -- Population of five races p0030070 integer, -- Population of six races -- This section is referred to as P4. HISPANIC OR LATINO, AND NOT HISPANIC OR LATINO BY RACE -- FOR THE POPULATION 18 YEARS AND OVER p0040001 integer, -- Total p0040002 integer, -- Hispanic or Latino p0040003 integer, -- Not Hispanic or Latino: p0040004 integer, -- Population of one race: p0040005 integer, -- White alone p0040006 integer, -- Black or African American alone p0040007 integer, -- American Indian and Alaska Native alone p0040008 integer, -- Asian alone p0040009 integer, -- Native Hawaiian and Other Pacific Islander alone p0040010 integer, -- Some Other Race alone p0040011 integer, -- Two or More Races p0040012 integer, -- Population of two races p0040028 integer, -- Population of three races p0040049 integer, -- Population of four races p0040065 integer, -- Population of five races p0040072 integer, -- Population of six races -- This section is referred to as H1. OCCUPANCY STATUS h0010001 integer, -- Total housing units h0010002 integer, -- Occupied h0010003 integer -- Vacant ); SELECT * FROM us_counties_2010; -- Listing 5-3: Importing Census data using COPY -- Note! If you run into an import error here, be sure you downloaded the code and -- data for the book according to the steps listed on page xxvii in the Introduction. -- Windows users: Please check the Note on page xxvii as well. COPY us_counties_2010 FROM 'C:\YourDirectory\us_counties_2010.csv' WITH (FORMAT CSV, HEADER); -- Checking the data SELECT * FROM us_counties_2010; SELECT geo_name, state_us_abbreviation, area_land FROM us_counties_2010 ORDER BY area_land DESC LIMIT 3; SELECT geo_name, state_us_abbreviation, internal_point_lon FROM us_counties_2010 ORDER BY internal_point_lon DESC LIMIT 5; -- Listing 5-4: Creating a table to track supervisor salaries CREATE TABLE supervisor_salaries ( town varchar(30), county varchar(30), supervisor varchar(30), start_date date, salary money, benefits money ); -- Listing 5-5: Importing salaries data from CSV to three table columns COPY supervisor_salaries (town, supervisor, salary) FROM 'C:\YourDirectory\supervisor_salaries.csv' WITH (FORMAT CSV, HEADER); -- Check the data SELECT * FROM supervisor_salaries LIMIT 2; -- Listing 5-6 Use a temporary table to add a default value to a column during -- import DELETE FROM supervisor_salaries; CREATE TEMPORARY TABLE supervisor_salaries_temp (LIKE supervisor_salaries); COPY supervisor_salaries_temp (town, supervisor, salary) FROM 'C:\YourDirectory\supervisor_salaries.csv' WITH (FORMAT CSV, HEADER); INSERT INTO supervisor_salaries (town, county, supervisor, salary) SELECT town, 'Some County', supervisor, salary FROM supervisor_salaries_temp; DROP TABLE supervisor_salaries_temp; -- Check the data SELECT * FROM supervisor_salaries LIMIT 2; -- Listing 5-7: Export an entire table with COPY COPY us_counties_2010 TO 'C:\YourDirectory\us_counties_export.txt' WITH (FORMAT CSV, HEADER, DELIMITER '|'); -- Listing 5-8: Exporting selected columns from a table with COPY COPY us_counties_2010 (geo_name, internal_point_lat, internal_point_lon) TO 'C:\YourDirectory\us_counties_latlon_export.txt' WITH (FORMAT CSV, HEADER, DELIMITER '|'); -- Listing 5-9: Exporting query results with COPY COPY ( SELECT geo_name, state_us_abbreviation FROM us_counties_2010 WHERE geo_name ILIKE '%mill%' ) TO 'C:\YourDirectory\us_counties_mill_export.txt' WITH (FORMAT CSV, HEADER, DELIMITER '|');