Don't use double quoted string literals (in triggers / RAISE)

This commit is contained in:
Bernd Bestel
2025-08-03 23:14:33 +02:00
parent 6b18b0a7be
commit ba2cb6ce08
14 changed files with 223 additions and 22 deletions

View File

@@ -5,9 +5,9 @@ WITH RECURSIVE r1(recipe_id, includes_recipe_id, includes_servings)
AS (
SELECT id, id, 1
FROM recipes
UNION ALL
SELECT rn.recipe_id, r1.includes_recipe_id, rn.servings
FROM recipes_nestings rn, r1 r1
WHERE rn.includes_recipe_id = r1.recipe_id
@@ -24,7 +24,7 @@ SELECT CASE WHEN((
FROM recipes_nestings
WHERE NEW.recipe_id = NEW.includes_recipe_id
)
NOTNULL) THEN RAISE(ABORT, "Recursive nested recipe detected") END;
NOTNULL) THEN RAISE(ABORT, 'Recursive nested recipe detected') END;
END;
CREATE TRIGGER prevent_self_nested_recipes_UPD BEFORE UPDATE ON recipes_nestings
@@ -34,7 +34,7 @@ SELECT CASE WHEN((
FROM recipes_nestings
WHERE NEW.recipe_id = NEW.includes_recipe_id
)
NOTNULL) THEN RAISE(ABORT, "Recursive nested recipe detected") END;
NOTNULL) THEN RAISE(ABORT, 'Recursive nested recipe detected') END;
END;
DELETE FROM recipes_nestings

View File

@@ -88,7 +88,7 @@ BEGIN
FROM stock_log
WHERE product_id = NEW.id
AND NEW.qu_id_stock != OLD.qu_id_stock
) NOTNULL) THEN RAISE(ABORT, "qu_id_stock cannot be changed when the product was once added to stock") END;
) NOTNULL) THEN RAISE(ABORT, 'qu_id_stock cannot be changed when the product was once added to stock') END;
END;
CREATE TRIGGER enforce_parent_product_id_null_when_empty_INS AFTER INSERT ON products

View File

@@ -13,7 +13,7 @@ BEGIN
FROM recipes_nestings_resolved rnr
WHERE NEW.recipe_id = rnr.includes_recipe_id
AND NEW.includes_recipe_id = rnr.recipe_id
) NOTNULL) THEN RAISE(ABORT, "Recursive nested recipe detected") END;
) NOTNULL) THEN RAISE(ABORT, 'Recursive nested recipe detected') END;
END;
CREATE TRIGGER prevent_infinite_nested_recipes_UPD BEFORE UPDATE ON recipes_nestings
@@ -23,5 +23,5 @@ BEGIN
FROM recipes_nestings_resolved rnr
WHERE NEW.recipe_id = rnr.includes_recipe_id
AND NEW.includes_recipe_id = rnr.recipe_id
) NOTNULL) THEN RAISE(ABORT, "Recursive nested recipe detected") END;
) NOTNULL) THEN RAISE(ABORT, 'Recursive nested recipe detected') END;
END;

View File

@@ -6,5 +6,5 @@ BEGIN
FROM products p
WHERE IFNULL(NEW.parent_product_id, '') != ''
AND IFNULL(parent_product_id, '') = NEW.id
) NOTNULL) THEN RAISE(ABORT, "Unsupported product nesting level detected (currently only 1 level is supported)") END;
) NOTNULL) THEN RAISE(ABORT, 'Unsupported product nesting level detected (currently only 1 level is supported)') END;
END;

View File

@@ -20,5 +20,5 @@ BEGIN
FROM meal_plan_sections
WHERE id = OLD.id
AND id = -1
) NOTNULL) THEN RAISE(ABORT, "This is an internally used/required default section and therefore can't be deleted") END;
) NOTNULL) THEN RAISE(ABORT, 'This is an internally used/required default section and therefore can''t be deleted') END;
END;

View File

@@ -48,7 +48,7 @@ BEGIN
FROM stock_log
WHERE product_id = NEW.id
AND NEW.qu_id_stock != OLD.qu_id_stock
) NOTNULL) THEN RAISE(ABORT, "qu_id_stock cannot be changed when the product was once added to stock") END;
) NOTNULL) THEN RAISE(ABORT, 'qu_id_stock cannot be changed when the product was once added to stock') END;
END;
CREATE TRIGGER enforce_parent_product_id_null_when_empty_INS AFTER INSERT ON products
@@ -104,7 +104,7 @@ BEGIN
FROM products p
WHERE IFNULL(NEW.parent_product_id, '') != ''
AND IFNULL(parent_product_id, '') = NEW.id
) NOTNULL) THEN RAISE(ABORT, "Unsupported product nesting level detected (currently only 1 level is supported)") END;
) NOTNULL) THEN RAISE(ABORT, 'Unsupported product nesting level detected (currently only 1 level is supported)') END;
END;
CREATE TRIGGER enforce_min_stock_amount_for_cumulated_childs_INS AFTER INSERT ON products

View File

@@ -20,7 +20,7 @@ BEGIN
FROM stock_log
WHERE product_id = NEW.id
AND NEW.qu_id_stock != OLD.qu_id_stock
) NOTNULL) THEN RAISE(ABORT, "qu_id_stock can only be changed when a corresponding QU conversion (old QU => new QU) exists when the product was once added to stock") END;
) NOTNULL) THEN RAISE(ABORT, 'qu_id_stock can only be changed when a corresponding QU conversion (old QU => new QU) exists when the product was once added to stock') END;
UPDATE chores
SET product_amount = product_amount * IFNULL((SELECT factor FROM quantity_unit_conversions_resolved WHERE product_id = NEW.id AND from_qu_id = OLD.qu_id_stock AND to_qu_id = NEW.qu_id_stock AND source NOT LIKE '1%'), 1.0)

View File

@@ -72,5 +72,5 @@ BEGIN
FROM products p
WHERE id = NEW.product_id
AND no_own_stock = 1
) NOTNULL) THEN RAISE(ABORT, "no_own_stock=1 products can't be added to stock") END;
) NOTNULL) THEN RAISE(ABORT, 'no_own_stock = 1 products can''t be added to stock') END;
END;

View File

@@ -35,7 +35,7 @@ SELECT CASE WHEN((
AND qu_id_purchase = NEW.to_qu_id
AND qu_id_stock = NEW.from_qu_id
)
NOTNULL) THEN RAISE(ABORT, "QU conversion already exists") END;
NOTNULL) THEN RAISE(ABORT, 'QU conversion already exists') END;
END;
DROP TRIGGER quantity_unit_conversions_custom_unique_constraint_UPD;
@@ -67,7 +67,7 @@ SELECT CASE WHEN((
AND qu_id_purchase = NEW.to_qu_id
AND qu_id_stock = NEW.from_qu_id
)
NOTNULL) THEN RAISE(ABORT, "QU conversion already exists") END;
NOTNULL) THEN RAISE(ABORT, 'QU conversion already exists') END;
END;
CREATE TRIGGER qu_conversions_inverse_INS AFTER INSERT ON quantity_unit_conversions

View File

@@ -8,5 +8,5 @@ BEGIN
SELECT 1
FROM products p
WHERE id = NEW.product_id
) ISNULL) THEN RAISE(ABORT, "product_id doesn't reference a existing product") END;
) ISNULL) THEN RAISE(ABORT, 'product_id doesn''t reference a existing product') END;
END;

View File

@@ -18,7 +18,7 @@ BEGIN
FROM stock_log
WHERE product_id = NEW.id
AND NEW.qu_id_stock != OLD.qu_id_stock
) NOTNULL) THEN RAISE(ABORT, "qu_id_stock can only be changed when a corresponding QU conversion (old QU => new QU) exists when the product was once added to stock") END;
) NOTNULL) THEN RAISE(ABORT, 'qu_id_stock can only be changed when a corresponding QU conversion (old QU => new QU) exists when the product was once added to stock') END;
UPDATE chores
SET product_amount = product_amount * IFNULL((SELECT factor FROM quantity_unit_conversions_resolved WHERE product_id = NEW.id AND from_qu_id = OLD.qu_id_stock AND to_qu_id = NEW.qu_id_stock LIMIT 1), 1.0)

View File

@@ -21,5 +21,5 @@ BEGIN
FROM recipes_pos rp
WHERE rp.id = NEW.id
AND IFNULL(rp.only_check_single_unit_in_stock, 0) = 1
) ISNULL) THEN RAISE(ABORT, "Provided qu_id doesn't have a related conversion for that product") END;
) ISNULL) THEN RAISE(ABORT, 'Provided qu_id doesn''t have a related conversion for that product') END;
END;

View File

@@ -12,7 +12,7 @@ SELECT CASE WHEN((
AND to_qu_id = NEW.to_qu_id
AND IFNULL(product_id, 0) = IFNULL(NEW.product_id, 0)
)
NOTNULL) THEN RAISE(ABORT, "QU conversion already exists") END;
NOTNULL) THEN RAISE(ABORT, 'QU conversion already exists') END;
END;
-- Remove including the product's qu_factor_purchase_to_stock
@@ -32,7 +32,7 @@ SELECT CASE WHEN((
AND IFNULL(product_id, 0) = IFNULL(NEW.product_id, 0)
AND id != NEW.id
)
NOTNULL) THEN RAISE(ABORT, "QU conversion already exists") END;
NOTNULL) THEN RAISE(ABORT, 'QU conversion already exists') END;
END;
-- Migrate qu_factor_purchase_to_stock to product specific QU conversions
@@ -154,7 +154,7 @@ BEGIN
FROM products p
WHERE IFNULL(NEW.parent_product_id, '') != ''
AND IFNULL(parent_product_id, '') = NEW.id
) NOTNULL) THEN RAISE(ABORT, "Unsupported product nesting level detected (currently only 1 level is supported)") END;
) NOTNULL) THEN RAISE(ABORT, 'Unsupported product nesting level detected (currently only 1 level is supported)') END;
END;
CREATE TRIGGER enforce_min_stock_amount_for_cumulated_childs_INS AFTER INSERT ON products
@@ -218,7 +218,7 @@ BEGIN
FROM stock_log
WHERE product_id = NEW.id
AND NEW.qu_id_stock != OLD.qu_id_stock
) NOTNULL) THEN RAISE(ABORT, "qu_id_stock can only be changed when a corresponding QU conversion (old QU => new QU) exists when the product was once added to stock") END;
) NOTNULL) THEN RAISE(ABORT, 'qu_id_stock can only be changed when a corresponding QU conversion (old QU => new QU) exists when the product was once added to stock') END;
UPDATE chores
SET product_amount = product_amount * IFNULL((SELECT factor FROM quantity_unit_conversions_resolved WHERE product_id = NEW.id AND from_qu_id = OLD.qu_id_stock AND to_qu_id = NEW.qu_id_stock LIMIT 1), 1.0)

201
migrations/0254.sql Normal file
View File

@@ -0,0 +1,201 @@
-- Recreated triggers that use double quoted string literals / convert them to single quoted ones
DROP TRIGGER prevent_self_nested_recipes_INS;
CREATE TRIGGER prevent_self_nested_recipes_INS BEFORE INSERT ON recipes_nestings
BEGIN
SELECT CASE WHEN((
SELECT 1
FROM recipes_nestings
WHERE NEW.recipe_id = NEW.includes_recipe_id
)
NOTNULL) THEN RAISE(ABORT, 'Recursive nested recipe detected') END;
END;
DROP TRIGGER prevent_self_nested_recipes_UPD;
CREATE TRIGGER prevent_self_nested_recipes_UPD BEFORE UPDATE ON recipes_nestings
BEGIN
SELECT CASE WHEN((
SELECT 1
FROM recipes_nestings
WHERE NEW.recipe_id = NEW.includes_recipe_id
)
NOTNULL) THEN RAISE(ABORT, 'Recursive nested recipe detected') END;
END;
DROP TRIGGER prevent_infinite_nested_recipes_INS;
CREATE TRIGGER prevent_infinite_nested_recipes_INS BEFORE INSERT ON recipes_nestings
BEGIN
SELECT CASE WHEN((
SELECT 1
FROM recipes_nestings_resolved rnr
WHERE NEW.recipe_id = rnr.includes_recipe_id
AND NEW.includes_recipe_id = rnr.recipe_id
) NOTNULL) THEN RAISE(ABORT, 'Recursive nested recipe detected') END;
END;
DROP TRIGGER prevent_infinite_nested_recipes_UPD;
CREATE TRIGGER prevent_infinite_nested_recipes_UPD BEFORE UPDATE ON recipes_nestings
BEGIN
SELECT CASE WHEN((
SELECT 1
FROM recipes_nestings_resolved rnr
WHERE NEW.recipe_id = rnr.includes_recipe_id
AND NEW.includes_recipe_id = rnr.recipe_id
) NOTNULL) THEN RAISE(ABORT, 'Recursive nested recipe detected') END;
END;
DROP TRIGGER enfore_product_nesting_level;
CREATE TRIGGER enfore_product_nesting_level BEFORE UPDATE ON products
BEGIN
-- Currently only 1 level is supported
SELECT CASE WHEN((
SELECT 1
FROM products p
WHERE IFNULL(NEW.parent_product_id, '') != ''
AND IFNULL(parent_product_id, '') = NEW.id
) NOTNULL) THEN RAISE(ABORT, 'Unsupported product nesting level detected (currently only 1 level is supported)') END;
END;
DROP TRIGGER prevent_internal_meal_plan_section_removal;
CREATE TRIGGER prevent_internal_meal_plan_section_removal BEFORE DELETE ON meal_plan_sections
BEGIN
SELECT CASE WHEN((
SELECT 1
FROM meal_plan_sections
WHERE id = OLD.id
AND id = -1
) NOTNULL) THEN RAISE(ABORT, 'This is an internally used/required default section and therefore can''t be deleted') END;
END;
DROP TRIGGER cascade_change_qu_id_stock;
CREATE TRIGGER cascade_change_qu_id_stock BEFORE UPDATE ON products WHEN NEW.qu_id_stock != OLD.qu_id_stock
BEGIN
-- All amounts anywhere are related to the products stock QU,
-- so apply the appropriate unit conversion to all amounts everywhere on change
-- (and enforce that such a conversion need to exist when the product was once added to stock)
SELECT CASE WHEN((
SELECT 1
FROM quantity_unit_conversions_resolved
WHERE product_id = NEW.id
AND from_qu_id = OLD.qu_id_stock
AND to_qu_id = NEW.qu_id_stock
) ISNULL)
AND
((
SELECT 1
FROM stock_log
WHERE product_id = NEW.id
AND NEW.qu_id_stock != OLD.qu_id_stock
) NOTNULL) THEN RAISE(ABORT, 'qu_id_stock can only be changed when a corresponding QU conversion (old QU => new QU) exists when the product was once added to stock') END;
UPDATE chores
SET product_amount = product_amount * IFNULL((SELECT factor FROM quantity_unit_conversions_resolved WHERE product_id = NEW.id AND from_qu_id = OLD.qu_id_stock AND to_qu_id = NEW.qu_id_stock LIMIT 1), 1.0)
WHERE product_id = NEW.id;
UPDATE meal_plan
SET product_amount = product_amount * IFNULL((SELECT factor FROM quantity_unit_conversions_resolved WHERE product_id = NEW.id AND from_qu_id = OLD.qu_id_stock AND to_qu_id = NEW.qu_id_stock LIMIT 1), 1.0)
WHERE type = 'product'
AND product_id = NEW.id;
UPDATE recipes_pos
SET amount = amount * IFNULL((SELECT factor FROM quantity_unit_conversions_resolved WHERE product_id = NEW.id AND from_qu_id = OLD.qu_id_stock AND to_qu_id = NEW.qu_id_stock LIMIT 1), 1.0)
WHERE product_id = NEW.id;
UPDATE shopping_list
SET amount = amount * IFNULL((SELECT factor FROM quantity_unit_conversions_resolved WHERE product_id = NEW.id AND from_qu_id = OLD.qu_id_stock AND to_qu_id = NEW.qu_id_stock LIMIT 1), 1.0)
WHERE product_id = NEW.id
AND product_id IS NOT NULL;
UPDATE stock
SET amount = amount * IFNULL((SELECT factor FROM quantity_unit_conversions_resolved WHERE product_id = NEW.id AND from_qu_id = OLD.qu_id_stock AND to_qu_id = NEW.qu_id_stock LIMIT 1), 1.0),
price = price / IFNULL((SELECT factor FROM quantity_unit_conversions_resolved WHERE product_id = NEW.id AND from_qu_id = OLD.qu_id_stock AND to_qu_id = NEW.qu_id_stock LIMIT 1), 1.0)
WHERE product_id = NEW.id;
UPDATE stock_log
SET amount = amount * IFNULL((SELECT factor FROM quantity_unit_conversions_resolved WHERE product_id = NEW.id AND from_qu_id = OLD.qu_id_stock AND to_qu_id = NEW.qu_id_stock LIMIT 1), 1.0),
price = price / IFNULL((SELECT factor FROM quantity_unit_conversions_resolved WHERE product_id = NEW.id AND from_qu_id = OLD.qu_id_stock AND to_qu_id = NEW.qu_id_stock LIMIT 1), 1.0)
WHERE product_id = NEW.id;
END;
DROP TRIGGER prevent_adding_no_own_stock_products_to_stock;
CREATE TRIGGER prevent_adding_no_own_stock_products_to_stock AFTER INSERT ON stock
BEGIN
SELECT CASE WHEN((
SELECT 1
FROM products p
WHERE id = NEW.product_id
AND no_own_stock = 1
) NOTNULL) THEN RAISE(ABORT, 'no_own_stock = 1 products can''t be added to stock') END;
END;
DROP TRIGGER qu_conversions_custom_constraint_INS;
CREATE TRIGGER qu_conversions_custom_constraint_INS BEFORE INSERT ON quantity_unit_conversions
BEGIN
/*
Necessary because unique constraints don''t include NULL values in SQLite
*/
SELECT CASE WHEN((
SELECT 1
FROM quantity_unit_conversions
WHERE from_qu_id = NEW.from_qu_id
AND to_qu_id = NEW.to_qu_id
AND IFNULL(product_id, 0) = IFNULL(NEW.product_id, 0)
)
NOTNULL) THEN RAISE(ABORT, 'QU conversion already exists') END;
END;
DROP TRIGGER prevent_adding_barcodes_for_not_existing_products;
CREATE TRIGGER prevent_adding_barcodes_for_not_existing_products AFTER INSERT ON product_barcodes
BEGIN
SELECT CASE WHEN((
SELECT 1
FROM products p
WHERE id = NEW.product_id
) ISNULL) THEN RAISE(ABORT, 'product_id doesn''t reference a existing product') END;
END;
DROP TRIGGER recipes_pos_qu_id_default;
CREATE TRIGGER recipes_pos_qu_id_default AFTER INSERT ON recipes_pos
BEGIN
UPDATE recipes_pos
SET qu_id = (SELECT qu_id_stock FROM products where id = product_id)
WHERE id = NEW.id
AND IFNULL(qu_id, '') = '';
SELECT CASE WHEN((
SELECT 1
FROM recipes_pos rp
JOIN quantity_unit_conversions_resolved qucr
ON qucr.product_id = rp.product_id
AND qucr.to_qu_id = rp.qu_id
WHERE rp.id = NEW.id
UNION
-- only_check_single_unit_in_stock = 1 ingredients can have any QU
SELECT 1
FROM recipes_pos rp
WHERE rp.id = NEW.id
AND IFNULL(rp.only_check_single_unit_in_stock, 0) = 1
) ISNULL) THEN RAISE(ABORT, 'Provided qu_id doesn''t have a related conversion for that product') END;
END;
DROP TRIGGER qu_conversions_custom_constraint_UPD;
CREATE TRIGGER qu_conversions_custom_constraint_UPD BEFORE UPDATE ON quantity_unit_conversions
BEGIN
/* This contains practically the same logic as the trigger qu_conversions_custom_constraint_INS */
/*
Necessary because unique constraints don''t include NULL values in SQLite
*/
SELECT CASE WHEN((
SELECT 1
FROM quantity_unit_conversions
WHERE from_qu_id = NEW.from_qu_id
AND to_qu_id = NEW.to_qu_id
AND IFNULL(product_id, 0) = IFNULL(NEW.product_id, 0)
AND id != NEW.id
)
NOTNULL) THEN RAISE(ABORT, 'QU conversion already exists') END;
END;