liquid_feedback_core

annotate core.sql @ 203:976e7dafe641

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

Impressum / About Us