liquid_feedback_core

annotate core.sql @ 263:30465830ad9c

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

Impressum / About Us