-- Mart: Neighbourhood Overview with Composite Livability Score -- Dashboard Tab: Overview -- Grain: One row per neighbourhood per year with demographics as ( select * from {{ ref('int_neighbourhood__demographics') }} ), housing as ( select * from {{ ref('int_neighbourhood__housing') }} ), crime as ( select * from {{ ref('int_neighbourhood__crime_summary') }} ), amenities as ( select * from {{ ref('int_neighbourhood__amenity_scores') }} ), -- Compute percentile ranks for scoring components percentiles as ( select d.neighbourhood_id, d.neighbourhood_name, d.geometry, d.census_year as year, d.population, d.median_household_income, -- Safety score: inverse of crime rate (higher = safer) case when c.crime_rate_per_100k is not null then 100 - percent_rank() over ( partition by d.census_year order by c.crime_rate_per_100k ) * 100 else null end as safety_score, -- Affordability score: inverse of rent-to-income ratio case when h.rent_to_income_pct is not null then 100 - percent_rank() over ( partition by d.census_year order by h.rent_to_income_pct ) * 100 else null end as affordability_score, -- Amenity score: based on amenities per capita case when a.total_amenities_per_1000 is not null then percent_rank() over ( partition by d.census_year order by a.total_amenities_per_1000 ) * 100 else null end as amenity_score, -- Raw metrics for reference c.crime_rate_per_100k, h.rent_to_income_pct, h.avg_rent_2bed, a.total_amenities_per_1000 from demographics d left join housing h on d.neighbourhood_id = h.neighbourhood_id and d.census_year = h.year left join crime c on d.neighbourhood_id = c.neighbourhood_id and d.census_year = c.year left join amenities a on d.neighbourhood_id = a.neighbourhood_id and d.census_year = a.year ), final as ( select neighbourhood_id, neighbourhood_name, geometry, year, population, median_household_income, -- Component scores (0-100) round(safety_score::numeric, 1) as safety_score, round(affordability_score::numeric, 1) as affordability_score, round(amenity_score::numeric, 1) as amenity_score, -- Composite livability score: safety (30%), affordability (40%), amenities (30%) round( (coalesce(safety_score, 50) * 0.30 + coalesce(affordability_score, 50) * 0.40 + coalesce(amenity_score, 50) * 0.30)::numeric, 1 ) as livability_score, -- Raw metrics crime_rate_per_100k, rent_to_income_pct, avg_rent_2bed, total_amenities_per_1000 from percentiles ) select * from final