liquid_feedback_core

annotate core.sql @ 217:9474e2038590

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

Impressum / About Us