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:
@@ -0,0 +1,57 @@
|
||||
-- Per-city pricing and occupancy benchmarks from Playtomic availability data.
|
||||
-- Aggregates venue-level daily metrics (last 30 days) into city-level benchmarks.
|
||||
-- Consumed by: planner defaults (pre-fill), city market profile, SEO articles.
|
||||
--
|
||||
-- Minimum data threshold: venues with >= 3 days of observations.
|
||||
|
||||
MODEL (
|
||||
name serving.venue_pricing_benchmarks,
|
||||
kind FULL,
|
||||
cron '@daily',
|
||||
grain (country_code, city)
|
||||
);
|
||||
|
||||
WITH venue_stats AS (
|
||||
-- Aggregate last 30 days per venue
|
||||
SELECT
|
||||
da.tenant_id,
|
||||
da.country_code,
|
||||
da.city,
|
||||
da.price_currency,
|
||||
AVG(da.occupancy_rate) AS avg_occupancy_rate,
|
||||
MEDIAN(da.median_price) AS median_hourly_rate,
|
||||
MEDIAN(da.median_price_peak) AS median_peak_rate,
|
||||
MEDIAN(da.median_price_offpeak) AS median_offpeak_rate,
|
||||
AVG(da.estimated_revenue_eur) AS avg_daily_revenue,
|
||||
MAX(da.active_court_count) AS court_count,
|
||||
COUNT(DISTINCT da.snapshot_date) AS days_observed
|
||||
FROM foundation.fct_daily_availability da
|
||||
WHERE da.snapshot_date >= CURRENT_DATE - INTERVAL '30 days'
|
||||
AND da.occupancy_rate IS NOT NULL
|
||||
AND da.occupancy_rate BETWEEN 0 AND 1.5
|
||||
GROUP BY da.tenant_id, da.country_code, da.city, da.price_currency
|
||||
HAVING COUNT(DISTINCT da.snapshot_date) >= 3
|
||||
)
|
||||
SELECT
|
||||
country_code,
|
||||
city,
|
||||
price_currency,
|
||||
COUNT(*) AS venue_count,
|
||||
-- Pricing benchmarks
|
||||
ROUND(MEDIAN(median_hourly_rate), 2) AS median_hourly_rate,
|
||||
ROUND(MEDIAN(median_peak_rate), 2) AS median_peak_rate,
|
||||
ROUND(MEDIAN(median_offpeak_rate), 2) AS median_offpeak_rate,
|
||||
ROUND(PERCENTILE_CONT(0.25) WITHIN GROUP (ORDER BY median_hourly_rate), 2) AS hourly_rate_p25,
|
||||
ROUND(PERCENTILE_CONT(0.75) WITHIN GROUP (ORDER BY median_hourly_rate), 2) AS hourly_rate_p75,
|
||||
-- Occupancy benchmarks
|
||||
ROUND(MEDIAN(avg_occupancy_rate), 4) AS median_occupancy_rate,
|
||||
ROUND(AVG(avg_occupancy_rate), 4) AS avg_occupancy_rate,
|
||||
-- Revenue benchmarks (per venue per day)
|
||||
ROUND(MEDIAN(avg_daily_revenue), 2) AS median_daily_revenue_per_venue,
|
||||
-- Court mix
|
||||
ROUND(MEDIAN(court_count), 0)::INTEGER AS median_court_count,
|
||||
-- Data quality
|
||||
SUM(days_observed) AS total_venue_days_observed,
|
||||
CURRENT_DATE AS refreshed_date
|
||||
FROM venue_stats
|
||||
GROUP BY country_code, city, price_currency
|
||||
Reference in New Issue
Block a user