/* Foundation fact: daily weather observations for 8 coffee-growing regions. */ /* Source: OpenWeatherMap One Call API 3.0 / Day Summary */ /* Landing: LANDING_DIR/weather/{location_id}/{year}/{date}.json.gz */ /* One file per (location_id, date). Content: raw OWM day summary JSON. */ /* Each file is a single JSON object (not newline-delimited), so format='auto'. */ /* Grain: (location_id, observation_date) — one row per location per day. */ /* Dedup key: hash(location_id, date) — past weather is immutable. */ /* location_id is parsed from the filename path: split(filename, '/')[-3] */ /* Path structure: .../weather/{location_id}/{year}/{date}.json.gz */ /* Crop stress flags (agronomic thresholds for Arabica coffee): */ /* is_frost — temp_min_c < 2.0°C (ICO frost damage threshold) */ /* is_heat_stress — temp_max_c > 35.0°C (photosynthesis impairment) */ /* is_drought — precipitation_mm < 1.0 (dry day; OWM omits field when 0) */ /* in_growing_season — simplified month-range flag by variety */ MODEL ( name foundation.fct_weather_daily, kind INCREMENTAL_BY_TIME_RANGE ( time_column observation_date ), grain (location_id, observation_date), start '2020-01-01', cron '@daily' ); WITH src AS ( /* Each file is a single JSON object with nested fields: */ /* temperature.{min,max,afternoon,morning,evening,night} */ /* precipitation.total (absent when 0 — COALESCE to 0 downstream) */ /* humidity.afternoon */ /* cloud_cover.afternoon */ /* wind.max.{speed,direction} */ /* pressure.afternoon */ /* DuckDB read_json(format='auto') creates STRUCT columns for nested objects; */ /* fields are accessed with dot notation (temperature.min, wind.max.speed). */ SELECT * FROM READ_JSON(@weather_glob(), format = 'auto', compression = 'gzip', filename = TRUE) ), located AS ( SELECT src.*, STR_SPLIT(filename, '/')[-3] AS location_id, /* location_id is the 3rd-from-last path segment: */ /* e.g. .../weather/brazil_minas_gerais/2024/2024-01-15.json.gz → 'brazil_minas_gerais' */ TRY_CAST(src."date" AS DATE) AS observation_date FROM src ), cast_and_clean AS ( SELECT location_id, observation_date, TRY_CAST(located.temperature.min AS DOUBLE) AS temp_min_c, /* Temperature (°C, metric units) */ TRY_CAST(located.temperature.max AS DOUBLE) AS temp_max_c, TRY_CAST(located.temperature.afternoon AS DOUBLE) AS temp_afternoon_c, COALESCE(TRY_CAST(located.precipitation.total AS DOUBLE), 0.0) AS precipitation_mm, /* Precipitation (mm total for the day; OWM omits field when 0) */ TRY_CAST(located.humidity.afternoon AS DOUBLE) AS humidity_afternoon_pct, /* Humidity (% afternoon reading) */ TRY_CAST(located.cloud_cover.afternoon AS DOUBLE) AS cloud_cover_afternoon_pct, /* Cloud cover (% afternoon) */ TRY_CAST(located.wind.max.speed AS DOUBLE) AS wind_max_speed_ms, /* Wind (m/s max speed, degrees direction) */ TRY_CAST(located.pressure.afternoon AS DOUBLE) AS pressure_afternoon_hpa, /* Pressure (hPa afternoon) */ TRY_CAST(located.temperature.min AS DOUBLE) /* Crop stress flags */ < 2.0 AS is_frost, TRY_CAST(located.temperature.max AS DOUBLE) > 35.0 AS is_heat_stress, COALESCE(TRY_CAST(located.precipitation.total AS DOUBLE), 0.0) < 1.0 AS is_drought, HASH(location_id, src."date") AS hkey, filename FROM located WHERE NOT observation_date IS NULL AND NOT location_id IS NULL AND location_id <> '' ), deduplicated AS ( SELECT ANY_VALUE(location_id) AS location_id, ANY_VALUE(observation_date) AS observation_date, ANY_VALUE(temp_min_c) AS temp_min_c, ANY_VALUE(temp_max_c) AS temp_max_c, ANY_VALUE(temp_afternoon_c) AS temp_afternoon_c, ANY_VALUE(precipitation_mm) AS precipitation_mm, ANY_VALUE(humidity_afternoon_pct) AS humidity_afternoon_pct, ANY_VALUE(cloud_cover_afternoon_pct) AS cloud_cover_afternoon_pct, ANY_VALUE(wind_max_speed_ms) AS wind_max_speed_ms, ANY_VALUE(pressure_afternoon_hpa) AS pressure_afternoon_hpa, ANY_VALUE(is_frost) AS is_frost, ANY_VALUE(is_heat_stress) AS is_heat_stress, ANY_VALUE(is_drought) AS is_drought, hkey FROM cast_and_clean GROUP BY hkey ) SELECT d.observation_date, d.location_id, loc.name AS location_name, loc.country, loc.lat, loc.lon, loc.variety, d.temp_min_c, d.temp_max_c, d.temp_afternoon_c, d.precipitation_mm, d.humidity_afternoon_pct, d.cloud_cover_afternoon_pct, d.wind_max_speed_ms, d.pressure_afternoon_hpa, d.is_frost, d.is_heat_stress, d.is_drought, CASE loc.variety WHEN 'Arabica' THEN EXTRACT(MONTH FROM d.observation_date) BETWEEN 4 AND 10 WHEN 'Robusta' THEN EXTRACT(MONTH FROM d.observation_date) BETWEEN 4 AND 11 ELSE FALSE END AS in_growing_season /* Growing season: simplified month-range flag by variety. */ /* Arabica: Apr–Oct (covers northern + southern hemisphere risk windows). */ /* Robusta: Apr–Nov (Vietnam/Indonesia main cycle). */ FROM deduplicated AS d LEFT JOIN seeds.weather_locations AS loc ON d.location_id = loc.location_id WHERE d.observation_date BETWEEN @start_ds AND @end_ds