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:
@@ -9,6 +9,8 @@ DECLARE
|
||||
_start_time TIMESTAMPTZ := clock_timestamp(); -- Time execution started
|
||||
_last_calc_time TIMESTAMPTZ;
|
||||
_target_date DATE := CURRENT_DATE; -- Always recalculate today for simplicity with hourly runs
|
||||
_total_records INT := 0;
|
||||
_has_orders BOOLEAN := FALSE;
|
||||
BEGIN
|
||||
-- Get the timestamp before the last successful run of this module
|
||||
SELECT last_calculation_timestamp INTO _last_calc_time
|
||||
@@ -17,11 +19,48 @@ BEGIN
|
||||
|
||||
RAISE NOTICE 'Running % for date %. Start Time: %', _module_name, _target_date, _start_time;
|
||||
|
||||
-- Use CTEs to aggregate data for the target date
|
||||
-- CRITICAL FIX: Check if we have any orders or receiving activity for today
|
||||
-- to prevent creating artificial records when no real activity exists
|
||||
SELECT EXISTS (
|
||||
SELECT 1 FROM public.orders WHERE date::date = _target_date
|
||||
UNION
|
||||
SELECT 1 FROM public.purchase_orders
|
||||
WHERE date::date = _target_date
|
||||
OR EXISTS (
|
||||
SELECT 1 FROM jsonb_array_elements(receiving_history) AS rh
|
||||
WHERE jsonb_typeof(receiving_history) = 'array'
|
||||
AND (
|
||||
(rh->>'date')::date = _target_date OR
|
||||
(rh->>'received_at')::date = _target_date OR
|
||||
(rh->>'receipt_date')::date = _target_date
|
||||
)
|
||||
)
|
||||
LIMIT 1
|
||||
) INTO _has_orders;
|
||||
|
||||
-- If no orders or receiving activity found for today, log and exit
|
||||
IF NOT _has_orders THEN
|
||||
RAISE NOTICE 'No orders or receiving activity found for % - skipping daily snapshot creation', _target_date;
|
||||
|
||||
-- Still update the calculate_status to prevent repeated attempts
|
||||
UPDATE public.calculate_status
|
||||
SET last_calculation_timestamp = _start_time
|
||||
WHERE module_name = _module_name;
|
||||
|
||||
RETURN; -- Exit without creating snapshots
|
||||
END IF;
|
||||
|
||||
-- IMPORTANT: First delete any existing data for this date to prevent duplication
|
||||
DELETE FROM public.daily_product_snapshots
|
||||
WHERE snapshot_date = _target_date;
|
||||
|
||||
-- Proceed with calculating daily metrics only for products with actual activity
|
||||
WITH SalesData AS (
|
||||
SELECT
|
||||
p.pid,
|
||||
p.sku,
|
||||
-- Track number of orders to ensure we have real data
|
||||
COUNT(o.id) as order_count,
|
||||
-- Aggregate Sales (Quantity > 0, Status not Canceled/Returned)
|
||||
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
|
||||
@@ -37,10 +76,13 @@ BEGIN
|
||||
ON p.pid = o.pid
|
||||
AND o.date::date = _target_date -- Cast to date to ensure compatibility regardless of original type
|
||||
GROUP BY p.pid, p.sku
|
||||
HAVING COUNT(o.id) > 0 -- CRITICAL: Only include products with actual orders
|
||||
),
|
||||
ReceivingData AS (
|
||||
SELECT
|
||||
po.pid,
|
||||
-- Track number of POs to ensure we have real data
|
||||
COUNT(po.po_id) as po_count,
|
||||
-- Prioritize the actual table fields over the JSON data
|
||||
COALESCE(
|
||||
-- First try the received field from purchase_orders table
|
||||
@@ -89,6 +131,15 @@ BEGIN
|
||||
jsonb_typeof(po.receiving_history) = 'array' AND
|
||||
jsonb_array_length(po.receiving_history) > 0
|
||||
GROUP BY po.pid
|
||||
-- CRITICAL: Only include products with actual receiving activity
|
||||
HAVING COUNT(po.po_id) > 0 OR SUM(
|
||||
CASE
|
||||
WHEN (rh.item->>'date')::date = _target_date THEN (rh.item->>'qty')::numeric
|
||||
WHEN (rh.item->>'received_at')::date = _target_date THEN (rh.item->>'qty')::numeric
|
||||
WHEN (rh.item->>'receipt_date')::date = _target_date THEN (rh.item->>'qty')::numeric
|
||||
ELSE 0
|
||||
END
|
||||
) > 0
|
||||
),
|
||||
CurrentStock AS (
|
||||
-- Select current stock values directly from products table
|
||||
@@ -100,7 +151,7 @@ BEGIN
|
||||
COALESCE(regular_price, 0.00) as current_regular_price
|
||||
FROM public.products
|
||||
)
|
||||
-- Upsert into the daily snapshots table
|
||||
-- Now insert records, but ONLY for products with actual activity
|
||||
INSERT INTO public.daily_product_snapshots (
|
||||
snapshot_date,
|
||||
pid,
|
||||
@@ -125,8 +176,8 @@ BEGIN
|
||||
)
|
||||
SELECT
|
||||
_target_date AS snapshot_date,
|
||||
p.pid,
|
||||
p.sku,
|
||||
COALESCE(sd.pid, rd.pid) AS pid, -- Use sales or receiving PID
|
||||
COALESCE(sd.sku, p.sku) AS sku, -- Get SKU from sales data or products table
|
||||
-- Inventory Metrics (Using CurrentStock)
|
||||
cs.stock_quantity AS eod_stock_quantity,
|
||||
cs.stock_quantity * cs.effective_cost_price AS eod_stock_cost,
|
||||
@@ -147,31 +198,15 @@ BEGIN
|
||||
COALESCE(rd.units_received, 0),
|
||||
COALESCE(rd.cost_received, 0.00),
|
||||
_start_time -- Timestamp of this calculation run
|
||||
FROM public.products p
|
||||
LEFT JOIN CurrentStock cs ON p.pid = cs.pid
|
||||
LEFT JOIN SalesData sd ON p.pid = sd.pid
|
||||
LEFT JOIN ReceivingData rd ON p.pid = rd.pid
|
||||
WHERE p.pid IS NOT NULL -- Ensure we only insert for existing products
|
||||
FROM SalesData sd
|
||||
FULL OUTER JOIN ReceivingData rd ON sd.pid = rd.pid
|
||||
LEFT JOIN public.products p ON COALESCE(sd.pid, rd.pid) = p.pid
|
||||
LEFT JOIN CurrentStock cs ON COALESCE(sd.pid, rd.pid) = cs.pid
|
||||
WHERE p.pid IS NOT NULL; -- Ensure we only insert for existing products
|
||||
|
||||
ON CONFLICT (snapshot_date, pid) DO UPDATE SET
|
||||
sku = EXCLUDED.sku,
|
||||
eod_stock_quantity = EXCLUDED.eod_stock_quantity,
|
||||
eod_stock_cost = EXCLUDED.eod_stock_cost,
|
||||
eod_stock_retail = EXCLUDED.eod_stock_retail,
|
||||
eod_stock_gross = EXCLUDED.eod_stock_gross,
|
||||
stockout_flag = EXCLUDED.stockout_flag,
|
||||
units_sold = EXCLUDED.units_sold,
|
||||
units_returned = EXCLUDED.units_returned,
|
||||
gross_revenue = EXCLUDED.gross_revenue,
|
||||
discounts = EXCLUDED.discounts,
|
||||
returns_revenue = EXCLUDED.returns_revenue,
|
||||
net_revenue = EXCLUDED.net_revenue,
|
||||
cogs = EXCLUDED.cogs,
|
||||
gross_regular_revenue = EXCLUDED.gross_regular_revenue,
|
||||
profit = EXCLUDED.profit,
|
||||
units_received = EXCLUDED.units_received,
|
||||
cost_received = EXCLUDED.cost_received,
|
||||
calculation_timestamp = EXCLUDED.calculation_timestamp; -- Use the timestamp from this run
|
||||
-- Get the total number of records inserted
|
||||
GET DIAGNOSTICS _total_records = ROW_COUNT;
|
||||
RAISE NOTICE 'Created % daily snapshot records for % with sales/receiving activity', _total_records, _target_date;
|
||||
|
||||
-- Update the status table with the timestamp from the START of this run
|
||||
UPDATE public.calculate_status
|
||||
|
||||
Reference in New Issue
Block a user