66 lines
2.5 KiB
PL/PgSQL
66 lines
2.5 KiB
PL/PgSQL
-- Migration: Create Customers Table for Customer Authentication
|
|
-- Date: 2026-01-15
|
|
-- Description: Customer accounts for frontend login, email verification, and newsletter
|
|
|
|
-- Create customers table
|
|
CREATE TABLE IF NOT EXISTS customers (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
first_name VARCHAR(100) NOT NULL,
|
|
last_name VARCHAR(100) NOT NULL,
|
|
email VARCHAR(255) NOT NULL UNIQUE,
|
|
password_hash VARCHAR(255) NOT NULL,
|
|
phone VARCHAR(50),
|
|
|
|
-- Email verification
|
|
email_verified BOOLEAN DEFAULT FALSE,
|
|
verification_code VARCHAR(6),
|
|
verification_code_expires TIMESTAMP WITH TIME ZONE,
|
|
|
|
-- Password reset
|
|
reset_token VARCHAR(100),
|
|
reset_token_expires TIMESTAMP WITH TIME ZONE,
|
|
|
|
-- Account status
|
|
is_active BOOLEAN DEFAULT TRUE,
|
|
|
|
-- Newsletter subscription
|
|
newsletter_subscribed BOOLEAN DEFAULT TRUE,
|
|
|
|
-- OAuth providers (for future Google/Facebook/Apple login)
|
|
oauth_provider VARCHAR(50),
|
|
oauth_provider_id VARCHAR(255),
|
|
|
|
-- Metadata
|
|
last_login TIMESTAMP WITH TIME ZONE,
|
|
login_count INTEGER DEFAULT 0,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Create indexes for better performance
|
|
CREATE INDEX IF NOT EXISTS idx_customers_email ON customers(email);
|
|
CREATE INDEX IF NOT EXISTS idx_customers_verification_code ON customers(verification_code) WHERE verification_code IS NOT NULL;
|
|
CREATE INDEX IF NOT EXISTS idx_customers_reset_token ON customers(reset_token) WHERE reset_token IS NOT NULL;
|
|
CREATE INDEX IF NOT EXISTS idx_customers_newsletter ON customers(newsletter_subscribed) WHERE newsletter_subscribed = TRUE;
|
|
CREATE INDEX IF NOT EXISTS idx_customers_created_at ON customers(created_at DESC);
|
|
|
|
-- Create trigger to auto-update updated_at
|
|
CREATE OR REPLACE FUNCTION update_customers_updated_at()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.updated_at = CURRENT_TIMESTAMP;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
DROP TRIGGER IF EXISTS customers_updated_at_trigger ON customers;
|
|
CREATE TRIGGER customers_updated_at_trigger
|
|
BEFORE UPDATE ON customers
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_customers_updated_at();
|
|
|
|
-- Add comment for documentation
|
|
COMMENT ON TABLE customers IS 'Customer accounts for frontend authentication and newsletter';
|
|
COMMENT ON COLUMN customers.verification_code IS '6-digit code sent via email for verification';
|
|
COMMENT ON COLUMN customers.newsletter_subscribed IS 'Whether customer wants to receive newsletter emails';
|