-- Raw OpenStreetMap padel courts from Overpass API landing files. -- Source: data/landing/overpass/{year}/{month}/courts.json.gz -- Format: {"version": ..., "elements": [{type, id, lat, lon, tags}, ...]} -- -- Only node elements carry direct lat/lon. Way and relation elements need -- centroid calculation from member nodes (not done here — filter to node only -- for the initial raw layer; ways/relations retained as-is for future enrichment). MODEL ( name padelnomics.raw_overpass_courts, kind FULL, cron '@daily', grain (osm_type, osm_id) ); SELECT elem ->> 'type' AS osm_type, (elem ->> 'id')::BIGINT AS osm_id, TRY_CAST(elem ->> 'lat' AS DOUBLE) AS lat, TRY_CAST(elem ->> 'lon' AS DOUBLE) AS lon, elem -> 'tags' ->> 'name' AS name, elem -> 'tags' ->> 'sport' AS sport, elem -> 'tags' ->> 'leisure' AS leisure, elem -> 'tags' ->> 'addr:country' AS country_code, elem -> 'tags' ->> 'addr:city' AS city_tag, elem -> 'tags' ->> 'addr:postcode' AS postcode, elem -> 'tags' ->> 'operator' AS operator_name, elem -> 'tags' ->> 'opening_hours' AS opening_hours, elem -> 'tags' ->> 'fee' AS fee, filename AS source_file, CURRENT_DATE AS extracted_date FROM ( SELECT UNNEST(elements) AS elem, filename FROM read_json( @LANDING_DIR || '/overpass/*/*/courts.json.gz', format = 'auto', filename = true ) ) WHERE (elem ->> 'type') IS NOT NULL