Files
padelnomics/padelnomics/transform/sqlmesh_padelnomics/models/serving/planner_defaults.sql
Deeman 9f8ca82505 feat(sqlmesh): add transform workspace member with 4-layer DuckDB pipeline
Adds sqlmesh_padelnomics UV workspace member at transform/sqlmesh_padelnomics/.
DuckDB gateway, LANDING_DIR variable, @daily cron on all models.

Raw layer (reads landing zone gzip JSON):
  raw_overpass_courts    — OSM padel court elements (nodes with lat/lon/tags)
  raw_playtomic_tenants  — Playtomic venue records (tenant_id, location, name)
  raw_eurostat_population — Eurostat urb_cpop1 city population (unpivoted)

Staging layer (typed, deduped, country-resolved):
  stg_padel_courts       — OSM nodes only, ~100m bbox country approximation
  stg_playtomic_venues   — deduplicated Playtomic venues
  stg_population         — city population by year with integer types

Foundation layer:
  dim_venues             — deduped union of OSM + Playtomic (~100m grid)
  dim_cities             — Eurostat cities with population + venue counts

Serving layer (consumed by web app and SEO generation):
  city_market_profile    — OBT: market score, venue density, population per city
  planner_defaults       — per-city calculator pre-fill values with country median
                           fallbacks and competitive-pressure rate adjustments

Co-Authored-By: Claude Sonnet 4.6 <noreply@anthropic.com>
2026-02-21 22:03:59 +01:00

73 lines
2.6 KiB
SQL

-- Per-city planner defaults for the financial calculator.
-- When a user selects a city in the planner, these values pre-fill the inputs.
-- Consumed by: padelnomics.planner.routes — city_defaults(city_slug) lookup.
--
-- Values are derived from market data where available, otherwise fall back to
-- country-level medians, then to global fallbacks from market research report.
--
-- Units are explicit in column names (EUR, %, h). All monetary values in EUR.
MODEL (
name padelnomics.planner_defaults,
kind FULL,
cron '@daily',
grain city_slug
);
WITH country_medians AS (
-- Country-level fallback values from market research (hardcoded until we
-- have richer pricing data from Playtomic or direct scraping).
SELECT * FROM (VALUES
-- (country_code, hourly_rate_peak_eur, monthly_rent_eur_sqm, capex_court_eur,
-- avg_utilisation_pct, courts_typical)
('DE', 22.0, 14.0, 42000.0, 0.55, 4),
('ES', 16.0, 9.0, 32000.0, 0.62, 6),
('GB', 24.0, 18.0, 48000.0, 0.52, 4),
('FR', 18.0, 12.0, 36000.0, 0.58, 5),
('IT', 15.0, 10.0, 30000.0, 0.60, 6),
('PT', 12.0, 8.0, 28000.0, 0.65, 6),
('AT', 20.0, 13.0, 40000.0, 0.54, 4),
('CH', 28.0, 22.0, 55000.0, 0.50, 4),
('NL', 20.0, 15.0, 40000.0, 0.56, 4),
('BE', 18.0, 13.0, 36000.0, 0.57, 4),
('SE', 22.0, 14.0, 42000.0, 0.50, 4),
('US', 20.0, 12.0, 38000.0, 0.58, 6)
) AS t(country_code, hourly_rate_peak_eur, monthly_rent_eur_sqm, capex_court_eur,
avg_utilisation_pct, courts_typical)
),
city_venue_density AS (
SELECT
city_slug,
country_code,
padel_venue_count,
population,
venues_per_100k,
market_score
FROM padelnomics.city_market_profile
)
SELECT
cvd.city_slug,
cvd.country_code,
cvd.padel_venue_count,
cvd.population,
cvd.market_score,
-- Hourly rate: adjust country median by market maturity
-- (high-density markets → slightly lower rates from competition)
ROUND(
cm.hourly_rate_peak_eur
* CASE
WHEN cvd.venues_per_100k > 4 THEN 0.90 -- very competitive
WHEN cvd.venues_per_100k > 2 THEN 0.95 -- competitive
WHEN cvd.venues_per_100k < 0.5 THEN 1.10 -- underserved premium
ELSE 1.0
END
, 2) AS hourly_rate_peak_eur,
ROUND(cm.hourly_rate_peak_eur * 0.75, 2) AS hourly_rate_offpeak_eur,
cm.monthly_rent_eur_sqm,
cm.capex_court_eur,
cm.avg_utilisation_pct,
cm.courts_typical,
CURRENT_DATE AS refreshed_date
FROM city_venue_density cvd
LEFT JOIN country_medians cm ON cvd.country_code = cm.country_code