-- Enable strict error reporting SET session_replication_role = 'replica'; -- Disable foreign key checks temporarily -- Create tables CREATE TABLE products ( pid BIGINT NOT NULL, title VARCHAR(255) NOT NULL, description TEXT, SKU VARCHAR(50) NOT NULL, created_at TIMESTAMP, first_received TIMESTAMP, stock_quantity INTEGER DEFAULT 0, preorder_count INTEGER DEFAULT 0, notions_inv_count INTEGER DEFAULT 0, price DECIMAL(10, 3) NOT NULL, regular_price DECIMAL(10, 3) NOT NULL, cost_price DECIMAL(10, 3), landing_cost_price DECIMAL(10, 3), barcode VARCHAR(50), harmonized_tariff_code VARCHAR(20), updated_at TIMESTAMP, visible BOOLEAN DEFAULT true, managing_stock BOOLEAN DEFAULT true, replenishable BOOLEAN DEFAULT true, vendor VARCHAR(100), vendor_reference VARCHAR(100), notions_reference VARCHAR(100), permalink VARCHAR(255), categories TEXT, image VARCHAR(255), image_175 VARCHAR(255), image_full VARCHAR(255), brand VARCHAR(100), line VARCHAR(100), subline VARCHAR(100), artist VARCHAR(100), options TEXT, tags TEXT, moq INTEGER DEFAULT 1, uom INTEGER DEFAULT 1, rating DECIMAL(10,2) DEFAULT 0.00, reviews INTEGER DEFAULT 0, weight DECIMAL(10,3), length DECIMAL(10,3), width DECIMAL(10,3), height DECIMAL(10,3), country_of_origin VARCHAR(5), location VARCHAR(50), total_sold INTEGER DEFAULT 0, baskets INTEGER DEFAULT 0, notifies INTEGER DEFAULT 0, date_last_sold DATE, updated TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (pid) ); -- Create indexes for products table CREATE INDEX idx_products_sku ON products(SKU); CREATE INDEX idx_products_vendor ON products(vendor); CREATE INDEX idx_products_brand ON products(brand); CREATE INDEX idx_products_location ON products(location); CREATE INDEX idx_products_total_sold ON products(total_sold); CREATE INDEX idx_products_date_last_sold ON products(date_last_sold); CREATE INDEX idx_products_updated ON products(updated); -- Create categories table with hierarchy support CREATE TABLE categories ( cat_id BIGINT PRIMARY KEY, name VARCHAR(100) NOT NULL, type SMALLINT NOT NULL, parent_id BIGINT, description TEXT, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, status VARCHAR(20) DEFAULT 'active', FOREIGN KEY (parent_id) REFERENCES categories(cat_id) ); COMMENT ON COLUMN categories.type IS '10=section, 11=category, 12=subcategory, 13=subsubcategory, 1=company, 2=line, 3=subline, 40=artist'; CREATE INDEX idx_categories_parent ON categories(parent_id); CREATE INDEX idx_categories_type ON categories(type); CREATE INDEX idx_categories_status ON categories(status); CREATE INDEX idx_categories_name_type ON categories(name, type); -- Create product_categories junction table CREATE TABLE product_categories ( cat_id BIGINT NOT NULL, pid BIGINT NOT NULL, PRIMARY KEY (pid, cat_id), FOREIGN KEY (pid) REFERENCES products(pid) ON DELETE CASCADE, FOREIGN KEY (cat_id) REFERENCES categories(cat_id) ON DELETE CASCADE ); CREATE INDEX idx_product_categories_category ON product_categories(cat_id); CREATE INDEX idx_product_categories_product ON product_categories(pid); -- Create orders table with its indexes CREATE TABLE orders ( id BIGSERIAL PRIMARY KEY, order_number VARCHAR(50) NOT NULL, pid BIGINT NOT NULL, SKU VARCHAR(50) NOT NULL, date DATE NOT NULL, price DECIMAL(10,3) NOT NULL, quantity INTEGER NOT NULL, discount DECIMAL(10,3) DEFAULT 0.000, tax DECIMAL(10,3) DEFAULT 0.000, tax_included BOOLEAN DEFAULT false, shipping DECIMAL(10,3) DEFAULT 0.000, costeach DECIMAL(10,3) DEFAULT 0.000, customer VARCHAR(50) NOT NULL, customer_name VARCHAR(100), status VARCHAR(20) DEFAULT 'pending', canceled BOOLEAN DEFAULT false, updated TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, UNIQUE (order_number, pid) ); CREATE INDEX idx_orders_number ON orders(order_number); CREATE INDEX idx_orders_pid ON orders(pid); CREATE INDEX idx_orders_customer ON orders(customer); CREATE INDEX idx_orders_date ON orders(date); CREATE INDEX idx_orders_status ON orders(status); CREATE INDEX idx_orders_metrics ON orders(pid, date, canceled); CREATE INDEX idx_orders_updated ON orders(updated); -- Create purchase_orders table with its indexes CREATE TABLE purchase_orders ( id BIGSERIAL PRIMARY KEY, po_id VARCHAR(50) NOT NULL, vendor VARCHAR(100) NOT NULL, date DATE NOT NULL, expected_date DATE, pid BIGINT NOT NULL, sku VARCHAR(50) NOT NULL, name VARCHAR(100) NOT NULL, cost_price DECIMAL(10, 3) NOT NULL, po_cost_price DECIMAL(10, 3) NOT NULL, status SMALLINT DEFAULT 1, receiving_status SMALLINT DEFAULT 1, notes TEXT, long_note TEXT, ordered INTEGER NOT NULL, received INTEGER DEFAULT 0, received_date DATE, last_received_date DATE, received_by VARCHAR(100), receiving_history JSONB, updated TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (pid) REFERENCES products(pid), UNIQUE (po_id, pid) ); COMMENT ON COLUMN purchase_orders.name IS 'Product name from products.description'; COMMENT ON COLUMN purchase_orders.po_cost_price IS 'Original cost from PO, before receiving adjustments'; COMMENT ON COLUMN purchase_orders.status IS '0=canceled,1=created,10=electronically_ready_send,11=ordered,12=preordered,13=electronically_sent,15=receiving_started,50=done'; COMMENT ON COLUMN purchase_orders.receiving_status IS '0=canceled,1=created,30=partial_received,40=full_received,50=paid'; COMMENT ON COLUMN purchase_orders.receiving_history IS 'Array of receiving records with qty, date, cost, receiving_id, and alt_po flag'; CREATE INDEX idx_po_id ON purchase_orders(po_id); CREATE INDEX idx_po_vendor ON purchase_orders(vendor); CREATE INDEX idx_po_status ON purchase_orders(status); CREATE INDEX idx_po_receiving_status ON purchase_orders(receiving_status); CREATE INDEX idx_po_metrics ON purchase_orders(pid, date, status, ordered, received); CREATE INDEX idx_po_metrics_receiving ON purchase_orders(pid, date, receiving_status, received_date); CREATE INDEX idx_po_product_date ON purchase_orders(pid, date); CREATE INDEX idx_po_product_status ON purchase_orders(pid, status); CREATE INDEX idx_po_updated ON purchase_orders(updated); SET session_replication_role = 'origin'; -- Re-enable foreign key checks -- Create views for common calculations -- product_sales_trends view moved to metrics-schema.sql