Files
padelnomics/transform/sqlmesh_padelnomics/models/foundation/fct_venue_capacity.sql
Deeman 79f7fc6fad 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>
2026-02-23 00:54:53 +01:00

46 lines
1.5 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters
This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.
-- Venue capacity: total bookable court-hours per day and week.
-- Derived from active court count × opening hours.
-- Used as the denominator for occupancy rate in fct_daily_availability.
--
-- One row per venue (Playtomic tenant).
MODEL (
name foundation.fct_venue_capacity,
kind FULL,
cron '@daily',
grain tenant_id
);
WITH weekly_hours AS (
SELECT
tenant_id,
SUM(hours_open) AS hours_open_per_week,
AVG(hours_open) AS avg_hours_open_per_day,
COUNT(*) AS days_open_per_week
FROM staging.stg_playtomic_opening_hours
GROUP BY tenant_id
),
court_counts AS (
SELECT
tenant_id,
COUNT(*) AS active_court_count
FROM staging.stg_playtomic_resources
WHERE is_active = TRUE
GROUP BY tenant_id
)
SELECT
v.tenant_id,
v.country_code,
v.city,
cc.active_court_count,
ROUND(wh.hours_open_per_week, 1) AS hours_open_per_week,
ROUND(wh.avg_hours_open_per_day, 1) AS avg_hours_open_per_day,
wh.days_open_per_week,
-- Total bookable court-hours per day (capacity denominator for occupancy)
ROUND(cc.active_court_count * wh.avg_hours_open_per_day, 1) AS capacity_court_hours_per_day,
-- Total bookable court-hours per week
ROUND(cc.active_court_count * wh.hours_open_per_week, 1) AS capacity_court_hours_per_week
FROM staging.stg_playtomic_venues v
JOIN court_counts cc ON v.tenant_id = cc.tenant_id
JOIN weekly_hours wh ON v.tenant_id = wh.tenant_id