- Add backend stale process monitoring API (/api/stale-processes) - Add users management route - Add frontend landing page and stale process monitor UI on /scraper-tools - Move old development scripts to backend/archive/ - Update frontend build with new features 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude <noreply@anthropic.com>
216 lines
7.6 KiB
TypeScript
216 lines
7.6 KiB
TypeScript
import { pool } from './src/db/migrate';
|
|
|
|
async function migrateCompleteSchema() {
|
|
console.log('🔧 Migrating to complete normalized schema...\n');
|
|
|
|
const client = await pool.connect();
|
|
|
|
try {
|
|
await client.query('BEGIN');
|
|
|
|
// Step 1: Add brand_id to products table
|
|
console.log('1. Adding brand_id column to products...');
|
|
await client.query(`
|
|
ALTER TABLE products
|
|
ADD COLUMN IF NOT EXISTS brand_id INTEGER REFERENCES brands(id) ON DELETE SET NULL
|
|
`);
|
|
|
|
// Step 2: Ensure brands.name has UNIQUE constraint
|
|
console.log('2. Ensuring brands.name has UNIQUE constraint...');
|
|
await client.query(`
|
|
ALTER TABLE brands DROP CONSTRAINT IF EXISTS brands_name_key;
|
|
ALTER TABLE brands ADD CONSTRAINT brands_name_key UNIQUE (name);
|
|
`);
|
|
|
|
// Step 9: Migrate existing brand text to brands table and update FKs
|
|
console.log('3. Migrating existing brand data...');
|
|
await client.query(`
|
|
-- Insert unique brands from products into brands table
|
|
INSERT INTO brands (name)
|
|
SELECT DISTINCT brand
|
|
FROM products
|
|
WHERE brand IS NOT NULL AND brand != ''
|
|
ON CONFLICT (name) DO NOTHING
|
|
`);
|
|
|
|
// Update products to use brand_id
|
|
await client.query(`
|
|
UPDATE products p
|
|
SET brand_id = b.id
|
|
FROM brands b
|
|
WHERE p.brand = b.name
|
|
AND p.brand IS NOT NULL
|
|
AND p.brand != ''
|
|
`);
|
|
|
|
// Step 9: Create product_brands junction table for historical tracking
|
|
console.log('3. Creating product_brands tracking table...');
|
|
await client.query(`
|
|
CREATE TABLE IF NOT EXISTS product_brands (
|
|
id SERIAL PRIMARY KEY,
|
|
product_id INTEGER REFERENCES products(id) ON DELETE CASCADE,
|
|
brand_id INTEGER REFERENCES brands(id) ON DELETE CASCADE,
|
|
first_seen_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
last_seen_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
UNIQUE(product_id, brand_id)
|
|
)
|
|
`);
|
|
|
|
// Populate product_brands from current data
|
|
await client.query(`
|
|
INSERT INTO product_brands (product_id, brand_id)
|
|
SELECT id, brand_id
|
|
FROM products
|
|
WHERE brand_id IS NOT NULL
|
|
ON CONFLICT (product_id, brand_id) DO NOTHING
|
|
`);
|
|
|
|
// Step 9: Add store contact information and address fields
|
|
console.log('4. Adding store contact info and address fields...');
|
|
await client.query(`
|
|
ALTER TABLE stores
|
|
ADD COLUMN IF NOT EXISTS address TEXT,
|
|
ADD COLUMN IF NOT EXISTS city VARCHAR(255),
|
|
ADD COLUMN IF NOT EXISTS state VARCHAR(50),
|
|
ADD COLUMN IF NOT EXISTS zip VARCHAR(20),
|
|
ADD COLUMN IF NOT EXISTS phone VARCHAR(50),
|
|
ADD COLUMN IF NOT EXISTS website TEXT,
|
|
ADD COLUMN IF NOT EXISTS email VARCHAR(255)
|
|
`);
|
|
|
|
// Step 9: Add product discount tracking
|
|
console.log('5. Adding product discount fields...');
|
|
await client.query(`
|
|
ALTER TABLE products
|
|
ADD COLUMN IF NOT EXISTS discount_percentage DECIMAL(5, 2),
|
|
ADD COLUMN IF NOT EXISTS discount_amount DECIMAL(10, 2),
|
|
ADD COLUMN IF NOT EXISTS sale_price DECIMAL(10, 2)
|
|
`);
|
|
|
|
// Step 9: Add missing timestamp columns
|
|
console.log('6. Ensuring all timestamp columns exist...');
|
|
|
|
// Products timestamps
|
|
await client.query(`
|
|
ALTER TABLE products
|
|
ADD COLUMN IF NOT EXISTS first_seen_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
ADD COLUMN IF NOT EXISTS last_seen_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
`);
|
|
|
|
// Categories timestamps
|
|
await client.query(`
|
|
ALTER TABLE categories
|
|
ADD COLUMN IF NOT EXISTS first_seen_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
ADD COLUMN IF NOT EXISTS last_seen_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
`);
|
|
|
|
// Step 9: Add indexes for reporting queries
|
|
console.log('7. Creating indexes for fast reporting...');
|
|
|
|
await client.query(`
|
|
-- Brand exposure queries (which stores carry which brands)
|
|
CREATE INDEX IF NOT EXISTS idx_store_brands_brand_active ON store_brands(brand_id, active);
|
|
CREATE INDEX IF NOT EXISTS idx_store_brands_store_active ON store_brands(store_id, active);
|
|
CREATE INDEX IF NOT EXISTS idx_store_brands_dates ON store_brands(first_seen_at, last_seen_at);
|
|
|
|
-- Product queries by store and brand
|
|
CREATE INDEX IF NOT EXISTS idx_products_store_brand ON products(store_id, brand_id);
|
|
CREATE INDEX IF NOT EXISTS idx_products_brand_stock ON products(brand_id, in_stock);
|
|
CREATE INDEX IF NOT EXISTS idx_products_dates ON products(first_seen_at, last_seen_at);
|
|
|
|
-- Category queries
|
|
CREATE INDEX IF NOT EXISTS idx_categories_store ON categories(store_id, scrape_enabled);
|
|
|
|
-- Specials queries
|
|
CREATE INDEX IF NOT EXISTS idx_products_specials ON products(store_id, is_special) WHERE is_special = true;
|
|
`);
|
|
|
|
// Step 9: Create helper views for common queries
|
|
console.log('8. Creating reporting views...');
|
|
|
|
// Brand exposure view
|
|
await client.query(`
|
|
CREATE OR REPLACE VIEW brand_exposure AS
|
|
SELECT
|
|
b.id as brand_id,
|
|
b.name as brand_name,
|
|
COUNT(DISTINCT sb.store_id) as store_count,
|
|
COUNT(DISTINCT CASE WHEN sb.active THEN sb.store_id END) as active_store_count,
|
|
MIN(sb.first_seen_at) as first_seen,
|
|
MAX(sb.last_seen_at) as last_seen
|
|
FROM brands b
|
|
LEFT JOIN store_brands sb ON b.id = sb.brand_id
|
|
GROUP BY b.id, b.name
|
|
ORDER BY active_store_count DESC, brand_name
|
|
`);
|
|
|
|
// Brand timeline view (track adds/drops)
|
|
await client.query(`
|
|
CREATE OR REPLACE VIEW brand_timeline AS
|
|
SELECT
|
|
sb.id,
|
|
b.name as brand_name,
|
|
s.name as store_name,
|
|
sb.first_seen_at as added_on,
|
|
CASE
|
|
WHEN sb.active THEN NULL
|
|
ELSE sb.last_seen_at
|
|
END as dropped_on,
|
|
sb.active as currently_active
|
|
FROM store_brands sb
|
|
JOIN brands b ON sb.brand_id = b.id
|
|
JOIN stores s ON sb.store_id = s.id
|
|
ORDER BY sb.first_seen_at DESC
|
|
`);
|
|
|
|
// Product inventory view
|
|
await client.query(`
|
|
CREATE OR REPLACE VIEW product_inventory AS
|
|
SELECT
|
|
p.id,
|
|
p.name as product_name,
|
|
b.name as brand_name,
|
|
s.name as store_name,
|
|
c.name as category_name,
|
|
p.price,
|
|
p.in_stock,
|
|
p.is_special,
|
|
p.first_seen_at,
|
|
p.last_seen_at
|
|
FROM products p
|
|
JOIN stores s ON p.store_id = s.id
|
|
LEFT JOIN brands b ON p.brand_id = b.id
|
|
LEFT JOIN categories c ON p.category_id = c.id
|
|
ORDER BY p.last_seen_at DESC
|
|
`);
|
|
|
|
await client.query('COMMIT');
|
|
|
|
console.log('\n✅ Schema migration complete!');
|
|
console.log('\n📊 Available reporting views:');
|
|
console.log(' - brand_exposure: See how many stores carry each brand');
|
|
console.log(' - brand_timeline: Track when brands were added/dropped');
|
|
console.log(' - product_inventory: Full product catalog with store/brand info');
|
|
|
|
console.log('\n💡 Example queries:');
|
|
console.log(' -- Brands by exposure:');
|
|
console.log(' SELECT * FROM brand_exposure ORDER BY active_store_count DESC;');
|
|
console.log(' ');
|
|
console.log(' -- Recently dropped brands:');
|
|
console.log(' SELECT * FROM brand_timeline WHERE dropped_on IS NOT NULL ORDER BY dropped_on DESC;');
|
|
console.log(' ');
|
|
console.log(' -- Products by brand:');
|
|
console.log(' SELECT * FROM product_inventory WHERE brand_name = \'Sol Flower\';');
|
|
|
|
} catch (error) {
|
|
await client.query('ROLLBACK');
|
|
console.error('❌ Migration failed:', error);
|
|
throw error;
|
|
} finally {
|
|
client.release();
|
|
await pool.end();
|
|
}
|
|
}
|
|
|
|
migrateCompleteSchema();
|