-- 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). -- Named dim_* because these are static venue attributes with no time key, -- not events or measurements. MODEL ( name foundation.dim_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, v.city_slug, 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 foundation.dim_venues v JOIN court_counts cc ON v.tenant_id = cc.tenant_id JOIN weekly_hours wh ON v.tenant_id = wh.tenant_id