Skip to content

Commit

Permalink
Merge pull request #26 from censusreporter/region-division-fix
Browse files Browse the repository at this point in the history
Use TIGER data on state regions and divisions when populating census_name_lookup
  • Loading branch information
JoeGermuska committed Apr 21, 2021
2 parents 47f11b5 + e434bfb commit ab1f66f
Showing 1 changed file with 78 additions and 13 deletions.
91 changes: 78 additions & 13 deletions 13_index_tiger_2019.sql
Expand Up @@ -477,7 +477,12 @@ INSERT INTO tiger2019.census_name_lookup
(SELECT b01003.b01003001 FROM acs2018_5yr.b01003 WHERE geoid = '03000US1'),
(SELECT SUM(aland) FROM tiger2019.state WHERE division='1'),
(SELECT SUM(awater) FROM tiger2019.state WHERE division='1'),
(SELECT ST_Union(geom) FROM tiger2019.census_name_lookup WHERE full_geoid IN ('04000US09', '04000US23', '04000US25', '04000US33', '04000US44', '04000US50'));
(SELECT ST_Multi(ST_Union(tiger2019.census_name_lookup.geom))
FROM tiger2019.census_name_lookup,
tiger2019.state
WHERE tiger2019.state.division = '1'
AND tiger2019.census_name_lookup.sumlevel = '040'
AND tiger2019.census_name_lookup.geoid = tiger2019.state.geoid);
-- Division 2
INSERT INTO tiger2019.census_name_lookup
SELECT
Expand All @@ -491,7 +496,12 @@ INSERT INTO tiger2019.census_name_lookup
(SELECT b01003.b01003001 FROM acs2018_5yr.b01003 WHERE geoid = '03000US2'),
(SELECT SUM(aland) FROM tiger2019.state WHERE division='2'),
(SELECT SUM(awater) FROM tiger2019.state WHERE division='2'),
(SELECT ST_Multi(ST_Union(geom)) FROM tiger2019.census_name_lookup WHERE full_geoid IN ('04000US34', '04000US36', '04000US42'));
(SELECT ST_Multi(ST_Union(tiger2019.census_name_lookup.geom))
FROM tiger2019.census_name_lookup,
tiger2019.state
WHERE tiger2019.state.division = '2'
AND tiger2019.census_name_lookup.sumlevel = '040'
AND tiger2019.census_name_lookup.geoid = tiger2019.state.geoid);
-- Division 3
INSERT INTO tiger2019.census_name_lookup
SELECT
Expand All @@ -505,7 +515,12 @@ INSERT INTO tiger2019.census_name_lookup
(SELECT b01003.b01003001 FROM acs2018_5yr.b01003 WHERE geoid = '03000US3'),
(SELECT SUM(aland) FROM tiger2019.state WHERE division='3'),
(SELECT SUM(awater) FROM tiger2019.state WHERE division='3'),
(SELECT ST_Multi(ST_Union(geom)) FROM tiger2019.census_name_lookup WHERE full_geoid IN ('04000US17', '04000US19', '04000US26', '04000US39', '04000US55'));
(SELECT ST_Multi(ST_Union(tiger2019.census_name_lookup.geom))
FROM tiger2019.census_name_lookup,
tiger2019.state
WHERE tiger2019.state.division = '3'
AND tiger2019.census_name_lookup.sumlevel = '040'
AND tiger2019.census_name_lookup.geoid = tiger2019.state.geoid);
-- Division 4
INSERT INTO tiger2019.census_name_lookup
SELECT
Expand All @@ -519,7 +534,12 @@ INSERT INTO tiger2019.census_name_lookup
(SELECT b01003.b01003001 FROM acs2018_5yr.b01003 WHERE geoid = '03000US4'),
(SELECT SUM(aland) FROM tiger2019.state WHERE division='4'),
(SELECT SUM(awater) FROM tiger2019.state WHERE division='4'),
(SELECT ST_Multi(ST_Union(geom)) FROM tiger2019.census_name_lookup WHERE full_geoid IN ('04000US19', '04000US20', '04000US27', '04000US29', '04000US31', '04000US38', '04000US46'));
(SELECT ST_Multi(ST_Union(tiger2019.census_name_lookup.geom))
FROM tiger2019.census_name_lookup,
tiger2019.state
WHERE tiger2019.state.division = '4'
AND tiger2019.census_name_lookup.sumlevel = '040'
AND tiger2019.census_name_lookup.geoid = tiger2019.state.geoid);
-- Division 5
INSERT INTO tiger2019.census_name_lookup
SELECT
Expand All @@ -533,7 +553,12 @@ INSERT INTO tiger2019.census_name_lookup
(SELECT b01003.b01003001 FROM acs2018_5yr.b01003 WHERE geoid = '03000US5'),
(SELECT SUM(aland) FROM tiger2019.state WHERE division='5'),
(SELECT SUM(awater) FROM tiger2019.state WHERE division='5'),
(SELECT ST_Multi(ST_Union(geom)) FROM tiger2019.census_name_lookup WHERE full_geoid IN ('04000US10', '04000US11', '04000US12', '04000US13', '04000US24', '04000US37', '04000US45', '04000US51', '04000US54'));
(SELECT ST_Multi(ST_Union(tiger2019.census_name_lookup.geom))
FROM tiger2019.census_name_lookup,
tiger2019.state
WHERE tiger2019.state.division = '5'
AND tiger2019.census_name_lookup.sumlevel = '040'
AND tiger2019.census_name_lookup.geoid = tiger2019.state.geoid);
-- Division 6
INSERT INTO tiger2019.census_name_lookup
SELECT
Expand All @@ -547,7 +572,12 @@ INSERT INTO tiger2019.census_name_lookup
(SELECT b01003.b01003001 FROM acs2018_5yr.b01003 WHERE geoid = '03000US6'),
(SELECT SUM(aland) FROM tiger2019.state WHERE division='6'),
(SELECT SUM(awater) FROM tiger2019.state WHERE division='6'),
(SELECT ST_Multi(ST_Union(geom)) FROM tiger2019.census_name_lookup WHERE full_geoid IN ('04000US01', '04000US21', '04000US28', '04000US47'));
(SELECT ST_Multi(ST_Union(tiger2019.census_name_lookup.geom))
FROM tiger2019.census_name_lookup,
tiger2019.state
WHERE tiger2019.state.division = '6'
AND tiger2019.census_name_lookup.sumlevel = '040'
AND tiger2019.census_name_lookup.geoid = tiger2019.state.geoid);
-- Division 7
INSERT INTO tiger2019.census_name_lookup
SELECT
Expand All @@ -561,7 +591,12 @@ INSERT INTO tiger2019.census_name_lookup
(SELECT b01003.b01003001 FROM acs2018_5yr.b01003 WHERE geoid = '03000US7'),
(SELECT SUM(aland) FROM tiger2019.state WHERE division='7'),
(SELECT SUM(awater) FROM tiger2019.state WHERE division='7'),
(SELECT ST_Multi(ST_Union(geom)) FROM tiger2019.census_name_lookup WHERE full_geoid IN ('04000US05', '04000US22', '04000US40', '04000US48'));
(SELECT ST_Multi(ST_Union(tiger2019.census_name_lookup.geom))
FROM tiger2019.census_name_lookup,
tiger2019.state
WHERE tiger2019.state.division = '7'
AND tiger2019.census_name_lookup.sumlevel = '040'
AND tiger2019.census_name_lookup.geoid = tiger2019.state.geoid);
-- Division 8
INSERT INTO tiger2019.census_name_lookup
SELECT
Expand All @@ -575,7 +610,12 @@ INSERT INTO tiger2019.census_name_lookup
(SELECT b01003.b01003001 FROM acs2018_5yr.b01003 WHERE geoid = '03000US8'),
(SELECT SUM(aland) FROM tiger2019.state WHERE division='8'),
(SELECT SUM(awater) FROM tiger2019.state WHERE division='8'),
(SELECT ST_Multi(ST_Union(geom)) FROM tiger2019.census_name_lookup WHERE full_geoid IN ('04000US04', '04000US08', '04000US16', '04000US35', '04000US30', '04000US49', '04000US32', '04000US56'));
(SELECT ST_Multi(ST_Union(tiger2019.census_name_lookup.geom))
FROM tiger2019.census_name_lookup,
tiger2019.state
WHERE tiger2019.state.division = '8'
AND tiger2019.census_name_lookup.sumlevel = '040'
AND tiger2019.census_name_lookup.geoid = tiger2019.state.geoid);
-- Division 9
INSERT INTO tiger2019.census_name_lookup
SELECT
Expand All @@ -589,7 +629,12 @@ INSERT INTO tiger2019.census_name_lookup
(SELECT b01003.b01003001 FROM acs2018_5yr.b01003 WHERE geoid = '03000US9'),
(SELECT SUM(aland) FROM tiger2019.state WHERE division='9'),
(SELECT SUM(awater) FROM tiger2019.state WHERE division='9'),
(SELECT ST_Multi(ST_Union(geom)) FROM tiger2019.census_name_lookup WHERE full_geoid IN ('04000US02', '04000US06', '04000US15', '04000US41', '04000US53'));
(SELECT ST_Multi(ST_Union(tiger2019.census_name_lookup.geom))
FROM tiger2019.census_name_lookup,
tiger2019.state
WHERE tiger2019.state.division = '9'
AND tiger2019.census_name_lookup.sumlevel = '040'
AND tiger2019.census_name_lookup.geoid = tiger2019.state.geoid);

---- Regions
-- Region 1
Expand All @@ -605,7 +650,12 @@ INSERT INTO tiger2019.census_name_lookup
(SELECT b01003.b01003001 FROM acs2018_5yr.b01003 WHERE geoid = '02000US1'),
(SELECT SUM(aland) FROM tiger2019.state WHERE region='1'),
(SELECT SUM(awater) FROM tiger2019.state WHERE region='1'),
(SELECT ST_Multi(ST_Union(geom)) FROM tiger2019.census_name_lookup WHERE full_geoid IN ('03000US1', '03000US2'));
(SELECT ST_Multi(ST_Union(tiger2019.census_name_lookup.geom))
FROM tiger2019.census_name_lookup,
tiger2019.state
WHERE tiger2019.state.region = '1'
AND tiger2019.census_name_lookup.sumlevel = '040'
AND tiger2019.census_name_lookup.geoid = tiger2019.state.geoid);
-- Region 2
INSERT INTO tiger2019.census_name_lookup
SELECT
Expand All @@ -619,7 +669,12 @@ INSERT INTO tiger2019.census_name_lookup
(SELECT b01003.b01003001 FROM acs2018_5yr.b01003 WHERE geoid = '02000US2'),
(SELECT SUM(aland) FROM tiger2019.state WHERE region='2'),
(SELECT SUM(awater) FROM tiger2019.state WHERE region='2'),
(SELECT ST_Multi(ST_Union(geom)) FROM tiger2019.census_name_lookup WHERE full_geoid IN ('03000US3', '03000US4'));
(SELECT ST_Multi(ST_Union(tiger2019.census_name_lookup.geom))
FROM tiger2019.census_name_lookup,
tiger2019.state
WHERE tiger2019.state.region = '2'
AND tiger2019.census_name_lookup.sumlevel = '040'
AND tiger2019.census_name_lookup.geoid = tiger2019.state.geoid);
-- Region 3
INSERT INTO tiger2019.census_name_lookup
SELECT
Expand All @@ -633,7 +688,12 @@ INSERT INTO tiger2019.census_name_lookup
(SELECT b01003.b01003001 FROM acs2018_5yr.b01003 WHERE geoid = '02000US3'),
(SELECT SUM(aland) FROM tiger2019.state WHERE region='3'),
(SELECT SUM(awater) FROM tiger2019.state WHERE region='3'),
(SELECT ST_Multi(ST_Union(geom)) FROM tiger2019.census_name_lookup WHERE full_geoid IN ('03000US5', '03000US6', '03000US7'));
(SELECT ST_Multi(ST_Union(tiger2019.census_name_lookup.geom))
FROM tiger2019.census_name_lookup,
tiger2019.state
WHERE tiger2019.state.region = '3'
AND tiger2019.census_name_lookup.sumlevel = '040'
AND tiger2019.census_name_lookup.geoid = tiger2019.state.geoid);
-- Region 4
INSERT INTO tiger2019.census_name_lookup
SELECT
Expand All @@ -647,7 +707,12 @@ INSERT INTO tiger2019.census_name_lookup
(SELECT b01003.b01003001 FROM acs2018_5yr.b01003 WHERE geoid = '02000US4'),
(SELECT SUM(aland) FROM tiger2019.state WHERE region='4'),
(SELECT SUM(awater) FROM tiger2019.state WHERE region='4'),
(SELECT ST_Multi(ST_Union(geom)) FROM tiger2019.census_name_lookup WHERE full_geoid IN ('03000US8', '03000US9'));
(SELECT ST_Multi(ST_Union(tiger2019.census_name_lookup.geom))
FROM tiger2019.census_name_lookup,
tiger2019.state
WHERE tiger2019.state.region = '4'
AND tiger2019.census_name_lookup.sumlevel = '040'
AND tiger2019.census_name_lookup.geoid = tiger2019.state.geoid);

CREATE INDEX census_name_lookup_idx_lower ON tiger2019.census_name_lookup ((lower(prefix_match_name)) text_pattern_ops);
CREATE INDEX census_name_lookup_idx_geom ON tiger2019.census_name_lookup USING GIST(geom);
Expand Down

0 comments on commit ab1f66f

Please sign in to comment.