liquid_feedback_core

annotate core.sql @ 143:9d78380d1974

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

Impressum / About Us