grocy/migrations/0136.sql
Bernd Bestel 91d8eaeb74
Squashed commit
Improve journal pages loading time (new date range filter)
Various small style adjustments (meal plan page and others)
Pulled German translations from Transifex
Show the shopping list total value (closes #1309)
Make it possible to copy recipes (closes #714)
Implemented optional "auto decimal separator for price inputs" (closes #1345)
Removed table grouped column fixed order restriction (closes #1402)
Don't filter out style, class, id attributes of html text (closes #1298)
Added product picture as column on the stock overview page (closes #1283)
Added grocycodes also for chores and batteries (+ camera barcode scanning for /choretracking and /batterytracking, this now closes #221)
2021-07-13 19:29:23 +02:00

120 lines
4.6 KiB
SQL

DROP VIEW uihelper_stock_current_overview_including_opened;
CREATE VIEW uihelper_stock_current_overview_including_opened
AS
SELECT
p.id,
sc.amount_opened AS amount_opened,
p.tare_weight AS tare_weight,
p.enable_tare_weight_handling AS enable_tare_weight_handling,
sc.amount AS amount,
sc.value as value,
sc.product_id AS product_id,
sc.best_before_date AS best_before_date,
EXISTS(SELECT id FROM stock_missing_products_including_opened WHERE id = sc.product_id) AS product_missing,
(SELECT name FROM quantity_units WHERE quantity_units.id = p.qu_id_stock) AS qu_unit_name,
(SELECT name_plural FROM quantity_units WHERE quantity_units.id = p.qu_id_stock) AS qu_unit_name_plural,
p.name AS product_name,
(SELECT name FROM product_groups WHERE product_groups.id = p.product_group_id) AS product_group_name,
EXISTS(SELECT * FROM shopping_list WHERE shopping_list.product_id = sc.product_id) AS on_shopping_list,
(SELECT name FROM quantity_units WHERE quantity_units.id = p.qu_id_purchase) AS qu_purchase_unit_name,
(SELECT name_plural FROM quantity_units WHERE quantity_units.id = p.qu_id_purchase) AS qu_purchase_unit_name_plural,
sc.is_aggregated_amount,
sc.amount_opened_aggregated,
sc.amount_aggregated,
p.calories AS product_calories,
sc.amount * p.calories AS calories,
sc.amount_aggregated * p.calories AS calories_aggregated,
p.quick_consume_amount,
p.due_type,
plp.purchased_date AS last_purchased,
plp.price AS last_price,
p.min_stock_amount,
pbcs.barcodes AS product_barcodes,
p.description as product_description,
l.name AS product_default_location_name,
p_parent.id AS parent_product_id,
p_parent.name AS parent_product_name,
p.picture_file_name AS product_picture_file_name
FROM (
SELECT *
FROM stock_current
WHERE best_before_date IS NOT NULL
UNION
SELECT m.id, 0, 0, 0, null, 0, 0, 0, p.due_type
FROM stock_missing_products_including_opened m
JOIN products p
ON m.id = p.id
WHERE m.id NOT IN (SELECT product_id FROM stock_current)
) sc
LEFT JOIN products_last_purchased plp
ON sc.product_id = plp.product_id
LEFT JOIN products p
ON sc.product_id = p.id
LEFT JOIN product_barcodes_comma_separated pbcs
ON sc.product_id = pbcs.product_id
LEFT JOIN products p_parent
ON p.parent_product_id = p_parent.id
LEFT JOIN locations l
ON p.location_id = l.id
WHERE p.hide_on_stock_overview = 0;
DROP VIEW uihelper_stock_current_overview;
CREATE VIEW uihelper_stock_current_overview
AS
SELECT
p.id,
sc.amount_opened AS amount_opened,
p.tare_weight AS tare_weight,
p.enable_tare_weight_handling AS enable_tare_weight_handling,
sc.amount AS amount,
sc.value as value,
sc.product_id AS product_id,
sc.best_before_date AS best_before_date,
EXISTS(SELECT id FROM stock_missing_products WHERE id = sc.product_id) AS product_missing,
(SELECT name FROM quantity_units WHERE quantity_units.id = p.qu_id_stock) AS qu_unit_name,
(SELECT name_plural FROM quantity_units WHERE quantity_units.id = p.qu_id_stock) AS qu_unit_name_plural,
p.name AS product_name,
(SELECT name FROM product_groups WHERE product_groups.id = p.product_group_id) AS product_group_name,
EXISTS(SELECT * FROM shopping_list WHERE shopping_list.product_id = sc.product_id) AS on_shopping_list,
(SELECT name FROM quantity_units WHERE quantity_units.id = p.qu_id_purchase) AS qu_purchase_unit_name,
(SELECT name_plural FROM quantity_units WHERE quantity_units.id = p.qu_id_purchase) AS qu_purchase_unit_name_plural,
sc.is_aggregated_amount,
sc.amount_opened_aggregated,
sc.amount_aggregated,
p.calories AS product_calories,
sc.amount * p.calories AS calories,
sc.amount_aggregated * p.calories AS calories_aggregated,
p.quick_consume_amount,
p.due_type,
plp.purchased_date AS last_purchased,
plp.price AS last_price,
p.min_stock_amount,
pbcs.barcodes AS product_barcodes,
p.description AS product_description,
l.name AS product_default_location_name,
p_parent.id AS parent_product_id,
p_parent.name AS parent_product_name,
p.picture_file_name AS product_picture_file_name
FROM (
SELECT *
FROM stock_current
WHERE best_before_date IS NOT NULL
UNION
SELECT m.id, 0, 0, 0, null, 0, 0, 0, p.due_type
FROM stock_missing_products m
JOIN products p
ON m.id = p.id
WHERE m.id NOT IN (SELECT product_id FROM stock_current)
) sc
LEFT JOIN products_last_purchased plp
ON sc.product_id = plp.product_id
LEFT JOIN products p
ON sc.product_id = p.id
LEFT JOIN product_barcodes_comma_separated pbcs
ON sc.product_id = pbcs.product_id
LEFT JOIN products p_parent
ON p.parent_product_id = p_parent.id
LEFT JOIN locations l
ON p.location_id = l.id
WHERE p.hide_on_stock_overview = 0;