refactor: flatten padelnomics/padelnomics/ → repo root
git mv all tracked files from the nested padelnomics/ workspace directory to the git repo root. Merged .gitignore files. No code changes — pure path rename. Co-Authored-By: Claude Sonnet 4.6 <noreply@anthropic.com>
This commit is contained in:
@@ -0,0 +1,64 @@
|
||||
-- Raw Eurostat Urban Audit city population (dataset: urb_cpop1).
|
||||
-- Source: data/landing/eurostat/{year}/{month}/urb_cpop1.json.gz
|
||||
-- Format: Eurostat JSON Statistics API (dimensions + flat value array).
|
||||
--
|
||||
-- The Eurostat JSON format encodes dimensions separately from values:
|
||||
-- dimension.cities.category.index → maps city code to flat array position
|
||||
-- dimension.time.category.index → maps year to flat array position
|
||||
-- values → flat object {position_str: value}
|
||||
--
|
||||
-- This model stores one row per (city_code, year) by computing positions.
|
||||
-- Reference: https://wikis.ec.europa.eu/display/EUROSTATHELP/API+Statistics
|
||||
|
||||
MODEL (
|
||||
name padelnomics.raw_eurostat_population,
|
||||
kind FULL,
|
||||
cron '@daily',
|
||||
grain (city_code, ref_year)
|
||||
);
|
||||
|
||||
WITH raw AS (
|
||||
SELECT
|
||||
raw_json,
|
||||
filename
|
||||
FROM read_json(
|
||||
@LANDING_DIR || '/eurostat/*/*/urb_cpop1.json.gz',
|
||||
format = 'auto',
|
||||
filename = true,
|
||||
columns = { 'raw_json': 'JSON' }
|
||||
)
|
||||
),
|
||||
-- Unnest city codes with their ordinal positions
|
||||
cities AS (
|
||||
SELECT
|
||||
city_code,
|
||||
(city_pos)::INTEGER AS city_pos,
|
||||
filename,
|
||||
raw_json,
|
||||
(json_extract(raw_json, '$.size[1]'))::INTEGER AS n_times
|
||||
FROM raw,
|
||||
LATERAL (
|
||||
SELECT key AS city_code, value::INTEGER AS city_pos
|
||||
FROM json_each(json_extract(raw_json, '$.dimension.cities.category.index'))
|
||||
)
|
||||
),
|
||||
-- Unnest time (year) values with positions
|
||||
times AS (
|
||||
SELECT key AS ref_year, value::INTEGER AS time_pos
|
||||
FROM (SELECT raw_json FROM raw LIMIT 1),
|
||||
LATERAL (
|
||||
SELECT key, value
|
||||
FROM json_each(json_extract(raw_json, '$.dimension.time.category.index'))
|
||||
)
|
||||
)
|
||||
SELECT
|
||||
c.city_code,
|
||||
t.ref_year,
|
||||
TRY_CAST(
|
||||
json_extract(c.raw_json, '$.' || (c.city_pos * c.n_times + t.time_pos)::TEXT)
|
||||
AS DOUBLE
|
||||
) AS population,
|
||||
c.filename AS source_file,
|
||||
CURRENT_DATE AS extracted_date
|
||||
FROM cities c
|
||||
CROSS JOIN times t
|
||||
@@ -0,0 +1,42 @@
|
||||
-- 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
|
||||
@@ -0,0 +1,35 @@
|
||||
-- Raw Playtomic venue (tenant) listings from unauthenticated tenant search API.
|
||||
-- Source: data/landing/playtomic/{year}/{month}/tenants.json.gz
|
||||
-- Format: {"tenants": [{tenant_id, name, address, sport_ids, ...}], "count": N}
|
||||
|
||||
MODEL (
|
||||
name padelnomics.raw_playtomic_tenants,
|
||||
kind FULL,
|
||||
cron '@daily',
|
||||
grain tenant_id
|
||||
);
|
||||
|
||||
SELECT
|
||||
tenant ->> 'tenant_id' AS tenant_id,
|
||||
tenant ->> 'tenant_name' AS tenant_name,
|
||||
tenant -> 'address' ->> 'street' AS street,
|
||||
tenant -> 'address' ->> 'city' AS city,
|
||||
tenant -> 'address' ->> 'postal_code' AS postal_code,
|
||||
tenant -> 'address' ->> 'country_code' AS country_code,
|
||||
TRY_CAST(tenant -> 'address' ->> 'coordinate_lat' AS DOUBLE) AS lat,
|
||||
TRY_CAST(tenant -> 'address' ->> 'coordinate_lon' AS DOUBLE) AS lon,
|
||||
tenant ->> 'sport_ids' AS sport_ids_raw,
|
||||
tenant ->> 'tenant_type' AS tenant_type,
|
||||
filename AS source_file,
|
||||
CURRENT_DATE AS extracted_date
|
||||
FROM (
|
||||
SELECT
|
||||
UNNEST(tenants) AS tenant,
|
||||
filename
|
||||
FROM read_json(
|
||||
@LANDING_DIR || '/playtomic/*/*/tenants.json.gz',
|
||||
format = 'auto',
|
||||
filename = true
|
||||
)
|
||||
)
|
||||
WHERE (tenant ->> 'tenant_id') IS NOT NULL
|
||||
Reference in New Issue
Block a user