Files
cannaiq/backend/migrations/118_inventory_snapshots.sql
Kelly 294d3db7a2 fix: Remove NOW() from partial indexes (not immutable)
🤖 Generated with [Claude Code](https://claude.com/claude-code)

Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
2025-12-14 15:58:05 -07:00

49 lines
2.3 KiB
SQL

-- Migration 118: Inventory snapshots table
-- Lightweight per-product tracking for sales velocity estimation
-- Part of Real-Time Inventory Tracking feature
CREATE TABLE IF NOT EXISTS inventory_snapshots (
id BIGSERIAL PRIMARY KEY,
dispensary_id INT NOT NULL REFERENCES dispensaries(id) ON DELETE CASCADE,
product_id TEXT NOT NULL, -- provider_product_id (normalized across platforms)
captured_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
-- Platform (for debugging/filtering)
platform TEXT NOT NULL, -- 'dutchie' | 'jane' | 'treez'
-- Inventory fields (normalized from all platforms)
quantity_available INT, -- Dutchie: quantityAvailable, Jane: quantity, Treez: quantityAvailable
is_below_threshold BOOLEAN, -- Dutchie: isBelowThreshold, Jane: computed, Treez: lowInventory
status TEXT, -- Active/Inactive/available
-- Price fields (normalized)
price_rec NUMERIC(10,2), -- recreational price
price_med NUMERIC(10,2), -- medical price (if different)
-- Denormalized for fast queries
brand_name TEXT,
category TEXT,
product_name TEXT
);
-- Primary query: get snapshots for a store over time
CREATE INDEX idx_inv_snap_store_time ON inventory_snapshots(dispensary_id, captured_at DESC);
-- Delta calculation: get consecutive snapshots for a product
CREATE INDEX idx_inv_snap_product_time ON inventory_snapshots(dispensary_id, product_id, captured_at DESC);
-- Brand-level analytics
CREATE INDEX idx_inv_snap_brand_time ON inventory_snapshots(brand_name, captured_at DESC) WHERE brand_name IS NOT NULL;
-- Platform filtering
CREATE INDEX idx_inv_snap_platform ON inventory_snapshots(platform, captured_at DESC);
-- Retention cleanup (30 days) - simple index, cleanup job handles the WHERE
CREATE INDEX IF NOT EXISTS idx_inv_snap_cleanup ON inventory_snapshots(captured_at);
-- Comments
COMMENT ON TABLE inventory_snapshots IS 'Lightweight inventory snapshots for sales velocity tracking. Retained 30 days.';
COMMENT ON COLUMN inventory_snapshots.product_id IS 'Provider product ID, normalized across platforms';
COMMENT ON COLUMN inventory_snapshots.platform IS 'Menu platform: dutchie, jane, or treez';
COMMENT ON COLUMN inventory_snapshots.quantity_available IS 'Current quantity in stock (Dutchie: quantityAvailable, Jane: quantity)';