-- 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.';