Add brand history tracking for new/dropped brands detection

- Add first_seen_at/last_seen_at columns to brands table
- Create brand_history table for event tracking (added, dropped, returned)
- Add dispensary_brand_stats view for dashboard

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

Co-Authored-By: Claude <noreply@anthropic.com>
This commit is contained in:
Kelly
2025-12-01 00:18:47 -07:00
parent 9de0d709b2
commit c9947eb1de

View File

@@ -0,0 +1,57 @@
-- Migration 027: Brand History Tracking
-- Add first_seen_at and last_seen_at to brands table for history tracking
-- Also add dispensary_id since brands is currently store_id linked
-- Add timestamp columns to brands
ALTER TABLE brands ADD COLUMN IF NOT EXISTS first_seen_at TIMESTAMPTZ DEFAULT NOW();
ALTER TABLE brands ADD COLUMN IF NOT EXISTS last_seen_at TIMESTAMPTZ DEFAULT NOW();
ALTER TABLE brands ADD COLUMN IF NOT EXISTS dispensary_id INTEGER REFERENCES dispensaries(id);
-- Add index for tracking dropped brands
CREATE INDEX IF NOT EXISTS idx_brands_last_seen ON brands(last_seen_at DESC);
CREATE INDEX IF NOT EXISTS idx_brands_dispensary ON brands(dispensary_id);
-- Create brand_history table for detailed tracking
CREATE TABLE IF NOT EXISTS brand_history (
id SERIAL PRIMARY KEY,
dispensary_id INTEGER NOT NULL REFERENCES dispensaries(id) ON DELETE CASCADE,
brand_name VARCHAR(255) NOT NULL,
event_type VARCHAR(20) NOT NULL, -- 'added', 'dropped', 'returned'
event_at TIMESTAMPTZ DEFAULT NOW(),
product_count INTEGER, -- number of products from this brand at event time
metadata JSONB
);
CREATE INDEX IF NOT EXISTS idx_brand_history_dispensary ON brand_history(dispensary_id, event_at DESC);
CREATE INDEX IF NOT EXISTS idx_brand_history_brand ON brand_history(brand_name, event_at DESC);
CREATE INDEX IF NOT EXISTS idx_brand_history_event ON brand_history(event_type, event_at DESC);
-- Create view for brand stats per dispensary
CREATE OR REPLACE VIEW dispensary_brand_stats AS
SELECT
d.id AS dispensary_id,
COALESCE(d.dba_name, d.name) AS dispensary_name,
COUNT(DISTINCT p.brand) FILTER (WHERE p.last_seen_at >= NOW() - INTERVAL '7 days') AS current_brands,
COUNT(DISTINCT p.brand) AS total_brands_ever,
(
SELECT COUNT(DISTINCT brand_name)
FROM brand_history bh
WHERE bh.dispensary_id = d.id
AND bh.event_type = 'added'
AND bh.event_at >= NOW() - INTERVAL '7 days'
) AS new_brands_7d,
(
SELECT COUNT(DISTINCT brand_name)
FROM brand_history bh
WHERE bh.dispensary_id = d.id
AND bh.event_type = 'dropped'
AND bh.event_at >= NOW() - INTERVAL '7 days'
) AS dropped_brands_7d
FROM dispensaries d
LEFT JOIN products p ON p.dispensary_id = d.id
GROUP BY d.id, d.dba_name, d.name;
-- Grant permissions
GRANT SELECT ON brand_history TO scraper;
GRANT INSERT, UPDATE ON brand_history TO scraper;
GRANT SELECT ON dispensary_brand_stats TO scraper;