- serving/ice_aging_stocks.sql: pass-through from foundation, parses age bucket string to start/end days ints for correct sort order - serving/ice_warehouse_stocks_by_port.sql: monthly by-port since 1996, adds MoM change, MoM %, 12-month rolling average - analytics.py: get_ice_aging_latest(), get_ice_aging_trend(), get_ice_stocks_by_port_trend(), get_ice_stocks_by_port_latest() - api/routes.py: GET /commodities/<code>/stocks/aging and GET /commodities/<code>/stocks/by-port with auth + rate limiting - dashboard/routes.py: add 3 new queries to asyncio.gather(), pass to template - index.html: aging stacked bar chart (age buckets × port) with 4 metric cards; by-port stacked area chart (30-year history) with 4 metric cards Co-Authored-By: Claude Sonnet 4.6 <noreply@anthropic.com>
61 lines
1.6 KiB
SQL
61 lines
1.6 KiB
SQL
-- Serving mart: ICE certified Coffee C stock aging report, analytics-ready.
|
|
--
|
|
-- Shows the age distribution of certified stocks across delivery ports.
|
|
-- Age buckets represent how long coffee has been in certified storage.
|
|
-- Older stock approaching certificate limits is a supply quality signal.
|
|
--
|
|
-- Source: ICE Certified Stock Aging Report (monthly)
|
|
-- Grain: one row per (report_date, age_bucket).
|
|
|
|
MODEL (
|
|
name serving.ice_aging_stocks,
|
|
kind INCREMENTAL_BY_TIME_RANGE (
|
|
time_column report_date
|
|
),
|
|
grain (report_date, age_bucket),
|
|
start '2020-01-01',
|
|
cron '@daily'
|
|
);
|
|
|
|
WITH base AS (
|
|
SELECT
|
|
f.report_date,
|
|
f.age_bucket,
|
|
|
|
-- Parse age range from "0000 to 0120" format for correct sort order
|
|
TRY_CAST(split_part(f.age_bucket, ' to ', 1) AS int) AS age_bucket_start_days,
|
|
TRY_CAST(split_part(f.age_bucket, ' to ', 2) AS int) AS age_bucket_end_days,
|
|
|
|
f.antwerp_bags,
|
|
f.hamburg_bremen_bags,
|
|
f.houston_bags,
|
|
f.miami_bags,
|
|
f.new_orleans_bags,
|
|
f.new_york_bags,
|
|
f.total_bags,
|
|
|
|
f.source_file
|
|
FROM foundation.fct_ice_aging_stocks f
|
|
WHERE f.report_date BETWEEN @start_ds AND @end_ds
|
|
)
|
|
|
|
SELECT
|
|
b.report_date,
|
|
d.commodity_name,
|
|
d.ice_stock_report_code,
|
|
b.age_bucket,
|
|
b.age_bucket_start_days,
|
|
b.age_bucket_end_days,
|
|
b.antwerp_bags,
|
|
b.hamburg_bremen_bags,
|
|
b.houston_bags,
|
|
b.miami_bags,
|
|
b.new_orleans_bags,
|
|
b.new_york_bags,
|
|
b.total_bags,
|
|
b.source_file
|
|
FROM base b
|
|
CROSS JOIN foundation.dim_commodity d
|
|
WHERE d.ice_stock_report_code = 'COFFEE-C'
|
|
ORDER BY b.report_date, b.age_bucket_start_days
|