diff --git a/README.md b/README.md index 640a4b7..a3d8336 100644 --- a/README.md +++ b/README.md @@ -82,3 +82,4 @@ ssh -nNTvL 5432:fsmi-db.fsmi.org:5432 fsmi-login.fsmi.uni-karlsruhe.de - [x] Figure out/Add documentation about building `entry.js` - [ ] Clean up the code a little and add some comments - [ ] Needs good documentation for maintainability +- [ ] Use cool new function for deactivating items diff --git a/jon/db/add_views.sql b/jon/db/add_views.sql index 63b898c..81d6094 100644 --- a/jon/db/add_views.sql +++ b/jon/db/add_views.sql @@ -59,7 +59,6 @@ FROM garfield.inventory_items ORDER BY inventory_items.name; -- How many *other* active inventory lines exist with the same barcode in the same location that are newer? - CREATE TEMPORARY VIEW more_recent_inventory_lines_with_same_barcode AS SELECT a.item_id, @@ -74,3 +73,41 @@ LEFT JOIN garfield.inventory_items AS b AND b.available AND b.bought > a.bought GROUP BY a.item_id; + +-- We need to create this table so that we can put an index on it +-- Otherwise the join in the consumption graph query becomes much slower +-- Perhaps it would be nicer to use a materialized view instead +DROP TABLE IF EXISTS last_n_days; +CREATE TEMPORARY TABLE last_n_days AS ( + SELECT + generate_series(now() - interval '14 days', now(), interval '1 day')::date AS sale_date +); +CREATE UNIQUE INDEX last_n_days_sale_date ON last_n_days (sale_date); + +-- Get an array of how often items were sold over the last 14 days +CREATE TEMPORARY VIEW inventory_last_n_days_sales AS +WITH +sales_by_date AS ( + SELECT + inventory_line AS item_id, + date_trunc('day', snack_sales_log_timestamp AT TIME ZONE 'UTC+1') AS sale_date, + count(*)::int AS sales + FROM garfield.snack_sales_log + GROUP BY item_id, sale_date +), +beeg AS ( + SELECT item_id, sale_date, count(snack_sales_log_timestamp)::int AS sales + FROM garfield.inventory_items + CROSS JOIN last_n_days + LEFT JOIN garfield.snack_sales_log + ON inventory_line = item_id +-- snack_sales_log has an index on snack_sales_log_timestamp to speed up this query +-- If that index doesn't exist the query takes much longer. + AND sale_date = date_trunc('day', snack_sales_log_timestamp AT TIME ZONE 'UTC+1') + WHERE available + GROUP BY item_id, sale_date + ORDER BY item_id, sale_date +) +SELECT item_id, array_agg(sales) AS last_n_days_sales +FROM beeg +GROUP BY item_id diff --git a/jon/db/get_inventory_overview.sql b/jon/db/get_inventory_overview.sql index 6c03a21..2c08ed5 100644 --- a/jon/db/get_inventory_overview.sql +++ b/jon/db/get_inventory_overview.sql @@ -2,6 +2,7 @@ SELECT * FROM all_inventory_item_overview LEFT JOIN more_recent_inventory_lines_with_same_barcode USING (item_id) +LEFT JOIN inventory_last_n_days_sales USING (item_id) WHERE (%(location_id)s IS NULL OR location = %(location_id)s) AND available ORDER BY diff --git a/jon/static/jon.css b/jon/static/jon.css index 9f92248..66dde1c 100644 --- a/jon/static/jon.css +++ b/jon/static/jon.css @@ -74,3 +74,7 @@ th { details { font-size: 0.8em; } +.consumption-graph { + display: block; + height: 1em; +} diff --git a/jon/templates/inventory/index.html b/jon/templates/inventory/index.html index ce6164e..c488fb7 100644 --- a/jon/templates/inventory/index.html +++ b/jon/templates/inventory/index.html @@ -1,3 +1,26 @@ +{% macro consumption_graph_svg(values) -%} +{% set stroke_width = 8 %} +{% set width = 300 %} +{% set height = 100 %} +{% set padding = 4 %} +{% set dx = (width - 2 * padding) / ((values | length) + 1) %} +{% set dy = (height - 2 * padding) / ((values + [1]) | max) %} + + + +{% endmacro -%} + {% extends "base.html" %} {% block content %} @@ -5,6 +28,7 @@ Stat ID + Graph Barcode Name Preis (Netto) @@ -23,6 +47,7 @@ {% if item.other_lines_count != 0 %}🔄{% endif %} {{ item.item_id }} + {{ consumption_graph_svg(item.last_n_days_sales) }} {{ item.item_barcode }} {{ item.name }} {{ format_currency(item.unit_price) }}