- dim_cities: add geoname_id to geonames_pop CTE and final SELECT
Creates FK between dim_cities (city-with-padel-venues) and dim_locations (all GeoNames),
enabling joins to location_opportunity_profile for the first time.
- city_market_profile: pass geoname_id through base CTE and final SELECT
- pseo_city_costs_de: LEFT JOIN location_opportunity_profile on (country_code, geoname_id),
add opportunity_score to output columns
- pseo_country_overview: add avg_opportunity_score, top_opportunity_score, top_opportunity_slugs,
top_opportunity_names aggregates
Cities with no GeoNames name match get opportunity_score = NULL; templates guard with
{% if opportunity_score %}.
Co-Authored-By: Claude Opus 4.6 <noreply@anthropic.com>
44 lines
2.4 KiB
SQL
44 lines
2.4 KiB
SQL
-- 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,
|
|
-- Opportunity score aggregates (NULL-safe: cities without geoname_id match excluded from AVG)
|
|
ROUND(AVG(opportunity_score), 1) AS avg_opportunity_score,
|
|
MAX(opportunity_score) AS top_opportunity_score,
|
|
-- Top 5 cities by opportunity score (may differ from top market score cities)
|
|
LIST(city_slug ORDER BY opportunity_score DESC NULLS LAST)[1:5] AS top_opportunity_slugs,
|
|
LIST(city_name ORDER BY opportunity_score DESC NULLS LAST)[1:5] AS top_opportunity_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
|