-- Serving mart: ICE certified Coffee C warehouse stocks, analytics-ready. -- -- Adds 30-day rolling average, week-over-week change, and drawdown from -- 52-week high. Physical supply indicator used alongside S/D and positioning. -- -- "Certified stocks" = coffee graded and stamped as eligible for delivery -- against ICE Coffee C futures — traders watch this as a squeeze indicator. -- -- Grain: one row per report_date. MODEL ( name serving.ice_warehouse_stocks, kind INCREMENTAL_BY_TIME_RANGE ( time_column report_date ), grain (report_date), start '2000-01-01', cron '@daily' ); WITH base AS ( SELECT f.report_date, f.total_certified_bags, f.pending_grading_bags, -- Week-over-week change (compare to 7 calendar days ago via LAG over ordered rows) -- Using LAG(1) since data is daily: compares to previous trading/reporting day f.total_certified_bags - LAG(f.total_certified_bags, 1) OVER (ORDER BY f.report_date) AS wow_change_bags, -- 30-day rolling average (smooths daily noise) round( AVG(f.total_certified_bags::double) OVER ( ORDER BY f.report_date ROWS BETWEEN 29 PRECEDING AND CURRENT ROW ), 0 ) AS avg_30d_bags, -- 52-week high (365 calendar days ≈ 252 trading days; use 365-row window as proxy) MAX(f.total_certified_bags) OVER ( ORDER BY f.report_date ROWS BETWEEN 364 PRECEDING AND CURRENT ROW ) AS high_52w_bags, -- Drawdown from 52-week high (pct below peak — squeeze indicator) round( (f.total_certified_bags::double - MAX(f.total_certified_bags) OVER ( ORDER BY f.report_date ROWS BETWEEN 364 PRECEDING AND CURRENT ROW )::double ) / NULLIF( MAX(f.total_certified_bags) OVER ( ORDER BY f.report_date ROWS BETWEEN 364 PRECEDING AND CURRENT ROW )::double, 0 ) * 100, 2 ) AS drawdown_from_52w_high_pct FROM foundation.fct_ice_warehouse_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.total_certified_bags, b.pending_grading_bags, b.wow_change_bags, b.avg_30d_bags, b.high_52w_bags, b.drawdown_from_52w_high_pct FROM base b CROSS JOIN foundation.dim_commodity d WHERE d.ice_stock_report_code = 'COFFEE-C' ORDER BY b.report_date