From: Bill Erickson Date: Fri, 18 Dec 2015 23:09:16 +0000 (-0500) Subject: LP#1527342 SQL getting started X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=06f28779d3e7b4e6f00fe0c85510e6af5e1d1899;p=working%2FEvergreen.git LP#1527342 SQL getting started Signed-off-by: Bill Erickson --- diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.decouple_co_history.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.decouple_co_history.sql new file mode 100644 index 0000000000..5065ae6d73 --- /dev/null +++ b/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.decouple_co_history.sql @@ -0,0 +1,99 @@ + +BEGIN; + +-- TODO process to delete history items once the age threshold +-- history.circ.retention_age is reached? + +-- SELECT evergreen.upgrade_deps_block_check('XXXX', :eg_version); + +CREATE TABLE action.usr_circ_history ( + id BIGSERIAL PRIMARY KEY, + usr INTEGER NOT NULL REFERENCES actor.usr(id) + DEFERRABLE INITIALLY DEFERRED, + xact_start TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), + target_copy BIGINT NOT NULL REFERENCES asset.copy(id) + DEFERRABLE INITIALLY DEFERRED, + due_date TIMESTAMP WITH TIME ZONE NOT NULL, + checkin_time TIMESTAMP WITH TIME ZONE, + source_circ BIGINT NOT NULL REFERENCES action.circulation(id) + ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED +); + +CREATE OR REPLACE FUNCTION action.maintain_usr_circ_history() + RETURNS TRIGGER AS $FUNK$ +DECLARE + cur_circ BIGINT; + first_circ BIGINT; +BEGIN + + -- Any retention value signifies history is enabled. + -- This assumes that clearing these values via external + -- process deletes the action.usr_circ_history rows. + -- TODO: replace these settings w/ a single bool setting? + PERFORM 1 FROM actor.usr_setting + WHERE usr = NEW.usr AND value IS NOT NULL AND name IN ( + 'history.circ.retention_age', + 'history.circ.retention_start' + ); + + IF NOT FOUND THEN + RETURN NEW; + END IF; + + IF TG_OP = 'INSERT' AND NEW.parent_circ IS NULL THEN + -- Starting a new circulation. Insert the history row. + INSERT INTO action.usr_circ_history + (usr, xact_start, target_copy, due_date, source_circ) + VALUES ( + NEW.usr, + NEW.xact_start, + NEW.target_copy, + NEW.due_date, + NEW.id + ); + + RETURN NEW; + END IF; + + -- find the first and last circs in the circ chain + -- for the currently modified circ. + FOR cur_circ IN SELECT id FROM action.circ_chain(NEW.id) LOOP + IF first_circ IS NULL THEN + first_circ := cur_circ; + CONTINUE; + END IF; + -- Allow the loop to continue so that at as the loop + -- completes cur_circ points to the final circulation. + END LOOP; + + IF NEW.id <> cur_circ THEN + -- Modifying an intermediate circ. Ignore it. + RETURN NEW; + END IF; + + -- Update the due_date/checkin_time on the history row if the current + -- circ is the last circ in the chain and an update is warranted. + + UPDATE action.usr_circ_history + SET + due_date = NEW.due_date, + checkin_time = NEW.checkin_time + WHERE + source_circ = first_circ + AND ( + due_date <> NEW.due_date OR + -- coalesce on a common value so we can <> compare NULL's + COALESCE(checkin_time, NEW.xact_start) <> + COALESCE(NEW.checkin_time, NEW.xact_start) + ); + + RETURN NEW; +END; +$FUNK$ LANGUAGE PLPGSQL; + +CREATE TRIGGER maintain_usr_circ_history_tgr + AFTER INSERT OR UPDATE ON action.circulation + FOR EACH ROW EXECUTE PROCEDURE action.maintain_usr_circ_history(); + +COMMIT; +