Files
cannaiq/backend/migrations/124_timescaledb_snapshots.sql
Kelly 9f3bc8a843
Some checks failed
ci/woodpecker/push/woodpecker Pipeline failed
fix: Worker task concurrency limit and inventory tracking
- Fix claim_task to enforce max 5 tasks per worker (was unlimited)
- Add session_task_count check before ANY claiming path
- Add triggers to auto-decrement count on task complete/release
- Update MAX_CONCURRENT_TASKS default from 3 to 5
- Update frontend fallback to show 5 task slots

- Add Wasabi S3 storage for payload archival
- Add inventory snapshots service (delta-only tracking)
- Add sales analytics views and routes
- Add high-frequency manager UI components
- Reset hardcoded AZ 5-minute intervals (use UI to configure)

🤖 Generated with [Claude Code](https://claude.com/claude-code)

Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
2025-12-17 01:34:38 -07:00

74 lines
3.3 KiB
SQL

-- Migration 124: Convert inventory_snapshots to TimescaleDB hypertable
-- Requires: CREATE EXTENSION timescaledb; (run after installing TimescaleDB)
-- ============================================================
-- STEP 1: Enable TimescaleDB extension
-- ============================================================
CREATE EXTENSION IF NOT EXISTS timescaledb;
-- ============================================================
-- STEP 2: Convert to hypertable
-- ============================================================
-- Note: Table must have a time column and no foreign key constraints
-- First, drop any foreign keys if they exist
ALTER TABLE inventory_snapshots DROP CONSTRAINT IF EXISTS inventory_snapshots_dispensary_id_fkey;
-- Convert to hypertable, partitioned by captured_at (1 day chunks)
SELECT create_hypertable(
'inventory_snapshots',
'captured_at',
chunk_time_interval => INTERVAL '1 day',
if_not_exists => TRUE,
migrate_data => TRUE
);
-- ============================================================
-- STEP 3: Enable compression
-- ============================================================
-- Compress by dispensary_id and product_id (common query patterns)
ALTER TABLE inventory_snapshots SET (
timescaledb.compress,
timescaledb.compress_segmentby = 'dispensary_id, product_id',
timescaledb.compress_orderby = 'captured_at DESC'
);
-- ============================================================
-- STEP 4: Compression policy (compress chunks older than 1 day)
-- ============================================================
SELECT add_compression_policy('inventory_snapshots', INTERVAL '1 day');
-- ============================================================
-- STEP 5: Retention policy (optional - drop chunks older than 90 days)
-- ============================================================
-- Uncomment if you want automatic cleanup:
-- SELECT add_retention_policy('inventory_snapshots', INTERVAL '90 days');
-- ============================================================
-- STEP 6: Optimize indexes for time-series queries
-- ============================================================
-- TimescaleDB automatically creates time-based indexes
-- Add composite index for common queries
CREATE INDEX IF NOT EXISTS idx_snapshots_disp_prod_time
ON inventory_snapshots (dispensary_id, product_id, captured_at DESC);
-- ============================================================
-- VERIFICATION QUERIES (run after migration)
-- ============================================================
-- Check hypertable status:
-- SELECT * FROM timescaledb_information.hypertables WHERE hypertable_name = 'inventory_snapshots';
-- Check compression status:
-- SELECT * FROM timescaledb_information.compression_settings WHERE hypertable_name = 'inventory_snapshots';
-- Check chunk sizes:
-- SELECT chunk_name, pg_size_pretty(before_compression_total_bytes) as before,
-- pg_size_pretty(after_compression_total_bytes) as after,
-- round(100 - (after_compression_total_bytes::numeric / before_compression_total_bytes * 100), 1) as compression_pct
-- FROM chunk_compression_stats('inventory_snapshots');
-- ============================================================
-- COMMENTS
-- ============================================================
COMMENT ON TABLE inventory_snapshots IS 'TimescaleDB hypertable for inventory time-series data. Compressed after 1 day.';