liquid_feedback_core

annotate core.sql @ 158:374cca7355af

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

Impressum / About Us