2022-06-22 17:53:05 +00:00
-- Conservancy Supporter Database, Version 0.4
2015-01-03 23:02:18 +00:00
2015-12-30 11:10:07 +00:00
DROP TABLE IF EXISTS " donor " ;
2015-12-06 23:42:50 +00:00
2015-12-30 11:10:07 +00:00
CREATE TABLE " donor " (
2015-01-03 23:02:18 +00:00
" id " integer NOT NULL PRIMARY KEY ,
" ledger_entity_id " varchar ( 300 ) NOT NULL UNIQUE ,
" display_name " varchar ( 300 ) ,
2015-12-30 11:10:07 +00:00
" public_ack " bool ,
2021-01-13 20:04:05 +00:00
" is_supporter " bool NOT NULL ,
" rt_ticket integer
2015-01-03 23:02:18 +00:00
) ;
2015-12-06 23:42:53 +00:00
DROP TABLE IF EXISTS " request " ;
2015-12-06 23:42:50 +00:00
CREATE TABLE " request " (
" id " integer NOT NULL PRIMARY KEY ,
2015-12-30 11:10:07 +00:00
" donor_id " integer NOT NULL ,
2015-12-06 23:42:50 +00:00
" request_type_id " integer NOT NULL ,
" request_configuration_id " integer ,
" date_requested " date NOT NULL ,
" notes " TEXT
) ;
2015-12-30 11:10:07 +00:00
CREATE UNIQUE INDEX request__one_request_for_each_type_per_donor
ON request ( donor_id , request_type_id ) ;
2015-12-20 22:07:57 +00:00
2015-12-06 23:42:53 +00:00
DROP TABLE IF EXISTS " request_configuration " ;
2015-12-06 23:42:50 +00:00
CREATE TABLE " request_configuration " (
" id " integer NOT NULL PRIMARY KEY ,
" request_type_id " integer NOT NULL ,
2015-12-06 23:42:56 +00:00
" description " varchar ( 100 ) NOT NULL
2015-12-06 23:42:50 +00:00
) ;
2015-12-13 21:37:52 +00:00
CREATE UNIQUE INDEX request_configuration__single_description
ON request_configuration ( request_type_id , description ) ;
2015-12-06 23:42:53 +00:00
DROP TABLE IF EXISTS " fulfillment " ;
2015-12-06 23:42:50 +00:00
CREATE TABLE " fulfillment " (
" id " integer NOT NULL PRIMARY KEY ,
2015-12-20 21:59:50 +00:00
" request_id " integer NOT NULL ,
2015-12-06 23:42:50 +00:00
" date " TEXT NOT NULL ,
" who " varchar ( 300 ) NOT NULL ,
2015-12-06 23:42:56 +00:00
" how " TEXT
2015-12-06 23:42:50 +00:00
) ;
2015-12-20 21:59:50 +00:00
CREATE UNIQUE INDEX fulfillment__one_fulfillment_per_request ON fulfillment ( request_id ) ;
2016-12-08 23:08:53 +00:00
DROP TABLE IF EXISTS " request_hold " ;
CREATE TABLE " request_hold " (
" id " integer NOT NULL PRIMARY KEY ,
" request_id " integer NOT NULL ,
2023-01-02 23:59:12 +00:00
" hold_date " date NOT NULL ,
" release_date " date ,
2016-12-08 23:08:53 +00:00
" who " varchar ( 300 ) NOT NULL ,
" why " TEXT
) ;
CREATE UNIQUE INDEX request_hold__one_hold_per_request ON request_hold ( request_id ) ;
2015-12-06 23:42:53 +00:00
DROP TABLE IF EXISTS " request_type " ;
2015-12-06 23:42:50 +00:00
CREATE TABLE " request_type " (
" id " integer NOT NULL PRIMARY KEY ,
2015-12-06 23:42:56 +00:00
" type " varchar ( 100 ) NOT NULL
2015-12-06 23:42:50 +00:00
) ;
2019-12-10 17:33:37 +00:00
DROP TABLE IF EXISTS " delivery_error " ;
CREATE TABLE " delivery_error " (
" id " integer NOT NULL PRIMARY KEY ,
" error " varchar ( 300 ) NOT NULL UNIQUE
) ;
2015-12-06 23:42:53 +00:00
DROP TABLE IF EXISTS " email_address " ;
2015-12-06 23:42:50 +00:00
CREATE TABLE " email_address " (
" id " integer NOT NULL PRIMARY KEY ,
" email_address " varchar ( 300 ) NOT NULL UNIQUE ,
" type_id " integer ,
2015-12-06 23:42:56 +00:00
" date_encountered " date NOT NULL
2015-12-06 23:42:50 +00:00
) ;
2019-12-10 17:33:37 +00:00
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
) ;
2015-12-30 11:10:07 +00:00
DROP TABLE IF EXISTS " donor_email_address_mapping " ;
2015-12-06 23:42:53 +00:00
2015-12-30 11:10:07 +00:00
CREATE TABLE " donor_email_address_mapping " (
" donor_id " integer NOT NULL ,
2015-12-06 23:42:56 +00:00
" email_address_id " integer NOT NULL ,
2015-12-06 23:42:50 +00:00
" preferred " bool ,
2015-12-30 11:10:07 +00:00
PRIMARY KEY ( donor_id , email_address_id )
2015-12-06 23:42:50 +00:00
) ;
2015-12-06 23:42:53 +00:00
DROP TABLE IF EXISTS " address_type " ;
2015-12-06 23:42:50 +00:00
CREATE TABLE " address_type " (
" id " integer NOT NULL PRIMARY KEY ,
2015-12-06 23:42:56 +00:00
" name " varchar ( 50 ) NOT NULL UNIQUE
2015-12-06 23:42:50 +00:00
) ;
2022-12-16 19:36:15 +00:00
DROP TABLE IF EXISTS " old_postal_address " ;
2015-12-06 23:42:53 +00:00
2022-12-16 19:36:15 +00:00
CREATE TABLE " old_postal_address " (
2015-12-06 23:42:50 +00:00
" id " integer NOT NULL PRIMARY KEY ,
" formatted_address " varchar ( 5000 ) ,
" type_id " INTEGER NOT NULL ,
2022-06-21 17:09:27 +00:00
" date_encountered " date NOT NULL ,
" invalid " bool
2015-12-06 23:42:50 +00:00
) ;
2022-12-16 19:36:15 +00:00
DROP TABLE IF EXISTS " old_donor_postal_address_mapping " ;
CREATE TABLE " old_donor_postal_address_mapping " (
" donor_id " integer NOT NULL ,
" old_postal_address_id " integer NOT NULL ,
" preferred " bool ,
PRIMARY KEY ( donor_id , postal_address_id )
) ;
CREATE UNIQUE INDEX old_donor_postal_address_mapping_single_prefferred_per_donor
ON old_donor_postal_address_mapping ( donor_id , preferred ) ;
DROP TABLE IF EXISTS " postal_address " ;
CREATE TABLE " postal_address " (
" id " integer NOT NULL PRIMARY KEY ,
" first_name " varchar ( 64 ) ,
" middle_name " varchar ( 64 ) ,
" last_name " varchar ( 64 ) ,
" organization " varchar ( 64 ) ,
" address_1 " varchar ( 128 ) ,
" address_2 " varchar ( 128 ) ,
" address_3 " varchar ( 128 ) ,
" city " varchar ( 64 ) ,
" state_province_or_region " varchar ( 64 ) ,
" postcode " varchar ( 64 ) ,
" country " varchar ( 64 )
) ;
2015-12-30 11:10:07 +00:00
DROP TABLE IF EXISTS " donor_postal_address_mapping " ;
2015-12-06 23:42:53 +00:00
2015-12-30 11:10:07 +00:00
CREATE TABLE " donor_postal_address_mapping " (
" donor_id " integer NOT NULL ,
2015-12-06 23:43:00 +00:00
" postal_address_id " integer NOT NULL ,
2022-12-16 19:36:15 +00:00
" type_id " INTEGER NOT NULL ,
" date_valid_from " date NOT NULL ,
" date_valid_to " date ,
2015-12-30 11:10:07 +00:00
PRIMARY KEY ( donor_id , postal_address_id )
2015-12-06 23:42:50 +00:00
) ;
2022-12-16 19:36:15 +00:00
CREATE UNIQUE INDEX donor_postal_address_mapping_single_open_ended_addr
ON donor_postal_address_mapping ( donor_id , date_valid_to ) ;
2022-06-21 20:58:21 +00:00
-- ####################################### 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.
2024-11-03 23:54:50 +00:00
-- -------------- 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 ;
2022-11-21 23:25:00 +00:00
-- -------------- VIEW: UserOperation_update_email_address ---------------------
DROP VIEW IF EXISTS UserOperation_email_add_when_none ;
CREATE VIEW UserOperation_email_add_when_none AS
2022-11-22 01:21:55 +00:00
SELECT ledger_entity_id as entity , map . preferred as preferred_override , ea . date_encountered as entered_date ,
2022-11-21 23:25:00 +00:00
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 ;
2022-12-16 19:36:15 +00:00
-- -------------- VIEW: UserOperation_update_postal_address ---------------------
DROP TRIGGER IF EXISTS update_postal_address_preferred_override ;
DROP TRIGGER IF EXISTS update_postal_address_is_invalid ;
DROP TRIGGER IF EXISTS update_formatted_postal_address ;
2024-11-03 23:54:50 +00:00
DROP VIEW IF EXISTS UserOperation_add_postal_for_donor_with_none ;
2022-12-16 19:36:15 +00:00
DROP VIEW IF EXISTS UserOperation_postal_address_change ;
CREATE VIEW UserOperation_postal_address_change AS
SELECT dd . id as donor_id , ledger_entity_id as entity , map . date_valid_from as entered_date , map . date_valid_to as invalidated_date ,
pa . first_name as first_n , pa . middle_name as middle_n , pa . last_name as last_n , pa . organization as org ,
pa . address_1 as addr1 , pa . address_2 as addr2 , pa . address_3 as addr3 , pa . city as city ,
pa . state_province_or_region as state_or_region , pa . postcode as postcode , pa . country as country , pa . id AS postal_id
2022-11-21 23:25:00 +00:00
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
2022-12-16 19:36:15 +00:00
WHERE dd . is_supporter = 1
AND ( map . date_valid_to is NULL OR map . date_valid_to = ( SELECT max ( date_valid_to ) FROM donor_postal_address_mapping where donor_id = dd . id
AND donor_id NOT IN ( SELECT donor_id FROM donor_postal_address_mapping WHERE date_valid_to IS NULL ) ) )
2022-11-21 23:25:00 +00:00
ORDER BY ledger_entity_id ;
2022-12-16 19:36:15 +00:00
DROP TRIGGER IF EXISTS update_postal_address_from_add_UserOperation ;
CREATE TRIGGER update_postal_address_from_add_UserOperation
INSTEAD OF INSERT ON UserOperation_postal_address_change
2022-11-21 23:25:00 +00:00
BEGIN
2022-12-16 19:36:15 +00:00
UPDATE donor_postal_address_mapping SET date_valid_to = date ( " now " )
WHERE donor_id = NEW . donor_id AND date_valid_to IS NULL ;
INSERT INTO postal_address ( first_name , middle_name , last_name , organization , address_1 , address_2 ,
address_3 , city , state_province_or_region , postcode , country )
VALUES ( NEW . first_n , NEW . middle_n , NEW . last_n , NEW . org , NEW . addr1 , NEW . addr2 ,
NEW . addr3 , NEW . city , NEW . state_or_region , NEW . postcode , NEW . country ) ;
2022-11-21 23:25:00 +00:00
-- WITH wt(new_postal_address_id) AS (SELECT last_insert_rowid() AS new_postal_address_id)
2022-12-16 19:36:15 +00:00
INSERT INTO donor_postal_address_mapping ( donor_id , postal_address_id , type_id , date_valid_from )
VALUES ( NEW . donor_id , ( SELECT last_insert_rowid ( ) ) , 21 , date ( " now " ) ) ;
2022-11-21 23:25:00 +00:00
-- VALUES(OLD.donor_id, (SELECT new_postal_address_id FROM wt) );
2023-01-02 23:59:39 +00:00
- -- FIXME: Below doesn't work in sqlitebrowser, still don't know why
-- SELECT CASE
-- WHEN ( (SELECT address_1 FROM donor_postal_address_mapping dp, postal_address pa
-- WHERE dp.donor_id = NEW.donor_id
-- AND pa.id = (SELECT last_insert_rowid() )
-- AND dp.postal_address_id = (SELECT last_insert_rowid() )
-- AND pa.address_1 = NEW.addr1
-- != NEW.addr1 ) )
-- THEN RAISE(FAIL, "Error encountered while adding new postal address; please verify your changes worked!")
-- END;
2022-11-21 23:25:00 +00:00
END ;
2022-12-16 19:36:15 +00:00
DROP TRIGGER IF EXISTS invalidate_postal_address_from_UserOperation ;
CREATE TRIGGER invalidate_postal_address_from_UserOperation
INSTEAD OF UPDATE OF invalidated_date
ON UserOperation_postal_address_change
2022-11-11 00:06:38 +00:00
BEGIN
SELECT CASE
2022-12-16 19:36:15 +00:00
WHEN ( OLD . postal_id is NULL )
THEN RAISE ( FAIL , " Donor has no postal address yet; cannot invalidate non existent address. " )
2022-11-11 00:06:38 +00:00
END ;
2022-12-16 19:36:15 +00:00
UPDATE donor_postal_address_mapping SET date_valid_to = NEW . invalidated_date WHERE donor_id = OLD . donor_id AND postal_address_id = OLD . postal_id ;
-- FIXME, WHY DOES THE BELOW NOT WORK IN sqlitebrowser
-- SELECT CASE
-- WHEN ( (SELECT date_valid_to FROM donor_postal_address_mapping
-- WHERE donor_id = OLD.donor_id
-- AND postal_address_id = OLD.postal_id
-- != NEW.invalidated_date ) )
-- THEN RAISE(FAIL, "Error encountered while invalidating postal address; please verify your changes worked!")
-- END;
2022-11-11 03:38:18 +00:00
END ;
2022-06-22 17:15:37 +00:00
-- -------------- VIEW: UserOperation_fix_tshirt_size_request ---------------------
2022-06-21 20:58:21 +00:00
2022-11-11 03:39:10 +00:00
DROP TABLE IF EXISTS " zz__temp_request_configuration_change " ;
2022-06-22 17:15:37 +00:00
2022-11-11 03:39:10 +00:00
CREATE TABLE zz__temp_request_configuration_change (
2022-06-21 20:58:21 +00:00
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
2022-11-22 01:21:55 +00:00
SELECT donor . ledger_entity_id as entity ,
2022-06-21 20:58:21 +00:00
request_type . type as shirt_requested , request_configuration . description as size_requested ,
2022-06-22 17:15:37 +00:00
request . date_requested as request_date , request . notes as note , donor . id as donor_id , request . id as request_id
2022-06-21 20:58:21 +00:00
FROM donor , request_configuration , request , request_type
WHERE request . id not in ( select request_id from fulfillment ) AND
2023-01-02 23:58:35 +00:00
request_type . type LIKE ' %shirt% ' AND
2022-06-21 20:58:21 +00:00
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 ;
2024-11-03 23:54:50 +00:00
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 ;
2022-06-21 20:58:21 +00:00
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
2022-11-11 03:39:10 +00:00
DELETE FROM zz__temp_request_configuration_change ;
2022-06-21 20:58:21 +00:00
2022-11-11 03:39:10 +00:00
INSERT INTO zz__temp_request_configuration_change ( new_description ) VALUES ( NEW . size_requested ) ;
2022-06-21 20:58:21 +00:00
2022-11-11 03:39:10 +00:00
update zz__temp_request_configuration_change set new_request_configuration_id = ( select rc . id
2022-06-21 20:58:21 +00:00
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 ;
2022-11-11 03:39:10 +00:00
UPDATE zz__temp_request_configuration_change set old_request_configuration_id =
2022-06-21 20:58:21 +00:00
( 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
2022-11-11 03:39:10 +00:00
WHEN ( ( SELECT new_request_configuration_id from zz__temp_request_configuration_change ) IS NULL )
2022-06-21 20:58:21 +00:00
THEN RAISE ( FAIL , " Invalid t-shirt size for this particular t-shirt style! " )
END ;
UPDATE request
set request_configuration_id =
2022-11-11 03:39:10 +00:00
( select new_request_configuration_id from zz__temp_request_configuration_change )
2022-06-21 20:58:21 +00:00
where id = OLD . request_id
and request_configuration_id =
2022-11-11 03:39:10 +00:00
( select old_request_configuration_id from zz__temp_request_configuration_change ) ;
2022-06-21 20:58:21 +00:00
2022-11-11 03:39:10 +00:00
DELETE FROM zz__temp_request_configuration_change ;
2022-06-21 20:58:21 +00:00
END ;
2022-06-22 17:53:05 +00:00
-- -------------- END VIEW: UserOperation_fix_tshirt_size_request ---------------------
-- -------------- VIEW: UserOperation_donor_update ---------------------
DROP VIEW IF EXISTS UserOperation_donor_update ;
CREATE VIEW UserOperation_donor_update AS
2022-11-22 01:21:55 +00:00
SELECT donor . ledger_entity_id as entity , donor . rt_ticket as ticket , donor . display_name as public_name ,
2022-06-22 17:53:05 +00:00
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 ;
2022-11-21 23:24:27 +00:00
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 )
2022-11-22 01:21:55 +00:00
VALUES ( NEW . entity , NEW . public_name , NEW . public_acknowledge , NEW . ticket , 1 ) ;
2022-11-21 23:24:27 +00:00
END ;
2022-06-22 17:53:05 +00:00
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 ---------------------
2022-06-22 21:47:19 +00:00
-- -------------- VIEW: UserOperation_contact_setting_change ---------------------
2022-11-11 03:10:28 +00:00
-- 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.
2022-11-11 00:07:46 +00:00
DROP VIEW IF EXISTS UserQuery_contact_settings ;
CREATE VIEW UserQuery_contact_settings AS
2022-06-22 21:47:19 +00:00
SELECT request_configuration . description as setting_requested , request_type . type as contact_setting
2022-11-11 03:10:28 +00:00
FROM request_configuration , request_type
WHERE request_type . type = " contact-setting "
AND request_configuration . request_type_id = request_type . id
2022-06-22 21:47:19 +00:00
ORDER BY request_type . type , request_configuration . description ;
DROP VIEW IF EXISTS UserOperation_contact_setting_change ;
CREATE VIEW UserOperation_contact_setting_change AS
2022-11-22 01:21:55 +00:00
SELECT dd . ledger_entity_id as entity , rt . type as contact_setting , rc . description as setting_requested ,
2022-06-22 21:47:19 +00:00
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 ;
2022-11-21 19:39:23 +00:00
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 ;
2022-06-22 21:47:19 +00:00
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
2022-11-11 03:39:10 +00:00
DELETE FROM zz__temp_request_configuration_change ;
2022-06-22 21:47:19 +00:00
2022-11-11 03:39:10 +00:00
INSERT INTO zz__temp_request_configuration_change ( new_description ) VALUES ( NEW . setting_requested ) ;
2022-06-22 21:47:19 +00:00
2022-11-11 03:39:10 +00:00
UPDATE zz__temp_request_configuration_change
2022-11-11 03:10:28 +00:00
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 ;
2022-11-11 00:08:06 +00:00
2022-11-11 03:39:10 +00:00
UPDATE zz__temp_request_configuration_change set old_request_configuration_id =
2022-06-22 21:47:19 +00:00
( 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
2022-11-11 03:39:10 +00:00
WHEN ( ( SELECT new_request_configuration_id from zz__temp_request_configuration_change ) IS NULL )
2022-11-11 03:10:28 +00:00
THEN RAISE ( FAIL , " Invalid contact setting; see UserQuery_contact_settings to find what settings are permitted here! " )
2022-06-22 21:47:19 +00:00
END ;
2022-11-11 03:10:28 +00:00
INSERT OR IGNORE INTO request ( donor_id , request_type_id , request_configuration_id , date_requested , notes )
2022-11-21 19:39:05 +00:00
VALUES ( OLD . donor_id , 12 ,
2022-11-11 03:39:10 +00:00
( SELECT new_request_configuration_id from zz__temp_request_configuration_change ) ,
2022-11-11 03:10:28 +00:00
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.
2022-06-22 21:47:19 +00:00
UPDATE request
2022-11-11 03:10:28 +00:00
SET request_configuration_id =
2022-11-11 03:39:10 +00:00
( select new_request_configuration_id from zz__temp_request_configuration_change ) ,
2022-11-11 03:10:28 +00:00
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 =
2022-11-11 03:39:10 +00:00
( select old_request_configuration_id from zz__temp_request_configuration_change ) ;
2022-11-11 03:10:28 +00:00
2022-11-11 03:39:10 +00:00
DELETE FROM zz__temp_request_configuration_change ;
2022-06-22 21:47:19 +00:00
END ;
-- -------------- VIEW: UserOperation_contact_setting_change ---------------------