liquid_feedback_core

annotate core.sql @ 149:a07cfe298806

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

Impressum / About Us