liquid_feedback_core

annotate core.sql @ 226:10a231cfd585

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

Impressum / About Us