Implements per-store high-frequency crawl scheduling and inventory snapshot tracking for sales velocity estimation (Hoodie Analytics parity). Database migrations: - 117: Per-store crawl_interval_minutes and next_crawl_at columns - 118: inventory_snapshots table (30-day retention) - 119: product_visibility_events table for OOS/brand alerts (90-day) Backend changes: - inventory-snapshots.ts: Shared utility normalizing Dutchie/Jane/Treez - visibility-events.ts: Detects OOS, price changes, brand drops - task-scheduler.ts: checkHighFrequencyStores() runs every 60s - Handler updates: 2-line additions to save snapshots/events API endpoints: - GET /api/tasks/schedules/high-frequency - PUT /api/tasks/schedules/high-frequency/:id - DELETE /api/tasks/schedules/high-frequency/:id Frontend: - TasksDashboard: Per-Store Schedules section with stats Features: - Per-store intervals (15/30/60 min configurable) - Jitter (0-20%) to avoid detection patterns - Cross-platform support (Dutchie, Jane, Treez) - No crawler core changes - scheduling/post-crawl only 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
49 lines
2.3 KiB
SQL
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)
|
|
CREATE INDEX idx_inv_snap_cleanup ON inventory_snapshots(captured_at) WHERE captured_at < NOW() - INTERVAL '30 days';
|
|
|
|
-- 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)';
|