liquid_feedback_core

annotate core.sql @ 255:a1db85ce10ea

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

Impressum / About Us