Add receivings table, split PO import
This commit is contained in:
@@ -7,7 +7,7 @@ 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
|
||||
ELSIF TG_TABLE_NAME IN ('products', 'orders', 'purchase_orders', 'receivings') THEN
|
||||
NEW.updated = CURRENT_TIMESTAMP;
|
||||
END IF;
|
||||
RETURN NEW;
|
||||
@@ -159,27 +159,24 @@ 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
|
||||
-- This table now focuses solely on purchase order intent, not receivings
|
||||
CREATE TABLE purchase_orders (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
po_id TEXT NOT NULL,
|
||||
vendor TEXT NOT NULL,
|
||||
date DATE NOT NULL,
|
||||
date TIMESTAMP WITH TIME ZONE 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,
|
||||
supplier_id INTEGER,
|
||||
date_created TIMESTAMP WITH TIME ZONE,
|
||||
date_ordered TIMESTAMP WITH TIME ZONE,
|
||||
updated TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
FOREIGN KEY (pid) REFERENCES products(pid) ON DELETE CASCADE,
|
||||
UNIQUE (po_id, pid)
|
||||
@@ -192,21 +189,61 @@ CREATE TRIGGER update_purchase_orders_updated
|
||||
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.po_cost_price IS 'Original cost from PO';
|
||||
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);
|
||||
CREATE INDEX idx_po_supplier_id ON purchase_orders(supplier_id);
|
||||
|
||||
-- Create receivings table to track actual receipt of goods
|
||||
CREATE TABLE receivings (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
receiving_id TEXT NOT NULL,
|
||||
pid BIGINT NOT NULL,
|
||||
sku TEXT NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
vendor TEXT,
|
||||
qty_each INTEGER NOT NULL,
|
||||
qty_each_orig INTEGER,
|
||||
cost_each NUMERIC(14, 5) NOT NULL,
|
||||
cost_each_orig NUMERIC(14, 5),
|
||||
received_by INTEGER,
|
||||
received_by_name TEXT,
|
||||
received_date TIMESTAMP WITH TIME ZONE NOT NULL,
|
||||
receiving_created_date TIMESTAMP WITH TIME ZONE,
|
||||
supplier_id INTEGER,
|
||||
status TEXT DEFAULT 'created',
|
||||
updated TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
FOREIGN KEY (pid) REFERENCES products(pid) ON DELETE CASCADE,
|
||||
UNIQUE (receiving_id, pid)
|
||||
);
|
||||
|
||||
-- Create trigger for receivings
|
||||
CREATE TRIGGER update_receivings_updated
|
||||
BEFORE UPDATE ON receivings
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_updated_column();
|
||||
|
||||
COMMENT ON COLUMN receivings.status IS 'canceled, created, partial_received, full_received, paid';
|
||||
COMMENT ON COLUMN receivings.qty_each_orig IS 'Original quantity from the source system';
|
||||
COMMENT ON COLUMN receivings.cost_each_orig IS 'Original cost from the source system';
|
||||
COMMENT ON COLUMN receivings.vendor IS 'Vendor name, same as in purchase_orders';
|
||||
|
||||
CREATE INDEX idx_receivings_id ON receivings(receiving_id);
|
||||
CREATE INDEX idx_receivings_pid ON receivings(pid);
|
||||
CREATE INDEX idx_receivings_sku ON receivings(sku);
|
||||
CREATE INDEX idx_receivings_status ON receivings(status);
|
||||
CREATE INDEX idx_receivings_received_date ON receivings(received_date);
|
||||
CREATE INDEX idx_receivings_supplier_id ON receivings(supplier_id);
|
||||
CREATE INDEX idx_receivings_vendor ON receivings(vendor);
|
||||
CREATE INDEX idx_receivings_updated ON receivings(updated);
|
||||
|
||||
SET session_replication_role = 'origin'; -- Re-enable foreign key checks
|
||||
|
||||
|
||||
Reference in New Issue
Block a user