From: Mike Rylander Date: Wed, 13 Mar 2013 18:47:16 +0000 (-0400) Subject: Stamping upgrade scripts for "Storing Z39.50 Passwords on the server" X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=b973f1bb2006c06756ff75436ac2f3ab5986caf1;p=contrib%2FConifer.git Stamping upgrade scripts for "Storing Z39.50 Passwords on the server" Signed-off-by: Mike Rylander --- diff --git a/Open-ILS/src/sql/Pg/002.schema.config.sql b/Open-ILS/src/sql/Pg/002.schema.config.sql index 1c9323f8c6..e578c0fab6 100644 --- a/Open-ILS/src/sql/Pg/002.schema.config.sql +++ b/Open-ILS/src/sql/Pg/002.schema.config.sql @@ -91,7 +91,7 @@ CREATE TRIGGER no_overlapping_deps BEFORE INSERT OR UPDATE ON config.db_patch_dependencies FOR EACH ROW EXECUTE PROCEDURE evergreen.array_overlap_check ('deprecates'); -INSERT INTO config.upgrade_log (version, applied_to) VALUES ('0773', :eg_version); -- Callender/berick +INSERT INTO config.upgrade_log (version, applied_to) VALUES ('0774', :eg_version); -- berick/miker CREATE TABLE config.bib_source ( id SERIAL PRIMARY KEY, diff --git a/Open-ILS/src/sql/Pg/upgrade/0774.schema.z3950_credentials.sql b/Open-ILS/src/sql/Pg/upgrade/0774.schema.z3950_credentials.sql new file mode 100644 index 0000000000..739b20f9c5 --- /dev/null +++ b/Open-ILS/src/sql/Pg/upgrade/0774.schema.z3950_credentials.sql @@ -0,0 +1,62 @@ + +BEGIN; + +SELECT evergreen.upgrade_deps_block_check('0773', :eg_version); + +CREATE TABLE config.z3950_source_credentials ( + id SERIAL PRIMARY KEY, + owner INTEGER NOT NULL REFERENCES actor.org_unit(id), + source TEXT NOT NULL REFERENCES config.z3950_source(name) ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE INITIALLY DEFERRED, + -- do some Z servers require a username but no password or vice versa? + username TEXT, + password TEXT, + CONSTRAINT czsc_source_once_per_lib UNIQUE (source, owner) +); + +-- find the most relevant set of credentials for the Z source and org +CREATE OR REPLACE FUNCTION config.z3950_source_credentials_lookup + (source TEXT, owner INTEGER) + RETURNS config.z3950_source_credentials AS $$ + + SELECT creds.* + FROM config.z3950_source_credentials creds + JOIN actor.org_unit aou ON (aou.id = creds.owner) + JOIN actor.org_unit_type aout ON (aout.id = aou.ou_type) + WHERE creds.source = $1 AND creds.owner IN ( + SELECT id FROM actor.org_unit_ancestors($2) + ) + ORDER BY aout.depth DESC LIMIT 1; + +$$ LANGUAGE SQL STABLE; + +-- since we are not exposing config.z3950_source_credentials +-- via the IDL, providing a stored proc gives us a way to +-- set values in the table via cstore +CREATE OR REPLACE FUNCTION config.z3950_source_credentials_apply + (src TEXT, org INTEGER, uname TEXT, passwd TEXT) + RETURNS VOID AS $$ +BEGIN + PERFORM 1 FROM config.z3950_source_credentials + WHERE owner = org AND source = src; + + IF FOUND THEN + IF COALESCE(uname, '') = '' AND COALESCE(passwd, '') = '' THEN + DELETE FROM config.z3950_source_credentials + WHERE owner = org AND source = src; + ELSE + UPDATE config.z3950_source_credentials + SET username = uname, password = passwd + WHERE owner = org AND source = src; + END IF; + ELSE + IF COALESCE(uname, '') <> '' OR COALESCE(passwd, '') <> '' THEN + INSERT INTO config.z3950_source_credentials + (source, owner, username, password) + VALUES (src, org, uname, passwd); + END IF; + END IF; +END; +$$ LANGUAGE PLPGSQL; + + +COMMIT; diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.z3950_credentials.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.z3950_credentials.sql deleted file mode 100644 index 37a21c03f0..0000000000 --- a/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.z3950_credentials.sql +++ /dev/null @@ -1,60 +0,0 @@ - -BEGIN; - -CREATE TABLE config.z3950_source_credentials ( - id SERIAL PRIMARY KEY, - owner INTEGER NOT NULL REFERENCES actor.org_unit(id), - source TEXT NOT NULL REFERENCES config.z3950_source(name) ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE INITIALLY DEFERRED, - -- do some Z servers require a username but no password or vice versa? - username TEXT, - password TEXT, - CONSTRAINT czsc_source_once_per_lib UNIQUE (source, owner) -); - --- find the most relevant set of credentials for the Z source and org -CREATE OR REPLACE FUNCTION config.z3950_source_credentials_lookup - (source TEXT, owner INTEGER) - RETURNS config.z3950_source_credentials AS $$ - - SELECT creds.* - FROM config.z3950_source_credentials creds - JOIN actor.org_unit aou ON (aou.id = creds.owner) - JOIN actor.org_unit_type aout ON (aout.id = aou.ou_type) - WHERE creds.source = $1 AND creds.owner IN ( - SELECT id FROM actor.org_unit_ancestors($2) - ) - ORDER BY aout.depth DESC LIMIT 1; - -$$ LANGUAGE SQL STABLE; - --- since we are not exposing config.z3950_source_credentials --- via the IDL, providing a stored proc gives us a way to --- set values in the table via cstore -CREATE OR REPLACE FUNCTION config.z3950_source_credentials_apply - (src TEXT, org INTEGER, uname TEXT, passwd TEXT) - RETURNS VOID AS $$ -BEGIN - PERFORM 1 FROM config.z3950_source_credentials - WHERE owner = org AND source = src; - - IF FOUND THEN - IF COALESCE(uname, '') = '' AND COALESCE(passwd, '') = '' THEN - DELETE FROM config.z3950_source_credentials - WHERE owner = org AND source = src; - ELSE - UPDATE config.z3950_source_credentials - SET username = uname, password = passwd - WHERE owner = org AND source = src; - END IF; - ELSE - IF COALESCE(uname, '') <> '' OR COALESCE(passwd, '') <> '' THEN - INSERT INTO config.z3950_source_credentials - (source, owner, username, password) - VALUES (src, org, uname, passwd); - END IF; - END IF; -END; -$$ LANGUAGE PLPGSQL; - - -COMMIT;