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:
@@ -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)
|
||||
|
||||
@@ -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
|
||||
@@ -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
|
||||
Reference in New Issue
Block a user