Add new vendors, brands, categories tables and calculate scripts
This commit is contained in:
@@ -1,3 +1,21 @@
|
||||
-- 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;
|
||||
|
||||
@@ -162,4 +162,110 @@ 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_sells_out_in_days ON public.product_metrics(sells_out_in_days ASC NULLS LAST); -- Example sorting index
|
||||
|
||||
-- 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(),
|
||||
|
||||
-- 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,
|
||||
|
||||
-- Calculated KPIs (Based on 30d aggregates)
|
||||
avg_margin_30d NUMERIC(7, 3), -- (profit / revenue) * 100
|
||||
stock_turn_30d NUMERIC(10, 3), -- sales_units / avg_stock_units (Needs avg stock calc)
|
||||
-- growth_rate_30d NUMERIC(7, 3), -- (current 30d rev - prev 30d rev) / prev 30d rev
|
||||
|
||||
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(7, 3) -- (profit / revenue) * 100
|
||||
-- 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
|
||||
-- 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);
|
||||
Reference in New Issue
Block a user