Files
padelnomics/transform/sqlmesh_padelnomics/models/foundation/dim_venue_capacity.sql
Deeman 4e82907a70 refactor(transform): conform geographic dimension hierarchy via city_slug
Propagates the conformed city key (city_slug) from dim_venues through the
full pricing pipeline, eliminating 3 fragile LOWER(TRIM(...)) fuzzy string
joins with deterministic key joins.

Changes (cascading, task-by-task):
- dim_venues: add city_slug computed column (REGEXP_REPLACE slug derivation)
- dim_venue_capacity: join foundation.dim_venues instead of stg_playtomic_venues;
  carry city_slug alongside country_code/city
- fct_daily_availability: carry city_slug from dim_venue_capacity
- venue_pricing_benchmarks: carry city_slug from fct_daily_availability;
  add to venue_stats GROUP BY and final SELECT/GROUP BY
- city_market_profile: join vpb on city_slug = city_slug (was LOWER(TRIM))
- planner_defaults: add city_slug to city_benchmarks CTE; join on city_slug
- pseo_city_pricing: join city_market_profile on city_slug (was LOWER(TRIM))
- pipeline_routes._DAG: dim_venue_capacity now depends on dim_venues, not stg_playtomic_venues

Result: dim_venues.city_slug → dim_cities.(country_code, city_slug) forms a
fully conformed geographic hierarchy with no fuzzy string comparisons.

Co-Authored-By: Claude Sonnet 4.6 <noreply@anthropic.com>
2026-02-27 13:23:03 +01:00

49 lines
1.6 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).
-- 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