diff --git a/controllers/StockReportsController.php b/controllers/StockReportsController.php new file mode 100644 index 00000000..1c78eb34 --- /dev/null +++ b/controllers/StockReportsController.php @@ -0,0 +1,71 @@ +getQueryParams()['start_date']) && isset($request->getQueryParams()['end_date']) && IsIsoDate($request->getQueryParams()['start_date']) && IsIsoDate($request->getQueryParams()['end_date'])) + { + $startDate = $request->getQueryParams()['start_date']; + $endDate = $request->getQueryParams()['end_date']; + $where = "pph.purchased_date BETWEEN '$startDate' AND '$endDate'"; + } + else + { + // Default to this month + $where = "pph.purchased_date >= DATE(DATE('now', 'localtime'), 'start of month')"; + } + + + if (isset($request->getQueryParams()['byGroup'])) + { + $sql = " + SELECT + pg.id AS id, + pg.name AS name, + SUM(pph.amount * pph.price) AS total + FROM product_price_history pph + JOIN products p + ON pph.product_id = p.id + JOIN product_groups pg + ON p.product_group_id = pg.id + WHERE $where + GROUP BY pg.id + ORDER BY pg.NAME COLLATE NOCASE + "; + } + else + { + if (isset($request->getQueryParams()['product_group']) and $request->getQueryParams()['product_group'] != 'all') + { + $where .= ' AND pg.id = ' . $request->getQueryParams()['product_group']; + } + + $sql = " + SELECT + p.id AS id, + p.name AS name, + pg.id AS group_id, + pg.name AS group_name, + SUM(pph.amount * pph.price) AS total + FROM product_price_history pph + JOIN products p + ON pph.product_id = p.id + JOIN product_groups pg + ON p.product_group_id = pg.id + WHERE $where + GROUP BY p.id + ORDER BY p.NAME COLLATE NOCASE + "; + } + + return $this->renderPage($response, 'stockreportspendings', [ + 'metrics' => $this->getDatabaseService()->ExecuteDbQuery($sql)->fetchAll(\PDO::FETCH_OBJ), + 'productGroups' => $this->getDatabase()->product_groups()->orderBy('name', 'COLLATE NOCASE'), + 'selectedGroup' => isset($request->getQueryParams()['product_group']) ? $request->getQueryParams()['product_group'] : null, + 'byGroup' => isset($request->getQueryParams()['byGroup']) ? $request->getQueryParams()['byGroup'] : null + ]); + } +} diff --git a/localization/demo_data.pot b/localization/demo_data.pot index 5d1c2ca8..c4e24687 100644 --- a/localization/demo_data.pot +++ b/localization/demo_data.pot @@ -388,3 +388,18 @@ msgstr[1] "" msgid "Romanian" msgstr "" + +msgid "Pint" +msgstr "" + +msgid "Beverages" +msgstr "" + +msgid "Ice Cream" +msgstr "" + +msgid "Soda" +msgstr "" + +msgid "Beer" +msgstr "" diff --git a/localization/strings.pot b/localization/strings.pot index fcc0b034..473adf16 100644 --- a/localization/strings.pot +++ b/localization/strings.pot @@ -2374,3 +2374,39 @@ msgstr "" msgid "Track chore execution now" msgstr "" + +msgid "Total" +msgstr "" + +msgid "Apply" +msgstr "" + +msgid "Custom range" +msgstr "" + +msgid "Yesterday" +msgstr "" + +msgid "Last %1$s days" +msgstr "" + +msgid "This month" +msgstr "" + +msgid "Last month" +msgstr "" + +msgid "This year" +msgstr "" + +msgid "Last year" +msgstr "" + +msgid "Reports" +msgstr "" + +msgid "Spendings" +msgstr "" + +msgid "Stock report" +msgstr "" diff --git a/migrations/0216.sql b/migrations/0216.sql new file mode 100644 index 00000000..dd08cb0d --- /dev/null +++ b/migrations/0216.sql @@ -0,0 +1,25 @@ +DROP VIEW product_price_history; +CREATE VIEW product_price_history +AS +SELECT + sl.product_id AS id, -- Dummy, LessQL needs an id column + sl.product_id, + sl.price, + sl.amount, + sl.purchased_date, + sl.shopping_location_id +FROM stock_log sl +WHERE sl.transaction_type IN ('purchase', 'inventory-correction', 'stock-edit-new') + AND sl.undone = 0 + AND IFNULL(sl.price, 0) > 0 + AND IFNULL(sl.amount, 0) > 0 + AND sl.id NOT IN ( + -- These are edited purchase and inventory-correction rows + SELECT sl_origin.id + FROM stock_log sl_origin + JOIN stock_log sl_edit + ON sl_origin.stock_id = sl_edit.stock_id + AND sl_edit.transaction_type = 'stock-edit-new' + AND sl_edit.id > sl_origin.id + WHERE sl_origin.transaction_type IN ('purchase', 'inventory-correction') + ); diff --git a/package.json b/package.json index f9233c4c..6f9cd97b 100644 --- a/package.json +++ b/package.json @@ -12,6 +12,9 @@ "bootstrap-select": "^1.13.18", "bwip-js": "^3.0.1", "chart.js": "^2.8.0", + "chartjs-plugin-colorschemes": "^0.4.0", + "chartjs-plugin-doughnutlabel": "^2.0.3", + "chartjs-plugin-piechart-outlabels": "^0.1.4", "datatables.net": "^1.10.22", "datatables.net-bs4": "^1.10.22", "datatables.net-colreorder": "^1.5.2", @@ -21,6 +24,7 @@ "datatables.net-rowgroup-bs4": "^1.1.2", "datatables.net-select": "^1.3.1", "datatables.net-select-bs4": "^1.3.1", + "daterangepicker": "^3.1.0", "fullcalendar": "^3.10.1", "gettext-translator": "2.1.0", "jquery": "^3.6.0", diff --git a/public/viewjs/stockreportspendings.js b/public/viewjs/stockreportspendings.js new file mode 100644 index 00000000..bb332bcf --- /dev/null +++ b/public/viewjs/stockreportspendings.js @@ -0,0 +1,145 @@ +var labels = []; +var data = []; +var totalAmount = 0.0; +$("#metrics-table tbody tr").each(function() +{ + var self = $(this); + labels.push(self.find("td:eq(0)").attr("data-chart-label")); + var itemTotal = Number.parseFloat(self.find("td:eq(1)").attr("data-chart-value")); + data.push(itemTotal); + totalAmount += + itemTotal; +}); +totalAmount = totalAmount.toLocaleString(undefined, { style: "currency", currency: Grocy.Currency }); + +var backgroundColors = []; +var colorChoiceIndex = 0; +for (i = 0; i < data.length; i++) +{ + if (i + 1 == Chart.colorschemes.brewer.Paired12.length) + { + // Restart background color choices + colorChoiceIndex = 1; + } + backgroundColors.push(Chart.colorschemes.brewer.Paired12[colorChoiceIndex]); + colorChoiceIndex++; +} + +var metricsChart = new Chart("metrics-chart", { + "type": "outlabeledDoughnut", + "options": { + "legend": { + "display": false + }, + "tooltips": { + "enabled": false + }, + "tooltips": { + "enabled": false + }, + "plugins": { + "outlabels": { + "text": "%l %p", + "backgroundColor": "#343a40", + "font": { + "minSize": 12, + "maxSize": 18 + } + }, + "doughnutlabel": { + "labels": [ + { + "text": totalAmount, + "font": { + "size": 24, + "weight": "bold" + }, + }, + { + "text": __t("Total") + } + ] + } + } + }, + "data": { + "labels": labels, + "datasets": [{ + "data": data, + "backgroundColor": backgroundColors + }] + } +}); + + +var metricsTable = $("#metrics-table").DataTable({ + "columnDefs": [ + { "type": "num", "targets": 1 } + ].concat($.fn.dataTable.defaults.columnDefs) +}); +$("#metrics-table tbody").removeClass("d-none"); +metricsTable.columns.adjust().draw(); + +var startDate = moment().startOf("month").format("YYYY-MM-DD"); +var endDate = moment().endOf("month").format("YYYY-MM-DD"); +if (GetUriParam("start_date")) +{ + startDate = moment(GetUriParam("start_date")); +} +if (GetUriParam("end_date")) +{ + endDate = moment(GetUriParam("end_date")); +} + +var ranges = {}; +ranges[__t("Today")] = [moment(), moment()]; +ranges[__t("Yesterday")] = [moment().subtract(1, "days"), moment().subtract(1, "days")]; +ranges[__t("Last %1$s days", "7")] = [moment().subtract(6, "days"), moment()]; +ranges[__t("Last %1$s days", "14")] = [moment().subtract(13, "days"), moment()]; +ranges[__t("Last %1$s days", "30")] = [moment().subtract(29, "days"), moment()]; +ranges[__t("This month")] = [moment().startOf("month"), moment().endOf("month")]; +ranges[__t("Last month")] = [moment().subtract(1, "month").startOf("month"), moment().subtract(1, "month").endOf("month")]; +ranges[__t("This year")] = [moment().startOf("year"), moment().endOf("year")]; +ranges[__t("Last year")] = [moment().subtract(1, "year").startOf("year"), moment().subtract(1, "year").endOf("year")]; + +$("#daterange-filter").daterangepicker({ + "showDropdowns": true, + "alwaysShowCalendars": true, + "buttonClasses": "btn", + "applyButtonClasses": "btn-primary", + "cancelButtonClasses": "btn-secondary", + "startDate": startDate, + "endDate": endDate, + "showWeekNumbers": Grocy.CalendarShowWeekNumbers, + "locale": { + "format": "YYYY-MM-DD", + "firstDay": Grocy.CalendarFirstDayOfWeek + }, + "applyLabel": __t("Apply"), + "cancelLabel": __t("Cancel"), + "customRangeLabel": __t("Custom range"), + "ranges": ranges +}, function(start, end, label) +{ + UpdateUriParam("start_date", start.format("YYYY-MM-DD")); + UpdateUriParam("end_date", end.format("YYYY-MM-DD")) + window.location.reload(); +}); + +$("#daterange-filter").on("cancel.daterangepicker", function(ev, picker) +{ + $(this).val(startDate + " - " + endDate); +}); + +$("#clear-filter-button").on("click", function() +{ + RemoveUriParam("start_date"); + RemoveUriParam("end_date"); + RemoveUriParam("product_group"); + window.location.reload(); +}); + +$("#product-group-filter").on("change", function() +{ + UpdateUriParam("product_group", $(this).val()); + window.location.reload(); +}); diff --git a/routes.php b/routes.php index b0b2710d..aa73dbdf 100644 --- a/routes.php +++ b/routes.php @@ -63,6 +63,8 @@ $app->group('', function (RouteCollectorProxy $group) { $group->get('/stockentry/{entryId}/grocycode', '\Grocy\Controllers\StockController:StockEntryGrocycodeImage'); $group->get('/stockentry/{entryId}/label', '\Grocy\Controllers\StockController:StockEntryGrocycodeLabel'); $group->get('/quantityunitconversionsresolved', '\Grocy\Controllers\StockController:QuantityUnitConversionsResolved'); + + $group->get('/stockreports/spendings', '\Grocy\Controllers\StockReportsController:Spendings'); } // Stock price tracking diff --git a/services/DemoDataGeneratorService.php b/services/DemoDataGeneratorService.php index c057b7b6..814c4d63 100644 --- a/services/DemoDataGeneratorService.php +++ b/services/DemoDataGeneratorService.php @@ -66,6 +66,8 @@ class DemoDataGeneratorService extends BaseService INSERT INTO quantity_units (id, name, name_plural) VALUES (12, '{$this->__n_sql(1, 'Slice', 'Slices')}', '{$this->__n_sql(2, 'Slice', 'Slices')}'); --12 DELETE FROM quantity_units WHERE name = '{$this->__t_sql('Kilogram')}'; INSERT INTO quantity_units (id, name, name_plural) VALUES (13, '{$this->__n_sql(1, 'Kilogram', 'Kilograms')}', '{$this->__n_sql(2, 'Kilogram', 'Kilograms')}'); --13 + DELETE FROM quantity_units WHERE name = '{$this->__t_sql('Pint')}'; + INSERT INTO quantity_units (id, name, name_plural) VALUES (14, '{$this->__n_sql(1, 'Pint', 'Pints')}', '{$this->__n_sql(2, 'Pint', 'Pint')}'); --14 INSERT INTO product_groups(name) VALUES ('01 {$this->__t_sql('Sweets')}'); --1 INSERT INTO product_groups(name) VALUES ('02 {$this->__t_sql('Bakery products')}'); --2 @@ -73,13 +75,14 @@ class DemoDataGeneratorService extends BaseService INSERT INTO product_groups(name) VALUES ('04 {$this->__t_sql('Butchery products')}'); --4 INSERT INTO product_groups(name) VALUES ('05 {$this->__t_sql('Vegetables/Fruits')}'); --5 INSERT INTO product_groups(name) VALUES ('06 {$this->__t_sql('Refrigerated products')}'); --6 + INSERT INTO product_groups(name) VALUES ('07 {$this->__t_sql('Beverages')}'); --7' DELETE FROM sqlite_sequence WHERE name = 'products'; --Just to keep IDs in order as mentioned here... INSERT INTO products (name, location_id, qu_id_purchase, qu_id_stock, min_stock_amount, product_group_id, picture_file_name) VALUES ('{$this->__t_sql('Cookies')}', 4, 3, 3, 8, 1, 'cookies.jpg'); --1 INSERT INTO products (name, location_id, qu_id_purchase, qu_id_stock, min_stock_amount, product_group_id, cumulate_min_stock_amount_of_sub_products) VALUES ('{$this->__t_sql('Chocolate')}', 4, 3, 3, 8, 1, 1); --2 INSERT INTO products (name, location_id, qu_id_purchase, qu_id_stock, min_stock_amount, product_group_id, picture_file_name) VALUES ('{$this->__t_sql('Gummy bears')}', 4, 3, 3, 8, 1, 'gummybears.jpg'); --3 INSERT INTO products (name, location_id, qu_id_purchase, qu_id_stock, min_stock_amount, product_group_id) VALUES ('{$this->__t_sql('Crisps')}', 4, 3, 3, 10, 1); --4 - INSERT INTO products (name, location_id, qu_id_purchase, qu_id_stock, product_group_id) VALUES ('{$this->__t_sql('Eggs')}', 2, 3, 2, 5); --5 + INSERT INTO products (name, location_id, qu_id_purchase, qu_id_stock, product_group_id) VALUES ('{$this->__t_sql('Eggs')}', 2, 3, 2, 6); --5 INSERT INTO products (name, location_id, qu_id_purchase, qu_id_stock, product_group_id) VALUES ('{$this->__t_sql('Noodles')}', 3, 3, 3, 6); --6 INSERT INTO products (name, location_id, qu_id_purchase, qu_id_stock, product_group_id) VALUES ('{$this->__t_sql('Pickles')}', 5, 4, 4, 3); --7 INSERT INTO products (name, location_id, qu_id_purchase, qu_id_stock, product_group_id) VALUES ('{$this->__t_sql('Gulash soup')}', 5, 5, 5, 3); --8 @@ -101,6 +104,10 @@ class DemoDataGeneratorService extends BaseService INSERT INTO products (name, location_id, qu_id_purchase, qu_id_stock, product_group_id, parent_product_id) VALUES ('{$this->__t_sql('Milk Chocolate')}', 4, 3, 3, 1, 2); --24 INSERT INTO products (name, location_id, qu_id_purchase, qu_id_stock, product_group_id, parent_product_id) VALUES ('{$this->__t_sql('Dark Chocolate')}', 4, 3, 3, 1, 2); --25 INSERT INTO products (name, location_id, qu_id_purchase, qu_id_stock, product_group_id) VALUES ('{$this->__t_sql('Waffle rolls')}', 4, 3, 3, 1); --26 + INSERT INTO products (name, location_id, qu_id_purchase, qu_id_stock, product_group_id) VALUES ('{$this->__t_sql('Ice Cream')}', 6, 14, 14, 1); --27 + INSERT INTO products (name, location_id, qu_id_purchase, qu_id_stock, product_group_id) VALUES ('{$this->__t_sql('Soda')}', 2, 6, 6, 7); --28 + INSERT INTO products (name, location_id, qu_id_purchase, qu_id_stock, product_group_id) VALUES ('{$this->__t_sql('Beer')}', 2, 6, 6, 7); --29 + UPDATE products SET calories = 123 WHERE IFNULL(calories, 0) = 0; INSERT INTO product_barcodes (product_id, barcode) VALUES (8, '22111968'); @@ -289,6 +296,16 @@ class DemoDataGeneratorService extends BaseService $stockService->AddProduct(24, 2, date('Y-m-d', strtotime('+180 days')), StockService::TRANSACTION_TYPE_PURCHASE, date('Y-m-d', strtotime('-10 days')), $this->RandomPrice(), null, $this->NextSupermarketId(), $stockTransactionId); $stockService->AddProduct(25, 2, date('Y-m-d', strtotime('+180 days')), StockService::TRANSACTION_TYPE_PURCHASE, date('Y-m-d', strtotime('-10 days')), $this->RandomPrice(), null, $this->NextSupermarketId(), $stockTransactionId); $stockService->AddProduct(2, 1, date('Y-m-d', strtotime('+180 days')), StockService::TRANSACTION_TYPE_PURCHASE, date('Y-m-d', strtotime('-10 days')), $this->RandomPrice(), null, $this->NextSupermarketId(), $stockTransactionId); + $stockService->AddProduct(27, 1, date('Y-m-d', strtotime('+30 days')), StockService::TRANSACTION_TYPE_PURCHASE, date('Y-m-d', strtotime('now')), $this->RandomPrice(), null, $this->NextSupermarketId(), $stockTransactionId); + $stockService->AddProduct(23, 1, date('Y-m-d', strtotime('+60 days')), StockService::TRANSACTION_TYPE_PURCHASE, date('Y-m-d', strtotime('now')), $this->RandomPrice(), null, $this->NextSupermarketId(), $stockTransactionId); + $stockService->AddProduct(27, 1, date('Y-m-d', strtotime('+30 days')), StockService::TRANSACTION_TYPE_PURCHASE, date('Y-m-d', strtotime('-2 weeks')), $this->RandomPrice(), null, $this->NextSupermarketId(), $stockTransactionId); + $stockService->AddProduct(27, 1, date('Y-m-d', strtotime('+30 days')), StockService::TRANSACTION_TYPE_PURCHASE, date('Y-m-d', strtotime('-3 weeks')), $this->RandomPrice(), null, $this->NextSupermarketId(), $stockTransactionId); + $stockService->AddProduct(28, 12, date('Y-m-d', strtotime('+180 days')), StockService::TRANSACTION_TYPE_PURCHASE, date('Y-m-d', strtotime('-1 weeks')), $this->RandomPrice(), null, $this->NextSupermarketId(), $stockTransactionId); + $stockService->AddProduct(29, 12, date('Y-m-d', strtotime('+365 days')), StockService::TRANSACTION_TYPE_PURCHASE, date('Y-m-d', strtotime('-2 weeks')), $this->RandomPrice(), null, $this->NextSupermarketId(), $stockTransactionId); + $stockService->AddProduct(5, 1, date('Y-m-d', strtotime('+1 days')), StockService::TRANSACTION_TYPE_PURCHASE, date('Y-m-d', strtotime('-1 days')), $this->RandomPrice(), null, $this->NextSupermarketId(), $stockTransactionId); + $stockService->AddProduct(1, 12, date('Y-m-d', strtotime('+180 days')), StockService::TRANSACTION_TYPE_PURCHASE, date('Y-m-d', strtotime('-1 days')), $this->RandomPrice(), null, $this->NextSupermarketId(), $stockTransactionId); + $stockService->AddProduct(2, 12, date('Y-m-d', strtotime('+365 days')), StockService::TRANSACTION_TYPE_PURCHASE, date('Y-m-d', strtotime('-1 days')), $this->RandomPrice(), null, $this->NextSupermarketId(), $stockTransactionId); + $stockService->AddMissingProductsToShoppingList(); $stockService->OpenProduct(3, 1); $stockService->OpenProduct(6, 1); diff --git a/views/stockoverview.blade.php b/views/stockoverview.blade.php index f385f86f..6fbd0ae0 100755 --- a/views/stockoverview.blade.php +++ b/views/stockoverview.blade.php @@ -46,6 +46,19 @@ {{ $__t('Location Content Sheet') }} @endif + @if(GROCY_FEATURE_FLAG_STOCK_PRICE_TRACKING) +
+ @endif{{ $__t('Name') }} | +{{ $__t('Total') }} | + @if(!$byGroup) +{{ $__t('Product group') }} | + @endif +
---|---|---|
+ {{ $metric->name }} + | ++ {{ $metric->total }} + | + @if(!$byGroup) ++ {{ $metric->group_name }} + | + @endif +