-- Enable strict error reporting SET sql_mode = 'STRICT_ALL_TABLES,ERROR_FOR_DIVISION_BY_ZERO,NO_ZERO_DATE,NO_ZERO_IN_DATE,NO_ENGINE_SUBSTITUTION'; SET FOREIGN_KEY_CHECKS = 0; -- Create tables CREATE TABLE products ( pid BIGINT NOT NULL, title VARCHAR(255) NOT NULL, description TEXT, SKU VARCHAR(50) NOT NULL, created_at TIMESTAMP NULL, first_received TIMESTAMP NULL, stock_quantity INT DEFAULT 0, preorder_count INT DEFAULT 0, notions_inv_count INT 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 INT DEFAULT 1, uom INT DEFAULT 1, rating DECIMAL(10,2) DEFAULT 0.00, reviews INT UNSIGNED 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 INT UNSIGNED DEFAULT 0, baskets INT UNSIGNED DEFAULT 0, notifies INT UNSIGNED DEFAULT 0, date_last_sold DATE, PRIMARY KEY (pid), INDEX idx_sku (SKU), INDEX idx_vendor (vendor), INDEX idx_brand (brand), INDEX idx_location (location), INDEX idx_total_sold (total_sold), INDEX idx_date_last_sold (date_last_sold) ) ENGINE=InnoDB; -- Create categories table with hierarchy support CREATE TABLE categories ( cat_id BIGINT PRIMARY KEY, name VARCHAR(100) NOT NULL, type SMALLINT NOT NULL COMMENT '10=section, 11=category, 12=subcategory, 13=subsubcategory, 1=company, 2=line, 3=subline, 40=artist', parent_id BIGINT, description TEXT, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, status VARCHAR(20) DEFAULT 'active', FOREIGN KEY (parent_id) REFERENCES categories(cat_id), INDEX idx_parent (parent_id), INDEX idx_type (type), INDEX idx_status (status), INDEX idx_name_type (name, type) ) ENGINE=InnoDB; -- Create vendor_details table CREATE TABLE vendor_details ( vendor VARCHAR(100) PRIMARY KEY, contact_name VARCHAR(100), email VARCHAR(255), phone VARCHAR(50), status VARCHAR(20) DEFAULT 'active', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, INDEX idx_status (status) ) ENGINE=InnoDB; -- 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, INDEX idx_category (cat_id), INDEX idx_product (pid) ) ENGINE=InnoDB; -- Create orders table with its indexes CREATE TABLE IF NOT EXISTS orders ( id BIGINT NOT NULL AUTO_INCREMENT, 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 INT NOT NULL, discount DECIMAL(10,3) DEFAULT 0.000, tax DECIMAL(10,3) DEFAULT 0.000, tax_included TINYINT(1) DEFAULT 0, 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 TINYINT(1) DEFAULT 0, PRIMARY KEY (id), UNIQUE KEY unique_order_line (order_number, pid), KEY order_number (order_number), KEY pid (pid), KEY customer (customer), KEY date (date), KEY status (status), INDEX idx_orders_metrics (pid, date, canceled) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- Create purchase_orders table with its indexes CREATE TABLE purchase_orders ( id BIGINT AUTO_INCREMENT 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 COMMENT 'Product name from products.description', cost_price DECIMAL(10, 3) NOT NULL, po_cost_price DECIMAL(10, 3) NOT NULL COMMENT 'Original cost from PO, before receiving adjustments', status TINYINT UNSIGNED DEFAULT 1 COMMENT '0=canceled,1=created,10=electronically_ready_send,11=ordered,12=preordered,13=electronically_sent,15=receiving_started,50=done', receiving_status TINYINT UNSIGNED DEFAULT 1 COMMENT '0=canceled,1=created,30=partial_received,40=full_received,50=paid', notes TEXT, long_note TEXT, ordered INT NOT NULL, received INT DEFAULT 0, received_date DATE COMMENT 'Date of first receiving', last_received_date DATE COMMENT 'Date of most recent receiving', received_by VARCHAR(100) COMMENT 'Name of person who first received this PO line', receiving_history JSON COMMENT 'Array of receiving records with qty, date, cost, receiving_id, and alt_po flag', FOREIGN KEY (pid) REFERENCES products(pid), INDEX idx_po_id (po_id), INDEX idx_vendor (vendor), INDEX idx_status (status), INDEX idx_receiving_status (receiving_status), INDEX idx_purchase_orders_metrics (pid, date, status, ordered, received), INDEX idx_po_metrics (pid, date, receiving_status, received_date), INDEX idx_po_product_date (pid, date), INDEX idx_po_product_status (pid, status), UNIQUE KEY unique_po_product (po_id, pid) ) ENGINE=InnoDB; SET FOREIGN_KEY_CHECKS = 1; -- Create views for common calculations -- product_sales_trends view moved to metrics-schema.sql