90 lines
4.1 KiB
SQL
90 lines
4.1 KiB
SQL
-- Add phone number and location to stores
|
|
ALTER TABLE stores
|
|
ADD COLUMN IF NOT EXISTS phone VARCHAR(20),
|
|
ADD COLUMN IF NOT EXISTS city VARCHAR(100),
|
|
ADD COLUMN IF NOT EXISTS state VARCHAR(2) DEFAULT 'AZ',
|
|
ADD COLUMN IF NOT EXISTS address TEXT;
|
|
|
|
-- Stock change history
|
|
CREATE TABLE IF NOT EXISTS stock_changes (
|
|
id SERIAL PRIMARY KEY,
|
|
product_id INTEGER NOT NULL REFERENCES products(id) ON DELETE CASCADE,
|
|
store_id INTEGER NOT NULL REFERENCES stores(id) ON DELETE CASCADE,
|
|
previous_stock BOOLEAN NOT NULL,
|
|
current_stock BOOLEAN NOT NULL,
|
|
changed_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
notified BOOLEAN DEFAULT FALSE,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_stock_changes_product ON stock_changes(product_id);
|
|
CREATE INDEX IF NOT EXISTS idx_stock_changes_store ON stock_changes(store_id);
|
|
CREATE INDEX IF NOT EXISTS idx_stock_changes_notified ON stock_changes(notified);
|
|
CREATE INDEX IF NOT EXISTS idx_stock_changes_changed_at ON stock_changes(changed_at);
|
|
|
|
-- Customer product subscriptions
|
|
CREATE TABLE IF NOT EXISTS product_subscriptions (
|
|
id SERIAL PRIMARY KEY,
|
|
phone_number VARCHAR(20) NOT NULL,
|
|
product_id INTEGER NOT NULL REFERENCES products(id) ON DELETE CASCADE,
|
|
store_id INTEGER NOT NULL REFERENCES stores(id) ON DELETE CASCADE,
|
|
active BOOLEAN DEFAULT TRUE,
|
|
notify_on_restock BOOLEAN DEFAULT TRUE,
|
|
notify_on_out_of_stock BOOLEAN DEFAULT FALSE,
|
|
subscribed_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
last_notified_at TIMESTAMP,
|
|
unsubscribed_at TIMESTAMP,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
UNIQUE(phone_number, product_id, store_id)
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_subscriptions_phone ON product_subscriptions(phone_number);
|
|
CREATE INDEX IF NOT EXISTS idx_subscriptions_product ON product_subscriptions(product_id);
|
|
CREATE INDEX IF NOT EXISTS idx_subscriptions_store ON product_subscriptions(store_id);
|
|
CREATE INDEX IF NOT EXISTS idx_subscriptions_active ON product_subscriptions(active);
|
|
|
|
-- Notification log
|
|
CREATE TABLE IF NOT EXISTS notification_log (
|
|
id SERIAL PRIMARY KEY,
|
|
subscription_id INTEGER REFERENCES product_subscriptions(id) ON DELETE SET NULL,
|
|
stock_change_id INTEGER REFERENCES stock_changes(id) ON DELETE SET NULL,
|
|
phone_number VARCHAR(20) NOT NULL,
|
|
message TEXT NOT NULL,
|
|
notification_type VARCHAR(50) NOT NULL, -- 'restock', 'out_of_stock'
|
|
status VARCHAR(50) DEFAULT 'pending', -- 'pending', 'sent', 'failed', 'bounced'
|
|
provider VARCHAR(50), -- 'twilio', 'aws_sns', etc.
|
|
provider_message_id VARCHAR(255),
|
|
error_message TEXT,
|
|
sent_at TIMESTAMP,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_notification_log_phone ON notification_log(phone_number);
|
|
CREATE INDEX IF NOT EXISTS idx_notification_log_status ON notification_log(status);
|
|
CREATE INDEX IF NOT EXISTS idx_notification_log_type ON notification_log(notification_type);
|
|
CREATE INDEX IF NOT EXISTS idx_notification_log_created_at ON notification_log(created_at);
|
|
|
|
-- Reorder triggers (for internal system integration)
|
|
CREATE TABLE IF NOT EXISTS reorder_triggers (
|
|
id SERIAL PRIMARY KEY,
|
|
product_id INTEGER NOT NULL REFERENCES products(id) ON DELETE CASCADE,
|
|
store_id INTEGER NOT NULL REFERENCES stores(id) ON DELETE CASCADE,
|
|
stock_change_id INTEGER REFERENCES stock_changes(id) ON DELETE SET NULL,
|
|
triggered_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
processed BOOLEAN DEFAULT FALSE,
|
|
processed_at TIMESTAMP,
|
|
webhook_url TEXT,
|
|
webhook_response TEXT,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_reorder_triggers_processed ON reorder_triggers(processed);
|
|
CREATE INDEX IF NOT EXISTS idx_reorder_triggers_product ON reorder_triggers(product_id);
|
|
CREATE INDEX IF NOT EXISTS idx_reorder_triggers_store ON reorder_triggers(store_id);
|
|
|
|
-- Comments
|
|
COMMENT ON TABLE stock_changes IS 'Tracks all product stock status changes';
|
|
COMMENT ON TABLE product_subscriptions IS 'Customer subscriptions for product stock notifications';
|
|
COMMENT ON TABLE notification_log IS 'Log of all SMS notifications sent';
|
|
COMMENT ON TABLE reorder_triggers IS 'Triggers for automatic reordering system';
|