Three deviations from the quart_saas_boilerplate methodology corrected:
1. Fix dim_cities LIKE join (data quality bug)
- Old: FROM eurostat_cities LEFT JOIN venue_counts LIKE '%country_code%'
→ cartesian product (2.6M rows vs ~5500 expected)
- New: FROM venue_cities (dim_venues) as primary table, Eurostat for
enrichment only. grain (country_code, city_slug).
- Also fixes REGEXP_REPLACE to LOWER() before regex so uppercase city
names aren't stripped to '-'
2. Rename fct_venue_capacity → dim_venue_capacity
- Static venue attributes with no time key are a dimension, not a fact
- No SQL logic changes; update fct_daily_availability reference
3. Add fct_availability_slot at event grain
- New: grain (snapshot_date, tenant_id, resource_id, slot_start_time)
- Recheck dedup logic moves here from fct_daily_availability
- fct_daily_availability now reads fct_availability_slot (cleaner DAG)
Downstream fixes:
- city_market_profile, planner_defaults grain → (country_code, city_slug)
- pseo_city_costs_de, pseo_city_pricing add city_key composite natural key
(country_slug || '-' || city_slug) to avoid URL collisions across countries
- planner_defaults join in pseo_city_costs_de uses both country_code + city_slug
- Templates updated: natural_key city_slug → city_key
Added transform/sqlmesh_padelnomics/CLAUDE.md documenting data modeling rules,
conformed dimension map, and source integration architecture.
Co-Authored-By: Claude Sonnet 4.6 <noreply@anthropic.com>
48 lines
1.6 KiB
SQL
48 lines
1.6 KiB
SQL
-- 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,
|
||
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
|