Various additions for views for editing in sqlitebrowser

I had made these various additions previously and not committed them.
This commit is contained in:
Bradley M. Kuhn 2024-11-03 15:54:50 -08:00
parent 9f24452cbd
commit 333b526299

View file

@ -171,6 +171,127 @@ CREATE UNIQUE INDEX donor_postal_address_mapping_single_open_ended_addr
-- Note: CREATE TEMP TABLE doesn't work in BEGIN/END block of a CREATE TRIGGER, and as such, we have to create -- 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. -- all the temp tables as real tables.
-- -------------- VIEW: UserOperation_add_request ---------------------
DROP VIEW IF EXISTS UserOperation_add_shirt_request;
CREATE VIEW UserOperation_add_shirt_request AS
SELECT NULL as donor_id, rt.type as request_type, rc.description as request_detail, rt.id as type_id, rc.id as detail_id
FROM request_configuration rc, request_type rt
WHERE rt.type LIKE '%shirt%' AND
rc.request_type_id = rt.id
ORDER BY rt.type, rc.description;
DROP TRIGGER IF EXISTS add_shirt_request;
CREATE TRIGGER add_shirt_request
INSTEAD OF UPDATE OF donor_id ON UserOperation_add_shirt_request
BEGIN
SELECT CASE
WHEN ( (SELECT donor.id FROM donor WHERE id = NEW.donor_id) != NEW.donor_id )
THEN RAISE(FAIL, "Invalid donor ID; must enter a valid donor ID to add this shirt request.")
END;
SELECT CASE
WHEN ( (SELECT rr.id FROM donor dd, request rr WHERE rr.donor_id = dd.id AND dd.id = NEW.donor_id and rr.request_type_id = OLD.type_id) IS NOT NULL )
THEN RAISE(FAIL, "That donor already has a request of that type in the database; perhaps you wanted UserOperation_fix_tshirt_size_request instead of this view?")
END;
INSERT INTO request(donor_id, request_type_id, request_configuration_id, date_requested)
VALUES(NEW.donor_id, OLD.type_id, OLD.detail_id, date('now'));
END;
-- -------------- VIEW: UserOperation_fulfill_request_manually ---------------------
DROP VIEW IF EXISTS UserOperation_fulfill_request_manually;
CREATE VIEW UserOperation_fulfill_request_manually AS
SELECT donor.ledger_entity_id as entity, NULL as fulfill_how,
request_type.type as shirt_requested, request_configuration.description as size_requested,
request.date_requested as request_date, request.notes as note,
donor.id as donor_id, request.id as request_id
FROM donor, request_configuration, request, request_type
LEFT OUTER JOIN fulfillment ON fulfillment.request_id = request.id
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 request.date_requested DESC, donor.ledger_entity_id;
DROP TRIGGER IF EXISTS fulfill_request_manually;
CREATE TRIGGER fulfill_request_mannually
INSTEAD OF UPDATE OF fulfill_how on UserOperation_fulfill_request_manually
BEGIN
SELECT CASE
WHEN ( (SELECT rh.id FROM request_hold rh
WHERE rh.request_id = OLD.request_id
AND rh.release_date > date('now') )
IS NOT NULL )
THEN RAISE(FAIL, "Request is on hold; cannot fulfill; use UserOperation_unhold_request to unhold this request *first*!")
END;
INSERT INTO fulfillment(request_id, who, how, date)
VALUES(OLD.request_id, 'gui-edit', NEW.fulfill_how , date('now'));
END;
-- -------------- VIEW: UserOperation_fulfillment_failure ---------------------
DROP VIEW IF EXISTS UserOperation_fulfillment_failure;
CREATE VIEW UserOperation_fulfillment_failure AS
SELECT donor.ledger_entity_id as entity, fulfillment.date as fulfill_date,
request_type.type as shirt_requested, request_configuration.description as size_requested,
request.date_requested as request_date, request.notes as note,
fulfillment.who as fulfill_who, fulfillment.how as fulfill_how,
donor.id as donor_id, request.id as request_id, fulfillment.id as fulfill_id
FROM donor, request_configuration, request, request_type, fulfillment
WHERE request.id 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 AND
fulfillment.request_id = request.id
ORDER BY fulfillment.date DESC, request.date_requested, donor.ledger_entity_id;
DROP TRIGGER IF EXISTS fulfillment_failure;
CREATE TRIGGER fulfillment_failure
INSTEAD OF UPDATE OF fulfill_how on UserOperation_fulfillment_failure
BEGIN
INSERT INTO request_hold(request_id, who, why, release_date, hold_date)
VALUES(OLD.request_id, "gui-edit",
(select 'because ' || NEW.fulfill_how || ', fulfillment failed (prev attempted via '
|| OLD.fulfill_how || ' by ' || OLD.fulfill_who || ' on ' || OLD.fulfill_date || ')'),
"9999-12-31", date('now'));
DELETE from fulfillment where id = OLD.fulfill_id;
END;
-- -------------- VIEW: UserOperation_unhold_request ---------------------
DROP VIEW IF EXISTS UserOperation_unhold_request;
CREATE VIEW UserOperation_unhold_request AS
SELECT donor.ledger_entity_id as entity, rh.release_date as release_date, rh.hold_date as held_date, rh.why as held_why, rh.who as held_who,
request_type.type as shirt_requested, request_configuration.description as size_requested,
request.date_requested as request_date, request.notes as note,
donor.id as donor_id, request.id as request_id, rh.id as held_id
FROM donor, request_configuration, request, request_type, request_hold rh
WHERE request.id in (select request_id from request_hold) AND
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 AND
rh.request_id = request.id
ORDER BY rh.release_date DESC, rh.hold_date DESC, request.date_requested, donor.ledger_entity_id;
DROP TRIGGER IF EXISTS release_hold;
CREATE TRIGGER release_hold
INSTEAD OF UPDATE OF release_date on UserOperation_unhold_request
BEGIN
UPDATE request_hold set release_date = NEW.release_date WHERE id = OLD.held_id;
END;
-- -------------- VIEW: UserOperation_update_email_address --------------------- -- -------------- VIEW: UserOperation_update_email_address ---------------------
DROP VIEW IF EXISTS UserOperation_email_add_when_none; DROP VIEW IF EXISTS UserOperation_email_add_when_none;
CREATE VIEW UserOperation_email_add_when_none AS CREATE VIEW UserOperation_email_add_when_none AS
@ -209,6 +330,7 @@ END;
DROP TRIGGER IF EXISTS update_postal_address_preferred_override; DROP TRIGGER IF EXISTS update_postal_address_preferred_override;
DROP TRIGGER IF EXISTS update_postal_address_is_invalid; DROP TRIGGER IF EXISTS update_postal_address_is_invalid;
DROP TRIGGER IF EXISTS update_formatted_postal_address; DROP TRIGGER IF EXISTS update_formatted_postal_address;
DROP VIEW IF EXISTS UserOperation_add_postal_for_donor_with_none;
DROP VIEW IF EXISTS UserOperation_postal_address_change; DROP VIEW IF EXISTS UserOperation_postal_address_change;
CREATE VIEW UserOperation_postal_address_change AS CREATE VIEW UserOperation_postal_address_change AS
@ -298,6 +420,15 @@ CREATE VIEW UserOperation_fix_tshirt_size_request AS
request_configuration.id = request.request_configuration_id request_configuration.id = request.request_configuration_id
ORDER BY donor.ledger_entity_id, request.date_requested; ORDER BY donor.ledger_entity_id, request.date_requested;
DROP TRIGGER IF EXISTS fix_tshirt_size_note_updater;
CREATE TRIGGER fix_tshirt_size_note_updater
INSTEAD OF UPDATE OF note on UserOperation_fix_tshirt_size_request
BEGIN
UPDATE request set notes = NEW.note WHERE request.donor_id = OLD.donor_id and request.id = OLD.request_id;
END;
DROP TRIGGER IF EXISTS fix_tshirt_size_request_updater; DROP TRIGGER IF EXISTS fix_tshirt_size_request_updater;
CREATE TRIGGER fix_tshirt_size_request_updater CREATE TRIGGER fix_tshirt_size_request_updater
INSTEAD OF UPDATE OF size_requested on UserOperation_fix_tshirt_size_request INSTEAD OF UPDATE OF size_requested on UserOperation_fix_tshirt_size_request