liquid_feedback_core

annotate core.sql @ 138:1542ffbc7ddb

Fixed syntax error
author jbe
date Sat May 28 04:35:24 2011 +0200 (2011-05-28)
parents 8766ddbd9b40
children e3bfa2d7954c
rev   line source
jbe@0 1
jbe@92 2 -- Execute the following command manually for PostgreSQL prior version 9.0:
jbe@92 3 -- CREATE LANGUAGE plpgsql;
jbe@0 4
jbe@0 5 -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index
jbe@0 6
jbe@0 7 BEGIN;
jbe@0 8
jbe@5 9 CREATE VIEW "liquid_feedback_version" AS
jbe@134 10 SELECT * FROM (VALUES ('1.4.0_rc1', 1, 4, -1))
jbe@5 11 AS "subquery"("string", "major", "minor", "revision");
jbe@5 12
jbe@0 13
jbe@0 14
jbe@7 15 ----------------------
jbe@7 16 -- Full text search --
jbe@7 17 ----------------------
jbe@7 18
jbe@7 19
jbe@7 20 CREATE FUNCTION "text_search_query"("query_text_p" TEXT)
jbe@7 21 RETURNS TSQUERY
jbe@7 22 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@7 23 BEGIN
jbe@7 24 RETURN plainto_tsquery('pg_catalog.simple', "query_text_p");
jbe@7 25 END;
jbe@7 26 $$;
jbe@7 27
jbe@7 28 COMMENT ON FUNCTION "text_search_query"(TEXT) IS 'Usage: WHERE "text_search_data" @@ "text_search_query"(''<user query>'')';
jbe@7 29
jbe@7 30
jbe@7 31 CREATE FUNCTION "highlight"
jbe@7 32 ( "body_p" TEXT,
jbe@7 33 "query_text_p" TEXT )
jbe@7 34 RETURNS TEXT
jbe@7 35 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@7 36 BEGIN
jbe@7 37 RETURN ts_headline(
jbe@7 38 'pg_catalog.simple',
jbe@8 39 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
jbe@7 40 "text_search_query"("query_text_p"),
jbe@7 41 'StartSel=* StopSel=* HighlightAll=TRUE' );
jbe@7 42 END;
jbe@7 43 $$;
jbe@7 44
jbe@7 45 COMMENT ON FUNCTION "highlight"
jbe@7 46 ( "body_p" TEXT,
jbe@7 47 "query_text_p" TEXT )
jbe@7 48 IS 'For a given a user query this function encapsulates all matches with asterisks. Asterisks and backslashes being already present are preceeded with one extra backslash.';
jbe@7 49
jbe@7 50
jbe@7 51
jbe@0 52 -------------------------
jbe@0 53 -- Tables and indicies --
jbe@0 54 -------------------------
jbe@0 55
jbe@8 56
jbe@104 57 CREATE TABLE "system_setting" (
jbe@104 58 "member_ttl" INTERVAL );
jbe@104 59 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1));
jbe@104 60
jbe@104 61 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.';
jbe@104 62 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.';
jbe@104 63
jbe@104 64 COMMENT ON COLUMN "system_setting"."member_ttl" IS 'Time after members get their "active" flag set to FALSE, if they do not login anymore.';
jbe@104 65
jbe@104 66
jbe@111 67 CREATE TABLE "contingent" (
jbe@111 68 "time_frame" INTERVAL PRIMARY KEY,
jbe@111 69 "text_entry_limit" INT4,
jbe@111 70 "initiative_limit" INT4 );
jbe@111 71
jbe@111 72 COMMENT ON TABLE "contingent" IS 'Amount of text entries or initiatives a user may create within a given time frame. Only one row needs to be fulfilled for a member to be allowed to post. This table must not be empty.';
jbe@111 73
jbe@111 74 COMMENT ON COLUMN "contingent"."text_entry_limit" IS 'Number of new drafts or suggestions to be submitted by each member within the given time frame';
jbe@111 75 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame';
jbe@111 76
jbe@111 77
jbe@113 78 CREATE TYPE "notify_level" AS ENUM
jbe@113 79 ('none', 'voting', 'verification', 'discussion', 'all');
jbe@113 80
jbe@113 81 COMMENT ON TYPE "notify_level" IS 'Level of notification: ''none'' = no notifications, ''voting'' = notifications about finished issues and issues in voting, ''verification'' = notifications about finished issues, issues in voting and verification phase, ''discussion'' = notifications about everything except issues in admission phase, ''all'' = notifications about everything';
jbe@113 82
jbe@113 83
jbe@0 84 CREATE TABLE "member" (
jbe@0 85 "id" SERIAL4 PRIMARY KEY,
jbe@13 86 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@42 87 "last_login" TIMESTAMPTZ,
jbe@103 88 "last_login_public" DATE,
jbe@45 89 "login" TEXT UNIQUE,
jbe@0 90 "password" TEXT,
jbe@99 91 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@0 92 "active" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@0 93 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@7 94 "notify_email" TEXT,
jbe@11 95 "notify_email_unconfirmed" TEXT,
jbe@11 96 "notify_email_secret" TEXT UNIQUE,
jbe@11 97 "notify_email_secret_expiry" TIMESTAMPTZ,
jbe@55 98 "notify_email_lock_expiry" TIMESTAMPTZ,
jbe@113 99 "notify_level" "notify_level" NOT NULL DEFAULT 'none',
jbe@113 100 "notify_event_id" INT8,
jbe@11 101 "password_reset_secret" TEXT UNIQUE,
jbe@11 102 "password_reset_secret_expiry" TIMESTAMPTZ,
jbe@7 103 "name" TEXT NOT NULL UNIQUE,
jbe@7 104 "identification" TEXT UNIQUE,
jbe@7 105 "organizational_unit" TEXT,
jbe@7 106 "internal_posts" TEXT,
jbe@7 107 "realname" TEXT,
jbe@7 108 "birthday" DATE,
jbe@7 109 "address" TEXT,
jbe@7 110 "email" TEXT,
jbe@7 111 "xmpp_address" TEXT,
jbe@7 112 "website" TEXT,
jbe@7 113 "phone" TEXT,
jbe@7 114 "mobile_phone" TEXT,
jbe@7 115 "profession" TEXT,
jbe@7 116 "external_memberships" TEXT,
jbe@7 117 "external_posts" TEXT,
jbe@7 118 "statement" TEXT,
jbe@10 119 "text_search_data" TSVECTOR );
jbe@0 120 CREATE INDEX "member_active_idx" ON "member" ("active");
jbe@8 121 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
jbe@7 122 CREATE TRIGGER "update_text_search_data"
jbe@7 123 BEFORE INSERT OR UPDATE ON "member"
jbe@7 124 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 125 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@7 126 "name", "identification", "organizational_unit", "internal_posts",
jbe@7 127 "realname", "external_memberships", "external_posts", "statement" );
jbe@0 128
jbe@0 129 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
jbe@0 130
jbe@103 131 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
jbe@103 132 COMMENT ON COLUMN "member"."last_login_public" IS 'Date of last login (time stripped for privacy reasons, updated only after day change)';
jbe@10 133 COMMENT ON COLUMN "member"."login" IS 'Login name';
jbe@10 134 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
jbe@99 135 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
jbe@99 136 COMMENT ON COLUMN "member"."active" IS 'Memberships, support and votes are taken into account when corresponding members are marked as active. When the user does not log in for an extended period of time, this flag may be set to FALSE. If the user is not locked, he/she may reset the active flag by logging in.';
jbe@10 137 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
jbe@10 138 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
jbe@10 139 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
jbe@10 140 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
jbe@10 141 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
jbe@55 142 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
jbe@113 143 COMMENT ON COLUMN "member"."notify_level" IS 'Selects which event notifications are to be sent to the "notify_email" mail address';
jbe@113 144 COMMENT ON COLUMN "member"."notify_event_id" IS 'Latest "id" of an "event" the member was notified about';
jbe@10 145 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member';
jbe@10 146 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
jbe@10 147 COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to';
jbe@10 148 COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization';
jbe@10 149 COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"';
jbe@10 150 COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications';
jbe@10 151 COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in';
jbe@10 152 COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization';
jbe@10 153 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his homepage within the system';
jbe@7 154
jbe@7 155
jbe@13 156 CREATE TABLE "member_history" (
jbe@13 157 "id" SERIAL8 PRIMARY KEY,
jbe@13 158 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@13 159 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@42 160 "active" BOOLEAN NOT NULL,
jbe@13 161 "name" TEXT NOT NULL );
jbe@45 162 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
jbe@13 163
jbe@57 164 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
jbe@13 165
jbe@13 166 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
jbe@57 167 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
jbe@13 168
jbe@13 169
jbe@9 170 CREATE TABLE "invite_code" (
jbe@97 171 "id" SERIAL8 PRIMARY KEY,
jbe@97 172 "code" TEXT NOT NULL UNIQUE,
jbe@9 173 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@9 174 "used" TIMESTAMPTZ,
jbe@9 175 "member_id" INT4 UNIQUE REFERENCES "member" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
jbe@9 176 "comment" TEXT,
jbe@9 177 CONSTRAINT "only_used_codes_may_refer_to_member" CHECK ("used" NOTNULL OR "member_id" ISNULL) );
jbe@9 178
jbe@9 179 COMMENT ON TABLE "invite_code" IS 'Invite codes can be used once to create a new member account.';
jbe@9 180
jbe@9 181 COMMENT ON COLUMN "invite_code"."code" IS 'Secret code';
jbe@9 182 COMMENT ON COLUMN "invite_code"."created" IS 'Time of creation of the secret code';
jbe@9 183 COMMENT ON COLUMN "invite_code"."used" IS 'NULL, if not used yet, otherwise tells when this code was used to create a member account';
jbe@9 184 COMMENT ON COLUMN "invite_code"."member_id" IS 'References the member whose account was created with this code';
jbe@9 185 COMMENT ON COLUMN "invite_code"."comment" IS 'Comment on the code, which is to be used for administrative reasons only';
jbe@9 186
jbe@9 187
jbe@9 188 CREATE TABLE "setting" (
jbe@9 189 PRIMARY KEY ("member_id", "key"),
jbe@9 190 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@9 191 "key" TEXT NOT NULL,
jbe@9 192 "value" TEXT NOT NULL );
jbe@9 193 CREATE INDEX "setting_key_idx" ON "setting" ("key");
jbe@9 194
jbe@38 195 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
jbe@9 196
jbe@9 197 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
jbe@9 198
jbe@9 199
jbe@16 200 CREATE TABLE "setting_map" (
jbe@16 201 PRIMARY KEY ("member_id", "key", "subkey"),
jbe@16 202 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@16 203 "key" TEXT NOT NULL,
jbe@16 204 "subkey" TEXT NOT NULL,
jbe@16 205 "value" TEXT NOT NULL );
jbe@16 206 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
jbe@16 207
jbe@23 208 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
jbe@16 209
jbe@16 210 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
jbe@16 211 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
jbe@16 212 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
jbe@16 213
jbe@16 214
jbe@23 215 CREATE TABLE "member_relation_setting" (
jbe@23 216 PRIMARY KEY ("member_id", "key", "other_member_id"),
jbe@23 217 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 218 "key" TEXT NOT NULL,
jbe@23 219 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 220 "value" TEXT NOT NULL );
jbe@23 221
jbe@38 222 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
jbe@23 223
jbe@23 224
jbe@7 225 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
jbe@7 226
jbe@7 227 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
jbe@7 228
jbe@7 229
jbe@7 230 CREATE TABLE "member_image" (
jbe@7 231 PRIMARY KEY ("member_id", "image_type", "scaled"),
jbe@7 232 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@7 233 "image_type" "member_image_type",
jbe@7 234 "scaled" BOOLEAN,
jbe@7 235 "content_type" TEXT,
jbe@7 236 "data" BYTEA NOT NULL );
jbe@7 237
jbe@7 238 COMMENT ON TABLE "member_image" IS 'Images of members';
jbe@7 239
jbe@7 240 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
jbe@0 241
jbe@0 242
jbe@4 243 CREATE TABLE "member_count" (
jbe@5 244 "calculated" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
jbe@5 245 "total_count" INT4 NOT NULL );
jbe@4 246
jbe@5 247 COMMENT ON TABLE "member_count" IS 'Contains one row which contains the total count of active(!) members and a timestamp indicating when the total member count and area member counts were calculated';
jbe@4 248
jbe@5 249 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
jbe@5 250 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
jbe@4 251
jbe@4 252
jbe@0 253 CREATE TABLE "contact" (
jbe@0 254 PRIMARY KEY ("member_id", "other_member_id"),
jbe@0 255 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 256 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@11 257 "public" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@11 258 CONSTRAINT "cant_save_yourself_as_contact"
jbe@11 259 CHECK ("member_id" != "other_member_id") );
jbe@113 260 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
jbe@0 261
jbe@0 262 COMMENT ON TABLE "contact" IS 'Contact lists';
jbe@0 263
jbe@0 264 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
jbe@0 265 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
jbe@0 266 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
jbe@0 267
jbe@0 268
jbe@113 269 CREATE TABLE "ignored_member" (
jbe@113 270 PRIMARY KEY ("member_id", "other_member_id"),
jbe@113 271 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@113 272 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@113 273 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
jbe@113 274
jbe@113 275 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
jbe@113 276
jbe@113 277 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
jbe@113 278 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
jbe@113 279
jbe@113 280
jbe@0 281 CREATE TABLE "session" (
jbe@0 282 "ident" TEXT PRIMARY KEY,
jbe@0 283 "additional_secret" TEXT,
jbe@0 284 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
jbe@0 285 "member_id" INT8 REFERENCES "member" ("id") ON DELETE SET NULL,
jbe@0 286 "lang" TEXT );
jbe@0 287 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
jbe@0 288
jbe@0 289 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend';
jbe@0 290
jbe@0 291 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
jbe@0 292 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
jbe@0 293 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
jbe@0 294 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
jbe@0 295
jbe@0 296
jbe@0 297 CREATE TABLE "policy" (
jbe@0 298 "id" SERIAL4 PRIMARY KEY,
jbe@9 299 "index" INT4 NOT NULL,
jbe@0 300 "active" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@0 301 "name" TEXT NOT NULL UNIQUE,
jbe@0 302 "description" TEXT NOT NULL DEFAULT '',
jbe@0 303 "admission_time" INTERVAL NOT NULL,
jbe@0 304 "discussion_time" INTERVAL NOT NULL,
jbe@3 305 "verification_time" INTERVAL NOT NULL,
jbe@0 306 "voting_time" INTERVAL NOT NULL,
jbe@0 307 "issue_quorum_num" INT4 NOT NULL,
jbe@0 308 "issue_quorum_den" INT4 NOT NULL,
jbe@0 309 "initiative_quorum_num" INT4 NOT NULL,
jbe@10 310 "initiative_quorum_den" INT4 NOT NULL,
jbe@10 311 "majority_num" INT4 NOT NULL DEFAULT 1,
jbe@10 312 "majority_den" INT4 NOT NULL DEFAULT 2,
jbe@137 313 "majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@137 314 "majority_indirect" BOOLEAN NOT NULL DEFAULT TRUE );
jbe@0 315 CREATE INDEX "policy_active_idx" ON "policy" ("active");
jbe@0 316
jbe@0 317 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
jbe@0 318
jbe@9 319 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
jbe@0 320 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
jbe@0 321 COMMENT ON COLUMN "policy"."admission_time" IS 'Maximum time an issue stays open without being "accepted"';
jbe@3 322 COMMENT ON COLUMN "policy"."discussion_time" IS 'Regular time until an issue is "half_frozen" after being "accepted"';
jbe@3 323 COMMENT ON COLUMN "policy"."verification_time" IS 'Regular time until an issue is "fully_frozen" after being "half_frozen"';
jbe@3 324 COMMENT ON COLUMN "policy"."voting_time" IS 'Time after an issue is "fully_frozen" but not "closed"';
jbe@10 325 COMMENT ON COLUMN "policy"."issue_quorum_num" IS 'Numerator of potential supporter quorum to be reached by one initiative of an issue to be "accepted"';
jbe@10 326 COMMENT ON COLUMN "policy"."issue_quorum_den" IS 'Denominator of potential supporter quorum to be reached by one initiative of an issue to be "accepted"';
jbe@10 327 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
jbe@10 328 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
jbe@10 329 COMMENT ON COLUMN "policy"."majority_num" IS 'Numerator of fraction of majority to be reached during voting by an initiative to be aggreed upon';
jbe@10 330 COMMENT ON COLUMN "policy"."majority_den" IS 'Denominator of fraction of majority to be reached during voting by an initiative to be aggreed upon';
jbe@10 331 COMMENT ON COLUMN "policy"."majority_strict" IS 'If TRUE, then the majority must be strictly greater than "majority_num"/"majority_den", otherwise it may also be equal.';
jbe@138 332 COMMENT ON COLUMN "policy"."majority_indirect" IS 'If TRUE, then also indirect majorities (though beat paths) are taken into account, when an initiative has at least as many "positive_votes" as "negative_votes".';
jbe@0 333
jbe@0 334
jbe@97 335 CREATE TABLE "unit" (
jbe@97 336 "id" SERIAL4 PRIMARY KEY,
jbe@97 337 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@97 338 "active" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@97 339 "name" TEXT NOT NULL,
jbe@97 340 "description" TEXT NOT NULL DEFAULT '',
jbe@97 341 "member_count" INT4,
jbe@97 342 "text_search_data" TSVECTOR );
jbe@97 343 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
jbe@97 344 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
jbe@97 345 CREATE INDEX "unit_active_idx" ON "unit" ("active");
jbe@97 346 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
jbe@97 347 CREATE TRIGGER "update_text_search_data"
jbe@97 348 BEFORE INSERT OR UPDATE ON "unit"
jbe@97 349 FOR EACH ROW EXECUTE PROCEDURE
jbe@97 350 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@97 351 "name", "description" );
jbe@97 352
jbe@97 353 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
jbe@97 354
jbe@97 355 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
jbe@97 356 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in units of this area';
jbe@97 357 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
jbe@97 358
jbe@97 359
jbe@0 360 CREATE TABLE "area" (
jbe@0 361 "id" SERIAL4 PRIMARY KEY,
jbe@97 362 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 363 "active" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@0 364 "name" TEXT NOT NULL,
jbe@4 365 "description" TEXT NOT NULL DEFAULT '',
jbe@5 366 "direct_member_count" INT4,
jbe@5 367 "member_weight" INT4,
jbe@7 368 "autoreject_weight" INT4,
jbe@7 369 "text_search_data" TSVECTOR );
jbe@97 370 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
jbe@0 371 CREATE INDEX "area_active_idx" ON "area" ("active");
jbe@8 372 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
jbe@7 373 CREATE TRIGGER "update_text_search_data"
jbe@7 374 BEFORE INSERT OR UPDATE ON "area"
jbe@7 375 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 376 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@7 377 "name", "description" );
jbe@0 378
jbe@0 379 COMMENT ON TABLE "area" IS 'Subject areas';
jbe@0 380
jbe@5 381 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
jbe@5 382 COMMENT ON COLUMN "area"."direct_member_count" IS 'Number of active members of that area (ignoring their weight), as calculated from view "area_member_count"';
jbe@5 383 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
jbe@5 384 COMMENT ON COLUMN "area"."autoreject_weight" IS 'Sum of weight of members using the autoreject feature';
jbe@0 385
jbe@0 386
jbe@23 387 CREATE TABLE "area_setting" (
jbe@23 388 PRIMARY KEY ("member_id", "key", "area_id"),
jbe@23 389 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 390 "key" TEXT NOT NULL,
jbe@23 391 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 392 "value" TEXT NOT NULL );
jbe@23 393
jbe@23 394 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
jbe@23 395
jbe@23 396
jbe@9 397 CREATE TABLE "allowed_policy" (
jbe@9 398 PRIMARY KEY ("area_id", "policy_id"),
jbe@9 399 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@9 400 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@9 401 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
jbe@9 402 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
jbe@9 403
jbe@9 404 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
jbe@9 405
jbe@9 406 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
jbe@9 407
jbe@9 408
jbe@21 409 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
jbe@21 410
jbe@21 411 COMMENT ON TYPE "snapshot_event" IS 'Reason for snapshots: ''periodic'' = due to periodic recalculation, ''end_of_admission'' = saved state at end of admission period, ''half_freeze'' = saved state at end of discussion period, ''full_freeze'' = saved state at end of verification period';
jbe@8 412
jbe@8 413
jbe@112 414 CREATE TYPE "issue_state" AS ENUM (
jbe@112 415 'admission', 'discussion', 'verification', 'voting',
jbe@113 416 'canceled_revoked_before_accepted',
jbe@113 417 'canceled_issue_not_accepted',
jbe@113 418 'canceled_after_revocation_during_discussion',
jbe@113 419 'canceled_after_revocation_during_verification',
jbe@113 420 'calculation',
jbe@113 421 'canceled_no_initiative_admitted',
jbe@112 422 'finished_without_winner', 'finished_with_winner');
jbe@111 423
jbe@111 424 COMMENT ON TYPE "issue_state" IS 'State of issues';
jbe@111 425
jbe@111 426
jbe@0 427 CREATE TABLE "issue" (
jbe@0 428 "id" SERIAL4 PRIMARY KEY,
jbe@0 429 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 430 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@111 431 "state" "issue_state" NOT NULL DEFAULT 'admission',
jbe@0 432 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 433 "accepted" TIMESTAMPTZ,
jbe@3 434 "half_frozen" TIMESTAMPTZ,
jbe@3 435 "fully_frozen" TIMESTAMPTZ,
jbe@0 436 "closed" TIMESTAMPTZ,
jbe@0 437 "ranks_available" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@59 438 "cleaned" TIMESTAMPTZ,
jbe@22 439 "admission_time" INTERVAL NOT NULL,
jbe@22 440 "discussion_time" INTERVAL NOT NULL,
jbe@22 441 "verification_time" INTERVAL NOT NULL,
jbe@22 442 "voting_time" INTERVAL NOT NULL,
jbe@0 443 "snapshot" TIMESTAMPTZ,
jbe@8 444 "latest_snapshot_event" "snapshot_event",
jbe@0 445 "population" INT4,
jbe@0 446 "vote_now" INT4,
jbe@0 447 "vote_later" INT4,
jbe@4 448 "voter_count" INT4,
jbe@111 449 CONSTRAINT "valid_state" CHECK ((
jbe@3 450 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
jbe@3 451 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
jbe@3 452 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
jbe@34 453 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
jbe@3 454 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
jbe@34 455 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
jbe@3 456 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
jbe@3 457 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
jbe@111 458 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = TRUE)) AND (
jbe@111 459 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
jbe@111 460 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
jbe@111 461 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
jbe@111 462 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
jbe@113 463 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
jbe@113 464 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
jbe@113 465 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
jbe@113 466 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
jbe@113 467 ("state" = 'calculation' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = FALSE) OR
jbe@113 468 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
jbe@113 469 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
jbe@113 470 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE)
jbe@111 471 )),
jbe@3 472 CONSTRAINT "state_change_order" CHECK (
jbe@10 473 "created" <= "accepted" AND
jbe@10 474 "accepted" <= "half_frozen" AND
jbe@10 475 "half_frozen" <= "fully_frozen" AND
jbe@3 476 "fully_frozen" <= "closed" ),
jbe@61 477 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
jbe@61 478 "cleaned" ISNULL OR "closed" NOTNULL ),
jbe@10 479 CONSTRAINT "last_snapshot_on_full_freeze"
jbe@10 480 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
jbe@10 481 CONSTRAINT "freeze_requires_snapshot"
jbe@10 482 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
jbe@10 483 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
jbe@10 484 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) );
jbe@0 485 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
jbe@0 486 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
jbe@16 487 CREATE INDEX "issue_created_idx" ON "issue" ("created");
jbe@16 488 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
jbe@16 489 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
jbe@16 490 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
jbe@16 491 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
jbe@0 492 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
jbe@16 493 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
jbe@0 494
jbe@0 495 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
jbe@0 496
jbe@8 497 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
jbe@10 498 COMMENT ON COLUMN "issue"."half_frozen" IS 'Point in time, when "discussion_time" has elapsed, or members voted for voting; Frontends must ensure that for half_frozen issues a) initiatives are not revoked, b) no new drafts are created, c) no initiators are added or removed.';
jbe@86 499 COMMENT ON COLUMN "issue"."fully_frozen" IS 'Point in time, when "verification_time" has elapsed and voting has started; Frontends must ensure that for fully_frozen issues additionally to the restrictions for half_frozen issues a) initiatives are not created, b) no interest is created or removed, c) no supporters are added or removed, d) no opinions are created, changed or deleted.';
jbe@10 500 COMMENT ON COLUMN "issue"."closed" IS 'Point in time, when "admission_time" or "voting_time" have elapsed, and issue is no longer active; Frontends must ensure that for closed issues additionally to the restrictions for half_frozen and fully_frozen issues a) no voter is added or removed to/from the direct_voter table, b) no votes are added, modified or removed.';
jbe@8 501 COMMENT ON COLUMN "issue"."ranks_available" IS 'TRUE = ranks have been calculated';
jbe@59 502 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
jbe@22 503 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue';
jbe@22 504 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
jbe@22 505 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
jbe@22 506 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
jbe@8 507 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population", "vote_now", "vote_later" and *_count values were precalculated';
jbe@8 508 COMMENT ON COLUMN "issue"."latest_snapshot_event" IS 'Event type of latest snapshot for issue; Can be used to select the latest snapshot data in the snapshot tables';
jbe@8 509 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
jbe@8 510 COMMENT ON COLUMN "issue"."vote_now" IS 'Number of votes in favor of voting now, as calculated from table "direct_interest_snapshot"';
jbe@8 511 COMMENT ON COLUMN "issue"."vote_later" IS 'Number of votes against voting now, as calculated from table "direct_interest_snapshot"';
jbe@8 512 COMMENT ON COLUMN "issue"."voter_count" IS 'Total number of direct and delegating voters; This value is related to the final voting, while "population" is related to snapshots before the final voting';
jbe@0 513
jbe@0 514
jbe@23 515 CREATE TABLE "issue_setting" (
jbe@23 516 PRIMARY KEY ("member_id", "key", "issue_id"),
jbe@23 517 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 518 "key" TEXT NOT NULL,
jbe@23 519 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 520 "value" TEXT NOT NULL );
jbe@23 521
jbe@23 522 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
jbe@23 523
jbe@23 524
jbe@0 525 CREATE TABLE "initiative" (
jbe@0 526 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
jbe@0 527 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 528 "id" SERIAL4 PRIMARY KEY,
jbe@0 529 "name" TEXT NOT NULL,
jbe@8 530 "discussion_url" TEXT,
jbe@0 531 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 532 "revoked" TIMESTAMPTZ,
jbe@112 533 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@14 534 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 535 "admitted" BOOLEAN,
jbe@0 536 "supporter_count" INT4,
jbe@0 537 "informed_supporter_count" INT4,
jbe@0 538 "satisfied_supporter_count" INT4,
jbe@0 539 "satisfied_informed_supporter_count" INT4,
jbe@0 540 "positive_votes" INT4,
jbe@0 541 "negative_votes" INT4,
jbe@128 542 "attainable" BOOLEAN,
jbe@128 543 "favored" BOOLEAN,
jbe@128 544 "unfavored" BOOLEAN,
jbe@128 545 "eligible" BOOLEAN,
jbe@0 546 "rank" INT4,
jbe@126 547 "winner" BOOLEAN,
jbe@134 548 "promising" BOOLEAN,
jbe@7 549 "text_search_data" TSVECTOR,
jbe@112 550 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
jbe@112 551 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL),
jbe@14 552 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
jbe@14 553 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
jbe@0 554 CONSTRAINT "revoked_initiatives_cant_be_admitted"
jbe@0 555 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
jbe@128 556 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
jbe@128 557 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
jbe@128 558 ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
jbe@128 559 "attainable" ISNULL AND "favored" ISNULL AND "unfavored" ISNULL AND
jbe@134 560 "eligible" ISNULL AND "rank" ISNULL AND
jbe@134 561 "winner" ISNULL AND "promising" ISNULL ) ),
jbe@128 562 CONSTRAINT "all_or_none_of_positive_votes_negative_votes_and_attainable_must_be_null"
jbe@128 563 CHECK ("positive_votes" NOTNULL = "negative_votes" NOTNULL AND "positive_votes" NOTNULL = "attainable" NOTNULL),
jbe@134 564 CONSTRAINT "favored_excludes_unfavored" CHECK (NOT ("favored" AND "unfavored")),
jbe@128 565 CONSTRAINT "attainable_and_favored_result_in_eligible" CHECK (
jbe@128 566 ( "favored" ISNULL AND "eligible" ISNULL ) OR
jbe@128 567 ( "attainable" NOTNULL AND "favored" NOTNULL AND "eligible" NOTNULL AND
jbe@134 568 ("attainable" AND "favored") = "eligible" ) ),
jbe@134 569 CONSTRAINT "winner_excludes_promising" CHECK (NOT ("winner" AND "promising")) );
jbe@16 570 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
jbe@16 571 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
jbe@8 572 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
jbe@7 573 CREATE TRIGGER "update_text_search_data"
jbe@7 574 BEFORE INSERT OR UPDATE ON "initiative"
jbe@7 575 FOR EACH ROW EXECUTE PROCEDURE
jbe@8 576 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@8 577 "name", "discussion_url");
jbe@0 578
jbe@10 579 COMMENT ON TABLE "initiative" IS 'Group of members publishing drafts for resolutions to be passed; Frontends must ensure that initiatives of half_frozen issues are not revoked, and that initiatives of fully_frozen or closed issues are neither revoked nor created.';
jbe@0 580
jbe@112 581 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
jbe@112 582 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
jbe@112 583 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoked the initiative';
jbe@112 584 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
jbe@0 585 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@0 586 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@0 587 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@0 588 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@0 589 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
jbe@0 590 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
jbe@128 591 COMMENT ON COLUMN "initiative"."attainable" IS 'TRUE, if "positive_votes"/("positive_votes"+"negative_votes") is strictly greater or greater-equal than "majority_num"/"majority_den"';
jbe@128 592 COMMENT ON COLUMN "initiative"."favored" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
jbe@128 593 COMMENT ON COLUMN "initiative"."unfavored" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
jbe@128 594 COMMENT ON COLUMN "initiative"."eligible" IS 'TRUE, if initiative is "attainable" and "favored"';
jbe@128 595 COMMENT ON COLUMN "initiative"."rank" IS 'Schulze-Ranking after tie-breaking';
jbe@128 596 COMMENT ON COLUMN "initiative"."winner" IS 'TRUE, if initiative is final winner (best ranked initiative being "eligible")';
jbe@135 597 COMMENT ON COLUMN "initiative"."promising" IS 'TRUE, if and only if this initiative is not a winner and there is a number n>0, such that repeating the calculation of the winner n times with the previous winner as status quo causes this initiative to win. The calculations use the same preferences and include the previous status quo as an explicit option. Non "attainable" initiatives may never be "winner", but they can be "promising".';
jbe@0 598
jbe@0 599
jbe@61 600 CREATE TABLE "battle" (
jbe@126 601 "issue_id" INT4 NOT NULL,
jbe@61 602 "winning_initiative_id" INT4,
jbe@61 603 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@61 604 "losing_initiative_id" INT4,
jbe@61 605 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@126 606 "count" INT4 NOT NULL,
jbe@126 607 CONSTRAINT "initiative_ids_not_equal" CHECK (
jbe@126 608 "winning_initiative_id" != "losing_initiative_id" OR
jbe@126 609 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
jbe@126 610 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
jbe@126 611 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
jbe@126 612 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
jbe@126 613 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
jbe@126 614
jbe@126 615 COMMENT ON TABLE "battle" IS 'Number of members preferring one initiative to another; Filled by "battle_view" when closing an issue; NULL as initiative_id denotes virtual "status-quo" initiative';
jbe@61 616
jbe@61 617
jbe@113 618 CREATE TABLE "ignored_initiative" (
jbe@113 619 PRIMARY KEY ("initiative_id", "member_id"),
jbe@113 620 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@113 621 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@113 622 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
jbe@113 623
jbe@113 624 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
jbe@113 625
jbe@113 626
jbe@23 627 CREATE TABLE "initiative_setting" (
jbe@23 628 PRIMARY KEY ("member_id", "key", "initiative_id"),
jbe@23 629 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 630 "key" TEXT NOT NULL,
jbe@23 631 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 632 "value" TEXT NOT NULL );
jbe@23 633
jbe@23 634 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
jbe@23 635
jbe@23 636
jbe@0 637 CREATE TABLE "draft" (
jbe@0 638 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
jbe@0 639 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 640 "id" SERIAL8 PRIMARY KEY,
jbe@0 641 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 642 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@9 643 "formatting_engine" TEXT,
jbe@7 644 "content" TEXT NOT NULL,
jbe@7 645 "text_search_data" TSVECTOR );
jbe@16 646 CREATE INDEX "draft_created_idx" ON "draft" ("created");
jbe@9 647 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
jbe@8 648 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
jbe@7 649 CREATE TRIGGER "update_text_search_data"
jbe@7 650 BEFORE INSERT OR UPDATE ON "draft"
jbe@7 651 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 652 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
jbe@0 653
jbe@10 654 COMMENT ON TABLE "draft" IS 'Drafts of initiatives to solve issues; Frontends must ensure that new drafts for initiatives of half_frozen, fully_frozen or closed issues can''t be created.';
jbe@0 655
jbe@9 656 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
jbe@9 657 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
jbe@9 658
jbe@0 659
jbe@63 660 CREATE TABLE "rendered_draft" (
jbe@63 661 PRIMARY KEY ("draft_id", "format"),
jbe@63 662 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@63 663 "format" TEXT,
jbe@63 664 "content" TEXT NOT NULL );
jbe@63 665
jbe@63 666 COMMENT ON TABLE "rendered_draft" IS 'This table may be used by frontends to cache "rendered" drafts (e.g. HTML output generated from wiki text)';
jbe@63 667
jbe@63 668
jbe@0 669 CREATE TABLE "suggestion" (
jbe@0 670 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
jbe@0 671 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 672 "id" SERIAL8 PRIMARY KEY,
jbe@0 673 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 674 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@0 675 "name" TEXT NOT NULL,
jbe@0 676 "description" TEXT NOT NULL DEFAULT '',
jbe@7 677 "text_search_data" TSVECTOR,
jbe@0 678 "minus2_unfulfilled_count" INT4,
jbe@0 679 "minus2_fulfilled_count" INT4,
jbe@0 680 "minus1_unfulfilled_count" INT4,
jbe@0 681 "minus1_fulfilled_count" INT4,
jbe@0 682 "plus1_unfulfilled_count" INT4,
jbe@0 683 "plus1_fulfilled_count" INT4,
jbe@0 684 "plus2_unfulfilled_count" INT4,
jbe@0 685 "plus2_fulfilled_count" INT4 );
jbe@16 686 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
jbe@9 687 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
jbe@8 688 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
jbe@7 689 CREATE TRIGGER "update_text_search_data"
jbe@7 690 BEFORE INSERT OR UPDATE ON "suggestion"
jbe@7 691 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 692 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@7 693 "name", "description");
jbe@0 694
jbe@10 695 COMMENT ON TABLE "suggestion" IS 'Suggestions to initiators, to change the current draft; must not be deleted explicitly, as they vanish automatically if the last opinion is deleted';
jbe@0 696
jbe@0 697 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 698 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 699 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 700 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 701 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 702 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 703 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 704 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 705
jbe@0 706
jbe@23 707 CREATE TABLE "suggestion_setting" (
jbe@23 708 PRIMARY KEY ("member_id", "key", "suggestion_id"),
jbe@23 709 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 710 "key" TEXT NOT NULL,
jbe@23 711 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 712 "value" TEXT NOT NULL );
jbe@23 713
jbe@23 714 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
jbe@23 715
jbe@23 716
jbe@97 717 CREATE TABLE "invite_code_unit" (
jbe@97 718 PRIMARY KEY ("invite_code_id", "unit_id"),
jbe@97 719 "invite_code_id" INT8 REFERENCES "invite_code" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@97 720 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@97 721
jbe@97 722 COMMENT ON TABLE "invite_code_unit" IS 'Units where accounts created with a given invite codes get voting rights';
jbe@97 723
jbe@97 724
jbe@97 725 CREATE TABLE "privilege" (
jbe@97 726 PRIMARY KEY ("unit_id", "member_id"),
jbe@97 727 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@97 728 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@97 729 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@97 730 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@97 731 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@97 732 "voting_right_manager" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@97 733 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE );
jbe@97 734
jbe@97 735 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
jbe@97 736
jbe@97 737 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke admin privileges to/from other users';
jbe@97 738 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create or lock sub units';
jbe@97 739 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create or lock areas and set area parameters';
jbe@97 740 COMMENT ON COLUMN "privilege"."voting_right_manager" IS 'Select which members are allowed to discuss and vote inside the unit';
jbe@97 741 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to discuss and vote';
jbe@97 742
jbe@97 743
jbe@0 744 CREATE TABLE "membership" (
jbe@0 745 PRIMARY KEY ("area_id", "member_id"),
jbe@0 746 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 747 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@113 748 "autoreject" BOOLEAN NOT NULL DEFAULT FALSE );
jbe@0 749 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
jbe@0 750
jbe@0 751 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
jbe@0 752
jbe@114 753 COMMENT ON COLUMN "membership"."autoreject" IS 'TRUE = member votes against all initiatives, if he is neither direct_ or delegating_voter; Entries in the "interest" table can override this setting.';
jbe@0 754
jbe@0 755
jbe@0 756 CREATE TABLE "interest" (
jbe@0 757 PRIMARY KEY ("issue_id", "member_id"),
jbe@0 758 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 759 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@86 760 "autoreject" BOOLEAN,
jbe@0 761 "voting_requested" BOOLEAN );
jbe@0 762 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
jbe@0 763
jbe@10 764 COMMENT ON TABLE "interest" IS 'Interest of members in a particular issue; Frontends must ensure that interest for fully_frozen or closed issues is not added or removed.';
jbe@0 765
jbe@0 766 COMMENT ON COLUMN "interest"."autoreject" IS 'TRUE = member votes against all initiatives in case of not explicitly taking part in the voting procedure';
jbe@0 767 COMMENT ON COLUMN "interest"."voting_requested" IS 'TRUE = member wants to vote now, FALSE = member wants to vote later, NULL = policy rules should apply';
jbe@0 768
jbe@0 769
jbe@0 770 CREATE TABLE "initiator" (
jbe@0 771 PRIMARY KEY ("initiative_id", "member_id"),
jbe@0 772 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 773 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@14 774 "accepted" BOOLEAN );
jbe@0 775 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
jbe@0 776
jbe@10 777 COMMENT ON TABLE "initiator" IS 'Members who are allowed to post new drafts; Frontends must ensure that initiators are not added or removed from half_frozen, fully_frozen or closed initiatives.';
jbe@0 778
jbe@14 779 COMMENT ON COLUMN "initiator"."accepted" IS 'If "accepted" is NULL, then the member was invited to be a co-initiator, but has not answered yet. If it is TRUE, the member has accepted the invitation, if it is FALSE, the member has rejected the invitation.';
jbe@0 780
jbe@0 781
jbe@0 782 CREATE TABLE "supporter" (
jbe@0 783 "issue_id" INT4 NOT NULL,
jbe@0 784 PRIMARY KEY ("initiative_id", "member_id"),
jbe@0 785 "initiative_id" INT4,
jbe@0 786 "member_id" INT4,
jbe@0 787 "draft_id" INT8 NOT NULL,
jbe@10 788 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 789 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@0 790 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
jbe@0 791
jbe@10 792 COMMENT ON TABLE "supporter" IS 'Members who support an initiative (conditionally); Frontends must ensure that supporters are not added or removed from fully_frozen or closed initiatives.';
jbe@0 793
jbe@90 794 COMMENT ON COLUMN "supporter"."draft_id" IS 'Latest seen draft, defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
jbe@84 795
jbe@0 796
jbe@0 797 CREATE TABLE "opinion" (
jbe@0 798 "initiative_id" INT4 NOT NULL,
jbe@0 799 PRIMARY KEY ("suggestion_id", "member_id"),
jbe@0 800 "suggestion_id" INT8,
jbe@0 801 "member_id" INT4,
jbe@0 802 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
jbe@0 803 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@42 804 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 805 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@10 806 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
jbe@0 807
jbe@10 808 COMMENT ON TABLE "opinion" IS 'Opinion on suggestions (criticism related to initiatives); Frontends must ensure that opinions are not created modified or deleted when related to fully_frozen or closed issues.';
jbe@0 809
jbe@0 810 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
jbe@0 811
jbe@0 812
jbe@97 813 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
jbe@97 814
jbe@97 815 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
jbe@10 816
jbe@10 817
jbe@0 818 CREATE TABLE "delegation" (
jbe@0 819 "id" SERIAL8 PRIMARY KEY,
jbe@0 820 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@86 821 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@10 822 "scope" "delegation_scope" NOT NULL,
jbe@97 823 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 824 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 825 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 826 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
jbe@97 827 CONSTRAINT "no_unit_delegation_to_null"
jbe@97 828 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
jbe@10 829 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
jbe@97 830 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
jbe@97 831 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
jbe@97 832 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
jbe@97 833 UNIQUE ("unit_id", "truster_id"),
jbe@74 834 UNIQUE ("area_id", "truster_id"),
jbe@74 835 UNIQUE ("issue_id", "truster_id") );
jbe@0 836 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
jbe@0 837 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
jbe@0 838
jbe@0 839 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
jbe@0 840
jbe@97 841 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
jbe@0 842 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
jbe@0 843 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
jbe@0 844
jbe@0 845
jbe@0 846 CREATE TABLE "direct_population_snapshot" (
jbe@0 847 PRIMARY KEY ("issue_id", "event", "member_id"),
jbe@0 848 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 849 "event" "snapshot_event",
jbe@45 850 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@54 851 "weight" INT4 );
jbe@0 852 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
jbe@0 853
jbe@0 854 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"';
jbe@0 855
jbe@0 856 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
jbe@0 857 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
jbe@0 858
jbe@0 859
jbe@0 860 CREATE TABLE "delegating_population_snapshot" (
jbe@0 861 PRIMARY KEY ("issue_id", "event", "member_id"),
jbe@0 862 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 863 "event" "snapshot_event",
jbe@45 864 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@8 865 "weight" INT4,
jbe@10 866 "scope" "delegation_scope" NOT NULL,
jbe@0 867 "delegate_member_ids" INT4[] NOT NULL );
jbe@0 868 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
jbe@0 869
jbe@0 870 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table';
jbe@0 871
jbe@0 872 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
jbe@0 873 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
jbe@8 874 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
jbe@0 875 COMMENT ON COLUMN "delegating_population_snapshot"."delegate_member_ids" IS 'Chain of members who act as delegates; last entry referes to "member_id" column of table "direct_population_snapshot"';
jbe@0 876
jbe@0 877
jbe@0 878 CREATE TABLE "direct_interest_snapshot" (
jbe@0 879 PRIMARY KEY ("issue_id", "event", "member_id"),
jbe@0 880 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 881 "event" "snapshot_event",
jbe@45 882 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@0 883 "weight" INT4,
jbe@0 884 "voting_requested" BOOLEAN );
jbe@0 885 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
jbe@0 886
jbe@0 887 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"';
jbe@0 888
jbe@0 889 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
jbe@0 890 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
jbe@0 891 COMMENT ON COLUMN "direct_interest_snapshot"."voting_requested" IS 'Copied from column "voting_requested" of table "interest"';
jbe@0 892
jbe@0 893
jbe@0 894 CREATE TABLE "delegating_interest_snapshot" (
jbe@0 895 PRIMARY KEY ("issue_id", "event", "member_id"),
jbe@0 896 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 897 "event" "snapshot_event",
jbe@45 898 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@8 899 "weight" INT4,
jbe@10 900 "scope" "delegation_scope" NOT NULL,
jbe@0 901 "delegate_member_ids" INT4[] NOT NULL );
jbe@0 902 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
jbe@0 903
jbe@0 904 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table';
jbe@0 905
jbe@0 906 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
jbe@0 907 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
jbe@8 908 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
jbe@0 909 COMMENT ON COLUMN "delegating_interest_snapshot"."delegate_member_ids" IS 'Chain of members who act as delegates; last entry referes to "member_id" column of table "direct_interest_snapshot"';
jbe@0 910
jbe@0 911
jbe@0 912 CREATE TABLE "direct_supporter_snapshot" (
jbe@0 913 "issue_id" INT4 NOT NULL,
jbe@0 914 PRIMARY KEY ("initiative_id", "event", "member_id"),
jbe@0 915 "initiative_id" INT4,
jbe@0 916 "event" "snapshot_event",
jbe@45 917 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@0 918 "informed" BOOLEAN NOT NULL,
jbe@0 919 "satisfied" BOOLEAN NOT NULL,
jbe@0 920 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 921 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@0 922 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
jbe@0 923
jbe@8 924 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
jbe@0 925
jbe@0 926 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
jbe@0 927 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
jbe@0 928 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
jbe@0 929
jbe@0 930
jbe@113 931 CREATE TABLE "non_voter" (
jbe@113 932 PRIMARY KEY ("issue_id", "member_id"),
jbe@113 933 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@113 934 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@113 935 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
jbe@113 936
jbe@113 937 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
jbe@113 938
jbe@113 939
jbe@0 940 CREATE TABLE "direct_voter" (
jbe@0 941 PRIMARY KEY ("issue_id", "member_id"),
jbe@0 942 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@45 943 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@0 944 "weight" INT4,
jbe@0 945 "autoreject" BOOLEAN NOT NULL DEFAULT FALSE );
jbe@0 946 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
jbe@0 947
jbe@10 948 COMMENT ON TABLE "direct_voter" IS 'Members having directly voted for/against initiatives of an issue; Frontends must ensure that no voters are added or removed to/from this table when the issue has been closed.';
jbe@0 949
jbe@0 950 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
jbe@0 951 COMMENT ON COLUMN "direct_voter"."autoreject" IS 'Votes were inserted due to "autoreject" feature';
jbe@0 952
jbe@0 953
jbe@0 954 CREATE TABLE "delegating_voter" (
jbe@0 955 PRIMARY KEY ("issue_id", "member_id"),
jbe@0 956 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@45 957 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@8 958 "weight" INT4,
jbe@10 959 "scope" "delegation_scope" NOT NULL,
jbe@0 960 "delegate_member_ids" INT4[] NOT NULL );
jbe@52 961 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
jbe@0 962
jbe@0 963 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
jbe@0 964
jbe@0 965 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
jbe@8 966 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
jbe@0 967 COMMENT ON COLUMN "delegating_voter"."delegate_member_ids" IS 'Chain of members who act as delegates; last entry referes to "member_id" column of table "direct_voter"';
jbe@0 968
jbe@0 969
jbe@0 970 CREATE TABLE "vote" (
jbe@0 971 "issue_id" INT4 NOT NULL,
jbe@0 972 PRIMARY KEY ("initiative_id", "member_id"),
jbe@0 973 "initiative_id" INT4,
jbe@0 974 "member_id" INT4,
jbe@0 975 "grade" INT4,
jbe@0 976 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 977 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@0 978 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
jbe@0 979
jbe@10 980 COMMENT ON TABLE "vote" IS 'Manual and delegated votes without abstentions; Frontends must ensure that no votes are added modified or removed when the issue has been closed.';
jbe@0 981
jbe@0 982 COMMENT ON COLUMN "vote"."grade" IS 'Values smaller than zero mean reject, values greater than zero mean acceptance, zero or missing row means abstention. Preferences are expressed by different positive or negative numbers.';
jbe@0 983
jbe@0 984
jbe@111 985 CREATE TABLE "issue_comment" (
jbe@111 986 PRIMARY KEY ("issue_id", "member_id"),
jbe@111 987 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@111 988 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@111 989 "changed" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@111 990 "formatting_engine" TEXT,
jbe@111 991 "content" TEXT NOT NULL,
jbe@111 992 "text_search_data" TSVECTOR );
jbe@111 993 CREATE INDEX "issue_comment_member_id_idx" ON "issue_comment" ("member_id");
jbe@111 994 CREATE INDEX "issue_comment_text_search_data_idx" ON "issue_comment" USING gin ("text_search_data");
jbe@111 995 CREATE TRIGGER "update_text_search_data"
jbe@111 996 BEFORE INSERT OR UPDATE ON "issue_comment"
jbe@111 997 FOR EACH ROW EXECUTE PROCEDURE
jbe@111 998 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
jbe@111 999
jbe@111 1000 COMMENT ON TABLE "issue_comment" IS 'Place to store free comments of members related to issues';
jbe@111 1001
jbe@111 1002 COMMENT ON COLUMN "issue_comment"."changed" IS 'Time the comment was last changed';
jbe@111 1003
jbe@111 1004
jbe@111 1005 CREATE TABLE "rendered_issue_comment" (
jbe@111 1006 PRIMARY KEY ("issue_id", "member_id", "format"),
jbe@111 1007 FOREIGN KEY ("issue_id", "member_id")
jbe@111 1008 REFERENCES "issue_comment" ("issue_id", "member_id")
jbe@111 1009 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@111 1010 "issue_id" INT4,
jbe@111 1011 "member_id" INT4,
jbe@111 1012 "format" TEXT,
jbe@111 1013 "content" TEXT NOT NULL );
jbe@111 1014
jbe@111 1015 COMMENT ON TABLE "rendered_issue_comment" IS 'This table may be used by frontends to cache "rendered" issue comments (e.g. HTML output generated from wiki text)';
jbe@111 1016
jbe@111 1017
jbe@111 1018 CREATE TABLE "voting_comment" (
jbe@111 1019 PRIMARY KEY ("issue_id", "member_id"),
jbe@111 1020 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@111 1021 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@111 1022 "changed" TIMESTAMPTZ,
jbe@111 1023 "formatting_engine" TEXT,
jbe@111 1024 "content" TEXT NOT NULL,
jbe@111 1025 "text_search_data" TSVECTOR );
jbe@111 1026 CREATE INDEX "voting_comment_member_id_idx" ON "voting_comment" ("member_id");
jbe@111 1027 CREATE INDEX "voting_comment_text_search_data_idx" ON "voting_comment" USING gin ("text_search_data");
jbe@111 1028 CREATE TRIGGER "update_text_search_data"
jbe@111 1029 BEFORE INSERT OR UPDATE ON "voting_comment"
jbe@111 1030 FOR EACH ROW EXECUTE PROCEDURE
jbe@111 1031 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
jbe@111 1032
jbe@111 1033 COMMENT ON TABLE "voting_comment" IS 'Storage for comments of voters to be published after voting has finished.';
jbe@111 1034
jbe@111 1035 COMMENT ON COLUMN "voting_comment"."changed" IS 'Is to be set or updated by the frontend, if comment was inserted or updated AFTER the issue has been closed. Otherwise it shall be set to NULL.';
jbe@111 1036
jbe@111 1037
jbe@111 1038 CREATE TABLE "rendered_voting_comment" (
jbe@111 1039 PRIMARY KEY ("issue_id", "member_id", "format"),
jbe@111 1040 FOREIGN KEY ("issue_id", "member_id")
jbe@111 1041 REFERENCES "voting_comment" ("issue_id", "member_id")
jbe@111 1042 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@111 1043 "issue_id" INT4,
jbe@111 1044 "member_id" INT4,
jbe@111 1045 "format" TEXT,
jbe@111 1046 "content" TEXT NOT NULL );
jbe@111 1047
jbe@111 1048 COMMENT ON TABLE "rendered_voting_comment" IS 'This table may be used by frontends to cache "rendered" voting comments (e.g. HTML output generated from wiki text)';
jbe@111 1049
jbe@111 1050
jbe@112 1051 CREATE TYPE "event_type" AS ENUM (
jbe@112 1052 'issue_state_changed',
jbe@112 1053 'initiative_created_in_new_issue',
jbe@112 1054 'initiative_created_in_existing_issue',
jbe@112 1055 'initiative_revoked',
jbe@112 1056 'new_draft_created',
jbe@112 1057 'suggestion_created');
jbe@112 1058
jbe@112 1059 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
jbe@112 1060
jbe@112 1061
jbe@112 1062 CREATE TABLE "event" (
jbe@112 1063 "id" SERIAL8 PRIMARY KEY,
jbe@112 1064 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@112 1065 "event" "event_type" NOT NULL,
jbe@112 1066 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@112 1067 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@112 1068 "state" "issue_state" CHECK ("state" != 'calculation'),
jbe@112 1069 "initiative_id" INT4,
jbe@112 1070 "draft_id" INT8,
jbe@112 1071 "suggestion_id" INT8,
jbe@112 1072 FOREIGN KEY ("issue_id", "initiative_id")
jbe@112 1073 REFERENCES "initiative" ("issue_id", "id")
jbe@112 1074 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@112 1075 FOREIGN KEY ("initiative_id", "draft_id")
jbe@112 1076 REFERENCES "draft" ("initiative_id", "id")
jbe@112 1077 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@112 1078 FOREIGN KEY ("initiative_id", "suggestion_id")
jbe@112 1079 REFERENCES "suggestion" ("initiative_id", "id")
jbe@112 1080 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@112 1081 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
jbe@112 1082 "event" != 'issue_state_changed' OR (
jbe@112 1083 "member_id" ISNULL AND
jbe@112 1084 "issue_id" NOTNULL AND
jbe@113 1085 "state" NOTNULL AND
jbe@112 1086 "initiative_id" ISNULL AND
jbe@112 1087 "draft_id" ISNULL AND
jbe@112 1088 "suggestion_id" ISNULL )),
jbe@112 1089 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
jbe@112 1090 "event" NOT IN (
jbe@112 1091 'initiative_created_in_new_issue',
jbe@112 1092 'initiative_created_in_existing_issue',
jbe@112 1093 'initiative_revoked',
jbe@112 1094 'new_draft_created'
jbe@112 1095 ) OR (
jbe@112 1096 "member_id" NOTNULL AND
jbe@112 1097 "issue_id" NOTNULL AND
jbe@113 1098 "state" NOTNULL AND
jbe@112 1099 "initiative_id" NOTNULL AND
jbe@112 1100 "draft_id" NOTNULL AND
jbe@112 1101 "suggestion_id" ISNULL )),
jbe@112 1102 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
jbe@112 1103 "event" != 'suggestion_created' OR (
jbe@112 1104 "member_id" NOTNULL AND
jbe@112 1105 "issue_id" NOTNULL AND
jbe@113 1106 "state" NOTNULL AND
jbe@112 1107 "initiative_id" NOTNULL AND
jbe@112 1108 "draft_id" ISNULL AND
jbe@112 1109 "suggestion_id" NOTNULL )) );
jbe@112 1110
jbe@112 1111 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
jbe@112 1112
jbe@114 1113 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
jbe@114 1114 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
jbe@114 1115 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
jbe@114 1116 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
jbe@114 1117
jbe@112 1118
jbe@112 1119
jbe@112 1120 ----------------------------------------------
jbe@112 1121 -- Writing of history entries and event log --
jbe@112 1122 ----------------------------------------------
jbe@13 1123
jbe@13 1124 CREATE FUNCTION "write_member_history_trigger"()
jbe@13 1125 RETURNS TRIGGER
jbe@13 1126 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@13 1127 BEGIN
jbe@42 1128 IF
jbe@42 1129 NEW."active" != OLD."active" OR
jbe@42 1130 NEW."name" != OLD."name"
jbe@42 1131 THEN
jbe@42 1132 INSERT INTO "member_history"
jbe@57 1133 ("member_id", "active", "name")
jbe@57 1134 VALUES (NEW."id", OLD."active", OLD."name");
jbe@13 1135 END IF;
jbe@13 1136 RETURN NULL;
jbe@13 1137 END;
jbe@13 1138 $$;
jbe@13 1139
jbe@13 1140 CREATE TRIGGER "write_member_history"
jbe@13 1141 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
jbe@13 1142 "write_member_history_trigger"();
jbe@13 1143
jbe@13 1144 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
jbe@57 1145 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
jbe@13 1146
jbe@13 1147
jbe@112 1148 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
jbe@112 1149 RETURNS TRIGGER
jbe@112 1150 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@112 1151 BEGIN
jbe@112 1152 IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
jbe@112 1153 INSERT INTO "event" ("event", "issue_id", "state")
jbe@112 1154 VALUES ('issue_state_changed', NEW."id", NEW."state");
jbe@112 1155 END IF;
jbe@112 1156 RETURN NULL;
jbe@112 1157 END;
jbe@112 1158 $$;
jbe@112 1159
jbe@112 1160 CREATE TRIGGER "write_event_issue_state_changed"
jbe@112 1161 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 1162 "write_event_issue_state_changed_trigger"();
jbe@112 1163
jbe@112 1164 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
jbe@112 1165 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
jbe@112 1166
jbe@112 1167
jbe@112 1168 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
jbe@112 1169 RETURNS TRIGGER
jbe@112 1170 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@112 1171 DECLARE
jbe@112 1172 "initiative_row" "initiative"%ROWTYPE;
jbe@113 1173 "issue_row" "issue"%ROWTYPE;
jbe@112 1174 "event_v" "event_type";
jbe@112 1175 BEGIN
jbe@112 1176 SELECT * INTO "initiative_row" FROM "initiative"
jbe@112 1177 WHERE "id" = NEW."initiative_id";
jbe@113 1178 SELECT * INTO "issue_row" FROM "issue"
jbe@113 1179 WHERE "id" = "initiative_row"."issue_id";
jbe@112 1180 IF EXISTS (
jbe@112 1181 SELECT NULL FROM "draft"
jbe@112 1182 WHERE "initiative_id" = NEW."initiative_id"
jbe@112 1183 AND "id" != NEW."id"
jbe@112 1184 ) THEN
jbe@112 1185 "event_v" := 'new_draft_created';
jbe@112 1186 ELSE
jbe@112 1187 IF EXISTS (
jbe@112 1188 SELECT NULL FROM "initiative"
jbe@112 1189 WHERE "issue_id" = "initiative_row"."issue_id"
jbe@112 1190 AND "id" != "initiative_row"."id"
jbe@112 1191 ) THEN
jbe@112 1192 "event_v" := 'initiative_created_in_existing_issue';
jbe@112 1193 ELSE
jbe@112 1194 "event_v" := 'initiative_created_in_new_issue';
jbe@112 1195 END IF;
jbe@112 1196 END IF;
jbe@112 1197 INSERT INTO "event" (
jbe@112 1198 "event", "member_id",
jbe@113 1199 "issue_id", "state", "initiative_id", "draft_id"
jbe@112 1200 ) VALUES (
jbe@112 1201 "event_v",
jbe@112 1202 NEW."author_id",
jbe@112 1203 "initiative_row"."issue_id",
jbe@113 1204 "issue_row"."state",
jbe@112 1205 "initiative_row"."id",
jbe@112 1206 NEW."id" );
jbe@112 1207 RETURN NULL;
jbe@112 1208 END;
jbe@112 1209 $$;
jbe@112 1210
jbe@112 1211 CREATE TRIGGER "write_event_initiative_or_draft_created"
jbe@112 1212 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 1213 "write_event_initiative_or_draft_created_trigger"();
jbe@112 1214
jbe@112 1215 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
jbe@112 1216 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
jbe@112 1217
jbe@112 1218
jbe@112 1219 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
jbe@112 1220 RETURNS TRIGGER
jbe@112 1221 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@113 1222 DECLARE
jbe@113 1223 "issue_row" "issue"%ROWTYPE;
jbe@112 1224 BEGIN
jbe@113 1225 SELECT * INTO "issue_row" FROM "issue"
jbe@113 1226 WHERE "id" = NEW."issue_id";
jbe@112 1227 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
jbe@112 1228 INSERT INTO "event" (
jbe@113 1229 "event", "member_id", "issue_id", "state", "initiative_id"
jbe@112 1230 ) VALUES (
jbe@112 1231 'initiative_revoked',
jbe@112 1232 NEW."revoked_by_member_id",
jbe@112 1233 NEW."issue_id",
jbe@113 1234 "issue_row"."state",
jbe@112 1235 NEW."id" );
jbe@112 1236 END IF;
jbe@112 1237 RETURN NULL;
jbe@112 1238 END;
jbe@112 1239 $$;
jbe@112 1240
jbe@112 1241 CREATE TRIGGER "write_event_initiative_revoked"
jbe@112 1242 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 1243 "write_event_initiative_revoked_trigger"();
jbe@112 1244
jbe@112 1245 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
jbe@112 1246 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
jbe@112 1247
jbe@112 1248
jbe@112 1249 CREATE FUNCTION "write_event_suggestion_created_trigger"()
jbe@112 1250 RETURNS TRIGGER
jbe@112 1251 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@112 1252 DECLARE
jbe@112 1253 "initiative_row" "initiative"%ROWTYPE;
jbe@113 1254 "issue_row" "issue"%ROWTYPE;
jbe@112 1255 BEGIN
jbe@112 1256 SELECT * INTO "initiative_row" FROM "initiative"
jbe@112 1257 WHERE "id" = NEW."initiative_id";
jbe@113 1258 SELECT * INTO "issue_row" FROM "issue"
jbe@113 1259 WHERE "id" = "initiative_row"."issue_id";
jbe@112 1260 INSERT INTO "event" (
jbe@112 1261 "event", "member_id",
jbe@113 1262 "issue_id", "state", "initiative_id", "suggestion_id"
jbe@112 1263 ) VALUES (
jbe@112 1264 'suggestion_created',
jbe@112 1265 NEW."author_id",
jbe@112 1266 "initiative_row"."issue_id",
jbe@113 1267 "issue_row"."state",
jbe@112 1268 "initiative_row"."id",
jbe@112 1269 NEW."id" );
jbe@112 1270 RETURN NULL;
jbe@112 1271 END;
jbe@112 1272 $$;
jbe@112 1273
jbe@112 1274 CREATE TRIGGER "write_event_suggestion_created"
jbe@112 1275 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 1276 "write_event_suggestion_created_trigger"();
jbe@112 1277
jbe@112 1278 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
jbe@112 1279 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
jbe@112 1280
jbe@112 1281
jbe@13 1282
jbe@0 1283 ----------------------------
jbe@0 1284 -- Additional constraints --
jbe@0 1285 ----------------------------
jbe@0 1286
jbe@0 1287
jbe@0 1288 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
jbe@0 1289 RETURNS TRIGGER
jbe@0 1290 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1291 BEGIN
jbe@0 1292 IF NOT EXISTS (
jbe@0 1293 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
jbe@0 1294 ) THEN
jbe@0 1295 --RAISE 'Cannot create issue without an initial initiative.' USING
jbe@0 1296 -- ERRCODE = 'integrity_constraint_violation',
jbe@0 1297 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
jbe@0 1298 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
jbe@0 1299 END IF;
jbe@0 1300 RETURN NULL;
jbe@0 1301 END;
jbe@0 1302 $$;
jbe@0 1303
jbe@0 1304 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
jbe@0 1305 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
jbe@0 1306 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 1307 "issue_requires_first_initiative_trigger"();
jbe@0 1308
jbe@0 1309 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
jbe@0 1310 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
jbe@0 1311
jbe@0 1312
jbe@0 1313 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
jbe@0 1314 RETURNS TRIGGER
jbe@0 1315 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1316 DECLARE
jbe@0 1317 "reference_lost" BOOLEAN;
jbe@0 1318 BEGIN
jbe@0 1319 IF TG_OP = 'DELETE' THEN
jbe@0 1320 "reference_lost" := TRUE;
jbe@0 1321 ELSE
jbe@0 1322 "reference_lost" := NEW."issue_id" != OLD."issue_id";
jbe@0 1323 END IF;
jbe@0 1324 IF
jbe@0 1325 "reference_lost" AND NOT EXISTS (
jbe@0 1326 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
jbe@0 1327 )
jbe@0 1328 THEN
jbe@0 1329 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
jbe@0 1330 END IF;
jbe@0 1331 RETURN NULL;
jbe@0 1332 END;
jbe@0 1333 $$;
jbe@0 1334
jbe@0 1335 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
jbe@0 1336 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
jbe@0 1337 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 1338 "last_initiative_deletes_issue_trigger"();
jbe@0 1339
jbe@0 1340 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
jbe@0 1341 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
jbe@0 1342
jbe@0 1343
jbe@0 1344 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
jbe@0 1345 RETURNS TRIGGER
jbe@0 1346 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1347 BEGIN
jbe@0 1348 IF NOT EXISTS (
jbe@0 1349 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
jbe@0 1350 ) THEN
jbe@0 1351 --RAISE 'Cannot create initiative without an initial draft.' USING
jbe@0 1352 -- ERRCODE = 'integrity_constraint_violation',
jbe@0 1353 -- HINT = 'Create issue, initiative and draft within the same transaction.';
jbe@0 1354 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
jbe@0 1355 END IF;
jbe@0 1356 RETURN NULL;
jbe@0 1357 END;
jbe@0 1358 $$;
jbe@0 1359
jbe@0 1360 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
jbe@0 1361 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
jbe@0 1362 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 1363 "initiative_requires_first_draft_trigger"();
jbe@0 1364
jbe@0 1365 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
jbe@0 1366 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
jbe@0 1367
jbe@0 1368
jbe@0 1369 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
jbe@0 1370 RETURNS TRIGGER
jbe@0 1371 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1372 DECLARE
jbe@0 1373 "reference_lost" BOOLEAN;
jbe@0 1374 BEGIN
jbe@0 1375 IF TG_OP = 'DELETE' THEN
jbe@0 1376 "reference_lost" := TRUE;
jbe@0 1377 ELSE
jbe@0 1378 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
jbe@0 1379 END IF;
jbe@0 1380 IF
jbe@0 1381 "reference_lost" AND NOT EXISTS (
jbe@0 1382 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
jbe@0 1383 )
jbe@0 1384 THEN
jbe@0 1385 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
jbe@0 1386 END IF;
jbe@0 1387 RETURN NULL;
jbe@0 1388 END;
jbe@0 1389 $$;
jbe@0 1390
jbe@0 1391 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
jbe@0 1392 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
jbe@0 1393 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 1394 "last_draft_deletes_initiative_trigger"();
jbe@0 1395
jbe@0 1396 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
jbe@0 1397 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
jbe@0 1398
jbe@0 1399
jbe@0 1400 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
jbe@0 1401 RETURNS TRIGGER
jbe@0 1402 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1403 BEGIN
jbe@0 1404 IF NOT EXISTS (
jbe@0 1405 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
jbe@0 1406 ) THEN
jbe@0 1407 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
jbe@0 1408 END IF;
jbe@0 1409 RETURN NULL;
jbe@0 1410 END;
jbe@0 1411 $$;
jbe@0 1412
jbe@0 1413 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
jbe@0 1414 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
jbe@0 1415 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 1416 "suggestion_requires_first_opinion_trigger"();
jbe@0 1417
jbe@0 1418 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
jbe@0 1419 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
jbe@0 1420
jbe@0 1421
jbe@0 1422 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
jbe@0 1423 RETURNS TRIGGER
jbe@0 1424 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1425 DECLARE
jbe@0 1426 "reference_lost" BOOLEAN;
jbe@0 1427 BEGIN
jbe@0 1428 IF TG_OP = 'DELETE' THEN
jbe@0 1429 "reference_lost" := TRUE;
jbe@0 1430 ELSE
jbe@0 1431 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
jbe@0 1432 END IF;
jbe@0 1433 IF
jbe@0 1434 "reference_lost" AND NOT EXISTS (
jbe@0 1435 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
jbe@0 1436 )
jbe@0 1437 THEN
jbe@0 1438 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
jbe@0 1439 END IF;
jbe@0 1440 RETURN NULL;
jbe@0 1441 END;
jbe@0 1442 $$;
jbe@0 1443
jbe@0 1444 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
jbe@0 1445 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
jbe@0 1446 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 1447 "last_opinion_deletes_suggestion_trigger"();
jbe@0 1448
jbe@0 1449 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
jbe@0 1450 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
jbe@0 1451
jbe@0 1452
jbe@0 1453
jbe@20 1454 ---------------------------------------------------------------
jbe@20 1455 -- Ensure that votes are not modified when issues are frozen --
jbe@20 1456 ---------------------------------------------------------------
jbe@20 1457
jbe@20 1458 -- NOTE: Frontends should ensure this anyway, but in case of programming
jbe@20 1459 -- errors the following triggers ensure data integrity.
jbe@20 1460
jbe@20 1461
jbe@20 1462 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
jbe@20 1463 RETURNS TRIGGER
jbe@20 1464 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@20 1465 DECLARE
jbe@32 1466 "issue_id_v" "issue"."id"%TYPE;
jbe@32 1467 "issue_row" "issue"%ROWTYPE;
jbe@20 1468 BEGIN
jbe@32 1469 IF TG_OP = 'DELETE' THEN
jbe@32 1470 "issue_id_v" := OLD."issue_id";
jbe@32 1471 ELSE
jbe@32 1472 "issue_id_v" := NEW."issue_id";
jbe@32 1473 END IF;
jbe@20 1474 SELECT INTO "issue_row" * FROM "issue"
jbe@32 1475 WHERE "id" = "issue_id_v" FOR SHARE;
jbe@20 1476 IF "issue_row"."closed" NOTNULL THEN
jbe@20 1477 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
jbe@20 1478 END IF;
jbe@20 1479 RETURN NULL;
jbe@20 1480 END;
jbe@20 1481 $$;
jbe@20 1482
jbe@20 1483 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 1484 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
jbe@20 1485 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 1486 "forbid_changes_on_closed_issue_trigger"();
jbe@20 1487
jbe@20 1488 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 1489 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
jbe@20 1490 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 1491 "forbid_changes_on_closed_issue_trigger"();
jbe@20 1492
jbe@20 1493 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 1494 AFTER INSERT OR UPDATE OR DELETE ON "vote"
jbe@20 1495 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 1496 "forbid_changes_on_closed_issue_trigger"();
jbe@20 1497
jbe@20 1498 COMMENT ON FUNCTION "forbid_changes_on_closed_issue_trigger"() IS 'Implementation of triggers "forbid_changes_on_closed_issue" on tables "direct_voter", "delegating_voter" and "vote"';
jbe@20 1499 COMMENT ON TRIGGER "forbid_changes_on_closed_issue" ON "direct_voter" IS 'Ensures that frontends can''t tamper with votings of closed issues, in case of programming errors';
jbe@20 1500 COMMENT ON TRIGGER "forbid_changes_on_closed_issue" ON "delegating_voter" IS 'Ensures that frontends can''t tamper with votings of closed issues, in case of programming errors';
jbe@20 1501 COMMENT ON TRIGGER "forbid_changes_on_closed_issue" ON "vote" IS 'Ensures that frontends can''t tamper with votings of closed issues, in case of programming errors';
jbe@20 1502
jbe@20 1503
jbe@20 1504
jbe@0 1505 --------------------------------------------------------------------
jbe@0 1506 -- Auto-retrieval of fields only needed for referential integrity --
jbe@0 1507 --------------------------------------------------------------------
jbe@0 1508
jbe@20 1509
jbe@0 1510 CREATE FUNCTION "autofill_issue_id_trigger"()
jbe@0 1511 RETURNS TRIGGER
jbe@0 1512 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1513 BEGIN
jbe@0 1514 IF NEW."issue_id" ISNULL THEN
jbe@0 1515 SELECT "issue_id" INTO NEW."issue_id"
jbe@0 1516 FROM "initiative" WHERE "id" = NEW."initiative_id";
jbe@0 1517 END IF;
jbe@0 1518 RETURN NEW;
jbe@0 1519 END;
jbe@0 1520 $$;
jbe@0 1521
jbe@0 1522 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
jbe@0 1523 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
jbe@0 1524
jbe@0 1525 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
jbe@0 1526 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
jbe@0 1527
jbe@0 1528 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
jbe@0 1529 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
jbe@0 1530 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
jbe@0 1531
jbe@0 1532
jbe@0 1533 CREATE FUNCTION "autofill_initiative_id_trigger"()
jbe@0 1534 RETURNS TRIGGER
jbe@0 1535 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1536 BEGIN
jbe@0 1537 IF NEW."initiative_id" ISNULL THEN
jbe@0 1538 SELECT "initiative_id" INTO NEW."initiative_id"
jbe@0 1539 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
jbe@0 1540 END IF;
jbe@0 1541 RETURN NEW;
jbe@0 1542 END;
jbe@0 1543 $$;
jbe@0 1544
jbe@0 1545 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
jbe@0 1546 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
jbe@0 1547
jbe@0 1548 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
jbe@0 1549 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
jbe@0 1550
jbe@0 1551
jbe@0 1552
jbe@4 1553 -----------------------------------------------------
jbe@4 1554 -- Automatic calculation of certain default values --
jbe@4 1555 -----------------------------------------------------
jbe@0 1556
jbe@22 1557
jbe@22 1558 CREATE FUNCTION "copy_timings_trigger"()
jbe@22 1559 RETURNS TRIGGER
jbe@22 1560 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@22 1561 DECLARE
jbe@22 1562 "policy_row" "policy"%ROWTYPE;
jbe@22 1563 BEGIN
jbe@22 1564 SELECT * INTO "policy_row" FROM "policy"
jbe@22 1565 WHERE "id" = NEW."policy_id";
jbe@22 1566 IF NEW."admission_time" ISNULL THEN
jbe@22 1567 NEW."admission_time" := "policy_row"."admission_time";
jbe@22 1568 END IF;
jbe@22 1569 IF NEW."discussion_time" ISNULL THEN
jbe@22 1570 NEW."discussion_time" := "policy_row"."discussion_time";
jbe@22 1571 END IF;
jbe@22 1572 IF NEW."verification_time" ISNULL THEN
jbe@22 1573 NEW."verification_time" := "policy_row"."verification_time";
jbe@22 1574 END IF;
jbe@22 1575 IF NEW."voting_time" ISNULL THEN
jbe@22 1576 NEW."voting_time" := "policy_row"."voting_time";
jbe@22 1577 END IF;
jbe@22 1578 RETURN NEW;
jbe@22 1579 END;
jbe@22 1580 $$;
jbe@22 1581
jbe@22 1582 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
jbe@22 1583 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
jbe@22 1584
jbe@22 1585 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
jbe@22 1586 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
jbe@22 1587
jbe@22 1588
jbe@2 1589 CREATE FUNCTION "supporter_default_for_draft_id_trigger"()
jbe@2 1590 RETURNS TRIGGER
jbe@2 1591 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@2 1592 BEGIN
jbe@2 1593 IF NEW."draft_id" ISNULL THEN
jbe@2 1594 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
jbe@2 1595 WHERE "initiative_id" = NEW."initiative_id";
jbe@2 1596 END IF;
jbe@2 1597 RETURN NEW;
jbe@2 1598 END;
jbe@2 1599 $$;
jbe@2 1600
jbe@2 1601 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
jbe@2 1602 FOR EACH ROW EXECUTE PROCEDURE "supporter_default_for_draft_id_trigger"();
jbe@2 1603
jbe@2 1604 COMMENT ON FUNCTION "supporter_default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on table "supporter"';
jbe@2 1605 COMMENT ON TRIGGER "default_for_draft_id" ON "supporter" IS 'If "draft_id" is NULL, then use the current draft of the initiative as default';
jbe@2 1606
jbe@2 1607
jbe@0 1608
jbe@0 1609 ----------------------------------------
jbe@0 1610 -- Automatic creation of dependencies --
jbe@0 1611 ----------------------------------------
jbe@0 1612
jbe@22 1613
jbe@0 1614 CREATE FUNCTION "autocreate_interest_trigger"()
jbe@0 1615 RETURNS TRIGGER
jbe@0 1616 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1617 BEGIN
jbe@0 1618 IF NOT EXISTS (
jbe@0 1619 SELECT NULL FROM "initiative" JOIN "interest"
jbe@0 1620 ON "initiative"."issue_id" = "interest"."issue_id"
jbe@0 1621 WHERE "initiative"."id" = NEW."initiative_id"
jbe@0 1622 AND "interest"."member_id" = NEW."member_id"
jbe@0 1623 ) THEN
jbe@0 1624 BEGIN
jbe@0 1625 INSERT INTO "interest" ("issue_id", "member_id")
jbe@0 1626 SELECT "issue_id", NEW."member_id"
jbe@0 1627 FROM "initiative" WHERE "id" = NEW."initiative_id";
jbe@0 1628 EXCEPTION WHEN unique_violation THEN END;
jbe@0 1629 END IF;
jbe@0 1630 RETURN NEW;
jbe@0 1631 END;
jbe@0 1632 $$;
jbe@0 1633
jbe@0 1634 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
jbe@0 1635 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
jbe@0 1636
jbe@0 1637 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
jbe@0 1638 COMMENT ON TRIGGER "autocreate_interest" ON "supporter" IS 'Supporting an initiative implies interest in the issue, thus automatically creates an entry in the "interest" table';
jbe@0 1639
jbe@0 1640
jbe@0 1641 CREATE FUNCTION "autocreate_supporter_trigger"()
jbe@0 1642 RETURNS TRIGGER
jbe@0 1643 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1644 BEGIN
jbe@0 1645 IF NOT EXISTS (
jbe@0 1646 SELECT NULL FROM "suggestion" JOIN "supporter"
jbe@0 1647 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
jbe@0 1648 WHERE "suggestion"."id" = NEW."suggestion_id"
jbe@0 1649 AND "supporter"."member_id" = NEW."member_id"
jbe@0 1650 ) THEN
jbe@0 1651 BEGIN
jbe@0 1652 INSERT INTO "supporter" ("initiative_id", "member_id")
jbe@0 1653 SELECT "initiative_id", NEW."member_id"
jbe@0 1654 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
jbe@0 1655 EXCEPTION WHEN unique_violation THEN END;
jbe@0 1656 END IF;
jbe@0 1657 RETURN NEW;
jbe@0 1658 END;
jbe@0 1659 $$;
jbe@0 1660
jbe@0 1661 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
jbe@0 1662 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
jbe@0 1663
jbe@0 1664 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
jbe@0 1665 COMMENT ON TRIGGER "autocreate_supporter" ON "opinion" IS 'Opinions can only be added for supported initiatives. This trigger automatrically creates an entry in the "supporter" table, if not existent yet.';
jbe@0 1666
jbe@0 1667
jbe@0 1668
jbe@0 1669 ------------------------------------------
jbe@0 1670 -- Views and helper functions for views --
jbe@0 1671 ------------------------------------------
jbe@0 1672
jbe@5 1673
jbe@97 1674 CREATE VIEW "unit_delegation" AS
jbe@97 1675 SELECT
jbe@97 1676 "unit"."id" AS "unit_id",
jbe@97 1677 "delegation"."id",
jbe@97 1678 "delegation"."truster_id",
jbe@97 1679 "delegation"."trustee_id",
jbe@97 1680 "delegation"."scope"
jbe@97 1681 FROM "unit"
jbe@97 1682 JOIN "delegation"
jbe@97 1683 ON "delegation"."unit_id" = "unit"."id"
jbe@97 1684 JOIN "member"
jbe@97 1685 ON "delegation"."truster_id" = "member"."id"
jbe@97 1686 JOIN "privilege"
jbe@97 1687 ON "delegation"."unit_id" = "privilege"."unit_id"
jbe@97 1688 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@97 1689 WHERE "member"."active" AND "privilege"."voting_right";
jbe@97 1690
jbe@97 1691 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
jbe@5 1692
jbe@5 1693
jbe@5 1694 CREATE VIEW "area_delegation" AS
jbe@70 1695 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
jbe@70 1696 "area"."id" AS "area_id",
jbe@70 1697 "delegation"."id",
jbe@70 1698 "delegation"."truster_id",
jbe@70 1699 "delegation"."trustee_id",
jbe@70 1700 "delegation"."scope"
jbe@97 1701 FROM "area"
jbe@97 1702 JOIN "delegation"
jbe@97 1703 ON "delegation"."unit_id" = "area"."unit_id"
jbe@97 1704 OR "delegation"."area_id" = "area"."id"
jbe@97 1705 JOIN "member"
jbe@97 1706 ON "delegation"."truster_id" = "member"."id"
jbe@97 1707 JOIN "privilege"
jbe@97 1708 ON "area"."unit_id" = "privilege"."unit_id"
jbe@97 1709 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@97 1710 WHERE "member"."active" AND "privilege"."voting_right"
jbe@70 1711 ORDER BY
jbe@70 1712 "area"."id",
jbe@70 1713 "delegation"."truster_id",
jbe@70 1714 "delegation"."scope" DESC;
jbe@70 1715
jbe@97 1716 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
jbe@5 1717
jbe@5 1718
jbe@5 1719 CREATE VIEW "issue_delegation" AS
jbe@70 1720 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
jbe@70 1721 "issue"."id" AS "issue_id",
jbe@70 1722 "delegation"."id",
jbe@70 1723 "delegation"."truster_id",
jbe@70 1724 "delegation"."trustee_id",
jbe@70 1725 "delegation"."scope"
jbe@97 1726 FROM "issue"
jbe@97 1727 JOIN "area"
jbe@97 1728 ON "area"."id" = "issue"."area_id"
jbe@97 1729 JOIN "delegation"
jbe@97 1730 ON "delegation"."unit_id" = "area"."unit_id"
jbe@97 1731 OR "delegation"."area_id" = "area"."id"
jbe@97 1732 OR "delegation"."issue_id" = "issue"."id"
jbe@97 1733 JOIN "member"
jbe@97 1734 ON "delegation"."truster_id" = "member"."id"
jbe@97 1735 JOIN "privilege"
jbe@97 1736 ON "area"."unit_id" = "privilege"."unit_id"
jbe@97 1737 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@97 1738 WHERE "member"."active" AND "privilege"."voting_right"
jbe@70 1739 ORDER BY
jbe@70 1740 "issue"."id",
jbe@70 1741 "delegation"."truster_id",
jbe@70 1742 "delegation"."scope" DESC;
jbe@70 1743
jbe@97 1744 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
jbe@5 1745
jbe@5 1746
jbe@5 1747 CREATE FUNCTION "membership_weight_with_skipping"
jbe@5 1748 ( "area_id_p" "area"."id"%TYPE,
jbe@5 1749 "member_id_p" "member"."id"%TYPE,
jbe@5 1750 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
jbe@5 1751 RETURNS INT4
jbe@5 1752 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 1753 DECLARE
jbe@5 1754 "sum_v" INT4;
jbe@5 1755 "delegation_row" "area_delegation"%ROWTYPE;
jbe@5 1756 BEGIN
jbe@5 1757 "sum_v" := 1;
jbe@5 1758 FOR "delegation_row" IN
jbe@5 1759 SELECT "area_delegation".*
jbe@5 1760 FROM "area_delegation" LEFT JOIN "membership"
jbe@5 1761 ON "membership"."area_id" = "area_id_p"
jbe@5 1762 AND "membership"."member_id" = "area_delegation"."truster_id"
jbe@5 1763 WHERE "area_delegation"."area_id" = "area_id_p"
jbe@5 1764 AND "area_delegation"."trustee_id" = "member_id_p"
jbe@5 1765 AND "membership"."member_id" ISNULL
jbe@5 1766 LOOP
jbe@5 1767 IF NOT
jbe@5 1768 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
jbe@5 1769 THEN
jbe@5 1770 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
jbe@5 1771 "area_id_p",
jbe@5 1772 "delegation_row"."truster_id",
jbe@5 1773 "skip_member_ids_p" || "delegation_row"."truster_id"
jbe@5 1774 );
jbe@5 1775 END IF;
jbe@5 1776 END LOOP;
jbe@5 1777 RETURN "sum_v";
jbe@5 1778 END;
jbe@5 1779 $$;
jbe@5 1780
jbe@8 1781 COMMENT ON FUNCTION "membership_weight_with_skipping"
jbe@8 1782 ( "area"."id"%TYPE,
jbe@8 1783 "member"."id"%TYPE,
jbe@8 1784 INT4[] )
jbe@8 1785 IS 'Helper function for "membership_weight" function';
jbe@8 1786
jbe@8 1787
jbe@5 1788 CREATE FUNCTION "membership_weight"
jbe@5 1789 ( "area_id_p" "area"."id"%TYPE,
jbe@5 1790 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
jbe@5 1791 RETURNS INT4
jbe@5 1792 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 1793 BEGIN
jbe@5 1794 RETURN "membership_weight_with_skipping"(
jbe@5 1795 "area_id_p",
jbe@5 1796 "member_id_p",
jbe@5 1797 ARRAY["member_id_p"]
jbe@5 1798 );
jbe@5 1799 END;
jbe@5 1800 $$;
jbe@5 1801
jbe@8 1802 COMMENT ON FUNCTION "membership_weight"
jbe@8 1803 ( "area"."id"%TYPE,
jbe@8 1804 "member"."id"%TYPE )
jbe@8 1805 IS 'Calculates the potential voting weight of a member in a given area';
jbe@8 1806
jbe@5 1807
jbe@4 1808 CREATE VIEW "member_count_view" AS
jbe@5 1809 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
jbe@4 1810
jbe@4 1811 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
jbe@4 1812
jbe@4 1813
jbe@97 1814 CREATE VIEW "unit_member_count" AS
jbe@97 1815 SELECT
jbe@97 1816 "unit"."id" AS "unit_id",
jbe@97 1817 sum("member"."id") AS "member_count"
jbe@97 1818 FROM "unit"
jbe@97 1819 LEFT JOIN "privilege"
jbe@97 1820 ON "privilege"."unit_id" = "unit"."id"
jbe@97 1821 AND "privilege"."voting_right"
jbe@97 1822 LEFT JOIN "member"
jbe@97 1823 ON "member"."id" = "privilege"."member_id"
jbe@97 1824 AND "member"."active"
jbe@97 1825 GROUP BY "unit"."id";
jbe@97 1826
jbe@97 1827 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
jbe@97 1828
jbe@97 1829
jbe@4 1830 CREATE VIEW "area_member_count" AS
jbe@5 1831 SELECT
jbe@5 1832 "area"."id" AS "area_id",
jbe@5 1833 count("member"."id") AS "direct_member_count",
jbe@5 1834 coalesce(
jbe@5 1835 sum(
jbe@5 1836 CASE WHEN "member"."id" NOTNULL THEN
jbe@5 1837 "membership_weight"("area"."id", "member"."id")
jbe@5 1838 ELSE 0 END
jbe@5 1839 )
jbe@5 1840 ) AS "member_weight",
jbe@5 1841 coalesce(
jbe@5 1842 sum(
jbe@5 1843 CASE WHEN "member"."id" NOTNULL AND "membership"."autoreject" THEN
jbe@5 1844 "membership_weight"("area"."id", "member"."id")
jbe@5 1845 ELSE 0 END
jbe@5 1846 )
jbe@5 1847 ) AS "autoreject_weight"
jbe@4 1848 FROM "area"
jbe@4 1849 LEFT JOIN "membership"
jbe@4 1850 ON "area"."id" = "membership"."area_id"
jbe@97 1851 LEFT JOIN "privilege"
jbe@97 1852 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 1853 AND "privilege"."member_id" = "membership"."member_id"
jbe@97 1854 AND "privilege"."voting_right"
jbe@4 1855 LEFT JOIN "member"
jbe@97 1856 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
jbe@4 1857 AND "member"."active"
jbe@4 1858 GROUP BY "area"."id";
jbe@4 1859
jbe@97 1860 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count", "member_weight" and "autoreject_weight" columns of table "area"';
jbe@4 1861
jbe@4 1862
jbe@9 1863 CREATE VIEW "opening_draft" AS
jbe@9 1864 SELECT "draft".* FROM (
jbe@9 1865 SELECT
jbe@9 1866 "initiative"."id" AS "initiative_id",
jbe@9 1867 min("draft"."id") AS "draft_id"
jbe@9 1868 FROM "initiative" JOIN "draft"
jbe@9 1869 ON "initiative"."id" = "draft"."initiative_id"
jbe@9 1870 GROUP BY "initiative"."id"
jbe@9 1871 ) AS "subquery"
jbe@9 1872 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
jbe@9 1873
jbe@9 1874 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
jbe@9 1875
jbe@9 1876
jbe@0 1877 CREATE VIEW "current_draft" AS
jbe@0 1878 SELECT "draft".* FROM (
jbe@0 1879 SELECT
jbe@0 1880 "initiative"."id" AS "initiative_id",
jbe@0 1881 max("draft"."id") AS "draft_id"
jbe@0 1882 FROM "initiative" JOIN "draft"
jbe@0 1883 ON "initiative"."id" = "draft"."initiative_id"
jbe@0 1884 GROUP BY "initiative"."id"
jbe@0 1885 ) AS "subquery"
jbe@0 1886 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
jbe@0 1887
jbe@0 1888 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
jbe@0 1889
jbe@0 1890
jbe@0 1891 CREATE VIEW "critical_opinion" AS
jbe@0 1892 SELECT * FROM "opinion"
jbe@0 1893 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
jbe@0 1894 OR ("degree" = -2 AND "fulfilled" = TRUE);
jbe@0 1895
jbe@0 1896 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
jbe@0 1897
jbe@0 1898
jbe@126 1899 CREATE VIEW "battle_participant" AS
jbe@126 1900 SELECT "initiative"."id", "initiative"."issue_id"
jbe@126 1901 FROM "issue" JOIN "initiative"
jbe@126 1902 ON "issue"."id" = "initiative"."issue_id"
jbe@126 1903 WHERE "initiative"."admitted"
jbe@126 1904 UNION ALL
jbe@126 1905 SELECT NULL, "id" AS "issue_id"
jbe@126 1906 FROM "issue";
jbe@126 1907
jbe@126 1908 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
jbe@126 1909
jbe@126 1910
jbe@61 1911 CREATE VIEW "battle_view" AS
jbe@0 1912 SELECT
jbe@0 1913 "issue"."id" AS "issue_id",
jbe@10 1914 "winning_initiative"."id" AS "winning_initiative_id",
jbe@10 1915 "losing_initiative"."id" AS "losing_initiative_id",
jbe@0 1916 sum(
jbe@0 1917 CASE WHEN
jbe@0 1918 coalesce("better_vote"."grade", 0) >
jbe@0 1919 coalesce("worse_vote"."grade", 0)
jbe@0 1920 THEN "direct_voter"."weight" ELSE 0 END
jbe@0 1921 ) AS "count"
jbe@0 1922 FROM "issue"
jbe@0 1923 LEFT JOIN "direct_voter"
jbe@0 1924 ON "issue"."id" = "direct_voter"."issue_id"
jbe@126 1925 JOIN "battle_participant" AS "winning_initiative"
jbe@10 1926 ON "issue"."id" = "winning_initiative"."issue_id"
jbe@126 1927 JOIN "battle_participant" AS "losing_initiative"
jbe@10 1928 ON "issue"."id" = "losing_initiative"."issue_id"
jbe@0 1929 LEFT JOIN "vote" AS "better_vote"
jbe@10 1930 ON "direct_voter"."member_id" = "better_vote"."member_id"
jbe@10 1931 AND "winning_initiative"."id" = "better_vote"."initiative_id"
jbe@0 1932 LEFT JOIN "vote" AS "worse_vote"
jbe@10 1933 ON "direct_voter"."member_id" = "worse_vote"."member_id"
jbe@10 1934 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
jbe@61 1935 WHERE "issue"."closed" NOTNULL
jbe@61 1936 AND "issue"."cleaned" ISNULL
jbe@126 1937 AND (
jbe@126 1938 "winning_initiative"."id" != "losing_initiative"."id" OR
jbe@126 1939 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
jbe@126 1940 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
jbe@0 1941 GROUP BY
jbe@0 1942 "issue"."id",
jbe@10 1943 "winning_initiative"."id",
jbe@10 1944 "losing_initiative"."id";
jbe@0 1945
jbe@126 1946 COMMENT ON VIEW "battle_view" IS 'Number of members preferring one initiative (or status-quo) to another initiative (or status-quo); Used to fill "battle" table';
jbe@0 1947
jbe@0 1948
jbe@1 1949 CREATE VIEW "expired_session" AS
jbe@1 1950 SELECT * FROM "session" WHERE now() > "expiry";
jbe@1 1951
jbe@1 1952 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
jbe@1 1953 DELETE FROM "session" WHERE "ident" = OLD."ident";
jbe@1 1954
jbe@1 1955 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
jbe@1 1956 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
jbe@1 1957
jbe@1 1958
jbe@0 1959 CREATE VIEW "open_issue" AS
jbe@0 1960 SELECT * FROM "issue" WHERE "closed" ISNULL;
jbe@0 1961
jbe@0 1962 COMMENT ON VIEW "open_issue" IS 'All open issues';
jbe@0 1963
jbe@0 1964
jbe@0 1965 CREATE VIEW "issue_with_ranks_missing" AS
jbe@0 1966 SELECT * FROM "issue"
jbe@3 1967 WHERE "fully_frozen" NOTNULL
jbe@0 1968 AND "closed" NOTNULL
jbe@0 1969 AND "ranks_available" = FALSE;
jbe@0 1970
jbe@0 1971 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
jbe@0 1972
jbe@0 1973
jbe@9 1974 CREATE VIEW "member_contingent" AS
jbe@9 1975 SELECT
jbe@9 1976 "member"."id" AS "member_id",
jbe@9 1977 "contingent"."time_frame",
jbe@9 1978 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
jbe@9 1979 (
jbe@9 1980 SELECT count(1) FROM "draft"
jbe@9 1981 WHERE "draft"."author_id" = "member"."id"
jbe@9 1982 AND "draft"."created" > now() - "contingent"."time_frame"
jbe@9 1983 ) + (
jbe@9 1984 SELECT count(1) FROM "suggestion"
jbe@9 1985 WHERE "suggestion"."author_id" = "member"."id"
jbe@9 1986 AND "suggestion"."created" > now() - "contingent"."time_frame"
jbe@9 1987 )
jbe@9 1988 ELSE NULL END AS "text_entry_count",
jbe@9 1989 "contingent"."text_entry_limit",
jbe@9 1990 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
jbe@9 1991 SELECT count(1) FROM "opening_draft"
jbe@9 1992 WHERE "opening_draft"."author_id" = "member"."id"
jbe@9 1993 AND "opening_draft"."created" > now() - "contingent"."time_frame"
jbe@9 1994 ) ELSE NULL END AS "initiative_count",
jbe@9 1995 "contingent"."initiative_limit"
jbe@9 1996 FROM "member" CROSS JOIN "contingent";
jbe@9 1997
jbe@9 1998 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
jbe@9 1999
jbe@9 2000 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
jbe@9 2001 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
jbe@9 2002
jbe@9 2003
jbe@9 2004 CREATE VIEW "member_contingent_left" AS
jbe@9 2005 SELECT
jbe@9 2006 "member_id",
jbe@9 2007 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
jbe@9 2008 max("initiative_limit" - "initiative_count") AS "initiatives_left"
jbe@9 2009 FROM "member_contingent" GROUP BY "member_id";
jbe@9 2010
jbe@9 2011 COMMENT ON VIEW "member_contingent_left" IS 'Amount of text entries or initiatives which can be posted now instantly by a member. This view should be used by a frontend to determine, if the contingent for posting is exhausted.';
jbe@9 2012
jbe@9 2013
jbe@113 2014 CREATE VIEW "event_seen_by_member" AS
jbe@113 2015 SELECT
jbe@113 2016 "member"."id" AS "seen_by_member_id",
jbe@113 2017 CASE WHEN "event"."state" IN (
jbe@113 2018 'voting',
jbe@113 2019 'finished_without_winner',
jbe@113 2020 'finished_with_winner'
jbe@113 2021 ) THEN
jbe@113 2022 'voting'::"notify_level"
jbe@113 2023 ELSE
jbe@113 2024 CASE WHEN "event"."state" IN (
jbe@113 2025 'verification',
jbe@113 2026 'canceled_after_revocation_during_verification',
jbe@113 2027 'canceled_no_initiative_admitted'
jbe@113 2028 ) THEN
jbe@113 2029 'verification'::"notify_level"
jbe@113 2030 ELSE
jbe@113 2031 CASE WHEN "event"."state" IN (
jbe@113 2032 'discussion',
jbe@113 2033 'canceled_after_revocation_during_discussion'
jbe@113 2034 ) THEN
jbe@113 2035 'discussion'::"notify_level"
jbe@113 2036 ELSE
jbe@113 2037 'all'::"notify_level"
jbe@113 2038 END
jbe@113 2039 END
jbe@113 2040 END AS "notify_level",
jbe@113 2041 "event".*
jbe@113 2042 FROM "member" CROSS JOIN "event"
jbe@113 2043 LEFT JOIN "issue"
jbe@113 2044 ON "event"."issue_id" = "issue"."id"
jbe@113 2045 LEFT JOIN "membership"
jbe@113 2046 ON "member"."id" = "membership"."member_id"
jbe@113 2047 AND "issue"."area_id" = "membership"."area_id"
jbe@113 2048 LEFT JOIN "interest"
jbe@113 2049 ON "member"."id" = "interest"."member_id"
jbe@113 2050 AND "event"."issue_id" = "interest"."issue_id"
jbe@113 2051 LEFT JOIN "supporter"
jbe@113 2052 ON "member"."id" = "supporter"."member_id"
jbe@113 2053 AND "event"."initiative_id" = "supporter"."initiative_id"
jbe@113 2054 LEFT JOIN "ignored_member"
jbe@113 2055 ON "member"."id" = "ignored_member"."member_id"
jbe@113 2056 AND "event"."member_id" = "ignored_member"."other_member_id"
jbe@113 2057 LEFT JOIN "ignored_initiative"
jbe@113 2058 ON "member"."id" = "ignored_initiative"."member_id"
jbe@113 2059 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
jbe@113 2060 WHERE (
jbe@113 2061 "supporter"."member_id" NOTNULL OR
jbe@113 2062 "interest"."member_id" NOTNULL OR
jbe@113 2063 ( "membership"."member_id" NOTNULL AND
jbe@113 2064 "event"."event" IN (
jbe@113 2065 'issue_state_changed',
jbe@113 2066 'initiative_created_in_new_issue',
jbe@113 2067 'initiative_created_in_existing_issue',
jbe@113 2068 'initiative_revoked' ) ) )
jbe@113 2069 AND "ignored_member"."member_id" ISNULL
jbe@113 2070 AND "ignored_initiative"."member_id" ISNULL;
jbe@113 2071
jbe@113 2072 COMMENT ON VIEW "event_seen_by_member" IS 'Events as seen by a member, depending on its memberships, interests and support';
jbe@113 2073
jbe@113 2074
jbe@113 2075 CREATE VIEW "pending_notification" AS
jbe@113 2076 SELECT
jbe@113 2077 "member"."id" AS "seen_by_member_id",
jbe@113 2078 "event".*
jbe@113 2079 FROM "member" CROSS JOIN "event"
jbe@113 2080 LEFT JOIN "issue"
jbe@113 2081 ON "event"."issue_id" = "issue"."id"
jbe@113 2082 LEFT JOIN "membership"
jbe@113 2083 ON "member"."id" = "membership"."member_id"
jbe@113 2084 AND "issue"."area_id" = "membership"."area_id"
jbe@113 2085 LEFT JOIN "interest"
jbe@113 2086 ON "member"."id" = "interest"."member_id"
jbe@113 2087 AND "event"."issue_id" = "interest"."issue_id"
jbe@113 2088 LEFT JOIN "supporter"
jbe@113 2089 ON "member"."id" = "supporter"."member_id"
jbe@113 2090 AND "event"."initiative_id" = "supporter"."initiative_id"
jbe@113 2091 LEFT JOIN "ignored_member"
jbe@113 2092 ON "member"."id" = "ignored_member"."member_id"
jbe@113 2093 AND "event"."member_id" = "ignored_member"."other_member_id"
jbe@113 2094 LEFT JOIN "ignored_initiative"
jbe@113 2095 ON "member"."id" = "ignored_initiative"."member_id"
jbe@113 2096 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
jbe@113 2097 WHERE (
jbe@113 2098 "member"."notify_event_id" ISNULL OR
jbe@113 2099 ( "member"."notify_event_id" NOTNULL AND
jbe@113 2100 "member"."notify_event_id" < "event"."id" ) )
jbe@113 2101 AND (
jbe@113 2102 ( "member"."notify_level" >= 'all' ) OR
jbe@113 2103 ( "member"."notify_level" >= 'voting' AND
jbe@113 2104 "event"."state" IN (
jbe@113 2105 'voting',
jbe@113 2106 'finished_without_winner',
jbe@113 2107 'finished_with_winner' ) ) OR
jbe@113 2108 ( "member"."notify_level" >= 'verification' AND
jbe@113 2109 "event"."state" IN (
jbe@113 2110 'verification',
jbe@113 2111 'canceled_after_revocation_during_verification',
jbe@113 2112 'canceled_no_initiative_admitted' ) ) OR
jbe@113 2113 ( "member"."notify_level" >= 'discussion' AND
jbe@113 2114 "event"."state" IN (
jbe@113 2115 'discussion',
jbe@113 2116 'canceled_after_revocation_during_discussion' ) ) )
jbe@113 2117 AND (
jbe@113 2118 "supporter"."member_id" NOTNULL OR
jbe@113 2119 "interest"."member_id" NOTNULL OR
jbe@113 2120 ( "membership"."member_id" NOTNULL AND
jbe@113 2121 "event"."event" IN (
jbe@113 2122 'issue_state_changed',
jbe@113 2123 'initiative_created_in_new_issue',
jbe@113 2124 'initiative_created_in_existing_issue',
jbe@113 2125 'initiative_revoked' ) ) )
jbe@113 2126 AND "ignored_member"."member_id" ISNULL
jbe@113 2127 AND "ignored_initiative"."member_id" ISNULL;
jbe@113 2128
jbe@113 2129 COMMENT ON VIEW "pending_notification" IS 'Events to be sent to "notify_email" address of member referred to by "seen_by_member_id"';
jbe@113 2130
jbe@113 2131
jbe@16 2132 CREATE TYPE "timeline_event" AS ENUM (
jbe@16 2133 'issue_created',
jbe@16 2134 'issue_canceled',
jbe@16 2135 'issue_accepted',
jbe@16 2136 'issue_half_frozen',
jbe@16 2137 'issue_finished_without_voting',
jbe@16 2138 'issue_voting_started',
jbe@16 2139 'issue_finished_after_voting',
jbe@16 2140 'initiative_created',
jbe@16 2141 'initiative_revoked',
jbe@16 2142 'draft_created',
jbe@16 2143 'suggestion_created');
jbe@16 2144
jbe@112 2145 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
jbe@16 2146
jbe@16 2147
jbe@16 2148 CREATE VIEW "timeline_issue" AS
jbe@16 2149 SELECT
jbe@16 2150 "created" AS "occurrence",
jbe@16 2151 'issue_created'::"timeline_event" AS "event",
jbe@16 2152 "id" AS "issue_id"
jbe@16 2153 FROM "issue"
jbe@16 2154 UNION ALL
jbe@16 2155 SELECT
jbe@16 2156 "closed" AS "occurrence",
jbe@16 2157 'issue_canceled'::"timeline_event" AS "event",
jbe@16 2158 "id" AS "issue_id"
jbe@16 2159 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
jbe@16 2160 UNION ALL
jbe@16 2161 SELECT
jbe@16 2162 "accepted" AS "occurrence",
jbe@16 2163 'issue_accepted'::"timeline_event" AS "event",
jbe@16 2164 "id" AS "issue_id"
jbe@16 2165 FROM "issue" WHERE "accepted" NOTNULL
jbe@16 2166 UNION ALL
jbe@16 2167 SELECT
jbe@16 2168 "half_frozen" AS "occurrence",
jbe@16 2169 'issue_half_frozen'::"timeline_event" AS "event",
jbe@16 2170 "id" AS "issue_id"
jbe@16 2171 FROM "issue" WHERE "half_frozen" NOTNULL
jbe@16 2172 UNION ALL
jbe@16 2173 SELECT
jbe@16 2174 "fully_frozen" AS "occurrence",
jbe@16 2175 'issue_voting_started'::"timeline_event" AS "event",
jbe@16 2176 "id" AS "issue_id"
jbe@16 2177 FROM "issue"
jbe@17 2178 WHERE "fully_frozen" NOTNULL
jbe@17 2179 AND ("closed" ISNULL OR "closed" != "fully_frozen")
jbe@16 2180 UNION ALL
jbe@16 2181 SELECT
jbe@16 2182 "closed" AS "occurrence",
jbe@16 2183 CASE WHEN "fully_frozen" = "closed" THEN
jbe@16 2184 'issue_finished_without_voting'::"timeline_event"
jbe@16 2185 ELSE
jbe@16 2186 'issue_finished_after_voting'::"timeline_event"
jbe@16 2187 END AS "event",
jbe@16 2188 "id" AS "issue_id"
jbe@16 2189 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
jbe@16 2190
jbe@112 2191 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
jbe@16 2192
jbe@16 2193
jbe@16 2194 CREATE VIEW "timeline_initiative" AS
jbe@16 2195 SELECT
jbe@16 2196 "created" AS "occurrence",
jbe@16 2197 'initiative_created'::"timeline_event" AS "event",
jbe@16 2198 "id" AS "initiative_id"
jbe@16 2199 FROM "initiative"
jbe@16 2200 UNION ALL
jbe@16 2201 SELECT
jbe@16 2202 "revoked" AS "occurrence",
jbe@16 2203 'initiative_revoked'::"timeline_event" AS "event",
jbe@16 2204 "id" AS "initiative_id"
jbe@16 2205 FROM "initiative" WHERE "revoked" NOTNULL;
jbe@16 2206
jbe@112 2207 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
jbe@16 2208
jbe@16 2209
jbe@16 2210 CREATE VIEW "timeline_draft" AS
jbe@16 2211 SELECT
jbe@16 2212 "created" AS "occurrence",
jbe@16 2213 'draft_created'::"timeline_event" AS "event",
jbe@16 2214 "id" AS "draft_id"
jbe@16 2215 FROM "draft";
jbe@16 2216
jbe@112 2217 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
jbe@16 2218
jbe@16 2219
jbe@16 2220 CREATE VIEW "timeline_suggestion" AS
jbe@16 2221 SELECT
jbe@16 2222 "created" AS "occurrence",
jbe@16 2223 'suggestion_created'::"timeline_event" AS "event",
jbe@16 2224 "id" AS "suggestion_id"
jbe@16 2225 FROM "suggestion";
jbe@16 2226
jbe@112 2227 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
jbe@16 2228
jbe@16 2229
jbe@16 2230 CREATE VIEW "timeline" AS
jbe@16 2231 SELECT
jbe@16 2232 "occurrence",
jbe@16 2233 "event",
jbe@16 2234 "issue_id",
jbe@16 2235 NULL AS "initiative_id",
jbe@16 2236 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
jbe@16 2237 NULL::INT8 AS "suggestion_id"
jbe@16 2238 FROM "timeline_issue"
jbe@16 2239 UNION ALL
jbe@16 2240 SELECT
jbe@16 2241 "occurrence",
jbe@16 2242 "event",
jbe@16 2243 NULL AS "issue_id",
jbe@16 2244 "initiative_id",
jbe@16 2245 NULL AS "draft_id",
jbe@16 2246 NULL AS "suggestion_id"
jbe@16 2247 FROM "timeline_initiative"
jbe@16 2248 UNION ALL
jbe@16 2249 SELECT
jbe@16 2250 "occurrence",
jbe@16 2251 "event",
jbe@16 2252 NULL AS "issue_id",
jbe@16 2253 NULL AS "initiative_id",
jbe@16 2254 "draft_id",
jbe@16 2255 NULL AS "suggestion_id"
jbe@16 2256 FROM "timeline_draft"
jbe@16 2257 UNION ALL
jbe@16 2258 SELECT
jbe@16 2259 "occurrence",
jbe@16 2260 "event",
jbe@16 2261 NULL AS "issue_id",
jbe@16 2262 NULL AS "initiative_id",
jbe@16 2263 NULL AS "draft_id",
jbe@16 2264 "suggestion_id"
jbe@16 2265 FROM "timeline_suggestion";
jbe@16 2266
jbe@112 2267 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
jbe@16 2268
jbe@16 2269
jbe@0 2270
jbe@5 2271 --------------------------------------------------
jbe@5 2272 -- Set returning function for delegation chains --
jbe@5 2273 --------------------------------------------------
jbe@5 2274
jbe@5 2275
jbe@5 2276 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
jbe@5 2277 ('first', 'intermediate', 'last', 'repetition');
jbe@5 2278
jbe@5 2279 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
jbe@5 2280
jbe@5 2281
jbe@5 2282 CREATE TYPE "delegation_chain_row" AS (
jbe@5 2283 "index" INT4,
jbe@5 2284 "member_id" INT4,
jbe@97 2285 "member_valid" BOOLEAN,
jbe@5 2286 "participation" BOOLEAN,
jbe@5 2287 "overridden" BOOLEAN,
jbe@5 2288 "scope_in" "delegation_scope",
jbe@5 2289 "scope_out" "delegation_scope",
jbe@86 2290 "disabled_out" BOOLEAN,
jbe@5 2291 "loop" "delegation_chain_loop_tag" );
jbe@5 2292
jbe@5 2293 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain"(...) functions';
jbe@5 2294
jbe@5 2295 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
jbe@5 2296 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest, for areas: membership, for global delegation chains: always null';
jbe@5 2297 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
jbe@5 2298 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
jbe@5 2299 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
jbe@86 2300 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
jbe@5 2301 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
jbe@5 2302
jbe@5 2303
jbe@5 2304 CREATE FUNCTION "delegation_chain"
jbe@5 2305 ( "member_id_p" "member"."id"%TYPE,
jbe@97 2306 "unit_id_p" "unit"."id"%TYPE,
jbe@5 2307 "area_id_p" "area"."id"%TYPE,
jbe@5 2308 "issue_id_p" "issue"."id"%TYPE,
jbe@5 2309 "simulate_trustee_id_p" "member"."id"%TYPE )
jbe@5 2310 RETURNS SETOF "delegation_chain_row"
jbe@5 2311 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 2312 DECLARE
jbe@97 2313 "scope_v" "delegation_scope";
jbe@97 2314 "unit_id_v" "unit"."id"%TYPE;
jbe@97 2315 "area_id_v" "area"."id"%TYPE;
jbe@5 2316 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
jbe@5 2317 "loop_member_id_v" "member"."id"%TYPE;
jbe@5 2318 "output_row" "delegation_chain_row";
jbe@5 2319 "output_rows" "delegation_chain_row"[];
jbe@5 2320 "delegation_row" "delegation"%ROWTYPE;
jbe@5 2321 "row_count" INT4;
jbe@5 2322 "i" INT4;
jbe@5 2323 "loop_v" BOOLEAN;
jbe@5 2324 BEGIN
jbe@97 2325 IF
jbe@97 2326 "unit_id_p" NOTNULL AND
jbe@97 2327 "area_id_p" ISNULL AND
jbe@97 2328 "issue_id_p" ISNULL
jbe@97 2329 THEN
jbe@97 2330 "scope_v" := 'unit';
jbe@97 2331 "unit_id_v" := "unit_id_p";
jbe@97 2332 ELSIF
jbe@97 2333 "unit_id_p" ISNULL AND
jbe@97 2334 "area_id_p" NOTNULL AND
jbe@97 2335 "issue_id_p" ISNULL
jbe@97 2336 THEN
jbe@97 2337 "scope_v" := 'area';
jbe@97 2338 "area_id_v" := "area_id_p";
jbe@97 2339 SELECT "unit_id" INTO "unit_id_v"
jbe@97 2340 FROM "area" WHERE "id" = "area_id_v";
jbe@97 2341 ELSIF
jbe@97 2342 "unit_id_p" ISNULL AND
jbe@97 2343 "area_id_p" ISNULL AND
jbe@97 2344 "issue_id_p" NOTNULL
jbe@97 2345 THEN
jbe@97 2346 "scope_v" := 'issue';
jbe@97 2347 SELECT "area_id" INTO "area_id_v"
jbe@97 2348 FROM "issue" WHERE "id" = "issue_id_p";
jbe@97 2349 SELECT "unit_id" INTO "unit_id_v"
jbe@97 2350 FROM "area" WHERE "id" = "area_id_v";
jbe@97 2351 ELSE
jbe@97 2352 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
jbe@97 2353 END IF;
jbe@5 2354 "visited_member_ids" := '{}';
jbe@5 2355 "loop_member_id_v" := NULL;
jbe@5 2356 "output_rows" := '{}';
jbe@5 2357 "output_row"."index" := 0;
jbe@5 2358 "output_row"."member_id" := "member_id_p";
jbe@97 2359 "output_row"."member_valid" := TRUE;
jbe@5 2360 "output_row"."participation" := FALSE;
jbe@5 2361 "output_row"."overridden" := FALSE;
jbe@86 2362 "output_row"."disabled_out" := FALSE;
jbe@5 2363 "output_row"."scope_out" := NULL;
jbe@5 2364 LOOP
jbe@5 2365 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
jbe@5 2366 "loop_member_id_v" := "output_row"."member_id";
jbe@5 2367 ELSE
jbe@5 2368 "visited_member_ids" :=
jbe@5 2369 "visited_member_ids" || "output_row"."member_id";
jbe@5 2370 END IF;
jbe@5 2371 IF "output_row"."participation" THEN
jbe@5 2372 "output_row"."overridden" := TRUE;
jbe@5 2373 END IF;
jbe@5 2374 "output_row"."scope_in" := "output_row"."scope_out";
jbe@5 2375 IF EXISTS (
jbe@97 2376 SELECT NULL FROM "member" JOIN "privilege"
jbe@97 2377 ON "privilege"."member_id" = "member"."id"
jbe@97 2378 AND "privilege"."unit_id" = "unit_id_v"
jbe@97 2379 WHERE "id" = "output_row"."member_id"
jbe@97 2380 AND "member"."active" AND "privilege"."voting_right"
jbe@5 2381 ) THEN
jbe@97 2382 IF "scope_v" = 'unit' THEN
jbe@5 2383 SELECT * INTO "delegation_row" FROM "delegation"
jbe@5 2384 WHERE "truster_id" = "output_row"."member_id"
jbe@97 2385 AND "unit_id" = "unit_id_v";
jbe@97 2386 ELSIF "scope_v" = 'area' THEN
jbe@5 2387 "output_row"."participation" := EXISTS (
jbe@5 2388 SELECT NULL FROM "membership"
jbe@5 2389 WHERE "area_id" = "area_id_p"
jbe@5 2390 AND "member_id" = "output_row"."member_id"
jbe@5 2391 );
jbe@5 2392 SELECT * INTO "delegation_row" FROM "delegation"
jbe@5 2393 WHERE "truster_id" = "output_row"."member_id"
jbe@97 2394 AND (
jbe@97 2395 "unit_id" = "unit_id_v" OR
jbe@97 2396 "area_id" = "area_id_v"
jbe@97 2397 )
jbe@10 2398 ORDER BY "scope" DESC;
jbe@97 2399 ELSIF "scope_v" = 'issue' THEN
jbe@5 2400 "output_row"."participation" := EXISTS (
jbe@5 2401 SELECT NULL FROM "interest"
jbe@5 2402 WHERE "issue_id" = "issue_id_p"
jbe@5 2403 AND "member_id" = "output_row"."member_id"
jbe@5 2404 );
jbe@5 2405 SELECT * INTO "delegation_row" FROM "delegation"
jbe@5 2406 WHERE "truster_id" = "output_row"."member_id"
jbe@97 2407 AND (
jbe@97 2408 "unit_id" = "unit_id_v" OR
jbe@97 2409 "area_id" = "area_id_v" OR
jbe@10 2410 "issue_id" = "issue_id_p"
jbe@10 2411 )
jbe@10 2412 ORDER BY "scope" DESC;
jbe@5 2413 END IF;
jbe@5 2414 ELSE
jbe@97 2415 "output_row"."member_valid" := FALSE;
jbe@5 2416 "output_row"."participation" := FALSE;
jbe@5 2417 "output_row"."scope_out" := NULL;
jbe@5 2418 "delegation_row" := ROW(NULL);
jbe@5 2419 END IF;
jbe@5 2420 IF
jbe@5 2421 "output_row"."member_id" = "member_id_p" AND
jbe@5 2422 "simulate_trustee_id_p" NOTNULL
jbe@5 2423 THEN
jbe@97 2424 "output_row"."scope_out" := "scope_v";
jbe@5 2425 "output_rows" := "output_rows" || "output_row";
jbe@5 2426 "output_row"."member_id" := "simulate_trustee_id_p";
jbe@5 2427 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
jbe@10 2428 "output_row"."scope_out" := "delegation_row"."scope";
jbe@5 2429 "output_rows" := "output_rows" || "output_row";
jbe@5 2430 "output_row"."member_id" := "delegation_row"."trustee_id";
jbe@86 2431 ELSIF "delegation_row"."scope" NOTNULL THEN
jbe@86 2432 "output_row"."scope_out" := "delegation_row"."scope";
jbe@86 2433 "output_row"."disabled_out" := TRUE;
jbe@86 2434 "output_rows" := "output_rows" || "output_row";
jbe@86 2435 EXIT;
jbe@5 2436 ELSE
jbe@5 2437 "output_row"."scope_out" := NULL;
jbe@5 2438 "output_rows" := "output_rows" || "output_row";
jbe@5 2439 EXIT;
jbe@5 2440 END IF;
jbe@5 2441 EXIT WHEN "loop_member_id_v" NOTNULL;
jbe@5 2442 "output_row"."index" := "output_row"."index" + 1;
jbe@5 2443 END LOOP;
jbe@5 2444 "row_count" := array_upper("output_rows", 1);
jbe@5 2445 "i" := 1;
jbe@5 2446 "loop_v" := FALSE;
jbe@5 2447 LOOP
jbe@5 2448 "output_row" := "output_rows"["i"];
jbe@98 2449 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
jbe@5 2450 IF "loop_v" THEN
jbe@5 2451 IF "i" + 1 = "row_count" THEN
jbe@5 2452 "output_row"."loop" := 'last';
jbe@5 2453 ELSIF "i" = "row_count" THEN
jbe@5 2454 "output_row"."loop" := 'repetition';
jbe@5 2455 ELSE
jbe@5 2456 "output_row"."loop" := 'intermediate';
jbe@5 2457 END IF;
jbe@5 2458 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
jbe@5 2459 "output_row"."loop" := 'first';
jbe@5 2460 "loop_v" := TRUE;
jbe@5 2461 END IF;
jbe@97 2462 IF "scope_v" = 'unit' THEN
jbe@5 2463 "output_row"."participation" := NULL;
jbe@5 2464 END IF;
jbe@5 2465 RETURN NEXT "output_row";
jbe@5 2466 "i" := "i" + 1;
jbe@5 2467 END LOOP;
jbe@5 2468 RETURN;
jbe@5 2469 END;
jbe@5 2470 $$;
jbe@5 2471
jbe@5 2472 COMMENT ON FUNCTION "delegation_chain"
jbe@5 2473 ( "member"."id"%TYPE,
jbe@97 2474 "unit"."id"%TYPE,
jbe@5 2475 "area"."id"%TYPE,
jbe@5 2476 "issue"."id"%TYPE,
jbe@5 2477 "member"."id"%TYPE )
jbe@5 2478 IS 'Helper function for frontends to display delegation chains; Not part of internal voting logic';
jbe@5 2479
jbe@97 2480
jbe@5 2481 CREATE FUNCTION "delegation_chain"
jbe@5 2482 ( "member_id_p" "member"."id"%TYPE,
jbe@97 2483 "unit_id_p" "unit"."id"%TYPE,
jbe@5 2484 "area_id_p" "area"."id"%TYPE,
jbe@5 2485 "issue_id_p" "issue"."id"%TYPE )
jbe@5 2486 RETURNS SETOF "delegation_chain_row"
jbe@5 2487 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 2488 DECLARE
jbe@5 2489 "result_row" "delegation_chain_row";
jbe@5 2490 BEGIN
jbe@5 2491 FOR "result_row" IN
jbe@5 2492 SELECT * FROM "delegation_chain"(
jbe@123 2493 "member_id_p", "unit_id_p", "area_id_p", "issue_id_p", NULL
jbe@5 2494 )
jbe@5 2495 LOOP
jbe@5 2496 RETURN NEXT "result_row";
jbe@5 2497 END LOOP;
jbe@5 2498 RETURN;
jbe@5 2499 END;
jbe@5 2500 $$;
jbe@5 2501
jbe@5 2502 COMMENT ON FUNCTION "delegation_chain"
jbe@5 2503 ( "member"."id"%TYPE,
jbe@97 2504 "unit"."id"%TYPE,
jbe@5 2505 "area"."id"%TYPE,
jbe@5 2506 "issue"."id"%TYPE )
jbe@5 2507 IS 'Shortcut for "delegation_chain"(...) function where 4th parameter is null';
jbe@5 2508
jbe@5 2509
jbe@5 2510
jbe@0 2511 ------------------------------
jbe@0 2512 -- Comparison by vote count --
jbe@0 2513 ------------------------------
jbe@0 2514
jbe@0 2515 CREATE FUNCTION "vote_ratio"
jbe@0 2516 ( "positive_votes_p" "initiative"."positive_votes"%TYPE,
jbe@0 2517 "negative_votes_p" "initiative"."negative_votes"%TYPE )
jbe@0 2518 RETURNS FLOAT8
jbe@0 2519 LANGUAGE 'plpgsql' STABLE AS $$
jbe@0 2520 BEGIN
jbe@30 2521 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN
jbe@30 2522 RETURN
jbe@30 2523 "positive_votes_p"::FLOAT8 /
jbe@30 2524 ("positive_votes_p" + "negative_votes_p")::FLOAT8;
jbe@30 2525 ELSIF "positive_votes_p" > 0 THEN
jbe@30 2526 RETURN "positive_votes_p";
jbe@30 2527 ELSIF "negative_votes_p" > 0 THEN
jbe@30 2528 RETURN 1 - "negative_votes_p";
jbe@0 2529 ELSE
jbe@0 2530 RETURN 0.5;
jbe@0 2531 END IF;
jbe@0 2532 END;
jbe@0 2533 $$;
jbe@0 2534
jbe@0 2535 COMMENT ON FUNCTION "vote_ratio"
jbe@0 2536 ( "initiative"."positive_votes"%TYPE,
jbe@0 2537 "initiative"."negative_votes"%TYPE )
jbe@30 2538 IS 'Returns a number, which can be used for comparison of initiatives based on count of approvals and disapprovals. Greater numbers indicate a better result. This function is NOT injective.';
jbe@0 2539
jbe@0 2540
jbe@0 2541
jbe@0 2542 ------------------------------------------------
jbe@0 2543 -- Locking for snapshots and voting procedure --
jbe@0 2544 ------------------------------------------------
jbe@0 2545
jbe@67 2546
jbe@67 2547 CREATE FUNCTION "share_row_lock_issue_trigger"()
jbe@67 2548 RETURNS TRIGGER
jbe@67 2549 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@67 2550 BEGIN
jbe@67 2551 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
jbe@67 2552 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
jbe@67 2553 END IF;
jbe@67 2554 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
jbe@67 2555 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
jbe@67 2556 RETURN NEW;
jbe@67 2557 ELSE
jbe@67 2558 RETURN OLD;
jbe@67 2559 END IF;
jbe@67 2560 END;
jbe@67 2561 $$;
jbe@67 2562
jbe@67 2563 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
jbe@67 2564
jbe@67 2565
jbe@67 2566 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
jbe@67 2567 RETURNS TRIGGER
jbe@0 2568 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2569 BEGIN
jbe@67 2570 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
jbe@67 2571 PERFORM NULL FROM "issue"
jbe@67 2572 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
jbe@67 2573 WHERE "initiative"."id" = OLD."initiative_id"
jbe@67 2574 FOR SHARE OF "issue";
jbe@67 2575 END IF;
jbe@67 2576 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
jbe@67 2577 PERFORM NULL FROM "issue"
jbe@67 2578 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
jbe@67 2579 WHERE "initiative"."id" = NEW."initiative_id"
jbe@67 2580 FOR SHARE OF "issue";
jbe@67 2581 RETURN NEW;
jbe@67 2582 ELSE
jbe@67 2583 RETURN OLD;
jbe@67 2584 END IF;
jbe@67 2585 END;
jbe@67 2586 $$;
jbe@67 2587
jbe@67 2588 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
jbe@67 2589
jbe@67 2590
jbe@67 2591 CREATE TRIGGER "share_row_lock_issue"
jbe@67 2592 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
jbe@67 2593 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2594 "share_row_lock_issue_trigger"();
jbe@67 2595
jbe@67 2596 CREATE TRIGGER "share_row_lock_issue"
jbe@67 2597 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
jbe@67 2598 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2599 "share_row_lock_issue_trigger"();
jbe@67 2600
jbe@67 2601 CREATE TRIGGER "share_row_lock_issue"
jbe@67 2602 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
jbe@67 2603 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2604 "share_row_lock_issue_trigger"();
jbe@67 2605
jbe@67 2606 CREATE TRIGGER "share_row_lock_issue_via_initiative"
jbe@67 2607 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
jbe@67 2608 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2609 "share_row_lock_issue_via_initiative_trigger"();
jbe@67 2610
jbe@67 2611 CREATE TRIGGER "share_row_lock_issue"
jbe@67 2612 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
jbe@67 2613 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2614 "share_row_lock_issue_trigger"();
jbe@67 2615
jbe@67 2616 CREATE TRIGGER "share_row_lock_issue"
jbe@67 2617 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
jbe@67 2618 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2619 "share_row_lock_issue_trigger"();
jbe@67 2620
jbe@67 2621 CREATE TRIGGER "share_row_lock_issue"
jbe@67 2622 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
jbe@67 2623 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2624 "share_row_lock_issue_trigger"();
jbe@67 2625
jbe@67 2626 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
jbe@67 2627 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
jbe@67 2628 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
jbe@67 2629 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
jbe@67 2630 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
jbe@67 2631 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
jbe@67 2632 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
jbe@67 2633
jbe@67 2634
jbe@67 2635 CREATE FUNCTION "lock_issue"
jbe@67 2636 ( "issue_id_p" "issue"."id"%TYPE )
jbe@67 2637 RETURNS VOID
jbe@67 2638 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@67 2639 BEGIN
jbe@67 2640 LOCK TABLE "member" IN SHARE MODE;
jbe@97 2641 LOCK TABLE "privilege" IN SHARE MODE;
jbe@67 2642 LOCK TABLE "membership" IN SHARE MODE;
jbe@67 2643 LOCK TABLE "policy" IN SHARE MODE;
jbe@67 2644 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
jbe@67 2645 -- NOTE: The row-level exclusive lock in combination with the
jbe@67 2646 -- share_row_lock_issue(_via_initiative)_trigger functions (which
jbe@67 2647 -- acquire a row-level share lock on the issue) ensure that no data
jbe@67 2648 -- is changed, which could affect calculation of snapshots or
jbe@67 2649 -- counting of votes. Table "delegation" must be table-level-locked,
jbe@67 2650 -- as it also contains issue- and global-scope delegations.
jbe@67 2651 LOCK TABLE "delegation" IN SHARE MODE;
jbe@0 2652 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
jbe@0 2653 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
jbe@0 2654 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
jbe@0 2655 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
jbe@0 2656 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
jbe@0 2657 RETURN;
jbe@0 2658 END;
jbe@0 2659 $$;
jbe@0 2660
jbe@67 2661 COMMENT ON FUNCTION "lock_issue"
jbe@67 2662 ( "issue"."id"%TYPE )
jbe@67 2663 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
jbe@0 2664
jbe@0 2665
jbe@0 2666
jbe@103 2667 ------------------------------------------------------------------------
jbe@103 2668 -- Regular tasks, except calculcation of snapshots and voting results --
jbe@103 2669 ------------------------------------------------------------------------
jbe@103 2670
jbe@104 2671 CREATE FUNCTION "check_last_login"()
jbe@103 2672 RETURNS VOID
jbe@103 2673 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@104 2674 DECLARE
jbe@104 2675 "system_setting_row" "system_setting"%ROWTYPE;
jbe@103 2676 BEGIN
jbe@104 2677 SELECT * INTO "system_setting_row" FROM "system_setting";
jbe@103 2678 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
jbe@103 2679 UPDATE "member" SET "last_login_public" = "last_login"::date
jbe@105 2680 FROM (
jbe@105 2681 SELECT DISTINCT "member"."id"
jbe@105 2682 FROM "member" LEFT JOIN "member_history"
jbe@105 2683 ON "member"."id" = "member_history"."member_id"
jbe@105 2684 WHERE "member"."last_login"::date < 'today' OR (
jbe@105 2685 "member_history"."until"::date >= 'today' AND
jbe@105 2686 "member_history"."active" = FALSE AND "member"."active" = TRUE
jbe@105 2687 )
jbe@105 2688 ) AS "subquery"
jbe@105 2689 WHERE "member"."id" = "subquery"."id";
jbe@104 2690 IF "system_setting_row"."member_ttl" NOTNULL THEN
jbe@104 2691 UPDATE "member" SET "active" = FALSE
jbe@104 2692 WHERE "active" = TRUE
jbe@106 2693 AND "last_login"::date < 'today'
jbe@104 2694 AND "last_login_public" <
jbe@104 2695 (now() - "system_setting_row"."member_ttl")::date;
jbe@104 2696 END IF;
jbe@103 2697 RETURN;
jbe@103 2698 END;
jbe@103 2699 $$;
jbe@103 2700
jbe@105 2701 COMMENT ON FUNCTION "check_last_login"() IS 'Updates "last_login_public" field, which contains the date but not the time of the last login, and deactivates members who do not login for the time specified in "system_setting"."member_ttl". For privacy reasons this function does not update "last_login_public", if the last login of a member has been today (except when member was reactivated today).';
jbe@103 2702
jbe@4 2703
jbe@4 2704 CREATE FUNCTION "calculate_member_counts"()
jbe@4 2705 RETURNS VOID
jbe@4 2706 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@4 2707 BEGIN
jbe@67 2708 LOCK TABLE "member" IN SHARE MODE;
jbe@67 2709 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
jbe@97 2710 LOCK TABLE "unit" IN EXCLUSIVE MODE;
jbe@67 2711 LOCK TABLE "area" IN EXCLUSIVE MODE;
jbe@97 2712 LOCK TABLE "privilege" IN SHARE MODE;
jbe@67 2713 LOCK TABLE "membership" IN SHARE MODE;
jbe@4 2714 DELETE FROM "member_count";
jbe@5 2715 INSERT INTO "member_count" ("total_count")
jbe@5 2716 SELECT "total_count" FROM "member_count_view";
jbe@97 2717 UPDATE "unit" SET "member_count" = "view"."member_count"
jbe@97 2718 FROM "unit_member_count" AS "view"
jbe@97 2719 WHERE "view"."unit_id" = "unit"."id";
jbe@5 2720 UPDATE "area" SET
jbe@5 2721 "direct_member_count" = "view"."direct_member_count",
jbe@5 2722 "member_weight" = "view"."member_weight",
jbe@5 2723 "autoreject_weight" = "view"."autoreject_weight"
jbe@5 2724 FROM "area_member_count" AS "view"
jbe@5 2725 WHERE "view"."area_id" = "area"."id";
jbe@4 2726 RETURN;
jbe@4 2727 END;
jbe@4 2728 $$;
jbe@4 2729
jbe@4 2730 COMMENT ON FUNCTION "calculate_member_counts"() IS 'Updates "member_count" table and "member_count" column of table "area" by materializing data from views "member_count_view" and "area_member_count"';
jbe@4 2731
jbe@4 2732
jbe@4 2733
jbe@0 2734 ------------------------------
jbe@0 2735 -- Calculation of snapshots --
jbe@0 2736 ------------------------------
jbe@0 2737
jbe@0 2738 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
jbe@0 2739 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 2740 "member_id_p" "member"."id"%TYPE,
jbe@0 2741 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
jbe@0 2742 RETURNS "direct_population_snapshot"."weight"%TYPE
jbe@0 2743 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2744 DECLARE
jbe@0 2745 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 2746 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
jbe@0 2747 "weight_v" INT4;
jbe@8 2748 "sub_weight_v" INT4;
jbe@0 2749 BEGIN
jbe@0 2750 "weight_v" := 0;
jbe@0 2751 FOR "issue_delegation_row" IN
jbe@0 2752 SELECT * FROM "issue_delegation"
jbe@0 2753 WHERE "trustee_id" = "member_id_p"
jbe@0 2754 AND "issue_id" = "issue_id_p"
jbe@0 2755 LOOP
jbe@0 2756 IF NOT EXISTS (
jbe@0 2757 SELECT NULL FROM "direct_population_snapshot"
jbe@0 2758 WHERE "issue_id" = "issue_id_p"
jbe@0 2759 AND "event" = 'periodic'
jbe@0 2760 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 2761 ) AND NOT EXISTS (
jbe@0 2762 SELECT NULL FROM "delegating_population_snapshot"
jbe@0 2763 WHERE "issue_id" = "issue_id_p"
jbe@0 2764 AND "event" = 'periodic'
jbe@0 2765 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 2766 ) THEN
jbe@0 2767 "delegate_member_ids_v" :=
jbe@0 2768 "member_id_p" || "delegate_member_ids_p";
jbe@10 2769 INSERT INTO "delegating_population_snapshot" (
jbe@10 2770 "issue_id",
jbe@10 2771 "event",
jbe@10 2772 "member_id",
jbe@10 2773 "scope",
jbe@10 2774 "delegate_member_ids"
jbe@10 2775 ) VALUES (
jbe@0 2776 "issue_id_p",
jbe@0 2777 'periodic',
jbe@0 2778 "issue_delegation_row"."truster_id",
jbe@10 2779 "issue_delegation_row"."scope",
jbe@0 2780 "delegate_member_ids_v"
jbe@0 2781 );
jbe@8 2782 "sub_weight_v" := 1 +
jbe@0 2783 "weight_of_added_delegations_for_population_snapshot"(
jbe@0 2784 "issue_id_p",
jbe@0 2785 "issue_delegation_row"."truster_id",
jbe@0 2786 "delegate_member_ids_v"
jbe@0 2787 );
jbe@8 2788 UPDATE "delegating_population_snapshot"
jbe@8 2789 SET "weight" = "sub_weight_v"
jbe@8 2790 WHERE "issue_id" = "issue_id_p"
jbe@8 2791 AND "event" = 'periodic'
jbe@8 2792 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 2793 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 2794 END IF;
jbe@0 2795 END LOOP;
jbe@0 2796 RETURN "weight_v";
jbe@0 2797 END;
jbe@0 2798 $$;
jbe@0 2799
jbe@0 2800 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
jbe@0 2801 ( "issue"."id"%TYPE,
jbe@0 2802 "member"."id"%TYPE,
jbe@0 2803 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
jbe@0 2804 IS 'Helper function for "create_population_snapshot" function';
jbe@0 2805
jbe@0 2806
jbe@0 2807 CREATE FUNCTION "create_population_snapshot"
jbe@0 2808 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 2809 RETURNS VOID
jbe@0 2810 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2811 DECLARE
jbe@0 2812 "member_id_v" "member"."id"%TYPE;
jbe@0 2813 BEGIN
jbe@0 2814 DELETE FROM "direct_population_snapshot"
jbe@0 2815 WHERE "issue_id" = "issue_id_p"
jbe@0 2816 AND "event" = 'periodic';
jbe@0 2817 DELETE FROM "delegating_population_snapshot"
jbe@0 2818 WHERE "issue_id" = "issue_id_p"
jbe@0 2819 AND "event" = 'periodic';
jbe@0 2820 INSERT INTO "direct_population_snapshot"
jbe@54 2821 ("issue_id", "event", "member_id")
jbe@54 2822 SELECT
jbe@54 2823 "issue_id_p" AS "issue_id",
jbe@54 2824 'periodic'::"snapshot_event" AS "event",
jbe@54 2825 "member"."id" AS "member_id"
jbe@54 2826 FROM "issue"
jbe@54 2827 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@54 2828 JOIN "membership" ON "area"."id" = "membership"."area_id"
jbe@54 2829 JOIN "member" ON "membership"."member_id" = "member"."id"
jbe@97 2830 JOIN "privilege"
jbe@97 2831 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 2832 AND "privilege"."member_id" = "member"."id"
jbe@54 2833 WHERE "issue"."id" = "issue_id_p"
jbe@97 2834 AND "member"."active" AND "privilege"."voting_right"
jbe@54 2835 UNION
jbe@54 2836 SELECT
jbe@54 2837 "issue_id_p" AS "issue_id",
jbe@54 2838 'periodic'::"snapshot_event" AS "event",
jbe@54 2839 "member"."id" AS "member_id"
jbe@97 2840 FROM "issue"
jbe@97 2841 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@97 2842 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
jbe@97 2843 JOIN "member" ON "interest"."member_id" = "member"."id"
jbe@97 2844 JOIN "privilege"
jbe@97 2845 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 2846 AND "privilege"."member_id" = "member"."id"
jbe@97 2847 WHERE "issue"."id" = "issue_id_p"
jbe@97 2848 AND "member"."active" AND "privilege"."voting_right";
jbe@0 2849 FOR "member_id_v" IN
jbe@0 2850 SELECT "member_id" FROM "direct_population_snapshot"
jbe@0 2851 WHERE "issue_id" = "issue_id_p"
jbe@0 2852 AND "event" = 'periodic'
jbe@0 2853 LOOP
jbe@0 2854 UPDATE "direct_population_snapshot" SET
jbe@0 2855 "weight" = 1 +
jbe@0 2856 "weight_of_added_delegations_for_population_snapshot"(
jbe@0 2857 "issue_id_p",
jbe@0 2858 "member_id_v",
jbe@0 2859 '{}'
jbe@0 2860 )
jbe@0 2861 WHERE "issue_id" = "issue_id_p"
jbe@0 2862 AND "event" = 'periodic'
jbe@0 2863 AND "member_id" = "member_id_v";
jbe@0 2864 END LOOP;
jbe@0 2865 RETURN;
jbe@0 2866 END;
jbe@0 2867 $$;
jbe@0 2868
jbe@0 2869 COMMENT ON FUNCTION "create_population_snapshot"
jbe@67 2870 ( "issue"."id"%TYPE )
jbe@0 2871 IS 'This function creates a new ''periodic'' population snapshot for the given issue. It does neither lock any tables, nor updates precalculated values in other tables.';
jbe@0 2872
jbe@0 2873
jbe@0 2874 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
jbe@0 2875 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 2876 "member_id_p" "member"."id"%TYPE,
jbe@0 2877 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@0 2878 RETURNS "direct_interest_snapshot"."weight"%TYPE
jbe@0 2879 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2880 DECLARE
jbe@0 2881 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 2882 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
jbe@0 2883 "weight_v" INT4;
jbe@8 2884 "sub_weight_v" INT4;
jbe@0 2885 BEGIN
jbe@0 2886 "weight_v" := 0;
jbe@0 2887 FOR "issue_delegation_row" IN
jbe@0 2888 SELECT * FROM "issue_delegation"
jbe@0 2889 WHERE "trustee_id" = "member_id_p"
jbe@0 2890 AND "issue_id" = "issue_id_p"
jbe@0 2891 LOOP
jbe@0 2892 IF NOT EXISTS (
jbe@0 2893 SELECT NULL FROM "direct_interest_snapshot"
jbe@0 2894 WHERE "issue_id" = "issue_id_p"
jbe@0 2895 AND "event" = 'periodic'
jbe@0 2896 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 2897 ) AND NOT EXISTS (
jbe@0 2898 SELECT NULL FROM "delegating_interest_snapshot"
jbe@0 2899 WHERE "issue_id" = "issue_id_p"
jbe@0 2900 AND "event" = 'periodic'
jbe@0 2901 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 2902 ) THEN
jbe@0 2903 "delegate_member_ids_v" :=
jbe@0 2904 "member_id_p" || "delegate_member_ids_p";
jbe@10 2905 INSERT INTO "delegating_interest_snapshot" (
jbe@10 2906 "issue_id",
jbe@10 2907 "event",
jbe@10 2908 "member_id",
jbe@10 2909 "scope",
jbe@10 2910 "delegate_member_ids"
jbe@10 2911 ) VALUES (
jbe@0 2912 "issue_id_p",
jbe@0 2913 'periodic',
jbe@0 2914 "issue_delegation_row"."truster_id",
jbe@10 2915 "issue_delegation_row"."scope",
jbe@0 2916 "delegate_member_ids_v"
jbe@0 2917 );
jbe@8 2918 "sub_weight_v" := 1 +
jbe@0 2919 "weight_of_added_delegations_for_interest_snapshot"(
jbe@0 2920 "issue_id_p",
jbe@0 2921 "issue_delegation_row"."truster_id",
jbe@0 2922 "delegate_member_ids_v"
jbe@0 2923 );
jbe@8 2924 UPDATE "delegating_interest_snapshot"
jbe@8 2925 SET "weight" = "sub_weight_v"
jbe@8 2926 WHERE "issue_id" = "issue_id_p"
jbe@8 2927 AND "event" = 'periodic'
jbe@8 2928 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 2929 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 2930 END IF;
jbe@0 2931 END LOOP;
jbe@0 2932 RETURN "weight_v";
jbe@0 2933 END;
jbe@0 2934 $$;
jbe@0 2935
jbe@0 2936 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
jbe@0 2937 ( "issue"."id"%TYPE,
jbe@0 2938 "member"."id"%TYPE,
jbe@0 2939 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@0 2940 IS 'Helper function for "create_interest_snapshot" function';
jbe@0 2941
jbe@0 2942
jbe@0 2943 CREATE FUNCTION "create_interest_snapshot"
jbe@0 2944 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 2945 RETURNS VOID
jbe@0 2946 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2947 DECLARE
jbe@0 2948 "member_id_v" "member"."id"%TYPE;
jbe@0 2949 BEGIN
jbe@0 2950 DELETE FROM "direct_interest_snapshot"
jbe@0 2951 WHERE "issue_id" = "issue_id_p"
jbe@0 2952 AND "event" = 'periodic';
jbe@0 2953 DELETE FROM "delegating_interest_snapshot"
jbe@0 2954 WHERE "issue_id" = "issue_id_p"
jbe@0 2955 AND "event" = 'periodic';
jbe@0 2956 DELETE FROM "direct_supporter_snapshot"
jbe@0 2957 WHERE "issue_id" = "issue_id_p"
jbe@0 2958 AND "event" = 'periodic';
jbe@0 2959 INSERT INTO "direct_interest_snapshot"
jbe@0 2960 ("issue_id", "event", "member_id", "voting_requested")
jbe@0 2961 SELECT
jbe@0 2962 "issue_id_p" AS "issue_id",
jbe@0 2963 'periodic' AS "event",
jbe@0 2964 "member"."id" AS "member_id",
jbe@0 2965 "interest"."voting_requested"
jbe@97 2966 FROM "issue"
jbe@97 2967 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@97 2968 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
jbe@97 2969 JOIN "member" ON "interest"."member_id" = "member"."id"
jbe@97 2970 JOIN "privilege"
jbe@97 2971 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 2972 AND "privilege"."member_id" = "member"."id"
jbe@97 2973 WHERE "issue"."id" = "issue_id_p"
jbe@97 2974 AND "member"."active" AND "privilege"."voting_right";
jbe@0 2975 FOR "member_id_v" IN
jbe@0 2976 SELECT "member_id" FROM "direct_interest_snapshot"
jbe@0 2977 WHERE "issue_id" = "issue_id_p"
jbe@0 2978 AND "event" = 'periodic'
jbe@0 2979 LOOP
jbe@0 2980 UPDATE "direct_interest_snapshot" SET
jbe@0 2981 "weight" = 1 +
jbe@0 2982 "weight_of_added_delegations_for_interest_snapshot"(
jbe@0 2983 "issue_id_p",
jbe@0 2984 "member_id_v",
jbe@0 2985 '{}'
jbe@0 2986 )
jbe@0 2987 WHERE "issue_id" = "issue_id_p"
jbe@0 2988 AND "event" = 'periodic'
jbe@0 2989 AND "member_id" = "member_id_v";
jbe@0 2990 END LOOP;
jbe@0 2991 INSERT INTO "direct_supporter_snapshot"
jbe@0 2992 ( "issue_id", "initiative_id", "event", "member_id",
jbe@0 2993 "informed", "satisfied" )
jbe@0 2994 SELECT
jbe@96 2995 "issue_id_p" AS "issue_id",
jbe@96 2996 "initiative"."id" AS "initiative_id",
jbe@96 2997 'periodic' AS "event",
jbe@96 2998 "supporter"."member_id" AS "member_id",
jbe@0 2999 "supporter"."draft_id" = "current_draft"."id" AS "informed",
jbe@0 3000 NOT EXISTS (
jbe@0 3001 SELECT NULL FROM "critical_opinion"
jbe@0 3002 WHERE "initiative_id" = "initiative"."id"
jbe@96 3003 AND "member_id" = "supporter"."member_id"
jbe@0 3004 ) AS "satisfied"
jbe@96 3005 FROM "initiative"
jbe@96 3006 JOIN "supporter"
jbe@0 3007 ON "supporter"."initiative_id" = "initiative"."id"
jbe@0 3008 JOIN "current_draft"
jbe@0 3009 ON "initiative"."id" = "current_draft"."initiative_id"
jbe@0 3010 JOIN "direct_interest_snapshot"
jbe@96 3011 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
jbe@0 3012 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
jbe@3 3013 AND "event" = 'periodic'
jbe@96 3014 WHERE "initiative"."issue_id" = "issue_id_p";
jbe@0 3015 RETURN;
jbe@0 3016 END;
jbe@0 3017 $$;
jbe@0 3018
jbe@0 3019 COMMENT ON FUNCTION "create_interest_snapshot"
jbe@0 3020 ( "issue"."id"%TYPE )
jbe@0 3021 IS 'This function creates a new ''periodic'' interest/supporter snapshot for the given issue. It does neither lock any tables, nor updates precalculated values in other tables.';
jbe@0 3022
jbe@0 3023
jbe@0 3024 CREATE FUNCTION "create_snapshot"
jbe@0 3025 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3026 RETURNS VOID
jbe@0 3027 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3028 DECLARE
jbe@0 3029 "initiative_id_v" "initiative"."id"%TYPE;
jbe@0 3030 "suggestion_id_v" "suggestion"."id"%TYPE;
jbe@0 3031 BEGIN
jbe@67 3032 PERFORM "lock_issue"("issue_id_p");
jbe@0 3033 PERFORM "create_population_snapshot"("issue_id_p");
jbe@0 3034 PERFORM "create_interest_snapshot"("issue_id_p");
jbe@0 3035 UPDATE "issue" SET
jbe@8 3036 "snapshot" = now(),
jbe@8 3037 "latest_snapshot_event" = 'periodic',
jbe@0 3038 "population" = (
jbe@0 3039 SELECT coalesce(sum("weight"), 0)
jbe@0 3040 FROM "direct_population_snapshot"
jbe@0 3041 WHERE "issue_id" = "issue_id_p"
jbe@0 3042 AND "event" = 'periodic'
jbe@0 3043 ),
jbe@8 3044 "vote_now" = (
jbe@0 3045 SELECT coalesce(sum("weight"), 0)
jbe@0 3046 FROM "direct_interest_snapshot"
jbe@0 3047 WHERE "issue_id" = "issue_id_p"
jbe@0 3048 AND "event" = 'periodic'
jbe@0 3049 AND "voting_requested" = TRUE
jbe@0 3050 ),
jbe@0 3051 "vote_later" = (
jbe@0 3052 SELECT coalesce(sum("weight"), 0)
jbe@0 3053 FROM "direct_interest_snapshot"
jbe@0 3054 WHERE "issue_id" = "issue_id_p"
jbe@0 3055 AND "event" = 'periodic'
jbe@0 3056 AND "voting_requested" = FALSE
jbe@0 3057 )
jbe@0 3058 WHERE "id" = "issue_id_p";
jbe@0 3059 FOR "initiative_id_v" IN
jbe@0 3060 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
jbe@0 3061 LOOP
jbe@0 3062 UPDATE "initiative" SET
jbe@0 3063 "supporter_count" = (
jbe@0 3064 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3065 FROM "direct_interest_snapshot" AS "di"
jbe@0 3066 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3067 ON "di"."member_id" = "ds"."member_id"
jbe@0 3068 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3069 AND "di"."event" = 'periodic'
jbe@0 3070 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3071 AND "ds"."event" = 'periodic'
jbe@0 3072 ),
jbe@0 3073 "informed_supporter_count" = (
jbe@0 3074 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3075 FROM "direct_interest_snapshot" AS "di"
jbe@0 3076 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3077 ON "di"."member_id" = "ds"."member_id"
jbe@0 3078 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3079 AND "di"."event" = 'periodic'
jbe@0 3080 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3081 AND "ds"."event" = 'periodic'
jbe@0 3082 AND "ds"."informed"
jbe@0 3083 ),
jbe@0 3084 "satisfied_supporter_count" = (
jbe@0 3085 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3086 FROM "direct_interest_snapshot" AS "di"
jbe@0 3087 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3088 ON "di"."member_id" = "ds"."member_id"
jbe@0 3089 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3090 AND "di"."event" = 'periodic'
jbe@0 3091 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3092 AND "ds"."event" = 'periodic'
jbe@0 3093 AND "ds"."satisfied"
jbe@0 3094 ),
jbe@0 3095 "satisfied_informed_supporter_count" = (
jbe@0 3096 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3097 FROM "direct_interest_snapshot" AS "di"
jbe@0 3098 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3099 ON "di"."member_id" = "ds"."member_id"
jbe@0 3100 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3101 AND "di"."event" = 'periodic'
jbe@0 3102 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3103 AND "ds"."event" = 'periodic'
jbe@0 3104 AND "ds"."informed"
jbe@0 3105 AND "ds"."satisfied"
jbe@0 3106 )
jbe@0 3107 WHERE "id" = "initiative_id_v";
jbe@0 3108 FOR "suggestion_id_v" IN
jbe@0 3109 SELECT "id" FROM "suggestion"
jbe@0 3110 WHERE "initiative_id" = "initiative_id_v"
jbe@0 3111 LOOP
jbe@0 3112 UPDATE "suggestion" SET
jbe@0 3113 "minus2_unfulfilled_count" = (
jbe@0 3114 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3115 FROM "issue" CROSS JOIN "opinion"
jbe@36 3116 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3117 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3118 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3119 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3120 WHERE "issue"."id" = "issue_id_p"
jbe@36 3121 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3122 AND "opinion"."degree" = -2
jbe@0 3123 AND "opinion"."fulfilled" = FALSE
jbe@0 3124 ),
jbe@0 3125 "minus2_fulfilled_count" = (
jbe@0 3126 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3127 FROM "issue" CROSS JOIN "opinion"
jbe@36 3128 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3129 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3130 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3131 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3132 WHERE "issue"."id" = "issue_id_p"
jbe@36 3133 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3134 AND "opinion"."degree" = -2
jbe@0 3135 AND "opinion"."fulfilled" = TRUE
jbe@0 3136 ),
jbe@0 3137 "minus1_unfulfilled_count" = (
jbe@0 3138 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3139 FROM "issue" CROSS JOIN "opinion"
jbe@36 3140 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3141 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3142 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3143 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3144 WHERE "issue"."id" = "issue_id_p"
jbe@36 3145 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3146 AND "opinion"."degree" = -1
jbe@0 3147 AND "opinion"."fulfilled" = FALSE
jbe@0 3148 ),
jbe@0 3149 "minus1_fulfilled_count" = (
jbe@0 3150 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3151 FROM "issue" CROSS JOIN "opinion"
jbe@36 3152 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3153 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3154 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3155 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3156 WHERE "issue"."id" = "issue_id_p"
jbe@36 3157 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3158 AND "opinion"."degree" = -1
jbe@0 3159 AND "opinion"."fulfilled" = TRUE
jbe@0 3160 ),
jbe@0 3161 "plus1_unfulfilled_count" = (
jbe@0 3162 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3163 FROM "issue" CROSS JOIN "opinion"
jbe@36 3164 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3165 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3166 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3167 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3168 WHERE "issue"."id" = "issue_id_p"
jbe@36 3169 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3170 AND "opinion"."degree" = 1
jbe@0 3171 AND "opinion"."fulfilled" = FALSE
jbe@0 3172 ),
jbe@0 3173 "plus1_fulfilled_count" = (
jbe@0 3174 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3175 FROM "issue" CROSS JOIN "opinion"
jbe@36 3176 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3177 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3178 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3179 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3180 WHERE "issue"."id" = "issue_id_p"
jbe@36 3181 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3182 AND "opinion"."degree" = 1
jbe@0 3183 AND "opinion"."fulfilled" = TRUE
jbe@0 3184 ),
jbe@0 3185 "plus2_unfulfilled_count" = (
jbe@0 3186 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3187 FROM "issue" CROSS JOIN "opinion"
jbe@36 3188 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3189 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3190 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3191 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3192 WHERE "issue"."id" = "issue_id_p"
jbe@36 3193 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3194 AND "opinion"."degree" = 2
jbe@0 3195 AND "opinion"."fulfilled" = FALSE
jbe@0 3196 ),
jbe@0 3197 "plus2_fulfilled_count" = (
jbe@0 3198 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3199 FROM "issue" CROSS JOIN "opinion"
jbe@36 3200 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3201 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3202 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3203 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3204 WHERE "issue"."id" = "issue_id_p"
jbe@36 3205 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3206 AND "opinion"."degree" = 2
jbe@0 3207 AND "opinion"."fulfilled" = TRUE
jbe@0 3208 )
jbe@0 3209 WHERE "suggestion"."id" = "suggestion_id_v";
jbe@0 3210 END LOOP;
jbe@0 3211 END LOOP;
jbe@0 3212 RETURN;
jbe@0 3213 END;
jbe@0 3214 $$;
jbe@0 3215
jbe@0 3216 COMMENT ON FUNCTION "create_snapshot"
jbe@0 3217 ( "issue"."id"%TYPE )
jbe@0 3218 IS 'This function creates a complete new ''periodic'' snapshot of population, interest and support for the given issue. All involved tables are locked, and after completion precalculated values in the source tables are updated.';
jbe@0 3219
jbe@0 3220
jbe@0 3221 CREATE FUNCTION "set_snapshot_event"
jbe@0 3222 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 3223 "event_p" "snapshot_event" )
jbe@0 3224 RETURNS VOID
jbe@0 3225 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@21 3226 DECLARE
jbe@21 3227 "event_v" "issue"."latest_snapshot_event"%TYPE;
jbe@0 3228 BEGIN
jbe@21 3229 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
jbe@21 3230 WHERE "id" = "issue_id_p" FOR UPDATE;
jbe@8 3231 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
jbe@8 3232 WHERE "id" = "issue_id_p";
jbe@3 3233 UPDATE "direct_population_snapshot" SET "event" = "event_p"
jbe@21 3234 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 3235 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
jbe@21 3236 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 3237 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
jbe@21 3238 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 3239 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
jbe@21 3240 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 3241 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
jbe@21 3242 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@0 3243 RETURN;
jbe@0 3244 END;
jbe@0 3245 $$;
jbe@0 3246
jbe@0 3247 COMMENT ON FUNCTION "set_snapshot_event"
jbe@0 3248 ( "issue"."id"%TYPE,
jbe@0 3249 "snapshot_event" )
jbe@0 3250 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
jbe@0 3251
jbe@0 3252
jbe@0 3253
jbe@0 3254 ---------------------
jbe@0 3255 -- Freezing issues --
jbe@0 3256 ---------------------
jbe@0 3257
jbe@0 3258 CREATE FUNCTION "freeze_after_snapshot"
jbe@0 3259 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3260 RETURNS VOID
jbe@0 3261 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3262 DECLARE
jbe@0 3263 "issue_row" "issue"%ROWTYPE;
jbe@0 3264 "policy_row" "policy"%ROWTYPE;
jbe@0 3265 "initiative_row" "initiative"%ROWTYPE;
jbe@0 3266 BEGIN
jbe@0 3267 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@0 3268 SELECT * INTO "policy_row"
jbe@0 3269 FROM "policy" WHERE "id" = "issue_row"."policy_id";
jbe@21 3270 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
jbe@0 3271 FOR "initiative_row" IN
jbe@15 3272 SELECT * FROM "initiative"
jbe@15 3273 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@0 3274 LOOP
jbe@0 3275 IF
jbe@0 3276 "initiative_row"."satisfied_supporter_count" > 0 AND
jbe@0 3277 "initiative_row"."satisfied_supporter_count" *
jbe@0 3278 "policy_row"."initiative_quorum_den" >=
jbe@0 3279 "issue_row"."population" * "policy_row"."initiative_quorum_num"
jbe@0 3280 THEN
jbe@0 3281 UPDATE "initiative" SET "admitted" = TRUE
jbe@0 3282 WHERE "id" = "initiative_row"."id";
jbe@0 3283 ELSE
jbe@0 3284 UPDATE "initiative" SET "admitted" = FALSE
jbe@0 3285 WHERE "id" = "initiative_row"."id";
jbe@0 3286 END IF;
jbe@0 3287 END LOOP;
jbe@113 3288 IF EXISTS (
jbe@9 3289 SELECT NULL FROM "initiative"
jbe@9 3290 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
jbe@9 3291 ) THEN
jbe@113 3292 UPDATE "issue" SET
jbe@113 3293 "state" = 'voting',
jbe@113 3294 "accepted" = coalesce("accepted", now()),
jbe@113 3295 "half_frozen" = coalesce("half_frozen", now()),
jbe@113 3296 "fully_frozen" = now()
jbe@113 3297 WHERE "id" = "issue_id_p";
jbe@113 3298 ELSE
jbe@113 3299 UPDATE "issue" SET
jbe@121 3300 "state" = 'canceled_no_initiative_admitted',
jbe@121 3301 "accepted" = coalesce("accepted", now()),
jbe@121 3302 "half_frozen" = coalesce("half_frozen", now()),
jbe@121 3303 "fully_frozen" = now(),
jbe@121 3304 "closed" = now(),
jbe@121 3305 "ranks_available" = TRUE
jbe@113 3306 WHERE "id" = "issue_id_p";
jbe@113 3307 -- NOTE: The following DELETE statements have effect only when
jbe@113 3308 -- issue state has been manipulated
jbe@113 3309 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
jbe@113 3310 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
jbe@113 3311 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@9 3312 END IF;
jbe@0 3313 RETURN;
jbe@0 3314 END;
jbe@0 3315 $$;
jbe@0 3316
jbe@0 3317 COMMENT ON FUNCTION "freeze_after_snapshot"
jbe@0 3318 ( "issue"."id"%TYPE )
jbe@9 3319 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
jbe@0 3320
jbe@0 3321
jbe@0 3322 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
jbe@0 3323 RETURNS VOID
jbe@0 3324 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3325 DECLARE
jbe@0 3326 "issue_row" "issue"%ROWTYPE;
jbe@0 3327 BEGIN
jbe@0 3328 PERFORM "create_snapshot"("issue_id_p");
jbe@0 3329 PERFORM "freeze_after_snapshot"("issue_id_p");
jbe@0 3330 RETURN;
jbe@0 3331 END;
jbe@0 3332 $$;
jbe@0 3333
jbe@55 3334 COMMENT ON FUNCTION "manual_freeze"
jbe@0 3335 ( "issue"."id"%TYPE )
jbe@3 3336 IS 'Freeze an issue manually (fully) and start voting';
jbe@0 3337
jbe@0 3338
jbe@0 3339
jbe@0 3340 -----------------------
jbe@0 3341 -- Counting of votes --
jbe@0 3342 -----------------------
jbe@0 3343
jbe@0 3344
jbe@5 3345 CREATE FUNCTION "weight_of_added_vote_delegations"
jbe@0 3346 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 3347 "member_id_p" "member"."id"%TYPE,
jbe@0 3348 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
jbe@0 3349 RETURNS "direct_voter"."weight"%TYPE
jbe@0 3350 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3351 DECLARE
jbe@0 3352 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 3353 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
jbe@0 3354 "weight_v" INT4;
jbe@8 3355 "sub_weight_v" INT4;
jbe@0 3356 BEGIN
jbe@0 3357 "weight_v" := 0;
jbe@0 3358 FOR "issue_delegation_row" IN
jbe@0 3359 SELECT * FROM "issue_delegation"
jbe@0 3360 WHERE "trustee_id" = "member_id_p"
jbe@0 3361 AND "issue_id" = "issue_id_p"
jbe@0 3362 LOOP
jbe@0 3363 IF NOT EXISTS (
jbe@0 3364 SELECT NULL FROM "direct_voter"
jbe@0 3365 WHERE "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3366 AND "issue_id" = "issue_id_p"
jbe@0 3367 ) AND NOT EXISTS (
jbe@0 3368 SELECT NULL FROM "delegating_voter"
jbe@0 3369 WHERE "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3370 AND "issue_id" = "issue_id_p"
jbe@0 3371 ) THEN
jbe@0 3372 "delegate_member_ids_v" :=
jbe@0 3373 "member_id_p" || "delegate_member_ids_p";
jbe@10 3374 INSERT INTO "delegating_voter" (
jbe@10 3375 "issue_id",
jbe@10 3376 "member_id",
jbe@10 3377 "scope",
jbe@10 3378 "delegate_member_ids"
jbe@10 3379 ) VALUES (
jbe@5 3380 "issue_id_p",
jbe@5 3381 "issue_delegation_row"."truster_id",
jbe@10 3382 "issue_delegation_row"."scope",
jbe@5 3383 "delegate_member_ids_v"
jbe@5 3384 );
jbe@8 3385 "sub_weight_v" := 1 +
jbe@8 3386 "weight_of_added_vote_delegations"(
jbe@8 3387 "issue_id_p",
jbe@8 3388 "issue_delegation_row"."truster_id",
jbe@8 3389 "delegate_member_ids_v"
jbe@8 3390 );
jbe@8 3391 UPDATE "delegating_voter"
jbe@8 3392 SET "weight" = "sub_weight_v"
jbe@8 3393 WHERE "issue_id" = "issue_id_p"
jbe@8 3394 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 3395 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 3396 END IF;
jbe@0 3397 END LOOP;
jbe@0 3398 RETURN "weight_v";
jbe@0 3399 END;
jbe@0 3400 $$;
jbe@0 3401
jbe@5 3402 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
jbe@0 3403 ( "issue"."id"%TYPE,
jbe@0 3404 "member"."id"%TYPE,
jbe@0 3405 "delegating_voter"."delegate_member_ids"%TYPE )
jbe@0 3406 IS 'Helper function for "add_vote_delegations" function';
jbe@0 3407
jbe@0 3408
jbe@0 3409 CREATE FUNCTION "add_vote_delegations"
jbe@0 3410 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3411 RETURNS VOID
jbe@0 3412 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3413 DECLARE
jbe@0 3414 "member_id_v" "member"."id"%TYPE;
jbe@0 3415 BEGIN
jbe@0 3416 FOR "member_id_v" IN
jbe@0 3417 SELECT "member_id" FROM "direct_voter"
jbe@0 3418 WHERE "issue_id" = "issue_id_p"
jbe@0 3419 LOOP
jbe@0 3420 UPDATE "direct_voter" SET
jbe@5 3421 "weight" = "weight" + "weight_of_added_vote_delegations"(
jbe@0 3422 "issue_id_p",
jbe@0 3423 "member_id_v",
jbe@0 3424 '{}'
jbe@0 3425 )
jbe@0 3426 WHERE "member_id" = "member_id_v"
jbe@0 3427 AND "issue_id" = "issue_id_p";
jbe@0 3428 END LOOP;
jbe@0 3429 RETURN;
jbe@0 3430 END;
jbe@0 3431 $$;
jbe@0 3432
jbe@0 3433 COMMENT ON FUNCTION "add_vote_delegations"
jbe@0 3434 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3435 IS 'Helper function for "close_voting" function';
jbe@0 3436
jbe@0 3437
jbe@0 3438 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
jbe@0 3439 RETURNS VOID
jbe@0 3440 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3441 DECLARE
jbe@97 3442 "area_id_v" "area"."id"%TYPE;
jbe@97 3443 "unit_id_v" "unit"."id"%TYPE;
jbe@0 3444 "member_id_v" "member"."id"%TYPE;
jbe@0 3445 BEGIN
jbe@67 3446 PERFORM "lock_issue"("issue_id_p");
jbe@129 3447 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
jbe@129 3448 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
jbe@137 3449 -- consider delegations and auto-reject:
jbe@0 3450 DELETE FROM "delegating_voter"
jbe@0 3451 WHERE "issue_id" = "issue_id_p";
jbe@0 3452 DELETE FROM "direct_voter"
jbe@0 3453 WHERE "issue_id" = "issue_id_p"
jbe@0 3454 AND "autoreject" = TRUE;
jbe@97 3455 DELETE FROM "direct_voter"
jbe@97 3456 USING (
jbe@97 3457 SELECT
jbe@97 3458 "direct_voter"."member_id"
jbe@97 3459 FROM "direct_voter"
jbe@97 3460 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
jbe@97 3461 LEFT JOIN "privilege"
jbe@97 3462 ON "privilege"."unit_id" = "unit_id_v"
jbe@97 3463 AND "privilege"."member_id" = "direct_voter"."member_id"
jbe@97 3464 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
jbe@97 3465 "member"."active" = FALSE OR
jbe@97 3466 "privilege"."voting_right" ISNULL OR
jbe@97 3467 "privilege"."voting_right" = FALSE
jbe@97 3468 )
jbe@97 3469 ) AS "subquery"
jbe@97 3470 WHERE "direct_voter"."issue_id" = "issue_id_p"
jbe@97 3471 AND "direct_voter"."member_id" = "subquery"."member_id";
jbe@0 3472 UPDATE "direct_voter" SET "weight" = 1
jbe@0 3473 WHERE "issue_id" = "issue_id_p";
jbe@0 3474 PERFORM "add_vote_delegations"("issue_id_p");
jbe@0 3475 FOR "member_id_v" IN
jbe@0 3476 SELECT "interest"."member_id"
jbe@0 3477 FROM "interest"
jbe@87 3478 JOIN "member"
jbe@87 3479 ON "interest"."member_id" = "member"."id"
jbe@0 3480 LEFT JOIN "direct_voter"
jbe@0 3481 ON "interest"."member_id" = "direct_voter"."member_id"
jbe@0 3482 AND "interest"."issue_id" = "direct_voter"."issue_id"
jbe@0 3483 LEFT JOIN "delegating_voter"
jbe@0 3484 ON "interest"."member_id" = "delegating_voter"."member_id"
jbe@0 3485 AND "interest"."issue_id" = "delegating_voter"."issue_id"
jbe@0 3486 WHERE "interest"."issue_id" = "issue_id_p"
jbe@0 3487 AND "interest"."autoreject" = TRUE
jbe@87 3488 AND "member"."active"
jbe@0 3489 AND "direct_voter"."member_id" ISNULL
jbe@0 3490 AND "delegating_voter"."member_id" ISNULL
jbe@0 3491 UNION SELECT "membership"."member_id"
jbe@0 3492 FROM "membership"
jbe@87 3493 JOIN "member"
jbe@87 3494 ON "membership"."member_id" = "member"."id"
jbe@0 3495 LEFT JOIN "interest"
jbe@0 3496 ON "membership"."member_id" = "interest"."member_id"
jbe@0 3497 AND "interest"."issue_id" = "issue_id_p"
jbe@0 3498 LEFT JOIN "direct_voter"
jbe@0 3499 ON "membership"."member_id" = "direct_voter"."member_id"
jbe@0 3500 AND "direct_voter"."issue_id" = "issue_id_p"
jbe@0 3501 LEFT JOIN "delegating_voter"
jbe@0 3502 ON "membership"."member_id" = "delegating_voter"."member_id"
jbe@0 3503 AND "delegating_voter"."issue_id" = "issue_id_p"
jbe@97 3504 WHERE "membership"."area_id" = "area_id_v"
jbe@0 3505 AND "membership"."autoreject" = TRUE
jbe@87 3506 AND "member"."active"
jbe@0 3507 AND "interest"."autoreject" ISNULL
jbe@0 3508 AND "direct_voter"."member_id" ISNULL
jbe@0 3509 AND "delegating_voter"."member_id" ISNULL
jbe@0 3510 LOOP
jbe@11 3511 INSERT INTO "direct_voter"
jbe@11 3512 ("member_id", "issue_id", "weight", "autoreject") VALUES
jbe@11 3513 ("member_id_v", "issue_id_p", 1, TRUE);
jbe@0 3514 INSERT INTO "vote" (
jbe@0 3515 "member_id",
jbe@0 3516 "issue_id",
jbe@0 3517 "initiative_id",
jbe@0 3518 "grade"
jbe@0 3519 ) SELECT
jbe@0 3520 "member_id_v" AS "member_id",
jbe@0 3521 "issue_id_p" AS "issue_id",
jbe@0 3522 "id" AS "initiative_id",
jbe@0 3523 -1 AS "grade"
jbe@0 3524 FROM "initiative" WHERE "issue_id" = "issue_id_p";
jbe@0 3525 END LOOP;
jbe@0 3526 PERFORM "add_vote_delegations"("issue_id_p");
jbe@137 3527 -- set voter count and mark issue as being calculated:
jbe@4 3528 UPDATE "issue" SET
jbe@111 3529 "state" = 'calculation',
jbe@61 3530 "closed" = now(),
jbe@4 3531 "voter_count" = (
jbe@4 3532 SELECT coalesce(sum("weight"), 0)
jbe@4 3533 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
jbe@6 3534 )
jbe@6 3535 WHERE "id" = "issue_id_p";
jbe@137 3536 -- calculate "positive_votes" and "negative_votes"
jbe@137 3537 -- and set "attainable" flag without regarding indirect majorities:
jbe@0 3538 UPDATE "initiative" SET
jbe@10 3539 "positive_votes" = "vote_counts"."positive_votes",
jbe@10 3540 "negative_votes" = "vote_counts"."negative_votes",
jbe@128 3541 "attainable" = CASE WHEN "majority_strict" THEN
jbe@10 3542 "vote_counts"."positive_votes" * "majority_den" >
jbe@10 3543 "majority_num" *
jbe@10 3544 ("vote_counts"."positive_votes"+"vote_counts"."negative_votes")
jbe@10 3545 ELSE
jbe@10 3546 "vote_counts"."positive_votes" * "majority_den" >=
jbe@10 3547 "majority_num" *
jbe@10 3548 ("vote_counts"."positive_votes"+"vote_counts"."negative_votes")
jbe@10 3549 END
jbe@10 3550 FROM
jbe@10 3551 ( SELECT
jbe@10 3552 "initiative"."id" AS "initiative_id",
jbe@10 3553 coalesce(
jbe@10 3554 sum(
jbe@10 3555 CASE WHEN "grade" > 0 THEN "direct_voter"."weight" ELSE 0 END
jbe@10 3556 ),
jbe@10 3557 0
jbe@10 3558 ) AS "positive_votes",
jbe@10 3559 coalesce(
jbe@10 3560 sum(
jbe@10 3561 CASE WHEN "grade" < 0 THEN "direct_voter"."weight" ELSE 0 END
jbe@10 3562 ),
jbe@10 3563 0
jbe@10 3564 ) AS "negative_votes"
jbe@10 3565 FROM "initiative"
jbe@10 3566 JOIN "issue" ON "initiative"."issue_id" = "issue"."id"
jbe@10 3567 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
jbe@10 3568 LEFT JOIN "direct_voter"
jbe@10 3569 ON "direct_voter"."issue_id" = "initiative"."issue_id"
jbe@10 3570 LEFT JOIN "vote"
jbe@10 3571 ON "vote"."initiative_id" = "initiative"."id"
jbe@10 3572 AND "vote"."member_id" = "direct_voter"."member_id"
jbe@10 3573 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@15 3574 AND "initiative"."admitted" -- NOTE: NULL case is handled too
jbe@10 3575 GROUP BY "initiative"."id"
jbe@10 3576 ) AS "vote_counts",
jbe@10 3577 "issue",
jbe@10 3578 "policy"
jbe@10 3579 WHERE "vote_counts"."initiative_id" = "initiative"."id"
jbe@10 3580 AND "issue"."id" = "initiative"."issue_id"
jbe@10 3581 AND "policy"."id" = "issue"."policy_id";
jbe@137 3582 -- materialize battle_view:
jbe@61 3583 -- NOTE: "closed" column of issue must be set at this point
jbe@61 3584 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@61 3585 INSERT INTO "battle" (
jbe@61 3586 "issue_id",
jbe@61 3587 "winning_initiative_id", "losing_initiative_id",
jbe@61 3588 "count"
jbe@61 3589 ) SELECT
jbe@61 3590 "issue_id",
jbe@61 3591 "winning_initiative_id", "losing_initiative_id",
jbe@61 3592 "count"
jbe@61 3593 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
jbe@137 3594 -- take indirect majorities into account,
jbe@137 3595 -- if "policy"."majority_indirect" = TRUE:
jbe@137 3596 LOOP
jbe@137 3597 UPDATE "initiative" SET "attainable" = TRUE
jbe@137 3598 FROM (
jbe@137 3599 SELECT "new_initiative"."id" AS "initiative_id"
jbe@137 3600 FROM "issue"
jbe@137 3601 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
jbe@137 3602 JOIN "initiative" "old_initiative"
jbe@137 3603 ON "old_initiative"."issue_id" = "issue_id_p"
jbe@137 3604 AND "old_initiative"."admitted"
jbe@137 3605 AND "old_initiative"."attainable"
jbe@137 3606 JOIN "initiative" "new_initiative"
jbe@137 3607 ON "new_initiative"."issue_id" = "issue_id_p"
jbe@137 3608 AND "new_initiative"."admitted"
jbe@137 3609 AND NOT "new_initiative"."attainable"
jbe@137 3610 AND "new_initiative"."positive_votes" >= "new_initiative"."negative_votes"
jbe@137 3611 JOIN "battle" "battle_win"
jbe@137 3612 ON "battle_win"."issue_id" = "issue_id_p"
jbe@137 3613 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
jbe@137 3614 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
jbe@137 3615 JOIN "battle" "battle_lose"
jbe@137 3616 ON "battle_lose"."issue_id" = "issue_id_p"
jbe@137 3617 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
jbe@137 3618 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
jbe@137 3619 WHERE "issue"."id" = "issue_id_p"
jbe@137 3620 AND "policy"."majority_indirect"
jbe@137 3621 AND CASE WHEN "policy"."majority_strict" THEN
jbe@137 3622 "battle_win"."count" * "policy"."majority_den" >
jbe@137 3623 "policy"."majority_num" *
jbe@137 3624 ("battle_win"."count"+"battle_lose"."count")
jbe@137 3625 ELSE
jbe@137 3626 "battle_win"."count" * "policy"."majority_den" >=
jbe@137 3627 "policy"."majority_num" *
jbe@137 3628 ("battle_win"."count"+"battle_lose"."count")
jbe@137 3629 END
jbe@137 3630 ) AS "subquery"
jbe@137 3631 WHERE "id" = "subquery"."initiative_id";
jbe@137 3632 EXIT WHEN NOT FOUND;
jbe@137 3633 END LOOP;
jbe@0 3634 END;
jbe@0 3635 $$;
jbe@0 3636
jbe@0 3637 COMMENT ON FUNCTION "close_voting"
jbe@0 3638 ( "issue"."id"%TYPE )
jbe@0 3639 IS 'Closes the voting on an issue, and calculates positive and negative votes for each initiative; The ranking is not calculated yet, to keep the (locking) transaction short.';
jbe@0 3640
jbe@0 3641
jbe@30 3642 CREATE FUNCTION "defeat_strength"
jbe@30 3643 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
jbe@30 3644 RETURNS INT8
jbe@30 3645 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@30 3646 BEGIN
jbe@30 3647 IF "positive_votes_p" > "negative_votes_p" THEN
jbe@30 3648 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
jbe@30 3649 ELSIF "positive_votes_p" = "negative_votes_p" THEN
jbe@30 3650 RETURN 0;
jbe@30 3651 ELSE
jbe@30 3652 RETURN -1;
jbe@30 3653 END IF;
jbe@30 3654 END;
jbe@30 3655 $$;
jbe@30 3656
jbe@30 3657 COMMENT ON FUNCTION "defeat_strength"(INT4, INT4) IS 'Calculates defeat strength (INT8!) of a pairwise defeat primarily by the absolute number of votes for the winner and secondarily by the absolute number of votes for the loser';
jbe@30 3658
jbe@30 3659
jbe@30 3660 CREATE FUNCTION "array_init_string"("dim_p" INTEGER)
jbe@30 3661 RETURNS TEXT
jbe@0 3662 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@0 3663 DECLARE
jbe@0 3664 "i" INTEGER;
jbe@0 3665 "ary_text_v" TEXT;
jbe@0 3666 BEGIN
jbe@0 3667 IF "dim_p" >= 1 THEN
jbe@0 3668 "ary_text_v" := '{NULL';
jbe@0 3669 "i" := "dim_p";
jbe@0 3670 LOOP
jbe@0 3671 "i" := "i" - 1;
jbe@0 3672 EXIT WHEN "i" = 0;
jbe@0 3673 "ary_text_v" := "ary_text_v" || ',NULL';
jbe@0 3674 END LOOP;
jbe@0 3675 "ary_text_v" := "ary_text_v" || '}';
jbe@30 3676 RETURN "ary_text_v";
jbe@0 3677 ELSE
jbe@0 3678 RAISE EXCEPTION 'Dimension needs to be at least 1.';
jbe@0 3679 END IF;
jbe@0 3680 END;
jbe@0 3681 $$;
jbe@0 3682
jbe@30 3683 COMMENT ON FUNCTION "array_init_string"(INTEGER) IS 'Needed for PostgreSQL < 8.4, due to missing "array_fill" function';
jbe@30 3684
jbe@30 3685
jbe@30 3686 CREATE FUNCTION "square_matrix_init_string"("dim_p" INTEGER)
jbe@30 3687 RETURNS TEXT
jbe@0 3688 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@0 3689 DECLARE
jbe@0 3690 "i" INTEGER;
jbe@0 3691 "row_text_v" TEXT;
jbe@0 3692 "ary_text_v" TEXT;
jbe@0 3693 BEGIN
jbe@0 3694 IF "dim_p" >= 1 THEN
jbe@0 3695 "row_text_v" := '{NULL';
jbe@0 3696 "i" := "dim_p";
jbe@0 3697 LOOP
jbe@0 3698 "i" := "i" - 1;
jbe@0 3699 EXIT WHEN "i" = 0;
jbe@0 3700 "row_text_v" := "row_text_v" || ',NULL';
jbe@0 3701 END LOOP;
jbe@0 3702 "row_text_v" := "row_text_v" || '}';
jbe@0 3703 "ary_text_v" := '{' || "row_text_v";
jbe@0 3704 "i" := "dim_p";
jbe@0 3705 LOOP
jbe@0 3706 "i" := "i" - 1;
jbe@0 3707 EXIT WHEN "i" = 0;
jbe@0 3708 "ary_text_v" := "ary_text_v" || ',' || "row_text_v";
jbe@0 3709 END LOOP;
jbe@0 3710 "ary_text_v" := "ary_text_v" || '}';
jbe@30 3711 RETURN "ary_text_v";
jbe@0 3712 ELSE
jbe@0 3713 RAISE EXCEPTION 'Dimension needs to be at least 1.';
jbe@0 3714 END IF;
jbe@0 3715 END;
jbe@0 3716 $$;
jbe@0 3717
jbe@30 3718 COMMENT ON FUNCTION "square_matrix_init_string"(INTEGER) IS 'Needed for PostgreSQL < 8.4, due to missing "array_fill" function';
jbe@0 3719
jbe@0 3720
jbe@0 3721 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
jbe@0 3722 RETURNS VOID
jbe@0 3723 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3724 DECLARE
jbe@134 3725 "dimension_v" INTEGER;
jbe@134 3726 "vote_matrix" INT4[][]; -- absolute votes
jbe@134 3727 "matrix" INT8[][]; -- defeat strength / best paths
jbe@134 3728 "i" INTEGER;
jbe@134 3729 "j" INTEGER;
jbe@134 3730 "k" INTEGER;
jbe@134 3731 "battle_row" "battle"%ROWTYPE;
jbe@134 3732 "rank_ary" INT4[];
jbe@134 3733 "rank_v" INT4;
jbe@134 3734 "done_v" INTEGER;
jbe@134 3735 "winners_ary" INTEGER[];
jbe@134 3736 "initiative_id_v" "initiative"."id"%TYPE;
jbe@0 3737 BEGIN
jbe@0 3738 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
jbe@126 3739 SELECT count(1) INTO "dimension_v"
jbe@126 3740 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
jbe@126 3741 IF "dimension_v" > 1 THEN
jbe@30 3742 -- Create "vote_matrix" with absolute number of votes in pairwise
jbe@30 3743 -- comparison:
jbe@30 3744 "vote_matrix" := "square_matrix_init_string"("dimension_v"); -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
jbe@0 3745 "i" := 1;
jbe@0 3746 "j" := 2;
jbe@0 3747 FOR "battle_row" IN
jbe@0 3748 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
jbe@126 3749 ORDER BY
jbe@126 3750 "winning_initiative_id" NULLS LAST,
jbe@126 3751 "losing_initiative_id" NULLS LAST
jbe@0 3752 LOOP
jbe@30 3753 "vote_matrix"["i"]["j"] := "battle_row"."count";
jbe@0 3754 IF "j" = "dimension_v" THEN
jbe@0 3755 "i" := "i" + 1;
jbe@0 3756 "j" := 1;
jbe@0 3757 ELSE
jbe@0 3758 "j" := "j" + 1;
jbe@0 3759 IF "j" = "i" THEN
jbe@0 3760 "j" := "j" + 1;
jbe@0 3761 END IF;
jbe@0 3762 END IF;
jbe@0 3763 END LOOP;
jbe@0 3764 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
jbe@0 3765 RAISE EXCEPTION 'Wrong battle count (should not happen)';
jbe@0 3766 END IF;
jbe@30 3767 -- Store defeat strengths in "matrix" using "defeat_strength"
jbe@30 3768 -- function:
jbe@30 3769 "matrix" := "square_matrix_init_string"("dimension_v"); -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
jbe@0 3770 "i" := 1;
jbe@0 3771 LOOP
jbe@30 3772 "j" := 1;
jbe@0 3773 LOOP
jbe@0 3774 IF "i" != "j" THEN
jbe@30 3775 "matrix"["i"]["j"] := "defeat_strength"(
jbe@30 3776 "vote_matrix"["i"]["j"],
jbe@30 3777 "vote_matrix"["j"]["i"]
jbe@30 3778 );
jbe@0 3779 END IF;
jbe@0 3780 EXIT WHEN "j" = "dimension_v";
jbe@0 3781 "j" := "j" + 1;
jbe@0 3782 END LOOP;
jbe@30 3783 EXIT WHEN "i" = "dimension_v";
jbe@0 3784 "i" := "i" + 1;
jbe@0 3785 END LOOP;
jbe@0 3786 -- Find best paths:
jbe@0 3787 "i" := 1;
jbe@0 3788 LOOP
jbe@0 3789 "j" := 1;
jbe@0 3790 LOOP
jbe@0 3791 IF "i" != "j" THEN
jbe@0 3792 "k" := 1;
jbe@0 3793 LOOP
jbe@0 3794 IF "i" != "k" AND "j" != "k" THEN
jbe@0 3795 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
jbe@0 3796 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
jbe@0 3797 "matrix"["j"]["k"] := "matrix"["j"]["i"];
jbe@0 3798 END IF;
jbe@0 3799 ELSE
jbe@0 3800 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
jbe@0 3801 "matrix"["j"]["k"] := "matrix"["i"]["k"];
jbe@0 3802 END IF;
jbe@0 3803 END IF;
jbe@0 3804 END IF;
jbe@0 3805 EXIT WHEN "k" = "dimension_v";
jbe@0 3806 "k" := "k" + 1;
jbe@0 3807 END LOOP;
jbe@0 3808 END IF;
jbe@0 3809 EXIT WHEN "j" = "dimension_v";
jbe@0 3810 "j" := "j" + 1;
jbe@0 3811 END LOOP;
jbe@0 3812 EXIT WHEN "i" = "dimension_v";
jbe@0 3813 "i" := "i" + 1;
jbe@0 3814 END LOOP;
jbe@0 3815 -- Determine order of winners:
jbe@30 3816 "rank_ary" := "array_init_string"("dimension_v"); -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
jbe@0 3817 "rank_v" := 1;
jbe@0 3818 "done_v" := 0;
jbe@0 3819 LOOP
jbe@0 3820 "winners_ary" := '{}';
jbe@0 3821 "i" := 1;
jbe@0 3822 LOOP
jbe@0 3823 IF "rank_ary"["i"] ISNULL THEN
jbe@0 3824 "j" := 1;
jbe@0 3825 LOOP
jbe@0 3826 IF
jbe@0 3827 "i" != "j" AND
jbe@0 3828 "rank_ary"["j"] ISNULL AND
jbe@0 3829 "matrix"["j"]["i"] > "matrix"["i"]["j"]
jbe@0 3830 THEN
jbe@0 3831 -- someone else is better
jbe@0 3832 EXIT;
jbe@0 3833 END IF;
jbe@0 3834 IF "j" = "dimension_v" THEN
jbe@0 3835 -- noone is better
jbe@0 3836 "winners_ary" := "winners_ary" || "i";
jbe@0 3837 EXIT;
jbe@0 3838 END IF;
jbe@0 3839 "j" := "j" + 1;
jbe@0 3840 END LOOP;
jbe@0 3841 END IF;
jbe@0 3842 EXIT WHEN "i" = "dimension_v";
jbe@0 3843 "i" := "i" + 1;
jbe@0 3844 END LOOP;
jbe@0 3845 "i" := 1;
jbe@0 3846 LOOP
jbe@0 3847 "rank_ary"["winners_ary"["i"]] := "rank_v";
jbe@0 3848 "done_v" := "done_v" + 1;
jbe@0 3849 EXIT WHEN "i" = array_upper("winners_ary", 1);
jbe@0 3850 "i" := "i" + 1;
jbe@0 3851 END LOOP;
jbe@0 3852 EXIT WHEN "done_v" = "dimension_v";
jbe@0 3853 "rank_v" := "rank_v" + 1;
jbe@0 3854 END LOOP;
jbe@128 3855 -- write preliminary results:
jbe@0 3856 "i" := 1;
jbe@0 3857 FOR "initiative_id_v" IN
jbe@10 3858 SELECT "id" FROM "initiative"
jbe@126 3859 WHERE "issue_id" = "issue_id_p" AND "admitted"
jbe@10 3860 ORDER BY "id"
jbe@0 3861 LOOP
jbe@128 3862 UPDATE "initiative" SET
jbe@128 3863 "favored" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
jbe@128 3864 "unfavored" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
jbe@128 3865 "eligible" = "attainable" AND
jbe@128 3866 "rank_ary"["i"] < "rank_ary"["dimension_v"],
jbe@134 3867 "rank" = "rank_ary"["i"],
jbe@134 3868 "winner" = FALSE,
jbe@134 3869 "promising" = FALSE
jbe@0 3870 WHERE "id" = "initiative_id_v";
jbe@0 3871 "i" := "i" + 1;
jbe@0 3872 END LOOP;
jbe@126 3873 IF "i" != "dimension_v" THEN
jbe@0 3874 RAISE EXCEPTION 'Wrong winner count (should not happen)';
jbe@0 3875 END IF;
jbe@134 3876 -- mark final winner:
jbe@134 3877 SELECT "id" INTO "initiative_id_v" FROM "initiative"
jbe@134 3878 WHERE "issue_id" = "issue_id_p" AND "admitted" AND "eligible"
jbe@134 3879 ORDER BY "rank", "id"
jbe@134 3880 LIMIT 1;
jbe@134 3881 UPDATE "initiative" SET "winner" = TRUE WHERE "id" = "initiative_id_v";
jbe@134 3882 -- determine promising initiatives:
jbe@134 3883 LOOP
jbe@135 3884 -- NOTE: non-straightened ranks are used
jbe@136 3885 UPDATE "initiative" SET "promising" = TRUE
jbe@136 3886 FROM (
jbe@136 3887 SELECT "new_initiative"."id" AS "initiative_id"
jbe@136 3888 FROM "issue"
jbe@136 3889 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
jbe@136 3890 JOIN "initiative" "old_initiative"
jbe@136 3891 ON "old_initiative"."issue_id" = "issue_id_p"
jbe@136 3892 AND "old_initiative"."admitted"
jbe@136 3893 AND ("old_initiative"."winner" OR "old_initiative"."promising")
jbe@136 3894 JOIN "initiative" "new_initiative"
jbe@136 3895 ON "new_initiative"."issue_id" = "issue_id_p"
jbe@136 3896 AND "new_initiative"."admitted"
jbe@136 3897 AND "new_initiative"."favored"
jbe@136 3898 AND NOT ("new_initiative"."winner" OR "new_initiative"."promising")
jbe@136 3899 JOIN "battle" "battle_win"
jbe@136 3900 ON "battle_win"."issue_id" = "issue_id_p"
jbe@136 3901 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
jbe@136 3902 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
jbe@136 3903 JOIN "battle" "battle_lose"
jbe@136 3904 ON "battle_lose"."issue_id" = "issue_id_p"
jbe@136 3905 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
jbe@136 3906 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
jbe@136 3907 WHERE "issue"."id" = "issue_id_p"
jbe@136 3908 AND "new_initiative"."rank" < "old_initiative"."rank"
jbe@136 3909 AND CASE WHEN "policy"."majority_strict" THEN
jbe@136 3910 "battle_win"."count" * "policy"."majority_den" >
jbe@136 3911 "policy"."majority_num" *
jbe@136 3912 ("battle_win"."count"+"battle_lose"."count")
jbe@136 3913 ELSE
jbe@136 3914 "battle_win"."count" * "policy"."majority_den" >=
jbe@136 3915 "policy"."majority_num" *
jbe@136 3916 ("battle_win"."count"+"battle_lose"."count")
jbe@136 3917 END
jbe@136 3918 ORDER BY "new_initiative"."rank"
jbe@136 3919 LIMIT 1
jbe@136 3920 ) AS "subquery"
jbe@136 3921 WHERE "id" = "subquery"."initiative_id";
jbe@136 3922 EXIT WHEN NOT FOUND;
jbe@134 3923 END LOOP;
jbe@0 3924 -- straighten ranks (start counting with 1, no equal ranks):
jbe@0 3925 "rank_v" := 1;
jbe@0 3926 FOR "initiative_id_v" IN
jbe@0 3927 SELECT "id" FROM "initiative"
jbe@134 3928 WHERE "issue_id" = "issue_id_p" AND "admitted"
jbe@134 3929 ORDER BY "rank", "id"
jbe@0 3930 LOOP
jbe@0 3931 UPDATE "initiative" SET "rank" = "rank_v"
jbe@0 3932 WHERE "id" = "initiative_id_v";
jbe@0 3933 "rank_v" := "rank_v" + 1;
jbe@0 3934 END LOOP;
jbe@0 3935 END IF;
jbe@0 3936 -- mark issue as finished
jbe@111 3937 UPDATE "issue" SET
jbe@111 3938 "state" =
jbe@134 3939 CASE WHEN "dimension_v" = 0 THEN -- TODO: Broken! To be fixed!
jbe@121 3940 'finished_without_winner'::"issue_state"
jbe@111 3941 ELSE
jbe@121 3942 'finished_with_winner'::"issue_state"
jbe@111 3943 END,
jbe@111 3944 "ranks_available" = TRUE
jbe@0 3945 WHERE "id" = "issue_id_p";
jbe@0 3946 RETURN;
jbe@0 3947 END;
jbe@0 3948 $$;
jbe@0 3949
jbe@0 3950 COMMENT ON FUNCTION "calculate_ranks"
jbe@0 3951 ( "issue"."id"%TYPE )
jbe@0 3952 IS 'Determine ranking (Votes have to be counted first)';
jbe@0 3953
jbe@0 3954
jbe@0 3955
jbe@0 3956 -----------------------------
jbe@0 3957 -- Automatic state changes --
jbe@0 3958 -----------------------------
jbe@0 3959
jbe@0 3960
jbe@0 3961 CREATE FUNCTION "check_issue"
jbe@0 3962 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3963 RETURNS VOID
jbe@0 3964 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3965 DECLARE
jbe@0 3966 "issue_row" "issue"%ROWTYPE;
jbe@0 3967 "policy_row" "policy"%ROWTYPE;
jbe@0 3968 "voting_requested_v" BOOLEAN;
jbe@0 3969 BEGIN
jbe@67 3970 PERFORM "lock_issue"("issue_id_p");
jbe@0 3971 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@24 3972 -- only process open issues:
jbe@0 3973 IF "issue_row"."closed" ISNULL THEN
jbe@0 3974 SELECT * INTO "policy_row" FROM "policy"
jbe@0 3975 WHERE "id" = "issue_row"."policy_id";
jbe@24 3976 -- create a snapshot, unless issue is already fully frozen:
jbe@3 3977 IF "issue_row"."fully_frozen" ISNULL THEN
jbe@0 3978 PERFORM "create_snapshot"("issue_id_p");
jbe@0 3979 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@0 3980 END IF;
jbe@24 3981 -- eventually close or accept issues, which have not been accepted:
jbe@0 3982 IF "issue_row"."accepted" ISNULL THEN
jbe@0 3983 IF EXISTS (
jbe@0 3984 SELECT NULL FROM "initiative"
jbe@0 3985 WHERE "issue_id" = "issue_id_p"
jbe@0 3986 AND "supporter_count" > 0
jbe@0 3987 AND "supporter_count" * "policy_row"."issue_quorum_den"
jbe@0 3988 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
jbe@0 3989 ) THEN
jbe@24 3990 -- accept issues, if supporter count is high enough
jbe@3 3991 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
jbe@111 3992 -- NOTE: "issue_row" used later
jbe@111 3993 "issue_row"."state" := 'discussion';
jbe@111 3994 "issue_row"."accepted" := now();
jbe@111 3995 UPDATE "issue" SET
jbe@111 3996 "state" = "issue_row"."state",
jbe@111 3997 "accepted" = "issue_row"."accepted"
jbe@0 3998 WHERE "id" = "issue_row"."id";
jbe@0 3999 ELSIF
jbe@22 4000 now() >= "issue_row"."created" + "issue_row"."admission_time"
jbe@0 4001 THEN
jbe@24 4002 -- close issues, if admission time has expired
jbe@0 4003 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
jbe@111 4004 UPDATE "issue" SET
jbe@111 4005 "state" = 'canceled_issue_not_accepted',
jbe@111 4006 "closed" = now()
jbe@0 4007 WHERE "id" = "issue_row"."id";
jbe@0 4008 END IF;
jbe@0 4009 END IF;
jbe@24 4010 -- eventually half freeze issues:
jbe@0 4011 IF
jbe@24 4012 -- NOTE: issue can't be closed at this point, if it has been accepted
jbe@0 4013 "issue_row"."accepted" NOTNULL AND
jbe@3 4014 "issue_row"."half_frozen" ISNULL
jbe@0 4015 THEN
jbe@0 4016 SELECT
jbe@0 4017 CASE
jbe@0 4018 WHEN "vote_now" * 2 > "issue_row"."population" THEN
jbe@0 4019 TRUE
jbe@0 4020 WHEN "vote_later" * 2 > "issue_row"."population" THEN
jbe@0 4021 FALSE
jbe@0 4022 ELSE NULL
jbe@0 4023 END
jbe@0 4024 INTO "voting_requested_v"
jbe@0 4025 FROM "issue" WHERE "id" = "issue_id_p";
jbe@0 4026 IF
jbe@0 4027 "voting_requested_v" OR (
jbe@3 4028 "voting_requested_v" ISNULL AND
jbe@22 4029 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
jbe@0 4030 )
jbe@0 4031 THEN
jbe@21 4032 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
jbe@111 4033 -- NOTE: "issue_row" used later
jbe@111 4034 "issue_row"."state" := 'verification';
jbe@111 4035 "issue_row"."half_frozen" := now();
jbe@111 4036 UPDATE "issue" SET
jbe@111 4037 "state" = "issue_row"."state",
jbe@111 4038 "half_frozen" = "issue_row"."half_frozen"
jbe@3 4039 WHERE "id" = "issue_row"."id";
jbe@0 4040 END IF;
jbe@0 4041 END IF;
jbe@24 4042 -- close issues after some time, if all initiatives have been revoked:
jbe@24 4043 IF
jbe@24 4044 "issue_row"."closed" ISNULL AND
jbe@24 4045 NOT EXISTS (
jbe@24 4046 -- all initiatives are revoked
jbe@24 4047 SELECT NULL FROM "initiative"
jbe@24 4048 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@24 4049 ) AND (
jbe@111 4050 -- and issue has not been accepted yet
jbe@111 4051 "issue_row"."accepted" ISNULL OR
jbe@24 4052 NOT EXISTS (
jbe@111 4053 -- or no initiatives have been revoked lately
jbe@24 4054 SELECT NULL FROM "initiative"
jbe@24 4055 WHERE "issue_id" = "issue_id_p"
jbe@24 4056 AND now() < "revoked" + "issue_row"."verification_time"
jbe@24 4057 ) OR (
jbe@24 4058 -- or verification time has elapsed
jbe@24 4059 "issue_row"."half_frozen" NOTNULL AND
jbe@24 4060 "issue_row"."fully_frozen" ISNULL AND
jbe@24 4061 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
jbe@24 4062 )
jbe@24 4063 )
jbe@24 4064 THEN
jbe@111 4065 -- NOTE: "issue_row" used later
jbe@113 4066 IF "issue_row"."accepted" ISNULL THEN
jbe@113 4067 "issue_row"."state" := 'canceled_revoked_before_accepted';
jbe@113 4068 ELSIF "issue_row"."half_frozen" ISNULL THEN
jbe@113 4069 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
jbe@113 4070 ELSE
jbe@113 4071 "issue_row"."state" := 'canceled_after_revocation_during_verification';
jbe@113 4072 END IF;
jbe@111 4073 "issue_row"."closed" := now();
jbe@111 4074 UPDATE "issue" SET
jbe@111 4075 "state" = "issue_row"."state",
jbe@111 4076 "closed" = "issue_row"."closed"
jbe@24 4077 WHERE "id" = "issue_row"."id";
jbe@24 4078 END IF;
jbe@24 4079 -- fully freeze issue after verification time:
jbe@0 4080 IF
jbe@3 4081 "issue_row"."half_frozen" NOTNULL AND
jbe@3 4082 "issue_row"."fully_frozen" ISNULL AND
jbe@24 4083 "issue_row"."closed" ISNULL AND
jbe@22 4084 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
jbe@3 4085 THEN
jbe@3 4086 PERFORM "freeze_after_snapshot"("issue_id_p");
jbe@24 4087 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
jbe@3 4088 END IF;
jbe@9 4089 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@24 4090 -- close issue by calling close_voting(...) after voting time:
jbe@3 4091 IF
jbe@9 4092 "issue_row"."closed" ISNULL AND
jbe@3 4093 "issue_row"."fully_frozen" NOTNULL AND
jbe@22 4094 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
jbe@0 4095 THEN
jbe@0 4096 PERFORM "close_voting"("issue_id_p");
jbe@111 4097 -- calculate ranks will not consume much time and can be done now
jbe@111 4098 PERFORM "calculate_ranks"("issue_id_p");
jbe@0 4099 END IF;
jbe@0 4100 END IF;
jbe@0 4101 RETURN;
jbe@0 4102 END;
jbe@0 4103 $$;
jbe@0 4104
jbe@0 4105 COMMENT ON FUNCTION "check_issue"
jbe@0 4106 ( "issue"."id"%TYPE )
jbe@0 4107 IS 'Precalculate supporter counts etc. for a given issue, and check, if status change is required; At end of voting the ranking is not calculated by this function, but must be calculated in a seperate transaction using the "calculate_ranks" function.';
jbe@0 4108
jbe@0 4109
jbe@0 4110 CREATE FUNCTION "check_everything"()
jbe@0 4111 RETURNS VOID
jbe@0 4112 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4113 DECLARE
jbe@0 4114 "issue_id_v" "issue"."id"%TYPE;
jbe@0 4115 BEGIN
jbe@1 4116 DELETE FROM "expired_session";
jbe@104 4117 PERFORM "check_last_login"();
jbe@4 4118 PERFORM "calculate_member_counts"();
jbe@4 4119 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
jbe@0 4120 PERFORM "check_issue"("issue_id_v");
jbe@0 4121 END LOOP;
jbe@4 4122 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
jbe@0 4123 PERFORM "calculate_ranks"("issue_id_v");
jbe@0 4124 END LOOP;
jbe@0 4125 RETURN;
jbe@0 4126 END;
jbe@0 4127 $$;
jbe@0 4128
jbe@103 4129 COMMENT ON FUNCTION "check_everything"() IS 'Amongst other regular tasks this function performs "check_issue" for every open issue, and if possible, automatically calculates ranks. Use this function only for development and debugging purposes, as long transactions with exclusive locking may result. In productive environments you should call the lf_update program instead.';
jbe@0 4130
jbe@0 4131
jbe@0 4132
jbe@59 4133 ----------------------
jbe@59 4134 -- Deletion of data --
jbe@59 4135 ----------------------
jbe@59 4136
jbe@59 4137
jbe@59 4138 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
jbe@59 4139 RETURNS VOID
jbe@59 4140 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@59 4141 DECLARE
jbe@59 4142 "issue_row" "issue"%ROWTYPE;
jbe@59 4143 BEGIN
jbe@59 4144 SELECT * INTO "issue_row"
jbe@59 4145 FROM "issue" WHERE "id" = "issue_id_p"
jbe@59 4146 FOR UPDATE;
jbe@59 4147 IF "issue_row"."cleaned" ISNULL THEN
jbe@59 4148 UPDATE "issue" SET
jbe@59 4149 "closed" = NULL,
jbe@59 4150 "ranks_available" = FALSE
jbe@59 4151 WHERE "id" = "issue_id_p";
jbe@59 4152 DELETE FROM "delegating_voter"
jbe@59 4153 WHERE "issue_id" = "issue_id_p";
jbe@59 4154 DELETE FROM "direct_voter"
jbe@59 4155 WHERE "issue_id" = "issue_id_p";
jbe@59 4156 DELETE FROM "delegating_interest_snapshot"
jbe@59 4157 WHERE "issue_id" = "issue_id_p";
jbe@59 4158 DELETE FROM "direct_interest_snapshot"
jbe@59 4159 WHERE "issue_id" = "issue_id_p";
jbe@59 4160 DELETE FROM "delegating_population_snapshot"
jbe@59 4161 WHERE "issue_id" = "issue_id_p";
jbe@59 4162 DELETE FROM "direct_population_snapshot"
jbe@59 4163 WHERE "issue_id" = "issue_id_p";
jbe@113 4164 DELETE FROM "non_voter"
jbe@94 4165 WHERE "issue_id" = "issue_id_p";
jbe@59 4166 DELETE FROM "delegation"
jbe@59 4167 WHERE "issue_id" = "issue_id_p";
jbe@59 4168 DELETE FROM "supporter"
jbe@59 4169 WHERE "issue_id" = "issue_id_p";
jbe@59 4170 UPDATE "issue" SET
jbe@59 4171 "closed" = "issue_row"."closed",
jbe@59 4172 "ranks_available" = "issue_row"."ranks_available",
jbe@59 4173 "cleaned" = now()
jbe@59 4174 WHERE "id" = "issue_id_p";
jbe@59 4175 END IF;
jbe@59 4176 RETURN;
jbe@59 4177 END;
jbe@59 4178 $$;
jbe@59 4179
jbe@59 4180 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
jbe@8 4181
jbe@8 4182
jbe@54 4183 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
jbe@8 4184 RETURNS VOID
jbe@8 4185 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@8 4186 BEGIN
jbe@9 4187 UPDATE "member" SET
jbe@57 4188 "last_login" = NULL,
jbe@103 4189 "last_login_public" = NULL,
jbe@45 4190 "login" = NULL,
jbe@11 4191 "password" = NULL,
jbe@101 4192 "locked" = TRUE,
jbe@54 4193 "active" = FALSE,
jbe@11 4194 "notify_email" = NULL,
jbe@11 4195 "notify_email_unconfirmed" = NULL,
jbe@11 4196 "notify_email_secret" = NULL,
jbe@11 4197 "notify_email_secret_expiry" = NULL,
jbe@57 4198 "notify_email_lock_expiry" = NULL,
jbe@11 4199 "password_reset_secret" = NULL,
jbe@11 4200 "password_reset_secret_expiry" = NULL,
jbe@11 4201 "organizational_unit" = NULL,
jbe@11 4202 "internal_posts" = NULL,
jbe@11 4203 "realname" = NULL,
jbe@11 4204 "birthday" = NULL,
jbe@11 4205 "address" = NULL,
jbe@11 4206 "email" = NULL,
jbe@11 4207 "xmpp_address" = NULL,
jbe@11 4208 "website" = NULL,
jbe@11 4209 "phone" = NULL,
jbe@11 4210 "mobile_phone" = NULL,
jbe@11 4211 "profession" = NULL,
jbe@11 4212 "external_memberships" = NULL,
jbe@11 4213 "external_posts" = NULL,
jbe@45 4214 "statement" = NULL
jbe@45 4215 WHERE "id" = "member_id_p";
jbe@11 4216 -- "text_search_data" is updated by triggers
jbe@45 4217 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
jbe@45 4218 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
jbe@45 4219 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
jbe@45 4220 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
jbe@45 4221 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
jbe@113 4222 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
jbe@113 4223 DELETE FROM "session" WHERE "member_id" = "member_id_p";
jbe@45 4224 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
jbe@45 4225 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
jbe@113 4226 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
jbe@45 4227 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
jbe@45 4228 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
jbe@54 4229 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
jbe@54 4230 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
jbe@113 4231 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
jbe@57 4232 DELETE FROM "direct_voter" USING "issue"
jbe@57 4233 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@57 4234 AND "issue"."closed" ISNULL
jbe@57 4235 AND "member_id" = "member_id_p";
jbe@45 4236 RETURN;
jbe@45 4237 END;
jbe@45 4238 $$;
jbe@45 4239
jbe@57 4240 COMMENT ON FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE) IS 'Deactivate member and clear certain settings and data of this member (data protection)';
jbe@45 4241
jbe@45 4242
jbe@45 4243 CREATE FUNCTION "delete_private_data"()
jbe@45 4244 RETURNS VOID
jbe@45 4245 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@45 4246 BEGIN
jbe@50 4247 UPDATE "member" SET
jbe@57 4248 "last_login" = NULL,
jbe@50 4249 "login" = NULL,
jbe@50 4250 "password" = NULL,
jbe@50 4251 "notify_email" = NULL,
jbe@50 4252 "notify_email_unconfirmed" = NULL,
jbe@50 4253 "notify_email_secret" = NULL,
jbe@50 4254 "notify_email_secret_expiry" = NULL,
jbe@57 4255 "notify_email_lock_expiry" = NULL,
jbe@50 4256 "password_reset_secret" = NULL,
jbe@50 4257 "password_reset_secret_expiry" = NULL,
jbe@50 4258 "organizational_unit" = NULL,
jbe@50 4259 "internal_posts" = NULL,
jbe@50 4260 "realname" = NULL,
jbe@50 4261 "birthday" = NULL,
jbe@50 4262 "address" = NULL,
jbe@50 4263 "email" = NULL,
jbe@50 4264 "xmpp_address" = NULL,
jbe@50 4265 "website" = NULL,
jbe@50 4266 "phone" = NULL,
jbe@50 4267 "mobile_phone" = NULL,
jbe@50 4268 "profession" = NULL,
jbe@50 4269 "external_memberships" = NULL,
jbe@50 4270 "external_posts" = NULL,
jbe@50 4271 "statement" = NULL;
jbe@50 4272 -- "text_search_data" is updated by triggers
jbe@54 4273 DELETE FROM "invite_code";
jbe@50 4274 DELETE FROM "setting";
jbe@50 4275 DELETE FROM "setting_map";
jbe@50 4276 DELETE FROM "member_relation_setting";
jbe@50 4277 DELETE FROM "member_image";
jbe@50 4278 DELETE FROM "contact";
jbe@113 4279 DELETE FROM "ignored_member";
jbe@54 4280 DELETE FROM "session";
jbe@50 4281 DELETE FROM "area_setting";
jbe@50 4282 DELETE FROM "issue_setting";
jbe@113 4283 DELETE FROM "ignored_initiative";
jbe@50 4284 DELETE FROM "initiative_setting";
jbe@50 4285 DELETE FROM "suggestion_setting";
jbe@113 4286 DELETE FROM "non_voter";
jbe@8 4287 DELETE FROM "direct_voter" USING "issue"
jbe@8 4288 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@8 4289 AND "issue"."closed" ISNULL;
jbe@8 4290 RETURN;
jbe@8 4291 END;
jbe@8 4292 $$;
jbe@8 4293
jbe@103 4294 COMMENT ON FUNCTION "delete_private_data"() IS 'Used by lf_export script. DO NOT USE on productive database, but only on a copy! This function deletes all data which should not be publicly available, and can be used to create a database dump for publication.';
jbe@8 4295
jbe@8 4296
jbe@8 4297
jbe@0 4298 COMMIT;

Impressum / About Us