Skip to content

Instantly share code, notes, and snippets.

@ericbusboom
Last active August 29, 2015 13:56
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save ericbusboom/9101554 to your computer and use it in GitHub Desktop.
Save ericbusboom/9101554 to your computer and use it in GitHub Desktop.
HHSA / CHCF code-a-thon ambry manifest
This Ambry Manifest assembles a database of health datasets for the San Diego County HHSA / CHCF code-a-thon
NOTE! In version 0.0.2 of the ACS data, the "measure" and "error" files have the
names backwards.
ambry warehouse -d 'postgis://postgres:frangible234!@warehouse1/db1' install /Users/eric/proj/chcf_codeathon/manifest.txt
partitions:
census.gov-acs-geo-orig-geofile-20105-0.1.1
census.gov-acs-p5ye2012-b00001-errors-0.0.2 # Unweighted Sample Count
census.gov-acs-p5ye2012-b01003-errors-0.0.2 # Total Population
census.gov-acs-p5ye2012-b01001-errors-0.0.2 # Sex By Age
census.gov-acs-p5ye2012-b01002-errors-0.0.2
census.gov-acs-p5ye2012-b02001-errors-0.0.2 # Race
census.gov-acs-p5ye2012-b03003-errors-0.0.2 # Hispanic Origin
census.gov-acs-p5ye2012-b05002-errors-0.0.2 # PLACE OF BIRTH BY NATIVITY AND CITIZENSHIP STATUS
census.gov-acs-p5ye2012-b18107-errors-0.0.2
census.gov-acs-p5ye2012-b99021-errors-0.0.2
census.gov-acs-p5ye2012-b99187-errors-0.0.2
census.gov-acs-p5ye2012-b21001-errors-0.0.2 # Sex By Age By Veteran Status
census.gov-tigerline-2012-blockgroup-ca-geo-0.0.2
census.gov-tigerline-2012-tracts-ca-geo-0.0.2
clarinova.com-crosswalks-census-casnd-bgtosra-0.1.4
clarinova.com-crosswalks-census-casnd-srato3450-0.1.4
clarinova.com-crosswalks-census-casnd-tracttosra-0.1.4
sangis.org-jurisdiction-orig-sra-geo-0.0.2
sdcounty.ca.gov-deaths3450-casnd-deaths3450-0.0.1
sql:postgres|postgis
CREATE INDEX ON d00h001_geofile ((lower(stusab)));
CREATE INDEX ON d00h001_geofile (sumlevel);
CREATE INDEX ON d024002_b00001 ((logrecno::Int));
CREATE INDEX ON d024002_b01001 ((logrecno::Int));
CREATE INDEX ON d024002_b03003 ((logrecno::Int));
CREATE INDEX ON d024002_b02001 ((logrecno::Int));
DROP TABLE IF EXISTS sra_linked;
CREATE TABLE sra_linked WITH OIDS AS
SELECT sra.wkb_geometry, deaths.*
FROM d028002_sra AS sra
JOIN d029004_srato3450 AS crossw ON sra.sra = crossw.sra_id::Integer
JOIN d02a001_deaths3450 AS deaths ON deaths.area = crossw.sra_3450;
DROP TABLE IF EXISTS sra_tract CASCADE;
CREATE TABLE sra_tract WITH OIDS AS
SELECT
ogc_fid,
wkb_geometry,
geofile.name as tract_name,
lower(geofile.stusab) as stusab,
geofile.logrecno::Int,
crossw.*
FROM d00h001_geofile as geofile
JOIN d029004_tracttosra AS crossw ON crossw.slgeoid = geofile.geoid
JOIN d025002_tracts AS tracts ON tracts.geoid = crossw.geoid;
DROP TABLE IF EXISTS tract_pop;
CREATE TABLE tract_pop WITH OIDS AS
SELECT
d025002_tracts.ogc_fid,
d025002_tracts.wkb_geometry,
ST_Area(ST_Transform(d025002_tracts.wkb_geometry,2771))/(1000*1000) as area,
d00h001_geofile.county,
d00h001_geofile.state,
d00h001_geofile.tract,
d00h001_geofile.logrecno,
d00h001_geofile.geoid,
d024002_b00001.c1 AS samp,
d024002_b01003.c1 AS pop_1003, -- Looks like it should be total pop, but isnt
d024002_b03003.c1 AS total_pop,
d024002_b03003.c3 AS hispanic,
d024002_b02001.c2 AS white,
d024002_b02001.c3 AS black,
d024002_b02001.c4 AS indian,
d024002_b02001.c5 AS asian,
d024002_b21001.c7 AS veteran
FROM d00h001_geofile
JOIN d025002_tracts ON d00h001_geofile.geoid = '14000US'||d025002_tracts.geoid
JOIN d024002_b00001 ON d024002_b00001.logrecno::Int = d00h001_geofile.logrecno::Int AND d024002_b00001.stusab = lower(d00h001_geofile.stusab)
JOIN d024002_b01001 ON d024002_b01001.logrecno::Int = d00h001_geofile.logrecno::Int AND d024002_b01001.stusab = lower(d00h001_geofile.stusab)
JOIN d024002_b03003 ON d024002_b03003.logrecno::Int = d00h001_geofile.logrecno::Int AND d024002_b03003.stusab = lower(d00h001_geofile.stusab)
JOIN d024002_b01003 ON d024002_b01003.logrecno::Int = d00h001_geofile.logrecno::Int AND d024002_b01003.stusab = lower(d00h001_geofile.stusab)
JOIN d024002_b02001 ON d024002_b02001.logrecno::Int = d00h001_geofile.logrecno::Int AND d024002_b02001.stusab = lower(d00h001_geofile.stusab)
JOIN d024002_b21001 ON d024002_b21001.logrecno::Int = d00h001_geofile.logrecno::Int AND d024002_b21001.stusab = lower(d00h001_geofile.stusab)
WHERE
d00h001_geofile.state = 6 AND d00h001_geofile.county = 73 AND d00h001_geofile.sumlevel = 140
AND d025002_tracts.arealand > 0
AND d024002_b03003.c1 > 0;
DROP VIEW IF EXISTS sra_demographics;
CREATE VIEW sra_demographics AS
SELECT
sra_id,
sum(total_pop)::Real AS total_pop,
sum(area)::Real AS area,
sum(hispanic)::Real AS hispanic,
sum(white)::Real AS white,
sum(black)::Real AS black,
sum(asian)::Real AS asian,
sum(veteran)::Real AS veteran
FROM tract_pop
JOIN sra_tract on sra_tract.slgeoid = tract_pop.geoid
GROUP BY sra_id;
DROP VIEW IF EXISTS sra_demographics_density;
CREATE VIEW sra_demographics_density AS
SELECT
sra_demographics.*,
(total_pop/area) AS pop_density,
(hispanic/total_pop) AS hisp_pct,
(hispanic/area) AS hisp_density,
(white/total_pop) AS white_pct,
(white/area) AS white_density,
(black/total_pop) AS black_pct,
(black/area) AS black_density,
(asian/total_pop) AS asian_pct,
(asian/area) AS asian_density,
(veteran/total_pop) AS veteran_pct,
(veteran/area) AS veteran_density
FROM sra_demographics;
DROP TABLE IF EXISTS sra_deaths_demo;
CREATE TABLE sra_deaths_demo WITH OIDS AS
SELECT
geo.ogc_fid,
geo.wkb_geometry,
deaths.area as "name",
deaths.year,
deaths.all,
deaths.asthma,
deaths.cancer,
deaths.chd,
deaths.copd,
deaths.deaths3450,
deaths.diabetes,
deaths.pct3450,
deaths.rate3450,
deaths.stroke,
deaths.deaths3450/deaths.rate3450*100000 as est_pop,
demo.*
FROM d029004_srato3450 AS crossw
JOIN sra_demographics AS demo ON demo.sra_id = crossw.sra_id::Int
JOIN "d02a001_deaths3450" AS deaths ON deaths.area = crossw.sra_3450
JOIN d028002_sra AS geo ON geo.sra::Int = crossw.sra_id::Int
ORDER BY name, year
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment