Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with
or
.
Download ZIP
Browse files

Add triggers to prevent desk asset drift.

There are two disconnected places in the databases where the assets on desks
are tracked. One is the `desk__id` column in the `story`, `media`, and
`template` tables. The other is "asset groups." These are kind of nasty, but
necessary in order for permissions to work properly.

Unfortunately, these two sources can drift from one another. So this commit
adds a migration that corrects any existing drift, and then adds triggers
to prevent it in the future. This required a few other changes:

* The installer now installs PL/pgSQL, which is required for the trigger
  functions. If the database is created in advance, it must include PL/pgSQL
  or the installation will fail.
* Bric::Biz::Workflow::Parts::Desk now has to save its corresponding asset
  group before it saves the assets in that group with new IDs. This won't
  usually be necessary, since the trigger executes at transaction commmit
  time, but tests run under autocommit, and so generated quite a lot of
  errors. By making the order of execution a little saner, the errors go away
  and all tests pass.

For now, there are no corresponding triggers for MySQL. I *think* MySQL 5 can
do the same thing (or close to it), but I don't have the energy to figure out
how just now.

[#272 state:resolved]
  • Loading branch information...
commit ddffd06403d76695ee728529c8b5799887845a8b 1 parent 6d45e11
@theory theory authored
View
16 inst/dbload_Pg.pl
@@ -57,6 +57,7 @@ =head1 See Also
$DBDEFDB = 'template1';
create_db();
+ create_plpgsql();
create_user();
} else {
# Set environment variables for psql.
@@ -128,6 +129,21 @@ sub create_db {
print "Database created.\n";
}
+# create PL/pgSQL
+sub create_plpgsql {
+ print "Creating PL/pgSQL in $DB->{db_name}...\n";
+ my $err = exec_sql(qq{CREATE LANGUAGE plpgsql}, 0, $DB->{db_name});
+
+ if ($err && $err !~ /language "plpgsql" already exists/) {
+ # There was an error.
+ hard_fail(
+ "Failed to create PL/pgSQL. The database error was\n\n",
+ "$err\n"
+ );
+ }
+ print "PL/pgSQL created.\n";
+}
+
# create SYS_USER, optionally dropping an existing syst
sub create_user {
my $user = $DB->{sys_user};
View
425 inst/upgrade/2.1.0/add_desk_triggers.pl
@@ -0,0 +1,425 @@
+#!/usr/bin/perl -w
+
+use strict;
+use File::Spec::Functions qw(catdir updir);
+use FindBin;
+use lib catdir $FindBin::Bin, updir, 'lib';
+use bric_upgrade qw(:all);
+
+# This upgrade is for PostgreSQL only.
+exit if DBD_TYPE ne 'Pg';
+
+exit if fetch_sql q{
+ SELECT true
+ FROM pg_catalog.pg_trigger t
+ JOIN pg_catalog.pg_class c ON c.oid = t.tgrelid
+ WHERE c.relname = 'story_member'
+ AND t.tgname = 'set_member_story_desk_id'
+};
+
+do_sql 'CREATE LANGUAGE plpgsql' unless fetch_sql q{
+ SELECT true
+ FROM pg_catalog.pg_language
+ WHERE lanname = 'plpgsql'
+ AND lanispl
+};
+
+local $/;
+do_sql $_ for split /-- split/, <DATA>;
+
+__DATA__
+-- Set desk ID to 0 where not on a desk.
+UPDATE story SET desk__id = 0
+ WHERE desk__id > 0 AND id NOT IN (
+SELECT story.id
+ FROM story
+ JOIN story_member ON story.id = story_member.object_id
+ JOIN member ON story_member.member__id = member.id
+ JOIN desk ON member.grp__id = desk.asset_grp
+);
+
+-- split
+
+UPDATE media SET desk__id = 0
+ WHERE desk__id > 0 AND id NOT IN (
+SELECT media.id
+ FROM media
+ JOIN media_member ON media.id = media_member.object_id
+ JOIN member ON media_member.member__id = member.id
+ JOIN desk ON member.grp__id = desk.asset_grp
+);
+
+-- split
+
+UPDATE template SET desk__id = 0
+ WHERE desk__id > 0 AND id NOT IN (
+SELECT template.id
+ FROM template
+ JOIN template_member ON template.id = template_member.object_id
+ JOIN member ON template_member.member__id = member.id
+ JOIN desk ON member.grp__id = desk.asset_grp
+);
+
+-- split
+
+-- Set desk ID where asset is on a desk.
+UPDATE story
+ SET desk__id = desk.id
+ FROM story_member
+ JOIN member ON story_member.member__id = member.id
+ JOIN desk ON member.grp__id = desk.asset_grp
+ WHERE story.id = story_member.object_id
+ AND story.desk__id <> desk.id;
+
+-- split
+
+UPDATE media
+ SET desk__id = desk.id
+ FROM media_member
+ JOIN member ON media_member.member__id = member.id
+ JOIN desk ON member.grp__id = desk.asset_grp
+ WHERE media.id = media_member.object_id
+ AND media.desk__id <> desk.id;
+
+-- split
+
+UPDATE template
+ SET desk__id = desk.id
+ FROM template_member
+ JOIN member ON template_member.member__id = member.id
+ JOIN desk ON member.grp__id = desk.asset_grp
+ WHERE template.id = template_member.object_id
+ AND template.desk__id <> desk.id;
+
+-- split
+
+/****************************************************************************/
+-- Add triggers for story desk memberships.
+CREATE OR REPLACE FUNCTION desk_has_story(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ IF TG_OP = 'UPDATE' THEN
+ IF NEW.desk__id = OLD.desk__id THEN RETURN NEW; END IF;
+ END IF;
+ IF NEW.desk__id > 0 THEN
+ IF EXISTS (
+ SELECT story_member.object_id
+ FROM desk
+ JOIN member ON member.grp__id = desk.asset_grp
+ JOIN story_member ON story_member.member__id = member.id
+ WHERE desk.id = NEW.desk__id
+ AND story_member.object_id = NEW.id
+ ) THEN RETURN NEW; END IF;
+ RAISE EXCEPTION 'Desk % should have story % in its group but does not',
+ NEW.desk__id, NEW.id;
+ ELSIF TG_OP = 'UPDATE' THEN
+ IF NOT EXISTS (
+ SELECT story_member.object_id
+ FROM desk
+ JOIN member ON member.grp__id = desk.asset_grp
+ JOIN story_member ON story_member.member__id = member.id
+ WHERE desk.id = OLD.desk__id
+ AND story_member.object_id = NEW.id
+ ) THEN RETURN NEW; END IF;
+ RAISE EXCEPTION 'Desk % should not have story % in its group but does',
+ OLD.desk__id, NEW.id;
+ ELSE
+ RETURN NEW;
+ END IF;
+END;
+$$;
+
+-- split
+
+CREATE CONSTRAINT TRIGGER story_is_on_desk
+ AFTER INSERT OR UPDATE ON story
+DEFERRABLE INITIALLY DEFERRED
+ FOR EACH ROW EXECUTE PROCEDURE desk_has_story();
+
+-- split
+
+CREATE OR REPLACE FUNCTION desk_hasnt_story(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ IF NOT EXISTS (
+ SELECT story_member.object_id
+ FROM desk
+ JOIN member ON member.grp__id = desk.asset_grp
+ JOIN story_member ON story_member.member__id = member.id
+ WHERE desk.id = OLD.desk__id
+ AND story_member.object_id = OLD.id
+ ) THEN RETURN NEW; END IF;
+ RAISE EXCEPTION 'Desk % should not have story % in its group but does',
+ NEW.desk__id, NEW.id;
+END;
+$$;
+
+-- split
+
+CREATE CONSTRAINT TRIGGER story_not_on_desk
+ AFTER DELETE ON story
+DEFERRABLE INITIALLY DEFERRED
+ FOR EACH ROW EXECUTE PROCEDURE desk_hasnt_story();
+
+-- split
+
+CREATE OR REPLACE FUNCTION set_member_story_desk_id(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ UPDATE story
+ SET desk__id = desk.id
+ FROM member
+ JOIN desk ON member.grp__id = desk.asset_grp
+ WHERE story.id = NEW.object_id
+ AND member.id = NEW.member__id;
+ RETURN NEW;
+END;
+$$;
+
+-- split
+
+CREATE TRIGGER set_member_story_desk_id
+ AFTER INSERT OR UPDATE ON story_member
+ FOR EACH ROW EXECUTE PROCEDURE set_member_story_desk_id();
+
+CREATE OR REPLACE FUNCTION unset_member_story_desk_id(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ UPDATE story
+ SET desk__id = 0
+ FROM member
+ JOIN desk ON member.grp__id = desk.asset_grp
+ WHERE story.id = OLD.object_id
+ AND member.id = OLD.member__id
+ AND story.desk__id = desk.id;
+ RETURN OLD;
+END;
+$$;
+
+-- split
+
+CREATE TRIGGER unset_member_story_desk_id
+ BEFORE DELETE ON story_member
+ FOR EACH ROW EXECUTE PROCEDURE unset_member_story_desk_id();
+
+-- split
+
+/****************************************************************************/
+-- Add triggers for media desk memberships.
+CREATE OR REPLACE FUNCTION desk_has_media(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ IF TG_OP = 'UPDATE' THEN
+ IF NEW.desk__id = OLD.desk__id THEN RETURN NEW; END IF;
+ END IF;
+ IF NEW.desk__id > 0 THEN
+ IF EXISTS (
+ SELECT media_member.object_id
+ FROM desk
+ JOIN member ON member.grp__id = desk.asset_grp
+ JOIN media_member ON media_member.member__id = member.id
+ WHERE desk.id = NEW.desk__id
+ AND media_member.object_id = NEW.id
+ ) THEN RETURN NEW; END IF;
+ RAISE EXCEPTION 'Desk % should have media % in its group but does not',
+ NEW.desk__id, NEW.id;
+ ELSIF TG_OP = 'UPDATE' THEN
+ IF NOT EXISTS (
+ SELECT media_member.object_id
+ FROM desk
+ JOIN member ON member.grp__id = desk.asset_grp
+ JOIN media_member ON media_member.member__id = member.id
+ WHERE desk.id = OLD.desk__id
+ AND media_member.object_id = NEW.id
+ ) THEN RETURN NEW; END IF;
+ RAISE EXCEPTION 'Desk % should not have media % in its group but does',
+ OLD.desk__id, NEW.id;
+ ELSE
+ RETURN NEW;
+ END IF;
+END;
+$$;
+
+-- split
+
+CREATE CONSTRAINT TRIGGER media_is_on_desk
+ AFTER INSERT OR UPDATE ON media
+DEFERRABLE INITIALLY DEFERRED
+ FOR EACH ROW EXECUTE PROCEDURE desk_has_media();
+
+-- split
+
+CREATE OR REPLACE FUNCTION desk_hasnt_media(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ IF NOT EXISTS (
+ SELECT media_member.object_id
+ FROM desk
+ JOIN member ON member.grp__id = desk.asset_grp
+ JOIN media_member ON media_member.member__id = member.id
+ WHERE desk.id = OLD.desk__id
+ AND media_member.object_id = OLD.id
+ ) THEN RETURN NEW; END IF;
+ RAISE EXCEPTION 'Desk % should not have media % in its group but does',
+ NEW.desk__id, NEW.id;
+END;
+$$;
+
+-- split
+
+CREATE CONSTRAINT TRIGGER media_not_on_desk
+ AFTER DELETE ON media
+DEFERRABLE INITIALLY DEFERRED
+ FOR EACH ROW EXECUTE PROCEDURE desk_hasnt_media();
+
+-- split
+
+CREATE OR REPLACE FUNCTION set_member_media_desk_id(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ UPDATE media
+ SET desk__id = desk.id
+ FROM member
+ JOIN desk ON member.grp__id = desk.asset_grp
+ WHERE media.id = NEW.object_id
+ AND member.id = NEW.member__id;
+ RETURN NEW;
+END;
+$$;
+
+-- split
+
+CREATE TRIGGER set_member_media_desk_id
+ AFTER INSERT OR UPDATE ON media_member
+ FOR EACH ROW EXECUTE PROCEDURE set_member_media_desk_id();
+
+CREATE OR REPLACE FUNCTION unset_member_media_desk_id(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ UPDATE media
+ SET desk__id = 0
+ FROM member
+ JOIN desk ON member.grp__id = desk.asset_grp
+ WHERE media.id = OLD.object_id
+ AND member.id = OLD.member__id
+ AND media.desk__id = desk.id;
+ RETURN OLD;
+END;
+$$;
+
+-- split
+
+CREATE TRIGGER unset_member_media_desk_id
+ BEFORE DELETE ON media_member
+ FOR EACH ROW EXECUTE PROCEDURE unset_member_media_desk_id();
+
+-- split
+
+/****************************************************************************/
+-- Add triggers for template desk memberships.
+CREATE OR REPLACE FUNCTION desk_has_template(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ IF TG_OP = 'UPDATE' THEN
+ IF NEW.desk__id = OLD.desk__id THEN RETURN NEW; END IF;
+ END IF;
+ IF NEW.desk__id > 0 THEN
+ IF EXISTS (
+ SELECT template_member.object_id
+ FROM desk
+ JOIN member ON member.grp__id = desk.asset_grp
+ JOIN template_member ON template_member.member__id = member.id
+ WHERE desk.id = NEW.desk__id
+ AND template_member.object_id = NEW.id
+ ) THEN RETURN NEW; END IF;
+ RAISE EXCEPTION 'Desk % should have template % in its group but does not',
+ NEW.desk__id, NEW.id;
+ ELSIF TG_OP = 'UPDATE' THEN
+ IF NOT EXISTS (
+ SELECT template_member.object_id
+ FROM desk
+ JOIN member ON member.grp__id = desk.asset_grp
+ JOIN template_member ON template_member.member__id = member.id
+ WHERE desk.id = OLD.desk__id
+ AND template_member.object_id = NEW.id
+ ) THEN RETURN NEW; END IF;
+ RAISE EXCEPTION 'Desk % should not have template % in its group but does',
+ OLD.desk__id, NEW.id;
+ ELSE
+ RETURN NEW;
+ END IF;
+END;
+$$;
+
+-- split
+
+CREATE CONSTRAINT TRIGGER template_is_on_desk
+ AFTER INSERT OR UPDATE ON template
+DEFERRABLE INITIALLY DEFERRED
+ FOR EACH ROW EXECUTE PROCEDURE desk_has_template();
+
+-- split
+
+CREATE OR REPLACE FUNCTION desk_hasnt_template(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ IF NOT EXISTS (
+ SELECT template_member.object_id
+ FROM desk
+ JOIN member ON member.grp__id = desk.asset_grp
+ JOIN template_member ON template_member.member__id = member.id
+ WHERE desk.id = OLD.desk__id
+ AND template_member.object_id = OLD.id
+ ) THEN RETURN NEW; END IF;
+ RAISE EXCEPTION 'Desk % should not have template % in its group but does',
+ NEW.desk__id, NEW.id;
+END;
+$$;
+
+-- split
+
+CREATE CONSTRAINT TRIGGER template_not_on_desk
+ AFTER DELETE ON template
+DEFERRABLE INITIALLY DEFERRED
+ FOR EACH ROW EXECUTE PROCEDURE desk_hasnt_template();
+
+-- split
+
+CREATE OR REPLACE FUNCTION set_member_template_desk_id(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ UPDATE template
+ SET desk__id = desk.id
+ FROM member
+ JOIN desk ON member.grp__id = desk.asset_grp
+ WHERE template.id = NEW.object_id
+ AND member.id = NEW.member__id;
+ RETURN NEW;
+END;
+$$;
+
+-- split
+
+CREATE TRIGGER set_member_template_desk_id
+ AFTER INSERT OR UPDATE ON template_member
+ FOR EACH ROW EXECUTE PROCEDURE set_member_template_desk_id();
+
+CREATE OR REPLACE FUNCTION unset_member_template_desk_id(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ UPDATE template
+ SET desk__id = 0
+ FROM member
+ JOIN desk ON member.grp__id = desk.asset_grp
+ WHERE template.id = OLD.object_id
+ AND member.id = OLD.member__id
+ AND template.desk__id = desk.id;
+ RETURN OLD;
+END;
+$$;
+
+-- split
+
+CREATE TRIGGER unset_member_template_desk_id
+ BEFORE DELETE ON template_member
+ FOR EACH ROW EXECUTE PROCEDURE unset_member_template_desk_id();
View
4 lib/Bric/Admin.pod
@@ -179,8 +179,8 @@ to find the appropriate one to use for the default.
A boolean indicating whether or not the databse should be created. Defaults to
true. If you set this to a false value, the database should already exist and
-the Bricolage database user will need to have permission to create objects in
-it (tables, indexes, sequences, etc.).
+include PL/pgSQL. The Bricolage database user will need to have permission to
+create objects in it (tables, indexes, sequences, etc.).
=item * BRICOLAGE_PG_SUPERUSER
View
6 lib/Bric/Biz/Workflow/Parts/Desk.pm
@@ -1171,13 +1171,13 @@ sub save {
$self->_set(['_asset_grp_obj'], [$asset_grp_obj]);
$self->_set__dirty($dirty);
}
+ # Save all the grouped objects.
+ $asset_grp_obj->save;
+
$self->_sync_checkin;
$self->_sync_checkout;
$self->_sync_transfer;
- # Save all the grouped objects.
- $asset_grp_obj->save;
-
# Save the IDs if we have them.
my $ag = $self->get_asset_grp;
my $newagid = $asset_grp_obj->get_id;
View
10 lib/Bric/Changes.pod
@@ -153,6 +153,16 @@ Added C<expired> parameter to the C<list()> methods of
L<Bric::Biz::Asset::Business::Story> and L<Bric::Biz::Asset::Business::Media>.
[Gred Heo]
+=item *
+
+Added triggers to the PostgreSQL database to ensure that stories, media, and
+templates are always on the desks they think they should be on. Because that
+information is stored in two different places (one for performance, the other
+for permissions), there can be some drift between them. The new triggers throw
+an error whenever such drift is detected, in an effort to prevent it from
+happening at all. The migration that adds the triggers also corrects any
+existing drift. [David]
+
=back
=head2 Bug fixes
View
96 sql/Pg/Bric/Biz/Asset/Business/Media.con
@@ -108,3 +108,99 @@ REFERENCES media(id) ON DELETE CASCADE;
ALTER TABLE media_member
ADD CONSTRAINT fk_member__media_member FOREIGN KEY (member__id)
REFERENCES member(id) ON DELETE CASCADE;
+
+-- Add triggers for media desk memberships.
+CREATE OR REPLACE FUNCTION desk_has_media(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ IF TG_OP = 'UPDATE' THEN
+ IF NEW.desk__id = OLD.desk__id THEN RETURN NEW; END IF;
+ END IF;
+ IF NEW.desk__id > 0 THEN
+ IF EXISTS (
+ SELECT media_member.object_id
+ FROM desk
+ JOIN member ON member.grp__id = desk.asset_grp
+ JOIN media_member ON media_member.member__id = member.id
+ WHERE desk.id = NEW.desk__id
+ AND media_member.object_id = NEW.id
+ ) THEN RETURN NEW; END IF;
+ RAISE EXCEPTION 'Desk % should have media % in its group but does not',
+ NEW.desk__id, NEW.id;
+ ELSIF TG_OP = 'UPDATE' THEN
+ IF NOT EXISTS (
+ SELECT media_member.object_id
+ FROM desk
+ JOIN member ON member.grp__id = desk.asset_grp
+ JOIN media_member ON media_member.member__id = member.id
+ WHERE desk.id = OLD.desk__id
+ AND media_member.object_id = NEW.id
+ ) THEN RETURN NEW; END IF;
+ RAISE EXCEPTION 'Desk % should not have media % in its group but does',
+ OLD.desk__id, NEW.id;
+ ELSE
+ RETURN NEW;
+ END IF;
+END;
+$$;
+
+CREATE CONSTRAINT TRIGGER media_is_on_desk
+ AFTER INSERT OR UPDATE ON media
+DEFERRABLE INITIALLY DEFERRED
+ FOR EACH ROW EXECUTE PROCEDURE desk_has_media();
+
+CREATE OR REPLACE FUNCTION desk_hasnt_media(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ IF NOT EXISTS (
+ SELECT media_member.object_id
+ FROM desk
+ JOIN member ON member.grp__id = desk.asset_grp
+ JOIN media_member ON media_member.member__id = member.id
+ WHERE desk.id = OLD.desk__id
+ AND media_member.object_id = OLD.id
+ ) THEN RETURN NEW; END IF;
+ RAISE EXCEPTION 'Desk % should not have media % in its group but does',
+ NEW.desk__id, NEW.id;
+END;
+$$;
+
+CREATE CONSTRAINT TRIGGER media_not_on_desk
+ AFTER DELETE ON media
+DEFERRABLE INITIALLY DEFERRED
+ FOR EACH ROW EXECUTE PROCEDURE desk_hasnt_media();
+
+CREATE OR REPLACE FUNCTION set_member_media_desk_id(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ UPDATE media
+ SET desk__id = desk.id
+ FROM member
+ JOIN desk ON member.grp__id = desk.asset_grp
+ WHERE media.id = NEW.object_id
+ AND member.id = NEW.member__id;
+ RETURN NEW;
+END;
+$$;
+
+CREATE TRIGGER set_member_media_desk_id
+ AFTER INSERT OR UPDATE ON media_member
+ FOR EACH ROW EXECUTE PROCEDURE set_member_media_desk_id();
+
+CREATE OR REPLACE FUNCTION unset_member_media_desk_id(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ UPDATE media
+ SET desk__id = 0
+ FROM member
+ JOIN desk ON member.grp__id = desk.asset_grp
+ WHERE media.id = OLD.object_id
+ AND member.id = OLD.member__id
+ AND media.desk__id = desk.id;
+ RETURN OLD;
+END;
+$$;
+
+CREATE TRIGGER unset_member_media_desk_id
+ BEFORE DELETE ON media_member
+ FOR EACH ROW EXECUTE PROCEDURE unset_member_media_desk_id();
View
98 sql/Pg/Bric/Biz/Asset/Business/Story.con
@@ -95,3 +95,101 @@ ADD CONSTRAINT fk_story__story__contributor FOREIGN KEY (story_instance__id)
ALTER TABLE story__contributor
ADD CONSTRAINT fk_member__story__contributor FOREIGN KEY (member__id)
REFERENCES member(id) ON DELETE CASCADE;
+
+-- Add triggers for story desk memberships.
+CREATE OR REPLACE FUNCTION desk_has_story(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ IF TG_OP = 'UPDATE' THEN
+ IF NEW.desk__id = OLD.desk__id THEN RETURN NEW; END IF;
+ END IF;
+ IF NEW.desk__id > 0 THEN
+ IF EXISTS (
+ SELECT story_member.object_id
+ FROM desk
+ JOIN member ON member.grp__id = desk.asset_grp
+ JOIN story_member ON story_member.member__id = member.id
+ WHERE desk.id = NEW.desk__id
+ AND story_member.object_id = NEW.id
+ ) THEN RETURN NEW; END IF;
+ RAISE EXCEPTION 'Desk % should have story % in its group but does not',
+ NEW.desk__id, NEW.id;
+ ELSIF TG_OP = 'UPDATE' THEN
+ IF NOT EXISTS (
+ SELECT story_member.object_id
+ FROM desk
+ JOIN member ON member.grp__id = desk.asset_grp
+ JOIN story_member ON story_member.member__id = member.id
+ WHERE desk.id = OLD.desk__id
+ AND story_member.object_id = NEW.id
+ ) THEN RETURN NEW; END IF;
+ RAISE EXCEPTION 'Desk % should not have story % in its group but does',
+ OLD.desk__id, NEW.id;
+ ELSE
+ RETURN NEW;
+ END IF;
+END;
+$$;
+
+CREATE CONSTRAINT TRIGGER story_is_on_desk
+ AFTER INSERT OR UPDATE ON story
+DEFERRABLE INITIALLY DEFERRED
+ FOR EACH ROW EXECUTE PROCEDURE desk_has_story();
+
+CREATE OR REPLACE FUNCTION desk_hasnt_story(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ IF NOT EXISTS (
+ SELECT story_member.object_id
+ FROM desk
+ JOIN member ON member.grp__id = desk.asset_grp
+ JOIN story_member ON story_member.member__id = member.id
+ WHERE desk.id = OLD.desk__id
+ AND story_member.object_id = OLD.id
+ ) THEN RETURN NEW; END IF;
+ RAISE EXCEPTION 'Desk % should not have story % in its group but does',
+ NEW.desk__id, NEW.id;
+END;
+$$;
+
+CREATE CONSTRAINT TRIGGER story_not_on_desk
+ AFTER DELETE ON story
+DEFERRABLE INITIALLY DEFERRED
+ FOR EACH ROW EXECUTE PROCEDURE desk_hasnt_story();
+
+
+CREATE OR REPLACE FUNCTION set_member_story_desk_id(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ UPDATE story
+ SET desk__id = desk.id
+ FROM member
+ JOIN desk ON member.grp__id = desk.asset_grp
+ WHERE story.id = NEW.object_id
+ AND member.id = NEW.member__id;
+ RETURN NEW;
+END;
+$$;
+
+CREATE TRIGGER set_member_story_desk_id
+ AFTER INSERT OR UPDATE ON story_member
+ FOR EACH ROW EXECUTE PROCEDURE set_member_story_desk_id();
+
+CREATE OR REPLACE FUNCTION unset_member_story_desk_id(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ UPDATE story
+ SET desk__id = 0
+ FROM member
+ JOIN desk ON member.grp__id = desk.asset_grp
+ WHERE story.id = OLD.object_id
+ AND member.id = OLD.member__id
+ AND story.desk__id = desk.id;
+ RETURN OLD;
+END;
+$$;
+
+CREATE TRIGGER unset_member_story_desk_id
+ BEFORE DELETE ON story_member
+ FOR EACH ROW EXECUTE PROCEDURE unset_member_story_desk_id();
+
View
96 sql/Pg/Bric/Biz/Asset/Template.con
@@ -56,3 +56,99 @@ REFERENCES template(id) ON DELETE CASCADE;
ALTER TABLE template_member
ADD CONSTRAINT fk_member__template_member FOREIGN KEY (member__id)
REFERENCES member(id) ON DELETE CASCADE;
+
+-- Add triggers for template desk memberships.
+CREATE OR REPLACE FUNCTION desk_has_template(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ IF TG_OP = 'UPDATE' THEN
+ IF NEW.desk__id = OLD.desk__id THEN RETURN NEW; END IF;
+ END IF;
+ IF NEW.desk__id > 0 THEN
+ IF EXISTS (
+ SELECT template_member.object_id
+ FROM desk
+ JOIN member ON member.grp__id = desk.asset_grp
+ JOIN template_member ON template_member.member__id = member.id
+ WHERE desk.id = NEW.desk__id
+ AND template_member.object_id = NEW.id
+ ) THEN RETURN NEW; END IF;
+ RAISE EXCEPTION 'Desk % should have template % in its group but does not',
+ NEW.desk__id, NEW.id;
+ ELSIF TG_OP = 'UPDATE' THEN
+ IF NOT EXISTS (
+ SELECT template_member.object_id
+ FROM desk
+ JOIN member ON member.grp__id = desk.asset_grp
+ JOIN template_member ON template_member.member__id = member.id
+ WHERE desk.id = OLD.desk__id
+ AND template_member.object_id = NEW.id
+ ) THEN RETURN NEW; END IF;
+ RAISE EXCEPTION 'Desk % should not have template % in its group but does',
+ OLD.desk__id, NEW.id;
+ ELSE
+ RETURN NEW;
+ END IF;
+END;
+$$;
+
+CREATE CONSTRAINT TRIGGER template_is_on_desk
+ AFTER INSERT OR UPDATE ON template
+DEFERRABLE INITIALLY DEFERRED
+ FOR EACH ROW EXECUTE PROCEDURE desk_has_template();
+
+CREATE OR REPLACE FUNCTION desk_hasnt_template(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ IF NOT EXISTS (
+ SELECT template_member.object_id
+ FROM desk
+ JOIN member ON member.grp__id = desk.asset_grp
+ JOIN template_member ON template_member.member__id = member.id
+ WHERE desk.id = OLD.desk__id
+ AND template_member.object_id = OLD.id
+ ) THEN RETURN NEW; END IF;
+ RAISE EXCEPTION 'Desk % should not have template % in its group but does',
+ NEW.desk__id, NEW.id;
+END;
+$$;
+
+CREATE CONSTRAINT TRIGGER template_not_on_desk
+ AFTER DELETE ON template
+DEFERRABLE INITIALLY DEFERRED
+ FOR EACH ROW EXECUTE PROCEDURE desk_hasnt_template();
+
+CREATE OR REPLACE FUNCTION set_member_template_desk_id(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ UPDATE template
+ SET desk__id = desk.id
+ FROM member
+ JOIN desk ON member.grp__id = desk.asset_grp
+ WHERE template.id = NEW.object_id
+ AND member.id = NEW.member__id;
+ RETURN NEW;
+END;
+$$;
+
+CREATE TRIGGER set_member_template_desk_id
+ AFTER INSERT OR UPDATE ON template_member
+ FOR EACH ROW EXECUTE PROCEDURE set_member_template_desk_id();
+
+CREATE OR REPLACE FUNCTION unset_member_template_desk_id(
+) RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
+BEGIN
+ UPDATE template
+ SET desk__id = 0
+ FROM member
+ JOIN desk ON member.grp__id = desk.asset_grp
+ WHERE template.id = OLD.object_id
+ AND member.id = OLD.member__id
+ AND template.desk__id = desk.id;
+ RETURN OLD;
+END;
+$$;
+
+CREATE TRIGGER unset_member_template_desk_id
+ BEFORE DELETE ON template_member
+ FOR EACH ROW EXECUTE PROCEDURE unset_member_template_desk_id();
Please sign in to comment.
Something went wrong with that request. Please try again.