Opus corrections/fixes/additions
This commit is contained in:
@@ -116,6 +116,7 @@ CREATE TABLE public.product_metrics (
|
||||
-- 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),
|
||||
@@ -176,6 +177,29 @@ CREATE TABLE public.product_metrics (
|
||||
-- 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
|
||||
);
|
||||
|
||||
@@ -242,7 +266,8 @@ CREATE TABLE public.category_metrics (
|
||||
-- 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
|
||||
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
|
||||
);
|
||||
@@ -280,7 +305,9 @@ CREATE TABLE public.vendor_metrics (
|
||||
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
|
||||
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);
|
||||
@@ -309,7 +336,9 @@ CREATE TABLE public.brand_metrics (
|
||||
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
|
||||
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);
|
||||
@@ -437,7 +437,6 @@ async function executeSqlStep(config, progress) {
|
||||
|
||||
try {
|
||||
// Try executing exactly as individual scripts do
|
||||
console.log('Executing SQL with simple query method...');
|
||||
const result = await connection.query(sqlQuery);
|
||||
|
||||
// Try to extract row count from result
|
||||
|
||||
@@ -42,6 +42,20 @@ BEGIN
|
||||
JOIN public.products p ON pm.pid = p.pid
|
||||
GROUP BY brand_group
|
||||
),
|
||||
PreviousPeriodBrandMetrics AS (
|
||||
-- Get previous period metrics for growth calculation
|
||||
SELECT
|
||||
COALESCE(p.brand, 'Unbranded') AS brand_group,
|
||||
SUM(CASE WHEN dps.snapshot_date >= CURRENT_DATE - INTERVAL '59 days'
|
||||
AND dps.snapshot_date < CURRENT_DATE - INTERVAL '29 days'
|
||||
THEN dps.units_sold ELSE 0 END) AS sales_prev_30d,
|
||||
SUM(CASE WHEN dps.snapshot_date >= CURRENT_DATE - INTERVAL '59 days'
|
||||
AND dps.snapshot_date < CURRENT_DATE - INTERVAL '29 days'
|
||||
THEN dps.net_revenue ELSE 0 END) AS revenue_prev_30d
|
||||
FROM public.daily_product_snapshots dps
|
||||
JOIN public.products p ON dps.pid = p.pid
|
||||
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
|
||||
@@ -53,7 +67,8 @@ BEGIN
|
||||
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
|
||||
avg_margin_30d,
|
||||
sales_growth_30d_vs_prev, revenue_growth_30d_vs_prev
|
||||
)
|
||||
SELECT
|
||||
b.brand_group,
|
||||
@@ -78,9 +93,13 @@ BEGIN
|
||||
-- This is mathematically equivalent to profit/revenue but more explicit
|
||||
((COALESCE(ba.revenue_30d, 0) - COALESCE(ba.cogs_30d, 0)) / COALESCE(ba.revenue_30d, 1)) * 100.0
|
||||
ELSE NULL -- No margin for low/no revenue brands
|
||||
END
|
||||
END,
|
||||
-- Growth metrics
|
||||
std_numeric(safe_divide((ba.sales_30d - ppbm.sales_prev_30d) * 100.0, ppbm.sales_prev_30d), 2),
|
||||
std_numeric(safe_divide((ba.revenue_30d - ppbm.revenue_prev_30d) * 100.0, ppbm.revenue_prev_30d), 2)
|
||||
FROM AllBrands b
|
||||
LEFT JOIN BrandAggregates ba ON b.brand_group = ba.brand_group
|
||||
LEFT JOIN PreviousPeriodBrandMetrics ppbm ON b.brand_group = ppbm.brand_group
|
||||
|
||||
ON CONFLICT (brand_name) DO UPDATE SET
|
||||
last_calculated = EXCLUDED.last_calculated,
|
||||
@@ -95,7 +114,9 @@ BEGIN
|
||||
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
|
||||
avg_margin_30d = EXCLUDED.avg_margin_30d,
|
||||
sales_growth_30d_vs_prev = EXCLUDED.sales_growth_30d_vs_prev,
|
||||
revenue_growth_30d_vs_prev = EXCLUDED.revenue_growth_30d_vs_prev
|
||||
WHERE -- Only update if at least one value has changed
|
||||
brand_metrics.product_count IS DISTINCT FROM EXCLUDED.product_count OR
|
||||
brand_metrics.active_product_count IS DISTINCT FROM EXCLUDED.active_product_count OR
|
||||
|
||||
@@ -1,5 +1,5 @@
|
||||
-- Description: Calculates and updates aggregated metrics per category.
|
||||
-- Dependencies: product_metrics, products, categories, product_categories, calculate_status table.
|
||||
-- Description: Calculates and updates aggregated metrics per category with hierarchy rollups.
|
||||
-- Dependencies: product_metrics, products, categories, product_categories, category_hierarchy, calculate_status table.
|
||||
-- Frequency: Daily (after product_metrics update).
|
||||
|
||||
DO $$
|
||||
@@ -9,55 +9,21 @@ DECLARE
|
||||
_min_revenue NUMERIC := 50.00; -- Minimum revenue threshold for margin calculation
|
||||
BEGIN
|
||||
RAISE NOTICE 'Running % calculation...', _module_name;
|
||||
|
||||
-- Refresh the category hierarchy materialized view first
|
||||
REFRESH MATERIALIZED VIEW CONCURRENTLY category_hierarchy;
|
||||
|
||||
WITH
|
||||
-- Identify the hierarchy depth for each category
|
||||
CategoryDepth AS (
|
||||
WITH RECURSIVE CategoryTree AS (
|
||||
-- Base case: Start with categories without parents (root categories)
|
||||
SELECT cat_id, name, parent_id, 0 AS depth
|
||||
FROM public.categories
|
||||
WHERE parent_id IS NULL
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- Recursive step: Add child categories with incremented depth
|
||||
SELECT c.cat_id, c.name, c.parent_id, ct.depth + 1
|
||||
FROM public.categories c
|
||||
JOIN CategoryTree ct ON c.parent_id = ct.cat_id
|
||||
)
|
||||
SELECT cat_id, depth
|
||||
FROM CategoryTree
|
||||
),
|
||||
-- For each product, find the most specific (deepest) category it belongs to
|
||||
ProductDeepestCategory AS (
|
||||
SELECT
|
||||
pc.pid,
|
||||
pc.cat_id
|
||||
FROM public.product_categories pc
|
||||
JOIN CategoryDepth cd ON pc.cat_id = cd.cat_id
|
||||
-- This is the key part: for each product, select only the category with maximum depth
|
||||
WHERE (pc.pid, cd.depth) IN (
|
||||
SELECT pc2.pid, MAX(cd2.depth)
|
||||
FROM public.product_categories pc2
|
||||
JOIN CategoryDepth cd2 ON pc2.cat_id = cd2.cat_id
|
||||
GROUP BY pc2.pid
|
||||
)
|
||||
),
|
||||
-- Calculate metrics only at the most specific category level for each product
|
||||
-- These are the direct metrics (only products directly in this category)
|
||||
DirectCategoryMetrics AS (
|
||||
-- First calculate direct metrics (products directly in each category)
|
||||
WITH DirectCategoryMetrics AS (
|
||||
SELECT
|
||||
pdc.cat_id,
|
||||
-- Counts
|
||||
pc.cat_id,
|
||||
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 - Only include products with actual sales in each period
|
||||
-- Sales metrics with proper filtering
|
||||
SUM(CASE WHEN pm.sales_7d > 0 THEN pm.sales_7d ELSE 0 END) AS sales_7d,
|
||||
SUM(CASE WHEN pm.revenue_7d > 0 THEN pm.revenue_7d ELSE 0 END) AS revenue_7d,
|
||||
SUM(CASE WHEN pm.sales_30d > 0 THEN pm.sales_30d ELSE 0 END) AS sales_30d,
|
||||
@@ -67,179 +33,141 @@ BEGIN
|
||||
SUM(CASE WHEN pm.sales_365d > 0 THEN pm.sales_365d ELSE 0 END) AS sales_365d,
|
||||
SUM(CASE WHEN pm.revenue_365d > 0 THEN pm.revenue_365d ELSE 0 END) AS revenue_365d,
|
||||
SUM(CASE WHEN pm.lifetime_sales > 0 THEN pm.lifetime_sales ELSE 0 END) AS lifetime_sales,
|
||||
SUM(CASE WHEN pm.lifetime_revenue > 0 THEN pm.lifetime_revenue ELSE 0 END) AS lifetime_revenue,
|
||||
-- Data for KPIs - Only average stock for products with stock
|
||||
SUM(CASE WHEN pm.avg_stock_units_30d > 0 THEN pm.avg_stock_units_30d ELSE 0 END) AS total_avg_stock_units_30d
|
||||
FROM public.product_metrics pm
|
||||
JOIN ProductDeepestCategory pdc ON pm.pid = pdc.pid
|
||||
GROUP BY pdc.cat_id
|
||||
SUM(CASE WHEN pm.lifetime_revenue > 0 THEN pm.lifetime_revenue ELSE 0 END) AS lifetime_revenue
|
||||
FROM public.product_categories pc
|
||||
JOIN public.product_metrics pm ON pc.pid = pm.pid
|
||||
GROUP BY pc.cat_id
|
||||
),
|
||||
-- Build a category lookup table for parent relationships
|
||||
CategoryHierarchyPaths AS (
|
||||
WITH RECURSIVE ParentPaths AS (
|
||||
-- Base case: All categories with their immediate parents
|
||||
SELECT
|
||||
cat_id,
|
||||
cat_id as leaf_id, -- Every category is its own leaf initially
|
||||
ARRAY[cat_id] as path
|
||||
FROM public.categories
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- Recursive step: Walk up the parent chain
|
||||
SELECT
|
||||
c.parent_id as cat_id,
|
||||
pp.leaf_id, -- Keep the original leaf_id
|
||||
c.parent_id || pp.path as path
|
||||
FROM ParentPaths pp
|
||||
JOIN public.categories c ON pp.cat_id = c.cat_id
|
||||
WHERE c.parent_id IS NOT NULL -- Stop at root categories
|
||||
)
|
||||
-- Select distinct paths to avoid duplication
|
||||
SELECT DISTINCT cat_id, leaf_id
|
||||
FROM ParentPaths
|
||||
),
|
||||
-- Aggregate metrics from leaf categories to their ancestors without duplication
|
||||
-- These are the rolled-up metrics (including all child categories)
|
||||
RollupMetrics AS (
|
||||
-- Calculate rolled-up metrics (including all descendant categories)
|
||||
RolledUpMetrics AS (
|
||||
SELECT
|
||||
chp.cat_id,
|
||||
-- For each parent category, count distinct products to avoid duplication
|
||||
COUNT(DISTINCT dcm.cat_id) AS child_categories_count,
|
||||
SUM(dcm.product_count) AS rollup_product_count,
|
||||
SUM(dcm.active_product_count) AS rollup_active_product_count,
|
||||
SUM(dcm.replenishable_product_count) AS rollup_replenishable_product_count,
|
||||
SUM(dcm.current_stock_units) AS rollup_current_stock_units,
|
||||
SUM(dcm.current_stock_cost) AS rollup_current_stock_cost,
|
||||
SUM(dcm.current_stock_retail) AS rollup_current_stock_retail,
|
||||
SUM(dcm.sales_7d) AS rollup_sales_7d,
|
||||
SUM(dcm.revenue_7d) AS rollup_revenue_7d,
|
||||
SUM(dcm.sales_30d) AS rollup_sales_30d,
|
||||
SUM(dcm.revenue_30d) AS rollup_revenue_30d,
|
||||
SUM(dcm.cogs_30d) AS rollup_cogs_30d,
|
||||
SUM(dcm.profit_30d) AS rollup_profit_30d,
|
||||
SUM(dcm.sales_365d) AS rollup_sales_365d,
|
||||
SUM(dcm.revenue_365d) AS rollup_revenue_365d,
|
||||
SUM(dcm.lifetime_sales) AS rollup_lifetime_sales,
|
||||
SUM(dcm.lifetime_revenue) AS rollup_lifetime_revenue,
|
||||
SUM(dcm.total_avg_stock_units_30d) AS rollup_total_avg_stock_units_30d
|
||||
FROM CategoryHierarchyPaths chp
|
||||
JOIN DirectCategoryMetrics dcm ON chp.leaf_id = dcm.cat_id
|
||||
GROUP BY chp.cat_id
|
||||
ch.cat_id,
|
||||
-- Sum metrics from this category and all its descendants
|
||||
SUM(dcm.product_count) AS product_count,
|
||||
SUM(dcm.active_product_count) AS active_product_count,
|
||||
SUM(dcm.replenishable_product_count) AS replenishable_product_count,
|
||||
SUM(dcm.current_stock_units) AS current_stock_units,
|
||||
SUM(dcm.current_stock_cost) AS current_stock_cost,
|
||||
SUM(dcm.current_stock_retail) AS current_stock_retail,
|
||||
SUM(dcm.sales_7d) AS sales_7d,
|
||||
SUM(dcm.revenue_7d) AS revenue_7d,
|
||||
SUM(dcm.sales_30d) AS sales_30d,
|
||||
SUM(dcm.revenue_30d) AS revenue_30d,
|
||||
SUM(dcm.cogs_30d) AS cogs_30d,
|
||||
SUM(dcm.profit_30d) AS profit_30d,
|
||||
SUM(dcm.sales_365d) AS sales_365d,
|
||||
SUM(dcm.revenue_365d) AS revenue_365d,
|
||||
SUM(dcm.lifetime_sales) AS lifetime_sales,
|
||||
SUM(dcm.lifetime_revenue) AS lifetime_revenue
|
||||
FROM category_hierarchy ch
|
||||
LEFT JOIN DirectCategoryMetrics dcm ON
|
||||
dcm.cat_id = ch.cat_id OR
|
||||
dcm.cat_id = ANY(SELECT cat_id FROM category_hierarchy WHERE ch.cat_id = ANY(ancestor_ids))
|
||||
GROUP BY ch.cat_id
|
||||
),
|
||||
-- Combine direct and rollup metrics
|
||||
CombinedMetrics AS (
|
||||
PreviousPeriodCategoryMetrics AS (
|
||||
-- Get previous period metrics for growth calculation
|
||||
SELECT
|
||||
pc.cat_id,
|
||||
SUM(CASE WHEN dps.snapshot_date >= CURRENT_DATE - INTERVAL '59 days'
|
||||
AND dps.snapshot_date < CURRENT_DATE - INTERVAL '29 days'
|
||||
THEN dps.units_sold ELSE 0 END) AS sales_prev_30d,
|
||||
SUM(CASE WHEN dps.snapshot_date >= CURRENT_DATE - INTERVAL '59 days'
|
||||
AND dps.snapshot_date < CURRENT_DATE - INTERVAL '29 days'
|
||||
THEN dps.net_revenue ELSE 0 END) AS revenue_prev_30d
|
||||
FROM public.daily_product_snapshots dps
|
||||
JOIN public.product_categories pc ON dps.pid = pc.pid
|
||||
GROUP BY pc.cat_id
|
||||
),
|
||||
RolledUpPreviousPeriod AS (
|
||||
-- Calculate rolled-up previous period metrics
|
||||
SELECT
|
||||
ch.cat_id,
|
||||
SUM(ppcm.sales_prev_30d) AS sales_prev_30d,
|
||||
SUM(ppcm.revenue_prev_30d) AS revenue_prev_30d
|
||||
FROM category_hierarchy ch
|
||||
LEFT JOIN PreviousPeriodCategoryMetrics ppcm ON
|
||||
ppcm.cat_id = ch.cat_id OR
|
||||
ppcm.cat_id = ANY(SELECT cat_id FROM category_hierarchy WHERE ch.cat_id = ANY(ancestor_ids))
|
||||
GROUP BY ch.cat_id
|
||||
),
|
||||
AllCategories AS (
|
||||
-- Ensure all categories are included
|
||||
SELECT
|
||||
c.cat_id,
|
||||
c.name,
|
||||
c.type,
|
||||
c.parent_id,
|
||||
-- Direct metrics (just this category)
|
||||
COALESCE(dcm.product_count, 0) AS direct_product_count,
|
||||
COALESCE(dcm.active_product_count, 0) AS direct_active_product_count,
|
||||
COALESCE(dcm.replenishable_product_count, 0) AS direct_replenishable_product_count,
|
||||
COALESCE(dcm.current_stock_units, 0) AS direct_current_stock_units,
|
||||
COALESCE(dcm.current_stock_cost, 0) AS direct_current_stock_cost,
|
||||
COALESCE(dcm.current_stock_retail, 0) AS direct_current_stock_retail,
|
||||
COALESCE(dcm.sales_7d, 0) AS direct_sales_7d,
|
||||
COALESCE(dcm.revenue_7d, 0) AS direct_revenue_7d,
|
||||
COALESCE(dcm.sales_30d, 0) AS direct_sales_30d,
|
||||
COALESCE(dcm.revenue_30d, 0) AS direct_revenue_30d,
|
||||
COALESCE(dcm.cogs_30d, 0) AS direct_cogs_30d,
|
||||
COALESCE(dcm.profit_30d, 0) AS direct_profit_30d,
|
||||
COALESCE(dcm.sales_365d, 0) AS direct_sales_365d,
|
||||
COALESCE(dcm.revenue_365d, 0) AS direct_revenue_365d,
|
||||
COALESCE(dcm.lifetime_sales, 0) AS direct_lifetime_sales,
|
||||
COALESCE(dcm.lifetime_revenue, 0) AS direct_lifetime_revenue,
|
||||
COALESCE(dcm.total_avg_stock_units_30d, 0) AS direct_avg_stock_units_30d,
|
||||
|
||||
-- Rolled up metrics (this category + all children)
|
||||
COALESCE(rm.rollup_product_count, 0) AS product_count,
|
||||
COALESCE(rm.rollup_active_product_count, 0) AS active_product_count,
|
||||
COALESCE(rm.rollup_replenishable_product_count, 0) AS replenishable_product_count,
|
||||
COALESCE(rm.rollup_current_stock_units, 0) AS current_stock_units,
|
||||
COALESCE(rm.rollup_current_stock_cost, 0) AS current_stock_cost,
|
||||
COALESCE(rm.rollup_current_stock_retail, 0) AS current_stock_retail,
|
||||
COALESCE(rm.rollup_sales_7d, 0) AS sales_7d,
|
||||
COALESCE(rm.rollup_revenue_7d, 0) AS revenue_7d,
|
||||
COALESCE(rm.rollup_sales_30d, 0) AS sales_30d,
|
||||
COALESCE(rm.rollup_revenue_30d, 0) AS revenue_30d,
|
||||
COALESCE(rm.rollup_cogs_30d, 0) AS cogs_30d,
|
||||
COALESCE(rm.rollup_profit_30d, 0) AS profit_30d,
|
||||
COALESCE(rm.rollup_sales_365d, 0) AS sales_365d,
|
||||
COALESCE(rm.rollup_revenue_365d, 0) AS revenue_365d,
|
||||
COALESCE(rm.rollup_lifetime_sales, 0) AS lifetime_sales,
|
||||
COALESCE(rm.rollup_lifetime_revenue, 0) AS lifetime_revenue,
|
||||
COALESCE(rm.rollup_total_avg_stock_units_30d, 0) AS total_avg_stock_units_30d
|
||||
c.parent_id
|
||||
FROM public.categories c
|
||||
LEFT JOIN DirectCategoryMetrics dcm ON c.cat_id = dcm.cat_id
|
||||
LEFT JOIN RollupMetrics rm ON c.cat_id = rm.cat_id
|
||||
WHERE c.status = 'active'
|
||||
)
|
||||
INSERT INTO public.category_metrics (
|
||||
category_id, category_name, category_type, parent_id, last_calculated,
|
||||
-- Store all direct and rolled up metrics
|
||||
-- Rolled-up metrics
|
||||
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,
|
||||
-- Also store direct metrics with direct_ prefix
|
||||
-- Direct metrics
|
||||
direct_product_count, direct_active_product_count, direct_replenishable_product_count,
|
||||
direct_current_stock_units, direct_stock_cost, direct_stock_retail,
|
||||
direct_sales_7d, direct_revenue_7d, direct_sales_30d, direct_revenue_30d,
|
||||
direct_sales_7d, direct_revenue_7d, direct_sales_30d, direct_revenue_30d,
|
||||
direct_profit_30d, direct_cogs_30d, direct_sales_365d, direct_revenue_365d,
|
||||
direct_lifetime_sales, direct_lifetime_revenue,
|
||||
-- KPIs
|
||||
avg_margin_30d, stock_turn_30d
|
||||
avg_margin_30d,
|
||||
sales_growth_30d_vs_prev, revenue_growth_30d_vs_prev
|
||||
)
|
||||
SELECT
|
||||
cm.cat_id,
|
||||
cm.name,
|
||||
cm.type,
|
||||
cm.parent_id,
|
||||
ac.cat_id,
|
||||
ac.name,
|
||||
ac.type,
|
||||
ac.parent_id,
|
||||
_start_time,
|
||||
-- Rolled-up metrics (total including children)
|
||||
cm.product_count,
|
||||
cm.active_product_count,
|
||||
cm.replenishable_product_count,
|
||||
cm.current_stock_units,
|
||||
cm.current_stock_cost,
|
||||
cm.current_stock_retail,
|
||||
cm.sales_7d, cm.revenue_7d,
|
||||
cm.sales_30d, cm.revenue_30d, cm.profit_30d, cm.cogs_30d,
|
||||
cm.sales_365d, cm.revenue_365d,
|
||||
cm.lifetime_sales, cm.lifetime_revenue,
|
||||
-- Direct metrics (just this category)
|
||||
cm.direct_product_count,
|
||||
cm.direct_active_product_count,
|
||||
cm.direct_replenishable_product_count,
|
||||
cm.direct_current_stock_units,
|
||||
cm.direct_current_stock_cost,
|
||||
cm.direct_current_stock_retail,
|
||||
cm.direct_sales_7d, cm.direct_revenue_7d,
|
||||
cm.direct_sales_30d, cm.direct_revenue_30d, cm.direct_profit_30d, cm.direct_cogs_30d,
|
||||
cm.direct_sales_365d, cm.direct_revenue_365d,
|
||||
cm.direct_lifetime_sales, cm.direct_lifetime_revenue,
|
||||
-- Rolled-up metrics (includes descendants)
|
||||
COALESCE(rum.product_count, 0),
|
||||
COALESCE(rum.active_product_count, 0),
|
||||
COALESCE(rum.replenishable_product_count, 0),
|
||||
COALESCE(rum.current_stock_units, 0),
|
||||
COALESCE(rum.current_stock_cost, 0.00),
|
||||
COALESCE(rum.current_stock_retail, 0.00),
|
||||
COALESCE(rum.sales_7d, 0), COALESCE(rum.revenue_7d, 0.00),
|
||||
COALESCE(rum.sales_30d, 0), COALESCE(rum.revenue_30d, 0.00),
|
||||
COALESCE(rum.profit_30d, 0.00), COALESCE(rum.cogs_30d, 0.00),
|
||||
COALESCE(rum.sales_365d, 0), COALESCE(rum.revenue_365d, 0.00),
|
||||
COALESCE(rum.lifetime_sales, 0), COALESCE(rum.lifetime_revenue, 0.00),
|
||||
-- Direct metrics (only this category)
|
||||
COALESCE(dcm.product_count, 0),
|
||||
COALESCE(dcm.active_product_count, 0),
|
||||
COALESCE(dcm.replenishable_product_count, 0),
|
||||
COALESCE(dcm.current_stock_units, 0),
|
||||
COALESCE(dcm.current_stock_cost, 0.00),
|
||||
COALESCE(dcm.current_stock_retail, 0.00),
|
||||
COALESCE(dcm.sales_7d, 0), COALESCE(dcm.revenue_7d, 0.00),
|
||||
COALESCE(dcm.sales_30d, 0), COALESCE(dcm.revenue_30d, 0.00),
|
||||
COALESCE(dcm.profit_30d, 0.00), COALESCE(dcm.cogs_30d, 0.00),
|
||||
COALESCE(dcm.sales_365d, 0), COALESCE(dcm.revenue_365d, 0.00),
|
||||
COALESCE(dcm.lifetime_sales, 0), COALESCE(dcm.lifetime_revenue, 0.00),
|
||||
-- KPIs - Calculate margin only for categories with significant revenue
|
||||
CASE
|
||||
WHEN cm.revenue_30d >= _min_revenue THEN
|
||||
((cm.revenue_30d - cm.cogs_30d) / cm.revenue_30d) * 100.0
|
||||
ELSE NULL -- No margin for low/no revenue categories
|
||||
WHEN COALESCE(rum.revenue_30d, 0) >= _min_revenue THEN
|
||||
((COALESCE(rum.revenue_30d, 0) - COALESCE(rum.cogs_30d, 0)) / COALESCE(rum.revenue_30d, 1)) * 100.0
|
||||
ELSE NULL
|
||||
END,
|
||||
-- Stock Turn calculation
|
||||
CASE
|
||||
WHEN cm.total_avg_stock_units_30d > 0 THEN
|
||||
cm.sales_30d / cm.total_avg_stock_units_30d
|
||||
ELSE NULL -- No stock turn if no average stock
|
||||
END
|
||||
FROM CombinedMetrics cm
|
||||
-- Growth metrics for rolled-up values
|
||||
std_numeric(safe_divide((rum.sales_30d - rupp.sales_prev_30d) * 100.0, rupp.sales_prev_30d), 2),
|
||||
std_numeric(safe_divide((rum.revenue_30d - rupp.revenue_prev_30d) * 100.0, rupp.revenue_prev_30d), 2)
|
||||
FROM AllCategories ac
|
||||
LEFT JOIN DirectCategoryMetrics dcm ON ac.cat_id = dcm.cat_id
|
||||
LEFT JOIN RolledUpMetrics rum ON ac.cat_id = rum.cat_id
|
||||
LEFT JOIN RolledUpPreviousPeriod rupp ON ac.cat_id = rupp.cat_id
|
||||
|
||||
ON CONFLICT (category_id) DO UPDATE SET
|
||||
last_calculated = EXCLUDED.last_calculated,
|
||||
category_name = EXCLUDED.category_name,
|
||||
category_type = EXCLUDED.category_type,
|
||||
parent_id = EXCLUDED.parent_id,
|
||||
last_calculated = EXCLUDED.last_calculated,
|
||||
|
||||
-- ROLLED-UP METRICS (includes this category + all descendants)
|
||||
-- Rolled-up metrics
|
||||
product_count = EXCLUDED.product_count,
|
||||
active_product_count = EXCLUDED.active_product_count,
|
||||
replenishable_product_count = EXCLUDED.replenishable_product_count,
|
||||
@@ -251,8 +179,7 @@ BEGIN
|
||||
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,
|
||||
|
||||
-- DIRECT METRICS (only products directly in this category)
|
||||
-- Direct metrics
|
||||
direct_product_count = EXCLUDED.direct_product_count,
|
||||
direct_active_product_count = EXCLUDED.direct_active_product_count,
|
||||
direct_replenishable_product_count = EXCLUDED.direct_replenishable_product_count,
|
||||
@@ -264,10 +191,9 @@ BEGIN
|
||||
direct_profit_30d = EXCLUDED.direct_profit_30d, direct_cogs_30d = EXCLUDED.direct_cogs_30d,
|
||||
direct_sales_365d = EXCLUDED.direct_sales_365d, direct_revenue_365d = EXCLUDED.direct_revenue_365d,
|
||||
direct_lifetime_sales = EXCLUDED.direct_lifetime_sales, direct_lifetime_revenue = EXCLUDED.direct_lifetime_revenue,
|
||||
|
||||
-- Calculated KPIs
|
||||
avg_margin_30d = EXCLUDED.avg_margin_30d,
|
||||
stock_turn_30d = EXCLUDED.stock_turn_30d
|
||||
sales_growth_30d_vs_prev = EXCLUDED.sales_growth_30d_vs_prev,
|
||||
revenue_growth_30d_vs_prev = EXCLUDED.revenue_growth_30d_vs_prev
|
||||
WHERE -- Only update if at least one value has changed
|
||||
category_metrics.product_count IS DISTINCT FROM EXCLUDED.product_count OR
|
||||
category_metrics.active_product_count IS DISTINCT FROM EXCLUDED.active_product_count OR
|
||||
@@ -291,19 +217,23 @@ WITH update_stats AS (
|
||||
SELECT
|
||||
COUNT(*) as total_categories,
|
||||
COUNT(*) FILTER (WHERE last_calculated >= NOW() - INTERVAL '5 minutes') as rows_processed,
|
||||
COUNT(*) FILTER (WHERE category_type = 11) as main_categories, -- 11 = category
|
||||
COUNT(*) FILTER (WHERE category_type = 12) as subcategories, -- 12 = subcategory
|
||||
SUM(product_count) as total_products,
|
||||
SUM(active_product_count) as total_active_products,
|
||||
SUM(current_stock_units) as total_stock_units
|
||||
COUNT(*) FILTER (WHERE category_type = 10) as sections,
|
||||
COUNT(*) FILTER (WHERE category_type = 11) as categories,
|
||||
COUNT(*) FILTER (WHERE category_type = 12) as subcategories,
|
||||
SUM(product_count) as total_products_rolled,
|
||||
SUM(direct_product_count) as total_products_direct,
|
||||
SUM(sales_30d) as total_sales_30d,
|
||||
SUM(revenue_30d) as total_revenue_30d
|
||||
FROM public.category_metrics
|
||||
)
|
||||
SELECT
|
||||
rows_processed,
|
||||
total_categories,
|
||||
main_categories,
|
||||
sections,
|
||||
categories,
|
||||
subcategories,
|
||||
total_products::int,
|
||||
total_active_products::int,
|
||||
total_stock_units::int
|
||||
total_products_rolled::int,
|
||||
total_products_direct::int,
|
||||
total_sales_30d::int,
|
||||
ROUND(total_revenue_30d, 2) as total_revenue_30d
|
||||
FROM update_stats;
|
||||
@@ -44,6 +44,21 @@ BEGIN
|
||||
WHERE p.vendor IS NOT NULL AND p.vendor <> ''
|
||||
GROUP BY p.vendor
|
||||
),
|
||||
PreviousPeriodVendorMetrics AS (
|
||||
-- Get previous period metrics for growth calculation
|
||||
SELECT
|
||||
p.vendor,
|
||||
SUM(CASE WHEN dps.snapshot_date >= CURRENT_DATE - INTERVAL '59 days'
|
||||
AND dps.snapshot_date < CURRENT_DATE - INTERVAL '29 days'
|
||||
THEN dps.units_sold ELSE 0 END) AS sales_prev_30d,
|
||||
SUM(CASE WHEN dps.snapshot_date >= CURRENT_DATE - INTERVAL '59 days'
|
||||
AND dps.snapshot_date < CURRENT_DATE - INTERVAL '29 days'
|
||||
THEN dps.net_revenue ELSE 0 END) AS revenue_prev_30d
|
||||
FROM public.daily_product_snapshots dps
|
||||
JOIN public.products p ON dps.pid = p.pid
|
||||
WHERE p.vendor IS NOT NULL AND p.vendor <> ''
|
||||
GROUP BY p.vendor
|
||||
),
|
||||
VendorPOAggregates AS (
|
||||
-- Aggregate PO related stats including lead time calculated from POs to receivings
|
||||
SELECT
|
||||
@@ -78,7 +93,8 @@ BEGIN
|
||||
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
|
||||
avg_margin_30d,
|
||||
sales_growth_30d_vs_prev, revenue_growth_30d_vs_prev
|
||||
)
|
||||
SELECT
|
||||
v.vendor,
|
||||
@@ -102,10 +118,14 @@ BEGIN
|
||||
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
|
||||
(vpa.profit_30d / NULLIF(vpa.revenue_30d, 0)) * 100.0,
|
||||
-- Growth metrics
|
||||
std_numeric(safe_divide((vpa.sales_30d - ppvm.sales_prev_30d) * 100.0, ppvm.sales_prev_30d), 2),
|
||||
std_numeric(safe_divide((vpa.revenue_30d - ppvm.revenue_prev_30d) * 100.0, ppvm.revenue_prev_30d), 2)
|
||||
FROM AllVendors v
|
||||
LEFT JOIN VendorProductAggregates vpa ON v.vendor = vpa.vendor
|
||||
LEFT JOIN VendorPOAggregates vpoa ON v.vendor = vpoa.vendor
|
||||
LEFT JOIN PreviousPeriodVendorMetrics ppvm ON v.vendor = ppvm.vendor
|
||||
|
||||
ON CONFLICT (vendor_name) DO UPDATE SET
|
||||
last_calculated = EXCLUDED.last_calculated,
|
||||
@@ -124,7 +144,9 @@ BEGIN
|
||||
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
|
||||
avg_margin_30d = EXCLUDED.avg_margin_30d,
|
||||
sales_growth_30d_vs_prev = EXCLUDED.sales_growth_30d_vs_prev,
|
||||
revenue_growth_30d_vs_prev = EXCLUDED.revenue_growth_30d_vs_prev
|
||||
WHERE -- Only update if at least one value has changed
|
||||
vendor_metrics.product_count IS DISTINCT FROM EXCLUDED.product_count OR
|
||||
vendor_metrics.active_product_count IS DISTINCT FROM EXCLUDED.active_product_count OR
|
||||
|
||||
@@ -86,7 +86,14 @@ BEGIN
|
||||
COALESCE(SUM(CASE WHEN o.quantity > 0 AND COALESCE(o.status, 'pending') NOT IN ('canceled', 'returned') THEN o.quantity ELSE 0 END), 0) AS units_sold,
|
||||
COALESCE(SUM(CASE WHEN o.quantity > 0 AND COALESCE(o.status, 'pending') NOT IN ('canceled', 'returned') THEN o.price * o.quantity ELSE 0 END), 0.00) AS gross_revenue_unadjusted, -- Before discount
|
||||
COALESCE(SUM(CASE WHEN o.quantity > 0 AND COALESCE(o.status, 'pending') NOT IN ('canceled', 'returned') THEN o.discount ELSE 0 END), 0.00) AS discounts,
|
||||
COALESCE(SUM(CASE WHEN o.quantity > 0 AND COALESCE(o.status, 'pending') NOT IN ('canceled', 'returned') THEN COALESCE(o.costeach, p.landing_cost_price, p.cost_price) * o.quantity ELSE 0 END), 0.00) AS cogs,
|
||||
COALESCE(SUM(CASE WHEN o.quantity > 0 AND COALESCE(o.status, 'pending') NOT IN ('canceled', 'returned') THEN
|
||||
COALESCE(
|
||||
o.costeach, -- First use order-specific cost if available
|
||||
get_weighted_avg_cost(p.pid, o.date::date), -- Then use weighted average cost
|
||||
p.landing_cost_price, -- Fallback to landing cost
|
||||
p.cost_price -- Final fallback to current cost
|
||||
) * o.quantity
|
||||
ELSE 0 END), 0.00) AS cogs,
|
||||
COALESCE(SUM(CASE WHEN o.quantity > 0 AND COALESCE(o.status, 'pending') NOT IN ('canceled', 'returned') THEN p.regular_price * o.quantity ELSE 0 END), 0.00) AS gross_regular_revenue, -- Use current regular price for simplicity here
|
||||
|
||||
-- Aggregate Returns (Quantity < 0 or Status = Returned)
|
||||
|
||||
@@ -171,6 +171,85 @@ BEGIN
|
||||
FROM public.products p
|
||||
LEFT JOIN public.settings_product sp ON p.pid = sp.pid
|
||||
LEFT JOIN public.settings_vendor sv ON p.vendor = sv.vendor
|
||||
),
|
||||
LifetimeRevenue AS (
|
||||
-- Calculate actual revenue from orders table
|
||||
SELECT
|
||||
o.pid,
|
||||
SUM(o.price * o.quantity - COALESCE(o.discount, 0)) AS lifetime_revenue_from_orders,
|
||||
SUM(o.quantity) AS lifetime_units_from_orders
|
||||
FROM public.orders o
|
||||
WHERE o.status NOT IN ('canceled', 'returned')
|
||||
AND o.quantity > 0
|
||||
GROUP BY o.pid
|
||||
),
|
||||
PreviousPeriodMetrics AS (
|
||||
-- Calculate metrics for previous 30-day period for growth comparison
|
||||
SELECT
|
||||
pid,
|
||||
SUM(CASE WHEN snapshot_date >= _current_date - INTERVAL '59 days'
|
||||
AND snapshot_date < _current_date - INTERVAL '29 days'
|
||||
THEN units_sold ELSE 0 END) AS sales_prev_30d,
|
||||
SUM(CASE WHEN snapshot_date >= _current_date - INTERVAL '59 days'
|
||||
AND snapshot_date < _current_date - INTERVAL '29 days'
|
||||
THEN net_revenue ELSE 0 END) AS revenue_prev_30d,
|
||||
-- Year-over-year comparison
|
||||
SUM(CASE WHEN snapshot_date >= _current_date - INTERVAL '395 days'
|
||||
AND snapshot_date < _current_date - INTERVAL '365 days'
|
||||
THEN units_sold ELSE 0 END) AS sales_30d_last_year,
|
||||
SUM(CASE WHEN snapshot_date >= _current_date - INTERVAL '395 days'
|
||||
AND snapshot_date < _current_date - INTERVAL '365 days'
|
||||
THEN net_revenue ELSE 0 END) AS revenue_30d_last_year
|
||||
FROM public.daily_product_snapshots
|
||||
GROUP BY pid
|
||||
),
|
||||
DemandVariability AS (
|
||||
-- Calculate variance and standard deviation of daily sales
|
||||
SELECT
|
||||
pid,
|
||||
COUNT(*) AS days_with_data,
|
||||
AVG(units_sold) AS avg_daily_sales,
|
||||
VARIANCE(units_sold) AS sales_variance,
|
||||
STDDEV(units_sold) AS sales_std_dev,
|
||||
-- Coefficient of variation
|
||||
CASE
|
||||
WHEN AVG(units_sold) > 0 THEN STDDEV(units_sold) / AVG(units_sold)
|
||||
ELSE NULL
|
||||
END AS sales_cv
|
||||
FROM public.daily_product_snapshots
|
||||
WHERE snapshot_date >= _current_date - INTERVAL '29 days'
|
||||
AND snapshot_date <= _current_date
|
||||
GROUP BY pid
|
||||
),
|
||||
ServiceLevels AS (
|
||||
-- Calculate service level and fill rate metrics
|
||||
SELECT
|
||||
pid,
|
||||
COUNT(*) FILTER (WHERE stockout_flag = true) AS stockout_incidents_30d,
|
||||
COUNT(*) FILTER (WHERE stockout_flag = true AND units_sold > 0) AS lost_sales_incidents_30d,
|
||||
-- Service level: percentage of days without stockouts
|
||||
(1.0 - (COUNT(*) FILTER (WHERE stockout_flag = true)::NUMERIC / NULLIF(COUNT(*), 0))) * 100 AS service_level_30d,
|
||||
-- Fill rate: units sold / (units sold + potential lost sales)
|
||||
CASE
|
||||
WHEN SUM(units_sold) > 0 THEN
|
||||
(SUM(units_sold)::NUMERIC /
|
||||
(SUM(units_sold) + SUM(CASE WHEN stockout_flag THEN units_sold * 0.2 ELSE 0 END))) * 100
|
||||
ELSE NULL
|
||||
END AS fill_rate_30d
|
||||
FROM public.daily_product_snapshots
|
||||
WHERE snapshot_date >= _current_date - INTERVAL '29 days'
|
||||
AND snapshot_date <= _current_date
|
||||
GROUP BY pid
|
||||
),
|
||||
SeasonalityAnalysis AS (
|
||||
-- Simple seasonality detection
|
||||
SELECT
|
||||
p.pid,
|
||||
sp.seasonal_pattern,
|
||||
sp.seasonality_index,
|
||||
sp.peak_season
|
||||
FROM products p
|
||||
CROSS JOIN LATERAL detect_seasonal_pattern(p.pid) sp
|
||||
)
|
||||
-- Final UPSERT into product_metrics
|
||||
INSERT INTO public.product_metrics (
|
||||
@@ -187,7 +266,7 @@ BEGIN
|
||||
stockout_days_30d, sales_365d, revenue_365d,
|
||||
avg_stock_units_30d, avg_stock_cost_30d, avg_stock_retail_30d, avg_stock_gross_30d,
|
||||
received_qty_30d, received_cost_30d,
|
||||
lifetime_sales, lifetime_revenue,
|
||||
lifetime_sales, lifetime_revenue, lifetime_revenue_quality,
|
||||
first_7_days_sales, first_7_days_revenue, first_30_days_sales, first_30_days_revenue,
|
||||
first_60_days_sales, first_60_days_revenue, first_90_days_sales, first_90_days_revenue,
|
||||
asp_30d, acp_30d, avg_ros_30d, avg_sales_per_day_30d, avg_sales_per_month_30d,
|
||||
@@ -203,7 +282,13 @@ BEGIN
|
||||
stock_cover_in_days, po_cover_in_days, sells_out_in_days, replenish_date,
|
||||
overstocked_units, overstocked_cost, overstocked_retail, is_old_stock,
|
||||
yesterday_sales,
|
||||
status -- Add status field for calculated status
|
||||
status, -- Add status field for calculated status
|
||||
-- New fields
|
||||
sales_growth_30d_vs_prev, revenue_growth_30d_vs_prev,
|
||||
sales_growth_yoy, revenue_growth_yoy,
|
||||
sales_variance_30d, sales_std_dev_30d, sales_cv_30d, demand_pattern,
|
||||
fill_rate_30d, stockout_incidents_30d, service_level_30d, lost_sales_incidents_30d,
|
||||
seasonality_index, seasonal_pattern, peak_season
|
||||
)
|
||||
SELECT
|
||||
ci.pid, _start_time, ci.sku, ci.title, ci.brand, ci.vendor, ci.image_url, ci.is_visible, ci.is_replenishable,
|
||||
@@ -227,27 +312,33 @@ BEGIN
|
||||
sa.received_qty_30d, sa.received_cost_30d,
|
||||
-- Use total_sold from products table as the source of truth for lifetime sales
|
||||
-- This includes all historical data from the production database
|
||||
ci.historical_total_sold AS lifetime_sales,
|
||||
COALESCE(
|
||||
-- Option 1: Use 30-day average price if available
|
||||
CASE WHEN sa.sales_30d > 0 THEN
|
||||
ci.historical_total_sold * (sa.revenue_30d / NULLIF(sa.sales_30d, 0))
|
||||
ELSE NULL END,
|
||||
-- Option 2: Try 365-day average price if available
|
||||
CASE WHEN sa.sales_365d > 0 THEN
|
||||
ci.historical_total_sold * (sa.revenue_365d / NULLIF(sa.sales_365d, 0))
|
||||
ELSE NULL END,
|
||||
-- Option 3: Use current price as a reasonable estimate
|
||||
ci.historical_total_sold * ci.current_price,
|
||||
-- Option 4: Use regular price if current price might be zero
|
||||
ci.historical_total_sold * ci.current_regular_price,
|
||||
-- Final fallback: Use accumulated revenue (this is less accurate for old products)
|
||||
sa.total_net_revenue
|
||||
) AS lifetime_revenue,
|
||||
ci.historical_total_sold AS lifetime_sales,
|
||||
-- Calculate lifetime revenue using actual historical prices where available
|
||||
CASE
|
||||
WHEN lr.lifetime_revenue_from_orders IS NOT NULL THEN
|
||||
-- We have some order history - use it plus estimate for remaining
|
||||
lr.lifetime_revenue_from_orders +
|
||||
(GREATEST(0, ci.historical_total_sold - COALESCE(lr.lifetime_units_from_orders, 0)) *
|
||||
COALESCE(
|
||||
-- Use oldest known price from snapshots as proxy
|
||||
(SELECT revenue_7d / NULLIF(sales_7d, 0)
|
||||
FROM daily_product_snapshots
|
||||
WHERE pid = ci.pid AND sales_7d > 0
|
||||
ORDER BY snapshot_date ASC
|
||||
LIMIT 1),
|
||||
ci.current_price
|
||||
))
|
||||
ELSE
|
||||
-- No order history - estimate using current price
|
||||
ci.historical_total_sold * ci.current_price
|
||||
END AS lifetime_revenue,
|
||||
CASE
|
||||
WHEN lr.lifetime_units_from_orders >= ci.historical_total_sold * 0.9 THEN 'exact'
|
||||
WHEN lr.lifetime_units_from_orders >= ci.historical_total_sold * 0.5 THEN 'partial'
|
||||
ELSE 'estimated'
|
||||
END AS lifetime_revenue_quality,
|
||||
fpm.first_7_days_sales, fpm.first_7_days_revenue, fpm.first_30_days_sales, fpm.first_30_days_revenue,
|
||||
fpm.first_60_days_sales, fpm.first_60_days_revenue, fpm.first_90_days_sales, fpm.first_90_days_revenue,
|
||||
|
||||
-- Calculated KPIs
|
||||
sa.revenue_30d / NULLIF(sa.sales_30d, 0) AS asp_30d,
|
||||
sa.cogs_30d / NULLIF(sa.sales_30d, 0) AS acp_30d,
|
||||
sa.profit_30d / NULLIF(sa.sales_30d, 0) AS avg_ros_30d,
|
||||
@@ -262,317 +353,59 @@ BEGIN
|
||||
(sa.stockout_days_30d / 30.0) * 100 AS stockout_rate_30d,
|
||||
sa.gross_regular_revenue_30d - sa.gross_revenue_30d AS markdown_30d,
|
||||
((sa.gross_regular_revenue_30d - sa.gross_revenue_30d) / NULLIF(sa.gross_regular_revenue_30d, 0)) * 100 AS markdown_rate_30d,
|
||||
(sa.sales_30d / NULLIF(ci.current_stock + sa.sales_30d, 0)) * 100 AS sell_through_30d,
|
||||
-- Fix sell-through rate: Industry standard is Units Sold / (Beginning Inventory + Units Received)
|
||||
-- Approximating beginning inventory as current stock + units sold - units received
|
||||
(sa.sales_30d / NULLIF(
|
||||
ci.current_stock + sa.sales_30d + sa.returns_units_30d - sa.received_qty_30d,
|
||||
0
|
||||
)) * 100 AS sell_through_30d,
|
||||
|
||||
-- Forecasting intermediate values
|
||||
-- CRITICAL FIX: Use safer velocity calculation to prevent extreme values
|
||||
-- Original problematic calculation: (sa.sales_30d / NULLIF(30.0 - sa.stockout_days_30d, 0))
|
||||
-- Use available days (not stockout days) as denominator with a minimum safety value
|
||||
(sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d, -- Standard calculation
|
||||
CASE
|
||||
WHEN sa.sales_30d > 0 THEN 14.0 -- If we have sales, ensure at least 14 days denominator
|
||||
ELSE 30.0 -- If no sales, use full period
|
||||
END
|
||||
),
|
||||
0
|
||||
)
|
||||
) AS sales_velocity_daily,
|
||||
-- Use the calculate_sales_velocity function instead of repetitive calculation
|
||||
calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) AS sales_velocity_daily,
|
||||
s.effective_lead_time AS config_lead_time,
|
||||
s.effective_days_of_stock AS config_days_of_stock,
|
||||
s.effective_safety_stock AS config_safety_stock,
|
||||
(s.effective_lead_time + s.effective_days_of_stock) AS planning_period_days,
|
||||
|
||||
-- Apply the same fix to all derived calculations
|
||||
(sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_lead_time AS lead_time_forecast_units,
|
||||
calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_lead_time AS lead_time_forecast_units,
|
||||
|
||||
(sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_days_of_stock AS days_of_stock_forecast_units,
|
||||
calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_days_of_stock AS days_of_stock_forecast_units,
|
||||
|
||||
(sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * (s.effective_lead_time + s.effective_days_of_stock) AS planning_period_forecast_units,
|
||||
calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * (s.effective_lead_time + s.effective_days_of_stock) AS planning_period_forecast_units,
|
||||
|
||||
(ci.current_stock + COALESCE(ooi.on_order_qty, 0) - ((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_lead_time)) AS lead_time_closing_stock,
|
||||
(ci.current_stock + COALESCE(ooi.on_order_qty, 0) - (calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_lead_time)) AS lead_time_closing_stock,
|
||||
|
||||
((ci.current_stock + COALESCE(ooi.on_order_qty, 0) - ((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_lead_time))) - ((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_days_of_stock) AS days_of_stock_closing_stock,
|
||||
((ci.current_stock + COALESCE(ooi.on_order_qty, 0) - (calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_lead_time))) - (calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_days_of_stock) AS days_of_stock_closing_stock,
|
||||
|
||||
(((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_lead_time) + ((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_days_of_stock)) + s.effective_safety_stock - ci.current_stock - COALESCE(ooi.on_order_qty, 0) AS replenishment_needed_raw,
|
||||
((calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_lead_time) + (calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_days_of_stock)) + s.effective_safety_stock - ci.current_stock - COALESCE(ooi.on_order_qty, 0) AS replenishment_needed_raw,
|
||||
|
||||
-- Final Forecasting / Replenishment Metrics (apply CEILING/GREATEST/etc.)
|
||||
-- Note: These calculations are nested for clarity, can be simplified in prod
|
||||
CEILING(GREATEST(0, ((((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_lead_time) + ((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_days_of_stock)) + s.effective_safety_stock - ci.current_stock - COALESCE(ooi.on_order_qty, 0))))::int AS replenishment_units,
|
||||
(CEILING(GREATEST(0, ((((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_lead_time) + ((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_days_of_stock)) + s.effective_safety_stock - ci.current_stock - COALESCE(ooi.on_order_qty, 0))))::int) * ci.current_effective_cost AS replenishment_cost,
|
||||
(CEILING(GREATEST(0, ((((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_lead_time) + ((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_days_of_stock)) + s.effective_safety_stock - ci.current_stock - COALESCE(ooi.on_order_qty, 0))))::int) * ci.current_price AS replenishment_retail,
|
||||
(CEILING(GREATEST(0, ((((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_lead_time) + ((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_days_of_stock)) + s.effective_safety_stock - ci.current_stock - COALESCE(ooi.on_order_qty, 0))))::int) * (ci.current_price - ci.current_effective_cost) AS replenishment_profit,
|
||||
-- Final Forecasting / Replenishment Metrics
|
||||
CEILING(GREATEST(0, (((calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_lead_time) + (calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_days_of_stock)) + s.effective_safety_stock - ci.current_stock - COALESCE(ooi.on_order_qty, 0))))::int AS replenishment_units,
|
||||
(CEILING(GREATEST(0, (((calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_lead_time) + (calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_days_of_stock)) + s.effective_safety_stock - ci.current_stock - COALESCE(ooi.on_order_qty, 0))))::int) * ci.current_effective_cost AS replenishment_cost,
|
||||
(CEILING(GREATEST(0, (((calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_lead_time) + (calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_days_of_stock)) + s.effective_safety_stock - ci.current_stock - COALESCE(ooi.on_order_qty, 0))))::int) * ci.current_price AS replenishment_retail,
|
||||
(CEILING(GREATEST(0, (((calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_lead_time) + (calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_days_of_stock)) + s.effective_safety_stock - ci.current_stock - COALESCE(ooi.on_order_qty, 0))))::int) * (ci.current_price - ci.current_effective_cost) AS replenishment_profit,
|
||||
|
||||
-- Placeholder for To Order (Apply MOQ/UOM logic here if needed, otherwise equals replenishment)
|
||||
CEILING(GREATEST(0, ((((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_lead_time) + ((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_days_of_stock)) + s.effective_safety_stock - ci.current_stock - COALESCE(ooi.on_order_qty, 0))))::int AS to_order_units,
|
||||
-- To Order (Apply MOQ/UOM logic here if needed, otherwise equals replenishment)
|
||||
CEILING(GREATEST(0, (((calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_lead_time) + (calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_days_of_stock)) + s.effective_safety_stock - ci.current_stock - COALESCE(ooi.on_order_qty, 0))))::int AS to_order_units,
|
||||
|
||||
GREATEST(0, - (ci.current_stock + COALESCE(ooi.on_order_qty, 0) - ((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_lead_time))) AS forecast_lost_sales_units,
|
||||
GREATEST(0, - (ci.current_stock + COALESCE(ooi.on_order_qty, 0) - ((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_lead_time))) * ci.current_price AS forecast_lost_revenue,
|
||||
GREATEST(0, - (ci.current_stock + COALESCE(ooi.on_order_qty, 0) - (calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_lead_time))) AS forecast_lost_sales_units,
|
||||
GREATEST(0, - (ci.current_stock + COALESCE(ooi.on_order_qty, 0) - (calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_lead_time))) * ci.current_price AS forecast_lost_revenue,
|
||||
|
||||
ci.current_stock / NULLIF((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
), 0) AS stock_cover_in_days,
|
||||
COALESCE(ooi.on_order_qty, 0) / NULLIF((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
), 0) AS po_cover_in_days,
|
||||
(ci.current_stock + COALESCE(ooi.on_order_qty, 0)) / NULLIF((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
), 0) AS sells_out_in_days,
|
||||
ci.current_stock / NULLIF(calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int), 0) AS stock_cover_in_days,
|
||||
COALESCE(ooi.on_order_qty, 0) / NULLIF(calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int), 0) AS po_cover_in_days,
|
||||
(ci.current_stock + COALESCE(ooi.on_order_qty, 0)) / NULLIF(calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int), 0) AS sells_out_in_days,
|
||||
|
||||
-- Replenish Date: Date when stock is projected to hit safety stock, minus lead time
|
||||
CASE
|
||||
WHEN (sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) > 0
|
||||
THEN _current_date + FLOOR(GREATEST(0, ci.current_stock - s.effective_safety_stock) / (sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
))::int - s.effective_lead_time
|
||||
WHEN calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) > 0
|
||||
THEN _current_date + FLOOR(GREATEST(0, ci.current_stock - s.effective_safety_stock) / calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int))::int - s.effective_lead_time
|
||||
ELSE NULL
|
||||
END AS replenish_date,
|
||||
|
||||
GREATEST(0, ci.current_stock - s.effective_safety_stock - (((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_lead_time) + ((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_days_of_stock)))::int AS overstocked_units,
|
||||
(GREATEST(0, ci.current_stock - s.effective_safety_stock - (((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_lead_time) + ((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_days_of_stock)))) * ci.current_effective_cost AS overstocked_cost,
|
||||
(GREATEST(0, ci.current_stock - s.effective_safety_stock - (((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_lead_time) + ((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_days_of_stock)))) * ci.current_price AS overstocked_retail,
|
||||
GREATEST(0, ci.current_stock - s.effective_safety_stock - ((calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_lead_time) + (calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_days_of_stock)))::int AS overstocked_units,
|
||||
(GREATEST(0, ci.current_stock - s.effective_safety_stock - ((calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_lead_time) + (calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_days_of_stock)))) * ci.current_effective_cost AS overstocked_cost,
|
||||
(GREATEST(0, ci.current_stock - s.effective_safety_stock - ((calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_lead_time) + (calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_days_of_stock)))) * ci.current_price AS overstocked_retail,
|
||||
|
||||
-- Old Stock Flag
|
||||
(ci.created_at::date < _current_date - INTERVAL '60 day') AND
|
||||
@@ -592,66 +425,18 @@ BEGIN
|
||||
ELSE
|
||||
CASE
|
||||
-- Check for overstock first
|
||||
WHEN GREATEST(0, ci.current_stock - s.effective_safety_stock - (((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_lead_time) + ((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
) * s.effective_days_of_stock))) > 0 THEN 'Overstock'
|
||||
WHEN GREATEST(0, ci.current_stock - s.effective_safety_stock - ((calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_lead_time) + (calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int) * s.effective_days_of_stock))) > 0 THEN 'Overstock'
|
||||
|
||||
-- Check for Critical stock
|
||||
WHEN ci.current_stock <= 0 OR
|
||||
(ci.current_stock / NULLIF((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
), 0)) <= 0 THEN 'Critical'
|
||||
(ci.current_stock / NULLIF(calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int), 0)) <= 0 THEN 'Critical'
|
||||
|
||||
WHEN (ci.current_stock / NULLIF((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
), 0)) < (COALESCE(s.effective_lead_time, 30) * 0.5) THEN 'Critical'
|
||||
WHEN (ci.current_stock / NULLIF(calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int), 0)) < (COALESCE(s.effective_lead_time, 30) * 0.5) THEN 'Critical'
|
||||
|
||||
-- Check for reorder soon
|
||||
WHEN ((ci.current_stock + COALESCE(ooi.on_order_qty, 0)) / NULLIF((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
), 0)) < (COALESCE(s.effective_lead_time, 30) + 7) THEN
|
||||
WHEN ((ci.current_stock + COALESCE(ooi.on_order_qty, 0)) / NULLIF(calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int), 0)) < (COALESCE(s.effective_lead_time, 30) + 7) THEN
|
||||
CASE
|
||||
WHEN (ci.current_stock / NULLIF((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
), 0)) < (COALESCE(s.effective_lead_time, 30) * 0.5) THEN 'Critical'
|
||||
WHEN (ci.current_stock / NULLIF(calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int), 0)) < (COALESCE(s.effective_lead_time, 30) * 0.5) THEN 'Critical'
|
||||
ELSE 'Reorder Soon'
|
||||
END
|
||||
|
||||
@@ -672,15 +457,7 @@ BEGIN
|
||||
END) > 180 THEN 'At Risk'
|
||||
|
||||
-- Very high stock cover is at risk too
|
||||
WHEN (ci.current_stock / NULLIF((sa.sales_30d /
|
||||
NULLIF(
|
||||
GREATEST(
|
||||
30.0 - sa.stockout_days_30d,
|
||||
CASE WHEN sa.sales_30d > 0 THEN 14.0 ELSE 30.0 END
|
||||
),
|
||||
0
|
||||
)
|
||||
), 0)) > 365 THEN 'At Risk'
|
||||
WHEN (ci.current_stock / NULLIF(calculate_sales_velocity(sa.sales_30d::int, sa.stockout_days_30d::int), 0)) > 365 THEN 'At Risk'
|
||||
|
||||
-- New products (less than 30 days old)
|
||||
WHEN (CASE
|
||||
@@ -693,7 +470,30 @@ BEGIN
|
||||
-- If none of the above, assume Healthy
|
||||
ELSE 'Healthy'
|
||||
END
|
||||
END AS status
|
||||
END AS status,
|
||||
|
||||
-- Growth Metrics (P3) - using safe_divide and std_numeric for consistency
|
||||
std_numeric(safe_divide((sa.sales_30d - ppm.sales_prev_30d) * 100.0, ppm.sales_prev_30d), 2) AS sales_growth_30d_vs_prev,
|
||||
std_numeric(safe_divide((sa.revenue_30d - ppm.revenue_prev_30d) * 100.0, ppm.revenue_prev_30d), 2) AS revenue_growth_30d_vs_prev,
|
||||
std_numeric(safe_divide((sa.sales_30d - ppm.sales_30d_last_year) * 100.0, ppm.sales_30d_last_year), 2) AS sales_growth_yoy,
|
||||
std_numeric(safe_divide((sa.revenue_30d - ppm.revenue_30d_last_year) * 100.0, ppm.revenue_30d_last_year), 2) AS revenue_growth_yoy,
|
||||
|
||||
-- Demand Variability (P3)
|
||||
std_numeric(dv.sales_variance, 2) AS sales_variance_30d,
|
||||
std_numeric(dv.sales_std_dev, 2) AS sales_std_dev_30d,
|
||||
std_numeric(dv.sales_cv, 2) AS sales_cv_30d,
|
||||
classify_demand_pattern(dv.avg_daily_sales, dv.sales_cv) AS demand_pattern,
|
||||
|
||||
-- Service Levels (P5)
|
||||
std_numeric(COALESCE(sl.fill_rate_30d, 100), 2) AS fill_rate_30d,
|
||||
COALESCE(sl.stockout_incidents_30d, 0)::int AS stockout_incidents_30d,
|
||||
std_numeric(COALESCE(sl.service_level_30d, 100), 2) AS service_level_30d,
|
||||
COALESCE(sl.lost_sales_incidents_30d, 0)::int AS lost_sales_incidents_30d,
|
||||
|
||||
-- Seasonality (P5)
|
||||
std_numeric(season.seasonality_index, 2) AS seasonality_index,
|
||||
COALESCE(season.seasonal_pattern, 'none') AS seasonal_pattern,
|
||||
season.peak_season
|
||||
|
||||
FROM CurrentInfo ci
|
||||
LEFT JOIN OnOrderInfo ooi ON ci.pid = ooi.pid
|
||||
@@ -701,6 +501,11 @@ BEGIN
|
||||
LEFT JOIN SnapshotAggregates sa ON ci.pid = sa.pid
|
||||
LEFT JOIN FirstPeriodMetrics fpm ON ci.pid = fpm.pid
|
||||
LEFT JOIN Settings s ON ci.pid = s.pid
|
||||
LEFT JOIN LifetimeRevenue lr ON ci.pid = lr.pid
|
||||
LEFT JOIN PreviousPeriodMetrics ppm ON ci.pid = ppm.pid
|
||||
LEFT JOIN DemandVariability dv ON ci.pid = dv.pid
|
||||
LEFT JOIN ServiceLevels sl ON ci.pid = sl.pid
|
||||
LEFT JOIN SeasonalityAnalysis season ON ci.pid = season.pid
|
||||
WHERE s.exclude_forecast IS FALSE OR s.exclude_forecast IS NULL -- Exclude products explicitly marked
|
||||
|
||||
ON CONFLICT (pid) DO UPDATE SET
|
||||
@@ -718,7 +523,7 @@ BEGIN
|
||||
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,
|
||||
received_qty_30d = EXCLUDED.received_qty_30d, received_cost_30d = EXCLUDED.received_cost_30d,
|
||||
lifetime_sales = EXCLUDED.lifetime_sales, lifetime_revenue = EXCLUDED.lifetime_revenue,
|
||||
lifetime_sales = EXCLUDED.lifetime_sales, lifetime_revenue = EXCLUDED.lifetime_revenue, lifetime_revenue_quality = EXCLUDED.lifetime_revenue_quality,
|
||||
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, avg_sales_per_month_30d = EXCLUDED.avg_sales_per_month_30d,
|
||||
@@ -734,7 +539,22 @@ BEGIN
|
||||
stock_cover_in_days = EXCLUDED.stock_cover_in_days, po_cover_in_days = EXCLUDED.po_cover_in_days, sells_out_in_days = EXCLUDED.sells_out_in_days, replenish_date = EXCLUDED.replenish_date,
|
||||
overstocked_units = EXCLUDED.overstocked_units, overstocked_cost = EXCLUDED.overstocked_cost, overstocked_retail = EXCLUDED.overstocked_retail, is_old_stock = EXCLUDED.is_old_stock,
|
||||
yesterday_sales = EXCLUDED.yesterday_sales,
|
||||
status = EXCLUDED.status
|
||||
status = EXCLUDED.status,
|
||||
sales_growth_30d_vs_prev = EXCLUDED.sales_growth_30d_vs_prev,
|
||||
revenue_growth_30d_vs_prev = EXCLUDED.revenue_growth_30d_vs_prev,
|
||||
sales_growth_yoy = EXCLUDED.sales_growth_yoy,
|
||||
revenue_growth_yoy = EXCLUDED.revenue_growth_yoy,
|
||||
sales_variance_30d = EXCLUDED.sales_variance_30d,
|
||||
sales_std_dev_30d = EXCLUDED.sales_std_dev_30d,
|
||||
sales_cv_30d = EXCLUDED.sales_cv_30d,
|
||||
demand_pattern = EXCLUDED.demand_pattern,
|
||||
fill_rate_30d = EXCLUDED.fill_rate_30d,
|
||||
stockout_incidents_30d = EXCLUDED.stockout_incidents_30d,
|
||||
service_level_30d = EXCLUDED.service_level_30d,
|
||||
lost_sales_incidents_30d = EXCLUDED.lost_sales_incidents_30d,
|
||||
seasonality_index = EXCLUDED.seasonality_index,
|
||||
seasonal_pattern = EXCLUDED.seasonal_pattern,
|
||||
peak_season = EXCLUDED.peak_season
|
||||
WHERE -- Only update if at least one key metric has changed
|
||||
product_metrics.current_stock IS DISTINCT FROM EXCLUDED.current_stock OR
|
||||
product_metrics.current_price IS DISTINCT FROM EXCLUDED.current_price OR
|
||||
@@ -750,7 +570,8 @@ BEGIN
|
||||
-- Check a few other important fields that might change
|
||||
product_metrics.date_last_sold IS DISTINCT FROM EXCLUDED.date_last_sold OR
|
||||
product_metrics.earliest_expected_date IS DISTINCT FROM EXCLUDED.earliest_expected_date OR
|
||||
product_metrics.lifetime_sales IS DISTINCT FROM EXCLUDED.lifetime_sales
|
||||
product_metrics.lifetime_sales IS DISTINCT FROM EXCLUDED.lifetime_sales OR
|
||||
product_metrics.lifetime_revenue_quality IS DISTINCT FROM EXCLUDED.lifetime_revenue_quality
|
||||
;
|
||||
|
||||
-- Update the status table with the timestamp from the START of this run
|
||||
|
||||
@@ -203,12 +203,8 @@ router.get('/vendors', async (req, res) => {
|
||||
0
|
||||
) as stock_turnover,
|
||||
product_count,
|
||||
-- Use an estimate of growth based on 7-day vs 30-day revenue
|
||||
CASE
|
||||
WHEN revenue_30d > 0
|
||||
THEN ((revenue_7d * 4.0) / revenue_30d - 1) * 100
|
||||
ELSE 0
|
||||
END as growth
|
||||
-- Use actual growth metrics from the vendor_metrics table
|
||||
sales_growth_30d_vs_prev as growth
|
||||
FROM vendor_metrics
|
||||
WHERE revenue_30d > 0
|
||||
ORDER BY revenue_30d DESC
|
||||
|
||||
@@ -26,6 +26,9 @@ const COLUMN_MAP = {
|
||||
lifetimeSales: { dbCol: 'bm.lifetime_sales', type: 'number' },
|
||||
lifetimeRevenue: { dbCol: 'bm.lifetime_revenue', type: 'number' },
|
||||
avgMargin30d: { dbCol: 'bm.avg_margin_30d', type: 'number' },
|
||||
// Growth metrics
|
||||
salesGrowth30dVsPrev: { dbCol: 'bm.sales_growth_30d_vs_prev', type: 'number' },
|
||||
revenueGrowth30dVsPrev: { dbCol: 'bm.revenue_growth_30d_vs_prev', type: 'number' },
|
||||
// Add aliases if needed
|
||||
name: { dbCol: 'bm.brand_name', type: 'string' },
|
||||
// Add status for filtering
|
||||
|
||||
@@ -31,6 +31,9 @@ const COLUMN_MAP = {
|
||||
lifetimeRevenue: { dbCol: 'cm.lifetime_revenue', type: 'number' },
|
||||
avgMargin30d: { dbCol: 'cm.avg_margin_30d', type: 'number' },
|
||||
stockTurn30d: { dbCol: 'cm.stock_turn_30d', type: 'number' },
|
||||
// Growth metrics
|
||||
salesGrowth30dVsPrev: { dbCol: 'cm.sales_growth_30d_vs_prev', type: 'number' },
|
||||
revenueGrowth30dVsPrev: { dbCol: 'cm.revenue_growth_30d_vs_prev', type: 'number' },
|
||||
// Add status from the categories table for filtering
|
||||
status: { dbCol: 'c.status', type: 'string' },
|
||||
};
|
||||
|
||||
@@ -143,7 +143,33 @@ const COLUMN_MAP = {
|
||||
// Yesterday
|
||||
yesterdaySales: 'pm.yesterday_sales',
|
||||
// Map status column - directly mapped now instead of calculated on frontend
|
||||
status: 'pm.status'
|
||||
status: 'pm.status',
|
||||
|
||||
// Growth Metrics (P3)
|
||||
salesGrowth30dVsPrev: 'pm.sales_growth_30d_vs_prev',
|
||||
revenueGrowth30dVsPrev: 'pm.revenue_growth_30d_vs_prev',
|
||||
salesGrowthYoy: 'pm.sales_growth_yoy',
|
||||
revenueGrowthYoy: 'pm.revenue_growth_yoy',
|
||||
|
||||
// Demand Variability Metrics (P3)
|
||||
salesVariance30d: 'pm.sales_variance_30d',
|
||||
salesStdDev30d: 'pm.sales_std_dev_30d',
|
||||
salesCv30d: 'pm.sales_cv_30d',
|
||||
demandPattern: 'pm.demand_pattern',
|
||||
|
||||
// Service Level Metrics (P5)
|
||||
fillRate30d: 'pm.fill_rate_30d',
|
||||
stockoutIncidents30d: 'pm.stockout_incidents_30d',
|
||||
serviceLevel30d: 'pm.service_level_30d',
|
||||
lostSalesIncidents30d: 'pm.lost_sales_incidents_30d',
|
||||
|
||||
// Seasonality Metrics (P5)
|
||||
seasonalityIndex: 'pm.seasonality_index',
|
||||
seasonalPattern: 'pm.seasonal_pattern',
|
||||
peakSeason: 'pm.peak_season',
|
||||
|
||||
// Lifetime Revenue Quality
|
||||
lifetimeRevenueQuality: 'pm.lifetime_revenue_quality'
|
||||
};
|
||||
|
||||
// Define column types for use in sorting/filtering
|
||||
@@ -173,7 +199,15 @@ const COLUMN_TYPES = {
|
||||
'overstockedCost', 'overstockedRetail', 'yesterdaySales',
|
||||
// New numeric columns
|
||||
'moq', 'rating', 'reviews', 'weight', 'length', 'width', 'height',
|
||||
'baskets', 'notifies', 'preorderCount', 'notionsInvCount'
|
||||
'baskets', 'notifies', 'preorderCount', 'notionsInvCount',
|
||||
// Growth metrics
|
||||
'salesGrowth30dVsPrev', 'revenueGrowth30dVsPrev', 'salesGrowthYoy', 'revenueGrowthYoy',
|
||||
// Demand variability metrics
|
||||
'salesVariance30d', 'salesStdDev30d', 'salesCv30d',
|
||||
// Service level metrics
|
||||
'fillRate30d', 'stockoutIncidents30d', 'serviceLevel30d', 'lostSalesIncidents30d',
|
||||
// Seasonality metrics
|
||||
'seasonalityIndex'
|
||||
],
|
||||
// Date columns (use date operators and sorting)
|
||||
date: [
|
||||
@@ -185,7 +219,9 @@ const COLUMN_TYPES = {
|
||||
'sku', 'title', 'brand', 'vendor', 'imageUrl', 'abcClass', 'status',
|
||||
// New string columns
|
||||
'barcode', 'harmonizedTariffCode', 'vendorReference', 'notionsReference',
|
||||
'line', 'subline', 'artist', 'countryOfOrigin', 'location'
|
||||
'line', 'subline', 'artist', 'countryOfOrigin', 'location',
|
||||
// New string columns for patterns
|
||||
'demandPattern', 'seasonalPattern', 'peakSeason', 'lifetimeRevenueQuality'
|
||||
],
|
||||
// Boolean columns (use boolean operators and sorting)
|
||||
boolean: ['isVisible', 'isReplenishable', 'isOldStock']
|
||||
@@ -208,6 +244,12 @@ const SPECIAL_SORT_COLUMNS = {
|
||||
// Velocity columns
|
||||
salesVelocityDaily: true,
|
||||
|
||||
// Growth rate columns
|
||||
salesGrowth30dVsPrev: 'abs',
|
||||
revenueGrowth30dVsPrev: 'abs',
|
||||
salesGrowthYoy: 'abs',
|
||||
revenueGrowthYoy: 'abs',
|
||||
|
||||
// Status column needs special ordering
|
||||
status: 'priority'
|
||||
};
|
||||
|
||||
@@ -30,6 +30,9 @@ const COLUMN_MAP = {
|
||||
lifetimeSales: { dbCol: 'vm.lifetime_sales', type: 'number' },
|
||||
lifetimeRevenue: { dbCol: 'vm.lifetime_revenue', type: 'number' },
|
||||
avgMargin30d: { dbCol: 'vm.avg_margin_30d', type: 'number' },
|
||||
// Growth metrics
|
||||
salesGrowth30dVsPrev: { dbCol: 'vm.sales_growth_30d_vs_prev', type: 'number' },
|
||||
revenueGrowth30dVsPrev: { dbCol: 'vm.revenue_growth_30d_vs_prev', type: 'number' },
|
||||
// Add aliases if needed for frontend compatibility
|
||||
name: { dbCol: 'vm.vendor_name', type: 'string' },
|
||||
leadTime: { dbCol: 'vm.avg_lead_time_days', type: 'number' },
|
||||
|
||||
@@ -16,7 +16,8 @@ import { Badge } from "@/components/ui/badge";
|
||||
type BrandSortableColumns =
|
||||
| 'brandName' | 'productCount' | 'activeProductCount' | 'currentStockUnits'
|
||||
| 'currentStockCost' | 'currentStockRetail' | 'revenue_7d' | 'revenue_30d'
|
||||
| 'profit_30d' | 'sales_30d' | 'avg_margin_30d' | 'stock_turn_30d' | 'status'; // Add more as needed
|
||||
| 'profit_30d' | 'sales_30d' | 'avg_margin_30d' | 'stock_turn_30d'
|
||||
| 'salesGrowth30dVsPrev' | 'revenueGrowth30dVsPrev' | 'status';
|
||||
|
||||
interface BrandMetric {
|
||||
brand_id: string | number;
|
||||
@@ -40,6 +41,9 @@ interface BrandMetric {
|
||||
lifetime_revenue: string | number;
|
||||
avg_margin_30d: string | number | null;
|
||||
stock_turn_30d: string | number | null;
|
||||
// Growth metrics
|
||||
sales_growth_30d_vs_prev: string | number | null;
|
||||
revenue_growth_30d_vs_prev: string | number | null;
|
||||
status: string;
|
||||
brand_status: string;
|
||||
description: string;
|
||||
@@ -57,6 +61,8 @@ interface BrandMetric {
|
||||
lifetimeRevenue: string | number;
|
||||
avgMargin_30d: string | number | null;
|
||||
stockTurn_30d: string | number | null;
|
||||
salesGrowth30dVsPrev: string | number | null;
|
||||
revenueGrowth30dVsPrev: string | number | null;
|
||||
}
|
||||
|
||||
// Define response type to avoid type errors
|
||||
@@ -140,6 +146,19 @@ const formatPercentage = (value: number | string | null | undefined, digits = 1)
|
||||
return `${value.toFixed(digits)}%`;
|
||||
};
|
||||
|
||||
// Growth formatting with color coding
|
||||
const formatGrowth = (value: number | string | null | undefined, digits = 1) => {
|
||||
if (value == null) return <span className="text-muted-foreground">N/A</span>;
|
||||
|
||||
const numValue = typeof value === "string" ? parseFloat(value) : value;
|
||||
if (isNaN(numValue)) return <span className="text-muted-foreground">N/A</span>;
|
||||
|
||||
const formatted = `${numValue >= 0 ? '+' : ''}${numValue.toFixed(digits)}%`;
|
||||
const colorClass = numValue >= 0 ? 'text-green-600' : 'text-red-600';
|
||||
|
||||
return <span className={colorClass}>{formatted}</span>;
|
||||
};
|
||||
|
||||
const getStatusVariant = (status: string): "default" | "secondary" | "outline" | "destructive" => {
|
||||
switch (status) {
|
||||
case 'active':
|
||||
@@ -361,6 +380,8 @@ export function Brands() {
|
||||
<TableHead onClick={() => handleSort("profit_30d")} className="cursor-pointer text-right">Profit (30d)</TableHead>
|
||||
<TableHead onClick={() => handleSort("avg_margin_30d")} className="cursor-pointer text-right">Margin (30d)</TableHead>
|
||||
<TableHead onClick={() => handleSort("stock_turn_30d")} className="cursor-pointer text-right">Stock Turn (30d)</TableHead>
|
||||
<TableHead onClick={() => handleSort("salesGrowth30dVsPrev")} className="cursor-pointer text-right">Sales Growth</TableHead>
|
||||
<TableHead onClick={() => handleSort("revenueGrowth30dVsPrev")} className="cursor-pointer text-right">Revenue Growth</TableHead>
|
||||
<TableHead onClick={() => handleSort("status")} className="cursor-pointer text-right">Status</TableHead>
|
||||
</TableRow>
|
||||
</TableHeader>
|
||||
@@ -378,17 +399,19 @@ export function Brands() {
|
||||
<TableCell className="text-right"><Skeleton className="h-5 w-16 ml-auto" /></TableCell>
|
||||
<TableCell className="text-right"><Skeleton className="h-5 w-16 ml-auto" /></TableCell>
|
||||
<TableCell className="text-right"><Skeleton className="h-5 w-16 ml-auto" /></TableCell>
|
||||
<TableCell className="text-right"><Skeleton className="h-5 w-16 ml-auto" /></TableCell>
|
||||
<TableCell className="text-right"><Skeleton className="h-5 w-16 ml-auto" /></TableCell>
|
||||
</TableRow>
|
||||
))
|
||||
) : listError ? (
|
||||
<TableRow>
|
||||
<TableCell colSpan={9} className="text-center py-8 text-destructive">
|
||||
<TableCell colSpan={12} className="text-center py-8 text-destructive">
|
||||
Error loading brands: {listError.message}
|
||||
</TableCell>
|
||||
</TableRow>
|
||||
) : brands.length === 0 ? (
|
||||
<TableRow>
|
||||
<TableCell colSpan={9} className="text-center py-8 text-muted-foreground">
|
||||
<TableCell colSpan={12} className="text-center py-8 text-muted-foreground">
|
||||
No brands found matching your criteria.
|
||||
</TableCell>
|
||||
</TableRow>
|
||||
@@ -404,6 +427,8 @@ export function Brands() {
|
||||
<TableCell className="text-right">{formatCurrency(brand.profit_30d as number)}</TableCell>
|
||||
<TableCell className="text-right">{formatPercentage(brand.avg_margin_30d as number)}</TableCell>
|
||||
<TableCell className="text-right">{formatNumber(brand.stock_turn_30d, 2)}</TableCell>
|
||||
<TableCell className="text-right">{formatGrowth(brand.sales_growth_30d_vs_prev)}</TableCell>
|
||||
<TableCell className="text-right">{formatGrowth(brand.revenue_growth_30d_vs_prev)}</TableCell>
|
||||
<TableCell className="text-right">
|
||||
<Badge variant={getStatusVariant(brand.status)}>
|
||||
{brand.status || 'Unknown'}
|
||||
|
||||
@@ -60,6 +60,8 @@ type CategorySortableColumns =
|
||||
| "sales30d"
|
||||
| "avgMargin30d"
|
||||
| "stockTurn30d"
|
||||
| "salesGrowth30dVsPrev"
|
||||
| "revenueGrowth30dVsPrev"
|
||||
| "status";
|
||||
|
||||
interface CategoryMetric {
|
||||
@@ -88,6 +90,9 @@ interface CategoryMetric {
|
||||
lifetime_revenue: string | number;
|
||||
avg_margin_30d: string | number | null;
|
||||
stock_turn_30d: string | number | null;
|
||||
// Growth metrics
|
||||
sales_growth_30d_vs_prev: string | number | null;
|
||||
revenue_growth_30d_vs_prev: string | number | null;
|
||||
// Fields from categories table
|
||||
status: string;
|
||||
description: string;
|
||||
@@ -108,6 +113,8 @@ interface CategoryMetric {
|
||||
lifetimeRevenue: string | number;
|
||||
avgMargin_30d: string | number | null;
|
||||
stockTurn_30d: string | number | null;
|
||||
salesGrowth30dVsPrev: string | number | null;
|
||||
revenueGrowth30dVsPrev: string | number | null;
|
||||
direct_active_product_count: number;
|
||||
direct_current_stock_units: number;
|
||||
direct_stock_cost: string | number;
|
||||
@@ -208,6 +215,19 @@ const formatPercentage = (
|
||||
return `${value.toFixed(digits)}%`;
|
||||
};
|
||||
|
||||
// Growth formatting with color coding
|
||||
const formatGrowth = (value: number | string | null | undefined, digits = 1) => {
|
||||
if (value == null) return <span className="text-muted-foreground">N/A</span>;
|
||||
|
||||
const numValue = typeof value === "string" ? parseFloat(value) : value;
|
||||
if (isNaN(numValue)) return <span className="text-muted-foreground">N/A</span>;
|
||||
|
||||
const formatted = `${numValue >= 0 ? '+' : ''}${numValue.toFixed(digits)}%`;
|
||||
const colorClass = numValue >= 0 ? 'text-green-600' : 'text-red-600';
|
||||
|
||||
return <span className={colorClass}>{formatted}</span>;
|
||||
};
|
||||
|
||||
// Define interfaces for hierarchical structure
|
||||
interface CategoryWithChildren extends CategoryMetric {
|
||||
children: CategoryWithChildren[];
|
||||
@@ -221,6 +241,8 @@ interface CategoryWithChildren extends CategoryMetric {
|
||||
revenue30d: number;
|
||||
profit30d: number;
|
||||
avg_margin_30d?: number;
|
||||
sales_growth_30d_vs_prev?: number;
|
||||
revenue_growth_30d_vs_prev?: number;
|
||||
};
|
||||
}
|
||||
|
||||
@@ -683,7 +705,9 @@ export function Categories() {
|
||||
profit30d: totals.profit30d,
|
||||
avg_margin_30d: totals.revenue30d > 0
|
||||
? (totals.profit30d / totals.revenue30d) * 100
|
||||
: 0
|
||||
: 0,
|
||||
sales_growth_30d_vs_prev: parseFloat(cat.sales_growth_30d_vs_prev?.toString() || "0"),
|
||||
revenue_growth_30d_vs_prev: parseFloat(cat.revenue_growth_30d_vs_prev?.toString() || "0")
|
||||
};
|
||||
} else {
|
||||
// If we don't have pre-calculated values (shouldn't happen with our algorithm)
|
||||
@@ -694,7 +718,9 @@ export function Categories() {
|
||||
currentStockCost: parseFloat(cat.direct_stock_cost?.toString() || "0"),
|
||||
revenue30d: parseFloat(cat.direct_revenue_30d?.toString() || "0"),
|
||||
profit30d: parseFloat(cat.direct_profit_30d?.toString() || "0"),
|
||||
avg_margin_30d: parseFloat(cat.avg_margin_30d?.toString() || "0")
|
||||
avg_margin_30d: parseFloat(cat.avg_margin_30d?.toString() || "0"),
|
||||
sales_growth_30d_vs_prev: parseFloat(cat.sales_growth_30d_vs_prev?.toString() || "0"),
|
||||
revenue_growth_30d_vs_prev: parseFloat(cat.revenue_growth_30d_vs_prev?.toString() || "0")
|
||||
};
|
||||
}
|
||||
|
||||
@@ -953,6 +979,56 @@ export function Categories() {
|
||||
formatPercentage(category.avg_margin_30d)}
|
||||
</TableCell>
|
||||
|
||||
{/* Sales Growth Cell */}
|
||||
<TableCell className="h-16 py-2 text-right">
|
||||
{hasChildren && category.aggregatedStats ? (
|
||||
<Tooltip>
|
||||
<TooltipTrigger asChild>
|
||||
<span className="font-medium cursor-help">
|
||||
{formatGrowth(category.aggregatedStats.sales_growth_30d_vs_prev)}
|
||||
</span>
|
||||
</TooltipTrigger>
|
||||
<TooltipContent>
|
||||
<p>
|
||||
Sales Growth (incl. children):{" "}
|
||||
{formatGrowth(category.aggregatedStats.sales_growth_30d_vs_prev)}
|
||||
</p>
|
||||
<p>
|
||||
Directly from '{category.category_name}':{" "}
|
||||
{formatGrowth(category.sales_growth_30d_vs_prev)}
|
||||
</p>
|
||||
</TooltipContent>
|
||||
</Tooltip>
|
||||
) : (
|
||||
formatGrowth(category.sales_growth_30d_vs_prev)
|
||||
)}
|
||||
</TableCell>
|
||||
|
||||
{/* Revenue Growth Cell */}
|
||||
<TableCell className="h-16 py-2 text-right">
|
||||
{hasChildren && category.aggregatedStats ? (
|
||||
<Tooltip>
|
||||
<TooltipTrigger asChild>
|
||||
<span className="font-medium cursor-help">
|
||||
{formatGrowth(category.aggregatedStats.revenue_growth_30d_vs_prev)}
|
||||
</span>
|
||||
</TooltipTrigger>
|
||||
<TooltipContent>
|
||||
<p>
|
||||
Revenue Growth (incl. children):{" "}
|
||||
{formatGrowth(category.aggregatedStats.revenue_growth_30d_vs_prev)}
|
||||
</p>
|
||||
<p>
|
||||
Directly from '{category.category_name}':{" "}
|
||||
{formatGrowth(category.revenue_growth_30d_vs_prev)}
|
||||
</p>
|
||||
</TooltipContent>
|
||||
</Tooltip>
|
||||
) : (
|
||||
formatGrowth(category.revenue_growth_30d_vs_prev)
|
||||
)}
|
||||
</TableCell>
|
||||
|
||||
{/* Stock Turn (30d) Cell - Display direct value */}
|
||||
<TableCell className="h-16 py-2 text-right">
|
||||
{formatNumber(category.stock_turn_30d, 2)}
|
||||
@@ -1009,6 +1085,9 @@ export function Categories() {
|
||||
<TableCell className="text-right w-[8%]">
|
||||
<Skeleton className="h-5 w-full ml-auto" />
|
||||
</TableCell>
|
||||
<TableCell className="text-right w-[8%]">
|
||||
<Skeleton className="h-5 w-full ml-auto" />
|
||||
</TableCell>
|
||||
<TableCell className="text-right w-[6%]">
|
||||
<Skeleton className="h-5 w-full ml-auto" />
|
||||
</TableCell>
|
||||
@@ -1027,7 +1106,7 @@ export function Categories() {
|
||||
return (
|
||||
<TableRow>
|
||||
<TableCell
|
||||
colSpan={11}
|
||||
colSpan={13}
|
||||
className="h-16 text-center py-8 text-muted-foreground"
|
||||
>
|
||||
{categories && categories.length > 0 ? (
|
||||
@@ -1321,6 +1400,20 @@ export function Categories() {
|
||||
Margin (30d)
|
||||
<SortIndicator active={sortColumn === "avgMargin30d"} />
|
||||
</TableHead>
|
||||
<TableHead
|
||||
onClick={() => handleSort("salesGrowth30dVsPrev")}
|
||||
className="cursor-pointer text-right w-[8%]"
|
||||
>
|
||||
Sales Growth
|
||||
<SortIndicator active={sortColumn === "salesGrowth30dVsPrev"} />
|
||||
</TableHead>
|
||||
<TableHead
|
||||
onClick={() => handleSort("revenueGrowth30dVsPrev")}
|
||||
className="cursor-pointer text-right w-[8%]"
|
||||
>
|
||||
Revenue Growth
|
||||
<SortIndicator active={sortColumn === "revenueGrowth30dVsPrev"} />
|
||||
</TableHead>
|
||||
<TableHead
|
||||
onClick={() => handleSort("stockTurn30d")}
|
||||
className="cursor-pointer text-right w-[6%]"
|
||||
|
||||
@@ -182,6 +182,32 @@ const AVAILABLE_COLUMNS: ColumnDef[] = [
|
||||
{ key: 'first60DaysRevenue', label: 'First 60 Days Revenue', group: 'First Period', format: (v) => v === 0 ? '0' : v ? v.toFixed(2) : '-' },
|
||||
{ key: 'first90DaysSales', label: 'First 90 Days Sales', group: 'First Period', format: (v) => v === 0 ? '0' : v ? v.toString() : '-' },
|
||||
{ key: 'first90DaysRevenue', label: 'First 90 Days Revenue', group: 'First Period', format: (v) => v === 0 ? '0' : v ? v.toFixed(2) : '-' },
|
||||
|
||||
// Growth Metrics
|
||||
{ key: 'salesGrowth30dVsPrev', label: 'Sales Growth % (30d vs Prev)', group: 'Growth Analysis', format: (v) => v === 0 ? '0%' : v ? `${v.toFixed(1)}%` : '-' },
|
||||
{ key: 'revenueGrowth30dVsPrev', label: 'Revenue Growth % (30d vs Prev)', group: 'Growth Analysis', format: (v) => v === 0 ? '0%' : v ? `${v.toFixed(1)}%` : '-' },
|
||||
{ key: 'salesGrowthYoy', label: 'Sales Growth % YoY', group: 'Growth Analysis', format: (v) => v === 0 ? '0%' : v ? `${v.toFixed(1)}%` : '-' },
|
||||
{ key: 'revenueGrowthYoy', label: 'Revenue Growth % YoY', group: 'Growth Analysis', format: (v) => v === 0 ? '0%' : v ? `${v.toFixed(1)}%` : '-' },
|
||||
|
||||
// Demand Variability Metrics
|
||||
{ key: 'salesVariance30d', label: 'Sales Variance (30d)', group: 'Demand Variability', format: (v) => v === 0 ? '0' : v ? v.toFixed(2) : '-' },
|
||||
{ key: 'salesStdDev30d', label: 'Sales Std Dev (30d)', group: 'Demand Variability', format: (v) => v === 0 ? '0' : v ? v.toFixed(2) : '-' },
|
||||
{ key: 'salesCv30d', label: 'Sales CV % (30d)', group: 'Demand Variability', format: (v) => v === 0 ? '0%' : v ? `${v.toFixed(1)}%` : '-' },
|
||||
{ key: 'demandPattern', label: 'Demand Pattern', group: 'Demand Variability' },
|
||||
|
||||
// Service Level Metrics
|
||||
{ key: 'fillRate30d', label: 'Fill Rate % (30d)', group: 'Service Level', format: (v) => v === 0 ? '0%' : v ? `${v.toFixed(1)}%` : '-' },
|
||||
{ key: 'stockoutIncidents30d', label: 'Stockout Incidents (30d)', group: 'Service Level', format: (v) => v === 0 ? '0' : v ? v.toString() : '-' },
|
||||
{ key: 'serviceLevel30d', label: 'Service Level % (30d)', group: 'Service Level', format: (v) => v === 0 ? '0%' : v ? `${v.toFixed(1)}%` : '-' },
|
||||
{ key: 'lostSalesIncidents30d', label: 'Lost Sales Incidents (30d)', group: 'Service Level', format: (v) => v === 0 ? '0' : v ? v.toString() : '-' },
|
||||
|
||||
// Seasonality Metrics
|
||||
{ key: 'seasonalityIndex', label: 'Seasonality Index', group: 'Seasonality', format: (v) => v === 0 ? '0' : v ? v.toFixed(2) : '-' },
|
||||
{ key: 'seasonalPattern', label: 'Seasonal Pattern', group: 'Seasonality' },
|
||||
{ key: 'peakSeason', label: 'Peak Season', group: 'Seasonality' },
|
||||
|
||||
// Quality Indicators
|
||||
{ key: 'lifetimeRevenueQuality', label: 'Lifetime Revenue Quality', group: 'Data Quality' },
|
||||
];
|
||||
|
||||
// Define default columns for each view
|
||||
@@ -198,7 +224,8 @@ const VIEW_COLUMNS: Record<string, ProductMetricColumnKey[]> = {
|
||||
'revenue30d',
|
||||
'profit30d',
|
||||
'stockCoverInDays',
|
||||
'currentStockCost'
|
||||
'currentStockCost',
|
||||
'salesGrowth30dVsPrev'
|
||||
],
|
||||
critical: [
|
||||
'status',
|
||||
@@ -214,7 +241,9 @@ const VIEW_COLUMNS: Record<string, ProductMetricColumnKey[]> = {
|
||||
'earliestExpectedDate',
|
||||
'vendor',
|
||||
'dateLastReceived',
|
||||
'avgLeadTimeDays'
|
||||
'avgLeadTimeDays',
|
||||
'serviceLevel30d',
|
||||
'stockoutIncidents30d'
|
||||
],
|
||||
reorder: [
|
||||
'status',
|
||||
@@ -229,7 +258,8 @@ const VIEW_COLUMNS: Record<string, ProductMetricColumnKey[]> = {
|
||||
'sales30d',
|
||||
'vendor',
|
||||
'avgLeadTimeDays',
|
||||
'dateLastReceived'
|
||||
'dateLastReceived',
|
||||
'demandPattern'
|
||||
],
|
||||
overstocked: [
|
||||
'status',
|
||||
@@ -244,7 +274,8 @@ const VIEW_COLUMNS: Record<string, ProductMetricColumnKey[]> = {
|
||||
'stockturn30d',
|
||||
'currentStockCost',
|
||||
'overstockedCost',
|
||||
'dateLastSold'
|
||||
'dateLastSold',
|
||||
'salesVariance30d'
|
||||
],
|
||||
'at-risk': [
|
||||
'status',
|
||||
@@ -259,7 +290,9 @@ const VIEW_COLUMNS: Record<string, ProductMetricColumnKey[]> = {
|
||||
'sellsOutInDays',
|
||||
'dateLastSold',
|
||||
'avgLeadTimeDays',
|
||||
'profit30d'
|
||||
'profit30d',
|
||||
'fillRate30d',
|
||||
'salesGrowth30dVsPrev'
|
||||
],
|
||||
new: [
|
||||
'status',
|
||||
@@ -274,7 +307,9 @@ const VIEW_COLUMNS: Record<string, ProductMetricColumnKey[]> = {
|
||||
'currentCostPrice',
|
||||
'dateFirstReceived',
|
||||
'ageDays',
|
||||
'abcClass'
|
||||
'abcClass',
|
||||
'first7DaysSales',
|
||||
'first30DaysSales'
|
||||
],
|
||||
healthy: [
|
||||
'status',
|
||||
@@ -288,7 +323,9 @@ const VIEW_COLUMNS: Record<string, ProductMetricColumnKey[]> = {
|
||||
'profit30d',
|
||||
'margin30d',
|
||||
'gmroi30d',
|
||||
'stockturn30d'
|
||||
'stockturn30d',
|
||||
'salesGrowth30dVsPrev',
|
||||
'serviceLevel30d'
|
||||
],
|
||||
};
|
||||
|
||||
|
||||
@@ -16,7 +16,8 @@ import { Label } from "@/components/ui/label";
|
||||
type VendorSortableColumns =
|
||||
| 'vendorName' | 'productCount' | 'activeProductCount' | 'currentStockUnits'
|
||||
| 'currentStockCost' | 'onOrderUnits' | 'onOrderCost' | 'avgLeadTimeDays'
|
||||
| 'revenue_30d' | 'profit_30d' | 'avg_margin_30d' | 'po_count_365d' | 'status';
|
||||
| 'revenue_30d' | 'profit_30d' | 'avg_margin_30d' | 'po_count_365d'
|
||||
| 'salesGrowth30dVsPrev' | 'revenueGrowth30dVsPrev' | 'status';
|
||||
|
||||
interface VendorMetric {
|
||||
vendor_id: string | number;
|
||||
@@ -43,6 +44,9 @@ interface VendorMetric {
|
||||
lifetime_sales: number;
|
||||
lifetime_revenue: string | number;
|
||||
avg_margin_30d: string | number | null;
|
||||
// Growth metrics
|
||||
sales_growth_30d_vs_prev: string | number | null;
|
||||
revenue_growth_30d_vs_prev: string | number | null;
|
||||
// New fields added by vendorsAggregate
|
||||
status: string;
|
||||
vendor_status: string;
|
||||
@@ -68,6 +72,8 @@ interface VendorMetric {
|
||||
lifetimeSales: number;
|
||||
lifetimeRevenue: string | number;
|
||||
avgMargin_30d: string | number | null;
|
||||
salesGrowth30dVsPrev: string | number | null;
|
||||
revenueGrowth30dVsPrev: string | number | null;
|
||||
}
|
||||
|
||||
// Define response type to avoid type errors
|
||||
@@ -162,6 +168,19 @@ const formatDays = (value: number | string | null | undefined, digits = 1): stri
|
||||
return `${value.toFixed(digits)} days`;
|
||||
};
|
||||
|
||||
// Growth formatting with color coding
|
||||
const formatGrowth = (value: number | string | null | undefined, digits = 1) => {
|
||||
if (value == null) return <span className="text-muted-foreground">N/A</span>;
|
||||
|
||||
const numValue = typeof value === "string" ? parseFloat(value) : value;
|
||||
if (isNaN(numValue)) return <span className="text-muted-foreground">N/A</span>;
|
||||
|
||||
const formatted = `${numValue >= 0 ? '+' : ''}${numValue.toFixed(digits)}%`;
|
||||
const colorClass = numValue >= 0 ? 'text-green-600' : 'text-red-600';
|
||||
|
||||
return <span className={colorClass}>{formatted}</span>;
|
||||
};
|
||||
|
||||
const getStatusVariant = (status: string): "default" | "secondary" | "outline" | "destructive" => {
|
||||
switch (status) {
|
||||
case 'active':
|
||||
@@ -381,6 +400,8 @@ export function Vendors() {
|
||||
<TableHead onClick={() => handleSort("profit_30d")} className="cursor-pointer text-right">Profit (30d)</TableHead>
|
||||
<TableHead onClick={() => handleSort("avg_margin_30d")} className="cursor-pointer text-right">Margin (30d)</TableHead>
|
||||
<TableHead onClick={() => handleSort("po_count_365d")} className="cursor-pointer text-right">POs (365d)</TableHead>
|
||||
<TableHead onClick={() => handleSort("salesGrowth30dVsPrev")} className="cursor-pointer text-right">Sales Growth</TableHead>
|
||||
<TableHead onClick={() => handleSort("revenueGrowth30dVsPrev")} className="cursor-pointer text-right">Revenue Growth</TableHead>
|
||||
<TableHead onClick={() => handleSort("status")} className="cursor-pointer text-right">Status</TableHead>
|
||||
</TableRow>
|
||||
</TableHeader>
|
||||
@@ -399,17 +420,19 @@ export function Vendors() {
|
||||
<TableCell className="text-right"><Skeleton className="h-5 w-16 ml-auto" /></TableCell>
|
||||
<TableCell className="text-right"><Skeleton className="h-5 w-16 ml-auto" /></TableCell>
|
||||
<TableCell className="text-right"><Skeleton className="h-5 w-16 ml-auto" /></TableCell>
|
||||
<TableCell className="text-right"><Skeleton className="h-5 w-16 ml-auto" /></TableCell>
|
||||
<TableCell className="text-right"><Skeleton className="h-5 w-16 ml-auto" /></TableCell>
|
||||
</TableRow>
|
||||
))
|
||||
) : listError ? (
|
||||
<TableRow>
|
||||
<TableCell colSpan={11} className="text-center py-8 text-destructive">
|
||||
<TableCell colSpan={13} className="text-center py-8 text-destructive">
|
||||
Error loading vendors: {listError.message}
|
||||
</TableCell>
|
||||
</TableRow>
|
||||
) : vendors.length === 0 ? (
|
||||
<TableRow>
|
||||
<TableCell colSpan={11} className="text-center py-8 text-muted-foreground">
|
||||
<TableCell colSpan={13} className="text-center py-8 text-muted-foreground">
|
||||
No vendors found matching your criteria.
|
||||
</TableCell>
|
||||
</TableRow>
|
||||
@@ -426,6 +449,8 @@ export function Vendors() {
|
||||
<TableCell className="text-right">{formatCurrency(vendor.profit_30d as number)}</TableCell>
|
||||
<TableCell className="text-right">{formatPercentage(vendor.avg_margin_30d as number)}</TableCell>
|
||||
<TableCell className="text-right">{formatNumber(vendor.po_count_365d || vendor.poCount_365d)}</TableCell>
|
||||
<TableCell className="text-right">{formatGrowth(vendor.sales_growth_30d_vs_prev)}</TableCell>
|
||||
<TableCell className="text-right">{formatGrowth(vendor.revenue_growth_30d_vs_prev)}</TableCell>
|
||||
<TableCell className="text-right">
|
||||
<Badge variant={getStatusVariant(vendor.status)}>
|
||||
{vendor.status || 'Unknown'}
|
||||
|
||||
@@ -213,6 +213,44 @@ export interface ProductMetric {
|
||||
// Yesterday
|
||||
yesterdaySales: number | null;
|
||||
|
||||
// Growth Metrics (P3)
|
||||
salesGrowth30dVsPrev: number | null;
|
||||
revenueGrowth30dVsPrev: number | null;
|
||||
salesGrowthYoy: number | null;
|
||||
revenueGrowthYoy: number | null;
|
||||
|
||||
// Demand Variability Metrics (P3)
|
||||
salesVariance30d: number | null;
|
||||
salesStdDev30d: number | null;
|
||||
salesCv30d: number | null;
|
||||
demandPattern: string | null;
|
||||
|
||||
// Service Level Metrics (P5)
|
||||
fillRate30d: number | null;
|
||||
stockoutIncidents30d: number | null;
|
||||
serviceLevel30d: number | null;
|
||||
lostSalesIncidents30d: number | null;
|
||||
|
||||
// Seasonality Metrics (P5)
|
||||
seasonalityIndex: number | null;
|
||||
seasonalPattern: string | null;
|
||||
peakSeason: string | null;
|
||||
|
||||
// Lifetime Metrics
|
||||
lifetimeSales: number | null;
|
||||
lifetimeRevenue: number | null;
|
||||
lifetimeRevenueQuality: string | null;
|
||||
|
||||
// First Period Metrics
|
||||
first7DaysSales: number | null;
|
||||
first7DaysRevenue: number | null;
|
||||
first30DaysSales: number | null;
|
||||
first30DaysRevenue: number | null;
|
||||
first60DaysSales: number | null;
|
||||
first60DaysRevenue: number | null;
|
||||
first90DaysSales: number | null;
|
||||
first90DaysRevenue: number | null;
|
||||
|
||||
// Calculated status (added by frontend)
|
||||
status?: ProductStatus;
|
||||
}
|
||||
@@ -364,7 +402,24 @@ export type ProductMetricColumnKey =
|
||||
| 'dateLastReceived'
|
||||
| 'dateFirstReceived'
|
||||
| 'dateFirstSold'
|
||||
| 'imageUrl';
|
||||
| 'imageUrl'
|
||||
// New metrics from P3-P5 implementation
|
||||
| 'salesGrowth30dVsPrev'
|
||||
| 'revenueGrowth30dVsPrev'
|
||||
| 'salesGrowthYoy'
|
||||
| 'revenueGrowthYoy'
|
||||
| 'salesVariance30d'
|
||||
| 'salesStdDev30d'
|
||||
| 'salesCv30d'
|
||||
| 'demandPattern'
|
||||
| 'fillRate30d'
|
||||
| 'stockoutIncidents30d'
|
||||
| 'serviceLevel30d'
|
||||
| 'lostSalesIncidents30d'
|
||||
| 'seasonalityIndex'
|
||||
| 'seasonalPattern'
|
||||
| 'peakSeason'
|
||||
| 'lifetimeRevenueQuality';
|
||||
|
||||
// Mapping frontend keys to backend query param keys
|
||||
export const FRONTEND_TO_BACKEND_KEY_MAP: Record<string, string> = {
|
||||
@@ -427,7 +482,24 @@ export const FRONTEND_TO_BACKEND_KEY_MAP: Record<string, string> = {
|
||||
overstockedCost: 'overstockedCost',
|
||||
isOldStock: 'isOldStock',
|
||||
yesterdaySales: 'yesterdaySales',
|
||||
status: 'status' // Frontend-only field
|
||||
status: 'status', // Frontend-only field
|
||||
// New metrics from P3-P5 implementation
|
||||
salesGrowth30dVsPrev: 'salesGrowth30dVsPrev',
|
||||
revenueGrowth30dVsPrev: 'revenueGrowth30dVsPrev',
|
||||
salesGrowthYoy: 'salesGrowthYoy',
|
||||
revenueGrowthYoy: 'revenueGrowthYoy',
|
||||
salesVariance30d: 'salesVariance30d',
|
||||
salesStdDev30d: 'salesStdDev30d',
|
||||
salesCv30d: 'salesCv30d',
|
||||
demandPattern: 'demandPattern',
|
||||
fillRate30d: 'fillRate30d',
|
||||
stockoutIncidents30d: 'stockoutIncidents30d',
|
||||
serviceLevel30d: 'serviceLevel30d',
|
||||
lostSalesIncidents30d: 'lostSalesIncidents30d',
|
||||
seasonalityIndex: 'seasonalityIndex',
|
||||
seasonalPattern: 'seasonalPattern',
|
||||
peakSeason: 'peakSeason',
|
||||
lifetimeRevenueQuality: 'lifetimeRevenueQuality'
|
||||
};
|
||||
|
||||
// Function to get backend key safely
|
||||
|
||||
Reference in New Issue
Block a user