feat(transform): add three pSEO serving models — city costs, country overview, city pricing
- pseo_city_costs_de: unblocks city-cost-de template (~600 city pages), joins city_market_profile + planner_defaults, includes camelCase calc override columns (ratePeak, rateOffPeak, utilTarget, dblCourts, country) - pseo_country_overview: per-country hub aggregating from pseo_city_costs_de, includes top_city_slugs/names lists for internal linking - pseo_city_pricing: per-city pricing pages requiring >= 2 Playtomic venues, includes P25/P75 price range and occupancy Co-Authored-By: Claude Opus 4.6 <noreply@anthropic.com>
This commit is contained in:
@@ -0,0 +1,49 @@
|
||||
-- pSEO article data: per-city padel cost and market analysis.
|
||||
-- One row per city — consumed by the city-cost-de.md.jinja template to generate
|
||||
-- ~600 city-level articles about padel investment costs.
|
||||
--
|
||||
-- Calculator override columns use camelCase to match the DEFAULTS keys in
|
||||
-- planner/calculator.py, so they are auto-applied as calc pre-fills.
|
||||
|
||||
MODEL (
|
||||
name serving.pseo_city_costs_de,
|
||||
kind FULL,
|
||||
cron '@daily',
|
||||
grain city_slug
|
||||
);
|
||||
|
||||
SELECT
|
||||
-- City identity
|
||||
c.city_slug,
|
||||
c.city_name,
|
||||
c.country_code,
|
||||
c.country_name_en,
|
||||
c.country_slug,
|
||||
-- Market metrics
|
||||
c.population,
|
||||
c.padel_venue_count,
|
||||
c.venues_per_100k,
|
||||
c.market_score,
|
||||
c.data_confidence,
|
||||
-- Pricing (from Playtomic, NULL when no coverage)
|
||||
c.median_hourly_rate,
|
||||
c.median_peak_rate,
|
||||
c.median_offpeak_rate,
|
||||
c.median_occupancy_rate,
|
||||
c.median_daily_revenue_per_venue,
|
||||
COALESCE(c.price_currency, p.price_currency, 'EUR') AS price_currency,
|
||||
-- Calculator override columns — camelCase keys match planner DEFAULTS auto-mapping.
|
||||
-- utilTarget: planner stores 0.0–1.0, calculator expects 0–100.
|
||||
p.rate_peak AS "ratePeak",
|
||||
p.rate_off_peak AS "rateOffPeak",
|
||||
p.avg_utilisation_pct * 100 AS "utilTarget",
|
||||
FLOOR(p.courts_typical) AS "dblCourts",
|
||||
-- 'country' drives currency formatting in the calculator
|
||||
c.country_code AS "country",
|
||||
CURRENT_DATE AS refreshed_date
|
||||
FROM serving.city_market_profile c
|
||||
LEFT JOIN serving.planner_defaults p
|
||||
ON c.city_slug = p.city_slug
|
||||
-- Only cities with actual padel presence and at least some rate data
|
||||
WHERE c.padel_venue_count > 0
|
||||
AND (p.rate_peak IS NOT NULL OR c.median_peak_rate IS NOT NULL)
|
||||
@@ -0,0 +1,44 @@
|
||||
-- pSEO article data: per-city padel court pricing.
|
||||
-- One row per city — consumed by the city-pricing.md.jinja template.
|
||||
-- Joins venue_pricing_benchmarks (real Playtomic data) with city_market_profile
|
||||
-- (population, venue count, country metadata).
|
||||
--
|
||||
-- Stricter filter than pseo_city_costs_de: requires >= 2 venues with real
|
||||
-- pricing data so pricing articles are always data-backed.
|
||||
|
||||
MODEL (
|
||||
name serving.pseo_city_pricing,
|
||||
kind FULL,
|
||||
cron '@daily',
|
||||
grain city_slug
|
||||
);
|
||||
|
||||
SELECT
|
||||
-- City identity (from city_market_profile, which has the canonical city_slug)
|
||||
c.city_slug,
|
||||
c.city_name,
|
||||
c.country_code,
|
||||
c.country_name_en,
|
||||
c.country_slug,
|
||||
-- Market context
|
||||
c.population,
|
||||
c.padel_venue_count,
|
||||
c.venues_per_100k,
|
||||
c.market_score,
|
||||
-- Pricing benchmarks (from Playtomic availability data)
|
||||
vpb.median_hourly_rate,
|
||||
vpb.median_peak_rate,
|
||||
vpb.median_offpeak_rate,
|
||||
vpb.hourly_rate_p25,
|
||||
vpb.hourly_rate_p75,
|
||||
vpb.median_occupancy_rate,
|
||||
vpb.venue_count,
|
||||
vpb.price_currency,
|
||||
CURRENT_DATE AS refreshed_date
|
||||
FROM serving.venue_pricing_benchmarks vpb
|
||||
-- Join city_market_profile to get the canonical city_slug and country metadata
|
||||
INNER JOIN serving.city_market_profile c
|
||||
ON vpb.country_code = c.country_code
|
||||
AND LOWER(TRIM(vpb.city)) = LOWER(TRIM(c.city_name))
|
||||
-- Only cities with enough venues for meaningful pricing statistics
|
||||
WHERE vpb.venue_count >= 2
|
||||
@@ -0,0 +1,37 @@
|
||||
-- pSEO article data: per-country padel market overview.
|
||||
-- One row per country — consumed by the country-overview.md.jinja template.
|
||||
-- Aggregates city-level data from pseo_city_costs_de.
|
||||
--
|
||||
-- top_city_slugs / top_city_names are ordered lists (up to 5) used to generate
|
||||
-- internal links from the country hub to its top city pages.
|
||||
|
||||
MODEL (
|
||||
name serving.pseo_country_overview,
|
||||
kind FULL,
|
||||
cron '@daily',
|
||||
grain country_slug
|
||||
);
|
||||
|
||||
SELECT
|
||||
country_code,
|
||||
country_name_en,
|
||||
country_slug,
|
||||
COUNT(*) AS city_count,
|
||||
SUM(padel_venue_count) AS total_venues,
|
||||
ROUND(AVG(market_score), 1) AS avg_market_score,
|
||||
MAX(market_score) AS top_city_market_score,
|
||||
-- Top 5 cities by market score for internal linking (DuckDB list slice syntax)
|
||||
LIST(city_slug ORDER BY market_score DESC NULLS LAST)[1:5] AS top_city_slugs,
|
||||
LIST(city_name ORDER BY market_score DESC NULLS LAST)[1:5] AS top_city_names,
|
||||
-- Pricing medians across cities (NULL when no Playtomic coverage in country)
|
||||
ROUND(MEDIAN(median_hourly_rate), 0) AS median_hourly_rate,
|
||||
ROUND(MEDIAN(median_peak_rate), 0) AS median_peak_rate,
|
||||
ROUND(MEDIAN(median_offpeak_rate), 0) AS median_offpeak_rate,
|
||||
-- Use the most common currency in the country (MIN is deterministic for single-currency countries)
|
||||
MIN(price_currency) AS price_currency,
|
||||
SUM(population) AS total_population,
|
||||
CURRENT_DATE AS refreshed_date
|
||||
FROM serving.pseo_city_costs_de
|
||||
GROUP BY country_code, country_name_en, country_slug
|
||||
-- Only countries with enough cities to be worth a hub page
|
||||
HAVING COUNT(*) >= 2
|
||||
Reference in New Issue
Block a user