Tweaks and fixes for products table

This commit is contained in:
2025-04-05 09:52:36 -04:00
parent d081a60662
commit c9b656d34b
10 changed files with 788 additions and 310 deletions

View File

@@ -53,6 +53,28 @@ CREATE TABLE public.product_metrics (
image_url VARCHAR, -- (e.g., products.image_175)
is_visible BOOLEAN,
is_replenishable BOOLEAN,
-- Additional product fields
barcode VARCHAR,
harmonized_tariff_code VARCHAR,
vendor_reference VARCHAR,
notions_reference VARCHAR,
line VARCHAR,
subline VARCHAR,
artist VARCHAR,
moq INT,
rating NUMERIC(10, 2),
reviews INT,
weight NUMERIC(14, 4),
length NUMERIC(14, 4),
width NUMERIC(14, 4),
height NUMERIC(14, 4),
country_of_origin VARCHAR,
location VARCHAR,
baskets INT,
notifies INT,
preorder_count INT,
notions_inv_count INT,
-- Current Status (Refreshed Hourly)
current_price NUMERIC(10, 2),

View File

@@ -8,7 +8,29 @@ dotenv.config({ path: path.join(__dirname, "../../.env") });
// Utility functions
const imageUrlBase = process.env.PRODUCT_IMAGE_URL_BASE || 'https://sbing.com/i/products/0000/';
const getImageUrls = (pid, iid = 1) => {
// Modified to accept a db connection for querying product_images
const getImageUrls = async (pid, prodConnection, iid = null) => {
// If iid isn't provided, try to get it from product_images
if (iid === null && prodConnection) {
try {
// Query for images with order=255 (default/primary images)
const [primaryImages] = await prodConnection.query(
'SELECT iid FROM product_images WHERE pid = ? AND `order` = 255 LIMIT 1',
[pid]
);
// Use the found iid or default to 1
iid = primaryImages.length > 0 ? primaryImages[0].iid : 1;
} catch (error) {
console.error(`Error fetching primary image for pid ${pid}:`, error);
iid = 1; // Fallback to default
}
} else {
// Use default if connection not provided
iid = iid || 1;
}
const paddedPid = pid.toString().padStart(6, '0');
// Use padded PID only for the first 3 digits
const prefix = paddedPid.slice(0, 3);
@@ -237,9 +259,11 @@ async function importMissingProducts(prodConnection, localConnection, missingPid
return `(${Array.from({ length: 47 }, (_, i) => `$${base + i + 1}`).join(', ')})`;
}).join(',');
const values = batch.flatMap(row => {
const imageUrls = getImageUrls(row.pid);
return [
// Process image URLs for the batch
const processedValues = [];
for (const row of batch) {
const imageUrls = await getImageUrls(row.pid, prodConnection);
processedValues.push([
row.pid,
row.title,
row.description,
@@ -287,8 +311,10 @@ async function importMissingProducts(prodConnection, localConnection, missingPid
imageUrls.image_full,
null,
null
];
});
]);
}
const values = processedValues.flat();
const [result] = await localConnection.query(`
WITH inserted_products AS (
@@ -442,9 +468,11 @@ async function materializeCalculations(prodConnection, localConnection, incremen
return `(${Array.from({ length: 47 }, (_, i) => `$${base + i + 1}`).join(', ')})`;
}).join(',');
const values = batch.flatMap(row => {
const imageUrls = getImageUrls(row.pid);
return [
// Process image URLs for the batch
const processedValues = [];
for (const row of batch) {
const imageUrls = await getImageUrls(row.pid, prodConnection);
processedValues.push([
row.pid,
row.title,
row.description,
@@ -492,8 +520,10 @@ async function materializeCalculations(prodConnection, localConnection, incremen
imageUrls.image_full,
null,
null
];
});
]);
}
const values = processedValues.flat();
await localConnection.query(`
INSERT INTO temp_products (
@@ -665,9 +695,11 @@ async function importProducts(prodConnection, localConnection, incrementalUpdate
return `(${Array.from({ length: 47 }, (_, i) => `$${base + i + 1}`).join(', ')})`;
}).join(',');
const values = batch.flatMap(row => {
const imageUrls = getImageUrls(row.pid);
return [
// Process image URLs for the batch
const processedValues = [];
for (const row of batch) {
const imageUrls = await getImageUrls(row.pid, prodConnection);
processedValues.push([
row.pid,
row.title,
row.description,
@@ -715,8 +747,10 @@ async function importProducts(prodConnection, localConnection, incrementalUpdate
imageUrls.image_full,
row.options,
row.tags
];
});
]);
}
const values = processedValues.flat();
const [result] = await localConnection.query(`
WITH upserted AS (

View File

@@ -28,6 +28,27 @@ BEGIN
COALESCE(p.image_175, p.image) as image_url,
p.visible as is_visible,
p.replenishable as is_replenishable,
-- Add new product fields
p.barcode,
p.harmonized_tariff_code,
p.vendor_reference,
p.notions_reference,
p.line,
p.subline,
p.artist,
p.moq,
p.rating,
p.reviews,
p.weight,
p.length,
p.width,
p.height,
p.country_of_origin,
p.location,
p.baskets,
p.notifies,
p.preorder_count,
p.notions_inv_count,
COALESCE(p.price, 0.00) as current_price,
COALESCE(p.regular_price, 0.00) as current_regular_price,
COALESCE(p.cost_price, 0.00) as current_cost_price,
@@ -36,7 +57,6 @@ BEGIN
p.created_at,
p.first_received,
p.date_last_sold,
p.moq,
p.uom -- Assuming UOM logic is handled elsewhere or simple (e.g., 1=each)
FROM public.products p
),
@@ -185,6 +205,9 @@ BEGIN
-- Final UPSERT into product_metrics
INSERT INTO public.product_metrics (
pid, last_calculated, sku, title, brand, vendor, image_url, is_visible, is_replenishable,
barcode, harmonized_tariff_code, vendor_reference, notions_reference, line, subline, artist,
moq, rating, reviews, weight, length, width, height, country_of_origin, location,
baskets, notifies, preorder_count, notions_inv_count,
current_price, current_regular_price, current_cost_price, current_landing_cost_price,
current_stock, current_stock_cost, current_stock_retail, current_stock_gross,
on_order_qty, on_order_cost, on_order_retail, earliest_expected_date,
@@ -214,6 +237,9 @@ BEGIN
)
SELECT
ci.pid, _start_time, ci.sku, ci.title, ci.brand, ci.vendor, ci.image_url, ci.is_visible, ci.is_replenishable,
ci.barcode, ci.harmonized_tariff_code, ci.vendor_reference, ci.notions_reference, ci.line, ci.subline, ci.artist,
ci.moq, ci.rating, ci.reviews, ci.weight, ci.length, ci.width, ci.height, ci.country_of_origin, ci.location,
ci.baskets, ci.notifies, ci.preorder_count, ci.notions_inv_count,
ci.current_price, ci.current_regular_price, ci.current_cost_price, ci.current_effective_cost,
ci.current_stock, ci.current_stock * ci.current_effective_cost, ci.current_stock * ci.current_price, ci.current_stock * ci.current_regular_price,
COALESCE(ooi.on_order_qty, 0), COALESCE(ooi.on_order_cost, 0.00), COALESCE(ooi.on_order_qty, 0) * ci.current_price, ooi.earliest_expected_date,
@@ -694,6 +720,9 @@ BEGIN
ON CONFLICT (pid) DO UPDATE SET
last_calculated = EXCLUDED.last_calculated,
sku = EXCLUDED.sku, title = EXCLUDED.title, brand = EXCLUDED.brand, vendor = EXCLUDED.vendor, image_url = EXCLUDED.image_url, is_visible = EXCLUDED.is_visible, is_replenishable = EXCLUDED.is_replenishable,
barcode = EXCLUDED.barcode, harmonized_tariff_code = EXCLUDED.harmonized_tariff_code, vendor_reference = EXCLUDED.vendor_reference, notions_reference = EXCLUDED.notions_reference, line = EXCLUDED.line, subline = EXCLUDED.subline, artist = EXCLUDED.artist,
moq = EXCLUDED.moq, rating = EXCLUDED.rating, reviews = EXCLUDED.reviews, weight = EXCLUDED.weight, length = EXCLUDED.length, width = EXCLUDED.width, height = EXCLUDED.height, country_of_origin = EXCLUDED.country_of_origin, location = EXCLUDED.location,
baskets = EXCLUDED.baskets, notifies = EXCLUDED.notifies, preorder_count = EXCLUDED.preorder_count, notions_inv_count = EXCLUDED.notions_inv_count,
current_price = EXCLUDED.current_price, current_regular_price = EXCLUDED.current_regular_price, current_cost_price = EXCLUDED.current_cost_price, current_landing_cost_price = EXCLUDED.current_landing_cost_price,
current_stock = EXCLUDED.current_stock, current_stock_cost = EXCLUDED.current_stock_cost, current_stock_retail = EXCLUDED.current_stock_retail, current_stock_gross = EXCLUDED.current_stock_gross,
on_order_qty = EXCLUDED.on_order_qty, on_order_cost = EXCLUDED.on_order_cost, on_order_retail = EXCLUDED.on_order_retail, earliest_expected_date = EXCLUDED.earliest_expected_date,

View File

@@ -19,6 +19,27 @@ const COLUMN_MAP = {
imageUrl: 'pm.image_url',
isVisible: 'pm.is_visible',
isReplenishable: 'pm.is_replenishable',
// Additional Product Fields
barcode: 'pm.barcode',
harmonizedTariffCode: 'pm.harmonized_tariff_code',
vendorReference: 'pm.vendor_reference',
notionsReference: 'pm.notions_reference',
line: 'pm.line',
subline: 'pm.subline',
artist: 'pm.artist',
moq: 'pm.moq',
rating: 'pm.rating',
reviews: 'pm.reviews',
weight: 'pm.weight',
length: 'pm.length',
width: 'pm.width',
height: 'pm.height',
countryOfOrigin: 'pm.country_of_origin',
location: 'pm.location',
baskets: 'pm.baskets',
notifies: 'pm.notifies',
preorderCount: 'pm.preorder_count',
notionsInvCount: 'pm.notions_inv_count',
// Current Status
currentPrice: 'pm.current_price',
currentRegularPrice: 'pm.current_regular_price',
@@ -125,50 +146,49 @@ const COLUMN_MAP = {
status: 'pm.status'
};
// Map of column types for proper sorting
// Define column types for use in sorting/filtering
// This helps apply correct comparison operators and sorting logic
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'
// Numeric columns (use numeric operators and sorting)
numeric: [
'pid', 'currentPrice', 'currentRegularPrice', 'currentCostPrice', 'currentLandingCostPrice',
'currentStock', 'currentStockCost', 'currentStockRetail', 'currentStockGross',
'onOrderQty', 'onOrderCost', 'onOrderRetail', 'ageDays',
'sales7d', 'revenue7d', 'sales14d', 'revenue14d', 'sales30d', 'revenue30d',
'cogs30d', 'profit30d', 'returnsUnits30d', 'returnsRevenue30d', 'discounts30d',
'grossRevenue30d', 'grossRegularRevenue30d', 'stockoutDays30d', 'sales365d', 'revenue365d',
'avgStockUnits30d', 'avgStockCost30d', 'avgStockRetail30d', 'avgStockGross30d',
'receivedQty30d', 'receivedCost30d', 'lifetimeSales', 'lifetimeRevenue',
'first7DaysSales', 'first7DaysRevenue', 'first30DaysSales', 'first30DaysRevenue',
'first60DaysSales', 'first60DaysRevenue', 'first90DaysSales', 'first90DaysRevenue',
'asp30d', 'acp30d', 'avgRos30d', 'avgSalesPerDay30d', 'avgSalesPerMonth30d',
'margin30d', 'markup30d', 'gmroi30d', 'stockturn30d', 'returnRate30d', 'discountRate30d',
'stockoutRate30d', 'markdown30d', 'markdownRate30d', 'sellThrough30d', 'avgLeadTimeDays',
'salesVelocityDaily', 'configLeadTime', 'configDaysOfStock', 'configSafetyStock',
'planningPeriodDays', 'leadTimeForecastUnits', 'daysOfStockForecastUnits',
'planningPeriodForecastUnits', 'leadTimeClosingStock', 'daysOfStockClosingStock',
'replenishmentNeededRaw', 'replenishmentUnits', 'replenishmentCost', 'replenishmentRetail',
'replenishmentProfit', 'toOrderUnits', 'forecastLostSalesUnits', 'forecastLostRevenue',
'stockCoverInDays', 'poCoverInDays', 'sellsOutInDays', 'overstockedUnits',
'overstockedCost', 'overstockedRetail', 'yesterdaySales',
// New numeric columns
'moq', 'rating', 'reviews', 'weight', 'length', 'width', 'height',
'baskets', 'notifies', 'preorderCount', 'notionsInvCount'
],
// Date columns (use date operators and sorting)
date: [
'dateCreated', 'dateFirstReceived', 'dateLastReceived', 'dateFirstSold', 'dateLastSold',
'earliestExpectedDate', 'replenishDate', 'forecastedOutOfStockDate'
],
// String columns (use string operators and sorting)
string: [
'sku', 'title', 'brand', 'vendor', 'imageUrl', 'abcClass', 'status',
// New string columns
'barcode', 'harmonizedTariffCode', 'vendorReference', 'notionsReference',
'line', 'subline', 'artist', 'countryOfOrigin', 'location'
],
// Boolean columns (use boolean operators and sorting)
boolean: ['isVisible', 'isReplenishable', 'isOldStock']
};
// Special sort handling for certain columns