Some checks failed
ci/woodpecker/push/woodpecker Pipeline failed
- 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>
403 lines
15 KiB
PL/PgSQL
403 lines
15 KiB
PL/PgSQL
-- Migration 125: Delta-only inventory snapshots
|
||
-- Only store a row when something meaningful changes
|
||
-- Revenue calculated as: effective_price × qty_sold
|
||
|
||
-- ============================================================
|
||
-- ADD DELTA TRACKING COLUMNS
|
||
-- ============================================================
|
||
|
||
-- Previous values (to show what changed)
|
||
ALTER TABLE inventory_snapshots ADD COLUMN IF NOT EXISTS prev_quantity INTEGER;
|
||
ALTER TABLE inventory_snapshots ADD COLUMN IF NOT EXISTS prev_price_rec DECIMAL(10,2);
|
||
ALTER TABLE inventory_snapshots ADD COLUMN IF NOT EXISTS prev_price_med DECIMAL(10,2);
|
||
ALTER TABLE inventory_snapshots ADD COLUMN IF NOT EXISTS prev_status VARCHAR(50);
|
||
|
||
-- Calculated deltas
|
||
ALTER TABLE inventory_snapshots ADD COLUMN IF NOT EXISTS qty_delta INTEGER; -- negative = sold, positive = restocked
|
||
ALTER TABLE inventory_snapshots ADD COLUMN IF NOT EXISTS price_delta DECIMAL(10,2);
|
||
|
||
-- Change type flags
|
||
ALTER TABLE inventory_snapshots ADD COLUMN IF NOT EXISTS change_type VARCHAR(50); -- 'sale', 'restock', 'price_change', 'oos', 'back_in_stock'
|
||
|
||
-- ============================================================
|
||
-- INDEX FOR CHANGE TYPE QUERIES
|
||
-- ============================================================
|
||
CREATE INDEX IF NOT EXISTS idx_snapshots_change_type ON inventory_snapshots(change_type);
|
||
CREATE INDEX IF NOT EXISTS idx_snapshots_qty_delta ON inventory_snapshots(qty_delta) WHERE qty_delta != 0;
|
||
|
||
-- ============================================================
|
||
-- VIEW: Latest product state (for delta comparison)
|
||
-- ============================================================
|
||
CREATE OR REPLACE VIEW v_product_latest_state AS
|
||
SELECT DISTINCT ON (dispensary_id, product_id)
|
||
dispensary_id,
|
||
product_id,
|
||
quantity_available,
|
||
price_rec,
|
||
price_med,
|
||
status,
|
||
captured_at
|
||
FROM inventory_snapshots
|
||
ORDER BY dispensary_id, product_id, captured_at DESC;
|
||
|
||
-- ============================================================
|
||
-- FUNCTION: Check if product state changed
|
||
-- ============================================================
|
||
CREATE OR REPLACE FUNCTION should_capture_snapshot(
|
||
p_dispensary_id INTEGER,
|
||
p_product_id TEXT,
|
||
p_quantity INTEGER,
|
||
p_price_rec DECIMAL,
|
||
p_price_med DECIMAL,
|
||
p_status VARCHAR
|
||
) RETURNS TABLE (
|
||
should_capture BOOLEAN,
|
||
prev_quantity INTEGER,
|
||
prev_price_rec DECIMAL,
|
||
prev_price_med DECIMAL,
|
||
prev_status VARCHAR,
|
||
qty_delta INTEGER,
|
||
price_delta DECIMAL,
|
||
change_type VARCHAR
|
||
) AS $$
|
||
DECLARE
|
||
v_prev RECORD;
|
||
BEGIN
|
||
-- Get previous state
|
||
SELECT
|
||
ls.quantity_available,
|
||
ls.price_rec,
|
||
ls.price_med,
|
||
ls.status
|
||
INTO v_prev
|
||
FROM v_product_latest_state ls
|
||
WHERE ls.dispensary_id = p_dispensary_id
|
||
AND ls.product_id = p_product_id;
|
||
|
||
-- First time seeing this product
|
||
IF NOT FOUND THEN
|
||
RETURN QUERY SELECT
|
||
TRUE,
|
||
NULL::INTEGER,
|
||
NULL::DECIMAL,
|
||
NULL::DECIMAL,
|
||
NULL::VARCHAR,
|
||
NULL::INTEGER,
|
||
NULL::DECIMAL,
|
||
'new_product'::VARCHAR;
|
||
RETURN;
|
||
END IF;
|
||
|
||
-- Check for changes
|
||
IF v_prev.quantity_available IS DISTINCT FROM p_quantity
|
||
OR v_prev.price_rec IS DISTINCT FROM p_price_rec
|
||
OR v_prev.price_med IS DISTINCT FROM p_price_med
|
||
OR v_prev.status IS DISTINCT FROM p_status THEN
|
||
|
||
RETURN QUERY SELECT
|
||
TRUE,
|
||
v_prev.quantity_available,
|
||
v_prev.price_rec,
|
||
v_prev.price_med,
|
||
v_prev.status,
|
||
COALESCE(p_quantity, 0) - COALESCE(v_prev.quantity_available, 0),
|
||
COALESCE(p_price_rec, 0) - COALESCE(v_prev.price_rec, 0),
|
||
CASE
|
||
WHEN COALESCE(p_quantity, 0) < COALESCE(v_prev.quantity_available, 0) THEN 'sale'
|
||
WHEN COALESCE(p_quantity, 0) > COALESCE(v_prev.quantity_available, 0) THEN 'restock'
|
||
WHEN p_quantity = 0 AND v_prev.quantity_available > 0 THEN 'oos'
|
||
WHEN p_quantity > 0 AND v_prev.quantity_available = 0 THEN 'back_in_stock'
|
||
WHEN p_price_rec IS DISTINCT FROM v_prev.price_rec THEN 'price_change'
|
||
ELSE 'status_change'
|
||
END;
|
||
RETURN;
|
||
END IF;
|
||
|
||
-- No change
|
||
RETURN QUERY SELECT
|
||
FALSE,
|
||
NULL::INTEGER,
|
||
NULL::DECIMAL,
|
||
NULL::DECIMAL,
|
||
NULL::VARCHAR,
|
||
NULL::INTEGER,
|
||
NULL::DECIMAL,
|
||
NULL::VARCHAR;
|
||
END;
|
||
$$ LANGUAGE plpgsql;
|
||
|
||
-- ============================================================
|
||
-- REVENUE CALCULATION COLUMNS
|
||
-- ============================================================
|
||
-- Effective prices (sale price if on special, otherwise regular)
|
||
ALTER TABLE inventory_snapshots ADD COLUMN IF NOT EXISTS effective_price_rec DECIMAL(10,2);
|
||
ALTER TABLE inventory_snapshots ADD COLUMN IF NOT EXISTS effective_price_med DECIMAL(10,2);
|
||
ALTER TABLE inventory_snapshots ADD COLUMN IF NOT EXISTS is_on_special BOOLEAN DEFAULT FALSE;
|
||
|
||
-- Revenue by market type
|
||
ALTER TABLE inventory_snapshots ADD COLUMN IF NOT EXISTS revenue_rec DECIMAL(10,2);
|
||
ALTER TABLE inventory_snapshots ADD COLUMN IF NOT EXISTS revenue_med DECIMAL(10,2);
|
||
|
||
-- Time between snapshots (for velocity calc)
|
||
ALTER TABLE inventory_snapshots ADD COLUMN IF NOT EXISTS time_since_last_snapshot INTERVAL;
|
||
ALTER TABLE inventory_snapshots ADD COLUMN IF NOT EXISTS hours_since_last DECIMAL(10,2);
|
||
|
||
-- ============================================================
|
||
-- VIEW: Hourly Sales Velocity
|
||
-- ============================================================
|
||
CREATE OR REPLACE VIEW v_hourly_sales AS
|
||
SELECT
|
||
dispensary_id,
|
||
DATE(captured_at) as sale_date,
|
||
EXTRACT(HOUR FROM captured_at) as sale_hour,
|
||
COUNT(*) FILTER (WHERE qty_delta < 0) as transactions,
|
||
SUM(ABS(qty_delta)) FILTER (WHERE qty_delta < 0) as units_sold,
|
||
SUM(revenue_estimate) FILTER (WHERE qty_delta < 0) as revenue,
|
||
COUNT(DISTINCT product_id) FILTER (WHERE qty_delta < 0) as unique_products_sold
|
||
FROM inventory_snapshots
|
||
WHERE change_type = 'sale'
|
||
GROUP BY dispensary_id, DATE(captured_at), EXTRACT(HOUR FROM captured_at);
|
||
|
||
-- ============================================================
|
||
-- VIEW: Daily Sales by Store
|
||
-- ============================================================
|
||
CREATE OR REPLACE VIEW v_daily_store_sales AS
|
||
SELECT
|
||
s.dispensary_id,
|
||
d.name as store_name,
|
||
d.state,
|
||
DATE(s.captured_at) as sale_date,
|
||
SUM(ABS(s.qty_delta)) as units_sold,
|
||
SUM(s.revenue_estimate) as revenue,
|
||
COUNT(*) as sale_events,
|
||
COUNT(DISTINCT s.product_id) as unique_products
|
||
FROM inventory_snapshots s
|
||
JOIN dispensaries d ON d.id = s.dispensary_id
|
||
WHERE s.change_type = 'sale'
|
||
GROUP BY s.dispensary_id, d.name, d.state, DATE(s.captured_at);
|
||
|
||
-- ============================================================
|
||
-- VIEW: Daily Sales by Brand
|
||
-- ============================================================
|
||
CREATE OR REPLACE VIEW v_daily_brand_sales AS
|
||
SELECT
|
||
s.brand_name,
|
||
d.state,
|
||
DATE(s.captured_at) as sale_date,
|
||
SUM(ABS(s.qty_delta)) as units_sold,
|
||
SUM(s.revenue_estimate) as revenue,
|
||
COUNT(DISTINCT s.dispensary_id) as stores_with_sales,
|
||
COUNT(DISTINCT s.product_id) as unique_skus_sold
|
||
FROM inventory_snapshots s
|
||
JOIN dispensaries d ON d.id = s.dispensary_id
|
||
WHERE s.change_type = 'sale'
|
||
AND s.brand_name IS NOT NULL
|
||
GROUP BY s.brand_name, d.state, DATE(s.captured_at);
|
||
|
||
-- ============================================================
|
||
-- VIEW: Product Velocity Rankings
|
||
-- ============================================================
|
||
CREATE OR REPLACE VIEW v_product_velocity AS
|
||
SELECT
|
||
s.product_id,
|
||
s.brand_name,
|
||
s.category,
|
||
s.dispensary_id,
|
||
d.name as store_name,
|
||
d.state,
|
||
SUM(ABS(s.qty_delta)) as units_sold_30d,
|
||
SUM(s.revenue_estimate) as revenue_30d,
|
||
COUNT(*) as sale_events,
|
||
ROUND(SUM(ABS(s.qty_delta))::NUMERIC / NULLIF(COUNT(DISTINCT DATE(s.captured_at)), 0), 2) as avg_daily_units,
|
||
ROUND(SUM(s.revenue_estimate) / NULLIF(COUNT(DISTINCT DATE(s.captured_at)), 0), 2) as avg_daily_revenue,
|
||
CASE
|
||
WHEN SUM(ABS(s.qty_delta)) / NULLIF(COUNT(DISTINCT DATE(s.captured_at)), 0) >= 10 THEN 'hot'
|
||
WHEN SUM(ABS(s.qty_delta)) / NULLIF(COUNT(DISTINCT DATE(s.captured_at)), 0) >= 3 THEN 'steady'
|
||
WHEN SUM(ABS(s.qty_delta)) / NULLIF(COUNT(DISTINCT DATE(s.captured_at)), 0) >= 1 THEN 'slow'
|
||
ELSE 'stale'
|
||
END as velocity_tier
|
||
FROM inventory_snapshots s
|
||
JOIN dispensaries d ON d.id = s.dispensary_id
|
||
WHERE s.change_type = 'sale'
|
||
AND s.captured_at >= NOW() - INTERVAL '30 days'
|
||
GROUP BY s.product_id, s.brand_name, s.category, s.dispensary_id, d.name, d.state;
|
||
|
||
-- ============================================================
|
||
-- VIEW: Busiest Hours by Store
|
||
-- ============================================================
|
||
CREATE OR REPLACE VIEW v_busiest_hours AS
|
||
SELECT
|
||
dispensary_id,
|
||
sale_hour,
|
||
AVG(units_sold) as avg_units_per_hour,
|
||
AVG(revenue) as avg_revenue_per_hour,
|
||
SUM(units_sold) as total_units,
|
||
SUM(revenue) as total_revenue,
|
||
COUNT(*) as days_with_data,
|
||
RANK() OVER (PARTITION BY dispensary_id ORDER BY AVG(revenue) DESC) as hour_rank
|
||
FROM v_hourly_sales
|
||
GROUP BY dispensary_id, sale_hour;
|
||
|
||
-- ============================================================
|
||
-- VIEW: Promotion Effectiveness (compare sale vs non-sale prices)
|
||
-- ============================================================
|
||
CREATE OR REPLACE VIEW v_promotion_effectiveness AS
|
||
SELECT
|
||
s.dispensary_id,
|
||
d.name as store_name,
|
||
s.product_id,
|
||
s.brand_name,
|
||
DATE(s.captured_at) as sale_date,
|
||
SUM(ABS(s.qty_delta)) FILTER (WHERE s.price_rec < s.prev_price_rec) as units_on_discount,
|
||
SUM(ABS(s.qty_delta)) FILTER (WHERE s.price_rec >= COALESCE(s.prev_price_rec, s.price_rec)) as units_full_price,
|
||
SUM(s.revenue_estimate) FILTER (WHERE s.price_rec < s.prev_price_rec) as revenue_discounted,
|
||
SUM(s.revenue_estimate) FILTER (WHERE s.price_rec >= COALESCE(s.prev_price_rec, s.price_rec)) as revenue_full_price
|
||
FROM inventory_snapshots s
|
||
JOIN dispensaries d ON d.id = s.dispensary_id
|
||
WHERE s.change_type = 'sale'
|
||
GROUP BY s.dispensary_id, d.name, s.product_id, s.brand_name, DATE(s.captured_at);
|
||
|
||
-- ============================================================
|
||
-- COMMENTS
|
||
-- ============================================================
|
||
COMMENT ON COLUMN inventory_snapshots.qty_delta IS 'Quantity change: negative=sold, positive=restocked';
|
||
COMMENT ON COLUMN inventory_snapshots.revenue_estimate IS 'Estimated revenue: ABS(qty_delta) * price_rec when qty_delta < 0';
|
||
COMMENT ON COLUMN inventory_snapshots.change_type IS 'Type of change: sale, restock, price_change, oos, back_in_stock, new_product';
|
||
COMMENT ON FUNCTION should_capture_snapshot IS 'Returns whether a snapshot should be captured and delta values';
|
||
COMMENT ON VIEW v_hourly_sales IS 'Sales aggregated by hour - find busiest times';
|
||
COMMENT ON VIEW v_daily_store_sales IS 'Daily revenue by store';
|
||
COMMENT ON VIEW v_daily_brand_sales IS 'Daily brand performance by state';
|
||
COMMENT ON VIEW v_product_velocity IS 'Product sales velocity rankings (hot/steady/slow/stale)';
|
||
COMMENT ON VIEW v_busiest_hours IS 'Rank hours by sales volume per store';
|
||
|
||
-- ============================================================
|
||
-- VIEW: Days Until Stock Out (Predictive)
|
||
-- ============================================================
|
||
CREATE OR REPLACE VIEW v_stock_out_prediction AS
|
||
WITH velocity AS (
|
||
SELECT
|
||
dispensary_id,
|
||
product_id,
|
||
brand_name,
|
||
-- Average units sold per day (last 7 days)
|
||
ROUND(SUM(ABS(qty_delta))::NUMERIC / NULLIF(COUNT(DISTINCT DATE(captured_at)), 0), 2) as daily_velocity,
|
||
-- Hours between sales
|
||
AVG(hours_since_last) FILTER (WHERE qty_delta < 0) as avg_hours_between_sales
|
||
FROM inventory_snapshots
|
||
WHERE change_type = 'sale'
|
||
AND captured_at >= NOW() - INTERVAL '7 days'
|
||
GROUP BY dispensary_id, product_id, brand_name
|
||
),
|
||
current_stock AS (
|
||
SELECT DISTINCT ON (dispensary_id, product_id)
|
||
dispensary_id,
|
||
product_id,
|
||
quantity_available as current_qty,
|
||
captured_at as last_seen
|
||
FROM inventory_snapshots
|
||
ORDER BY dispensary_id, product_id, captured_at DESC
|
||
)
|
||
SELECT
|
||
cs.dispensary_id,
|
||
d.name as store_name,
|
||
cs.product_id,
|
||
v.brand_name,
|
||
cs.current_qty,
|
||
v.daily_velocity,
|
||
CASE
|
||
WHEN v.daily_velocity > 0 THEN ROUND(cs.current_qty / v.daily_velocity, 1)
|
||
ELSE NULL
|
||
END as days_until_stock_out,
|
||
CASE
|
||
WHEN v.daily_velocity > 0 AND cs.current_qty / v.daily_velocity <= 3 THEN 'critical'
|
||
WHEN v.daily_velocity > 0 AND cs.current_qty / v.daily_velocity <= 7 THEN 'low'
|
||
WHEN v.daily_velocity > 0 AND cs.current_qty / v.daily_velocity <= 14 THEN 'moderate'
|
||
ELSE 'healthy'
|
||
END as stock_health,
|
||
cs.last_seen
|
||
FROM current_stock cs
|
||
JOIN velocity v ON v.dispensary_id = cs.dispensary_id AND v.product_id = cs.product_id
|
||
JOIN dispensaries d ON d.id = cs.dispensary_id
|
||
WHERE cs.current_qty > 0
|
||
AND v.daily_velocity > 0;
|
||
|
||
-- ============================================================
|
||
-- VIEW: Days Since OOS (for products currently out of stock)
|
||
-- ============================================================
|
||
CREATE OR REPLACE VIEW v_days_since_oos AS
|
||
SELECT
|
||
s.dispensary_id,
|
||
d.name as store_name,
|
||
s.product_id,
|
||
s.brand_name,
|
||
s.captured_at as went_oos_at,
|
||
EXTRACT(EPOCH FROM (NOW() - s.captured_at)) / 86400 as days_since_oos,
|
||
s.prev_quantity as last_known_qty
|
||
FROM inventory_snapshots s
|
||
JOIN dispensaries d ON d.id = s.dispensary_id
|
||
WHERE s.change_type = 'oos'
|
||
AND NOT EXISTS (
|
||
-- No back_in_stock event after this OOS
|
||
SELECT 1 FROM inventory_snapshots s2
|
||
WHERE s2.dispensary_id = s.dispensary_id
|
||
AND s2.product_id = s.product_id
|
||
AND s2.change_type = 'back_in_stock'
|
||
AND s2.captured_at > s.captured_at
|
||
);
|
||
|
||
-- ============================================================
|
||
-- VIEW: Brand Variant Counts (track brand growth)
|
||
-- ============================================================
|
||
CREATE OR REPLACE VIEW v_brand_variants AS
|
||
SELECT
|
||
sp.brand_name_raw as brand_name,
|
||
d.state,
|
||
COUNT(DISTINCT sp.id) as total_variants,
|
||
COUNT(DISTINCT sp.id) FILTER (WHERE sp.is_in_stock = TRUE) as active_variants,
|
||
COUNT(DISTINCT sp.id) FILTER (WHERE sp.is_in_stock = FALSE) as inactive_variants,
|
||
COUNT(DISTINCT sp.dispensary_id) as stores_carrying,
|
||
COUNT(DISTINCT sp.category_raw) as categories,
|
||
MIN(sp.first_seen_at) as brand_first_seen,
|
||
MAX(sp.last_seen_at) as brand_last_seen
|
||
FROM store_products sp
|
||
JOIN dispensaries d ON d.id = sp.dispensary_id
|
||
WHERE sp.brand_name_raw IS NOT NULL
|
||
GROUP BY sp.brand_name_raw, d.state;
|
||
|
||
-- ============================================================
|
||
-- VIEW: Brand Growth (compare variant counts over time)
|
||
-- ============================================================
|
||
CREATE OR REPLACE VIEW v_brand_growth AS
|
||
WITH weekly_counts AS (
|
||
SELECT
|
||
brand_name_raw as brand_name,
|
||
DATE_TRUNC('week', last_seen_at) as week,
|
||
COUNT(DISTINCT id) as variant_count
|
||
FROM store_products
|
||
WHERE brand_name_raw IS NOT NULL
|
||
AND last_seen_at >= NOW() - INTERVAL '90 days'
|
||
GROUP BY brand_name_raw, DATE_TRUNC('week', last_seen_at)
|
||
)
|
||
SELECT
|
||
w1.brand_name,
|
||
w1.week as current_week,
|
||
w1.variant_count as current_variants,
|
||
w2.variant_count as prev_week_variants,
|
||
w1.variant_count - COALESCE(w2.variant_count, 0) as variant_change,
|
||
CASE
|
||
WHEN w2.variant_count IS NULL THEN 'new'
|
||
WHEN w1.variant_count > w2.variant_count THEN 'growing'
|
||
WHEN w1.variant_count < w2.variant_count THEN 'declining'
|
||
ELSE 'stable'
|
||
END as growth_status
|
||
FROM weekly_counts w1
|
||
LEFT JOIN weekly_counts w2
|
||
ON w2.brand_name = w1.brand_name
|
||
AND w2.week = w1.week - INTERVAL '1 week'
|
||
ORDER BY w1.brand_name, w1.week DESC;
|
||
|
||
COMMENT ON VIEW v_stock_out_prediction IS 'Predict days until stock out based on velocity';
|
||
COMMENT ON VIEW v_days_since_oos IS 'Products currently OOS and how long they have been out';
|
||
COMMENT ON VIEW v_brand_variants IS 'Active vs inactive SKU counts per brand per state';
|
||
COMMENT ON VIEW v_brand_growth IS 'Week-over-week brand variant growth tracking';
|