Add CFTC COT data integration with foundation data model layer

- New extraction package (cftc_cot): downloads yearly Disaggregated Futures ZIPs
  from CFTC, etag-based dedup, dynamic inner filename discovery, gzip normalization
- SQLMesh 3-layer architecture: raw (technical) → foundation (business model) → serving (mart)
- dim_commodity seed: conformed dimension mapping USDA ↔ CFTC codes — the commodity ontology
- fct_cot_positioning: typed, deduplicated weekly positioning facts for all commodities
- obt_cot_positioning: Coffee C mart with COT Index (26w/52w), WoW delta, OI ratios
- Analytics functions + REST API endpoints: /commodities/<code>/positioning[/latest]
- Dashboard widget: Managed Money net, COT Index card, dual-axis Chart.js chart
- 23 passing tests (10 unit + 2 SQLMesh model + existing regression suite)

Co-Authored-By: Claude Sonnet 4.6 <noreply@anthropic.com>
This commit is contained in:
Deeman
2026-02-20 21:57:04 +01:00
parent d09ba91023
commit 0a83b2cb74
19 changed files with 1111 additions and 3 deletions

View File

@@ -0,0 +1,24 @@
-- Commodity dimension: conforms identifiers across source systems.
--
-- This is the ontology seed. Each row is a commodity tracked by BeanFlows.
-- As new sources are added (ICO, futures prices, satellite), their
-- commodity identifiers are added as columns here — not as separate tables.
-- As new commodities are added (cocoa, sugar), rows are added here.
--
-- References:
-- usda_commodity_code → raw.psd_alldata.commodity_code
-- cftc_commodity_code → raw.cot_disaggregated.cftc_commodity_code
MODEL (
name foundation.dim_commodity,
kind SEED (
path '$root/seeds/dim_commodity.csv',
csv_settings (delimiter = ';')
),
columns (
usda_commodity_code varchar,
cftc_commodity_code varchar,
commodity_name varchar,
commodity_group varchar
)
);

View File

@@ -0,0 +1,160 @@
-- Foundation fact: CFTC COT positioning, weekly grain, all commodities.
--
-- Casts raw varchar columns to proper types, cleans column names,
-- computes net positions (long - short) per trader category, and
-- deduplicates via hash key. Covers all commodities — filtering to
-- a specific commodity happens in the serving layer.
--
-- Grain: one row per (cftc_commodity_code, report_date, cftc_contract_market_code)
-- History: revisions appear as new rows with a later ingest_date.
-- Serving layer picks max(ingest_date) per grain for latest view.
MODEL (
name foundation.fct_cot_positioning,
kind INCREMENTAL_BY_TIME_RANGE (
time_column report_date
),
grain (cftc_commodity_code, report_date, cftc_contract_market_code, ingest_date),
start '2006-06-13',
cron '@daily'
);
WITH cast_and_clean AS (
SELECT
-- Identifiers
trim(market_and_exchange_names) AS market_and_exchange_name,
report_date_as_yyyy_mm_dd::date AS report_date,
trim(cftc_commodity_code) AS cftc_commodity_code,
trim(cftc_contract_market_code) AS cftc_contract_market_code,
trim(contract_units) AS contract_units,
-- Open interest
open_interest_all::int AS open_interest,
-- Producer / Merchant (commercial hedgers: exporters, processors)
prod_merc_positions_long_all::int AS prod_merc_long,
prod_merc_positions_short_all::int AS prod_merc_short,
-- Swap dealers
swap_positions_long_all::int AS swap_long,
swap_positions_short_all::int AS swap_short,
swap_positions_spread_all::int AS swap_spread,
-- Managed money (hedge funds, CTAs — the primary speculative signal)
m_money_positions_long_all::int AS managed_money_long,
m_money_positions_short_all::int AS managed_money_short,
m_money_positions_spread_all::int AS managed_money_spread,
-- Other reportables
other_rept_positions_long_all::int AS other_reportable_long,
other_rept_positions_short_all::int AS other_reportable_short,
other_rept_positions_spread_all::int AS other_reportable_spread,
-- Non-reportable (small speculators, below reporting threshold)
nonrept_positions_long_all::int AS nonreportable_long,
nonrept_positions_short_all::int AS nonreportable_short,
-- Net positions (long minus short per category)
prod_merc_positions_long_all::int
- prod_merc_positions_short_all::int AS prod_merc_net,
m_money_positions_long_all::int
- m_money_positions_short_all::int AS managed_money_net,
swap_positions_long_all::int
- swap_positions_short_all::int AS swap_net,
other_rept_positions_long_all::int
- other_rept_positions_short_all::int AS other_reportable_net,
nonrept_positions_long_all::int
- nonrept_positions_short_all::int AS nonreportable_net,
-- Week-over-week changes
change_in_open_interest_all::int AS change_open_interest,
change_in_m_money_long_all::int AS change_managed_money_long,
change_in_m_money_short_all::int AS change_managed_money_short,
change_in_m_money_long_all::int
- change_in_m_money_short_all::int AS change_managed_money_net,
change_in_prod_merc_long_all::int AS change_prod_merc_long,
change_in_prod_merc_short_all::int AS change_prod_merc_short,
-- Concentration ratios (% of OI held by top 4 / top 8 traders)
conc_gross_le_4_tdr_long_all::float AS concentration_top4_long_pct,
conc_gross_le_4_tdr_short_all::float AS concentration_top4_short_pct,
conc_gross_le_8_tdr_long_all::float AS concentration_top8_long_pct,
conc_gross_le_8_tdr_short_all::float AS concentration_top8_short_pct,
-- Trader counts
traders_tot_all::int AS traders_total,
traders_m_money_long_all::int AS traders_managed_money_long,
traders_m_money_short_all::int AS traders_managed_money_short,
traders_m_money_spread_all::int AS traders_managed_money_spread,
-- Ingest date: derived from landing path year directory
-- Path: .../cot/{year}/{etag}.csv.gzip → extract year from [-2]
make_date(split(filename, '/')[-2]::int, 1, 1) AS ingest_date,
-- Dedup key: hash of business grain + key metrics
hash(
cftc_commodity_code,
report_date_as_yyyy_mm_dd,
cftc_contract_market_code,
open_interest_all,
m_money_positions_long_all,
m_money_positions_short_all,
prod_merc_positions_long_all,
prod_merc_positions_short_all
) AS hkey
FROM raw.cot_disaggregated
-- Reject rows with null commodity code or malformed date
WHERE trim(cftc_commodity_code) IS NOT NULL
AND len(trim(cftc_commodity_code)) > 0
AND report_date_as_yyyy_mm_dd::date IS NOT NULL
),
deduplicated AS (
SELECT
any_value(market_and_exchange_name) AS market_and_exchange_name,
any_value(report_date) AS report_date,
any_value(cftc_commodity_code) AS cftc_commodity_code,
any_value(cftc_contract_market_code) AS cftc_contract_market_code,
any_value(contract_units) AS contract_units,
any_value(open_interest) AS open_interest,
any_value(prod_merc_long) AS prod_merc_long,
any_value(prod_merc_short) AS prod_merc_short,
any_value(prod_merc_net) AS prod_merc_net,
any_value(swap_long) AS swap_long,
any_value(swap_short) AS swap_short,
any_value(swap_spread) AS swap_spread,
any_value(swap_net) AS swap_net,
any_value(managed_money_long) AS managed_money_long,
any_value(managed_money_short) AS managed_money_short,
any_value(managed_money_spread) AS managed_money_spread,
any_value(managed_money_net) AS managed_money_net,
any_value(other_reportable_long) AS other_reportable_long,
any_value(other_reportable_short) AS other_reportable_short,
any_value(other_reportable_spread) AS other_reportable_spread,
any_value(other_reportable_net) AS other_reportable_net,
any_value(nonreportable_long) AS nonreportable_long,
any_value(nonreportable_short) AS nonreportable_short,
any_value(nonreportable_net) AS nonreportable_net,
any_value(change_open_interest) AS change_open_interest,
any_value(change_managed_money_long) AS change_managed_money_long,
any_value(change_managed_money_short) AS change_managed_money_short,
any_value(change_managed_money_net) AS change_managed_money_net,
any_value(change_prod_merc_long) AS change_prod_merc_long,
any_value(change_prod_merc_short) AS change_prod_merc_short,
any_value(concentration_top4_long_pct) AS concentration_top4_long_pct,
any_value(concentration_top4_short_pct) AS concentration_top4_short_pct,
any_value(concentration_top8_long_pct) AS concentration_top8_long_pct,
any_value(concentration_top8_short_pct) AS concentration_top8_short_pct,
any_value(traders_total) AS traders_total,
any_value(traders_managed_money_long) AS traders_managed_money_long,
any_value(traders_managed_money_short) AS traders_managed_money_short,
any_value(traders_managed_money_spread) AS traders_managed_money_spread,
any_value(ingest_date) AS ingest_date,
hkey
FROM cast_and_clean
GROUP BY hkey
)
SELECT *
FROM deduplicated
WHERE report_date BETWEEN @start_ds AND @end_ds