liquid_feedback_core

annotate core.sql @ 159:32887495ca57

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

Impressum / About Us