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:
Deeman
2026-02-23 00:54:53 +01:00
parent c25e20f83a
commit 79f7fc6fad
24 changed files with 1318 additions and 324 deletions

View File

@@ -0,0 +1,90 @@
-- Daily venue-level availability, pricing, occupancy, and revenue estimates.
-- Aggregates slot-level data from stg_playtomic_availability into per-venue
-- per-day statistics, then calculates occupancy by comparing available hours
-- against total capacity from fct_venue_capacity.
--
-- Occupancy = 1 - (available_court_hours / capacity_court_hours_per_day)
-- Revenue estimate = booked_court_hours × avg_price_of_available_slots
--
-- Peak hours defined as 17:0021:00 (captures main evening rush across markets).
MODEL (
name foundation.fct_daily_availability,
kind FULL,
cron '@daily',
grain (snapshot_date, tenant_id)
);
WITH slot_agg AS (
SELECT
a.snapshot_date,
a.tenant_id,
-- Slot counts: each row is one 60-min available slot on one court
COUNT(*) AS available_slot_count,
COUNT(DISTINCT a.resource_id) AS courts_with_availability,
-- Available (unbooked) court-hours: slots are on 30-min increments for 60-min bookings
-- Each available start_time represents a 60-min bookable window
ROUND(COUNT(*) * 1.0, 2) AS available_court_hours,
-- Pricing stats (60-min slots only)
ROUND(MEDIAN(a.price_amount), 2) AS median_price,
ROUND(AVG(a.price_amount), 2) AS avg_price,
MIN(a.price_amount) AS min_price,
MAX(a.price_amount) AS max_price,
-- Peak: 17:0021:00
ROUND(MEDIAN(a.price_amount) FILTER (
WHERE a.slot_start_time::TIME >= '17:00:00'
AND a.slot_start_time::TIME < '21:00:00'
), 2) AS median_price_peak,
-- Off-peak: everything outside 17:0021:00
ROUND(MEDIAN(a.price_amount) FILTER (
WHERE a.slot_start_time::TIME < '17:00:00'
OR a.slot_start_time::TIME >= '21:00:00'
), 2) AS median_price_offpeak,
MAX(a.price_currency) AS price_currency,
MAX(a.captured_at_utc) AS captured_at_utc
FROM staging.stg_playtomic_availability a
WHERE a.price_amount IS NOT NULL
AND a.price_amount > 0
GROUP BY a.snapshot_date, a.tenant_id
)
SELECT
sa.snapshot_date,
sa.tenant_id,
cap.country_code,
cap.city,
cap.active_court_count,
cap.capacity_court_hours_per_day,
sa.available_slot_count,
sa.courts_with_availability,
sa.available_court_hours,
-- Occupancy: (capacity - available) / capacity
CASE
WHEN cap.capacity_court_hours_per_day > 0
THEN ROUND(
1.0 - (sa.available_court_hours / cap.capacity_court_hours_per_day),
4
)
ELSE NULL
END AS occupancy_rate,
-- Estimated booked court-hours
ROUND(
GREATEST(cap.capacity_court_hours_per_day - sa.available_court_hours, 0),
2
) AS booked_court_hours,
-- Estimated daily revenue: booked hours × avg price
ROUND(
GREATEST(cap.capacity_court_hours_per_day - sa.available_court_hours, 0)
* sa.avg_price,
2
) AS estimated_revenue_eur,
-- Pricing
sa.median_price,
sa.avg_price,
sa.min_price,
sa.max_price,
sa.median_price_peak,
sa.median_price_offpeak,
sa.price_currency,
sa.captured_at_utc
FROM slot_agg sa
JOIN foundation.fct_venue_capacity cap ON sa.tenant_id = cap.tenant_id