jon/jon/db/get_inventory_report.sql
Paul Brinkmeier 1a34486a84 Update report
Report now has a 'total' column next to the 'inventory' column.

Also, for items that are not empty yet we use the current time instead of the most recent sale to estimate time until empty.
2023-08-18 00:14:11 +02:00

50 lines
1.3 KiB
SQL

WITH
most_recent_sales AS (
SELECT DISTINCT ON (inventory_line)
inventory_line, snack_sales_log_id, snack_sales_log_timestamp AS most_recent_sale
FROM garfield.snack_sales_log
ORDER BY inventory_line ASC, snack_sales_log_timestamp DESC
),
enhanced_overview1 AS (
SELECT
inventory_items.item_id,
inventory_items.item_barcode,
inventory_items.name,
units_left,
inventory_items.sales_units,
correction_delta,
location_name,
location,
CASE
WHEN snack_sales_log_id IS NULL THEN 0
ELSE sales / (EXTRACT(EPOCH FROM (
CASE
WHEN units_left <= 0 THEN most_recent_sale
ELSE NOW()
END
)) - EXTRACT(EPOCH FROM bought)) * 24 * 3600
END AS per_day
FROM garfield.inventory_item_overview
LEFT JOIN garfield.inventory_items USING (item_id)
LEFT JOIN most_recent_sales ON item_id = inventory_line
),
enhanced_overview2 AS (
SELECT
*,
CASE
WHEN per_day = 0 THEN NULL
ELSE GREATEST(0, units_left / per_day)
END AS days_left
FROM enhanced_overview1
)
SELECT
*,
CASE
WHEN days_left IS NULL THEN NULL
ELSE GREATEST(0, (60 - days_left) * per_day)
END AS for_two_months
FROM enhanced_overview2
WHERE (%(location_id)s IS NULL OR location = %(location_id)s)
ORDER BY days_left ASC, per_day DESC