Two new views and related triggers for email/post address insert

UserOperation_add_postal_for_donor_with_none, UserOperation_email_add_when_none
This commit is contained in:
Bradley M. Kuhn 2022-11-21 15:25:00 -08:00
parent d0b7f15f2a
commit 3fa1f004d3

View file

@ -140,6 +140,78 @@ CREATE UNIQUE INDEX donor_postal_address_mapping_single_prefferred_per_donor
-- 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.
-- -------------- VIEW: UserOperation_update_email_address ---------------------
DROP VIEW IF EXISTS UserOperation_email_add_when_none;
CREATE VIEW UserOperation_email_add_when_none AS
SELECT ledger_entity_id as donor_name, map.preferred as preferred_override, ea.date_encountered as entered_date,
ea.email_address as email_address, ea.id as address_id, dd.id as donor_id
FROM donor dd
LEFT JOIN donor_email_address_mapping map ON dd.id = map.donor_id
LEFT JOIN email_address ea ON ea.id = map.email_address_id
WHERE map.donor_id is NULL
ORDER BY ledger_entity_id;
DROP TRIGGER IF EXISTS add_email_address;
CREATE TRIGGER add_email_address
INSTEAD OF UPDATE OF email_address on UserOperation_email_add_when_none
BEGIN
INSERT INTO email_address(email_address, type_id, date_encountered)
VALUES(NEW.email_address, 21, date("now"));
INSERT INTO donor_email_address_mapping(donor_id, email_address_id)
VALUES(OLD.donor_id, (SELECT last_insert_rowid() ));
SELECT CASE
WHEN ( (SELECT email_address FROM donor_email_address_mapping de, email_address ea
WHERE de.donor_id = OLD.donor_id
AND ea.id = (SELECT last_insert_rowid() )
AND de.email_address_id = (SELECT last_insert_rowid() )
AND ea.email_address = NEW.email_address
!= NEW.email_address ) )
THEN RAISE(FAIL, "Error encountered while adding new postal address; please verify your changes worked!")
END;
END;
-- -------------- VIEW: UserOperation_add_postal_for_donor_with_none ---------------------
DROP VIEW IF EXISTS UserOperation_add_postal_for_donor_with_none;
CREATE VIEW UserOperation_add_postal_for_donor_with_none AS
SELECT ledger_entity_id as donor_name, map.preferred as preferred_override, pa.date_encountered as entered_date,
pa.formatted_address as formatted_postal_address, pa.id as address_id, dd.id as donor_id, pa.invalid as is_invalid
FROM donor dd
LEFT JOIN donor_postal_address_mapping map ON dd.id = map.donor_id
LEFT JOIN postal_address pa ON pa.id = map.postal_address_id
WHERE map.donor_id is NULL
AND dd.is_supporter = 1
AND pa.id is NULL
ORDER BY ledger_entity_id;
DROP TRIGGER IF EXISTS create_formatted_postal_address_for_donor_with_none;
CREATE TRIGGER create_formatted_postal_for_donor_with_none
INSTEAD OF UPDATE OF formatted_postal_address on UserOperation_add_postal_for_donor_with_none
BEGIN
INSERT INTO postal_address(formatted_address, type_id, date_encountered)
VALUES(NEW.formatted_postal_address, 21, date("now"));
-- WITH wt(new_postal_address_id) AS (SELECT last_insert_rowid() AS new_postal_address_id)
INSERT INTO donor_postal_address_mapping(donor_id, postal_address_id)
VALUES(OLD.donor_id, (SELECT last_insert_rowid() ));
-- VALUES(OLD.donor_id, (SELECT new_postal_address_id FROM wt) );
SELECT CASE
WHEN ( (SELECT formatted_address FROM donor_postal_address_mapping dp, postal_address pa
WHERE dp.donor_id = OLD.donor_id
AND pa.id = (SELECT last_insert_rowid() )
AND dp.postal_address_id = (SELECT last_insert_rowid() )
AND pa.formatted_address = NEW.formatted_postal_address
!= NEW.formatted_postal_address ) )
THEN RAISE(FAIL, "Error encountered while adding new postal address; please verify your changes worked!")
END;
END;
-- -------------- VIEW: UserOperation_update_postal_address ---------------------
DROP VIEW IF EXISTS UserOperation_postal_address_change;