feat: Playtomic pricing/occupancy pipeline + email i18n + audience restructure
Three workstreams:
1. Playtomic full data extraction & transform pipeline:
- Expand venue bounding boxes from 4 to 23 regions (global coverage)
- New staging models for court resources, opening hours, and slot-level
availability with real prices from the Playtomic API
- Foundation fact tables for venue capacity and daily occupancy/revenue
- City-level pricing benchmarks replacing hardcoded country estimates
- Planner defaults now use 3-tier cascade: city data → country → fallback
2. Transactional email i18n:
- _t() helper in worker.py with ~70 translation keys (EN + DE)
- All 8 email handlers translated, lang passed in task payloads
3. Resend audiences restructured to 3 named audiences (free plan limit)
Co-Authored-By: Claude Opus 4.6 <noreply@anthropic.com>
This commit is contained in:
@@ -1,11 +1,13 @@
|
||||
-- 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.
|
||||
-- Consumed by: padelnomics.planner.routes — /api/market-data endpoint.
|
||||
--
|
||||
-- Values are derived from market data where available, otherwise fall back to
|
||||
-- country-level medians, then to global fallbacks from market research report.
|
||||
-- 3-tier data cascade:
|
||||
-- 1. City-level: real pricing/occupancy from Playtomic availability snapshots
|
||||
-- 2. Country-level: median across cities in same country
|
||||
-- 3. Hardcoded fallback: market research estimates (only when no Playtomic data)
|
||||
--
|
||||
-- Units are explicit in column names (EUR, %, h). All monetary values in EUR.
|
||||
-- Units are explicit in column names. Monetary values in local currency.
|
||||
|
||||
MODEL (
|
||||
name serving.planner_defaults,
|
||||
@@ -14,59 +16,120 @@ MODEL (
|
||||
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)
|
||||
WITH -- Real city-level benchmarks from Playtomic
|
||||
city_benchmarks AS (
|
||||
SELECT
|
||||
country_code,
|
||||
city,
|
||||
median_peak_rate,
|
||||
median_offpeak_rate,
|
||||
median_occupancy_rate,
|
||||
median_daily_revenue_per_venue,
|
||||
median_court_count,
|
||||
venue_count,
|
||||
total_venue_days_observed,
|
||||
price_currency
|
||||
FROM serving.venue_pricing_benchmarks
|
||||
),
|
||||
city_venue_density AS (
|
||||
-- Country-level medians (fallback when a city has no availability data)
|
||||
country_benchmarks AS (
|
||||
SELECT
|
||||
country_code,
|
||||
MEDIAN(median_peak_rate) AS median_peak_rate,
|
||||
MEDIAN(median_offpeak_rate) AS median_offpeak_rate,
|
||||
MEDIAN(median_occupancy_rate) AS median_occupancy_rate,
|
||||
MEDIAN(median_court_count) AS median_court_count,
|
||||
SUM(venue_count) AS total_venues,
|
||||
MIN(price_currency) AS price_currency
|
||||
FROM city_benchmarks
|
||||
GROUP BY country_code
|
||||
),
|
||||
-- Hardcoded global fallbacks (only for countries with zero Playtomic coverage)
|
||||
hardcoded_fallbacks AS (
|
||||
SELECT * FROM (VALUES
|
||||
('DE', 22.0, 16.5, 0.55, 4, 'EUR'),
|
||||
('ES', 16.0, 12.0, 0.62, 6, 'EUR'),
|
||||
('GB', 24.0, 18.0, 0.52, 4, 'GBP'),
|
||||
('FR', 18.0, 13.5, 0.58, 5, 'EUR'),
|
||||
('IT', 15.0, 11.0, 0.60, 6, 'EUR'),
|
||||
('PT', 12.0, 9.0, 0.65, 6, 'EUR'),
|
||||
('AT', 20.0, 15.0, 0.54, 4, 'EUR'),
|
||||
('CH', 28.0, 21.0, 0.50, 4, 'CHF'),
|
||||
('NL', 20.0, 15.0, 0.56, 4, 'EUR'),
|
||||
('BE', 18.0, 13.5, 0.57, 4, 'EUR'),
|
||||
('SE', 22.0, 16.5, 0.50, 4, 'SEK'),
|
||||
('US', 20.0, 15.0, 0.58, 6, 'USD'),
|
||||
('MX', 12.0, 9.0, 0.55, 4, 'MXN'),
|
||||
('AR', 10.0, 7.5, 0.60, 4, 'ARS'),
|
||||
('DK', 24.0, 18.0, 0.48, 4, 'DKK'),
|
||||
('NO', 26.0, 19.5, 0.45, 4, 'NOK'),
|
||||
('FI', 22.0, 16.5, 0.48, 4, 'EUR')
|
||||
) AS t(country_code, peak_rate, offpeak_rate, occupancy, courts, currency)
|
||||
),
|
||||
city_profiles AS (
|
||||
SELECT
|
||||
city_slug,
|
||||
country_code,
|
||||
city_name,
|
||||
padel_venue_count,
|
||||
population,
|
||||
venues_per_100k,
|
||||
market_score
|
||||
market_score,
|
||||
venues_per_100k
|
||||
FROM serving.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
|
||||
cp.city_slug,
|
||||
cp.country_code,
|
||||
cp.city_name,
|
||||
cp.padel_venue_count,
|
||||
cp.population,
|
||||
cp.market_score,
|
||||
-- Peak rate: city → country → hardcoded
|
||||
ROUND(COALESCE(
|
||||
cb.median_peak_rate,
|
||||
ctb.median_peak_rate,
|
||||
hf.peak_rate
|
||||
), 2) AS rate_peak,
|
||||
-- Off-peak rate
|
||||
ROUND(COALESCE(
|
||||
cb.median_offpeak_rate,
|
||||
ctb.median_offpeak_rate,
|
||||
hf.offpeak_rate
|
||||
), 2) AS rate_off_peak,
|
||||
-- Occupancy (utilisation)
|
||||
ROUND(COALESCE(
|
||||
cb.median_occupancy_rate,
|
||||
ctb.median_occupancy_rate,
|
||||
hf.occupancy
|
||||
), 4) AS avg_utilisation_pct,
|
||||
-- Typical court count
|
||||
COALESCE(
|
||||
cb.median_court_count,
|
||||
ctb.median_court_count,
|
||||
hf.courts
|
||||
) AS courts_typical,
|
||||
-- Revenue estimate (city-level only)
|
||||
cb.median_daily_revenue_per_venue AS daily_revenue_per_venue,
|
||||
-- Data provenance
|
||||
CASE
|
||||
WHEN cb.venue_count IS NOT NULL THEN 'city_data'
|
||||
WHEN ctb.total_venues IS NOT NULL THEN 'country_data'
|
||||
ELSE 'hardcoded'
|
||||
END AS data_source,
|
||||
CASE
|
||||
WHEN cb.total_venue_days_observed >= 100 THEN 1.0
|
||||
WHEN cb.total_venue_days_observed >= 30 THEN 0.8
|
||||
WHEN cb.venue_count IS NOT NULL THEN 0.6
|
||||
WHEN ctb.total_venues IS NOT NULL THEN 0.4
|
||||
ELSE 0.2
|
||||
END AS data_confidence,
|
||||
COALESCE(cb.price_currency, ctb.price_currency, hf.currency, 'EUR') AS price_currency,
|
||||
CURRENT_DATE AS refreshed_date
|
||||
FROM city_profiles cp
|
||||
LEFT JOIN city_benchmarks cb
|
||||
ON cp.country_code = cb.country_code
|
||||
AND LOWER(TRIM(cp.city_name)) = LOWER(TRIM(cb.city))
|
||||
LEFT JOIN country_benchmarks ctb
|
||||
ON cp.country_code = ctb.country_code
|
||||
LEFT JOIN hardcoded_fallbacks hf
|
||||
ON cp.country_code = hf.country_code
|
||||
|
||||
Reference in New Issue
Block a user