Create neighbourhood-centric dbt transformation layer: Staging (5 models): - stg_toronto__neighbourhoods - Neighbourhood dimension - stg_toronto__census - Census demographics - stg_toronto__crime - Crime statistics - stg_toronto__amenities - Amenity counts - stg_cmhc__zone_crosswalk - Zone-to-neighbourhood weights Intermediate (5 models): - int_neighbourhood__demographics - Combined census with quintiles - int_neighbourhood__housing - Housing + affordability indicators - int_neighbourhood__crime_summary - Aggregated crime with YoY - int_neighbourhood__amenity_scores - Per-capita amenity metrics - int_rentals__neighbourhood_allocated - CMHC via area weights Marts (5 models): - mart_neighbourhood_overview - Composite livability score - mart_neighbourhood_housing - Affordability index - mart_neighbourhood_safety - Crime rates per 100K - mart_neighbourhood_demographics - Income/age indices - mart_neighbourhood_amenities - Amenity index Closes #60, #61, #62, #63 Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
82 lines
2.2 KiB
SQL
82 lines
2.2 KiB
SQL
-- Mart: Neighbourhood Demographics Analysis
|
|
-- Dashboard Tab: Demographics
|
|
-- Grain: One row per neighbourhood per census year
|
|
|
|
with demographics as (
|
|
select * from {{ ref('int_neighbourhood__demographics') }}
|
|
),
|
|
|
|
-- City-wide averages for comparison
|
|
city_avg as (
|
|
select
|
|
census_year,
|
|
avg(median_household_income) as city_avg_income,
|
|
avg(median_age) as city_avg_age,
|
|
avg(unemployment_rate) as city_avg_unemployment,
|
|
avg(education_bachelors_pct) as city_avg_education,
|
|
avg(population_density) as city_avg_density
|
|
from demographics
|
|
group by census_year
|
|
),
|
|
|
|
final as (
|
|
select
|
|
d.neighbourhood_id,
|
|
d.neighbourhood_name,
|
|
d.geometry,
|
|
d.census_year as year,
|
|
|
|
-- Population
|
|
d.population,
|
|
d.land_area_sqkm,
|
|
d.population_density,
|
|
|
|
-- Income
|
|
d.median_household_income,
|
|
d.average_household_income,
|
|
d.income_quintile,
|
|
|
|
-- Income index (100 = city average)
|
|
case
|
|
when ca.city_avg_income > 0
|
|
then round(d.median_household_income / ca.city_avg_income * 100, 1)
|
|
else null
|
|
end as income_index,
|
|
|
|
-- Demographics
|
|
d.median_age,
|
|
d.unemployment_rate,
|
|
d.education_bachelors_pct,
|
|
|
|
-- Age index (100 = city average)
|
|
case
|
|
when ca.city_avg_age > 0
|
|
then round(d.median_age / ca.city_avg_age * 100, 1)
|
|
else null
|
|
end as age_index,
|
|
|
|
-- Housing tenure
|
|
d.pct_owner_occupied,
|
|
d.pct_renter_occupied,
|
|
d.average_dwelling_value,
|
|
|
|
-- Diversity index (using tenure mix as proxy - higher rental = more diverse typically)
|
|
round(
|
|
1 - (
|
|
power(d.pct_owner_occupied / 100, 2) +
|
|
power(d.pct_renter_occupied / 100, 2)
|
|
),
|
|
3
|
|
) * 100 as tenure_diversity_index,
|
|
|
|
-- City comparisons
|
|
round(ca.city_avg_income::numeric, 2) as city_avg_income,
|
|
round(ca.city_avg_age::numeric, 1) as city_avg_age,
|
|
round(ca.city_avg_unemployment::numeric, 2) as city_avg_unemployment
|
|
|
|
from demographics d
|
|
left join city_avg ca on d.census_year = ca.census_year
|
|
)
|
|
|
|
select * from final
|