-- 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), -- 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 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) -- 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);