liquid_feedback_core

annotate core.sql @ 259:620ec5751a1b

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

Impressum / About Us