feat(data): Phase 2b complete — EU NUTS-2 spatial join + US state income
- stg_regional_income: expanded NUTS-1+2 (LENGTH IN 3,4), nuts_code rename, nuts_level - stg_nuts2_boundaries: new — ST_Read GISCO GeoJSON, bbox columns for spatial pre-filter - stg_income_usa: new — Census ACS state-level income staging model - dim_locations: spatial join replaces admin1_to_nuts1 VALUES CTE; us_income CTE with PPS normalisation (income/80610×30000); income cascade: NUTS-2→NUTS-1→US state→country - init_landing_seeds: compress=False for ST_Read files; gisco GeoJSON + census income seeds - CHANGELOG + PROJECT.md updated Co-Authored-By: Claude Sonnet 4.6 <noreply@anthropic.com>
This commit is contained in:
@@ -6,14 +6,17 @@
|
||||
-- covers all locations with population ≥ 1K so zero-court Gemeinden score fully.
|
||||
--
|
||||
-- Enriched with:
|
||||
-- stg_income → country-level median income PPS (fallback)
|
||||
-- stg_regional_income → NUTS-1 regional income PPS (preferred where mapped)
|
||||
-- stg_nuts2_boundaries + stg_regional_income → EU NUTS-2/NUTS-1 income (spatial join)
|
||||
-- stg_income_usa → US state-level income (PPS-normalised)
|
||||
-- stg_income → country-level income (fallback for all countries)
|
||||
-- stg_padel_courts → padel venue count + nearest court distance (km)
|
||||
-- stg_tennis_courts → tennis court count within 25km radius
|
||||
--
|
||||
-- Income resolution: COALESCE(regional_income, country_income) AS median_income_pps.
|
||||
-- Germany: all 16 Bundesländer mapped via admin1_code → NUTS-1.
|
||||
-- All other countries fall back to country-level income (stg_income).
|
||||
-- Income resolution cascade:
|
||||
-- 1. EU NUTS-2 regional income (finest; spatial join via ST_Contains)
|
||||
-- 2. EU NUTS-1 regional income (fallback when NUTS-2 income missing from dataset)
|
||||
-- 3. US state income (ratio-normalised to PPS scale; see us_income CTE)
|
||||
-- 4. Country-level income (global fallback from stg_income / ilc_di03)
|
||||
--
|
||||
-- Distance calculations use ST_Distance_Sphere (DuckDB spatial extension).
|
||||
-- A bounding-box pre-filter (~0.5°, ≈55km) reduces the cross-join before the
|
||||
@@ -44,43 +47,97 @@ locations AS (
|
||||
FROM staging.stg_population_geonames
|
||||
WHERE lat IS NOT NULL AND lon IS NOT NULL
|
||||
),
|
||||
-- Country income (same source and pattern as dim_cities) — fallback for unmapped regions
|
||||
-- Country income (ilc_di03) — global fallback for all countries
|
||||
country_income AS (
|
||||
SELECT country_code, median_income_pps, ref_year AS income_year
|
||||
FROM staging.stg_income
|
||||
QUALIFY ROW_NUMBER() OVER (PARTITION BY country_code ORDER BY ref_year DESC) = 1
|
||||
),
|
||||
-- Static mapping: GeoNames admin1_code → NUTS-1 code (Germany only; extend by adding rows)
|
||||
admin1_to_nuts1 (country_code, admin1_code, nuts1_code) AS (
|
||||
VALUES
|
||||
('DE', '01', 'DE1'), -- Baden-Württemberg
|
||||
('DE', '02', 'DE2'), -- Bayern
|
||||
('DE', '03', 'DE5'), -- Bremen
|
||||
('DE', '04', 'DE6'), -- Hamburg
|
||||
('DE', '05', 'DE7'), -- Hessen
|
||||
('DE', '06', 'DE9'), -- Niedersachsen
|
||||
('DE', '07', 'DEA'), -- Nordrhein-Westfalen
|
||||
('DE', '08', 'DEB'), -- Rheinland-Pfalz
|
||||
('DE', '09', 'DEC'), -- Saarland
|
||||
('DE', '10', 'DEF'), -- Schleswig-Holstein
|
||||
('DE', '11', 'DE4'), -- Brandenburg
|
||||
('DE', '12', 'DE8'), -- Mecklenburg-Vorpommern
|
||||
('DE', '13', 'DED'), -- Sachsen
|
||||
('DE', '14', 'DEE'), -- Sachsen-Anhalt
|
||||
('DE', '15', 'DEG'), -- Thüringen
|
||||
('DE', '16', 'DE3') -- Berlin
|
||||
-- ── EU NUTS-2 income via spatial join ──────────────────────────────────────
|
||||
-- Each EU location's (lon, lat) is matched against NUTS-2 boundary polygons.
|
||||
-- The bounding box pre-filter (bbox_lat/lon_min/max) eliminates most candidates
|
||||
-- before the exact ST_Contains test runs.
|
||||
nuts2_match AS (
|
||||
SELECT
|
||||
l.geoname_id,
|
||||
b.nuts2_code,
|
||||
-- Derive parent NUTS-1 code (first 3 chars of NUTS-2)
|
||||
SUBSTR(b.nuts2_code, 1, 3) AS nuts1_code
|
||||
FROM locations l
|
||||
JOIN staging.stg_nuts2_boundaries b
|
||||
-- Bounding-box pre-filter: only test ST_Contains for polygons whose bbox
|
||||
-- overlaps the point, reducing 140K x 242 to ~140K x 3-5 actual tests.
|
||||
ON l.lat BETWEEN b.bbox_lat_min AND b.bbox_lat_max
|
||||
AND l.lon BETWEEN b.bbox_lon_min AND b.bbox_lon_max
|
||||
WHERE ST_Contains(b.geometry, ST_Point(l.lon, l.lat))
|
||||
-- A point should fall in exactly one polygon; QUALIFY guards against rare
|
||||
-- boundary-precision duplicates.
|
||||
QUALIFY ROW_NUMBER() OVER (PARTITION BY l.geoname_id ORDER BY b.nuts2_code) = 1
|
||||
),
|
||||
-- Latest NUTS-1 regional income per region
|
||||
-- NUTS-2 income: latest year per NUTS-2 code
|
||||
nuts2_income AS (
|
||||
SELECT nuts_code, regional_income_pps, ref_year AS regional_income_year
|
||||
FROM staging.stg_regional_income
|
||||
WHERE nuts_level = 2
|
||||
QUALIFY ROW_NUMBER() OVER (PARTITION BY nuts_code ORDER BY ref_year DESC) = 1
|
||||
),
|
||||
-- NUTS-1 income: fallback when NUTS-2 income not in dataset for this region
|
||||
nuts1_income AS (
|
||||
SELECT nuts_code, regional_income_pps, ref_year AS regional_income_year
|
||||
FROM staging.stg_regional_income
|
||||
WHERE nuts_level = 1
|
||||
QUALIFY ROW_NUMBER() OVER (PARTITION BY nuts_code ORDER BY ref_year DESC) = 1
|
||||
),
|
||||
-- Combined EU regional income: NUTS-2 preferred, NUTS-1 fallback
|
||||
regional_income AS (
|
||||
SELECT
|
||||
m.country_code,
|
||||
nm.geoname_id,
|
||||
COALESCE(n2.regional_income_pps, n1.regional_income_pps) AS regional_income_pps,
|
||||
COALESCE(n2.regional_income_year, n1.regional_income_year) AS regional_income_year
|
||||
FROM nuts2_match nm
|
||||
LEFT JOIN nuts2_income n2 ON nm.nuts2_code = n2.nuts_code
|
||||
LEFT JOIN nuts1_income n1 ON nm.nuts1_code = n1.nuts_code
|
||||
),
|
||||
-- ── US state-level income ──────────────────────────────────────────────────
|
||||
-- GeoNames admin1_code for US = 2-letter state abbreviation (ISO 3166-2:US).
|
||||
-- Census ACS uses 2-digit FIPS codes. This 51-row VALUES CTE bridges them.
|
||||
us_state_fips (admin1_code, state_fips) AS (
|
||||
VALUES
|
||||
('AL', '01'), ('AK', '02'), ('AZ', '04'), ('AR', '05'), ('CA', '06'),
|
||||
('CO', '08'), ('CT', '09'), ('DE', '10'), ('FL', '12'), ('GA', '13'),
|
||||
('HI', '15'), ('ID', '16'), ('IL', '17'), ('IN', '18'), ('IA', '19'),
|
||||
('KS', '20'), ('KY', '21'), ('LA', '22'), ('ME', '23'), ('MD', '24'),
|
||||
('MA', '25'), ('MI', '26'), ('MN', '27'), ('MS', '28'), ('MO', '29'),
|
||||
('MT', '30'), ('NE', '31'), ('NV', '32'), ('NH', '33'), ('NJ', '34'),
|
||||
('NM', '35'), ('NY', '36'), ('NC', '37'), ('ND', '38'), ('OH', '39'),
|
||||
('OK', '40'), ('OR', '41'), ('PA', '42'), ('RI', '44'), ('SC', '45'),
|
||||
('SD', '46'), ('TN', '47'), ('TX', '48'), ('UT', '49'), ('VT', '50'),
|
||||
('VA', '51'), ('WA', '53'), ('WV', '54'), ('WI', '55'), ('WY', '56'),
|
||||
('DC', '11')
|
||||
),
|
||||
-- US state income normalised to PPS-equivalent scale.
|
||||
-- US Census reports median household income in nominal USD. To compare with EU
|
||||
-- PPS per inhabitant, we use a ratio normalisation:
|
||||
-- state_pps ≈ US_PPS_CONSTANT × (state_income / national_median)
|
||||
--
|
||||
-- Constants (update when ACS vintage changes):
|
||||
-- national_median = 80,610 — 2023 ACS national median household income (USD)
|
||||
-- US_PPS_CONSTANT = 30,000 — approximate US per-capita income in PPS terms
|
||||
-- (derived from OECD PPP tables, 2022)
|
||||
--
|
||||
-- This gives a realistic spread across states:
|
||||
-- California ($91,905) → ~34,200 PPS [≈ wealthy EU region]
|
||||
-- Texas ($67,321) → ~25,100 PPS [≈ Germany average]
|
||||
-- Mississippi($52,985) → ~19,700 PPS [≈ lower-income EU region]
|
||||
us_income AS (
|
||||
SELECT
|
||||
m.admin1_code,
|
||||
r.regional_income_pps,
|
||||
r.ref_year AS regional_income_year
|
||||
FROM admin1_to_nuts1 m
|
||||
JOIN staging.stg_regional_income r ON r.nuts1_code = m.nuts1_code
|
||||
ROUND(s.median_income_usd / 80610.0 * 30000.0, 0) AS median_income_pps,
|
||||
s.ref_year AS income_year
|
||||
FROM us_state_fips m
|
||||
JOIN staging.stg_income_usa s ON m.state_fips = s.state_fips
|
||||
QUALIFY ROW_NUMBER() OVER (
|
||||
PARTITION BY m.country_code, m.admin1_code ORDER BY r.ref_year DESC
|
||||
PARTITION BY m.admin1_code ORDER BY s.ref_year DESC
|
||||
) = 1
|
||||
),
|
||||
-- Padel court lat/lon for distance and density calculations
|
||||
@@ -197,8 +254,17 @@ SELECT
|
||||
l.admin2_code,
|
||||
l.population,
|
||||
l.ref_year AS population_year,
|
||||
COALESCE(ri.regional_income_pps, ci.median_income_pps) AS median_income_pps,
|
||||
COALESCE(ri.regional_income_year, ci.income_year) AS income_year,
|
||||
-- Income cascade: EU NUTS-2 → EU NUTS-1 → US state → country-level
|
||||
COALESCE(
|
||||
ri.regional_income_pps, -- EU: NUTS-2 (finest) or NUTS-1 (fallback)
|
||||
us.median_income_pps, -- US: state-level PPS-equivalent
|
||||
ci.median_income_pps -- Global: country-level from ilc_di03
|
||||
) AS median_income_pps,
|
||||
COALESCE(
|
||||
ri.regional_income_year,
|
||||
us.income_year,
|
||||
ci.income_year
|
||||
) AS income_year,
|
||||
COALESCE(pl.padel_venue_count, 0)::INTEGER AS padel_venue_count,
|
||||
-- Venues per 100K residents (NULL if population = 0)
|
||||
CASE WHEN l.population > 0
|
||||
@@ -210,12 +276,13 @@ SELECT
|
||||
CURRENT_DATE AS refreshed_date
|
||||
FROM locations l
|
||||
LEFT JOIN country_income ci ON l.country_code = ci.country_code
|
||||
LEFT JOIN regional_income ri ON l.country_code = ri.country_code
|
||||
AND l.admin1_code = ri.admin1_code
|
||||
LEFT JOIN regional_income ri ON l.geoname_id = ri.geoname_id
|
||||
LEFT JOIN us_income us ON l.country_code = 'US'
|
||||
AND l.admin1_code = us.admin1_code
|
||||
LEFT JOIN nearest_padel np ON l.geoname_id = np.geoname_id
|
||||
LEFT JOIN padel_local pl ON l.geoname_id = pl.geoname_id
|
||||
LEFT JOIN tennis_nearby tn ON l.geoname_id = tn.geoname_id
|
||||
-- Enforce grain: deduplicate if city slug collides within same country
|
||||
-- Enforce grain: deduplicate if location slug collides within same country
|
||||
QUALIFY ROW_NUMBER() OVER (
|
||||
PARTITION BY l.country_code, l.geoname_id
|
||||
ORDER BY l.population DESC NULLS LAST
|
||||
|
||||
Reference in New Issue
Block a user