liquid_feedback_core

annotate core.sql @ 160:cc520b58e8ec

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

Impressum / About Us