From: scottmk Date: Wed, 2 Jun 2010 19:24:14 +0000 (+0000) Subject: Replace most of the serial schema with a different set of tables. Only X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=2aecaa3146e3266afcf84ea5cda04c44d349f07f;p=contrib%2FConifer.git Replace most of the serial schema with a different set of tables. Only the serial.record_entry table remains unscathed. In addition: a new table asset.copy_template. M Open-ILS/src/sql/Pg/002.schema.config.sql M Open-ILS/src/sql/Pg/040.schema.asset.sql A Open-ILS/src/sql/Pg/upgrade/0288.schema.serial-overhaul.sql M Open-ILS/src/sql/Pg/210.schema.serials.sql M Open-ILS/examples/fm_IDL.xml git-svn-id: svn://svn.open-ils.org/ILS/trunk@16563 dcc99617-32d9-48b4-a31d-7c20da2025e4 --- diff --git a/Open-ILS/examples/fm_IDL.xml b/Open-ILS/examples/fm_IDL.xml index 9aa89734a2..6040f79143 100644 --- a/Open-ILS/examples/fm_IDL.xml +++ b/Open-ILS/examples/fm_IDL.xml @@ -3010,76 +3010,236 @@ Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA + - - - - - + + + + + - - + - - - + + + + - + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + - - - - - - + + + + + + + + + + + + + - - - + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + - + - + + - + - + + - + - + @@ -3944,6 +4104,45 @@ Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + diff --git a/Open-ILS/src/sql/Pg/002.schema.config.sql b/Open-ILS/src/sql/Pg/002.schema.config.sql index 382d40ac11..6ff9ad75d6 100644 --- a/Open-ILS/src/sql/Pg/002.schema.config.sql +++ b/Open-ILS/src/sql/Pg/002.schema.config.sql @@ -65,7 +65,7 @@ CREATE TABLE config.upgrade_log ( install_date TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW() ); -INSERT INTO config.upgrade_log (version) VALUES ('0287'); -- miker +INSERT INTO config.upgrade_log (version) VALUES ('0288'); -- Scott McKellar CREATE TABLE config.bib_source ( id SERIAL PRIMARY KEY, diff --git a/Open-ILS/src/sql/Pg/040.schema.asset.sql b/Open-ILS/src/sql/Pg/040.schema.asset.sql index 65f0d4f9be..cdc0354de6 100644 --- a/Open-ILS/src/sql/Pg/040.schema.asset.sql +++ b/Open-ILS/src/sql/Pg/040.schema.asset.sql @@ -216,6 +216,47 @@ CREATE TABLE asset.call_number_note ( ); CREATE INDEX asset_call_number_note_creator_idx ON asset.call_number_note ( creator ); +CREATE TABLE asset.copy_template ( + id SERIAL PRIMARY KEY, + owning_lib INT NOT NULL + REFERENCES actor.org_unit (id) + DEFERRABLE INITIALLY DEFERRED, + creator BIGINT NOT NULL + REFERENCES actor.usr (id) + DEFERRABLE INITIALLY DEFERRED, + editor BIGINT NOT NULL + REFERENCES actor.usr (id) + DEFERRABLE INITIALLY DEFERRED, + create_date TIMESTAMP WITH TIME ZONE DEFAULT NOW(), + edit_date TIMESTAMP WITH TIME ZONE DEFAULT NOW(), + name TEXT NOT NULL, + -- columns above this point are attributes of the template itself + -- columns after this point are attributes of the copy this template modifies/creates + circ_lib INT REFERENCES actor.org_unit (id) + DEFERRABLE INITIALLY DEFERRED, + status INT REFERENCES config.copy_status (id) + DEFERRABLE INITIALLY DEFERRED, + location INT REFERENCES asset.copy_location (id) + DEFERRABLE INITIALLY DEFERRED, + loan_duration INT CONSTRAINT valid_loan_duration CHECK ( + loan_duration IS NULL OR loan_duration IN (1,2,3)), + fine_level INT CONSTRAINT valid_fine_level CHECK ( + fine_level IS NULL OR loan_duration IN (1,2,3)), + age_protect INT, + circulate BOOL, + deposit BOOL, + ref BOOL, + holdable BOOL, + deposit_amount NUMERIC(6,2), + price NUMERIC(8,2), + circ_modifier TEXT, + circ_as_type TEXT, + alert_message TEXT, + opac_visible BOOL, + floating BOOL, + mint_condition BOOL +); + CREATE VIEW stats.fleshed_copy AS SELECT cp.*, CAST(cp.create_date AS DATE) AS create_date_day, diff --git a/Open-ILS/src/sql/Pg/210.schema.serials.sql b/Open-ILS/src/sql/Pg/210.schema.serials.sql index 5207729fe9..d0edba9d8d 100644 --- a/Open-ILS/src/sql/Pg/210.schema.serials.sql +++ b/Open-ILS/src/sql/Pg/210.schema.serials.sql @@ -27,49 +27,178 @@ CREATE INDEX serial_record_entry_owning_lib_idx ON serial.record_entry ( owning_ CREATE RULE protect_mfhd_delete AS ON DELETE TO serial.record_entry DO INSTEAD UPDATE serial.record_entry SET deleted = true WHERE old.id = serial.record_entry.id; CREATE TABLE serial.subscription ( - id SERIAL PRIMARY KEY, - callnumber BIGINT REFERENCES asset.call_number (id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED, - uri INT REFERENCES asset.uri (id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED, - start_date DATE NOT NULL, - end_date DATE -- interpret NULL as current subscription + id SERIAL PRIMARY KEY, + start_date TIMESTAMP WITH TIME ZONE NOT NULL, + end_date TIMESTAMP WITH TIME ZONE, -- interpret NULL as current subscription + record_entry BIGINT REFERENCES serial.record_entry (id) + ON DELETE SET NULL + DEFERRABLE INITIALLY DEFERRED, + expected_date_offset INTERVAL + -- acquisitions/business-side tables link to here ); -CREATE TABLE serial.binding_unit ( - id SERIAL PRIMARY KEY, - subscription INT NOT NULL REFERENCES serial.subscription (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, - label TEXT NOT NULL, - CONSTRAINT bu_label_once_per_sub UNIQUE (subscription, label) +--at least one distribution per org_unit holding issues +CREATE TABLE serial.distribution ( + id SERIAL PRIMARY KEY, + subscription INT NOT NULL + REFERENCES serial.subscription (id) + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + holding_lib INT NOT NULL + REFERENCES actor.org_unit (id) + DEFERRABLE INITIALLY DEFERRED, + label TEXT NOT NULL, + receive_call_number BIGINT REFERENCES asset.call_number (id) + DEFERRABLE INITIALLY DEFERRED, + receive_unit_template INT REFERENCES asset.copy_template (id) + DEFERRABLE INITIALLY DEFERRED, + bind_call_number BIGINT REFERENCES asset.call_number (id) + DEFERRABLE INITIALLY DEFERRED, + bind_unit_template INT REFERENCES asset.copy_template (id) + DEFERRABLE INITIALLY DEFERRED, + unit_label_base TEXT, + unit_label_suffix TEXT +); + +CREATE TABLE serial.stream ( + id SERIAL PRIMARY KEY, + distribution INT NOT NULL + REFERENCES serial.distribution (id) + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + routing_label TEXT +); + +CREATE UNIQUE INDEX label_once_per_dist + ON serial.stream (distribution, routing_label) + WHERE routing_label IS NOT NULL; + +CREATE TABLE serial.routing_list_user ( + id SERIAL PRIMARY KEY, + stream INT NOT NULL + REFERENCES serial.stream + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + pos INT NOT NULL DEFAULT 1, + reader INT REFERENCES actor.usr + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + department TEXT, + note TEXT, + CONSTRAINT one_pos_per_routing_list UNIQUE ( stream, pos ), + CONSTRAINT reader_or_dept CHECK + ( + -- Recipient is a person or a department, but not both + (reader IS NOT NULL AND department IS NULL) OR + (reader IS NULL AND department IS NOT NULL) + ) ); CREATE TABLE serial.issuance ( - id SERIAL PRIMARY KEY, - subscription INT NOT NULL REFERENCES serial.subscription (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, - target_copy BIGINT REFERENCES asset.copy (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, - location BIGINT REFERENCES asset.copy_location(id) DEFERRABLE INITIALLY DEFERRED, - binding_unit INT REFERENCES serial.binding_unit (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, - label TEXT + id SERIAL PRIMARY KEY, + creator INT NOT NULL + REFERENCES actor.usr (id) + DEFERRABLE INITIALLY DEFERRED, + editor INT NOT NULL + REFERENCES actor.usr (id) + DEFERRABLE INITIALLY DEFERRED, + create_date TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), + edit_date TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), + subscription INT NOT NULL + REFERENCES serial.subscription (id) + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + label TEXT, + date_published TIMESTAMP WITH TIME ZONE, + holding_code TEXT, + holding_type TEXT CONSTRAINT valid_holding_type CHECK + ( + holding_type IS NULL + OR holding_type IN ('basic','supplement','index') + ), + holding_link_id INT + -- TODO: add columns for separate enumeration/chronology values +); + +CREATE TABLE serial.unit ( + label TEXT, + label_sort_key TEXT, + contents TEXT NOT NULL +) INHERITS (asset.copy); + +ALTER TABLE serial.unit ADD PRIMARY KEY (id); + +CREATE TABLE serial.item ( + id SERIAL PRIMARY KEY, + creator INT NOT NULL + REFERENCES actor.usr (id) + DEFERRABLE INITIALLY DEFERRED, + editor INT NOT NULL + REFERENCES actor.usr (id) + DEFERRABLE INITIALLY DEFERRED, + create_date TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), + edit_date TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), + issuance INT NOT NULL + REFERENCES serial.issuance (id) + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + stream INT NOT NULL + REFERENCES serial.stream (id) + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + unit INT REFERENCES serial.unit (id) + ON DELETE SET NULL + DEFERRABLE INITIALLY DEFERRED, + uri INT REFERENCES asset.uri (id) + ON DELETE SET NULL + DEFERRABLE INITIALLY DEFERRED, + date_expected TIMESTAMP WITH TIME ZONE, + date_received TIMESTAMP WITH TIME ZONE +); + +CREATE TABLE serial.item_note ( + id SERIAL PRIMARY KEY, + item INT NOT NULL + REFERENCES serial.item (id) + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + creator INT NOT NULL + REFERENCES actor.usr (id) + DEFERRABLE INITIALLY DEFERRED, + create_date TIMESTAMP WITH TIME ZONE DEFAULT NOW(), + pub BOOL NOT NULL DEFAULT FALSE, + title TEXT NOT NULL, + value TEXT NOT NULL ); CREATE TABLE serial.bib_summary ( - id SERIAL PRIMARY KEY, - subscription INT UNIQUE NOT NULL REFERENCES serial.subscription (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, - generated_coverage TEXT NOT NULL, - textual_holdings TEXT + id SERIAL PRIMARY KEY, + distribution INT NOT NULL + REFERENCES serial.distribution (id) + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + generated_coverage TEXT NOT NULL, + textual_holdings TEXT ); CREATE TABLE serial.sup_summary ( - id SERIAL PRIMARY KEY, - subscription INT UNIQUE NOT NULL REFERENCES serial.subscription (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, - generated_coverage TEXT NOT NULL, - textual_holdings TEXT + id SERIAL PRIMARY KEY, + distribution INT NOT NULL + REFERENCES serial.distribution (id) + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + generated_coverage TEXT NOT NULL, + textual_holdings TEXT ); CREATE TABLE serial.index_summary ( - id SERIAL PRIMARY KEY, - subscription INT UNIQUE NOT NULL REFERENCES serial.subscription (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, - generated_coverage TEXT NOT NULL, - textual_holdings TEXT + id SERIAL PRIMARY KEY, + distribution INT NOT NULL + REFERENCES serial.distribution (id) + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + generated_coverage TEXT NOT NULL, + textual_holdings TEXT ); COMMIT; - diff --git a/Open-ILS/src/sql/Pg/upgrade/0288.schema.serial-overhaul.sql b/Open-ILS/src/sql/Pg/upgrade/0288.schema.serial-overhaul.sql new file mode 100644 index 0000000000..93e64cb6ca --- /dev/null +++ b/Open-ILS/src/sql/Pg/upgrade/0288.schema.serial-overhaul.sql @@ -0,0 +1,237 @@ +-- The following DROP statements are outside of the transaction. +-- That way if one of the tables doesn't exist, the DROP will +-- fail but the rest of the script can still run. + +DROP TABLE serial.bib_summary CASCADE; + +DROP TABLE serial.index_summary CASCADE; + +DROP TABLE serial.sup_summary CASCADE; + +DROP TABLE serial.issuance CASCADE; + +DROP TABLE serial.binding_unit CASCADE; + +DROP TABLE serial.subscription CASCADE; + +BEGIN; + +INSERT INTO config.upgrade_log (version) VALUES ('0288'); -- Scott McKellar + +CREATE TABLE asset.copy_template ( + id SERIAL PRIMARY KEY, + owning_lib INT NOT NULL + REFERENCES actor.org_unit (id) + DEFERRABLE INITIALLY DEFERRED, + creator BIGINT NOT NULL + REFERENCES actor.usr (id) + DEFERRABLE INITIALLY DEFERRED, + editor BIGINT NOT NULL + REFERENCES actor.usr (id) + DEFERRABLE INITIALLY DEFERRED, + create_date TIMESTAMP WITH TIME ZONE DEFAULT NOW(), + edit_date TIMESTAMP WITH TIME ZONE DEFAULT NOW(), + name TEXT NOT NULL, + -- columns above this point are attributes of the template itself + -- columns after this point are attributes of the copy this template modifies/creates + circ_lib INT REFERENCES actor.org_unit (id) + DEFERRABLE INITIALLY DEFERRED, + status INT REFERENCES config.copy_status (id) + DEFERRABLE INITIALLY DEFERRED, + location INT REFERENCES asset.copy_location (id) + DEFERRABLE INITIALLY DEFERRED, + loan_duration INT CONSTRAINT valid_loan_duration CHECK ( + loan_duration IS NULL OR loan_duration IN (1,2,3)), + fine_level INT CONSTRAINT valid_fine_level CHECK ( + fine_level IS NULL OR loan_duration IN (1,2,3)), + age_protect INT, + circulate BOOL, + deposit BOOL, + ref BOOL, + holdable BOOL, + deposit_amount NUMERIC(6,2), + price NUMERIC(8,2), + circ_modifier TEXT, + circ_as_type TEXT, + alert_message TEXT, + opac_visible BOOL, + floating BOOL, + mint_condition BOOL +); + +CREATE TABLE serial.subscription ( + id SERIAL PRIMARY KEY, + start_date TIMESTAMP WITH TIME ZONE NOT NULL, + end_date TIMESTAMP WITH TIME ZONE, -- interpret NULL as current subscription + record_entry BIGINT REFERENCES serial.record_entry (id) + ON DELETE SET NULL + DEFERRABLE INITIALLY DEFERRED, + expected_date_offset INTERVAL + -- acquisitions/business-side tables link to here +); + +--at least one distribution per org_unit holding issues +CREATE TABLE serial.distribution ( + id SERIAL PRIMARY KEY, + subscription INT NOT NULL + REFERENCES serial.subscription (id) + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + holding_lib INT NOT NULL + REFERENCES actor.org_unit (id) + DEFERRABLE INITIALLY DEFERRED, + label TEXT NOT NULL, + receive_call_number BIGINT REFERENCES asset.call_number (id) + DEFERRABLE INITIALLY DEFERRED, + receive_unit_template INT REFERENCES asset.copy_template (id) + DEFERRABLE INITIALLY DEFERRED, + bind_call_number BIGINT REFERENCES asset.call_number (id) + DEFERRABLE INITIALLY DEFERRED, + bind_unit_template INT REFERENCES asset.copy_template (id) + DEFERRABLE INITIALLY DEFERRED, + unit_label_base TEXT, + unit_label_suffix TEXT +); + +CREATE TABLE serial.stream ( + id SERIAL PRIMARY KEY, + distribution INT NOT NULL + REFERENCES serial.distribution (id) + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + routing_label TEXT +); + +CREATE UNIQUE INDEX label_once_per_dist + ON serial.stream (distribution, routing_label) + WHERE routing_label IS NOT NULL; + +CREATE TABLE serial.routing_list_user ( + id SERIAL PRIMARY KEY, + stream INT NOT NULL + REFERENCES serial.stream + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + pos INT NOT NULL DEFAULT 1, + reader INT REFERENCES actor.usr + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + department TEXT, + note TEXT, + CONSTRAINT one_pos_per_routing_list UNIQUE ( stream, pos ), + CONSTRAINT reader_or_dept CHECK + ( + -- Recipient is a person or a department, but not both + (reader IS NOT NULL AND department IS NULL) OR + (reader IS NULL AND department IS NOT NULL) + ) +); + +CREATE TABLE serial.issuance ( + id SERIAL PRIMARY KEY, + creator INT NOT NULL + REFERENCES actor.usr (id) + DEFERRABLE INITIALLY DEFERRED, + editor INT NOT NULL + REFERENCES actor.usr (id) + DEFERRABLE INITIALLY DEFERRED, + create_date TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), + edit_date TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), + subscription INT NOT NULL + REFERENCES serial.subscription (id) + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + label TEXT, + date_published TIMESTAMP WITH TIME ZONE, + holding_code TEXT, + holding_type TEXT CONSTRAINT valid_holding_type CHECK + ( + holding_type IS NULL + OR holding_type IN ('basic','supplement','index') + ), + holding_link_id INT + -- TODO: add columns for separate enumeration/chronology values +); + +CREATE TABLE serial.unit ( + label TEXT, + label_sort_key TEXT, + contents TEXT NOT NULL +) INHERITS (asset.copy); + +ALTER TABLE serial.unit ADD PRIMARY KEY (id); + +CREATE TABLE serial.item ( + id SERIAL PRIMARY KEY, + creator INT NOT NULL + REFERENCES actor.usr (id) + DEFERRABLE INITIALLY DEFERRED, + editor INT NOT NULL + REFERENCES actor.usr (id) + DEFERRABLE INITIALLY DEFERRED, + create_date TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), + edit_date TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), + issuance INT NOT NULL + REFERENCES serial.issuance (id) + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + stream INT NOT NULL + REFERENCES serial.stream (id) + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + unit INT REFERENCES serial.unit (id) + ON DELETE SET NULL + DEFERRABLE INITIALLY DEFERRED, + uri INT REFERENCES asset.uri (id) + ON DELETE SET NULL + DEFERRABLE INITIALLY DEFERRED, + date_expected TIMESTAMP WITH TIME ZONE, + date_received TIMESTAMP WITH TIME ZONE +); + +CREATE TABLE serial.item_note ( + id SERIAL PRIMARY KEY, + item INT NOT NULL + REFERENCES serial.item (id) + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + creator INT NOT NULL + REFERENCES actor.usr (id) + DEFERRABLE INITIALLY DEFERRED, + create_date TIMESTAMP WITH TIME ZONE DEFAULT NOW(), + pub BOOL NOT NULL DEFAULT FALSE, + title TEXT NOT NULL, + value TEXT NOT NULL +); + +CREATE TABLE serial.bib_summary ( + id SERIAL PRIMARY KEY, + distribution INT NOT NULL + REFERENCES serial.distribution (id) + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + generated_coverage TEXT NOT NULL, + textual_holdings TEXT +); + +CREATE TABLE serial.sup_summary ( + id SERIAL PRIMARY KEY, + distribution INT NOT NULL + REFERENCES serial.distribution (id) + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + generated_coverage TEXT NOT NULL, + textual_holdings TEXT +); + +CREATE TABLE serial.index_summary ( + id SERIAL PRIMARY KEY, + distribution INT NOT NULL + REFERENCES serial.distribution (id) + ON DELETE CASCADE + DEFERRABLE INITIALLY DEFERRED, + generated_coverage TEXT NOT NULL, + textual_holdings TEXT +); + +COMMIT;