Move product status calculation to database, fix up products table, more categories tweaks

This commit is contained in:
2025-04-03 17:12:10 -04:00
parent 2601a04211
commit 4552fa4862
9 changed files with 735 additions and 219 deletions

View File

@@ -151,6 +151,9 @@ CREATE TABLE public.product_metrics (
-- Yesterday's Metrics (Refreshed Hourly from daily_product_snapshots)
yesterday_sales INT,
-- Product Status (Calculated from metrics)
status VARCHAR, -- Stores status values like: Critical, Reorder Soon, Healthy, Overstock, At Risk, New
CONSTRAINT fk_product_metrics_pid FOREIGN KEY (pid) REFERENCES public.products(pid) ON DELETE CASCADE ON UPDATE CASCADE
);
@@ -163,6 +166,7 @@ CREATE INDEX idx_product_metrics_revenue_30d ON public.product_metrics(revenue_3
CREATE INDEX idx_product_metrics_sales_30d ON public.product_metrics(sales_30d DESC NULLS LAST); -- Example sorting index
CREATE INDEX idx_product_metrics_current_stock ON public.product_metrics(current_stock);
CREATE INDEX idx_product_metrics_sells_out_in_days ON public.product_metrics(sells_out_in_days ASC NULLS LAST); -- Example sorting index
CREATE INDEX idx_product_metrics_status ON public.product_metrics(status); -- Index for status filtering
-- Add new vendor, category, and brand metrics tables
-- Drop tables in reverse order if they exist

View File

@@ -5,11 +5,11 @@ const { Pool } = require('pg'); // Assuming you use 'pg'
// --- Configuration ---
// Toggle these constants to enable/disable specific steps for testing
const RUN_DAILY_SNAPSHOTS = false;
const RUN_PRODUCT_METRICS = false;
const RUN_PERIODIC_METRICS = false;
const RUN_BRAND_METRICS = false;
const RUN_VENDOR_METRICS = false;
const RUN_DAILY_SNAPSHOTS = true;
const RUN_PRODUCT_METRICS = true;
const RUN_PERIODIC_METRICS = true;
const RUN_BRAND_METRICS = true;
const RUN_VENDOR_METRICS = true;
const RUN_CATEGORY_METRICS = true;
// Maximum execution time for the entire sequence (e.g., 90 minutes)

View File

@@ -209,7 +209,8 @@ BEGIN
to_order_units, forecast_lost_sales_units, forecast_lost_revenue,
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
yesterday_sales,
status -- Add status field for calculated status
)
SELECT
ci.pid, _start_time, ci.sku, ci.title, ci.brand, ci.vendor, ci.image_url, ci.is_visible, ci.is_replenishable,
@@ -568,7 +569,119 @@ BEGIN
COALESCE(ooi.on_order_qty, 0) = 0
AS is_old_stock,
sa.yesterday_sales
sa.yesterday_sales,
-- Calculate status using direct CASE statements (inline logic)
CASE
-- Non-replenishable items default to Healthy
WHEN NOT ci.is_replenishable THEN 'Healthy'
-- Calculate lead time and thresholds
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'
-- 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'
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'
-- 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
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'
ELSE 'Reorder Soon'
END
-- Check for 'At Risk' - old stock
WHEN (ci.created_at::date < _current_date - INTERVAL '60 day') AND
(COALESCE(ci.date_last_sold, hd.max_order_date) IS NULL OR COALESCE(ci.date_last_sold, hd.max_order_date) < _current_date - INTERVAL '60 day') AND
(hd.date_last_received_calc IS NULL OR hd.date_last_received_calc < _current_date - INTERVAL '60 day') AND
COALESCE(ooi.on_order_qty, 0) = 0 THEN 'At Risk'
-- Check for 'At Risk' - hasn't sold in a long time
WHEN COALESCE(ci.date_last_sold, hd.max_order_date) IS NOT NULL
AND COALESCE(ci.date_last_sold, hd.max_order_date) < (_current_date - INTERVAL '90 days')
AND (CASE
WHEN ci.created_at IS NULL AND hd.date_first_sold IS NULL THEN 0
WHEN ci.created_at IS NULL THEN (_current_date - hd.date_first_sold)::integer
WHEN hd.date_first_sold IS NULL THEN (_current_date - ci.created_at::date)::integer
ELSE (_current_date - LEAST(ci.created_at::date, hd.date_first_sold))::integer
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'
-- New products (less than 30 days old)
WHEN (CASE
WHEN ci.created_at IS NULL AND hd.date_first_sold IS NULL THEN 0
WHEN ci.created_at IS NULL THEN (_current_date - hd.date_first_sold)::integer
WHEN hd.date_first_sold IS NULL THEN (_current_date - ci.created_at::date)::integer
ELSE (_current_date - LEAST(ci.created_at::date, hd.date_first_sold))::integer
END) <= 30 THEN 'New'
-- If none of the above, assume Healthy
ELSE 'Healthy'
END
END AS status
FROM CurrentInfo ci
LEFT JOIN OnOrderInfo ooi ON ci.pid = ooi.pid
@@ -605,7 +718,8 @@ BEGIN
to_order_units = EXCLUDED.to_order_units, forecast_lost_sales_units = EXCLUDED.forecast_lost_sales_units, forecast_lost_revenue = EXCLUDED.forecast_lost_revenue,
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
yesterday_sales = EXCLUDED.yesterday_sales,
status = EXCLUDED.status
;
-- Update the status table with the timestamp from the START of this run

View File

@@ -178,6 +178,8 @@ router.get('/', async (req, res) => {
const params = [];
let paramCounter = 1;
console.log("Starting to process filters from query:", req.query);
// Add filters based on req.query using COLUMN_MAP and parseValue
for (const key in req.query) {
if (['page', 'limit', 'sort', 'order'].includes(key)) continue;
@@ -185,11 +187,14 @@ router.get('/', async (req, res) => {
let filterKey = key;
let operator = '='; // Default operator
const value = req.query[key];
console.log(`Processing filter key: "${key}" with value: "${value}"`);
const operatorMatch = key.match(/^(.*)_(eq|ne|gt|gte|lt|lte|like|ilike|between|in)$/);
if (operatorMatch) {
filterKey = operatorMatch[1];
operator = operatorMatch[2];
console.log(`Parsed filter key: "${filterKey}" with operator: "${operator}"`);
}
// Special case for parentName requires join
@@ -197,6 +202,7 @@ router.get('/', async (req, res) => {
const columnInfo = getSafeColumnInfo(filterKey);
if (columnInfo) {
console.log(`Column info for "${filterKey}":`, columnInfo);
const dbColumn = columnInfo.dbCol;
const valueType = columnInfo.type;
try {
@@ -232,22 +238,46 @@ router.get('/', async (req, res) => {
}
if (needsParam) {
conditionFragment = `${dbColumn} ${operator} $${paramCounter++}`;
params.push(parseValue(value, valueType));
try {
// Special handling for categoryType to ensure it works
if (filterKey === 'categoryType') {
console.log(`Special handling for categoryType: ${value}`);
// Force conversion to integer
const numericValue = parseInt(value, 10);
if (!isNaN(numericValue)) {
console.log(`Successfully converted categoryType to integer: ${numericValue}`);
conditionFragment = `${dbColumn} ${operator} $${paramCounter++}`;
params.push(numericValue);
} else {
console.error(`Failed to convert categoryType to integer: "${value}"`);
throw new Error(`Invalid categoryType value: "${value}"`);
}
} else {
// Normal handling for other fields
const parsedValue = parseValue(value, valueType);
console.log(`Parsed "${value}" as ${valueType}: ${parsedValue}`);
conditionFragment = `${dbColumn} ${operator} $${paramCounter++}`;
params.push(parsedValue);
}
} catch (innerError) {
console.error(`Failed to parse "${value}" as ${valueType}:`, innerError);
throw innerError;
}
} else if (!conditionFragment) { // For LIKE/ILIKE where needsParam is false
conditionFragment = `${dbColumn} ${operator} $${paramCounter++}`; // paramCounter was already incremented in push
}
if (conditionFragment) {
console.log(`Adding condition: ${conditionFragment}`);
conditions.push(`(${conditionFragment})`);
}
} catch (parseError) {
console.warn(`Skipping filter for key "${key}" due to parsing error: ${parseError.message}`);
console.error(`Skipping filter for key "${key}" due to parsing error:`, parseError);
if (needsParam) paramCounter--; // Roll back counter if param push failed
}
} else {
console.warn(`Invalid filter key ignored: ${key}`);
console.warn(`Invalid filter key ignored: "${key}", not found in COLUMN_MAP`);
}
}

View File

@@ -7,90 +7,210 @@ const { Pool } = require('pg'); // Assuming pg driver
const DEFAULT_PAGE_LIMIT = 50;
const MAX_PAGE_LIMIT = 200; // Prevent excessive data requests
/**
* Maps user-friendly query parameter keys (camelCase) to database column names.
* Also validates if the column is safe for sorting or filtering.
* Add ALL columns from product_metrics that should be filterable/sortable.
*/
// Define direct mapping from frontend column names to database columns
// This simplifies the code by eliminating conversion logic
const COLUMN_MAP = {
// Product Info
pid: { dbCol: 'pm.pid', type: 'number' },
sku: { dbCol: 'pm.sku', type: 'string' },
title: { dbCol: 'pm.title', type: 'string' },
brand: { dbCol: 'pm.brand', type: 'string' },
vendor: { dbCol: 'pm.vendor', type: 'string' },
imageUrl: { dbCol: 'pm.image_url', type: 'string' },
isVisible: { dbCol: 'pm.is_visible', type: 'boolean' },
isReplenishable: { dbCol: 'pm.is_replenishable', type: 'boolean' },
pid: 'pm.pid',
sku: 'pm.sku',
title: 'pm.title',
brand: 'pm.brand',
vendor: 'pm.vendor',
imageUrl: 'pm.image_url',
isVisible: 'pm.is_visible',
isReplenishable: 'pm.is_replenishable',
// Current Status
currentPrice: { dbCol: 'pm.current_price', type: 'number' },
currentRegularPrice: { dbCol: 'pm.current_regular_price', type: 'number' },
currentCostPrice: { dbCol: 'pm.current_cost_price', type: 'number' },
currentLandingCostPrice: { dbCol: 'pm.current_landing_cost_price', type: 'number' },
currentStock: { dbCol: 'pm.current_stock', type: 'number' },
currentStockCost: { dbCol: 'pm.current_stock_cost', type: 'number' },
currentStockRetail: { dbCol: 'pm.current_stock_retail', type: 'number' },
currentStockGross: { dbCol: 'pm.current_stock_gross', type: 'number' },
onOrderQty: { dbCol: 'pm.on_order_qty', type: 'number' },
onOrderCost: { dbCol: 'pm.on_order_cost', type: 'number' },
onOrderRetail: { dbCol: 'pm.on_order_retail', type: 'number' },
earliestExpectedDate: { dbCol: 'pm.earliest_expected_date', type: 'date' },
currentPrice: 'pm.current_price',
currentRegularPrice: 'pm.current_regular_price',
currentCostPrice: 'pm.current_cost_price',
currentLandingCostPrice: 'pm.current_landing_cost_price',
currentStock: 'pm.current_stock',
currentStockCost: 'pm.current_stock_cost',
currentStockRetail: 'pm.current_stock_retail',
currentStockGross: 'pm.current_stock_gross',
onOrderQty: 'pm.on_order_qty',
onOrderCost: 'pm.on_order_cost',
onOrderRetail: 'pm.on_order_retail',
earliestExpectedDate: 'pm.earliest_expected_date',
// Historical Dates
dateCreated: { dbCol: 'pm.date_created', type: 'date' },
dateFirstReceived: { dbCol: 'pm.date_first_received', type: 'date' },
dateLastReceived: { dbCol: 'pm.date_last_received', type: 'date' },
dateFirstSold: { dbCol: 'pm.date_first_sold', type: 'date' },
dateLastSold: { dbCol: 'pm.date_last_sold', type: 'date' },
ageDays: { dbCol: 'pm.age_days', type: 'number' },
dateCreated: 'pm.date_created',
dateFirstReceived: 'pm.date_first_received',
dateLastReceived: 'pm.date_last_received',
dateFirstSold: 'pm.date_first_sold',
dateLastSold: 'pm.date_last_sold',
ageDays: 'pm.age_days',
// Rolling Period Metrics
sales7d: { dbCol: 'pm.sales_7d', type: 'number' }, revenue7d: { dbCol: 'pm.revenue_7d', type: 'number' },
sales14d: { dbCol: 'pm.sales_14d', type: 'number' }, revenue14d: { dbCol: 'pm.revenue_14d', type: 'number' },
sales30d: { dbCol: 'pm.sales_30d', type: 'number' }, revenue30d: { dbCol: 'pm.revenue_30d', type: 'number' },
cogs30d: { dbCol: 'pm.cogs_30d', type: 'number' }, profit30d: { dbCol: 'pm.profit_30d', type: 'number' },
returnsUnits30d: { dbCol: 'pm.returns_units_30d', type: 'number' }, returnsRevenue30d: { dbCol: 'pm.returns_revenue_30d', type: 'number' },
discounts30d: { dbCol: 'pm.discounts_30d', type: 'number' }, grossRevenue30d: { dbCol: 'pm.gross_revenue_30d', type: 'number' },
grossRegularRevenue30d: { dbCol: 'pm.gross_regular_revenue_30d', type: 'number' },
stockoutDays30d: { dbCol: 'pm.stockout_days_30d', type: 'number' },
sales365d: { dbCol: 'pm.sales_365d', type: 'number' }, revenue365d: { dbCol: 'pm.revenue_365d', type: 'number' },
avgStockUnits30d: { dbCol: 'pm.avg_stock_units_30d', type: 'number' }, avgStockCost30d: { dbCol: 'pm.avg_stock_cost_30d', type: 'number' },
avgStockRetail30d: { dbCol: 'pm.avg_stock_retail_30d', type: 'number' }, avgStockGross30d: { dbCol: 'pm.avg_stock_gross_30d', type: 'number' },
receivedQty30d: { dbCol: 'pm.received_qty_30d', type: 'number' }, receivedCost30d: { dbCol: 'pm.received_cost_30d', type: 'number' },
sales7d: 'pm.sales_7d',
revenue7d: 'pm.revenue_7d',
sales14d: 'pm.sales_14d',
revenue14d: 'pm.revenue_14d',
sales30d: 'pm.sales_30d',
revenue30d: 'pm.revenue_30d',
cogs30d: 'pm.cogs_30d',
profit30d: 'pm.profit_30d',
returnsUnits30d: 'pm.returns_units_30d',
returnsRevenue30d: 'pm.returns_revenue_30d',
discounts30d: 'pm.discounts_30d',
grossRevenue30d: 'pm.gross_revenue_30d',
grossRegularRevenue30d: 'pm.gross_regular_revenue_30d',
stockoutDays30d: 'pm.stockout_days_30d',
sales365d: 'pm.sales_365d',
revenue365d: 'pm.revenue_365d',
avgStockUnits30d: 'pm.avg_stock_units_30d',
avgStockCost30d: 'pm.avg_stock_cost_30d',
avgStockRetail30d: 'pm.avg_stock_retail_30d',
avgStockGross30d: 'pm.avg_stock_gross_30d',
receivedQty30d: 'pm.received_qty_30d',
receivedCost30d: 'pm.received_cost_30d',
// Lifetime Metrics
lifetimeSales: { dbCol: 'pm.lifetime_sales', type: 'number' }, lifetimeRevenue: { dbCol: 'pm.lifetime_revenue', type: 'number' },
lifetimeSales: 'pm.lifetime_sales',
lifetimeRevenue: 'pm.lifetime_revenue',
// First Period Metrics
first7DaysSales: { dbCol: 'pm.first_7_days_sales', type: 'number' }, first7DaysRevenue: { dbCol: 'pm.first_7_days_revenue', type: 'number' },
first30DaysSales: { dbCol: 'pm.first_30_days_sales', type: 'number' }, first30DaysRevenue: { dbCol: 'pm.first_30_days_revenue', type: 'number' },
first60DaysSales: { dbCol: 'pm.first_60_days_sales', type: 'number' }, first60DaysRevenue: { dbCol: 'pm.first_60_days_revenue', type: 'number' },
first90DaysSales: { dbCol: 'pm.first_90_days_sales', type: 'number' }, first90DaysRevenue: { dbCol: 'pm.first_90_days_revenue', type: 'number' },
first7DaysSales: 'pm.first_7_days_sales',
first7DaysRevenue: 'pm.first_7_days_revenue',
first30DaysSales: 'pm.first_30_days_sales',
first30DaysRevenue: 'pm.first_30_days_revenue',
first60DaysSales: 'pm.first_60_days_sales',
first60DaysRevenue: 'pm.first_60_days_revenue',
first90DaysSales: 'pm.first_90_days_sales',
first90DaysRevenue: 'pm.first_90_days_revenue',
// Calculated KPIs
asp30d: { dbCol: 'pm.asp_30d', type: 'number' }, acp30d: { dbCol: 'pm.acp_30d', type: 'number' }, avgRos30d: { dbCol: 'pm.avg_ros_30d', type: 'number' },
avgSalesPerDay30d: { dbCol: 'pm.avg_sales_per_day_30d', type: 'number' }, avgSalesPerMonth30d: { dbCol: 'pm.avg_sales_per_month_30d', type: 'number' },
margin30d: { dbCol: 'pm.margin_30d', type: 'number' }, markup30d: { dbCol: 'pm.markup_30d', type: 'number' }, gmroi30d: { dbCol: 'pm.gmroi_30d', type: 'number' },
stockturn30d: { dbCol: 'pm.stockturn_30d', type: 'number' }, returnRate30d: { dbCol: 'pm.return_rate_30d', type: 'number' },
discountRate30d: { dbCol: 'pm.discount_rate_30d', type: 'number' }, stockoutRate30d: { dbCol: 'pm.stockout_rate_30d', type: 'number' },
markdown30d: { dbCol: 'pm.markdown_30d', type: 'number' }, markdownRate30d: { dbCol: 'pm.markdown_rate_30d', type: 'number' },
sellThrough30d: { dbCol: 'pm.sell_through_30d', type: 'number' }, avgLeadTimeDays: { dbCol: 'pm.avg_lead_time_days', type: 'number' },
asp30d: 'pm.asp_30d',
acp30d: 'pm.acp_30d',
avgRos30d: 'pm.avg_ros_30d',
avgSalesPerDay30d: 'pm.avg_sales_per_day_30d',
avgSalesPerMonth30d: 'pm.avg_sales_per_month_30d',
margin30d: 'pm.margin_30d',
markup30d: 'pm.markup_30d',
gmroi30d: 'pm.gmroi_30d',
stockturn30d: 'pm.stockturn_30d',
returnRate30d: 'pm.return_rate_30d',
discountRate30d: 'pm.discount_rate_30d',
stockoutRate30d: 'pm.stockout_rate_30d',
markdown30d: 'pm.markdown_30d',
markdownRate30d: 'pm.markdown_rate_30d',
sellThrough30d: 'pm.sell_through_30d',
avgLeadTimeDays: 'pm.avg_lead_time_days',
// Forecasting & Replenishment
abcClass: { dbCol: 'pm.abc_class', type: 'string' }, salesVelocityDaily: { dbCol: 'pm.sales_velocity_daily', type: 'number' },
configLeadTime: { dbCol: 'pm.config_lead_time', type: 'number' }, configDaysOfStock: { dbCol: 'pm.config_days_of_stock', type: 'number' },
configSafetyStock: { dbCol: 'pm.config_safety_stock', type: 'number' }, planningPeriodDays: { dbCol: 'pm.planning_period_days', type: 'number' },
leadTimeForecastUnits: { dbCol: 'pm.lead_time_forecast_units', type: 'number' }, daysOfStockForecastUnits: { dbCol: 'pm.days_of_stock_forecast_units', type: 'number' },
planningPeriodForecastUnits: { dbCol: 'pm.planning_period_forecast_units', type: 'number' }, leadTimeClosingStock: { dbCol: 'pm.lead_time_closing_stock', type: 'number' },
daysOfStockClosingStock: { dbCol: 'pm.days_of_stock_closing_stock', type: 'number' }, replenishmentNeededRaw: { dbCol: 'pm.replenishment_needed_raw', type: 'number' },
replenishmentUnits: { dbCol: 'pm.replenishment_units', type: 'number' }, replenishmentCost: { dbCol: 'pm.replenishment_cost', type: 'number' },
replenishmentRetail: { dbCol: 'pm.replenishment_retail', type: 'number' }, replenishmentProfit: { dbCol: 'pm.replenishment_profit', type: 'number' },
toOrderUnits: { dbCol: 'pm.to_order_units', type: 'number' }, forecastLostSalesUnits: { dbCol: 'pm.forecast_lost_sales_units', type: 'number' },
forecastLostRevenue: { dbCol: 'pm.forecast_lost_revenue', type: 'number' }, stockCoverInDays: { dbCol: 'pm.stock_cover_in_days', type: 'number' },
poCoverInDays: { dbCol: 'pm.po_cover_in_days', type: 'number' }, sellsOutInDays: { dbCol: 'pm.sells_out_in_days', type: 'number' },
replenishDate: { dbCol: 'pm.replenish_date', type: 'date' }, overstockedUnits: { dbCol: 'pm.overstocked_units', type: 'number' },
overstockedCost: { dbCol: 'pm.overstocked_cost', type: 'number' }, overstockedRetail: { dbCol: 'pm.overstocked_retail', type: 'number' },
isOldStock: { dbCol: 'pm.is_old_stock', type: 'boolean' },
abcClass: 'pm.abc_class',
salesVelocityDaily: 'pm.sales_velocity_daily',
configLeadTime: 'pm.config_lead_time',
configDaysOfStock: 'pm.config_days_of_stock',
configSafetyStock: 'pm.config_safety_stock',
planningPeriodDays: 'pm.planning_period_days',
leadTimeForecastUnits: 'pm.lead_time_forecast_units',
daysOfStockForecastUnits: 'pm.days_of_stock_forecast_units',
planningPeriodForecastUnits: 'pm.planning_period_forecast_units',
leadTimeClosingStock: 'pm.lead_time_closing_stock',
daysOfStockClosingStock: 'pm.days_of_stock_closing_stock',
replenishmentNeededRaw: 'pm.replenishment_needed_raw',
replenishmentUnits: 'pm.replenishment_units',
replenishmentCost: 'pm.replenishment_cost',
replenishmentRetail: 'pm.replenishment_retail',
replenishmentProfit: 'pm.replenishment_profit',
toOrderUnits: 'pm.to_order_units',
forecastLostSalesUnits: 'pm.forecast_lost_sales_units',
forecastLostRevenue: 'pm.forecast_lost_revenue',
stockCoverInDays: 'pm.stock_cover_in_days',
poCoverInDays: 'pm.po_cover_in_days',
sellsOutInDays: 'pm.sells_out_in_days',
replenishDate: 'pm.replenish_date',
overstockedUnits: 'pm.overstocked_units',
overstockedCost: 'pm.overstocked_cost',
overstockedRetail: 'pm.overstocked_retail',
isOldStock: 'pm.is_old_stock',
// Yesterday
yesterdaySales: { dbCol: 'pm.yesterday_sales', type: 'number' },
yesterdaySales: 'pm.yesterday_sales',
// Map status column - directly mapped now instead of calculated on frontend
status: 'pm.status'
};
function getSafeColumnInfo(queryParamKey) {
return COLUMN_MAP[queryParamKey] || null;
// Map of column types for proper sorting
const COLUMN_TYPES = {
// Numeric columns
pid: 'number',
currentPrice: 'number',
currentRegularPrice: 'number',
currentCostPrice: 'number',
currentLandingCostPrice: 'number',
currentStock: 'number',
currentStockCost: 'number',
currentStockRetail: 'number',
currentStockGross: 'number',
onOrderQty: 'number',
onOrderCost: 'number',
onOrderRetail: 'number',
ageDays: 'number',
sales7d: 'number',
revenue7d: 'number',
sales14d: 'number',
revenue14d: 'number',
sales30d: 'number',
revenue30d: 'number',
cogs30d: 'number',
profit30d: 'number',
// ... other numeric columns
// Date columns
dateCreated: 'date',
dateFirstReceived: 'date',
dateLastReceived: 'date',
dateFirstSold: 'date',
dateLastSold: 'date',
earliestExpectedDate: 'date',
replenishDate: 'date',
// Status column - special handling
status: 'status',
// String columns default to 'string' type
// Boolean columns
isVisible: 'boolean',
isReplenishable: 'boolean',
isOldStock: 'boolean'
};
// Special sort handling for certain columns
const SPECIAL_SORT_COLUMNS = {
// Percentage columns where we want to sort by the numeric value
margin30d: true,
markup30d: true,
sellThrough30d: true,
discountRate30d: true,
stockoutRate30d: true,
returnRate30d: true,
markdownRate30d: true,
// Columns where we may want to sort by absolute value
profit30d: 'abs',
// Velocity columns
salesVelocityDaily: true,
// Status column needs special ordering
status: 'priority'
};
// Status priority for sorting (lower number = higher priority)
const STATUS_PRIORITY = {
'Critical': 1,
'At Risk': 2,
'Reorder': 3,
'Overstocked': 4,
'Healthy': 5,
'New': 6
// Any other status will be sorted alphabetically after these
};
// Get database column name from frontend column name
function getDbColumn(frontendColumn) {
return COLUMN_MAP[frontendColumn] || 'pm.title'; // Default to title if not found
}
// Get column type for proper sorting
function getColumnType(frontendColumn) {
return COLUMN_TYPES[frontendColumn] || 'string';
}
// --- Route Handlers ---
@@ -121,7 +241,7 @@ router.get('/filter-options', async (req, res) => {
// GET /metrics/ - List all product metrics with filtering, sorting, pagination
router.get('/', async (req, res) => {
const pool = req.app.locals.pool; // Get pool from app instance
const pool = req.app.locals.pool;
console.log('GET /metrics received query:', req.query);
try {
@@ -135,10 +255,45 @@ router.get('/', async (req, res) => {
// --- Sorting ---
const sortQueryKey = req.query.sort || 'title'; // Default sort field key
const sortColumnInfo = getSafeColumnInfo(sortQueryKey);
const sortColumn = sortColumnInfo ? sortColumnInfo.dbCol : 'pm.title'; // Default DB column
const dbColumn = getDbColumn(sortQueryKey);
const columnType = getColumnType(sortQueryKey);
console.log(`Sorting request: ${sortQueryKey} -> ${dbColumn} (${columnType})`);
const sortDirection = req.query.order?.toLowerCase() === 'desc' ? 'DESC' : 'ASC';
const nullsOrder = (sortDirection === 'ASC' ? 'NULLS FIRST' : 'NULLS LAST'); // Consistent null handling
// Always put nulls last regardless of sort direction or column type
const nullsOrder = 'NULLS LAST';
// Build the ORDER BY clause based on column type and special handling
let orderByClause;
if (SPECIAL_SORT_COLUMNS[sortQueryKey] === 'abs') {
// Sort by absolute value for columns where negative values matter
orderByClause = `ABS(${dbColumn}::numeric) ${sortDirection} ${nullsOrder}`;
} else if (columnType === 'number' || SPECIAL_SORT_COLUMNS[sortQueryKey] === true) {
// For numeric columns, cast to numeric to ensure proper sorting
orderByClause = `${dbColumn}::numeric ${sortDirection} ${nullsOrder}`;
} else if (columnType === 'date') {
// For date columns, cast to timestamp to ensure proper sorting
orderByClause = `CASE WHEN ${dbColumn} IS NULL THEN 1 ELSE 0 END, ${dbColumn}::timestamp ${sortDirection}`;
} else if (columnType === 'status' || SPECIAL_SORT_COLUMNS[sortQueryKey] === 'priority') {
// Special handling for status column, using priority for known statuses
orderByClause = `
CASE WHEN ${dbColumn} IS NULL THEN 999
WHEN ${dbColumn} = 'Critical' THEN 1
WHEN ${dbColumn} = 'At Risk' THEN 2
WHEN ${dbColumn} = 'Reorder' THEN 3
WHEN ${dbColumn} = 'Overstocked' THEN 4
WHEN ${dbColumn} = 'Healthy' THEN 5
WHEN ${dbColumn} = 'New' THEN 6
ELSE 100
END ${sortDirection} ${nullsOrder},
${dbColumn} ${sortDirection}`;
} else {
// For string and boolean columns, no special casting needed
orderByClause = `CASE WHEN ${dbColumn} IS NULL THEN 1 ELSE 0 END, ${dbColumn} ${sortDirection}`;
}
// --- Filtering ---
const conditions = [];
@@ -149,9 +304,24 @@ router.get('/', async (req, res) => {
if (req.query.showInvisible !== 'true') conditions.push(`pm.is_visible = true`);
if (req.query.showNonReplenishable !== 'true') conditions.push(`pm.is_replenishable = true`);
// Special handling for stock_status
if (req.query.stock_status) {
const status = req.query.stock_status;
// Handle special case for "at-risk" which is stored as "At Risk" in the database
if (status.toLowerCase() === 'at-risk') {
conditions.push(`pm.status = $${paramCounter++}`);
params.push('At Risk');
} else {
// Capitalize first letter to match database values
conditions.push(`pm.status = $${paramCounter++}`);
params.push(status.charAt(0).toUpperCase() + status.slice(1));
}
}
// Process other filters from query parameters
for (const key in req.query) {
if (['page', 'limit', 'sort', 'order', 'showInvisible', 'showNonReplenishable'].includes(key)) continue; // Skip control params
// Skip control params
if (['page', 'limit', 'sort', 'order', 'showInvisible', 'showNonReplenishable', 'stock_status'].includes(key)) continue;
let filterKey = key;
let operator = '='; // Default operator
@@ -164,15 +334,15 @@ router.get('/', async (req, res) => {
operator = operatorMatch[2]; // e.g., "gt"
}
const columnInfo = getSafeColumnInfo(filterKey);
if (!columnInfo) {
// Get the database column for this filter key
const dbColumn = getDbColumn(filterKey);
const valueType = getColumnType(filterKey);
if (!dbColumn) {
console.warn(`Invalid filter key ignored: ${key}`);
continue; // Skip if the key doesn't map to a known column
}
const dbColumn = columnInfo.dbCol;
const valueType = columnInfo.type;
// --- Build WHERE clause fragment ---
try {
let conditionFragment = '';
@@ -234,6 +404,10 @@ router.get('/', async (req, res) => {
// --- Construct and Execute Queries ---
const whereClause = conditions.length > 0 ? `WHERE ${conditions.join(' AND ')}` : '';
// Debug log of conditions and parameters
console.log('Constructed WHERE conditions:', conditions);
console.log('Parameters:', params);
// Count Query
const countSql = `SELECT COUNT(*) AS total FROM public.product_metrics pm ${whereClause}`;
console.log('Executing Count Query:', countSql, params);
@@ -244,11 +418,20 @@ router.get('/', async (req, res) => {
SELECT pm.*
FROM public.product_metrics pm
${whereClause}
ORDER BY ${sortColumn} ${sortDirection} ${nullsOrder}
ORDER BY ${orderByClause}
LIMIT $${paramCounter} OFFSET $${paramCounter + 1}
`;
const dataParams = [...params, limit, offset];
console.log('Executing Data Query:', dataSql, dataParams);
// Log detailed query information for debugging
console.log('Executing Data Query:');
console.log(' - Sort Column:', dbColumn);
console.log(' - Column Type:', columnType);
console.log(' - Sort Direction:', sortDirection);
console.log(' - Order By Clause:', orderByClause);
console.log(' - Full SQL:', dataSql);
console.log(' - Parameters:', dataParams);
const dataPromise = pool.query(dataSql, dataParams);
// Execute queries in parallel

View File

@@ -5,18 +5,28 @@
function parseValue(value, type) {
if (value === null || value === undefined || value === '') return null;
console.log(`Parsing value: "${value}" as type: "${type}"`);
switch (type) {
case 'number':
const num = parseFloat(value);
if (isNaN(num)) throw new Error(`Invalid number format: "${value}"`);
if (isNaN(num)) {
console.error(`Invalid number format: "${value}"`);
throw new Error(`Invalid number format: "${value}"`);
}
return num;
case 'integer': // Specific type for integer IDs etc.
const int = parseInt(value, 10);
if (isNaN(int)) throw new Error(`Invalid integer format: "${value}"`);
if (isNaN(int)) {
console.error(`Invalid integer format: "${value}"`);
throw new Error(`Invalid integer format: "${value}"`);
}
console.log(`Successfully parsed integer: ${int}`);
return int;
case 'boolean':
if (String(value).toLowerCase() === 'true') return true;
if (String(value).toLowerCase() === 'false') return false;
console.error(`Invalid boolean format: "${value}"`);
throw new Error(`Invalid boolean format: "${value}"`);
case 'date':
// Basic ISO date format validation (YYYY-MM-DD)