Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

use total population in CDBG #1359

Merged
merged 4 commits into from
Jan 3, 2025
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
1 change: 1 addition & 0 deletions products/cdbg/models/_sources.yml
Original file line number Diff line number Diff line change
Expand Up @@ -14,4 +14,5 @@ sources:
- not_null
- name: dcp_cb2020_wi
- name: dcp_ct2020_wi
- name: dcp_censusdata_blocks
- name: hud_lowmodincomebyblockgroup
17 changes: 17 additions & 0 deletions products/cdbg/models/intermediate/_intermediate_models.yml
Original file line number Diff line number Diff line change
Expand Up @@ -13,14 +13,31 @@ models:
- name: residential_floor_area
- name: residential_floor_area_percentage
- name: total_population
- name: potential_lowmod_population
- name: lowmod_population
- name: lowmod_population_percentage
- name: low_mod_income_population_percentage_source

- name: int__block_groups_raw
description: census block group geoemtries and demographic data
columns:
- name: geoid
tests:
- not_null
- unique
- name: total_population
tests: [not_null]

- name: int__lot_block_groups_details
description: int__lot_block_groups joined to pluto for lot info
columns:
- name: bbl
- name: block_group_geoid
tests:
- not_null
- relationships:
to: ref('int__block_groups_raw')
field: geoid
- name: overlap_ratio
- name: bldgarea
- name: bldgarea_in_block_group
Expand Down
51 changes: 39 additions & 12 deletions products/cdbg/models/intermediate/int__block_groups.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,10 +2,30 @@ WITH lot_block_groups AS (
SELECT * FROM {{ ref("int__lot_block_groups_details") }}
),

block_groups_population AS (
SELECT * FROM {{ ref("int__block_groups_raw") }}
),

block_groups_income AS (
SELECT * FROM {{ ref("stg__low_mod_by_block_group") }}
),

block_groups_demographics AS (
SELECT
block_groups_population.geoid,
block_groups_population.borough_code,
block_groups_population.borough_name,
block_groups_population.total_population,
block_groups_income.tract,
block_groups_income.block_group,
block_groups_income.potential_lowmod_population,
block_groups_income.low_mod_income_population,
block_groups_income.low_mod_income_population_percentage
FROM block_groups_population
LEFT JOIN block_groups_income
ON block_groups_population.geoid = block_groups_income.geoid
),

block_groups_floor_area AS (
SELECT
block_group_geoid AS geoid,
Expand All @@ -18,22 +38,29 @@ block_groups_floor_area AS (
block_group_details AS (
SELECT
block_groups_floor_area.geoid,
block_groups_income.boro AS borough_name,
block_groups_income.tract,
block_groups_income.block_group,
total_floor_area,
residential_floor_area,
block_groups_demographics.borough_name,
block_groups_demographics.tract,
block_groups_demographics.block_group,
block_groups_floor_area.total_floor_area,
block_groups_floor_area.residential_floor_area,
CASE
WHEN total_floor_area = 0
WHEN block_groups_floor_area.total_floor_area = 0
THEN 0
ELSE (residential_floor_area / total_floor_area) * 100
ELSE (block_groups_floor_area.residential_floor_area / block_groups_floor_area.total_floor_area) * 100
END AS residential_floor_area_percentage,
block_groups_income.total_population,
block_groups_income.lowmod_population AS low_mod_income_population,
block_groups_income.lowmod_pct AS low_mod_income_population_percentage
block_groups_demographics.total_population,
block_groups_demographics.potential_lowmod_population,
block_groups_demographics.low_mod_income_population,
CASE
WHEN block_groups_demographics.total_population = 0
THEN 0
ELSE
(block_groups_demographics.low_mod_income_population / block_groups_demographics.total_population) * 100
END AS low_mod_income_population_percentage,
block_groups_demographics.low_mod_income_population_percentage AS low_mod_income_population_percentage_source
FROM block_groups_floor_area
LEFT JOIN block_groups_income
ON block_groups_floor_area.geoid = block_groups_income.geoid
LEFT JOIN block_groups_demographics
ON block_groups_floor_area.geoid = block_groups_demographics.geoid
)

SELECT * FROM block_group_details
42 changes: 42 additions & 0 deletions products/cdbg/models/intermediate/int__block_groups_raw.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,42 @@
{{ config(
materialized = 'table',
indexes=[
{'columns': ['geom'], 'type': 'gist'},
{'columns': ['geoid']},
]
) }}

WITH census_blocks AS (
SELECT * FROM {{ ref("stg__census_blocks") }}
),

census_data_blocks AS (
SELECT * FROM {{ ref("stg__census_data_blocks") }}
),

blocks AS (
SELECT
census_blocks.block_group_geoid,
census_data_blocks.borough_code,
census_data_blocks.borough_name,
census_blocks.ct2020,
census_data_blocks.total_population,
census_blocks.wkb_geometry
FROM census_blocks
LEFT JOIN census_data_blocks
ON census_blocks.bctcb2020 = census_data_blocks.bctcb2020
)

SELECT
block_group_geoid AS geoid,
borough_code,
borough_name,
ct2020,
sum(total_population) AS total_population,
st_union(wkb_geometry) AS geom
FROM blocks
GROUP BY
block_group_geoid,
borough_code,
borough_name,
ct2020
Original file line number Diff line number Diff line change
Expand Up @@ -9,7 +9,7 @@ block_groups AS (
SELECT
geoid,
geom
FROM {{ ref("stg__census_block_groups") }}
FROM {{ ref("int__block_groups_raw") }}
),

lot_block_group_intersections AS (
Expand Down
20 changes: 19 additions & 1 deletion products/cdbg/models/staging/_staging_models.yml
Original file line number Diff line number Diff line change
@@ -1,5 +1,23 @@
version: 2

models:
- name: stg__census_block_groups
- name: stg__census_blocks
columns:
- name: geoid
tests:
- not_null
- unique

- name: stg__census_data_blocks
columns:
- name: bctcb2020
tests:
- not_null
- unique

- name: stg__low_mod_by_block_group
columns:
- name: geoid
tests:
- not_null
- unique
26 changes: 0 additions & 26 deletions products/cdbg/models/staging/stg__census_block_groups.sql

This file was deleted.

11 changes: 11 additions & 0 deletions products/cdbg/models/staging/stg__census_blocks.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
{{ config(
materialized = 'table',
indexes=[
{'columns': ['wkb_geometry'], 'type': 'gist'},
{'columns': ['geoid']},
]
) }}
SELECT
left(geoid, 12) AS block_group_geoid,
*
FROM {{ source("recipe_sources", "dcp_cb2020_wi") }}
7 changes: 7 additions & 0 deletions products/cdbg/models/staging/stg__census_data_blocks.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
SELECT
geoid20 AS bctcb2020,
borocode AS borough_code,
geogname AS borough_name,
"pop1.1"::numeric AS total_population -- noqa: RF01
FROM {{ source("recipe_sources", "dcp_censusdata_blocks") }}
WHERE geogtype = 'CB2020'
6 changes: 3 additions & 3 deletions products/cdbg/models/staging/stg__low_mod_by_block_group.sql
Original file line number Diff line number Diff line change
Expand Up @@ -8,7 +8,7 @@ SELECT
"BORO" AS boro,
"TRACT" AS tract,
"BLKGRP" AS block_group,
REPLACE("LOWMODUNIV", ',', '')::numeric AS total_population,
REPLACE("LOWMOD", ',', '')::numeric AS lowmod_population,
RTRIM("LOWMOD_PCT", '%')::numeric AS lowmod_pct
REPLACE("LOWMODUNIV", ',', '')::numeric AS potential_lowmod_population,
REPLACE("LOWMOD", ',', '')::numeric AS low_mod_income_population,
RTRIM("LOWMOD_PCT", '%')::numeric AS low_mod_income_population_percentage
FROM {{ source("recipe_sources", "hud_lowmodincomebyblockgroup") }}
2 changes: 2 additions & 0 deletions products/cdbg/recipe.yml
Original file line number Diff line number Diff line change
Expand Up @@ -6,4 +6,6 @@ inputs:
- name: dcp_mappluto_clipped
- name: dcp_cb2020_wi # maybe not needed. including for now in case it's helpful for block groups
- name: dcp_ct2020_wi
- name: dcp_censusdata_blocks
version: "2020"
- name: hud_lowmodincomebyblockgroup