diff --git a/inventory-server/db/config-schema-new.sql b/inventory-server/db/config-schema-new.sql index 76e315a..2236716 100644 --- a/inventory-server/db/config-schema-new.sql +++ b/inventory-server/db/config-schema-new.sql @@ -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; diff --git a/inventory-server/db/metrics-schema-new.sql b/inventory-server/db/metrics-schema-new.sql index a7f852f..27a7df8 100644 --- a/inventory-server/db/metrics-schema-new.sql +++ b/inventory-server/db/metrics-schema-new.sql @@ -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 \ No newline at end of file +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); \ No newline at end of file diff --git a/inventory-server/old/config-schema.sql b/inventory-server/old/config-schema.sql index c653b04..857acf9 100644 --- a/inventory-server/old/config-schema.sql +++ b/inventory-server/old/config-schema.sql @@ -1,22 +1,6 @@ -- -- Configuration tables schema --- -- 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'; -- -- Stock threshold configurations -- CREATE TABLE stock_thresholds ( diff --git a/inventory-server/scripts/calculate-metrics-new.js b/inventory-server/scripts/calculate-metrics-new.js index 648e73d..c41bded 100644 --- a/inventory-server/scripts/calculate-metrics-new.js +++ b/inventory-server/scripts/calculate-metrics-new.js @@ -8,6 +8,9 @@ const { Pool } = require('pg'); // Assuming you use 'pg' const RUN_DAILY_SNAPSHOTS = true; const RUN_PRODUCT_METRICS = true; const RUN_PERIODIC_METRICS = true; +const RUN_BRAND_METRICS = true; +const RUN_VENDOR_METRICS = true; +const RUN_CATEGORY_METRICS = true; // Maximum execution time for the entire sequence (e.g., 90 minutes) const MAX_EXECUTION_TIME_TOTAL = 90 * 60 * 1000; @@ -629,6 +632,27 @@ async function runAllCalculations() { sqlFile: 'metrics-new/update_periodic_metrics.sql', historyType: 'periodic_metrics', statusModule: 'periodic_metrics' + }, + { + run: RUN_BRAND_METRICS, + name: 'Brand Metrics Update', + sqlFile: 'metrics-new/calculate_brand_metrics.sql', + historyType: 'brand_metrics', + statusModule: 'brand_metrics' + }, + { + run: RUN_VENDOR_METRICS, + name: 'Vendor Metrics Update', + sqlFile: 'metrics-new/calculate_vendor_metrics.sql', + historyType: 'vendor_metrics', + statusModule: 'vendor_metrics' + }, + { + run: RUN_CATEGORY_METRICS, + name: 'Category Metrics Update', + sqlFile: 'metrics-new/calculate_category_metrics.sql', + historyType: 'category_metrics', + statusModule: 'category_metrics' } ]; @@ -707,6 +731,9 @@ if (require.main === module) { runDailySnapshots: () => executeSqlStep({ name: 'Daily Snapshots Update', sqlFile: 'update_daily_snapshots.sql', historyType: 'daily_snapshots', statusModule: 'daily_snapshots' }, progressUtils), runProductMetrics: () => executeSqlStep({ name: 'Product Metrics Update', sqlFile: 'update_product_metrics.sql', historyType: 'product_metrics', statusModule: 'product_metrics' }, progressUtils), runPeriodicMetrics: () => executeSqlStep({ name: 'Periodic Metrics Update', sqlFile: 'update_periodic_metrics.sql', historyType: 'periodic_metrics', statusModule: 'periodic_metrics' }, progressUtils), + runBrandMetrics: () => executeSqlStep({ name: 'Brand Metrics Update', sqlFile: 'calculate_brand_metrics.sql', historyType: 'brand_metrics', statusModule: 'brand_metrics' }, progressUtils), + runVendorMetrics: () => executeSqlStep({ name: 'Vendor Metrics Update', sqlFile: 'calculate_vendor_metrics.sql', historyType: 'vendor_metrics', statusModule: 'vendor_metrics' }, progressUtils), + runCategoryMetrics: () => executeSqlStep({ name: 'Category Metrics Update', sqlFile: 'calculate_category_metrics.sql', historyType: 'category_metrics', statusModule: 'category_metrics' }, progressUtils), getProgress: progressUtils.getProgress }; } \ No newline at end of file diff --git a/inventory-server/scripts/metrics-new/backfill-snapshots.js b/inventory-server/scripts/metrics-new/backfill/backfill-snapshots.js similarity index 99% rename from inventory-server/scripts/metrics-new/backfill-snapshots.js rename to inventory-server/scripts/metrics-new/backfill/backfill-snapshots.js index e7b7015..09df5c1 100644 --- a/inventory-server/scripts/metrics-new/backfill-snapshots.js +++ b/inventory-server/scripts/metrics-new/backfill/backfill-snapshots.js @@ -1,7 +1,7 @@ const path = require('path'); const fs = require('fs'); -const progress = require('./utils/progress'); // Assuming progress utils are here -const { getConnection, closePool } = require('./utils/db'); // Assuming db utils are here +const progress = require('../utils/progress'); // Assuming progress utils are here +const { getConnection, closePool } = require('../utils/db'); // Assuming db utils are here const os = require('os'); // For detecting number of CPU cores // --- Configuration --- diff --git a/inventory-server/scripts/metrics-new/backfill_historical_snapshots.sql b/inventory-server/scripts/metrics-new/backfill/backfill_historical_snapshots.sql similarity index 100% rename from inventory-server/scripts/metrics-new/backfill_historical_snapshots.sql rename to inventory-server/scripts/metrics-new/backfill/backfill_historical_snapshots.sql diff --git a/inventory-server/scripts/metrics-new/populate-initial-metrics.js b/inventory-server/scripts/metrics-new/backfill/populate-initial-metrics.js similarity index 99% rename from inventory-server/scripts/metrics-new/populate-initial-metrics.js rename to inventory-server/scripts/metrics-new/backfill/populate-initial-metrics.js index 74d4ea4..259a1f6 100644 --- a/inventory-server/scripts/metrics-new/populate-initial-metrics.js +++ b/inventory-server/scripts/metrics-new/backfill/populate-initial-metrics.js @@ -24,7 +24,7 @@ process.on('unhandledRejection', (reason, promise) => { }); // Load progress module -const progress = require('./utils/progress'); +const progress = require('../utils/progress'); // Store progress functions in global scope to ensure availability global.formatElapsedTime = progress.formatElapsedTime; @@ -36,7 +36,7 @@ global.getProgress = progress.getProgress; global.logError = progress.logError; // Load database module -const { getConnection, closePool } = require('./utils/db'); +const { getConnection, closePool } = require('../utils/db'); // Add cancel handler let isCancelled = false; diff --git a/inventory-server/scripts/metrics-new/populate_initial_product_metrics.sql b/inventory-server/scripts/metrics-new/backfill/populate_initial_product_metrics.sql similarity index 94% rename from inventory-server/scripts/metrics-new/populate_initial_product_metrics.sql rename to inventory-server/scripts/metrics-new/backfill/populate_initial_product_metrics.sql index a1a3f41..b95d88f 100644 --- a/inventory-server/scripts/metrics-new/populate_initial_product_metrics.sql +++ b/inventory-server/scripts/metrics-new/backfill/populate_initial_product_metrics.sql @@ -88,16 +88,6 @@ BEGIN SUM(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '29 days' AND _calculation_date THEN gross_revenue ELSE 0 END) AS gross_revenue_30d, SUM(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '29 days' AND _calculation_date THEN gross_regular_revenue ELSE 0 END) AS gross_regular_revenue_30d, SUM(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '29 days' AND _calculation_date AND stockout_flag THEN 1 ELSE 0 END) AS stockout_days_30d, - -- Add 90-day aggregates if needed - SUM(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '89 days' AND _calculation_date THEN units_sold ELSE 0 END) AS sales_90d, - SUM(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '89 days' AND _calculation_date THEN net_revenue ELSE 0 END) AS revenue_90d, - SUM(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '89 days' AND _calculation_date THEN cogs ELSE 0 END) AS cogs_90d, - SUM(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '89 days' AND _calculation_date THEN profit ELSE 0 END) AS profit_90d, - -- Add 60-day aggregates if needed - SUM(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '59 days' AND _calculation_date THEN units_sold ELSE 0 END) AS sales_60d, - SUM(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '59 days' AND _calculation_date THEN net_revenue ELSE 0 END) AS revenue_60d, - SUM(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '59 days' AND _calculation_date THEN cogs ELSE 0 END) AS cogs_60d, - SUM(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '59 days' AND _calculation_date THEN profit ELSE 0 END) AS profit_60d, SUM(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '364 days' AND _calculation_date THEN units_sold ELSE 0 END) AS sales_365d, SUM(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '364 days' AND _calculation_date THEN net_revenue ELSE 0 END) AS revenue_365d, SUM(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '29 days' AND _calculation_date THEN units_received ELSE 0 END) AS received_qty_30d, @@ -215,8 +205,6 @@ BEGIN on_order_qty, on_order_cost, on_order_retail, earliest_expected_date, date_created, date_first_received, date_last_received, date_first_sold, date_last_sold, age_days, sales_7d, revenue_7d, sales_14d, revenue_14d, sales_30d, revenue_30d, cogs_30d, profit_30d, - sales_60d, revenue_60d, cogs_60d, profit_60d, - sales_90d, revenue_90d, cogs_90d, profit_90d, returns_units_30d, returns_revenue_30d, discounts_30d, gross_revenue_30d, gross_regular_revenue_30d, stockout_days_30d, sales_365d, revenue_365d, avg_stock_units_30d, avg_stock_cost_30d, avg_stock_retail_30d, avg_stock_gross_30d, @@ -258,8 +246,6 @@ BEGIN END, COALESCE(sa.sales_7d, 0), COALESCE(sa.revenue_7d, 0), COALESCE(sa.sales_14d, 0), COALESCE(sa.revenue_14d, 0), COALESCE(sa.sales_30d, 0), COALESCE(sa.revenue_30d, 0), COALESCE(sa.cogs_30d, 0), COALESCE(sa.profit_30d, 0), - COALESCE(sa.sales_60d, 0), COALESCE(sa.revenue_60d, 0), COALESCE(sa.cogs_60d, 0), COALESCE(sa.profit_60d, 0), - COALESCE(sa.sales_90d, 0), COALESCE(sa.revenue_90d, 0), COALESCE(sa.cogs_90d, 0), COALESCE(sa.profit_90d, 0), COALESCE(sa.returns_units_30d, 0), COALESCE(sa.returns_revenue_30d, 0), COALESCE(sa.discounts_30d, 0), COALESCE(sa.gross_revenue_30d, 0), COALESCE(sa.gross_regular_revenue_30d, 0), COALESCE(sa.stockout_days_30d, 0), COALESCE(sa.sales_365d, 0), COALESCE(sa.revenue_365d, 0), sa.avg_stock_units_30d, sa.avg_stock_cost_30d, sa.avg_stock_retail_30d, sa.avg_stock_gross_30d, -- Averages can be NULL if no data @@ -420,9 +406,6 @@ BEGIN on_order_qty = EXCLUDED.on_order_qty, on_order_cost = EXCLUDED.on_order_cost, on_order_retail = EXCLUDED.on_order_retail, earliest_expected_date = EXCLUDED.earliest_expected_date, date_created = EXCLUDED.date_created, date_first_received = EXCLUDED.date_first_received, date_last_received = EXCLUDED.date_last_received, date_first_sold = EXCLUDED.date_first_sold, date_last_sold = EXCLUDED.date_last_sold, age_days = EXCLUDED.age_days, sales_7d = EXCLUDED.sales_7d, revenue_7d = EXCLUDED.revenue_7d, sales_14d = EXCLUDED.sales_14d, revenue_14d = EXCLUDED.revenue_14d, sales_30d = EXCLUDED.sales_30d, revenue_30d = EXCLUDED.revenue_30d, cogs_30d = EXCLUDED.cogs_30d, profit_30d = EXCLUDED.profit_30d, - -- Add 60d/90d columns - sales_60d = EXCLUDED.sales_60d, revenue_60d = EXCLUDED.revenue_60d, cogs_60d = EXCLUDED.cogs_60d, profit_60d = EXCLUDED.profit_60d, - sales_90d = EXCLUDED.sales_90d, revenue_90d = EXCLUDED.revenue_90d, cogs_90d = EXCLUDED.cogs_90d, profit_90d = EXCLUDED.profit_90d, returns_units_30d = EXCLUDED.returns_units_30d, returns_revenue_30d = EXCLUDED.returns_revenue_30d, discounts_30d = EXCLUDED.discounts_30d, gross_revenue_30d = EXCLUDED.gross_revenue_30d, gross_regular_revenue_30d = EXCLUDED.gross_regular_revenue_30d, stockout_days_30d = EXCLUDED.stockout_days_30d, sales_365d = EXCLUDED.sales_365d, revenue_365d = EXCLUDED.revenue_365d, avg_stock_units_30d = EXCLUDED.avg_stock_units_30d, avg_stock_cost_30d = EXCLUDED.avg_stock_cost_30d, avg_stock_retail_30d = EXCLUDED.avg_stock_retail_30d, avg_stock_gross_30d = EXCLUDED.avg_stock_gross_30d, @@ -431,7 +414,6 @@ BEGIN first_7_days_sales = EXCLUDED.first_7_days_sales, first_7_days_revenue = EXCLUDED.first_7_days_revenue, first_30_days_sales = EXCLUDED.first_30_days_sales, first_30_days_revenue = EXCLUDED.first_30_days_revenue, first_60_days_sales = EXCLUDED.first_60_days_sales, first_60_days_revenue = EXCLUDED.first_60_days_revenue, first_90_days_sales = EXCLUDED.first_90_days_sales, first_90_days_revenue = EXCLUDED.first_90_days_revenue, asp_30d = EXCLUDED.asp_30d, acp_30d = EXCLUDED.acp_30d, avg_ros_30d = EXCLUDED.avg_ros_30d, avg_sales_per_day_30d = EXCLUDED.avg_sales_per_day_30d, - -- *** REMOVED avg_sales_per_month_30d *** margin_30d = EXCLUDED.margin_30d, markup_30d = EXCLUDED.markup_30d, gmroi_30d = EXCLUDED.gmroi_30d, stockturn_30d = EXCLUDED.stockturn_30d, return_rate_30d = EXCLUDED.return_rate_30d, discount_rate_30d = EXCLUDED.discount_rate_30d, stockout_rate_30d = EXCLUDED.stockout_rate_30d, markdown_30d = EXCLUDED.markdown_30d, markdown_rate_30d = EXCLUDED.markdown_rate_30d, sell_through_30d = EXCLUDED.sell_through_30d, avg_lead_time_days = EXCLUDED.avg_lead_time_days, abc_class = EXCLUDED.abc_class, diff --git a/inventory-server/scripts/metrics-new/calculate_brand_metrics.sql b/inventory-server/scripts/metrics-new/calculate_brand_metrics.sql new file mode 100644 index 0000000..1022f9a --- /dev/null +++ b/inventory-server/scripts/metrics-new/calculate_brand_metrics.sql @@ -0,0 +1,87 @@ +-- Description: Calculates and updates aggregated metrics per brand. +-- Dependencies: product_metrics, products, calculate_status table. +-- Frequency: Daily (after product_metrics update). + +DO $$ +DECLARE + _module_name VARCHAR := 'brand_metrics'; + _start_time TIMESTAMPTZ := clock_timestamp(); +BEGIN + RAISE NOTICE 'Running % calculation...', _module_name; + + WITH BrandAggregates AS ( + -- Aggregate metrics from product_metrics table per brand + SELECT + COALESCE(p.brand, 'Unbranded') AS brand_group, -- Group NULL/empty brands together + COUNT(DISTINCT pm.pid) AS product_count, + COUNT(DISTINCT CASE WHEN pm.is_visible THEN pm.pid END) AS active_product_count, + COUNT(DISTINCT CASE WHEN pm.is_replenishable THEN pm.pid END) AS replenishable_product_count, + SUM(pm.current_stock) AS current_stock_units, + SUM(pm.current_stock_cost) AS current_stock_cost, + SUM(pm.current_stock_retail) AS current_stock_retail, + SUM(pm.sales_7d) AS sales_7d, SUM(pm.revenue_7d) AS revenue_7d, + SUM(pm.sales_30d) AS sales_30d, SUM(pm.revenue_30d) AS revenue_30d, + SUM(pm.profit_30d) AS profit_30d, SUM(pm.cogs_30d) AS cogs_30d, + SUM(pm.sales_365d) AS sales_365d, SUM(pm.revenue_365d) AS revenue_365d, + SUM(pm.lifetime_sales) AS lifetime_sales, SUM(pm.lifetime_revenue) AS lifetime_revenue + FROM public.product_metrics pm + JOIN public.products p ON pm.pid = p.pid + -- WHERE p.visible = true -- Optional: filter only visible products for brand metrics? + GROUP BY brand_group + ), + AllBrands AS ( + -- Ensure all brands from products table are included, mapping NULL/empty to 'Unbranded' + SELECT DISTINCT COALESCE(brand, 'Unbranded') as brand_group + FROM public.products + ) + INSERT INTO public.brand_metrics ( + brand_name, last_calculated, + product_count, active_product_count, replenishable_product_count, + current_stock_units, current_stock_cost, current_stock_retail, + sales_7d, revenue_7d, sales_30d, revenue_30d, profit_30d, cogs_30d, + sales_365d, revenue_365d, lifetime_sales, lifetime_revenue, + avg_margin_30d + ) + SELECT + b.brand_group, + _start_time, + -- Base Aggregates + COALESCE(ba.product_count, 0), + COALESCE(ba.active_product_count, 0), + COALESCE(ba.replenishable_product_count, 0), + COALESCE(ba.current_stock_units, 0), + COALESCE(ba.current_stock_cost, 0.00), + COALESCE(ba.current_stock_retail, 0.00), + -- Sales Aggregates + COALESCE(ba.sales_7d, 0), COALESCE(ba.revenue_7d, 0.00), + COALESCE(ba.sales_30d, 0), COALESCE(ba.revenue_30d, 0.00), + COALESCE(ba.profit_30d, 0.00), COALESCE(ba.cogs_30d, 0.00), + COALESCE(ba.sales_365d, 0), COALESCE(ba.revenue_365d, 0.00), + COALESCE(ba.lifetime_sales, 0), COALESCE(ba.lifetime_revenue, 0.00), + -- KPIs + (ba.profit_30d / NULLIF(ba.revenue_30d, 0)) * 100.0 + FROM AllBrands b + LEFT JOIN BrandAggregates ba ON b.brand_group = ba.brand_group + + ON CONFLICT (brand_name) DO UPDATE SET + last_calculated = EXCLUDED.last_calculated, + product_count = EXCLUDED.product_count, + active_product_count = EXCLUDED.active_product_count, + replenishable_product_count = EXCLUDED.replenishable_product_count, + current_stock_units = EXCLUDED.current_stock_units, + current_stock_cost = EXCLUDED.current_stock_cost, + current_stock_retail = EXCLUDED.current_stock_retail, + sales_7d = EXCLUDED.sales_7d, revenue_7d = EXCLUDED.revenue_7d, + sales_30d = EXCLUDED.sales_30d, revenue_30d = EXCLUDED.revenue_30d, + profit_30d = EXCLUDED.profit_30d, cogs_30d = EXCLUDED.cogs_30d, + sales_365d = EXCLUDED.sales_365d, revenue_365d = EXCLUDED.revenue_365d, + lifetime_sales = EXCLUDED.lifetime_sales, lifetime_revenue = EXCLUDED.lifetime_revenue, + avg_margin_30d = EXCLUDED.avg_margin_30d; + + -- Update calculate_status + INSERT INTO public.calculate_status (module_name, last_calculation_timestamp) + VALUES (_module_name, _start_time) + ON CONFLICT (module_name) DO UPDATE SET last_calculation_timestamp = _start_time; + + RAISE NOTICE 'Finished % calculation. Duration: %', _module_name, clock_timestamp() - _start_time; +END $$; \ No newline at end of file diff --git a/inventory-server/scripts/metrics-new/calculate_category_metrics.sql b/inventory-server/scripts/metrics-new/calculate_category_metrics.sql new file mode 100644 index 0000000..373692c --- /dev/null +++ b/inventory-server/scripts/metrics-new/calculate_category_metrics.sql @@ -0,0 +1,94 @@ +-- Description: Calculates and updates aggregated metrics per category. +-- Dependencies: product_metrics, products, categories, product_categories, calculate_status table. +-- Frequency: Daily (after product_metrics update). + +DO $$ +DECLARE + _module_name VARCHAR := 'category_metrics'; + _start_time TIMESTAMPTZ := clock_timestamp(); +BEGIN + RAISE NOTICE 'Running % calculation...', _module_name; + + WITH CategoryAggregates AS ( + SELECT + pc.cat_id, + -- Counts + COUNT(DISTINCT pm.pid) AS product_count, + COUNT(DISTINCT CASE WHEN pm.is_visible THEN pm.pid END) AS active_product_count, + COUNT(DISTINCT CASE WHEN pm.is_replenishable THEN pm.pid END) AS replenishable_product_count, + -- Current Stock + SUM(pm.current_stock) AS current_stock_units, + SUM(pm.current_stock_cost) AS current_stock_cost, + SUM(pm.current_stock_retail) AS current_stock_retail, + -- Rolling Periods (Sum directly from product_metrics) + SUM(pm.sales_7d) AS sales_7d, SUM(pm.revenue_7d) AS revenue_7d, + SUM(pm.sales_30d) AS sales_30d, SUM(pm.revenue_30d) AS revenue_30d, + SUM(pm.profit_30d) AS profit_30d, SUM(pm.cogs_30d) AS cogs_30d, + SUM(pm.sales_365d) AS sales_365d, SUM(pm.revenue_365d) AS revenue_365d, + SUM(pm.lifetime_sales) AS lifetime_sales, SUM(pm.lifetime_revenue) AS lifetime_revenue, + -- Data for KPIs + SUM(pm.avg_stock_units_30d) AS total_avg_stock_units_30d -- Sum of averages (use cautiously) + FROM public.product_metrics pm + JOIN public.product_categories pc ON pm.pid = pc.pid + -- Optional: JOIN products p ON pm.pid = p.pid if needed for filtering (e.g., only visible products) + -- WHERE p.visible = true -- Example filter + GROUP BY pc.cat_id + ) + INSERT INTO public.category_metrics ( + category_id, category_name, category_type, parent_id, last_calculated, + product_count, active_product_count, replenishable_product_count, + current_stock_units, current_stock_cost, current_stock_retail, + sales_7d, revenue_7d, sales_30d, revenue_30d, profit_30d, cogs_30d, + sales_365d, revenue_365d, lifetime_sales, lifetime_revenue, + avg_margin_30d, stock_turn_30d + ) + SELECT + c.cat_id, + c.name, + c.type, + c.parent_id, + _start_time, + -- Base Aggregates + COALESCE(ca.product_count, 0), + COALESCE(ca.active_product_count, 0), + COALESCE(ca.replenishable_product_count, 0), + COALESCE(ca.current_stock_units, 0), + COALESCE(ca.current_stock_cost, 0.00), + COALESCE(ca.current_stock_retail, 0.00), + COALESCE(ca.sales_7d, 0), COALESCE(ca.revenue_7d, 0.00), + COALESCE(ca.sales_30d, 0), COALESCE(ca.revenue_30d, 0.00), + COALESCE(ca.profit_30d, 0.00), COALESCE(ca.cogs_30d, 0.00), + COALESCE(ca.sales_365d, 0), COALESCE(ca.revenue_365d, 0.00), + COALESCE(ca.lifetime_sales, 0), COALESCE(ca.lifetime_revenue, 0.00), + -- KPIs + (ca.profit_30d / NULLIF(ca.revenue_30d, 0)) * 100.0, + ca.sales_30d / NULLIF(ca.total_avg_stock_units_30d, 0) -- Simple unit-based turnover + FROM public.categories c -- Start from categories to include those with no products yet + LEFT JOIN CategoryAggregates ca ON c.cat_id = ca.cat_id + + ON CONFLICT (category_id) DO UPDATE SET + category_name = EXCLUDED.category_name, + category_type = EXCLUDED.category_type, + parent_id = EXCLUDED.parent_id, + last_calculated = EXCLUDED.last_calculated, + product_count = EXCLUDED.product_count, + active_product_count = EXCLUDED.active_product_count, + replenishable_product_count = EXCLUDED.replenishable_product_count, + current_stock_units = EXCLUDED.current_stock_units, + current_stock_cost = EXCLUDED.current_stock_cost, + current_stock_retail = EXCLUDED.current_stock_retail, + sales_7d = EXCLUDED.sales_7d, revenue_7d = EXCLUDED.revenue_7d, + sales_30d = EXCLUDED.sales_30d, revenue_30d = EXCLUDED.revenue_30d, + profit_30d = EXCLUDED.profit_30d, cogs_30d = EXCLUDED.cogs_30d, + sales_365d = EXCLUDED.sales_365d, revenue_365d = EXCLUDED.revenue_365d, + lifetime_sales = EXCLUDED.lifetime_sales, lifetime_revenue = EXCLUDED.lifetime_revenue, + avg_margin_30d = EXCLUDED.avg_margin_30d, + stock_turn_30d = EXCLUDED.stock_turn_30d; + + -- Update calculate_status + INSERT INTO public.calculate_status (module_name, last_calculation_timestamp) + VALUES (_module_name, _start_time) + ON CONFLICT (module_name) DO UPDATE SET last_calculation_timestamp = _start_time; + + RAISE NOTICE 'Finished % calculation. Duration: %', _module_name, clock_timestamp() - _start_time; +END $$; \ No newline at end of file diff --git a/inventory-server/scripts/metrics-new/calculate_vendor_metrics.sql b/inventory-server/scripts/metrics-new/calculate_vendor_metrics.sql new file mode 100644 index 0000000..42e68b3 --- /dev/null +++ b/inventory-server/scripts/metrics-new/calculate_vendor_metrics.sql @@ -0,0 +1,115 @@ +-- Description: Calculates and updates aggregated metrics per vendor. +-- Dependencies: product_metrics, products, purchase_orders, calculate_status table. +-- Frequency: Daily (after product_metrics update). + +DO $$ +DECLARE + _module_name VARCHAR := 'vendor_metrics'; + _start_time TIMESTAMPTZ := clock_timestamp(); +BEGIN + RAISE NOTICE 'Running % calculation...', _module_name; + + WITH VendorProductAggregates AS ( + -- Aggregate metrics from product_metrics table per vendor + SELECT + p.vendor, + COUNT(DISTINCT pm.pid) AS product_count, + COUNT(DISTINCT CASE WHEN pm.is_visible THEN pm.pid END) AS active_product_count, + COUNT(DISTINCT CASE WHEN pm.is_replenishable THEN pm.pid END) AS replenishable_product_count, + SUM(pm.current_stock) AS current_stock_units, + SUM(pm.current_stock_cost) AS current_stock_cost, + SUM(pm.current_stock_retail) AS current_stock_retail, + SUM(pm.on_order_qty) AS on_order_units, + SUM(pm.on_order_cost) AS on_order_cost, + SUM(pm.sales_7d) AS sales_7d, SUM(pm.revenue_7d) AS revenue_7d, + SUM(pm.sales_30d) AS sales_30d, SUM(pm.revenue_30d) AS revenue_30d, + SUM(pm.profit_30d) AS profit_30d, SUM(pm.cogs_30d) AS cogs_30d, + SUM(pm.sales_365d) AS sales_365d, SUM(pm.revenue_365d) AS revenue_365d, + SUM(pm.lifetime_sales) AS lifetime_sales, SUM(pm.lifetime_revenue) AS lifetime_revenue + FROM public.product_metrics pm + JOIN public.products p ON pm.pid = p.pid + WHERE p.vendor IS NOT NULL AND p.vendor <> '' + GROUP BY p.vendor + ), + VendorPOAggregates AS ( + -- Aggregate PO related stats + SELECT + vendor, + COUNT(DISTINCT po_id) AS po_count_365d, + AVG(GREATEST(1, CASE WHEN last_received_date IS NOT NULL AND date IS NOT NULL THEN (last_received_date::date - date::date) ELSE NULL END))::int AS avg_lead_time_days_hist -- Avg lead time from HISTORICAL received POs + FROM public.purchase_orders + WHERE vendor IS NOT NULL AND vendor <> '' + AND date >= CURRENT_DATE - INTERVAL '1 year' -- Look at POs created in the last year + AND status = 'received' -- Only calculate lead time on fully received POs + AND last_received_date IS NOT NULL + AND date IS NOT NULL + AND last_received_date >= date + GROUP BY vendor + ), + AllVendors AS ( + -- Ensure all vendors from products table are included + SELECT DISTINCT vendor FROM public.products WHERE vendor IS NOT NULL AND vendor <> '' + ) + INSERT INTO public.vendor_metrics ( + vendor_name, last_calculated, + product_count, active_product_count, replenishable_product_count, + current_stock_units, current_stock_cost, current_stock_retail, + on_order_units, on_order_cost, + po_count_365d, avg_lead_time_days, + sales_7d, revenue_7d, sales_30d, revenue_30d, profit_30d, cogs_30d, + sales_365d, revenue_365d, lifetime_sales, lifetime_revenue, + avg_margin_30d + ) + SELECT + v.vendor, + _start_time, + -- Base Aggregates + COALESCE(vpa.product_count, 0), + COALESCE(vpa.active_product_count, 0), + COALESCE(vpa.replenishable_product_count, 0), + COALESCE(vpa.current_stock_units, 0), + COALESCE(vpa.current_stock_cost, 0.00), + COALESCE(vpa.current_stock_retail, 0.00), + COALESCE(vpa.on_order_units, 0), + COALESCE(vpa.on_order_cost, 0.00), + -- PO Aggregates + COALESCE(vpoa.po_count_365d, 0), + vpoa.avg_lead_time_days_hist, -- Can be NULL if no received POs + -- Sales Aggregates + COALESCE(vpa.sales_7d, 0), COALESCE(vpa.revenue_7d, 0.00), + COALESCE(vpa.sales_30d, 0), COALESCE(vpa.revenue_30d, 0.00), + COALESCE(vpa.profit_30d, 0.00), COALESCE(vpa.cogs_30d, 0.00), + COALESCE(vpa.sales_365d, 0), COALESCE(vpa.revenue_365d, 0.00), + COALESCE(vpa.lifetime_sales, 0), COALESCE(vpa.lifetime_revenue, 0.00), + -- KPIs + (vpa.profit_30d / NULLIF(vpa.revenue_30d, 0)) * 100.0 + FROM AllVendors v + LEFT JOIN VendorProductAggregates vpa ON v.vendor = vpa.vendor + LEFT JOIN VendorPOAggregates vpoa ON v.vendor = vpoa.vendor + + ON CONFLICT (vendor_name) DO UPDATE SET + last_calculated = EXCLUDED.last_calculated, + product_count = EXCLUDED.product_count, + active_product_count = EXCLUDED.active_product_count, + replenishable_product_count = EXCLUDED.replenishable_product_count, + current_stock_units = EXCLUDED.current_stock_units, + current_stock_cost = EXCLUDED.current_stock_cost, + current_stock_retail = EXCLUDED.current_stock_retail, + on_order_units = EXCLUDED.on_order_units, + on_order_cost = EXCLUDED.on_order_cost, + po_count_365d = EXCLUDED.po_count_365d, + avg_lead_time_days = EXCLUDED.avg_lead_time_days, + sales_7d = EXCLUDED.sales_7d, revenue_7d = EXCLUDED.revenue_7d, + sales_30d = EXCLUDED.sales_30d, revenue_30d = EXCLUDED.revenue_30d, + profit_30d = EXCLUDED.profit_30d, cogs_30d = EXCLUDED.cogs_30d, + sales_365d = EXCLUDED.sales_365d, revenue_365d = EXCLUDED.revenue_365d, + lifetime_sales = EXCLUDED.lifetime_sales, lifetime_revenue = EXCLUDED.lifetime_revenue, + avg_margin_30d = EXCLUDED.avg_margin_30d; + + -- Update calculate_status + INSERT INTO public.calculate_status (module_name, last_calculation_timestamp) + VALUES (_module_name, _start_time) + ON CONFLICT (module_name) DO UPDATE SET last_calculation_timestamp = _start_time; + + RAISE NOTICE 'Finished % calculation. Duration: %', _module_name, clock_timestamp() - _start_time; +END $$; \ No newline at end of file