-- Create UUID extension for generating UUIDs CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- Create users table CREATE TABLE users ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), email VARCHAR(255) UNIQUE NOT NULL, first_name VARCHAR(100), last_name VARCHAR(100), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), last_login TIMESTAMP WITH TIME ZONE, current_auth_id UUID, -- Foreign key to authentication table, NULL if logged out is_active BOOLEAN DEFAULT TRUE ); -- Create authentication table CREATE TABLE authentications ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), code VARCHAR(6) NOT NULL, -- 6-digit authentication code created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), expires_at TIMESTAMP WITH TIME ZONE NOT NULL, -- When this authentication code expires is_used BOOLEAN DEFAULT FALSE -- Track if this code has been used ); -- Add foreign key constraint ALTER TABLE users ADD CONSTRAINT fk_user_authentication FOREIGN KEY (current_auth_id) REFERENCES authentications (id) ON DELETE SET NULL; -- If auth record is deleted, just set NULL in users table -- Create product_categories table CREATE TABLE product_categories ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name VARCHAR(50) NOT NULL UNIQUE, description TEXT ); -- Insert the three main product categories INSERT INTO product_categories (name, description) VALUES ('Rock', 'Natural stone specimens of various types, sizes, and origins'), ('Bone', 'Preserved bones from various sources and species'), ('Stick', 'Natural wooden sticks and branches of different types and sizes'); -- Create products table CREATE TABLE products ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name VARCHAR(255) NOT NULL, description TEXT, category_id UUID NOT NULL REFERENCES product_categories(id), price DECIMAL(10, 2) NOT NULL, stock_quantity INTEGER NOT NULL DEFAULT 0, weight_grams DECIMAL(10, 2), length_cm DECIMAL(10, 2), width_cm DECIMAL(10, 2), height_cm DECIMAL(10, 2), origin VARCHAR(100), age VARCHAR(100), material_type VARCHAR(100), color VARCHAR(100), image_url VARCHAR(255), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), is_active BOOLEAN DEFAULT TRUE ); -- Create orders table CREATE TABLE orders ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL, status VARCHAR(50) NOT NULL DEFAULT 'pending', -- pending, processing, shipped, delivered, cancelled total_amount DECIMAL(10, 2) NOT NULL, shipping_address TEXT, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), FOREIGN KEY (user_id) REFERENCES users (id) ); -- Create order_items table for order details CREATE TABLE order_items ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), order_id UUID NOT NULL, product_id UUID NOT NULL, quantity INTEGER NOT NULL, price_at_purchase DECIMAL(10, 2) NOT NULL, -- Store price at time of purchase FOREIGN KEY (order_id) REFERENCES orders (id) ON DELETE CASCADE, FOREIGN KEY (product_id) REFERENCES products (id) ); -- Create shopping cart table CREATE TABLE carts ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), FOREIGN KEY (user_id) REFERENCES users (id) ON DELETE CASCADE ); -- Create cart items table CREATE TABLE cart_items ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), cart_id UUID NOT NULL, product_id UUID NOT NULL, quantity INTEGER NOT NULL DEFAULT 1, added_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), FOREIGN KEY (cart_id) REFERENCES carts (id) ON DELETE CASCADE, FOREIGN KEY (product_id) REFERENCES products (id), UNIQUE(cart_id, product_id) -- Prevent duplicate products in cart ); -- Create indexes for performance CREATE INDEX idx_user_email ON users(email); CREATE INDEX idx_auth_code ON authentications(code); -- Create tags table CREATE TABLE tags ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name VARCHAR(50) NOT NULL UNIQUE, description TEXT ); -- Create product_tags junction table CREATE TABLE product_tags ( product_id UUID NOT NULL REFERENCES products(id) ON DELETE CASCADE, tag_id UUID NOT NULL REFERENCES tags(id) ON DELETE CASCADE, PRIMARY KEY (product_id, tag_id) ); -- Insert common tags for natural items INSERT INTO tags (name, description) VALUES ('Polished', 'Items that have been polished to a smooth finish'), ('Raw', 'Items in their natural, unprocessed state'), ('Rare', 'Uncommon or hard-to-find specimens'), ('Fossil', 'Preserved remains or traces of ancient organisms'), ('Decorative', 'Items selected for their aesthetic appeal'), ('Educational', 'Items with significant educational value'), ('Collectible', 'Items that are part of a recognized collection series'); CREATE INDEX idx_product_name ON products(name); CREATE INDEX idx_product_category ON products(category_id); CREATE INDEX idx_product_tags_product ON product_tags(product_id); CREATE INDEX idx_product_tags_tag ON product_tags(tag_id); CREATE INDEX idx_orders_user_id ON orders(user_id); CREATE INDEX idx_order_items_order_id ON order_items(order_id); -- Create a function to update the updated_at timestamp CREATE OR REPLACE FUNCTION update_modified_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE 'plpgsql'; -- Create triggers to automatically update the updated_at column CREATE TRIGGER update_users_modtime BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_modified_column(); CREATE TRIGGER update_products_modtime BEFORE UPDATE ON products FOR EACH ROW EXECUTE FUNCTION update_modified_column(); CREATE TRIGGER update_orders_modtime BEFORE UPDATE ON orders FOR EACH ROW EXECUTE FUNCTION update_modified_column(); CREATE TRIGGER update_carts_modtime BEFORE UPDATE ON carts FOR EACH ROW EXECUTE FUNCTION update_modified_column();