UserOperation_fix_tshirt_size_request view: first implementation

The `UserOperation_fix_tshirt_size_request` view is designed to allow
end-users edit t-shirt sizes in the request using a program like
`sqlitebrowser`.

This is the first implementation attempt of a user operation that
allows changing the T-Shirt size.
This commit is contained in:
Bradley M. Kuhn 2022-06-21 13:58:21 -07:00
parent cc1aee90d8
commit e7bdf7db27

View file

@ -130,3 +130,73 @@ CREATE TABLE "donor_postal_address_mapping" (
CREATE UNIQUE INDEX donor_postal_address_mapping_single_prefferred_per_donor CREATE UNIQUE INDEX donor_postal_address_mapping_single_prefferred_per_donor
ON donor_postal_address_mapping(donor_id, preferred); ON donor_postal_address_mapping(donor_id, preferred);
-- ####################################### VIEWS FOR EASIER EDITING ##########################
-- The views below are particularly useful if you use a program like `sqlitebrowser`, as
-- these views can allow the user to make common changes to the data without
-- messing up the data integrity.
-- Note: CREATE TEMP TABLE doesn't work in BEGIN/END block of a CREATE TRIGGER, and as such, we have to create
-- all the temp tables as real tables.
DROP TABLE IF EXISTS "_temp_size_val_for_fix_tshirt_size_request";
CREATE TABLE _temp_size_val_for_fix_tshirt_size_request(
old_request_configuration_id integer,
new_request_configuration_id integer,
new_description varchar(100) NOT NULL);
DROP VIEW IF EXISTS UserOperation_fix_tshirt_size_request;
CREATE VIEW UserOperation_fix_tshirt_size_request AS
SELECT donor.id as donor_id, request.id as request_id, donor.ledger_entity_id as donor_name,
request_type.type as shirt_requested, request_configuration.description as size_requested,
request.date_requested as request_date, request.notes as note
FROM donor, request_configuration, request, request_type
WHERE request.id not in (select request_id from fulfillment) AND
request_type.type LIKE "%shirt%" AND
request_type.id = request.request_type_id AND
request.donor_id = donor.id AND
request_configuration.id = request.request_configuration_id
ORDER BY donor.ledger_entity_id, request.date_requested;
DROP TRIGGER IF EXISTS fix_tshirt_size_request_updater;
CREATE TRIGGER fix_tshirt_size_request_updater
INSTEAD OF UPDATE OF size_requested on UserOperation_fix_tshirt_size_request
BEGIN
DELETE FROM _temp_size_val_for_fix_tshirt_size_request;
INSERT INTO _temp_size_val_for_fix_tshirt_size_request(new_description) VALUES(NEW.size_requested);
update _temp_size_val_for_fix_tshirt_size_request set new_request_configuration_id = (select rc.id
from request_configuration rc, request_type rt
where rc.description = NEW.size_requested
and rt.id = rc.request_type_id
and rt.type = OLD.shirt_requested)
WHERE new_description = NEW.size_requested;
UPDATE _temp_size_val_for_fix_tshirt_size_request set old_request_configuration_id =
(SELECT rc.id
FROM request_configuration rc, request_type rt
where rc.description = OLD.size_requested
and rt.id = rc.request_type_id
and rt.type = OLD.shirt_requested)
WHERE new_description = NEW.size_requested
AND new_request_configuration_id IS NOT NULL;
SELECT CASE
WHEN ( (SELECT new_request_configuration_id from _temp_size_val_for_fix_tshirt_size_request) IS NULL )
THEN RAISE(FAIL, "Invalid t-shirt size for this particular t-shirt style!")
END;
UPDATE request
set request_configuration_id =
(select new_request_configuration_id from _temp_size_val_for_fix_tshirt_size_request)
where id = OLD.request_id
and request_configuration_id =
(select old_request_configuration_id from _temp_size_val_for_fix_tshirt_size_request);
DELETE FROM _temp_size_val_for_fix_tshirt_size_request;
END;