Skip to content

Commit

Permalink
Add Chicago cbd boundary to default.vw_pin_universe (#372)
Browse files Browse the repository at this point in the history
* Initial test

* replace file year

* Add cleaning function

* Invoke cbd function in clean_economy function

* Initial work on cta

* Changes to cta

* Add cbd num

* Add vw_pin_universe

* Switch ctas to num

* Add to location view

* Add to location fill

* Add cbd to dbt docs

* Remove Chicago

* Move to econ

* Add join

* Change to data_year

* Add to crosswalk year fill

* Add join

* lintr

* lint

* lintr

---------

Co-authored-by: Sweaty Handshake <william.ridgeway@cookcountyil.gov>
  • Loading branch information
Damonamajor and wrridgeway authored Apr 11, 2024
1 parent 739a4ba commit 14095e2
Show file tree
Hide file tree
Showing 9 changed files with 348 additions and 226 deletions.
12 changes: 11 additions & 1 deletion aws-athena/ctas/location-crosswalk_year_fill.sql
Original file line number Diff line number Diff line change
Expand Up @@ -40,6 +40,8 @@ WITH unfilled AS (
AS econ_industrial_growth_zone_data_year,
MAX(economy.econ_qualified_opportunity_zone_data_year)
AS econ_qualified_opportunity_zone_data_year,
MAX(economy.econ_central_business_district_data_year)
AS econ_central_business_district_data_year,
MAX(environment.env_flood_fema_data_year)
AS env_flood_fema_data_year,
MAX(environment.env_flood_fs_data_year)
Expand Down Expand Up @@ -97,9 +99,11 @@ WITH unfilled AS (
econ_coordinated_care_area_data_year,
econ_enterprise_zone_data_year,
econ_industrial_growth_zone_data_year,
econ_qualified_opportunity_zone_data_year
econ_qualified_opportunity_zone_data_year,
econ_central_business_district_data_year
FROM {{ ref('location.economy') }}
) AS economy ON pin.year = economy.year

LEFT JOIN (
SELECT DISTINCT
year,
Expand Down Expand Up @@ -218,6 +222,12 @@ SELECT
IGNORE NULLS
OVER (ORDER BY unfilled.year DESC)
) AS econ_qualified_opportunity_zone_data_year,
COALESCE(
econ_central_business_district_data_year,
LAST_VALUE(econ_central_business_district_data_year)
IGNORE NULLS
OVER (ORDER BY unfilled.year DESC)
) AS econ_central_business_district_data_year,
COALESCE(
env_flood_fema_data_year, LAST_VALUE(env_flood_fema_data_year)
IGNORE NULLS
Expand Down
42 changes: 42 additions & 0 deletions aws-athena/ctas/location-economy.sql
Original file line number Diff line number Diff line change
Expand Up @@ -29,6 +29,9 @@ distinct_years_rhs AS (
UNION ALL
SELECT DISTINCT year
FROM {{ source('spatial', 'qualified_opportunity_zone') }}
UNION ALL
SELECT DISTINCT year
FROM {{ source('spatial', 'central_business_district') }}
),

coordinated_care AS (
Expand Down Expand Up @@ -156,6 +159,39 @@ qualified_opportunity_zone AS (
ST_GEOMFROMBINARY(cprod.geometry_3435)
)
GROUP BY dp.x_3435, dp.y_3435, cprod.pin_year
),

central_business_district AS (
SELECT
dp.x_3435,
dp.y_3435,
MAX(cprod.cbd_num) AS econ_central_business_district_num,
MAX(cprod.year) AS econ_central_business_district_data_year,
cprod.pin_year
FROM distinct_pins AS dp
LEFT JOIN (
SELECT
fill_years.pin_year,
fill_data.*
FROM (
SELECT
dy.year AS pin_year,
MAX(df.year) AS fill_year
FROM {{ source('spatial', 'central_business_district') }} AS df
CROSS JOIN distinct_years AS dy
WHERE dy.year >= df.year
GROUP BY dy.year
) AS fill_years
LEFT JOIN
{{ source('spatial', 'central_business_district') }}
AS fill_data
ON fill_years.fill_year = fill_data.year
) AS cprod
ON ST_WITHIN(
ST_POINT(dp.x_3435, dp.y_3435),
ST_GEOMFROMBINARY(cprod.geometry_3435)
)
GROUP BY dp.x_3435, dp.y_3435, cprod.pin_year
)

SELECT
Expand All @@ -168,6 +204,8 @@ SELECT
igz.econ_industrial_growth_zone_data_year,
qoz.econ_qualified_opportunity_zone_num,
qoz.econ_qualified_opportunity_zone_data_year,
cbd.econ_central_business_district_num,
cbd.econ_central_business_district_data_year,
pcl.year
FROM {{ source('spatial', 'parcel') }} AS pcl
LEFT JOIN coordinated_care AS cc
Expand All @@ -186,4 +224,8 @@ LEFT JOIN qualified_opportunity_zone AS qoz
ON pcl.x_3435 = qoz.x_3435
AND pcl.y_3435 = qoz.y_3435
AND pcl.year = qoz.pin_year
LEFT JOIN central_business_district AS cbd
ON pcl.x_3435 = cbd.x_3435
AND pcl.y_3435 = cbd.y_3435
AND pcl.year = cbd.pin_year
WHERE pcl.year >= (SELECT MIN(year) FROM distinct_years_rhs)
294 changes: 148 additions & 146 deletions aws-athena/views/default-vw_pin_universe.sql
Original file line number Diff line number Diff line change
@@ -1,146 +1,148 @@
-- Source of truth view for PIN location
SELECT
-- Main PIN-level attribute data from iasWorld
par.parid AS pin,
SUBSTR(par.parid, 1, 10) AS pin10,
par.taxyr AS year,
REGEXP_REPLACE(par.class, '([^0-9EXR])', '') AS class,
twn.triad_name,
twn.triad_code,
twn.township_name,
leg.user1 AS township_code,
REGEXP_REPLACE(par.nbhd, '([^0-9])', '') AS nbhd_code,
leg.taxdist AS tax_code,
NULLIF(leg.zip1, '00000') AS zip_code,

-- Centroid of each PIN from county parcel files
sp.lon,
sp.lat,
sp.x_3435,
sp.y_3435,

-- Corner lot indicator
lot.is_corner_lot AS ccao_is_corner_lot,

-- PIN locations from spatial joins
vwl.census_block_group_geoid,
vwl.census_block_geoid,
vwl.census_congressional_district_geoid,
vwl.census_county_subdivision_geoid,
vwl.census_place_geoid,
vwl.census_puma_geoid,
vwl.census_school_district_elementary_geoid,
vwl.census_school_district_secondary_geoid,
vwl.census_school_district_unified_geoid,
vwl.census_state_representative_geoid,
vwl.census_state_senate_geoid,
vwl.census_tract_geoid,
vwl.census_zcta_geoid,
vwl.census_data_year,
vwl.census_acs5_congressional_district_geoid,
vwl.census_acs5_county_subdivision_geoid,
vwl.census_acs5_place_geoid,
vwl.census_acs5_puma_geoid,
vwl.census_acs5_school_district_elementary_geoid,
vwl.census_acs5_school_district_secondary_geoid,
vwl.census_acs5_school_district_unified_geoid,
vwl.census_acs5_state_representative_geoid,
vwl.census_acs5_state_senate_geoid,
vwl.census_acs5_tract_geoid,
vwl.census_acs5_data_year,
vwl.cook_board_of_review_district_num,
vwl.cook_board_of_review_district_data_year,
vwl.cook_commissioner_district_num,
vwl.cook_commissioner_district_data_year,
vwl.cook_judicial_district_num,
vwl.cook_judicial_district_data_year,
vwl.ward_num,
vwl.ward_name,
vwl.ward_chicago_data_year,
vwl.ward_evanston_data_year,
vwl.chicago_community_area_num,
vwl.chicago_community_area_name,
vwl.chicago_community_area_data_year,
vwl.chicago_industrial_corridor_num,
vwl.chicago_industrial_corridor_name,
vwl.chicago_industrial_corridor_data_year,
vwl.chicago_police_district_num,
vwl.chicago_police_district_data_year,
vwl.econ_coordinated_care_area_num,
vwl.econ_coordinated_care_area_data_year,
vwl.econ_enterprise_zone_num,
vwl.econ_enterprise_zone_data_year,
vwl.econ_industrial_growth_zone_num,
vwl.econ_industrial_growth_zone_data_year,
vwl.econ_qualified_opportunity_zone_num,
vwl.econ_qualified_opportunity_zone_data_year,
vwl.env_flood_fema_sfha,
vwl.env_flood_fema_data_year,
vwl.env_flood_fs_factor,
vwl.env_flood_fs_risk_direction,
vwl.env_flood_fs_data_year,
vwl.env_ohare_noise_contour_no_buffer_bool,
vwl.env_ohare_noise_contour_half_mile_buffer_bool,
vwl.env_ohare_noise_contour_data_year,
vwl.env_airport_noise_dnl,
vwl.env_airport_noise_data_year,
vwl.school_elementary_district_geoid,
vwl.school_elementary_district_name,
vwl.school_secondary_district_geoid,
vwl.school_secondary_district_name,
vwl.school_unified_district_geoid,
vwl.school_unified_district_name,
vwl.school_school_year,
vwl.school_data_year,
vwl.tax_municipality_num,
vwl.tax_municipality_name,
vwl.tax_school_elementary_district_num,
vwl.tax_school_elementary_district_name,
vwl.tax_school_secondary_district_num,
vwl.tax_school_secondary_district_name,
vwl.tax_school_unified_district_num,
vwl.tax_school_unified_district_name,
vwl.tax_community_college_district_num,
vwl.tax_community_college_district_name,
vwl.tax_fire_protection_district_num,
vwl.tax_fire_protection_district_name,
vwl.tax_library_district_num,
vwl.tax_library_district_name,
vwl.tax_park_district_num,
vwl.tax_park_district_name,
vwl.tax_sanitation_district_num,
vwl.tax_sanitation_district_name,
vwl.tax_special_service_area_num,
vwl.tax_special_service_area_name,
vwl.tax_tif_district_num,
vwl.tax_tif_district_name,
vwl.tax_data_year,
vwl.access_cmap_walk_id,
vwl.access_cmap_walk_nta_score,
vwl.access_cmap_walk_total_score,
vwl.access_cmap_walk_data_year,
vwl.misc_subdivision_id,
vwl.misc_subdivision_data_year
FROM {{ source('iasworld', 'pardat') }} AS par
LEFT JOIN {{ source('iasworld', 'legdat') }} AS leg
ON par.parid = leg.parid
AND par.taxyr = leg.taxyr
AND leg.cur = 'Y'
AND leg.deactivat IS NULL
LEFT JOIN {{ source('spatial', 'parcel') }} AS sp
ON SUBSTR(par.parid, 1, 10) = sp.pin10
AND par.taxyr = sp.year
LEFT JOIN {{ ref('location.vw_pin10_location') }} AS vwl
ON SUBSTR(par.parid, 1, 10) = vwl.pin10
AND par.taxyr = vwl.year
LEFT JOIN {{ source('spatial', 'township') }} AS twn
ON leg.user1 = CAST(twn.township_code AS VARCHAR)
LEFT JOIN {{ source('ccao', 'corner_lot') }} AS lot
ON SUBSTR(par.parid, 1, 10) = lot.pin10

WHERE par.cur = 'Y'
AND par.deactivat IS NULL
-- Remove any parcels with non-numeric characters
-- or that are not 14 characters long
AND REGEXP_COUNT(par.parid, '[a-zA-Z]') = 0
AND LENGTH(par.parid) = 14
-- Source of truth view for PIN location
SELECT
-- Main PIN-level attribute data from iasWorld
par.parid AS pin,
SUBSTR(par.parid, 1, 10) AS pin10,
par.taxyr AS year,
REGEXP_REPLACE(par.class, '([^0-9EXR])', '') AS class,
twn.triad_name,
twn.triad_code,
twn.township_name,
leg.user1 AS township_code,
REGEXP_REPLACE(par.nbhd, '([^0-9])', '') AS nbhd_code,
leg.taxdist AS tax_code,
NULLIF(leg.zip1, '00000') AS zip_code,

-- Centroid of each PIN from county parcel files
sp.lon,
sp.lat,
sp.x_3435,
sp.y_3435,

-- Corner lot indicator
lot.is_corner_lot AS ccao_is_corner_lot,

-- PIN locations from spatial joins
vwl.census_block_group_geoid,
vwl.census_block_geoid,
vwl.census_congressional_district_geoid,
vwl.census_county_subdivision_geoid,
vwl.census_place_geoid,
vwl.census_puma_geoid,
vwl.census_school_district_elementary_geoid,
vwl.census_school_district_secondary_geoid,
vwl.census_school_district_unified_geoid,
vwl.census_state_representative_geoid,
vwl.census_state_senate_geoid,
vwl.census_tract_geoid,
vwl.census_zcta_geoid,
vwl.census_data_year,
vwl.census_acs5_congressional_district_geoid,
vwl.census_acs5_county_subdivision_geoid,
vwl.census_acs5_place_geoid,
vwl.census_acs5_puma_geoid,
vwl.census_acs5_school_district_elementary_geoid,
vwl.census_acs5_school_district_secondary_geoid,
vwl.census_acs5_school_district_unified_geoid,
vwl.census_acs5_state_representative_geoid,
vwl.census_acs5_state_senate_geoid,
vwl.census_acs5_tract_geoid,
vwl.census_acs5_data_year,
vwl.cook_board_of_review_district_num,
vwl.cook_board_of_review_district_data_year,
vwl.cook_commissioner_district_num,
vwl.cook_commissioner_district_data_year,
vwl.cook_judicial_district_num,
vwl.cook_judicial_district_data_year,
vwl.ward_num,
vwl.ward_name,
vwl.ward_chicago_data_year,
vwl.ward_evanston_data_year,
vwl.chicago_community_area_num,
vwl.chicago_community_area_name,
vwl.chicago_community_area_data_year,
vwl.chicago_industrial_corridor_num,
vwl.chicago_industrial_corridor_name,
vwl.chicago_industrial_corridor_data_year,
vwl.chicago_police_district_num,
vwl.chicago_police_district_data_year,
vwl.econ_coordinated_care_area_num,
vwl.econ_coordinated_care_area_data_year,
vwl.econ_enterprise_zone_num,
vwl.econ_enterprise_zone_data_year,
vwl.econ_industrial_growth_zone_num,
vwl.econ_industrial_growth_zone_data_year,
vwl.econ_qualified_opportunity_zone_num,
vwl.econ_qualified_opportunity_zone_data_year,
vwl.econ_central_business_district_num,
vwl.econ_central_business_district_data_year,
vwl.env_flood_fema_sfha,
vwl.env_flood_fema_data_year,
vwl.env_flood_fs_factor,
vwl.env_flood_fs_risk_direction,
vwl.env_flood_fs_data_year,
vwl.env_ohare_noise_contour_no_buffer_bool,
vwl.env_ohare_noise_contour_half_mile_buffer_bool,
vwl.env_ohare_noise_contour_data_year,
vwl.env_airport_noise_dnl,
vwl.env_airport_noise_data_year,
vwl.school_elementary_district_geoid,
vwl.school_elementary_district_name,
vwl.school_secondary_district_geoid,
vwl.school_secondary_district_name,
vwl.school_unified_district_geoid,
vwl.school_unified_district_name,
vwl.school_school_year,
vwl.school_data_year,
vwl.tax_municipality_num,
vwl.tax_municipality_name,
vwl.tax_school_elementary_district_num,
vwl.tax_school_elementary_district_name,
vwl.tax_school_secondary_district_num,
vwl.tax_school_secondary_district_name,
vwl.tax_school_unified_district_num,
vwl.tax_school_unified_district_name,
vwl.tax_community_college_district_num,
vwl.tax_community_college_district_name,
vwl.tax_fire_protection_district_num,
vwl.tax_fire_protection_district_name,
vwl.tax_library_district_num,
vwl.tax_library_district_name,
vwl.tax_park_district_num,
vwl.tax_park_district_name,
vwl.tax_sanitation_district_num,
vwl.tax_sanitation_district_name,
vwl.tax_special_service_area_num,
vwl.tax_special_service_area_name,
vwl.tax_tif_district_num,
vwl.tax_tif_district_name,
vwl.tax_data_year,
vwl.access_cmap_walk_id,
vwl.access_cmap_walk_nta_score,
vwl.access_cmap_walk_total_score,
vwl.access_cmap_walk_data_year,
vwl.misc_subdivision_id,
vwl.misc_subdivision_data_year
FROM {{ source('iasworld', 'pardat') }} AS par
LEFT JOIN {{ source('iasworld', 'legdat') }} AS leg
ON par.parid = leg.parid
AND par.taxyr = leg.taxyr
AND leg.cur = 'Y'
AND leg.deactivat IS NULL
LEFT JOIN {{ source('spatial', 'parcel') }} AS sp
ON SUBSTR(par.parid, 1, 10) = sp.pin10
AND par.taxyr = sp.year
LEFT JOIN {{ ref('location.vw_pin10_location') }} AS vwl
ON SUBSTR(par.parid, 1, 10) = vwl.pin10
AND par.taxyr = vwl.year
LEFT JOIN {{ source('spatial', 'township') }} AS twn
ON leg.user1 = CAST(twn.township_code AS VARCHAR)
LEFT JOIN {{ source('ccao', 'corner_lot') }} AS lot
ON SUBSTR(par.parid, 1, 10) = lot.pin10

WHERE par.cur = 'Y'
AND par.deactivat IS NULL
-- Remove any parcels with non-numeric characters
-- or that are not 14 characters long
AND REGEXP_COUNT(par.parid, '[a-zA-Z]') = 0
AND LENGTH(par.parid) = 14
Loading

0 comments on commit 14095e2

Please sign in to comment.