Put back files
This commit is contained in:
196
inventory-server/db/config-schema-new.sql
Normal file
196
inventory-server/db/config-schema-new.sql
Normal file
@@ -0,0 +1,196 @@
|
||||
-- Create function for updating timestamps if it doesn't exist
|
||||
CREATE OR REPLACE FUNCTION update_updated_column()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated = CURRENT_TIMESTAMP;
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ language 'plpgsql';
|
||||
|
||||
-- Create function for updating updated_at timestamps
|
||||
CREATE OR REPLACE FUNCTION update_updated_at_column()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at = CURRENT_TIMESTAMP;
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ language 'plpgsql';
|
||||
|
||||
-- Drop tables in reverse order of dependency
|
||||
DROP TABLE IF EXISTS public.settings_product CASCADE;
|
||||
DROP TABLE IF EXISTS public.settings_vendor CASCADE;
|
||||
DROP TABLE IF EXISTS public.settings_global CASCADE;
|
||||
|
||||
-- Table Definition: settings_global
|
||||
CREATE TABLE public.settings_global (
|
||||
setting_key VARCHAR PRIMARY KEY,
|
||||
setting_value VARCHAR NOT NULL,
|
||||
description TEXT,
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
-- Table Definition: settings_vendor
|
||||
CREATE TABLE public.settings_vendor (
|
||||
vendor VARCHAR PRIMARY KEY, -- Matches products.vendor
|
||||
default_lead_time_days INT,
|
||||
default_days_of_stock INT,
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
-- Index for faster lookups if needed (PK usually sufficient)
|
||||
-- CREATE INDEX idx_settings_vendor_vendor ON public.settings_vendor(vendor);
|
||||
|
||||
-- Table Definition: settings_product
|
||||
CREATE TABLE public.settings_product (
|
||||
pid INT8 PRIMARY KEY,
|
||||
lead_time_days INT, -- Overrides vendor/global
|
||||
days_of_stock INT, -- Overrides vendor/global
|
||||
safety_stock INT DEFAULT 0, -- Minimum desired stock level
|
||||
forecast_method VARCHAR DEFAULT 'standard', -- e.g., 'standard', 'seasonal'
|
||||
exclude_from_forecast BOOLEAN DEFAULT FALSE,
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
CONSTRAINT fk_settings_product_pid FOREIGN KEY (pid) REFERENCES public.products(pid) ON DELETE CASCADE ON UPDATE CASCADE
|
||||
);
|
||||
|
||||
|
||||
-- Description: Inserts or updates standard default global settings.
|
||||
-- Safe to rerun; will update existing keys with these default values.
|
||||
-- Dependencies: `settings_global` table must exist.
|
||||
-- Frequency: Run once initially, or rerun if you want to reset global defaults.
|
||||
|
||||
INSERT INTO public.settings_global (setting_key, setting_value, description) VALUES
|
||||
('abc_revenue_threshold_a', '0.80', 'Revenue percentage for Class A (cumulative)'),
|
||||
('abc_revenue_threshold_b', '0.95', 'Revenue percentage for Class B (cumulative)'),
|
||||
('abc_calculation_basis', 'revenue_30d', 'Metric for ABC calc (revenue_30d, sales_30d, lifetime_revenue)'),
|
||||
('abc_calculation_period', '30', 'Days period for ABC calculation if not lifetime'),
|
||||
('default_forecast_method', 'standard', 'Default forecast method (standard, seasonal)'),
|
||||
('default_lead_time_days', '14', 'Global default lead time in days'),
|
||||
('default_days_of_stock', '30', 'Global default days of stock coverage target'),
|
||||
-- Set default safety stock to 0 units. Can be overridden per product.
|
||||
-- If you wanted safety stock in days, you'd store 'days' here and calculate units later.
|
||||
('default_safety_stock_units', '0', 'Global default safety stock in units')
|
||||
ON CONFLICT (setting_key) DO UPDATE SET
|
||||
setting_value = EXCLUDED.setting_value,
|
||||
description = EXCLUDED.description,
|
||||
updated_at = CURRENT_TIMESTAMP; -- Update timestamp if default value changes
|
||||
|
||||
|
||||
|
||||
-- Description: Creates placeholder rows in `settings_vendor` for each unique vendor
|
||||
-- found in the `products` table. Does NOT set specific overrides.
|
||||
-- Safe to rerun; will NOT overwrite existing vendor settings.
|
||||
-- Dependencies: `settings_vendor` table must exist, `products` table populated.
|
||||
-- Frequency: Run once after initial product load, or periodically if new vendors are added.
|
||||
|
||||
INSERT INTO public.settings_vendor (
|
||||
vendor,
|
||||
default_lead_time_days,
|
||||
default_days_of_stock
|
||||
-- updated_at will use its default CURRENT_TIMESTAMP on insert
|
||||
)
|
||||
SELECT
|
||||
DISTINCT p.vendor,
|
||||
-- Explicitly cast NULL to INTEGER to resolve type mismatch
|
||||
CAST(NULL AS INTEGER),
|
||||
CAST(NULL AS INTEGER)
|
||||
FROM
|
||||
public.products p
|
||||
WHERE
|
||||
p.vendor IS NOT NULL
|
||||
AND p.vendor <> '' -- Exclude blank vendors if necessary
|
||||
|
||||
ON CONFLICT (vendor) DO NOTHING; -- IMPORTANT: Do not overwrite existing vendor settings
|
||||
|
||||
SELECT COUNT(*) FROM public.settings_vendor; -- Verify rows were inserted
|
||||
|
||||
|
||||
-- Description: Creates placeholder rows in `settings_product` for each unique product
|
||||
-- found in the `products` table. Sets basic defaults but no specific overrides.
|
||||
-- Safe to rerun; will NOT overwrite existing product settings.
|
||||
-- Dependencies: `settings_product` table must exist, `products` table populated.
|
||||
-- Frequency: Run once after initial product load, or periodically if new products are added.
|
||||
|
||||
INSERT INTO public.settings_product (
|
||||
pid,
|
||||
lead_time_days, -- NULL = Inherit from Vendor/Global
|
||||
days_of_stock, -- NULL = Inherit from Vendor/Global
|
||||
safety_stock, -- Default to 0 units initially
|
||||
forecast_method, -- NULL = Inherit from Global ('standard')
|
||||
exclude_from_forecast -- Default to FALSE
|
||||
-- updated_at will use its default CURRENT_TIMESTAMP on insert
|
||||
)
|
||||
SELECT
|
||||
p.pid,
|
||||
CAST(NULL AS INTEGER), -- Explicitly cast NULL to INTEGER
|
||||
CAST(NULL AS INTEGER), -- Explicitly cast NULL to INTEGER
|
||||
COALESCE((SELECT setting_value::int FROM settings_global WHERE setting_key = 'default_safety_stock_units'), 0), -- Use global default safety stock units
|
||||
CAST(NULL AS VARCHAR), -- Cast NULL to VARCHAR for forecast_method (already varchar, but explicit)
|
||||
FALSE -- Default: Include in forecast
|
||||
FROM
|
||||
public.products p
|
||||
|
||||
ON CONFLICT (pid) DO NOTHING; -- IMPORTANT: Do not overwrite existing product-specific settings
|
||||
|
||||
|
||||
-- History and status tables
|
||||
CREATE TABLE IF NOT EXISTS calculate_history (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
start_time TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
end_time TIMESTAMP WITH TIME ZONE NULL,
|
||||
duration_seconds INTEGER,
|
||||
duration_minutes DECIMAL(10,2) GENERATED ALWAYS AS (duration_seconds::decimal / 60.0) STORED,
|
||||
total_products INTEGER DEFAULT 0,
|
||||
total_orders INTEGER DEFAULT 0,
|
||||
total_purchase_orders INTEGER DEFAULT 0,
|
||||
processed_products INTEGER DEFAULT 0,
|
||||
processed_orders INTEGER DEFAULT 0,
|
||||
processed_purchase_orders INTEGER DEFAULT 0,
|
||||
status calculation_status DEFAULT 'running',
|
||||
error_message TEXT,
|
||||
additional_info JSONB
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS calculate_status (
|
||||
module_name text PRIMARY KEY,
|
||||
last_calculation_timestamp TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS sync_status (
|
||||
table_name TEXT PRIMARY KEY,
|
||||
last_sync_timestamp TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
last_sync_id BIGINT
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS import_history (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
table_name VARCHAR(50) NOT NULL,
|
||||
start_time TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
end_time TIMESTAMP WITH TIME ZONE NULL,
|
||||
duration_seconds INTEGER,
|
||||
duration_minutes DECIMAL(10,2) GENERATED ALWAYS AS (duration_seconds::decimal / 60.0) STORED,
|
||||
records_added INTEGER DEFAULT 0,
|
||||
records_updated INTEGER DEFAULT 0,
|
||||
records_deleted INTEGER DEFAULT 0,
|
||||
records_skipped INTEGER DEFAULT 0,
|
||||
total_processed INTEGER DEFAULT 0,
|
||||
is_incremental BOOLEAN DEFAULT FALSE,
|
||||
status calculation_status DEFAULT 'running',
|
||||
error_message TEXT,
|
||||
additional_info JSONB
|
||||
);
|
||||
|
||||
-- Create all indexes after tables are fully created
|
||||
CREATE INDEX IF NOT EXISTS idx_last_calc ON calculate_status(last_calculation_timestamp);
|
||||
CREATE INDEX IF NOT EXISTS idx_last_sync ON sync_status(last_sync_timestamp);
|
||||
CREATE INDEX IF NOT EXISTS idx_table_time ON import_history(table_name, start_time);
|
||||
CREATE INDEX IF NOT EXISTS idx_import_history_status ON import_history(status);
|
||||
CREATE INDEX IF NOT EXISTS idx_calculate_history_status ON calculate_history(status);
|
||||
|
||||
-- Add comments for documentation
|
||||
COMMENT ON TABLE import_history IS 'Tracks history of data import operations with detailed statistics';
|
||||
COMMENT ON COLUMN import_history.records_deleted IS 'Number of records deleted during this import';
|
||||
COMMENT ON COLUMN import_history.records_skipped IS 'Number of records skipped (e.g., unchanged, invalid)';
|
||||
COMMENT ON COLUMN import_history.total_processed IS 'Total number of records examined/processed, including skipped';
|
||||
|
||||
COMMENT ON TABLE calculate_history IS 'Tracks history of metrics calculation runs with performance data';
|
||||
COMMENT ON COLUMN calculate_history.duration_seconds IS 'Total duration of the calculation in seconds';
|
||||
COMMENT ON COLUMN calculate_history.additional_info IS 'JSON object containing step timings, row counts, and other detailed metrics';
|
||||
344
inventory-server/db/metrics-schema-new.sql
Normal file
344
inventory-server/db/metrics-schema-new.sql
Normal file
@@ -0,0 +1,344 @@
|
||||
-- Drop tables in reverse order of dependency
|
||||
DROP TABLE IF EXISTS public.product_metrics CASCADE;
|
||||
DROP TABLE IF EXISTS public.daily_product_snapshots CASCADE;
|
||||
|
||||
-- Table Definition: daily_product_snapshots
|
||||
CREATE TABLE public.daily_product_snapshots (
|
||||
snapshot_date DATE NOT NULL,
|
||||
pid INT8 NOT NULL,
|
||||
sku VARCHAR, -- Copied for convenience
|
||||
|
||||
-- Inventory Metrics (End of Day / Last Snapshot of Day)
|
||||
eod_stock_quantity INT NOT NULL DEFAULT 0,
|
||||
eod_stock_cost NUMERIC(14, 4) NOT NULL DEFAULT 0.00, -- Increased precision
|
||||
eod_stock_retail NUMERIC(14, 4) NOT NULL DEFAULT 0.00,
|
||||
eod_stock_gross NUMERIC(14, 4) NOT NULL DEFAULT 0.00,
|
||||
stockout_flag BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
|
||||
-- Sales Metrics (Aggregated for the snapshot_date)
|
||||
units_sold INT NOT NULL DEFAULT 0,
|
||||
units_returned INT NOT NULL DEFAULT 0,
|
||||
gross_revenue NUMERIC(14, 4) NOT NULL DEFAULT 0.00,
|
||||
discounts NUMERIC(14, 4) NOT NULL DEFAULT 0.00,
|
||||
returns_revenue NUMERIC(14, 4) NOT NULL DEFAULT 0.00,
|
||||
net_revenue NUMERIC(14, 4) NOT NULL DEFAULT 0.00, -- gross_revenue - discounts
|
||||
cogs NUMERIC(14, 4) NOT NULL DEFAULT 0.00,
|
||||
gross_regular_revenue NUMERIC(14, 4) NOT NULL DEFAULT 0.00,
|
||||
profit NUMERIC(14, 4) NOT NULL DEFAULT 0.00, -- net_revenue - cogs
|
||||
|
||||
-- Receiving Metrics (Aggregated for the snapshot_date)
|
||||
units_received INT NOT NULL DEFAULT 0,
|
||||
cost_received NUMERIC(14, 4) NOT NULL DEFAULT 0.00,
|
||||
|
||||
calculation_timestamp TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
|
||||
PRIMARY KEY (snapshot_date, pid) -- Composite primary key
|
||||
-- CONSTRAINT fk_daily_snapshot_pid FOREIGN KEY (pid) REFERENCES public.products(pid) ON DELETE CASCADE ON UPDATE CASCADE -- FK Optional on snapshot table
|
||||
);
|
||||
|
||||
-- Add Indexes for daily_product_snapshots
|
||||
CREATE INDEX idx_daily_snapshot_pid_date ON public.daily_product_snapshots(pid, snapshot_date); -- Useful for product-specific time series
|
||||
|
||||
|
||||
-- Table Definition: product_metrics
|
||||
CREATE TABLE public.product_metrics (
|
||||
pid INT8 PRIMARY KEY,
|
||||
last_calculated TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
|
||||
-- Product Info (Copied for convenience/performance)
|
||||
sku VARCHAR,
|
||||
title VARCHAR,
|
||||
brand VARCHAR,
|
||||
vendor VARCHAR,
|
||||
image_url VARCHAR, -- (e.g., products.image_175)
|
||||
is_visible BOOLEAN,
|
||||
is_replenishable BOOLEAN,
|
||||
|
||||
-- Additional product fields
|
||||
barcode VARCHAR,
|
||||
harmonized_tariff_code VARCHAR,
|
||||
vendor_reference VARCHAR,
|
||||
notions_reference VARCHAR,
|
||||
line VARCHAR,
|
||||
subline VARCHAR,
|
||||
artist VARCHAR,
|
||||
moq INT,
|
||||
rating NUMERIC(10, 2),
|
||||
reviews INT,
|
||||
weight NUMERIC(14, 4),
|
||||
length NUMERIC(14, 4),
|
||||
width NUMERIC(14, 4),
|
||||
height NUMERIC(14, 4),
|
||||
country_of_origin VARCHAR,
|
||||
location VARCHAR,
|
||||
baskets INT,
|
||||
notifies INT,
|
||||
preorder_count INT,
|
||||
notions_inv_count INT,
|
||||
|
||||
-- Current Status (Refreshed Hourly)
|
||||
current_price NUMERIC(10, 2),
|
||||
current_regular_price NUMERIC(10, 2),
|
||||
current_cost_price NUMERIC(10, 4), -- Increased precision for cost
|
||||
current_landing_cost_price NUMERIC(10, 4), -- Increased precision for cost
|
||||
current_stock INT NOT NULL DEFAULT 0,
|
||||
current_stock_cost NUMERIC(14, 4) NOT NULL DEFAULT 0.00,
|
||||
current_stock_retail NUMERIC(14, 4) NOT NULL DEFAULT 0.00,
|
||||
current_stock_gross NUMERIC(14, 4) NOT NULL DEFAULT 0.00,
|
||||
on_order_qty INT NOT NULL DEFAULT 0,
|
||||
on_order_cost NUMERIC(14, 4) NOT NULL DEFAULT 0.00,
|
||||
on_order_retail NUMERIC(14, 4) NOT NULL DEFAULT 0.00,
|
||||
earliest_expected_date DATE,
|
||||
-- total_received_lifetime INT NOT NULL DEFAULT 0, -- Can calc if needed
|
||||
|
||||
-- Historical Dates (Calculated Once/Periodically)
|
||||
date_created DATE,
|
||||
date_first_received DATE,
|
||||
date_last_received DATE,
|
||||
date_first_sold DATE,
|
||||
date_last_sold DATE,
|
||||
age_days INT, -- Calculated based on LEAST(date_created, date_first_sold)
|
||||
|
||||
-- Rolling Period Metrics (Refreshed Hourly from daily_product_snapshots)
|
||||
sales_7d INT, revenue_7d NUMERIC(14, 4),
|
||||
sales_14d INT, revenue_14d NUMERIC(14, 4),
|
||||
sales_30d INT, revenue_30d NUMERIC(14, 4),
|
||||
cogs_30d NUMERIC(14, 4), profit_30d NUMERIC(14, 4),
|
||||
returns_units_30d INT, returns_revenue_30d NUMERIC(14, 4),
|
||||
discounts_30d NUMERIC(14, 4),
|
||||
gross_revenue_30d NUMERIC(14, 4), gross_regular_revenue_30d NUMERIC(14, 4),
|
||||
stockout_days_30d INT,
|
||||
sales_365d INT, revenue_365d NUMERIC(14, 4),
|
||||
avg_stock_units_30d NUMERIC(10, 2), avg_stock_cost_30d NUMERIC(14, 4),
|
||||
avg_stock_retail_30d NUMERIC(14, 4), avg_stock_gross_30d NUMERIC(14, 4),
|
||||
received_qty_30d INT, received_cost_30d NUMERIC(14, 4),
|
||||
|
||||
-- Lifetime Metrics (Recalculated Hourly/Daily from daily_product_snapshots)
|
||||
lifetime_sales INT,
|
||||
lifetime_revenue NUMERIC(16, 4),
|
||||
lifetime_revenue_quality VARCHAR(10), -- 'exact', 'partial', 'estimated'
|
||||
|
||||
-- First Period Metrics (Calculated Once/Periodically from daily_product_snapshots)
|
||||
first_7_days_sales INT, first_7_days_revenue NUMERIC(14, 4),
|
||||
first_30_days_sales INT, first_30_days_revenue NUMERIC(14, 4),
|
||||
first_60_days_sales INT, first_60_days_revenue NUMERIC(14, 4),
|
||||
first_90_days_sales INT, first_90_days_revenue NUMERIC(14, 4),
|
||||
|
||||
-- Calculated KPIs (Refreshed Hourly based on rolling metrics)
|
||||
asp_30d NUMERIC(10, 2), -- revenue_30d / sales_30d
|
||||
acp_30d NUMERIC(10, 4), -- cogs_30d / sales_30d
|
||||
avg_ros_30d NUMERIC(10, 4), -- profit_30d / sales_30d
|
||||
avg_sales_per_day_30d NUMERIC(10, 2), -- sales_30d / 30.0
|
||||
avg_sales_per_month_30d NUMERIC(10, 2), -- sales_30d (assuming 30d = 1 month for this metric)
|
||||
margin_30d NUMERIC(8, 2), -- (profit_30d / revenue_30d) * 100
|
||||
markup_30d NUMERIC(8, 2), -- (profit_30d / cogs_30d) * 100
|
||||
gmroi_30d NUMERIC(10, 2), -- profit_30d / avg_stock_cost_30d
|
||||
stockturn_30d NUMERIC(10, 2), -- sales_30d / avg_stock_units_30d
|
||||
return_rate_30d NUMERIC(8, 2), -- returns_units_30d / (sales_30d + returns_units_30d) * 100
|
||||
discount_rate_30d NUMERIC(8, 2), -- discounts_30d / gross_revenue_30d * 100
|
||||
stockout_rate_30d NUMERIC(8, 2), -- stockout_days_30d / 30.0 * 100
|
||||
markdown_30d NUMERIC(14, 4), -- gross_regular_revenue_30d - gross_revenue_30d
|
||||
markdown_rate_30d NUMERIC(8, 2), -- markdown_30d / gross_regular_revenue_30d * 100
|
||||
sell_through_30d NUMERIC(8, 2), -- sales_30d / (current_stock + sales_30d) * 100
|
||||
avg_lead_time_days INT, -- Calculated Periodically from purchase_orders
|
||||
|
||||
-- Forecasting & Replenishment (Refreshed Hourly)
|
||||
abc_class CHAR(1), -- Updated Periodically (e.g., Weekly)
|
||||
sales_velocity_daily NUMERIC(10, 4), -- sales_30d / (30.0 - stockout_days_30d)
|
||||
config_lead_time INT, -- From settings tables
|
||||
config_days_of_stock INT, -- From settings tables
|
||||
config_safety_stock INT, -- From settings_product
|
||||
planning_period_days INT, -- config_lead_time + config_days_of_stock
|
||||
lead_time_forecast_units NUMERIC(10, 2), -- sales_velocity_daily * config_lead_time
|
||||
days_of_stock_forecast_units NUMERIC(10, 2), -- sales_velocity_daily * config_days_of_stock
|
||||
planning_period_forecast_units NUMERIC(10, 2), -- lead_time_forecast_units + days_of_stock_forecast_units
|
||||
lead_time_closing_stock NUMERIC(10, 2), -- current_stock + on_order_qty - lead_time_forecast_units
|
||||
days_of_stock_closing_stock NUMERIC(10, 2), -- lead_time_closing_stock - days_of_stock_forecast_units
|
||||
replenishment_needed_raw NUMERIC(10, 2), -- planning_period_forecast_units + config_safety_stock - current_stock - on_order_qty
|
||||
replenishment_units INT, -- CEILING(GREATEST(0, replenishment_needed_raw))
|
||||
replenishment_cost NUMERIC(14, 4), -- replenishment_units * COALESCE(current_landing_cost_price, current_cost_price)
|
||||
replenishment_retail NUMERIC(14, 4), -- replenishment_units * current_price
|
||||
replenishment_profit NUMERIC(14, 4), -- replenishment_units * (current_price - COALESCE(current_landing_cost_price, current_cost_price))
|
||||
to_order_units INT, -- Apply MOQ/UOM logic to replenishment_units
|
||||
forecast_lost_sales_units NUMERIC(10, 2), -- GREATEST(0, -lead_time_closing_stock)
|
||||
forecast_lost_revenue NUMERIC(14, 4), -- forecast_lost_sales_units * current_price
|
||||
stock_cover_in_days NUMERIC(10, 1), -- current_stock / sales_velocity_daily
|
||||
po_cover_in_days NUMERIC(10, 1), -- on_order_qty / sales_velocity_daily
|
||||
sells_out_in_days NUMERIC(10, 1), -- (current_stock + on_order_qty) / sales_velocity_daily
|
||||
replenish_date DATE, -- Calc based on when stock hits safety stock minus lead time
|
||||
overstocked_units INT, -- GREATEST(0, current_stock - config_safety_stock - planning_period_forecast_units)
|
||||
overstocked_cost NUMERIC(14, 4), -- overstocked_units * COALESCE(current_landing_cost_price, current_cost_price)
|
||||
overstocked_retail NUMERIC(14, 4), -- overstocked_units * current_price
|
||||
is_old_stock BOOLEAN, -- Based on age, last sold, last received, on_order status
|
||||
|
||||
-- Yesterday's Metrics (Refreshed Hourly from daily_product_snapshots)
|
||||
yesterday_sales INT,
|
||||
|
||||
-- Product Status (Calculated from metrics)
|
||||
status VARCHAR, -- Stores status values like: Critical, Reorder Soon, Healthy, Overstock, At Risk, New
|
||||
|
||||
-- Growth Metrics (P3)
|
||||
sales_growth_30d_vs_prev NUMERIC(10, 2), -- % growth current 30d vs prev 30d
|
||||
revenue_growth_30d_vs_prev NUMERIC(10, 2), -- % growth current 30d vs prev 30d
|
||||
sales_growth_yoy NUMERIC(10, 2), -- Year-over-year sales growth %
|
||||
revenue_growth_yoy NUMERIC(10, 2), -- Year-over-year revenue growth %
|
||||
|
||||
-- Demand Variability Metrics (P3)
|
||||
sales_variance_30d NUMERIC(10, 2), -- Variance of daily sales
|
||||
sales_std_dev_30d NUMERIC(10, 2), -- Standard deviation of daily sales
|
||||
sales_cv_30d NUMERIC(10, 2), -- Coefficient of variation
|
||||
demand_pattern VARCHAR(20), -- 'stable', 'variable', 'sporadic', 'lumpy'
|
||||
|
||||
-- Service Level & Fill Rate (P5)
|
||||
fill_rate_30d NUMERIC(8, 2), -- % of demand fulfilled from stock
|
||||
stockout_incidents_30d INT, -- Days with stockouts
|
||||
service_level_30d NUMERIC(8, 2), -- % of days without stockouts
|
||||
lost_sales_incidents_30d INT, -- Days with potential lost sales
|
||||
|
||||
-- Seasonality (P5)
|
||||
seasonality_index NUMERIC(10, 2), -- Current vs average (100 = average)
|
||||
seasonal_pattern VARCHAR(20), -- 'none', 'weekly', 'monthly', 'quarterly', 'yearly'
|
||||
peak_season VARCHAR(20), -- e.g., 'Q4', 'summer', 'holiday'
|
||||
|
||||
CONSTRAINT fk_product_metrics_pid FOREIGN KEY (pid) REFERENCES public.products(pid) ON DELETE CASCADE ON UPDATE CASCADE
|
||||
);
|
||||
|
||||
-- Add Indexes for product_metrics (adjust based on common filtering/sorting in frontend)
|
||||
CREATE INDEX idx_product_metrics_brand ON public.product_metrics(brand);
|
||||
CREATE INDEX idx_product_metrics_vendor ON public.product_metrics(vendor);
|
||||
CREATE INDEX idx_product_metrics_sku ON public.product_metrics(sku);
|
||||
CREATE INDEX idx_product_metrics_abc_class ON public.product_metrics(abc_class);
|
||||
CREATE INDEX idx_product_metrics_revenue_30d ON public.product_metrics(revenue_30d DESC NULLS LAST); -- Example sorting index
|
||||
CREATE INDEX idx_product_metrics_sales_30d ON public.product_metrics(sales_30d DESC NULLS LAST); -- Example sorting index
|
||||
CREATE INDEX idx_product_metrics_current_stock ON public.product_metrics(current_stock);
|
||||
CREATE INDEX idx_product_metrics_sells_out_in_days ON public.product_metrics(sells_out_in_days ASC NULLS LAST); -- Example sorting index
|
||||
CREATE INDEX idx_product_metrics_status ON public.product_metrics(status); -- Index for status filtering
|
||||
|
||||
-- Add new vendor, category, and brand metrics tables
|
||||
-- Drop tables in reverse order if they exist
|
||||
DROP TABLE IF EXISTS public.brand_metrics CASCADE;
|
||||
DROP TABLE IF EXISTS public.vendor_metrics CASCADE;
|
||||
DROP TABLE IF EXISTS public.category_metrics CASCADE;
|
||||
|
||||
-- ========= Category Metrics =========
|
||||
CREATE TABLE public.category_metrics (
|
||||
category_id INT8 PRIMARY KEY, -- Foreign key to categories.cat_id
|
||||
category_name VARCHAR, -- Denormalized for convenience
|
||||
category_type INT2, -- Denormalized for convenience
|
||||
parent_id INT8, -- Denormalized for convenience
|
||||
last_calculated TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
|
||||
-- ROLLED-UP METRICS (includes this category + all descendants)
|
||||
-- Counts & Basic Info
|
||||
product_count INT NOT NULL DEFAULT 0, -- Total products linked
|
||||
active_product_count INT NOT NULL DEFAULT 0, -- Visible products linked
|
||||
replenishable_product_count INT NOT NULL DEFAULT 0,-- Replenishable products linked
|
||||
|
||||
-- Current Stock Value (approximated using current product costs/prices)
|
||||
current_stock_units INT NOT NULL DEFAULT 0,
|
||||
current_stock_cost NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
current_stock_retail NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
|
||||
-- Rolling Period Aggregates (Summed from product_metrics)
|
||||
sales_7d INT NOT NULL DEFAULT 0, revenue_7d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
sales_30d INT NOT NULL DEFAULT 0, revenue_30d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
profit_30d NUMERIC(16, 4) NOT NULL DEFAULT 0.00, cogs_30d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
sales_365d INT NOT NULL DEFAULT 0, revenue_365d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
lifetime_sales INT NOT NULL DEFAULT 0, lifetime_revenue NUMERIC(18, 4) NOT NULL DEFAULT 0.00,
|
||||
|
||||
-- DIRECT METRICS (only products directly in this category)
|
||||
direct_product_count INT NOT NULL DEFAULT 0, -- Products directly in this category
|
||||
direct_active_product_count INT NOT NULL DEFAULT 0, -- Visible products directly in this category
|
||||
direct_replenishable_product_count INT NOT NULL DEFAULT 0,-- Replenishable products directly in this category
|
||||
|
||||
-- Direct Current Stock Value
|
||||
direct_current_stock_units INT NOT NULL DEFAULT 0,
|
||||
direct_stock_cost NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
direct_stock_retail NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
|
||||
-- Direct Rolling Period Aggregates
|
||||
direct_sales_7d INT NOT NULL DEFAULT 0, direct_revenue_7d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
direct_sales_30d INT NOT NULL DEFAULT 0, direct_revenue_30d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
direct_profit_30d NUMERIC(16, 4) NOT NULL DEFAULT 0.00, direct_cogs_30d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
direct_sales_365d INT NOT NULL DEFAULT 0, direct_revenue_365d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
direct_lifetime_sales INT NOT NULL DEFAULT 0, direct_lifetime_revenue NUMERIC(18, 4) NOT NULL DEFAULT 0.00,
|
||||
|
||||
-- Calculated KPIs (Based on 30d aggregates) - Apply to rolled-up metrics
|
||||
avg_margin_30d NUMERIC(7, 3), -- (profit / revenue) * 100
|
||||
stock_turn_30d NUMERIC(10, 3), -- sales_units / avg_stock_units (Needs avg stock calc)
|
||||
sales_growth_30d_vs_prev NUMERIC(10, 2), -- % growth in sales units
|
||||
revenue_growth_30d_vs_prev NUMERIC(10, 2), -- % growth in revenue
|
||||
|
||||
CONSTRAINT fk_category_metrics_cat_id FOREIGN KEY (category_id) REFERENCES public.categories(cat_id) ON DELETE CASCADE ON UPDATE CASCADE
|
||||
);
|
||||
CREATE INDEX idx_category_metrics_name ON public.category_metrics(category_name);
|
||||
CREATE INDEX idx_category_metrics_type ON public.category_metrics(category_type);
|
||||
|
||||
-- ========= Vendor Metrics =========
|
||||
CREATE TABLE public.vendor_metrics (
|
||||
vendor_name VARCHAR PRIMARY KEY, -- Matches products.vendor
|
||||
last_calculated TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
|
||||
-- Counts & Basic Info
|
||||
product_count INT NOT NULL DEFAULT 0, -- Total products from this vendor
|
||||
active_product_count INT NOT NULL DEFAULT 0, -- Visible products
|
||||
replenishable_product_count INT NOT NULL DEFAULT 0,-- Replenishable products
|
||||
|
||||
-- Current Stock Value (approximated)
|
||||
current_stock_units INT NOT NULL DEFAULT 0,
|
||||
current_stock_cost NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
current_stock_retail NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
|
||||
-- On Order Value
|
||||
on_order_units INT NOT NULL DEFAULT 0,
|
||||
on_order_cost NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
|
||||
-- PO Performance (Simplified)
|
||||
po_count_365d INT NOT NULL DEFAULT 0, -- Count of distinct POs created in last year
|
||||
avg_lead_time_days INT, -- Calculated from received POs historically
|
||||
|
||||
-- Rolling Period Aggregates (Summed from product_metrics)
|
||||
sales_7d INT NOT NULL DEFAULT 0, revenue_7d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
sales_30d INT NOT NULL DEFAULT 0, revenue_30d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
profit_30d NUMERIC(16, 4) NOT NULL DEFAULT 0.00, cogs_30d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
sales_365d INT NOT NULL DEFAULT 0, revenue_365d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
lifetime_sales INT NOT NULL DEFAULT 0, lifetime_revenue NUMERIC(18, 4) NOT NULL DEFAULT 0.00,
|
||||
|
||||
-- Calculated KPIs (Based on 30d aggregates)
|
||||
avg_margin_30d NUMERIC(14, 4), -- (profit / revenue) * 100
|
||||
sales_growth_30d_vs_prev NUMERIC(10, 2), -- % growth in sales units
|
||||
revenue_growth_30d_vs_prev NUMERIC(10, 2), -- % growth in revenue
|
||||
-- Add more KPIs if needed (e.g., avg product value, sell-through rate for vendor)
|
||||
);
|
||||
CREATE INDEX idx_vendor_metrics_active_count ON public.vendor_metrics(active_product_count);
|
||||
|
||||
|
||||
-- ========= Brand Metrics =========
|
||||
CREATE TABLE public.brand_metrics (
|
||||
brand_name VARCHAR PRIMARY KEY, -- Matches products.brand (use 'Unbranded' for NULLs)
|
||||
last_calculated TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
|
||||
-- Counts & Basic Info
|
||||
product_count INT NOT NULL DEFAULT 0, -- Total products of this brand
|
||||
active_product_count INT NOT NULL DEFAULT 0, -- Visible products
|
||||
replenishable_product_count INT NOT NULL DEFAULT 0,-- Replenishable products
|
||||
|
||||
-- Current Stock Value (approximated)
|
||||
current_stock_units INT NOT NULL DEFAULT 0,
|
||||
current_stock_cost NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
current_stock_retail NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
|
||||
-- Rolling Period Aggregates (Summed from product_metrics)
|
||||
sales_7d INT NOT NULL DEFAULT 0, revenue_7d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
sales_30d INT NOT NULL DEFAULT 0, revenue_30d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
profit_30d NUMERIC(16, 4) NOT NULL DEFAULT 0.00, cogs_30d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
sales_365d INT NOT NULL DEFAULT 0, revenue_365d NUMERIC(16, 4) NOT NULL DEFAULT 0.00,
|
||||
lifetime_sales INT NOT NULL DEFAULT 0, lifetime_revenue NUMERIC(18, 4) NOT NULL DEFAULT 0.00,
|
||||
|
||||
-- Calculated KPIs (Based on 30d aggregates)
|
||||
avg_margin_30d NUMERIC(7, 3), -- (profit / revenue) * 100
|
||||
sales_growth_30d_vs_prev NUMERIC(10, 2), -- % growth in sales units
|
||||
revenue_growth_30d_vs_prev NUMERIC(10, 2), -- % growth in revenue
|
||||
-- Add more KPIs if needed (e.g., avg product value, sell-through rate for brand)
|
||||
);
|
||||
CREATE INDEX idx_brand_metrics_active_count ON public.brand_metrics(active_product_count);
|
||||
304
inventory-server/db/schema.sql
Normal file
304
inventory-server/db/schema.sql
Normal file
@@ -0,0 +1,304 @@
|
||||
-- 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', 'receivings') 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
|
||||
-- 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 TIMESTAMP WITH TIME ZONE NOT NULL,
|
||||
expected_date DATE,
|
||||
pid BIGINT NOT NULL,
|
||||
sku TEXT NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
po_cost_price NUMERIC(14, 4) NOT NULL,
|
||||
status TEXT DEFAULT 'created',
|
||||
notes TEXT,
|
||||
long_note TEXT,
|
||||
ordered INTEGER NOT NULL,
|
||||
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)
|
||||
);
|
||||
|
||||
-- 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';
|
||||
COMMENT ON COLUMN purchase_orders.status IS 'canceled, created, electronically_ready_send, ordered, preordered, electronically_sent, receiving_started, done';
|
||||
|
||||
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_expected_date ON purchase_orders(expected_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
|
||||
|
||||
-- Create views for common calculations
|
||||
-- product_sales_trends view moved to metrics-schema.sql
|
||||
|
||||
-- -- Historical data tables imported from production
|
||||
-- CREATE TABLE imported_product_current_prices (
|
||||
-- price_id BIGSERIAL PRIMARY KEY,
|
||||
-- pid BIGINT NOT NULL,
|
||||
-- qty_buy SMALLINT NOT NULL,
|
||||
-- is_min_qty_buy BOOLEAN NOT NULL,
|
||||
-- price_each NUMERIC(10,3) NOT NULL,
|
||||
-- qty_limit SMALLINT NOT NULL,
|
||||
-- no_promo BOOLEAN NOT NULL,
|
||||
-- checkout_offer BOOLEAN NOT NULL,
|
||||
-- active BOOLEAN NOT NULL,
|
||||
-- date_active TIMESTAMP WITH TIME ZONE,
|
||||
-- date_deactive TIMESTAMP WITH TIME ZONE,
|
||||
-- updated TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP
|
||||
-- );
|
||||
|
||||
-- CREATE INDEX idx_imported_product_current_prices_pid ON imported_product_current_prices(pid, active, qty_buy);
|
||||
-- CREATE INDEX idx_imported_product_current_prices_checkout ON imported_product_current_prices(checkout_offer, active);
|
||||
-- CREATE INDEX idx_imported_product_current_prices_deactive ON imported_product_current_prices(date_deactive, active);
|
||||
-- CREATE INDEX idx_imported_product_current_prices_active ON imported_product_current_prices(date_active, active);
|
||||
|
||||
-- CREATE TABLE imported_daily_inventory (
|
||||
-- date DATE NOT NULL,
|
||||
-- pid BIGINT NOT NULL,
|
||||
-- amountsold SMALLINT NOT NULL DEFAULT 0,
|
||||
-- times_sold SMALLINT NOT NULL DEFAULT 0,
|
||||
-- qtyreceived SMALLINT NOT NULL DEFAULT 0,
|
||||
-- price NUMERIC(7,2) NOT NULL DEFAULT 0,
|
||||
-- costeach NUMERIC(7,2) NOT NULL DEFAULT 0,
|
||||
-- stamp TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
-- updated TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
-- PRIMARY KEY (date, pid)
|
||||
-- );
|
||||
|
||||
-- CREATE INDEX idx_imported_daily_inventory_pid ON imported_daily_inventory(pid);
|
||||
|
||||
-- CREATE TABLE imported_product_stat_history (
|
||||
-- pid BIGINT NOT NULL,
|
||||
-- date DATE NOT NULL,
|
||||
-- score NUMERIC(10,2) NOT NULL,
|
||||
-- score2 NUMERIC(10,2) NOT NULL,
|
||||
-- qty_in_baskets SMALLINT NOT NULL,
|
||||
-- qty_sold SMALLINT NOT NULL,
|
||||
-- notifies_set SMALLINT NOT NULL,
|
||||
-- visibility_score NUMERIC(10,2) NOT NULL,
|
||||
-- health_score VARCHAR(5) NOT NULL,
|
||||
-- sold_view_score NUMERIC(6,3) NOT NULL,
|
||||
-- updated TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
-- PRIMARY KEY (pid, date)
|
||||
-- );
|
||||
|
||||
-- CREATE INDEX idx_imported_product_stat_history_date ON imported_product_stat_history(date);
|
||||
115
inventory-server/db/setup-schema.sql
Normal file
115
inventory-server/db/setup-schema.sql
Normal file
@@ -0,0 +1,115 @@
|
||||
-- Templates table for storing import templates
|
||||
CREATE TABLE IF NOT EXISTS templates (
|
||||
id SERIAL PRIMARY KEY,
|
||||
company TEXT NOT NULL,
|
||||
product_type TEXT NOT NULL,
|
||||
supplier TEXT,
|
||||
msrp DECIMAL(10,2),
|
||||
cost_each DECIMAL(10,2),
|
||||
qty_per_unit INTEGER,
|
||||
case_qty INTEGER,
|
||||
hts_code TEXT,
|
||||
description TEXT,
|
||||
weight DECIMAL(10,2),
|
||||
length DECIMAL(10,2),
|
||||
width DECIMAL(10,2),
|
||||
height DECIMAL(10,2),
|
||||
tax_cat TEXT,
|
||||
size_cat TEXT,
|
||||
categories TEXT[],
|
||||
ship_restrictions TEXT[],
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE(company, product_type)
|
||||
);
|
||||
|
||||
-- AI Prompts table for storing validation prompts
|
||||
CREATE TABLE IF NOT EXISTS ai_prompts (
|
||||
id SERIAL PRIMARY KEY,
|
||||
prompt_text TEXT NOT NULL,
|
||||
prompt_type TEXT NOT NULL CHECK (prompt_type IN ('general', 'company_specific', 'system')),
|
||||
company TEXT,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
||||
CONSTRAINT unique_company_prompt UNIQUE (company),
|
||||
CONSTRAINT company_required_for_specific CHECK (
|
||||
(prompt_type = 'general' AND company IS NULL) OR
|
||||
(prompt_type = 'system' AND company IS NULL) OR
|
||||
(prompt_type = 'company_specific' AND company IS NOT NULL)
|
||||
)
|
||||
);
|
||||
|
||||
-- Create a unique partial index to ensure only one general prompt
|
||||
CREATE UNIQUE INDEX IF NOT EXISTS idx_unique_general_prompt
|
||||
ON ai_prompts (prompt_type)
|
||||
WHERE prompt_type = 'general';
|
||||
|
||||
-- Create a unique partial index to ensure only one system prompt
|
||||
CREATE UNIQUE INDEX IF NOT EXISTS idx_unique_system_prompt
|
||||
ON ai_prompts (prompt_type)
|
||||
WHERE prompt_type = 'system';
|
||||
|
||||
-- Reusable Images table for storing persistent images
|
||||
CREATE TABLE IF NOT EXISTS reusable_images (
|
||||
id SERIAL PRIMARY KEY,
|
||||
name TEXT NOT NULL,
|
||||
filename TEXT NOT NULL,
|
||||
file_path TEXT NOT NULL,
|
||||
image_url TEXT NOT NULL,
|
||||
is_global BOOLEAN NOT NULL DEFAULT false,
|
||||
company TEXT,
|
||||
mime_type TEXT,
|
||||
file_size INTEGER,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
||||
CONSTRAINT company_required_for_non_global CHECK (
|
||||
(is_global = true AND company IS NULL) OR
|
||||
(is_global = false AND company IS NOT NULL)
|
||||
)
|
||||
);
|
||||
|
||||
-- Create index on company for efficient querying
|
||||
CREATE INDEX IF NOT EXISTS idx_reusable_images_company ON reusable_images(company);
|
||||
-- Create index on is_global for efficient querying
|
||||
CREATE INDEX IF NOT EXISTS idx_reusable_images_is_global ON reusable_images(is_global);
|
||||
|
||||
-- AI Validation Performance Tracking
|
||||
CREATE TABLE IF NOT EXISTS ai_validation_performance (
|
||||
id SERIAL PRIMARY KEY,
|
||||
prompt_length INTEGER NOT NULL,
|
||||
product_count INTEGER NOT NULL,
|
||||
start_time TIMESTAMP WITH TIME ZONE NOT NULL,
|
||||
end_time TIMESTAMP WITH TIME ZONE NOT NULL,
|
||||
duration_seconds DECIMAL(10,2) GENERATED ALWAYS AS (EXTRACT(EPOCH FROM (end_time - start_time))) STORED,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
-- Create index on prompt_length for efficient querying
|
||||
CREATE INDEX IF NOT EXISTS idx_ai_validation_prompt_length ON ai_validation_performance(prompt_length);
|
||||
|
||||
-- Function to update the updated_at timestamp
|
||||
CREATE OR REPLACE FUNCTION update_updated_at_column()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at = CURRENT_TIMESTAMP;
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ language 'plpgsql';
|
||||
|
||||
-- Trigger to automatically update the updated_at column
|
||||
CREATE TRIGGER update_templates_updated_at
|
||||
BEFORE UPDATE ON templates
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_updated_at_column();
|
||||
|
||||
-- Trigger to automatically update the updated_at column for ai_prompts
|
||||
CREATE TRIGGER update_ai_prompts_updated_at
|
||||
BEFORE UPDATE ON ai_prompts
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_updated_at_column();
|
||||
|
||||
-- Trigger to automatically update the updated_at column for reusable_images
|
||||
CREATE TRIGGER update_reusable_images_updated_at
|
||||
BEFORE UPDATE ON reusable_images
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_updated_at_column();
|
||||
Reference in New Issue
Block a user