liquid_feedback_core

annotate core.sql @ 146:8422bca3a218

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

Impressum / About Us