liquid_feedback_core

annotate core.sql @ 260:878f84407290

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

Impressum / About Us