Consolidate old/new vendor and category routes, enhance new brands route, update frontend accordingly for all three pages, improve hierarchy on categories page, fix some calculations

This commit is contained in:
2025-04-02 14:28:18 -04:00
parent dbd0232285
commit 6051b849d6
16 changed files with 2273 additions and 880 deletions

View File

@@ -28,6 +28,8 @@ const COLUMN_MAP = {
avgMargin30d: { dbCol: 'bm.avg_margin_30d', type: 'number' },
// Add aliases if needed
name: { dbCol: 'bm.brand_name', type: 'string' },
// Add status for filtering
status: { dbCol: 'brand_status', type: 'string' },
};
function getSafeColumnInfo(queryParamKey) {
@@ -41,11 +43,26 @@ router.get('/filter-options', async (req, res) => {
const pool = req.app.locals.pool;
console.log('GET /brands-aggregate/filter-options');
try {
// Get brand names
const { rows: brandRows } = await pool.query(`
SELECT DISTINCT brand_name FROM public.brand_metrics ORDER BY brand_name
`);
// Get status values - calculate them since they're derived
const { rows: statusRows } = await pool.query(`
SELECT DISTINCT
CASE
WHEN active_product_count > 0 AND sales_30d > 0 THEN 'active'
WHEN active_product_count > 0 THEN 'inactive'
ELSE 'pending'
END as status
FROM public.brand_metrics
ORDER BY status
`);
res.json({
brands: brandRows.map(r => r.brand_name),
statuses: statusRows.map(r => r.status)
});
} catch(error) {
console.error('Error fetching brand filter options:', error);
@@ -61,16 +78,17 @@ router.get('/stats', async (req, res) => {
const { rows: [stats] } = await pool.query(`
SELECT
COUNT(*) AS total_brands,
COUNT(CASE WHEN active_product_count > 0 THEN 1 END) AS active_brands,
SUM(active_product_count) AS total_active_products,
SUM(current_stock_cost) AS total_stock_value,
-- Weighted Average Margin
SUM(profit_30d) * 100.0 / NULLIF(SUM(revenue_30d), 0) AS overall_avg_margin_weighted
-- Add other stats
FROM public.brand_metrics bm
`);
res.json({
totalBrands: parseInt(stats?.total_brands || 0),
activeBrands: parseInt(stats?.active_brands || 0),
totalActiveProducts: parseInt(stats?.total_active_products || 0),
totalValue: parseFloat(stats?.total_stock_value || 0),
avgMargin: parseFloat(stats?.overall_avg_margin_weighted || 0),
@@ -177,10 +195,40 @@ router.get('/', async (req, res) => {
// --- Execute Queries ---
const whereClause = conditions.length > 0 ? `WHERE ${conditions.join(' AND ')}` : '';
const baseSql = `FROM public.brand_metrics bm ${whereClause}`;
// Status calculation similar to vendors
const statusCase = `
CASE
WHEN active_product_count > 0 AND sales_30d > 0 THEN 'active'
WHEN active_product_count > 0 THEN 'inactive'
ELSE 'pending'
END as brand_status
`;
const baseSql = `
FROM (
SELECT
bm.*,
${statusCase}
FROM public.brand_metrics bm
) bm
${whereClause}
`;
const countSql = `SELECT COUNT(*) AS total ${baseSql}`;
const dataSql = `SELECT bm.* ${baseSql} ${sortClause} LIMIT $${paramCounter} OFFSET $${paramCounter + 1}`;
const dataSql = `
WITH brand_data AS (
SELECT
bm.*,
${statusCase}
FROM public.brand_metrics bm
)
SELECT bm.*
FROM brand_data bm
${whereClause}
${sortClause}
LIMIT $${paramCounter} OFFSET $${paramCounter + 1}
`;
const dataParams = [...params, limit, offset];
console.log("Count SQL:", countSql, params);

View File

@@ -1,100 +0,0 @@
const express = require('express');
const router = express.Router();
// Get all categories
router.get('/', async (req, res) => {
const pool = req.app.locals.pool;
try {
// Get all categories with metrics and hierarchy info
const { rows: categories } = await pool.query(`
SELECT
c.cat_id,
c.name,
c.type,
c.parent_id,
c.description,
c.status,
p.name as parent_name,
p.type as parent_type,
COALESCE(cm.product_count, 0) as product_count,
COALESCE(cm.active_products, 0) as active_products,
ROUND(COALESCE(cm.total_value, 0)::numeric, 3) as total_value,
COALESCE(cm.avg_margin, 0) as avg_margin,
COALESCE(cm.turnover_rate, 0) as turnover_rate,
COALESCE(cm.growth_rate, 0) as growth_rate
FROM categories c
LEFT JOIN categories p ON c.parent_id = p.cat_id
LEFT JOIN category_metrics cm ON c.cat_id = cm.category_id
ORDER BY
CASE
WHEN c.type = 10 THEN 1 -- sections first
WHEN c.type = 11 THEN 2 -- categories second
WHEN c.type = 12 THEN 3 -- subcategories third
WHEN c.type = 13 THEN 4 -- subsubcategories fourth
WHEN c.type = 20 THEN 5 -- themes fifth
WHEN c.type = 21 THEN 6 -- subthemes last
ELSE 7
END,
c.name ASC
`);
// Get overall stats
const { rows: [stats] } = await pool.query(`
SELECT
COUNT(DISTINCT c.cat_id) as totalCategories,
COUNT(DISTINCT CASE WHEN c.status = 'active' THEN c.cat_id END) as activeCategories,
ROUND(COALESCE(SUM(cm.total_value), 0)::numeric, 3) as totalValue,
COALESCE(ROUND(AVG(NULLIF(cm.avg_margin, 0))::numeric, 1), 0) as avgMargin,
COALESCE(ROUND(AVG(NULLIF(cm.growth_rate, 0))::numeric, 1), 0) as avgGrowth
FROM categories c
LEFT JOIN category_metrics cm ON c.cat_id = cm.category_id
`);
// Get type counts for filtering
const { rows: typeCounts } = await pool.query(`
SELECT
type,
COUNT(*)::integer as count
FROM categories
GROUP BY type
ORDER BY type
`);
res.json({
categories: categories.map(cat => ({
cat_id: cat.cat_id,
name: cat.name,
type: cat.type,
parent_id: cat.parent_id,
parent_name: cat.parent_name,
parent_type: cat.parent_type,
description: cat.description,
status: cat.status,
metrics: {
product_count: parseInt(cat.product_count),
active_products: parseInt(cat.active_products),
total_value: parseFloat(cat.total_value),
avg_margin: parseFloat(cat.avg_margin),
turnover_rate: parseFloat(cat.turnover_rate),
growth_rate: parseFloat(cat.growth_rate)
}
})),
typeCounts: typeCounts.map(tc => ({
type: tc.type,
count: tc.count // Already cast to integer in the query
})),
stats: {
totalCategories: parseInt(stats.totalcategories),
activeCategories: parseInt(stats.activecategories),
totalValue: parseFloat(stats.totalvalue),
avgMargin: parseFloat(stats.avgmargin),
avgGrowth: parseFloat(stats.avggrowth)
}
});
} catch (error) {
console.error('Error fetching categories:', error);
res.status(500).json({ error: 'Failed to fetch categories' });
}
});
module.exports = router;

View File

@@ -4,7 +4,7 @@ const { parseValue } = require('../utils/apiHelpers'); // Adjust path if needed
// --- Configuration & Helpers ---
const DEFAULT_PAGE_LIMIT = 50;
const MAX_PAGE_LIMIT = 200;
const MAX_PAGE_LIMIT = 5000; // Increase this to allow retrieving all categories in one request
// Maps query keys to DB columns in category_metrics and categories tables
const COLUMN_MAP = {
@@ -31,8 +31,8 @@ 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' },
// Add 'status' if filtering by category status needed (requires JOIN)
// status: { dbCol: 'c.status', type: 'string' },
// Add status from the categories table for filtering
status: { dbCol: 'c.status', type: 'string' },
};
function getSafeColumnInfo(queryParamKey) {
@@ -43,7 +43,7 @@ function getSafeColumnInfo(queryParamKey) {
const TYPE_LABELS = {
10: 'Section', 11: 'Category', 12: 'Subcategory', 13: 'Sub-subcategory',
1: 'Company', 2: 'Line', 3: 'Subline', 40: 'Artist', // From old schema comments
// Add other types if needed
20: 'Theme', 21: 'Subtheme' // Additional types from categories.js
};
// --- Route Handlers ---
@@ -66,12 +66,28 @@ router.get('/filter-options', async (req, res) => {
label: TYPE_LABELS[r.category_type] || `Type ${r.category_type}` // Add labels
}));
// Add other filter options like status if needed
// const { rows: statusRows } = await pool.query(`SELECT DISTINCT status FROM public.categories ORDER BY status`);
// Add status options for filtering (from categories.js)
const { rows: statusRows } = await pool.query(`
SELECT DISTINCT status FROM public.categories ORDER BY status
`);
// Get type counts (from categories.js)
const { rows: typeCounts } = await pool.query(`
SELECT
type,
COUNT(*)::integer as count
FROM categories
GROUP BY type
ORDER BY type
`);
res.json({
types: typeOptions,
// statuses: statusRows.map(r => r.status)
statuses: statusRows.map(r => r.status),
typeCounts: typeCounts.map(tc => ({
type: tc.type,
count: tc.count
}))
});
} catch (error) {
console.error('Error fetching category filter options:', error);
@@ -96,7 +112,7 @@ router.get('/stats', async (req, res) => {
SUM(cm.profit_30d) * 100.0 / NULLIF(SUM(cm.revenue_30d), 0) AS overall_avg_margin_weighted,
-- Simple Average Margin (less accurate if categories vary greatly in size)
AVG(NULLIF(cm.avg_margin_30d, 0)) AS overall_avg_margin_simple
-- Add SUM(revenue_30d) / SUM(revenue_30d_previous) for growth if needed
-- Growth rate can be calculated from 30d vs previous 30d revenue if needed
FROM public.category_metrics cm
JOIN public.categories c ON cm.category_id = c.cat_id -- Join to check category status
`);
@@ -107,8 +123,8 @@ router.get('/stats', async (req, res) => {
totalActiveProducts: parseInt(stats?.total_active_products || 0),
totalValue: parseFloat(stats?.total_stock_value || 0),
// Choose which avg margin calculation to expose
avgMargin: parseFloat(stats?.overall_avg_margin_weighted || stats?.overall_avg_margin_simple || 0),
// avgGrowth: ... // Calculate if needed
avgMargin: parseFloat(stats?.overall_avg_margin_weighted || stats?.overall_avg_margin_simple || 0)
// Growth rate could be added if we implement the calculation
});
} catch (error) {
console.error('Error fetching category stats:', error);
@@ -130,10 +146,27 @@ router.get('/', async (req, res) => {
// --- Sorting ---
const sortQueryKey = req.query.sort || 'categoryName';
const sortColumnInfo = getSafeColumnInfo(sortQueryKey);
// Default sort order: Type then Name
const defaultSortOrder = 'ORDER BY cm.category_type ASC, cm.category_name ASC';
let sortClause = defaultSortOrder;
if (sortColumnInfo) {
// Hierarchical sorting logic from categories.js
const hierarchicalSortOrder = `
ORDER BY
CASE
WHEN cm.category_type = 10 THEN 1 -- sections first
WHEN cm.category_type = 11 THEN 2 -- categories second
WHEN cm.category_type = 12 THEN 3 -- subcategories third
WHEN cm.category_type = 13 THEN 4 -- subsubcategories fourth
WHEN cm.category_type = 20 THEN 5 -- themes fifth
WHEN cm.category_type = 21 THEN 6 -- subthemes last
ELSE 7
END,
cm.category_name ASC
`;
// Use hierarchical sort as default
let sortClause = hierarchicalSortOrder;
// Override with custom sort if specified
if (sortColumnInfo && sortQueryKey !== 'categoryName') {
const sortColumn = sortColumnInfo.dbCol;
const sortDirection = req.query.order?.toLowerCase() === 'desc' ? 'DESC' : 'ASC';
const nullsOrder = (sortDirection === 'ASC' ? 'NULLS FIRST' : 'NULLS LAST');
@@ -224,18 +257,26 @@ router.get('/', async (req, res) => {
// Need JOIN for parent_name if sorting/filtering by it, or always include for display
const sortColumn = sortColumnInfo?.dbCol;
// Always include the parent join for consistency
const parentJoinSql = 'LEFT JOIN public.categories p ON cm.parent_id = p.cat_id';
// Always include the category and parent joins for status and parent_name
const joinSql = `
JOIN public.categories c ON cm.category_id = c.cat_id
LEFT JOIN public.categories p ON cm.parent_id = p.cat_id
`;
const baseSql = `
FROM public.category_metrics cm
${parentJoinSql}
${joinSql}
${whereClause}
`;
const countSql = `SELECT COUNT(*) AS total ${baseSql}`;
const dataSql = `
SELECT cm.*, p.name as parent_name
SELECT
cm.*,
c.status,
c.description,
p.name as parent_name,
p.type as parent_type
${baseSql}
${sortClause}
LIMIT $${paramCounter} OFFSET $${paramCounter + 1}

View File

@@ -1,108 +0,0 @@
const express = require('express');
const router = express.Router();
// Get vendors with pagination, filtering, and sorting
router.get('/', async (req, res) => {
const pool = req.app.locals.pool;
try {
// Get all vendors with metrics
const { rows: vendors } = await pool.query(`
SELECT DISTINCT
p.vendor as name,
COALESCE(vm.active_products, 0) as active_products,
COALESCE(vm.total_orders, 0) as total_orders,
COALESCE(vm.avg_lead_time_days, 0) as avg_lead_time_days,
COALESCE(vm.on_time_delivery_rate, 0) as on_time_delivery_rate,
COALESCE(vm.order_fill_rate, 0) as order_fill_rate,
CASE
WHEN COALESCE(vm.total_orders, 0) > 0 AND COALESCE(vm.order_fill_rate, 0) >= 75 THEN 'active'
WHEN COALESCE(vm.total_orders, 0) > 0 THEN 'inactive'
ELSE 'pending'
END as status
FROM products p
LEFT JOIN vendor_metrics vm ON p.vendor = vm.vendor
WHERE p.vendor IS NOT NULL AND p.vendor != ''
`);
// Get cost metrics for all vendors
const vendorNames = vendors.map(v => v.name);
const { rows: costMetrics } = await pool.query(`
SELECT
vendor,
ROUND((SUM(ordered * cost_price)::numeric / NULLIF(SUM(ordered), 0)), 2) as avg_unit_cost,
ROUND(SUM(ordered * cost_price)::numeric, 3) as total_spend
FROM purchase_orders
WHERE status = 2
AND cost_price IS NOT NULL
AND ordered > 0
AND vendor = ANY($1)
GROUP BY vendor
`, [vendorNames]);
// Create a map of cost metrics by vendor
const costMetricsMap = costMetrics.reduce((acc, curr) => {
acc[curr.vendor] = {
avg_unit_cost: curr.avg_unit_cost,
total_spend: curr.total_spend
};
return acc;
}, {});
// Get overall stats
const { rows: [stats] } = await pool.query(`
SELECT
COUNT(DISTINCT p.vendor) as totalVendors,
COUNT(DISTINCT CASE
WHEN COALESCE(vm.total_orders, 0) > 0 AND COALESCE(vm.order_fill_rate, 0) >= 75
THEN p.vendor
END) as activeVendors,
COALESCE(ROUND(AVG(NULLIF(vm.avg_lead_time_days, 0))::numeric, 1), 0) as avgLeadTime,
COALESCE(ROUND(AVG(NULLIF(vm.order_fill_rate, 0))::numeric, 1), 0) as avgFillRate,
COALESCE(ROUND(AVG(NULLIF(vm.on_time_delivery_rate, 0))::numeric, 1), 0) as avgOnTimeDelivery
FROM products p
LEFT JOIN vendor_metrics vm ON p.vendor = vm.vendor
WHERE p.vendor IS NOT NULL AND p.vendor != ''
`);
// Get overall cost metrics
const { rows: [overallCostMetrics] } = await pool.query(`
SELECT
ROUND((SUM(ordered * cost_price)::numeric / NULLIF(SUM(ordered), 0)), 2) as avg_unit_cost,
ROUND(SUM(ordered * cost_price)::numeric, 3) as total_spend
FROM purchase_orders
WHERE status = 2
AND cost_price IS NOT NULL
AND ordered > 0
AND vendor IS NOT NULL AND vendor != ''
`);
res.json({
vendors: vendors.map(vendor => ({
vendor_id: vendor.name,
name: vendor.name,
status: vendor.status,
avg_lead_time_days: parseFloat(vendor.avg_lead_time_days),
on_time_delivery_rate: parseFloat(vendor.on_time_delivery_rate),
order_fill_rate: parseFloat(vendor.order_fill_rate),
total_orders: parseInt(vendor.total_orders),
active_products: parseInt(vendor.active_products),
avg_unit_cost: parseFloat(costMetricsMap[vendor.name]?.avg_unit_cost || 0),
total_spend: parseFloat(costMetricsMap[vendor.name]?.total_spend || 0)
})),
stats: {
totalVendors: parseInt(stats.totalvendors),
activeVendors: parseInt(stats.activevendors),
avgLeadTime: parseFloat(stats.avgleadtime),
avgFillRate: parseFloat(stats.avgfillrate),
avgOnTimeDelivery: parseFloat(stats.avgontimedelivery),
avgUnitCost: parseFloat(overallCostMetrics.avg_unit_cost),
totalSpend: parseFloat(overallCostMetrics.total_spend)
}
});
} catch (error) {
console.error('Error fetching vendors:', error);
res.status(500).json({ error: 'Failed to fetch vendors' });
}
});
module.exports = router;

View File

@@ -33,6 +33,8 @@ const COLUMN_MAP = {
// Add aliases if needed for frontend compatibility
name: { dbCol: 'vm.vendor_name', type: 'string' },
leadTime: { dbCol: 'vm.avg_lead_time_days', type: 'number' },
// Add status for filtering
status: { dbCol: 'vendor_status', type: 'string' },
};
function getSafeColumnInfo(queryParamKey) {
@@ -46,11 +48,26 @@ router.get('/filter-options', async (req, res) => {
const pool = req.app.locals.pool;
console.log('GET /vendors-aggregate/filter-options');
try {
// Get vendor names
const { rows: vendorRows } = await pool.query(`
SELECT DISTINCT vendor_name FROM public.vendor_metrics ORDER BY vendor_name
`);
// Get status values - calculate them since they're derived
const { rows: statusRows } = await pool.query(`
SELECT DISTINCT
CASE
WHEN po_count_365d > 0 AND sales_30d > 0 THEN 'active'
WHEN po_count_365d > 0 THEN 'inactive'
ELSE 'pending'
END as status
FROM public.vendor_metrics
ORDER BY status
`);
res.json({
vendors: vendorRows.map(r => r.vendor_name),
statuses: statusRows.map(r => r.status)
});
} catch(error) {
console.error('Error fetching vendor filter options:', error);
@@ -63,23 +80,47 @@ router.get('/stats', async (req, res) => {
const pool = req.app.locals.pool;
console.log('GET /vendors-aggregate/stats');
try {
// Get basic vendor stats from aggregate table
const { rows: [stats] } = await pool.query(`
SELECT
COUNT(*) AS total_vendors,
SUM(active_product_count) AS total_active_products,
SUM(current_stock_cost) AS total_stock_value,
SUM(on_order_cost) AS total_on_order_value,
AVG(NULLIF(avg_lead_time_days, 0)) AS overall_avg_lead_time -- Simple average
-- Add more overall stats: weighted margin, total POs etc.
AVG(NULLIF(avg_lead_time_days, 0)) AS overall_avg_lead_time
FROM public.vendor_metrics vm
`);
// Count active vendors based on criteria (from old vendors.js)
const { rows: [activeStats] } = await pool.query(`
SELECT
COUNT(DISTINCT CASE
WHEN po_count_365d > 0
THEN vendor_name
END) as active_vendors
FROM public.vendor_metrics
`);
// Get overall cost metrics from purchase orders
const { rows: [overallCostMetrics] } = await pool.query(`
SELECT
ROUND((SUM(ordered * cost_price)::numeric / NULLIF(SUM(ordered), 0)), 2) as avg_unit_cost,
ROUND(SUM(ordered * cost_price)::numeric, 3) as total_spend
FROM purchase_orders
WHERE cost_price IS NOT NULL
AND ordered > 0
AND vendor IS NOT NULL AND vendor != ''
`);
res.json({
totalVendors: parseInt(stats?.total_vendors || 0),
activeVendors: parseInt(activeStats?.active_vendors || 0),
totalActiveProducts: parseInt(stats?.total_active_products || 0),
totalValue: parseFloat(stats?.total_stock_value || 0),
totalOnOrderValue: parseFloat(stats?.total_on_order_value || 0),
avgLeadTime: parseFloat(stats?.overall_avg_lead_time || 0)
avgLeadTime: parseFloat(stats?.overall_avg_lead_time || 0),
avgUnitCost: parseFloat(overallCostMetrics?.avg_unit_cost || 0),
totalSpend: parseFloat(overallCostMetrics?.total_spend || 0)
});
} catch (error) {
console.error('Error fetching vendor stats:', error);
@@ -181,10 +222,52 @@ router.get('/', async (req, res) => {
// --- Execute Queries ---
const whereClause = conditions.length > 0 ? `WHERE ${conditions.join(' AND ')}` : '';
const baseSql = `FROM public.vendor_metrics vm ${whereClause}`;
// Status calculation from vendors.js
const statusCase = `
CASE
WHEN po_count_365d > 0 AND sales_30d > 0 THEN 'active'
WHEN po_count_365d > 0 THEN 'inactive'
ELSE 'pending'
END as vendor_status
`;
const baseSql = `
FROM (
SELECT
vm.*,
${statusCase}
FROM public.vendor_metrics vm
) vm
${whereClause}
`;
const countSql = `SELECT COUNT(*) AS total ${baseSql}`;
const dataSql = `SELECT vm.* ${baseSql} ${sortClause} LIMIT $${paramCounter} OFFSET $${paramCounter + 1}`;
const dataSql = `
WITH vendor_data AS (
SELECT
vm.*,
${statusCase}
FROM public.vendor_metrics vm
)
SELECT
vm.*,
COALESCE(po.avg_unit_cost, 0) as avg_unit_cost,
COALESCE(po.total_spend, 0) as total_spend
FROM vendor_data vm
LEFT JOIN (
SELECT
vendor,
ROUND((SUM(ordered * cost_price)::numeric / NULLIF(SUM(ordered), 0)), 2) as avg_unit_cost,
ROUND(SUM(ordered * cost_price)::numeric, 3) as total_spend
FROM purchase_orders
WHERE cost_price IS NOT NULL AND ordered > 0
GROUP BY vendor
) po ON vm.vendor_name = po.vendor
${whereClause}
${sortClause}
LIMIT $${paramCounter} OFFSET $${paramCounter + 1}
`;
const dataParams = [...params, limit, offset];
console.log("Count SQL:", countSql, params);