-- Conservancy Supporter Database, Version 0.2 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. 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;