-- Migration: Multi-domain user support with extended profile fields -- Adds domain tracking for findagram.co and findadispo.com users -- Adds extended profile fields (first_name, last_name, phone, sms_enabled) -- Add new columns to users table ALTER TABLE users ADD COLUMN IF NOT EXISTS first_name VARCHAR(100), ADD COLUMN IF NOT EXISTS last_name VARCHAR(100), ADD COLUMN IF NOT EXISTS phone VARCHAR(20), ADD COLUMN IF NOT EXISTS sms_enabled BOOLEAN DEFAULT false, ADD COLUMN IF NOT EXISTS domain VARCHAR(50) DEFAULT 'cannaiq.co'; -- Create index for domain-based queries CREATE INDEX IF NOT EXISTS idx_users_domain ON users(domain); -- Add domain column to wp_api_permissions ALTER TABLE wp_api_permissions ADD COLUMN IF NOT EXISTS domain VARCHAR(50) DEFAULT 'cannaiq.co'; -- Create index for domain-based permission queries CREATE INDEX IF NOT EXISTS idx_wp_api_permissions_domain ON wp_api_permissions(domain); -- Create findagram_users table for Find a Gram specific user data CREATE TABLE IF NOT EXISTS findagram_users ( id SERIAL PRIMARY KEY, user_id INTEGER REFERENCES users(id) ON DELETE CASCADE, -- Profile display_name VARCHAR(100), avatar_url TEXT, bio TEXT, -- Location preferences preferred_city VARCHAR(100), preferred_state VARCHAR(50), location_lat DECIMAL(10, 8), location_lng DECIMAL(11, 8), -- Preferences favorite_strains TEXT[], -- Array of strain types: hybrid, indica, sativa favorite_categories TEXT[], -- flower, edibles, concentrates, etc. price_alert_threshold DECIMAL(10, 2), notifications_enabled BOOLEAN DEFAULT true, -- Timestamps created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, UNIQUE(user_id) ); -- Create findadispo_users table for Find a Dispo specific user data CREATE TABLE IF NOT EXISTS findadispo_users ( id SERIAL PRIMARY KEY, user_id INTEGER REFERENCES users(id) ON DELETE CASCADE, -- Profile display_name VARCHAR(100), avatar_url TEXT, -- Location preferences preferred_city VARCHAR(100), preferred_state VARCHAR(50), location_lat DECIMAL(10, 8), location_lng DECIMAL(11, 8), search_radius_miles INTEGER DEFAULT 25, -- Preferences favorite_dispensary_ids INTEGER[], -- Array of dispensary IDs deal_notifications BOOLEAN DEFAULT true, -- Timestamps created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, UNIQUE(user_id) ); -- Create findagram_saved_searches table CREATE TABLE IF NOT EXISTS findagram_saved_searches ( id SERIAL PRIMARY KEY, user_id INTEGER REFERENCES users(id) ON DELETE CASCADE, name VARCHAR(100) NOT NULL, -- Search criteria query TEXT, category VARCHAR(50), brand VARCHAR(100), strain_type VARCHAR(20), min_price DECIMAL(10, 2), max_price DECIMAL(10, 2), min_thc DECIMAL(5, 2), max_thc DECIMAL(5, 2), city VARCHAR(100), state VARCHAR(50), -- Notification settings notify_on_new BOOLEAN DEFAULT false, notify_on_price_drop BOOLEAN DEFAULT false, -- Timestamps created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Create findagram_favorites table CREATE TABLE IF NOT EXISTS findagram_favorites ( id SERIAL PRIMARY KEY, user_id INTEGER REFERENCES users(id) ON DELETE CASCADE, product_id INTEGER, -- References products table dispensary_id INTEGER, -- References dispensaries table -- Product snapshot at time of save product_name VARCHAR(255), product_brand VARCHAR(100), product_price DECIMAL(10, 2), product_image_url TEXT, -- Timestamps created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, UNIQUE(user_id, product_id) ); -- Create findagram_alerts table CREATE TABLE IF NOT EXISTS findagram_alerts ( id SERIAL PRIMARY KEY, user_id INTEGER REFERENCES users(id) ON DELETE CASCADE, alert_type VARCHAR(50) NOT NULL, -- price_drop, back_in_stock, new_product -- Target product_id INTEGER, brand VARCHAR(100), category VARCHAR(50), dispensary_id INTEGER, -- Criteria target_price DECIMAL(10, 2), -- Status is_active BOOLEAN DEFAULT true, last_triggered_at TIMESTAMP, trigger_count INTEGER DEFAULT 0, -- Timestamps created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Create indexes for findagram tables CREATE INDEX IF NOT EXISTS idx_findagram_users_user_id ON findagram_users(user_id); CREATE INDEX IF NOT EXISTS idx_findadispo_users_user_id ON findadispo_users(user_id); CREATE INDEX IF NOT EXISTS idx_findagram_saved_searches_user_id ON findagram_saved_searches(user_id); CREATE INDEX IF NOT EXISTS idx_findagram_favorites_user_id ON findagram_favorites(user_id); CREATE INDEX IF NOT EXISTS idx_findagram_favorites_product_id ON findagram_favorites(product_id); CREATE INDEX IF NOT EXISTS idx_findagram_alerts_user_id ON findagram_alerts(user_id); CREATE INDEX IF NOT EXISTS idx_findagram_alerts_active ON findagram_alerts(is_active) WHERE is_active = true; -- Create view for admin user management across domains CREATE OR REPLACE VIEW admin_users_view AS SELECT u.id, u.email, u.first_name, u.last_name, u.phone, u.sms_enabled, u.role, u.domain, u.created_at, u.updated_at, CASE WHEN u.domain = 'findagram.co' THEN fg.display_name WHEN u.domain = 'findadispo.com' THEN fd.display_name ELSE NULL END as display_name, CASE WHEN u.domain = 'findagram.co' THEN fg.preferred_city WHEN u.domain = 'findadispo.com' THEN fd.preferred_city ELSE NULL END as preferred_city, CASE WHEN u.domain = 'findagram.co' THEN fg.preferred_state WHEN u.domain = 'findadispo.com' THEN fd.preferred_state ELSE NULL END as preferred_state FROM users u LEFT JOIN findagram_users fg ON u.id = fg.user_id AND u.domain = 'findagram.co' LEFT JOIN findadispo_users fd ON u.id = fd.user_id AND u.domain = 'findadispo.com'; -- Update existing cannaiq users to have domain set UPDATE users SET domain = 'cannaiq.co' WHERE domain IS NULL;