liquid_feedback_core

annotate core.sql @ 221:4a7ae2507515

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

Impressum / About Us