4a6ad06ebb
This is less confusing because `entity` is used elsewhere.
534 lines
22 KiB
SQL
534 lines
22 KiB
SQL
-- Conservancy Supporter Database, Version 0.4
|
|
|
|
DROP TABLE IF EXISTS "donor";
|
|
|
|
CREATE TABLE "donor" (
|
|
"id" integer NOT NULL PRIMARY KEY,
|
|
"ledger_entity_id" varchar(300) NOT NULL UNIQUE,
|
|
"display_name" varchar(300),
|
|
"public_ack" bool,
|
|
"is_supporter" bool NOT NULL,
|
|
"rt_ticket integer
|
|
);
|
|
|
|
DROP TABLE IF EXISTS "request";
|
|
|
|
CREATE TABLE "request" (
|
|
"id" integer NOT NULL PRIMARY KEY,
|
|
"donor_id" integer NOT NULL,
|
|
"request_type_id" integer NOT NULL,
|
|
"request_configuration_id" integer,
|
|
"date_requested" date NOT NULL,
|
|
"notes" TEXT
|
|
);
|
|
|
|
CREATE UNIQUE INDEX request__one_request_for_each_type_per_donor
|
|
ON request(donor_id, request_type_id);
|
|
|
|
DROP TABLE IF EXISTS "request_configuration";
|
|
|
|
CREATE TABLE "request_configuration" (
|
|
"id" integer NOT NULL PRIMARY KEY,
|
|
"request_type_id" integer NOT NULL,
|
|
"description" varchar(100) NOT NULL
|
|
);
|
|
|
|
CREATE UNIQUE INDEX request_configuration__single_description
|
|
ON request_configuration(request_type_id, description);
|
|
|
|
DROP TABLE IF EXISTS "fulfillment";
|
|
|
|
CREATE TABLE "fulfillment" (
|
|
"id" integer NOT NULL PRIMARY KEY,
|
|
"request_id" integer NOT NULL,
|
|
"date" TEXT NOT NULL,
|
|
"who" varchar(300) NOT NULL,
|
|
"how" TEXT
|
|
);
|
|
|
|
CREATE UNIQUE INDEX fulfillment__one_fulfillment_per_request ON fulfillment(request_id);
|
|
|
|
DROP TABLE IF EXISTS "request_hold";
|
|
|
|
CREATE TABLE "request_hold" (
|
|
"id" integer NOT NULL PRIMARY KEY,
|
|
"request_id" integer NOT NULL,
|
|
"hold_date" TEXT NOT NULL,
|
|
"release_date" TEXT,
|
|
"who" varchar(300) NOT NULL,
|
|
"why" TEXT
|
|
);
|
|
|
|
CREATE UNIQUE INDEX request_hold__one_hold_per_request ON request_hold(request_id);
|
|
|
|
DROP TABLE IF EXISTS "request_type";
|
|
|
|
CREATE TABLE "request_type" (
|
|
"id" integer NOT NULL PRIMARY KEY,
|
|
"type" varchar(100) NOT NULL
|
|
);
|
|
|
|
DROP TABLE IF EXISTS "delivery_error";
|
|
|
|
CREATE TABLE "delivery_error" (
|
|
"id" integer NOT NULL PRIMARY KEY,
|
|
"error" varchar(300) NOT NULL UNIQUE
|
|
);
|
|
|
|
DROP TABLE IF EXISTS "email_address";
|
|
|
|
CREATE TABLE "email_address" (
|
|
"id" integer NOT NULL PRIMARY KEY,
|
|
"email_address" varchar(300) NOT NULL UNIQUE,
|
|
"type_id" integer,
|
|
"date_encountered" date NOT NULL
|
|
);
|
|
|
|
DROP TABLE IF EXISTS "email_error_log";
|
|
|
|
CREATE TABLE "email_error_log" (
|
|
"email_address_id" integer NOT NULL,
|
|
"delivery_error_code_id" integer NOT NULL,
|
|
"date_encountered" date NOT NULL,
|
|
"comments" TEXT
|
|
);
|
|
|
|
DROP TABLE IF EXISTS "donor_email_address_mapping";
|
|
|
|
CREATE TABLE "donor_email_address_mapping" (
|
|
"donor_id" integer NOT NULL,
|
|
"email_address_id" integer NOT NULL,
|
|
"preferred" bool,
|
|
PRIMARY KEY(donor_id, email_address_id)
|
|
);
|
|
|
|
DROP TABLE IF EXISTS "address_type";
|
|
|
|
CREATE TABLE "address_type" (
|
|
"id" integer NOT NULL PRIMARY KEY,
|
|
"name" varchar(50) NOT NULL UNIQUE
|
|
);
|
|
|
|
DROP TABLE IF EXISTS "postal_address";
|
|
|
|
CREATE TABLE "postal_address" (
|
|
"id" integer NOT NULL PRIMARY KEY,
|
|
"formatted_address" varchar(5000),
|
|
"type_id" INTEGER NOT NULL,
|
|
"date_encountered" date NOT NULL,
|
|
"invalid" bool
|
|
);
|
|
|
|
DROP TABLE IF EXISTS "donor_postal_address_mapping";
|
|
|
|
CREATE TABLE "donor_postal_address_mapping" (
|
|
"donor_id" integer NOT NULL,
|
|
"postal_address_id" integer NOT NULL,
|
|
"preferred" bool,
|
|
PRIMARY KEY(donor_id, postal_address_id)
|
|
);
|
|
|
|
CREATE UNIQUE INDEX donor_postal_address_mapping_single_prefferred_per_donor
|
|
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.
|
|
|
|
-- -------------- 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 entity, 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 entity, 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;
|
|
CREATE VIEW UserOperation_postal_address_change AS
|
|
SELECT ledger_entity_id as entity, 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, donor_postal_address_mapping map, postal_address pa
|
|
WHERE dd.id = map.donor_id AND pa.id = map.postal_address_id
|
|
AND map.preferred is NOT NULL
|
|
|
|
UNION
|
|
|
|
SELECT ledger_entity_id as entity, 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, donor_postal_address_mapping map, postal_address pa
|
|
WHERE dd.id = map.donor_id AND pa.id = map.postal_address_id
|
|
AND map.preferred is NULL
|
|
AND pa.date_encountered = (SELECT max(sub_pa.date_encountered)
|
|
FROM donor_postal_address_mapping sub_map, postal_address sub_pa
|
|
WHERE sub_map.donor_id = dd.id AND sub_map.postal_address_id = sub_pa.id)
|
|
ORDER BY ledger_entity_id, pa.date_encountered;
|
|
|
|
DROP TRIGGER IF EXISTS update_postal_address_preferred_override;
|
|
CREATE TRIGGER update_postal_address_preferred_override
|
|
INSTEAD OF UPDATE OF preferred_override on UserOperation_postal_address_change
|
|
BEGIN
|
|
|
|
UPDATE donor_postal_address_mapping SET preferred = NEW.preferred_override
|
|
WHERE donor_id = OLD.donor_id and postal_address_id = OLD.address_id;
|
|
|
|
SELECT CASE
|
|
WHEN ( (SELECT preferred FROM donor_postal_address_mapping
|
|
WHERE donor_id = OLD.donor_id AND postal_address_Id = OLD.address_id)
|
|
!= NEW.preferred_override )
|
|
THEN RAISE(FAIL, "Error encountered while updating preferred setting; please verify your changes worked!")
|
|
END;
|
|
|
|
END;
|
|
|
|
DROP TRIGGER IF EXISTS update_postal_address_is_invalid;
|
|
CREATE TRIGGER update_postal_address_is_invalid
|
|
INSTEAD OF UPDATE OF is_invalid on UserOperation_postal_address_change
|
|
BEGIN
|
|
|
|
UPDATE postal_address SET invalid = NEW.is_invalid
|
|
WHERE id = OLD.address_id;
|
|
|
|
SELECT CASE
|
|
WHEN ( (SELECT invalid FROM postal_address
|
|
WHERE id = OLD.address_id)
|
|
!= NEW.is_invalid )
|
|
THEN RAISE(FAIL, "Error encountered while updating invalid setting; please verify your changes worked!")
|
|
END;
|
|
|
|
END;
|
|
|
|
|
|
DROP TRIGGER IF EXISTS update_formatted_postal_address;
|
|
CREATE TRIGGER update_formatted_postal_address
|
|
INSTEAD OF UPDATE OF formatted_postal_address on UserOperation_postal_address_change
|
|
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_fix_tshirt_size_request ---------------------
|
|
|
|
DROP TABLE IF EXISTS "zz__temp_request_configuration_change";
|
|
|
|
CREATE TABLE zz__temp_request_configuration_change(
|
|
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.ledger_entity_id as entity,
|
|
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
|
|
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 zz__temp_request_configuration_change;
|
|
|
|
INSERT INTO zz__temp_request_configuration_change(new_description) VALUES(NEW.size_requested);
|
|
|
|
update zz__temp_request_configuration_change 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 zz__temp_request_configuration_change 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 zz__temp_request_configuration_change) 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 zz__temp_request_configuration_change)
|
|
where id = OLD.request_id
|
|
and request_configuration_id =
|
|
(select old_request_configuration_id from zz__temp_request_configuration_change);
|
|
|
|
DELETE FROM zz__temp_request_configuration_change;
|
|
|
|
END;
|
|
|
|
-- -------------- END VIEW: UserOperation_fix_tshirt_size_request ---------------------
|
|
|
|
-- -------------- VIEW: UserOperation_donor_update ---------------------
|
|
|
|
DROP VIEW IF EXISTS UserOperation_donor_update;
|
|
CREATE VIEW UserOperation_donor_update AS
|
|
SELECT donor.ledger_entity_id as entity, donor.rt_ticket as ticket, donor.display_name as public_name,
|
|
donor.public_ack as public_acknowledge, donor.is_supporter as is_sustainer, donor.id as donor_id
|
|
FROM donor
|
|
ORDER BY donor.ledger_entity_id, donor.id;
|
|
|
|
DROP TRIGGER IF EXISTS donor_update_insert_new_donor;
|
|
CREATE TRIGGER donor_update_insert_new_donor
|
|
INSTEAD OF INSERT ON UserOperation_donor_update
|
|
BEGIN
|
|
INSERT INTO donor(ledger_entity_id, display_name, public_ack, rt_ticket, is_supporter)
|
|
VALUES(NEW.entity, NEW.public_name, NEW.public_acknowledge, NEW.ticket, 1);
|
|
END;
|
|
|
|
DROP TRIGGER IF EXISTS donor_update_display_name;
|
|
CREATE TRIGGER donor_update_display_name
|
|
INSTEAD OF UPDATE OF public_name on UserOperation_donor_update
|
|
BEGIN
|
|
|
|
UPDATE donor SET display_name = NEW.public_name
|
|
WHERE id = OLD.donor_id
|
|
AND (display_name = OLD.public_name OR display_name is NULL);
|
|
|
|
-- FIXME: I think this error message doesn't properly display when NEW.ticket
|
|
-- is NOT NULL and the select returns a NULL
|
|
|
|
SELECT CASE
|
|
WHEN ( (SELECT display_name FROM donor WHERE id = OLD.donor_id) != NEW.public_name )
|
|
THEN RAISE(FAIL, "Error encountered while updating public_name; please verify your changes worked!")
|
|
END;
|
|
|
|
END;
|
|
|
|
DROP TRIGGER IF EXISTS donor_update_rt_ticket;
|
|
CREATE TRIGGER donor_update_rt_ticket
|
|
INSTEAD OF UPDATE OF ticket on UserOperation_donor_update
|
|
BEGIN
|
|
|
|
UPDATE donor SET rt_ticket = NEW.ticket
|
|
WHERE id = OLD.donor_id
|
|
AND (rt_ticket = OLD.ticket or rt_ticket is NULL);
|
|
|
|
-- FIXME: I think this error message doesn't properly display when NEW.ticket
|
|
-- is NOT NULL and the select returns a NULL
|
|
|
|
SELECT CASE
|
|
WHEN ( (SELECT rt_ticket FROM donor WHERE id = OLD.donor_id) != NEW.ticket )
|
|
THEN RAISE(FAIL, "Error encountered while updating RT ticket; please verify your changes worked!")
|
|
END;
|
|
|
|
END;
|
|
|
|
DROP TRIGGER IF EXISTS donor_update_public_acknowledgment;
|
|
-- FIXME: This trigger does *not* add 'public-ack-change-N' request, as it should. I was not sure *why*
|
|
-- I'd kept track of public-ack changes in the request table anyway, so I did not implement that here.
|
|
CREATE TRIGGER donor_update_public_acknowledgment
|
|
INSTEAD OF UPDATE OF public_acknowledge on UserOperation_donor_update
|
|
BEGIN
|
|
|
|
UPDATE donor SET public_ack = NEW.public_acknowledge
|
|
WHERE id = OLD.donor_id
|
|
AND (public_ack = OLD.public_acknowledge OR public_ack is NULL);
|
|
|
|
-- FIXME: I think this error message doesn't properly display when NEW.ticket
|
|
-- is NOT NULL and the select returns a NULL
|
|
|
|
SELECT CASE
|
|
WHEN ( (SELECT public_ack FROM donor WHERE id = OLD.donor_id) != NEW.public_acknowledge )
|
|
THEN RAISE(FAIL, "Error encountered while updating public_acknowledge setting; please verify your changes worked!")
|
|
END;
|
|
|
|
END;
|
|
-- -------------- END VIEW: UserOperation_donor_update ---------------------
|
|
|
|
-- -------------- VIEW: UserOperation_contact_setting_change ---------------------
|
|
|
|
|
|
-- For this one, note that request_type(id) of 12 is hard-coded since that's known to be the "contact-setting" one.
|
|
-- … it would obviously be better not to hard code it, but looking it up in every query would make it harder to read.
|
|
DROP VIEW IF EXISTS UserQuery_contact_settings;
|
|
CREATE VIEW UserQuery_contact_settings AS
|
|
SELECT request_configuration.description as setting_requested, request_type.type as contact_setting
|
|
FROM request_configuration, request_type
|
|
WHERE request_type.type = "contact-setting"
|
|
AND request_configuration.request_type_id = request_type.id
|
|
ORDER BY request_type.type, request_configuration.description;
|
|
|
|
DROP VIEW IF EXISTS UserOperation_contact_setting_change;
|
|
|
|
CREATE VIEW UserOperation_contact_setting_change AS
|
|
SELECT dd.ledger_entity_id as entity, rt.type as contact_setting, rc.description as setting_requested,
|
|
rr.date_requested as request_date, rr.notes as note, dd.id as donor_id, rr.id as request_id
|
|
FROM donor dd
|
|
LEFT JOIN request rr ON dd.id = rr.donor_id AND rr.request_type_id = 12
|
|
LEFT JOIN request_configuration rc ON rc.id = rr.request_configuration_id
|
|
LEFT JOIN request_type rt ON rt.id = rr.request_type_id
|
|
ORDER BY dd.ledger_entity_id, rr.date_requested;
|
|
|
|
DROP TRIGGER IF EXISTS contact_setting_note_updater;
|
|
CREATE TRIGGER contact_setting_note_updater
|
|
INSTEAD OF UPDATE OF note on UserOperation_contact_setting_change
|
|
BEGIN
|
|
SELECT CASE
|
|
WHEN ( OLD.setting_requested IS NULL )
|
|
THEN RAISE(FAIL, "Invalid note setting; Cannot write note on when setting_requested is NULL")
|
|
END;
|
|
|
|
UPDATE request
|
|
SET notes = NEW.note
|
|
WHERE id = OLD.request_id
|
|
AND OLD.request_id is NOT NULL
|
|
AND OLD.donor_id = donor_id
|
|
AND request_type_id = 12;
|
|
END;
|
|
|
|
DROP TRIGGER IF EXISTS contact_setting_config_change_updater;
|
|
CREATE TRIGGER contact_setting_config_change_updater
|
|
INSTEAD OF UPDATE OF setting_requested on UserOperation_contact_setting_change
|
|
BEGIN
|
|
|
|
DELETE FROM zz__temp_request_configuration_change;
|
|
|
|
INSERT INTO zz__temp_request_configuration_change(new_description) VALUES(NEW.setting_requested);
|
|
|
|
UPDATE zz__temp_request_configuration_change
|
|
SET new_request_configuration_id =
|
|
(SELECT rc.id FROM request_configuration rc, request_type rt
|
|
WHERE rc.description = NEW.setting_requested
|
|
AND rt.id = rc.request_type_id
|
|
AND rt.id = 12)
|
|
WHERE new_description = NEW.setting_requested;
|
|
|
|
UPDATE zz__temp_request_configuration_change set old_request_configuration_id =
|
|
(SELECT rc.id
|
|
FROM request_configuration rc, request_type rt
|
|
where rc.description = OLD.setting_requested
|
|
and rt.id = rc.request_type_id
|
|
and rt.type = OLD.contact_setting)
|
|
WHERE new_description = NEW.setting_requested
|
|
AND new_request_configuration_id IS NOT NULL;
|
|
|
|
SELECT CASE
|
|
WHEN ( (SELECT new_request_configuration_id from zz__temp_request_configuration_change) IS NULL )
|
|
THEN RAISE(FAIL, "Invalid contact setting; see UserQuery_contact_settings to find what settings are permitted here!")
|
|
END;
|
|
|
|
INSERT OR IGNORE INTO request(donor_id, request_type_id, request_configuration_id, date_requested, notes)
|
|
VALUES(OLD.donor_id, 12,
|
|
(SELECT new_request_configuration_id from zz__temp_request_configuration_change),
|
|
date("now"), NEW.note);
|
|
|
|
-- The following UPDATE will effect 0 rows if OLD.request_id is NULL and this is *by design*.
|
|
-- The reason why is we have a UNIQUE index on request(donor_id, request_type_id) and as such, we want
|
|
-- to just UPDATE an existing request_type_id of 12 (aka "contact-setting") on this trigger if one is present;
|
|
-- otherwise we want to INSERT it. This is why we did the INSERT OR IGNORE above first; if that fails, then this
|
|
-- UPDATE will succeed.
|
|
|
|
UPDATE request
|
|
SET request_configuration_id =
|
|
(select new_request_configuration_id from zz__temp_request_configuration_change),
|
|
date_requested = date("now")
|
|
WHERE id = OLD.request_id
|
|
AND OLD.request_id is NOT NULL
|
|
AND OLD.donor_id = donor_id
|
|
AND request_type_id = 12
|
|
AND request_configuration_id =
|
|
(select old_request_configuration_id from zz__temp_request_configuration_change);
|
|
|
|
DELETE FROM zz__temp_request_configuration_change;
|
|
|
|
END;
|
|
-- -------------- VIEW: UserOperation_contact_setting_change ---------------------
|