214 lines
7.6 KiB
PL/PgSQL
214 lines
7.6 KiB
PL/PgSQL
-- Enable strict error reporting
|
|
SET session_replication_role = 'replica'; -- Disable foreign key checks temporarily
|
|
|
|
-- Create function for updating timestamps
|
|
CREATE OR REPLACE FUNCTION update_updated_column() RETURNS TRIGGER AS $func$
|
|
BEGIN
|
|
-- Check which table is being updated and use the appropriate column
|
|
IF TG_TABLE_NAME = 'categories' THEN
|
|
NEW.updated_at = CURRENT_TIMESTAMP;
|
|
ELSIF TG_TABLE_NAME IN ('products', 'orders', 'purchase_orders') THEN
|
|
NEW.updated = CURRENT_TIMESTAMP;
|
|
END IF;
|
|
RETURN NEW;
|
|
END;
|
|
$func$ language plpgsql;
|
|
|
|
-- Create tables
|
|
CREATE TABLE products (
|
|
pid BIGINT NOT NULL,
|
|
title TEXT NOT NULL,
|
|
description TEXT,
|
|
sku TEXT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE,
|
|
first_received TIMESTAMP WITH TIME ZONE,
|
|
stock_quantity INTEGER DEFAULT 0,
|
|
preorder_count INTEGER DEFAULT 0,
|
|
notions_inv_count INTEGER DEFAULT 0,
|
|
price NUMERIC(14, 4) NOT NULL,
|
|
regular_price NUMERIC(14, 4) NOT NULL,
|
|
cost_price NUMERIC(14, 4),
|
|
landing_cost_price NUMERIC(14, 4),
|
|
barcode TEXT,
|
|
harmonized_tariff_code TEXT,
|
|
updated_at TIMESTAMP WITH TIME ZONE,
|
|
visible BOOLEAN DEFAULT true,
|
|
managing_stock BOOLEAN DEFAULT true,
|
|
replenishable BOOLEAN DEFAULT true,
|
|
vendor TEXT,
|
|
vendor_reference TEXT,
|
|
notions_reference TEXT,
|
|
permalink TEXT,
|
|
categories TEXT,
|
|
image TEXT,
|
|
image_175 TEXT,
|
|
image_full TEXT,
|
|
brand TEXT,
|
|
line TEXT,
|
|
subline TEXT,
|
|
artist TEXT,
|
|
options TEXT,
|
|
tags TEXT,
|
|
moq INTEGER DEFAULT 1,
|
|
uom INTEGER DEFAULT 1,
|
|
rating NUMERIC(14, 4) DEFAULT 0.00,
|
|
reviews INTEGER DEFAULT 0,
|
|
weight NUMERIC(14, 4),
|
|
length NUMERIC(14, 4),
|
|
width NUMERIC(14, 4),
|
|
height NUMERIC(14, 4),
|
|
country_of_origin TEXT,
|
|
location TEXT,
|
|
total_sold INTEGER DEFAULT 0,
|
|
baskets INTEGER DEFAULT 0,
|
|
notifies INTEGER DEFAULT 0,
|
|
date_last_sold DATE,
|
|
updated TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
PRIMARY KEY (pid)
|
|
);
|
|
|
|
-- Create trigger for products
|
|
CREATE TRIGGER update_products_updated
|
|
BEFORE UPDATE ON products
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_updated_column();
|
|
|
|
-- 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_visible ON products(visible);
|
|
CREATE INDEX idx_products_replenishable ON products(replenishable);
|
|
CREATE INDEX idx_products_updated ON products(updated);
|
|
|
|
-- Create categories table with hierarchy support
|
|
CREATE TABLE categories (
|
|
cat_id BIGINT PRIMARY KEY,
|
|
name TEXT NOT NULL,
|
|
type SMALLINT NOT NULL,
|
|
parent_id BIGINT,
|
|
description TEXT,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
updated TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
status TEXT DEFAULT 'active',
|
|
FOREIGN KEY (parent_id) REFERENCES categories(cat_id) ON DELETE SET NULL
|
|
);
|
|
|
|
-- Create trigger for categories
|
|
CREATE TRIGGER update_categories_updated_at
|
|
BEFORE UPDATE ON categories
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_updated_column();
|
|
|
|
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 ON categories(name);
|
|
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 orders table with its indexes
|
|
CREATE TABLE orders (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
order_number TEXT NOT NULL,
|
|
pid BIGINT NOT NULL,
|
|
sku TEXT NOT NULL,
|
|
date TIMESTAMP WITH TIME ZONE NOT NULL,
|
|
price NUMERIC(14, 4) NOT NULL,
|
|
quantity INTEGER NOT NULL,
|
|
discount NUMERIC(14, 4) DEFAULT 0.0000,
|
|
tax NUMERIC(14, 4) DEFAULT 0.0000,
|
|
tax_included BOOLEAN DEFAULT false,
|
|
shipping NUMERIC(14, 4) DEFAULT 0.0000,
|
|
costeach NUMERIC(14, 4) DEFAULT 0.0000,
|
|
customer TEXT NOT NULL,
|
|
customer_name TEXT,
|
|
status TEXT DEFAULT 'pending',
|
|
canceled BOOLEAN DEFAULT false,
|
|
updated TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
UNIQUE (order_number, pid),
|
|
FOREIGN KEY (pid) REFERENCES products(pid) ON DELETE RESTRICT
|
|
);
|
|
|
|
-- Create trigger for orders
|
|
CREATE TRIGGER update_orders_updated
|
|
BEFORE UPDATE ON orders
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_updated_column();
|
|
|
|
CREATE INDEX idx_orders_number ON orders(order_number);
|
|
CREATE INDEX idx_orders_pid ON orders(pid);
|
|
CREATE INDEX idx_orders_sku ON orders(sku);
|
|
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_pid_date ON orders(pid, date);
|
|
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 TEXT NOT NULL,
|
|
vendor TEXT NOT NULL,
|
|
date DATE NOT NULL,
|
|
expected_date DATE,
|
|
pid BIGINT NOT NULL,
|
|
sku TEXT NOT NULL,
|
|
name TEXT NOT NULL,
|
|
cost_price NUMERIC(14, 4) NOT NULL,
|
|
po_cost_price NUMERIC(14, 4) NOT NULL,
|
|
status TEXT DEFAULT 'created',
|
|
receiving_status TEXT DEFAULT 'created',
|
|
notes TEXT,
|
|
long_note TEXT,
|
|
ordered INTEGER NOT NULL,
|
|
received INTEGER DEFAULT 0,
|
|
received_date DATE,
|
|
last_received_date DATE,
|
|
received_by TEXT,
|
|
receiving_history JSONB,
|
|
updated TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
FOREIGN KEY (pid) REFERENCES products(pid) ON DELETE CASCADE,
|
|
UNIQUE (po_id, pid)
|
|
);
|
|
|
|
-- Create trigger for purchase_orders
|
|
CREATE TRIGGER update_purchase_orders_updated
|
|
BEFORE UPDATE ON purchase_orders
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_updated_column();
|
|
|
|
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 'canceled, created, electronically_ready_send, ordered, preordered, electronically_sent, receiving_started, done';
|
|
COMMENT ON COLUMN purchase_orders.receiving_status IS 'canceled, created, partial_received, full_received, 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_sku ON purchase_orders(sku);
|
|
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_expected_date ON purchase_orders(expected_date);
|
|
CREATE INDEX idx_po_last_received_date ON purchase_orders(last_received_date);
|
|
CREATE INDEX idx_po_pid_status ON purchase_orders(pid, status);
|
|
CREATE INDEX idx_po_pid_date ON purchase_orders(pid, date);
|
|
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 |