Add Phase 1A-C + ICE warehouse stocks: prices, methodology, pipeline automation

Phase 1A — KC=F Coffee Futures Prices:
- New extract/coffee_prices/ package (yfinance): downloads KC=F daily OHLCV,
  stores as gzip CSV with SHA256-based idempotency
- SQLMesh models: raw/coffee_prices → foundation/fct_coffee_prices →
  serving/coffee_prices (with 20d/50d SMA, 52-week high/low, daily return %)
- Dashboard: 4 metric cards + dual-line chart (close, 20d MA, 50d MA)
- API: GET /commodities/<ticker>/prices

Phase 1B — Data Methodology Page:
- New /methodology route with full-page template (base.html)
- 6 anchored sections: USDA PSD, CFTC COT, KC=F price, ICE warehouse stocks,
  data quality model, update schedule table
- "Methodology" link added to marketing footer

Phase 1C — Automated Pipeline:
- supervisor.sh updated: runs extract_cot, extract_prices, extract_ice in
  sequence before transform
- Webhook failure alerting via ALERT_WEBHOOK_URL env var (ntfy/Slack/Telegram)

ICE Warehouse Stocks:
- New extract/ice_stocks/ package (niquests): normalizes ICE Report Center CSV
  to canonical schema, hash-based idempotency, soft-fail on 404 with guidance
- SQLMesh models: raw/ice_warehouse_stocks → foundation/fct_ice_warehouse_stocks
  → serving/ice_warehouse_stocks (30d avg, WoW change, 52w drawdown)
- Dashboard: 4 metric cards + line chart (certified bags + 30d avg)
- API: GET /commodities/<code>/stocks

Foundation:
- dim_commodity: added ticker (KC=F) and ice_stock_report_code (COFFEE-C) columns
- macros/__init__.py: added prices_glob() and ice_stocks_glob()
- pipelines.py: added extract_prices and extract_ice entries

Co-Authored-By: Claude Sonnet 4.6 <noreply@anthropic.com>
This commit is contained in:
Deeman
2026-02-21 11:41:43 +01:00
parent 2962bf5e3b
commit 67c048485b
25 changed files with 1350 additions and 6 deletions

View File

@@ -15,3 +15,17 @@ def cot_glob(evaluator) -> str:
"""Return a quoted glob path for all COT CSV gzip files under LANDING_DIR."""
landing_dir = evaluator.var("LANDING_DIR") or os.environ.get("LANDING_DIR", "data/landing")
return f"'{landing_dir}/cot/**/*.csv.gzip'"
@macro()
def prices_glob(evaluator) -> str:
"""Return a quoted glob path for all coffee price CSV gzip files under LANDING_DIR."""
landing_dir = evaluator.var("LANDING_DIR") or os.environ.get("LANDING_DIR", "data/landing")
return f"'{landing_dir}/prices/coffee_kc/**/*.csv.gzip'"
@macro()
def ice_stocks_glob(evaluator) -> str:
"""Return a quoted glob path for all ICE warehouse stock CSV gzip files under LANDING_DIR."""
landing_dir = evaluator.var("LANDING_DIR") or os.environ.get("LANDING_DIR", "data/landing")
return f"'{landing_dir}/ice_stocks/**/*.csv.gzip'"

View File

@@ -17,7 +17,7 @@ MODEL (
kind FULL
);
SELECT usda_commodity_code, cftc_commodity_code, commodity_name, commodity_group
SELECT usda_commodity_code, cftc_commodity_code, ticker, ice_stock_report_code, commodity_name, commodity_group
FROM (VALUES
('0711100', '083', 'Coffee, Green', 'Softs')
) AS t(usda_commodity_code, cftc_commodity_code, commodity_name, commodity_group)
('0711100', '083', 'KC=F', 'COFFEE-C', 'Coffee, Green', 'Softs')
) AS t(usda_commodity_code, cftc_commodity_code, ticker, ice_stock_report_code, commodity_name, commodity_group)

View File

@@ -0,0 +1,57 @@
-- Foundation fact: daily KC=F Coffee C futures prices.
--
-- Casts raw varchar columns to proper types and deduplicates via hash key.
-- Covers all available history from the landing directory.
--
-- Grain: one row per trade_date.
-- Dedup: hash of (trade_date, close) — if Yahoo Finance corrects a price,
-- the new hash triggers a re-ingest on the next incremental run.
MODEL (
name foundation.fct_coffee_prices,
kind INCREMENTAL_BY_TIME_RANGE (
time_column trade_date
),
grain (trade_date),
start '1971-08-16',
cron '@daily'
);
WITH cast_and_clean AS (
SELECT
TRY_CAST(Date AS date) AS trade_date,
TRY_CAST(Open AS double) AS open,
TRY_CAST(High AS double) AS high,
TRY_CAST(Low AS double) AS low,
TRY_CAST(Close AS double) AS close,
TRY_CAST(Adj_Close AS double) AS adj_close,
TRY_CAST(Volume AS bigint) AS volume,
-- Filename encodes the content hash — use as ingest identifier
filename AS source_file,
-- Dedup key: trade date + close price
hash(Date, Close) AS hkey
FROM raw.coffee_prices
WHERE TRY_CAST(Date AS date) IS NOT NULL
AND TRY_CAST(Close AS double) IS NOT NULL
),
deduplicated AS (
SELECT
any_value(trade_date) AS trade_date,
any_value(open) AS open,
any_value(high) AS high,
any_value(low) AS low,
any_value(close) AS close,
any_value(adj_close) AS adj_close,
any_value(volume) AS volume,
any_value(source_file) AS source_file,
hkey
FROM cast_and_clean
GROUP BY hkey
)
SELECT *
FROM deduplicated
WHERE trade_date BETWEEN @start_ds AND @end_ds

View File

@@ -0,0 +1,47 @@
-- Foundation fact: ICE certified Coffee C (Arabica) warehouse stocks.
--
-- Casts raw varchar columns to proper types and deduplicates via hash key.
-- "Certified" means Coffee C graded and stamped as delivery-eligible
-- against ICE futures contracts — a key physical supply indicator.
--
-- Grain: one row per report_date.
MODEL (
name foundation.fct_ice_warehouse_stocks,
kind INCREMENTAL_BY_TIME_RANGE (
time_column report_date
),
grain (report_date),
start '2000-01-01',
cron '@daily'
);
WITH cast_and_clean AS (
SELECT
TRY_CAST(report_date AS date) AS report_date,
TRY_CAST(total_certified_bags AS bigint) AS total_certified_bags,
TRY_CAST(pending_grading_bags AS bigint) AS pending_grading_bags,
filename AS source_file,
-- Dedup key: report date + total bags
hash(report_date, total_certified_bags) AS hkey
FROM raw.ice_warehouse_stocks
WHERE TRY_CAST(report_date AS date) IS NOT NULL
AND TRY_CAST(total_certified_bags AS bigint) IS NOT NULL
),
deduplicated AS (
SELECT
any_value(report_date) AS report_date,
any_value(total_certified_bags) AS total_certified_bags,
any_value(pending_grading_bags) AS pending_grading_bags,
any_value(source_file) AS source_file,
hkey
FROM cast_and_clean
GROUP BY hkey
)
SELECT *
FROM deduplicated
WHERE report_date BETWEEN @start_ds AND @end_ds

View File

@@ -0,0 +1,46 @@
-- Raw KC=F Coffee C futures prices — technical ingestion layer.
--
-- Reads daily OHLCV gzip CSVs from the landing directory. All values are
-- varchar; casting happens in foundation.fct_coffee_prices.
--
-- Source: Yahoo Finance via yfinance (KC=F ticker)
-- Coverage: 1971-present (historical futures data)
-- Frequency: daily (trading days only)
MODEL (
name raw.coffee_prices,
kind FULL,
grain (Date),
cron '@daily',
columns (
Date varchar,
Open varchar,
High varchar,
Low varchar,
Close varchar,
Adj_Close varchar,
Volume varchar,
filename varchar
)
);
SELECT
"Date" AS Date,
"Open" AS Open,
"High" AS High,
"Low" AS Low,
"Close" AS Close,
"Adj Close" AS Adj_Close,
"Volume" AS Volume,
filename
FROM read_csv(
@prices_glob(),
delim = ',',
encoding = 'utf-8',
compression = 'gzip',
header = true,
union_by_name = true,
filename = true,
all_varchar = true,
ignore_errors = true
)

View File

@@ -0,0 +1,37 @@
-- Raw ICE certified warehouse stocks — technical ingestion layer.
--
-- Reads daily stock report gzip CSVs from the landing directory.
-- All values are varchar; casting happens in foundation.fct_ice_warehouse_stocks.
--
-- Source: ICE Report Center (Coffee C certified warehouse stocks)
-- Coverage: varies by download history
-- Frequency: daily (ICE updates after market close)
MODEL (
name raw.ice_warehouse_stocks,
kind FULL,
cron '@daily',
columns (
report_date varchar,
total_certified_bags varchar,
pending_grading_bags varchar,
filename varchar
)
);
SELECT
report_date,
total_certified_bags,
pending_grading_bags,
filename
FROM read_csv(
@ice_stocks_glob(),
delim = ',',
encoding = 'utf-8',
compression = 'gzip',
header = true,
union_by_name = true,
filename = true,
all_varchar = true,
ignore_errors = true
)

View File

@@ -0,0 +1,77 @@
-- Serving mart: KC=F Coffee C futures prices, analytics-ready.
--
-- Adds moving averages (20-day, 50-day SMA) and 52-week high/low range.
-- Filtered to trading days only (NULL close rows excluded upstream).
--
-- Grain: one row per trade_date.
MODEL (
name serving.coffee_prices,
kind INCREMENTAL_BY_TIME_RANGE (
time_column trade_date
),
grain (trade_date),
start '1971-08-16',
cron '@daily'
);
WITH base AS (
SELECT
f.trade_date,
f.open,
f.high,
f.low,
f.close,
f.adj_close,
f.volume,
-- Daily return: (close - prev_close) / prev_close * 100
round(
(f.close - LAG(f.close, 1) OVER (ORDER BY f.trade_date))
/ NULLIF(LAG(f.close, 1) OVER (ORDER BY f.trade_date), 0) * 100,
4
) AS daily_return_pct,
-- 20-day simple moving average (1 trading month)
round(
AVG(f.close) OVER (ORDER BY f.trade_date ROWS BETWEEN 19 PRECEDING AND CURRENT ROW),
4
) AS sma_20d,
-- 50-day simple moving average (2.5 trading months)
round(
AVG(f.close) OVER (ORDER BY f.trade_date ROWS BETWEEN 49 PRECEDING AND CURRENT ROW),
4
) AS sma_50d,
-- 52-week high (approximately 252 trading days)
MAX(f.high) OVER (ORDER BY f.trade_date ROWS BETWEEN 251 PRECEDING AND CURRENT ROW)
AS high_52w,
-- 52-week low
MIN(f.low) OVER (ORDER BY f.trade_date ROWS BETWEEN 251 PRECEDING AND CURRENT ROW)
AS low_52w
FROM foundation.fct_coffee_prices f
WHERE f.trade_date BETWEEN @start_ds AND @end_ds
)
SELECT
b.trade_date,
d.commodity_name,
d.ticker,
b.open,
b.high,
b.low,
b.close,
b.adj_close,
b.volume,
b.daily_return_pct,
b.sma_20d,
b.sma_50d,
b.high_52w,
b.low_52w
FROM base b
CROSS JOIN foundation.dim_commodity d
WHERE d.ticker = 'KC=F'
ORDER BY b.trade_date

View File

@@ -0,0 +1,78 @@
-- 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