liquid_feedback_core

annotate core.sql @ 206:e14cb823f107

Use "invite_code" column instead of "invite_code" table in function "delete_private_data"
author jbe
date Mon Nov 14 13:48:22 2011 +0100 (2011-11-14)
parents b8fa47ee5d82
children 73d358fe20c7
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@204 949 "draft_id" INT8 NOT NULL,
jbe@0 950 "informed" BOOLEAN NOT NULL,
jbe@0 951 "satisfied" BOOLEAN NOT NULL,
jbe@0 952 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@204 953 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
jbe@0 954 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@0 955 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
jbe@0 956
jbe@8 957 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
jbe@0 958
jbe@0 959 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
jbe@0 960 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
jbe@0 961 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
jbe@0 962
jbe@0 963
jbe@113 964 CREATE TABLE "non_voter" (
jbe@113 965 PRIMARY KEY ("issue_id", "member_id"),
jbe@113 966 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@113 967 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@113 968 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
jbe@113 969
jbe@113 970 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
jbe@113 971
jbe@113 972
jbe@0 973 CREATE TABLE "direct_voter" (
jbe@0 974 PRIMARY KEY ("issue_id", "member_id"),
jbe@0 975 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@45 976 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@169 977 "weight" INT4 );
jbe@0 978 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
jbe@0 979
jbe@10 980 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 981
jbe@0 982 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
jbe@0 983
jbe@0 984
jbe@0 985 CREATE TABLE "delegating_voter" (
jbe@0 986 PRIMARY KEY ("issue_id", "member_id"),
jbe@0 987 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@45 988 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@8 989 "weight" INT4,
jbe@10 990 "scope" "delegation_scope" NOT NULL,
jbe@0 991 "delegate_member_ids" INT4[] NOT NULL );
jbe@52 992 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
jbe@0 993
jbe@0 994 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
jbe@0 995
jbe@0 996 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
jbe@8 997 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
jbe@0 998 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 999
jbe@0 1000
jbe@0 1001 CREATE TABLE "vote" (
jbe@0 1002 "issue_id" INT4 NOT NULL,
jbe@0 1003 PRIMARY KEY ("initiative_id", "member_id"),
jbe@0 1004 "initiative_id" INT4,
jbe@0 1005 "member_id" INT4,
jbe@0 1006 "grade" INT4,
jbe@0 1007 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1008 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@0 1009 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
jbe@0 1010
jbe@10 1011 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 1012
jbe@0 1013 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 1014
jbe@0 1015
jbe@111 1016 CREATE TABLE "issue_comment" (
jbe@111 1017 PRIMARY KEY ("issue_id", "member_id"),
jbe@111 1018 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@111 1019 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@111 1020 "changed" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@111 1021 "formatting_engine" TEXT,
jbe@111 1022 "content" TEXT NOT NULL,
jbe@111 1023 "text_search_data" TSVECTOR );
jbe@111 1024 CREATE INDEX "issue_comment_member_id_idx" ON "issue_comment" ("member_id");
jbe@111 1025 CREATE INDEX "issue_comment_text_search_data_idx" ON "issue_comment" USING gin ("text_search_data");
jbe@111 1026 CREATE TRIGGER "update_text_search_data"
jbe@111 1027 BEFORE INSERT OR UPDATE ON "issue_comment"
jbe@111 1028 FOR EACH ROW EXECUTE PROCEDURE
jbe@111 1029 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
jbe@111 1030
jbe@111 1031 COMMENT ON TABLE "issue_comment" IS 'Place to store free comments of members related to issues';
jbe@111 1032
jbe@111 1033 COMMENT ON COLUMN "issue_comment"."changed" IS 'Time the comment was last changed';
jbe@111 1034
jbe@111 1035
jbe@111 1036 CREATE TABLE "rendered_issue_comment" (
jbe@111 1037 PRIMARY KEY ("issue_id", "member_id", "format"),
jbe@111 1038 FOREIGN KEY ("issue_id", "member_id")
jbe@111 1039 REFERENCES "issue_comment" ("issue_id", "member_id")
jbe@111 1040 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@111 1041 "issue_id" INT4,
jbe@111 1042 "member_id" INT4,
jbe@111 1043 "format" TEXT,
jbe@111 1044 "content" TEXT NOT NULL );
jbe@111 1045
jbe@111 1046 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 1047
jbe@111 1048
jbe@111 1049 CREATE TABLE "voting_comment" (
jbe@111 1050 PRIMARY KEY ("issue_id", "member_id"),
jbe@111 1051 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@111 1052 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@111 1053 "changed" TIMESTAMPTZ,
jbe@111 1054 "formatting_engine" TEXT,
jbe@111 1055 "content" TEXT NOT NULL,
jbe@111 1056 "text_search_data" TSVECTOR );
jbe@111 1057 CREATE INDEX "voting_comment_member_id_idx" ON "voting_comment" ("member_id");
jbe@111 1058 CREATE INDEX "voting_comment_text_search_data_idx" ON "voting_comment" USING gin ("text_search_data");
jbe@111 1059 CREATE TRIGGER "update_text_search_data"
jbe@111 1060 BEFORE INSERT OR UPDATE ON "voting_comment"
jbe@111 1061 FOR EACH ROW EXECUTE PROCEDURE
jbe@111 1062 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
jbe@111 1063
jbe@111 1064 COMMENT ON TABLE "voting_comment" IS 'Storage for comments of voters to be published after voting has finished.';
jbe@111 1065
jbe@111 1066 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 1067
jbe@111 1068
jbe@111 1069 CREATE TABLE "rendered_voting_comment" (
jbe@111 1070 PRIMARY KEY ("issue_id", "member_id", "format"),
jbe@111 1071 FOREIGN KEY ("issue_id", "member_id")
jbe@111 1072 REFERENCES "voting_comment" ("issue_id", "member_id")
jbe@111 1073 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@111 1074 "issue_id" INT4,
jbe@111 1075 "member_id" INT4,
jbe@111 1076 "format" TEXT,
jbe@111 1077 "content" TEXT NOT NULL );
jbe@111 1078
jbe@111 1079 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 1080
jbe@111 1081
jbe@112 1082 CREATE TYPE "event_type" AS ENUM (
jbe@112 1083 'issue_state_changed',
jbe@112 1084 'initiative_created_in_new_issue',
jbe@112 1085 'initiative_created_in_existing_issue',
jbe@112 1086 'initiative_revoked',
jbe@112 1087 'new_draft_created',
jbe@112 1088 'suggestion_created');
jbe@112 1089
jbe@112 1090 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
jbe@112 1091
jbe@112 1092
jbe@112 1093 CREATE TABLE "event" (
jbe@112 1094 "id" SERIAL8 PRIMARY KEY,
jbe@112 1095 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@112 1096 "event" "event_type" NOT NULL,
jbe@112 1097 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@112 1098 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@112 1099 "state" "issue_state" CHECK ("state" != 'calculation'),
jbe@112 1100 "initiative_id" INT4,
jbe@112 1101 "draft_id" INT8,
jbe@112 1102 "suggestion_id" INT8,
jbe@112 1103 FOREIGN KEY ("issue_id", "initiative_id")
jbe@112 1104 REFERENCES "initiative" ("issue_id", "id")
jbe@112 1105 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@112 1106 FOREIGN KEY ("initiative_id", "draft_id")
jbe@112 1107 REFERENCES "draft" ("initiative_id", "id")
jbe@112 1108 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@112 1109 FOREIGN KEY ("initiative_id", "suggestion_id")
jbe@112 1110 REFERENCES "suggestion" ("initiative_id", "id")
jbe@112 1111 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@112 1112 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
jbe@112 1113 "event" != 'issue_state_changed' OR (
jbe@112 1114 "member_id" ISNULL AND
jbe@112 1115 "issue_id" NOTNULL AND
jbe@113 1116 "state" NOTNULL AND
jbe@112 1117 "initiative_id" ISNULL AND
jbe@112 1118 "draft_id" ISNULL AND
jbe@112 1119 "suggestion_id" ISNULL )),
jbe@112 1120 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
jbe@112 1121 "event" NOT IN (
jbe@112 1122 'initiative_created_in_new_issue',
jbe@112 1123 'initiative_created_in_existing_issue',
jbe@112 1124 'initiative_revoked',
jbe@112 1125 'new_draft_created'
jbe@112 1126 ) OR (
jbe@112 1127 "member_id" NOTNULL AND
jbe@112 1128 "issue_id" NOTNULL AND
jbe@113 1129 "state" NOTNULL AND
jbe@112 1130 "initiative_id" NOTNULL AND
jbe@112 1131 "draft_id" NOTNULL AND
jbe@112 1132 "suggestion_id" ISNULL )),
jbe@112 1133 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
jbe@112 1134 "event" != 'suggestion_created' OR (
jbe@112 1135 "member_id" NOTNULL AND
jbe@112 1136 "issue_id" NOTNULL AND
jbe@113 1137 "state" NOTNULL AND
jbe@112 1138 "initiative_id" NOTNULL AND
jbe@112 1139 "draft_id" ISNULL AND
jbe@112 1140 "suggestion_id" NOTNULL )) );
jbe@112 1141
jbe@112 1142 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
jbe@112 1143
jbe@114 1144 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
jbe@114 1145 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
jbe@114 1146 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
jbe@114 1147 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
jbe@114 1148
jbe@112 1149
jbe@112 1150
jbe@112 1151 ----------------------------------------------
jbe@112 1152 -- Writing of history entries and event log --
jbe@112 1153 ----------------------------------------------
jbe@13 1154
jbe@181 1155
jbe@13 1156 CREATE FUNCTION "write_member_history_trigger"()
jbe@13 1157 RETURNS TRIGGER
jbe@13 1158 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@13 1159 BEGIN
jbe@42 1160 IF
jbe@42 1161 NEW."active" != OLD."active" OR
jbe@42 1162 NEW."name" != OLD."name"
jbe@42 1163 THEN
jbe@42 1164 INSERT INTO "member_history"
jbe@57 1165 ("member_id", "active", "name")
jbe@57 1166 VALUES (NEW."id", OLD."active", OLD."name");
jbe@13 1167 END IF;
jbe@13 1168 RETURN NULL;
jbe@13 1169 END;
jbe@13 1170 $$;
jbe@13 1171
jbe@13 1172 CREATE TRIGGER "write_member_history"
jbe@13 1173 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
jbe@13 1174 "write_member_history_trigger"();
jbe@13 1175
jbe@13 1176 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
jbe@57 1177 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 1178
jbe@13 1179
jbe@112 1180 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
jbe@112 1181 RETURNS TRIGGER
jbe@112 1182 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@112 1183 BEGIN
jbe@112 1184 IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
jbe@112 1185 INSERT INTO "event" ("event", "issue_id", "state")
jbe@112 1186 VALUES ('issue_state_changed', NEW."id", NEW."state");
jbe@112 1187 END IF;
jbe@112 1188 RETURN NULL;
jbe@112 1189 END;
jbe@112 1190 $$;
jbe@112 1191
jbe@112 1192 CREATE TRIGGER "write_event_issue_state_changed"
jbe@112 1193 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 1194 "write_event_issue_state_changed_trigger"();
jbe@112 1195
jbe@112 1196 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
jbe@112 1197 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
jbe@112 1198
jbe@112 1199
jbe@112 1200 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
jbe@112 1201 RETURNS TRIGGER
jbe@112 1202 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@112 1203 DECLARE
jbe@112 1204 "initiative_row" "initiative"%ROWTYPE;
jbe@113 1205 "issue_row" "issue"%ROWTYPE;
jbe@112 1206 "event_v" "event_type";
jbe@112 1207 BEGIN
jbe@112 1208 SELECT * INTO "initiative_row" FROM "initiative"
jbe@112 1209 WHERE "id" = NEW."initiative_id";
jbe@113 1210 SELECT * INTO "issue_row" FROM "issue"
jbe@113 1211 WHERE "id" = "initiative_row"."issue_id";
jbe@112 1212 IF EXISTS (
jbe@112 1213 SELECT NULL FROM "draft"
jbe@112 1214 WHERE "initiative_id" = NEW."initiative_id"
jbe@112 1215 AND "id" != NEW."id"
jbe@112 1216 ) THEN
jbe@112 1217 "event_v" := 'new_draft_created';
jbe@112 1218 ELSE
jbe@112 1219 IF EXISTS (
jbe@112 1220 SELECT NULL FROM "initiative"
jbe@112 1221 WHERE "issue_id" = "initiative_row"."issue_id"
jbe@112 1222 AND "id" != "initiative_row"."id"
jbe@112 1223 ) THEN
jbe@112 1224 "event_v" := 'initiative_created_in_existing_issue';
jbe@112 1225 ELSE
jbe@112 1226 "event_v" := 'initiative_created_in_new_issue';
jbe@112 1227 END IF;
jbe@112 1228 END IF;
jbe@112 1229 INSERT INTO "event" (
jbe@112 1230 "event", "member_id",
jbe@113 1231 "issue_id", "state", "initiative_id", "draft_id"
jbe@112 1232 ) VALUES (
jbe@112 1233 "event_v",
jbe@112 1234 NEW."author_id",
jbe@112 1235 "initiative_row"."issue_id",
jbe@113 1236 "issue_row"."state",
jbe@112 1237 "initiative_row"."id",
jbe@112 1238 NEW."id" );
jbe@112 1239 RETURN NULL;
jbe@112 1240 END;
jbe@112 1241 $$;
jbe@112 1242
jbe@112 1243 CREATE TRIGGER "write_event_initiative_or_draft_created"
jbe@112 1244 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 1245 "write_event_initiative_or_draft_created_trigger"();
jbe@112 1246
jbe@112 1247 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 1248 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
jbe@112 1249
jbe@112 1250
jbe@112 1251 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
jbe@112 1252 RETURNS TRIGGER
jbe@112 1253 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@113 1254 DECLARE
jbe@113 1255 "issue_row" "issue"%ROWTYPE;
jbe@112 1256 BEGIN
jbe@113 1257 SELECT * INTO "issue_row" FROM "issue"
jbe@113 1258 WHERE "id" = NEW."issue_id";
jbe@112 1259 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
jbe@112 1260 INSERT INTO "event" (
jbe@113 1261 "event", "member_id", "issue_id", "state", "initiative_id"
jbe@112 1262 ) VALUES (
jbe@112 1263 'initiative_revoked',
jbe@112 1264 NEW."revoked_by_member_id",
jbe@112 1265 NEW."issue_id",
jbe@113 1266 "issue_row"."state",
jbe@112 1267 NEW."id" );
jbe@112 1268 END IF;
jbe@112 1269 RETURN NULL;
jbe@112 1270 END;
jbe@112 1271 $$;
jbe@112 1272
jbe@112 1273 CREATE TRIGGER "write_event_initiative_revoked"
jbe@112 1274 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 1275 "write_event_initiative_revoked_trigger"();
jbe@112 1276
jbe@112 1277 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
jbe@112 1278 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
jbe@112 1279
jbe@112 1280
jbe@112 1281 CREATE FUNCTION "write_event_suggestion_created_trigger"()
jbe@112 1282 RETURNS TRIGGER
jbe@112 1283 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@112 1284 DECLARE
jbe@112 1285 "initiative_row" "initiative"%ROWTYPE;
jbe@113 1286 "issue_row" "issue"%ROWTYPE;
jbe@112 1287 BEGIN
jbe@112 1288 SELECT * INTO "initiative_row" FROM "initiative"
jbe@112 1289 WHERE "id" = NEW."initiative_id";
jbe@113 1290 SELECT * INTO "issue_row" FROM "issue"
jbe@113 1291 WHERE "id" = "initiative_row"."issue_id";
jbe@112 1292 INSERT INTO "event" (
jbe@112 1293 "event", "member_id",
jbe@113 1294 "issue_id", "state", "initiative_id", "suggestion_id"
jbe@112 1295 ) VALUES (
jbe@112 1296 'suggestion_created',
jbe@112 1297 NEW."author_id",
jbe@112 1298 "initiative_row"."issue_id",
jbe@113 1299 "issue_row"."state",
jbe@112 1300 "initiative_row"."id",
jbe@112 1301 NEW."id" );
jbe@112 1302 RETURN NULL;
jbe@112 1303 END;
jbe@112 1304 $$;
jbe@112 1305
jbe@112 1306 CREATE TRIGGER "write_event_suggestion_created"
jbe@112 1307 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 1308 "write_event_suggestion_created_trigger"();
jbe@112 1309
jbe@112 1310 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
jbe@112 1311 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
jbe@112 1312
jbe@112 1313
jbe@13 1314
jbe@0 1315 ----------------------------
jbe@0 1316 -- Additional constraints --
jbe@0 1317 ----------------------------
jbe@0 1318
jbe@0 1319
jbe@0 1320 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
jbe@0 1321 RETURNS TRIGGER
jbe@0 1322 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1323 BEGIN
jbe@0 1324 IF NOT EXISTS (
jbe@0 1325 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
jbe@0 1326 ) THEN
jbe@0 1327 --RAISE 'Cannot create issue without an initial initiative.' USING
jbe@0 1328 -- ERRCODE = 'integrity_constraint_violation',
jbe@0 1329 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
jbe@0 1330 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
jbe@0 1331 END IF;
jbe@0 1332 RETURN NULL;
jbe@0 1333 END;
jbe@0 1334 $$;
jbe@0 1335
jbe@0 1336 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
jbe@0 1337 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
jbe@0 1338 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 1339 "issue_requires_first_initiative_trigger"();
jbe@0 1340
jbe@0 1341 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
jbe@0 1342 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
jbe@0 1343
jbe@0 1344
jbe@0 1345 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
jbe@0 1346 RETURNS TRIGGER
jbe@0 1347 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1348 DECLARE
jbe@0 1349 "reference_lost" BOOLEAN;
jbe@0 1350 BEGIN
jbe@0 1351 IF TG_OP = 'DELETE' THEN
jbe@0 1352 "reference_lost" := TRUE;
jbe@0 1353 ELSE
jbe@0 1354 "reference_lost" := NEW."issue_id" != OLD."issue_id";
jbe@0 1355 END IF;
jbe@0 1356 IF
jbe@0 1357 "reference_lost" AND NOT EXISTS (
jbe@0 1358 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
jbe@0 1359 )
jbe@0 1360 THEN
jbe@0 1361 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
jbe@0 1362 END IF;
jbe@0 1363 RETURN NULL;
jbe@0 1364 END;
jbe@0 1365 $$;
jbe@0 1366
jbe@0 1367 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
jbe@0 1368 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
jbe@0 1369 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 1370 "last_initiative_deletes_issue_trigger"();
jbe@0 1371
jbe@0 1372 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
jbe@0 1373 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
jbe@0 1374
jbe@0 1375
jbe@0 1376 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
jbe@0 1377 RETURNS TRIGGER
jbe@0 1378 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1379 BEGIN
jbe@0 1380 IF NOT EXISTS (
jbe@0 1381 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
jbe@0 1382 ) THEN
jbe@0 1383 --RAISE 'Cannot create initiative without an initial draft.' USING
jbe@0 1384 -- ERRCODE = 'integrity_constraint_violation',
jbe@0 1385 -- HINT = 'Create issue, initiative and draft within the same transaction.';
jbe@0 1386 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
jbe@0 1387 END IF;
jbe@0 1388 RETURN NULL;
jbe@0 1389 END;
jbe@0 1390 $$;
jbe@0 1391
jbe@0 1392 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
jbe@0 1393 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
jbe@0 1394 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 1395 "initiative_requires_first_draft_trigger"();
jbe@0 1396
jbe@0 1397 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
jbe@0 1398 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
jbe@0 1399
jbe@0 1400
jbe@0 1401 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
jbe@0 1402 RETURNS TRIGGER
jbe@0 1403 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1404 DECLARE
jbe@0 1405 "reference_lost" BOOLEAN;
jbe@0 1406 BEGIN
jbe@0 1407 IF TG_OP = 'DELETE' THEN
jbe@0 1408 "reference_lost" := TRUE;
jbe@0 1409 ELSE
jbe@0 1410 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
jbe@0 1411 END IF;
jbe@0 1412 IF
jbe@0 1413 "reference_lost" AND NOT EXISTS (
jbe@0 1414 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
jbe@0 1415 )
jbe@0 1416 THEN
jbe@0 1417 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
jbe@0 1418 END IF;
jbe@0 1419 RETURN NULL;
jbe@0 1420 END;
jbe@0 1421 $$;
jbe@0 1422
jbe@0 1423 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
jbe@0 1424 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
jbe@0 1425 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 1426 "last_draft_deletes_initiative_trigger"();
jbe@0 1427
jbe@0 1428 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
jbe@0 1429 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
jbe@0 1430
jbe@0 1431
jbe@0 1432 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
jbe@0 1433 RETURNS TRIGGER
jbe@0 1434 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1435 BEGIN
jbe@0 1436 IF NOT EXISTS (
jbe@0 1437 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
jbe@0 1438 ) THEN
jbe@0 1439 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
jbe@0 1440 END IF;
jbe@0 1441 RETURN NULL;
jbe@0 1442 END;
jbe@0 1443 $$;
jbe@0 1444
jbe@0 1445 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
jbe@0 1446 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
jbe@0 1447 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 1448 "suggestion_requires_first_opinion_trigger"();
jbe@0 1449
jbe@0 1450 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
jbe@0 1451 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
jbe@0 1452
jbe@0 1453
jbe@0 1454 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
jbe@0 1455 RETURNS TRIGGER
jbe@0 1456 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1457 DECLARE
jbe@0 1458 "reference_lost" BOOLEAN;
jbe@0 1459 BEGIN
jbe@0 1460 IF TG_OP = 'DELETE' THEN
jbe@0 1461 "reference_lost" := TRUE;
jbe@0 1462 ELSE
jbe@0 1463 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
jbe@0 1464 END IF;
jbe@0 1465 IF
jbe@0 1466 "reference_lost" AND NOT EXISTS (
jbe@0 1467 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
jbe@0 1468 )
jbe@0 1469 THEN
jbe@0 1470 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
jbe@0 1471 END IF;
jbe@0 1472 RETURN NULL;
jbe@0 1473 END;
jbe@0 1474 $$;
jbe@0 1475
jbe@0 1476 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
jbe@0 1477 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
jbe@0 1478 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 1479 "last_opinion_deletes_suggestion_trigger"();
jbe@0 1480
jbe@0 1481 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
jbe@0 1482 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
jbe@0 1483
jbe@0 1484
jbe@0 1485
jbe@20 1486 ---------------------------------------------------------------
jbe@20 1487 -- Ensure that votes are not modified when issues are frozen --
jbe@20 1488 ---------------------------------------------------------------
jbe@20 1489
jbe@20 1490 -- NOTE: Frontends should ensure this anyway, but in case of programming
jbe@20 1491 -- errors the following triggers ensure data integrity.
jbe@20 1492
jbe@20 1493
jbe@20 1494 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
jbe@20 1495 RETURNS TRIGGER
jbe@20 1496 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@20 1497 DECLARE
jbe@32 1498 "issue_id_v" "issue"."id"%TYPE;
jbe@32 1499 "issue_row" "issue"%ROWTYPE;
jbe@20 1500 BEGIN
jbe@32 1501 IF TG_OP = 'DELETE' THEN
jbe@32 1502 "issue_id_v" := OLD."issue_id";
jbe@32 1503 ELSE
jbe@32 1504 "issue_id_v" := NEW."issue_id";
jbe@32 1505 END IF;
jbe@20 1506 SELECT INTO "issue_row" * FROM "issue"
jbe@32 1507 WHERE "id" = "issue_id_v" FOR SHARE;
jbe@20 1508 IF "issue_row"."closed" NOTNULL THEN
jbe@20 1509 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
jbe@20 1510 END IF;
jbe@20 1511 RETURN NULL;
jbe@20 1512 END;
jbe@20 1513 $$;
jbe@20 1514
jbe@20 1515 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 1516 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
jbe@20 1517 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 1518 "forbid_changes_on_closed_issue_trigger"();
jbe@20 1519
jbe@20 1520 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 1521 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
jbe@20 1522 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 1523 "forbid_changes_on_closed_issue_trigger"();
jbe@20 1524
jbe@20 1525 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 1526 AFTER INSERT OR UPDATE OR DELETE ON "vote"
jbe@20 1527 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 1528 "forbid_changes_on_closed_issue_trigger"();
jbe@20 1529
jbe@20 1530 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 1531 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 1532 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 1533 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 1534
jbe@20 1535
jbe@20 1536
jbe@0 1537 --------------------------------------------------------------------
jbe@0 1538 -- Auto-retrieval of fields only needed for referential integrity --
jbe@0 1539 --------------------------------------------------------------------
jbe@0 1540
jbe@20 1541
jbe@0 1542 CREATE FUNCTION "autofill_issue_id_trigger"()
jbe@0 1543 RETURNS TRIGGER
jbe@0 1544 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1545 BEGIN
jbe@0 1546 IF NEW."issue_id" ISNULL THEN
jbe@0 1547 SELECT "issue_id" INTO NEW."issue_id"
jbe@0 1548 FROM "initiative" WHERE "id" = NEW."initiative_id";
jbe@0 1549 END IF;
jbe@0 1550 RETURN NEW;
jbe@0 1551 END;
jbe@0 1552 $$;
jbe@0 1553
jbe@0 1554 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
jbe@0 1555 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
jbe@0 1556
jbe@0 1557 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
jbe@0 1558 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
jbe@0 1559
jbe@0 1560 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
jbe@0 1561 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
jbe@0 1562 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
jbe@0 1563
jbe@0 1564
jbe@0 1565 CREATE FUNCTION "autofill_initiative_id_trigger"()
jbe@0 1566 RETURNS TRIGGER
jbe@0 1567 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1568 BEGIN
jbe@0 1569 IF NEW."initiative_id" ISNULL THEN
jbe@0 1570 SELECT "initiative_id" INTO NEW."initiative_id"
jbe@0 1571 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
jbe@0 1572 END IF;
jbe@0 1573 RETURN NEW;
jbe@0 1574 END;
jbe@0 1575 $$;
jbe@0 1576
jbe@0 1577 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
jbe@0 1578 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
jbe@0 1579
jbe@0 1580 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
jbe@0 1581 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
jbe@0 1582
jbe@0 1583
jbe@0 1584
jbe@4 1585 -----------------------------------------------------
jbe@4 1586 -- Automatic calculation of certain default values --
jbe@4 1587 -----------------------------------------------------
jbe@0 1588
jbe@22 1589
jbe@22 1590 CREATE FUNCTION "copy_timings_trigger"()
jbe@22 1591 RETURNS TRIGGER
jbe@22 1592 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@22 1593 DECLARE
jbe@22 1594 "policy_row" "policy"%ROWTYPE;
jbe@22 1595 BEGIN
jbe@22 1596 SELECT * INTO "policy_row" FROM "policy"
jbe@22 1597 WHERE "id" = NEW."policy_id";
jbe@22 1598 IF NEW."admission_time" ISNULL THEN
jbe@22 1599 NEW."admission_time" := "policy_row"."admission_time";
jbe@22 1600 END IF;
jbe@22 1601 IF NEW."discussion_time" ISNULL THEN
jbe@22 1602 NEW."discussion_time" := "policy_row"."discussion_time";
jbe@22 1603 END IF;
jbe@22 1604 IF NEW."verification_time" ISNULL THEN
jbe@22 1605 NEW."verification_time" := "policy_row"."verification_time";
jbe@22 1606 END IF;
jbe@22 1607 IF NEW."voting_time" ISNULL THEN
jbe@22 1608 NEW."voting_time" := "policy_row"."voting_time";
jbe@22 1609 END IF;
jbe@22 1610 RETURN NEW;
jbe@22 1611 END;
jbe@22 1612 $$;
jbe@22 1613
jbe@22 1614 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
jbe@22 1615 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
jbe@22 1616
jbe@22 1617 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
jbe@22 1618 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
jbe@22 1619
jbe@22 1620
jbe@160 1621 CREATE FUNCTION "default_for_draft_id_trigger"()
jbe@2 1622 RETURNS TRIGGER
jbe@2 1623 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@2 1624 BEGIN
jbe@2 1625 IF NEW."draft_id" ISNULL THEN
jbe@2 1626 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
jbe@2 1627 WHERE "initiative_id" = NEW."initiative_id";
jbe@2 1628 END IF;
jbe@2 1629 RETURN NEW;
jbe@2 1630 END;
jbe@2 1631 $$;
jbe@2 1632
jbe@160 1633 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
jbe@160 1634 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
jbe@2 1635 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
jbe@160 1636 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
jbe@160 1637
jbe@160 1638 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
jbe@160 1639 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 1640 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 1641
jbe@2 1642
jbe@0 1643
jbe@0 1644 ----------------------------------------
jbe@0 1645 -- Automatic creation of dependencies --
jbe@0 1646 ----------------------------------------
jbe@0 1647
jbe@22 1648
jbe@0 1649 CREATE FUNCTION "autocreate_interest_trigger"()
jbe@0 1650 RETURNS TRIGGER
jbe@0 1651 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1652 BEGIN
jbe@0 1653 IF NOT EXISTS (
jbe@0 1654 SELECT NULL FROM "initiative" JOIN "interest"
jbe@0 1655 ON "initiative"."issue_id" = "interest"."issue_id"
jbe@0 1656 WHERE "initiative"."id" = NEW."initiative_id"
jbe@0 1657 AND "interest"."member_id" = NEW."member_id"
jbe@0 1658 ) THEN
jbe@0 1659 BEGIN
jbe@0 1660 INSERT INTO "interest" ("issue_id", "member_id")
jbe@0 1661 SELECT "issue_id", NEW."member_id"
jbe@0 1662 FROM "initiative" WHERE "id" = NEW."initiative_id";
jbe@0 1663 EXCEPTION WHEN unique_violation THEN END;
jbe@0 1664 END IF;
jbe@0 1665 RETURN NEW;
jbe@0 1666 END;
jbe@0 1667 $$;
jbe@0 1668
jbe@0 1669 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
jbe@0 1670 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
jbe@0 1671
jbe@0 1672 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
jbe@0 1673 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 1674
jbe@0 1675
jbe@0 1676 CREATE FUNCTION "autocreate_supporter_trigger"()
jbe@0 1677 RETURNS TRIGGER
jbe@0 1678 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1679 BEGIN
jbe@0 1680 IF NOT EXISTS (
jbe@0 1681 SELECT NULL FROM "suggestion" JOIN "supporter"
jbe@0 1682 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
jbe@0 1683 WHERE "suggestion"."id" = NEW."suggestion_id"
jbe@0 1684 AND "supporter"."member_id" = NEW."member_id"
jbe@0 1685 ) THEN
jbe@0 1686 BEGIN
jbe@0 1687 INSERT INTO "supporter" ("initiative_id", "member_id")
jbe@0 1688 SELECT "initiative_id", NEW."member_id"
jbe@0 1689 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
jbe@0 1690 EXCEPTION WHEN unique_violation THEN END;
jbe@0 1691 END IF;
jbe@0 1692 RETURN NEW;
jbe@0 1693 END;
jbe@0 1694 $$;
jbe@0 1695
jbe@0 1696 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
jbe@0 1697 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
jbe@0 1698
jbe@0 1699 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
jbe@0 1700 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 1701
jbe@0 1702
jbe@0 1703
jbe@0 1704 ------------------------------------------
jbe@0 1705 -- Views and helper functions for views --
jbe@0 1706 ------------------------------------------
jbe@0 1707
jbe@5 1708
jbe@97 1709 CREATE VIEW "unit_delegation" AS
jbe@97 1710 SELECT
jbe@97 1711 "unit"."id" AS "unit_id",
jbe@97 1712 "delegation"."id",
jbe@97 1713 "delegation"."truster_id",
jbe@97 1714 "delegation"."trustee_id",
jbe@97 1715 "delegation"."scope"
jbe@97 1716 FROM "unit"
jbe@97 1717 JOIN "delegation"
jbe@97 1718 ON "delegation"."unit_id" = "unit"."id"
jbe@97 1719 JOIN "member"
jbe@97 1720 ON "delegation"."truster_id" = "member"."id"
jbe@97 1721 JOIN "privilege"
jbe@97 1722 ON "delegation"."unit_id" = "privilege"."unit_id"
jbe@97 1723 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@97 1724 WHERE "member"."active" AND "privilege"."voting_right";
jbe@97 1725
jbe@97 1726 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
jbe@5 1727
jbe@5 1728
jbe@5 1729 CREATE VIEW "area_delegation" AS
jbe@70 1730 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
jbe@70 1731 "area"."id" AS "area_id",
jbe@70 1732 "delegation"."id",
jbe@70 1733 "delegation"."truster_id",
jbe@70 1734 "delegation"."trustee_id",
jbe@70 1735 "delegation"."scope"
jbe@97 1736 FROM "area"
jbe@97 1737 JOIN "delegation"
jbe@97 1738 ON "delegation"."unit_id" = "area"."unit_id"
jbe@97 1739 OR "delegation"."area_id" = "area"."id"
jbe@97 1740 JOIN "member"
jbe@97 1741 ON "delegation"."truster_id" = "member"."id"
jbe@97 1742 JOIN "privilege"
jbe@97 1743 ON "area"."unit_id" = "privilege"."unit_id"
jbe@97 1744 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@97 1745 WHERE "member"."active" AND "privilege"."voting_right"
jbe@70 1746 ORDER BY
jbe@70 1747 "area"."id",
jbe@70 1748 "delegation"."truster_id",
jbe@70 1749 "delegation"."scope" DESC;
jbe@70 1750
jbe@97 1751 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
jbe@5 1752
jbe@5 1753
jbe@5 1754 CREATE VIEW "issue_delegation" AS
jbe@70 1755 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
jbe@70 1756 "issue"."id" AS "issue_id",
jbe@70 1757 "delegation"."id",
jbe@70 1758 "delegation"."truster_id",
jbe@70 1759 "delegation"."trustee_id",
jbe@70 1760 "delegation"."scope"
jbe@97 1761 FROM "issue"
jbe@97 1762 JOIN "area"
jbe@97 1763 ON "area"."id" = "issue"."area_id"
jbe@97 1764 JOIN "delegation"
jbe@97 1765 ON "delegation"."unit_id" = "area"."unit_id"
jbe@97 1766 OR "delegation"."area_id" = "area"."id"
jbe@97 1767 OR "delegation"."issue_id" = "issue"."id"
jbe@97 1768 JOIN "member"
jbe@97 1769 ON "delegation"."truster_id" = "member"."id"
jbe@97 1770 JOIN "privilege"
jbe@97 1771 ON "area"."unit_id" = "privilege"."unit_id"
jbe@97 1772 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@97 1773 WHERE "member"."active" AND "privilege"."voting_right"
jbe@70 1774 ORDER BY
jbe@70 1775 "issue"."id",
jbe@70 1776 "delegation"."truster_id",
jbe@70 1777 "delegation"."scope" DESC;
jbe@70 1778
jbe@97 1779 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
jbe@5 1780
jbe@5 1781
jbe@5 1782 CREATE FUNCTION "membership_weight_with_skipping"
jbe@5 1783 ( "area_id_p" "area"."id"%TYPE,
jbe@5 1784 "member_id_p" "member"."id"%TYPE,
jbe@5 1785 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
jbe@5 1786 RETURNS INT4
jbe@5 1787 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 1788 DECLARE
jbe@5 1789 "sum_v" INT4;
jbe@5 1790 "delegation_row" "area_delegation"%ROWTYPE;
jbe@5 1791 BEGIN
jbe@5 1792 "sum_v" := 1;
jbe@5 1793 FOR "delegation_row" IN
jbe@5 1794 SELECT "area_delegation".*
jbe@5 1795 FROM "area_delegation" LEFT JOIN "membership"
jbe@5 1796 ON "membership"."area_id" = "area_id_p"
jbe@5 1797 AND "membership"."member_id" = "area_delegation"."truster_id"
jbe@5 1798 WHERE "area_delegation"."area_id" = "area_id_p"
jbe@5 1799 AND "area_delegation"."trustee_id" = "member_id_p"
jbe@5 1800 AND "membership"."member_id" ISNULL
jbe@5 1801 LOOP
jbe@5 1802 IF NOT
jbe@5 1803 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
jbe@5 1804 THEN
jbe@5 1805 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
jbe@5 1806 "area_id_p",
jbe@5 1807 "delegation_row"."truster_id",
jbe@5 1808 "skip_member_ids_p" || "delegation_row"."truster_id"
jbe@5 1809 );
jbe@5 1810 END IF;
jbe@5 1811 END LOOP;
jbe@5 1812 RETURN "sum_v";
jbe@5 1813 END;
jbe@5 1814 $$;
jbe@5 1815
jbe@8 1816 COMMENT ON FUNCTION "membership_weight_with_skipping"
jbe@8 1817 ( "area"."id"%TYPE,
jbe@8 1818 "member"."id"%TYPE,
jbe@8 1819 INT4[] )
jbe@8 1820 IS 'Helper function for "membership_weight" function';
jbe@8 1821
jbe@8 1822
jbe@5 1823 CREATE FUNCTION "membership_weight"
jbe@5 1824 ( "area_id_p" "area"."id"%TYPE,
jbe@5 1825 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
jbe@5 1826 RETURNS INT4
jbe@5 1827 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 1828 BEGIN
jbe@5 1829 RETURN "membership_weight_with_skipping"(
jbe@5 1830 "area_id_p",
jbe@5 1831 "member_id_p",
jbe@5 1832 ARRAY["member_id_p"]
jbe@5 1833 );
jbe@5 1834 END;
jbe@5 1835 $$;
jbe@5 1836
jbe@8 1837 COMMENT ON FUNCTION "membership_weight"
jbe@8 1838 ( "area"."id"%TYPE,
jbe@8 1839 "member"."id"%TYPE )
jbe@8 1840 IS 'Calculates the potential voting weight of a member in a given area';
jbe@8 1841
jbe@5 1842
jbe@4 1843 CREATE VIEW "member_count_view" AS
jbe@5 1844 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
jbe@4 1845
jbe@4 1846 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
jbe@4 1847
jbe@4 1848
jbe@97 1849 CREATE VIEW "unit_member_count" AS
jbe@97 1850 SELECT
jbe@97 1851 "unit"."id" AS "unit_id",
jbe@97 1852 sum("member"."id") AS "member_count"
jbe@97 1853 FROM "unit"
jbe@97 1854 LEFT JOIN "privilege"
jbe@97 1855 ON "privilege"."unit_id" = "unit"."id"
jbe@97 1856 AND "privilege"."voting_right"
jbe@97 1857 LEFT JOIN "member"
jbe@97 1858 ON "member"."id" = "privilege"."member_id"
jbe@97 1859 AND "member"."active"
jbe@97 1860 GROUP BY "unit"."id";
jbe@97 1861
jbe@97 1862 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
jbe@97 1863
jbe@97 1864
jbe@4 1865 CREATE VIEW "area_member_count" AS
jbe@5 1866 SELECT
jbe@5 1867 "area"."id" AS "area_id",
jbe@5 1868 count("member"."id") AS "direct_member_count",
jbe@5 1869 coalesce(
jbe@5 1870 sum(
jbe@5 1871 CASE WHEN "member"."id" NOTNULL THEN
jbe@5 1872 "membership_weight"("area"."id", "member"."id")
jbe@5 1873 ELSE 0 END
jbe@5 1874 )
jbe@169 1875 ) AS "member_weight"
jbe@4 1876 FROM "area"
jbe@4 1877 LEFT JOIN "membership"
jbe@4 1878 ON "area"."id" = "membership"."area_id"
jbe@97 1879 LEFT JOIN "privilege"
jbe@97 1880 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 1881 AND "privilege"."member_id" = "membership"."member_id"
jbe@97 1882 AND "privilege"."voting_right"
jbe@4 1883 LEFT JOIN "member"
jbe@97 1884 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
jbe@4 1885 AND "member"."active"
jbe@4 1886 GROUP BY "area"."id";
jbe@4 1887
jbe@169 1888 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
jbe@4 1889
jbe@4 1890
jbe@9 1891 CREATE VIEW "opening_draft" AS
jbe@9 1892 SELECT "draft".* FROM (
jbe@9 1893 SELECT
jbe@9 1894 "initiative"."id" AS "initiative_id",
jbe@9 1895 min("draft"."id") AS "draft_id"
jbe@9 1896 FROM "initiative" JOIN "draft"
jbe@9 1897 ON "initiative"."id" = "draft"."initiative_id"
jbe@9 1898 GROUP BY "initiative"."id"
jbe@9 1899 ) AS "subquery"
jbe@9 1900 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
jbe@9 1901
jbe@9 1902 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
jbe@9 1903
jbe@9 1904
jbe@0 1905 CREATE VIEW "current_draft" AS
jbe@0 1906 SELECT "draft".* FROM (
jbe@0 1907 SELECT
jbe@0 1908 "initiative"."id" AS "initiative_id",
jbe@0 1909 max("draft"."id") AS "draft_id"
jbe@0 1910 FROM "initiative" JOIN "draft"
jbe@0 1911 ON "initiative"."id" = "draft"."initiative_id"
jbe@0 1912 GROUP BY "initiative"."id"
jbe@0 1913 ) AS "subquery"
jbe@0 1914 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
jbe@0 1915
jbe@0 1916 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
jbe@0 1917
jbe@0 1918
jbe@0 1919 CREATE VIEW "critical_opinion" AS
jbe@0 1920 SELECT * FROM "opinion"
jbe@0 1921 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
jbe@0 1922 OR ("degree" = -2 AND "fulfilled" = TRUE);
jbe@0 1923
jbe@0 1924 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
jbe@0 1925
jbe@0 1926
jbe@126 1927 CREATE VIEW "battle_participant" AS
jbe@126 1928 SELECT "initiative"."id", "initiative"."issue_id"
jbe@126 1929 FROM "issue" JOIN "initiative"
jbe@126 1930 ON "issue"."id" = "initiative"."issue_id"
jbe@126 1931 WHERE "initiative"."admitted"
jbe@126 1932 UNION ALL
jbe@126 1933 SELECT NULL, "id" AS "issue_id"
jbe@126 1934 FROM "issue";
jbe@126 1935
jbe@126 1936 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 1937
jbe@126 1938
jbe@61 1939 CREATE VIEW "battle_view" AS
jbe@0 1940 SELECT
jbe@0 1941 "issue"."id" AS "issue_id",
jbe@10 1942 "winning_initiative"."id" AS "winning_initiative_id",
jbe@10 1943 "losing_initiative"."id" AS "losing_initiative_id",
jbe@0 1944 sum(
jbe@0 1945 CASE WHEN
jbe@0 1946 coalesce("better_vote"."grade", 0) >
jbe@0 1947 coalesce("worse_vote"."grade", 0)
jbe@0 1948 THEN "direct_voter"."weight" ELSE 0 END
jbe@0 1949 ) AS "count"
jbe@0 1950 FROM "issue"
jbe@0 1951 LEFT JOIN "direct_voter"
jbe@0 1952 ON "issue"."id" = "direct_voter"."issue_id"
jbe@126 1953 JOIN "battle_participant" AS "winning_initiative"
jbe@10 1954 ON "issue"."id" = "winning_initiative"."issue_id"
jbe@126 1955 JOIN "battle_participant" AS "losing_initiative"
jbe@10 1956 ON "issue"."id" = "losing_initiative"."issue_id"
jbe@0 1957 LEFT JOIN "vote" AS "better_vote"
jbe@10 1958 ON "direct_voter"."member_id" = "better_vote"."member_id"
jbe@10 1959 AND "winning_initiative"."id" = "better_vote"."initiative_id"
jbe@0 1960 LEFT JOIN "vote" AS "worse_vote"
jbe@10 1961 ON "direct_voter"."member_id" = "worse_vote"."member_id"
jbe@10 1962 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
jbe@61 1963 WHERE "issue"."closed" NOTNULL
jbe@61 1964 AND "issue"."cleaned" ISNULL
jbe@126 1965 AND (
jbe@126 1966 "winning_initiative"."id" != "losing_initiative"."id" OR
jbe@126 1967 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
jbe@126 1968 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
jbe@0 1969 GROUP BY
jbe@0 1970 "issue"."id",
jbe@10 1971 "winning_initiative"."id",
jbe@10 1972 "losing_initiative"."id";
jbe@0 1973
jbe@126 1974 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 1975
jbe@1 1976
jbe@0 1977 CREATE VIEW "open_issue" AS
jbe@0 1978 SELECT * FROM "issue" WHERE "closed" ISNULL;
jbe@0 1979
jbe@0 1980 COMMENT ON VIEW "open_issue" IS 'All open issues';
jbe@0 1981
jbe@0 1982
jbe@0 1983 CREATE VIEW "issue_with_ranks_missing" AS
jbe@0 1984 SELECT * FROM "issue"
jbe@3 1985 WHERE "fully_frozen" NOTNULL
jbe@0 1986 AND "closed" NOTNULL
jbe@0 1987 AND "ranks_available" = FALSE;
jbe@0 1988
jbe@0 1989 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
jbe@0 1990
jbe@0 1991
jbe@9 1992 CREATE VIEW "member_contingent" AS
jbe@9 1993 SELECT
jbe@9 1994 "member"."id" AS "member_id",
jbe@9 1995 "contingent"."time_frame",
jbe@9 1996 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
jbe@9 1997 (
jbe@9 1998 SELECT count(1) FROM "draft"
jbe@9 1999 WHERE "draft"."author_id" = "member"."id"
jbe@9 2000 AND "draft"."created" > now() - "contingent"."time_frame"
jbe@9 2001 ) + (
jbe@9 2002 SELECT count(1) FROM "suggestion"
jbe@9 2003 WHERE "suggestion"."author_id" = "member"."id"
jbe@9 2004 AND "suggestion"."created" > now() - "contingent"."time_frame"
jbe@9 2005 )
jbe@9 2006 ELSE NULL END AS "text_entry_count",
jbe@9 2007 "contingent"."text_entry_limit",
jbe@9 2008 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
jbe@9 2009 SELECT count(1) FROM "opening_draft"
jbe@9 2010 WHERE "opening_draft"."author_id" = "member"."id"
jbe@9 2011 AND "opening_draft"."created" > now() - "contingent"."time_frame"
jbe@9 2012 ) ELSE NULL END AS "initiative_count",
jbe@9 2013 "contingent"."initiative_limit"
jbe@9 2014 FROM "member" CROSS JOIN "contingent";
jbe@9 2015
jbe@9 2016 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 2017
jbe@9 2018 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
jbe@9 2019 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
jbe@9 2020
jbe@9 2021
jbe@9 2022 CREATE VIEW "member_contingent_left" AS
jbe@9 2023 SELECT
jbe@9 2024 "member_id",
jbe@9 2025 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
jbe@9 2026 max("initiative_limit" - "initiative_count") AS "initiatives_left"
jbe@9 2027 FROM "member_contingent" GROUP BY "member_id";
jbe@9 2028
jbe@9 2029 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 2030
jbe@9 2031
jbe@113 2032 CREATE VIEW "event_seen_by_member" AS
jbe@113 2033 SELECT
jbe@113 2034 "member"."id" AS "seen_by_member_id",
jbe@113 2035 CASE WHEN "event"."state" IN (
jbe@113 2036 'voting',
jbe@113 2037 'finished_without_winner',
jbe@113 2038 'finished_with_winner'
jbe@113 2039 ) THEN
jbe@113 2040 'voting'::"notify_level"
jbe@113 2041 ELSE
jbe@113 2042 CASE WHEN "event"."state" IN (
jbe@113 2043 'verification',
jbe@113 2044 'canceled_after_revocation_during_verification',
jbe@113 2045 'canceled_no_initiative_admitted'
jbe@113 2046 ) THEN
jbe@113 2047 'verification'::"notify_level"
jbe@113 2048 ELSE
jbe@113 2049 CASE WHEN "event"."state" IN (
jbe@113 2050 'discussion',
jbe@113 2051 'canceled_after_revocation_during_discussion'
jbe@113 2052 ) THEN
jbe@113 2053 'discussion'::"notify_level"
jbe@113 2054 ELSE
jbe@113 2055 'all'::"notify_level"
jbe@113 2056 END
jbe@113 2057 END
jbe@113 2058 END AS "notify_level",
jbe@113 2059 "event".*
jbe@113 2060 FROM "member" CROSS JOIN "event"
jbe@113 2061 LEFT JOIN "issue"
jbe@113 2062 ON "event"."issue_id" = "issue"."id"
jbe@113 2063 LEFT JOIN "membership"
jbe@113 2064 ON "member"."id" = "membership"."member_id"
jbe@113 2065 AND "issue"."area_id" = "membership"."area_id"
jbe@113 2066 LEFT JOIN "interest"
jbe@113 2067 ON "member"."id" = "interest"."member_id"
jbe@113 2068 AND "event"."issue_id" = "interest"."issue_id"
jbe@113 2069 LEFT JOIN "supporter"
jbe@113 2070 ON "member"."id" = "supporter"."member_id"
jbe@113 2071 AND "event"."initiative_id" = "supporter"."initiative_id"
jbe@113 2072 LEFT JOIN "ignored_member"
jbe@113 2073 ON "member"."id" = "ignored_member"."member_id"
jbe@113 2074 AND "event"."member_id" = "ignored_member"."other_member_id"
jbe@113 2075 LEFT JOIN "ignored_initiative"
jbe@113 2076 ON "member"."id" = "ignored_initiative"."member_id"
jbe@113 2077 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
jbe@113 2078 WHERE (
jbe@113 2079 "supporter"."member_id" NOTNULL OR
jbe@113 2080 "interest"."member_id" NOTNULL OR
jbe@113 2081 ( "membership"."member_id" NOTNULL AND
jbe@113 2082 "event"."event" IN (
jbe@113 2083 'issue_state_changed',
jbe@113 2084 'initiative_created_in_new_issue',
jbe@113 2085 'initiative_created_in_existing_issue',
jbe@113 2086 'initiative_revoked' ) ) )
jbe@113 2087 AND "ignored_member"."member_id" ISNULL
jbe@113 2088 AND "ignored_initiative"."member_id" ISNULL;
jbe@113 2089
jbe@113 2090 COMMENT ON VIEW "event_seen_by_member" IS 'Events as seen by a member, depending on its memberships, interests and support';
jbe@113 2091
jbe@113 2092
jbe@113 2093 CREATE VIEW "pending_notification" AS
jbe@113 2094 SELECT
jbe@113 2095 "member"."id" AS "seen_by_member_id",
jbe@113 2096 "event".*
jbe@113 2097 FROM "member" CROSS JOIN "event"
jbe@113 2098 LEFT JOIN "issue"
jbe@113 2099 ON "event"."issue_id" = "issue"."id"
jbe@113 2100 LEFT JOIN "membership"
jbe@113 2101 ON "member"."id" = "membership"."member_id"
jbe@113 2102 AND "issue"."area_id" = "membership"."area_id"
jbe@113 2103 LEFT JOIN "interest"
jbe@113 2104 ON "member"."id" = "interest"."member_id"
jbe@113 2105 AND "event"."issue_id" = "interest"."issue_id"
jbe@113 2106 LEFT JOIN "supporter"
jbe@113 2107 ON "member"."id" = "supporter"."member_id"
jbe@113 2108 AND "event"."initiative_id" = "supporter"."initiative_id"
jbe@113 2109 LEFT JOIN "ignored_member"
jbe@113 2110 ON "member"."id" = "ignored_member"."member_id"
jbe@113 2111 AND "event"."member_id" = "ignored_member"."other_member_id"
jbe@113 2112 LEFT JOIN "ignored_initiative"
jbe@113 2113 ON "member"."id" = "ignored_initiative"."member_id"
jbe@113 2114 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
jbe@113 2115 WHERE (
jbe@113 2116 "member"."notify_event_id" ISNULL OR
jbe@113 2117 ( "member"."notify_event_id" NOTNULL AND
jbe@113 2118 "member"."notify_event_id" < "event"."id" ) )
jbe@113 2119 AND (
jbe@113 2120 ( "member"."notify_level" >= 'all' ) OR
jbe@113 2121 ( "member"."notify_level" >= 'voting' AND
jbe@113 2122 "event"."state" IN (
jbe@113 2123 'voting',
jbe@113 2124 'finished_without_winner',
jbe@113 2125 'finished_with_winner' ) ) OR
jbe@113 2126 ( "member"."notify_level" >= 'verification' AND
jbe@113 2127 "event"."state" IN (
jbe@113 2128 'verification',
jbe@113 2129 'canceled_after_revocation_during_verification',
jbe@113 2130 'canceled_no_initiative_admitted' ) ) OR
jbe@113 2131 ( "member"."notify_level" >= 'discussion' AND
jbe@113 2132 "event"."state" IN (
jbe@113 2133 'discussion',
jbe@113 2134 'canceled_after_revocation_during_discussion' ) ) )
jbe@113 2135 AND (
jbe@113 2136 "supporter"."member_id" NOTNULL OR
jbe@113 2137 "interest"."member_id" NOTNULL OR
jbe@113 2138 ( "membership"."member_id" NOTNULL AND
jbe@113 2139 "event"."event" IN (
jbe@113 2140 'issue_state_changed',
jbe@113 2141 'initiative_created_in_new_issue',
jbe@113 2142 'initiative_created_in_existing_issue',
jbe@113 2143 'initiative_revoked' ) ) )
jbe@113 2144 AND "ignored_member"."member_id" ISNULL
jbe@113 2145 AND "ignored_initiative"."member_id" ISNULL;
jbe@113 2146
jbe@113 2147 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 2148
jbe@113 2149
jbe@16 2150 CREATE TYPE "timeline_event" AS ENUM (
jbe@16 2151 'issue_created',
jbe@16 2152 'issue_canceled',
jbe@16 2153 'issue_accepted',
jbe@16 2154 'issue_half_frozen',
jbe@16 2155 'issue_finished_without_voting',
jbe@16 2156 'issue_voting_started',
jbe@16 2157 'issue_finished_after_voting',
jbe@16 2158 'initiative_created',
jbe@16 2159 'initiative_revoked',
jbe@16 2160 'draft_created',
jbe@16 2161 'suggestion_created');
jbe@16 2162
jbe@112 2163 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
jbe@16 2164
jbe@16 2165
jbe@16 2166 CREATE VIEW "timeline_issue" AS
jbe@16 2167 SELECT
jbe@16 2168 "created" AS "occurrence",
jbe@16 2169 'issue_created'::"timeline_event" AS "event",
jbe@16 2170 "id" AS "issue_id"
jbe@16 2171 FROM "issue"
jbe@16 2172 UNION ALL
jbe@16 2173 SELECT
jbe@16 2174 "closed" AS "occurrence",
jbe@16 2175 'issue_canceled'::"timeline_event" AS "event",
jbe@16 2176 "id" AS "issue_id"
jbe@16 2177 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
jbe@16 2178 UNION ALL
jbe@16 2179 SELECT
jbe@16 2180 "accepted" AS "occurrence",
jbe@16 2181 'issue_accepted'::"timeline_event" AS "event",
jbe@16 2182 "id" AS "issue_id"
jbe@16 2183 FROM "issue" WHERE "accepted" NOTNULL
jbe@16 2184 UNION ALL
jbe@16 2185 SELECT
jbe@16 2186 "half_frozen" AS "occurrence",
jbe@16 2187 'issue_half_frozen'::"timeline_event" AS "event",
jbe@16 2188 "id" AS "issue_id"
jbe@16 2189 FROM "issue" WHERE "half_frozen" NOTNULL
jbe@16 2190 UNION ALL
jbe@16 2191 SELECT
jbe@16 2192 "fully_frozen" AS "occurrence",
jbe@16 2193 'issue_voting_started'::"timeline_event" AS "event",
jbe@16 2194 "id" AS "issue_id"
jbe@16 2195 FROM "issue"
jbe@17 2196 WHERE "fully_frozen" NOTNULL
jbe@17 2197 AND ("closed" ISNULL OR "closed" != "fully_frozen")
jbe@16 2198 UNION ALL
jbe@16 2199 SELECT
jbe@16 2200 "closed" AS "occurrence",
jbe@16 2201 CASE WHEN "fully_frozen" = "closed" THEN
jbe@16 2202 'issue_finished_without_voting'::"timeline_event"
jbe@16 2203 ELSE
jbe@16 2204 'issue_finished_after_voting'::"timeline_event"
jbe@16 2205 END AS "event",
jbe@16 2206 "id" AS "issue_id"
jbe@16 2207 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
jbe@16 2208
jbe@112 2209 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
jbe@16 2210
jbe@16 2211
jbe@16 2212 CREATE VIEW "timeline_initiative" AS
jbe@16 2213 SELECT
jbe@16 2214 "created" AS "occurrence",
jbe@16 2215 'initiative_created'::"timeline_event" AS "event",
jbe@16 2216 "id" AS "initiative_id"
jbe@16 2217 FROM "initiative"
jbe@16 2218 UNION ALL
jbe@16 2219 SELECT
jbe@16 2220 "revoked" AS "occurrence",
jbe@16 2221 'initiative_revoked'::"timeline_event" AS "event",
jbe@16 2222 "id" AS "initiative_id"
jbe@16 2223 FROM "initiative" WHERE "revoked" NOTNULL;
jbe@16 2224
jbe@112 2225 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
jbe@16 2226
jbe@16 2227
jbe@16 2228 CREATE VIEW "timeline_draft" AS
jbe@16 2229 SELECT
jbe@16 2230 "created" AS "occurrence",
jbe@16 2231 'draft_created'::"timeline_event" AS "event",
jbe@16 2232 "id" AS "draft_id"
jbe@16 2233 FROM "draft";
jbe@16 2234
jbe@112 2235 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
jbe@16 2236
jbe@16 2237
jbe@16 2238 CREATE VIEW "timeline_suggestion" AS
jbe@16 2239 SELECT
jbe@16 2240 "created" AS "occurrence",
jbe@16 2241 'suggestion_created'::"timeline_event" AS "event",
jbe@16 2242 "id" AS "suggestion_id"
jbe@16 2243 FROM "suggestion";
jbe@16 2244
jbe@112 2245 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
jbe@16 2246
jbe@16 2247
jbe@16 2248 CREATE VIEW "timeline" AS
jbe@16 2249 SELECT
jbe@16 2250 "occurrence",
jbe@16 2251 "event",
jbe@16 2252 "issue_id",
jbe@16 2253 NULL AS "initiative_id",
jbe@16 2254 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
jbe@16 2255 NULL::INT8 AS "suggestion_id"
jbe@16 2256 FROM "timeline_issue"
jbe@16 2257 UNION ALL
jbe@16 2258 SELECT
jbe@16 2259 "occurrence",
jbe@16 2260 "event",
jbe@16 2261 NULL AS "issue_id",
jbe@16 2262 "initiative_id",
jbe@16 2263 NULL AS "draft_id",
jbe@16 2264 NULL AS "suggestion_id"
jbe@16 2265 FROM "timeline_initiative"
jbe@16 2266 UNION ALL
jbe@16 2267 SELECT
jbe@16 2268 "occurrence",
jbe@16 2269 "event",
jbe@16 2270 NULL AS "issue_id",
jbe@16 2271 NULL AS "initiative_id",
jbe@16 2272 "draft_id",
jbe@16 2273 NULL AS "suggestion_id"
jbe@16 2274 FROM "timeline_draft"
jbe@16 2275 UNION ALL
jbe@16 2276 SELECT
jbe@16 2277 "occurrence",
jbe@16 2278 "event",
jbe@16 2279 NULL AS "issue_id",
jbe@16 2280 NULL AS "initiative_id",
jbe@16 2281 NULL AS "draft_id",
jbe@16 2282 "suggestion_id"
jbe@16 2283 FROM "timeline_suggestion";
jbe@16 2284
jbe@112 2285 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
jbe@16 2286
jbe@16 2287
jbe@0 2288
jbe@5 2289 --------------------------------------------------
jbe@5 2290 -- Set returning function for delegation chains --
jbe@5 2291 --------------------------------------------------
jbe@5 2292
jbe@5 2293
jbe@5 2294 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
jbe@5 2295 ('first', 'intermediate', 'last', 'repetition');
jbe@5 2296
jbe@5 2297 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
jbe@5 2298
jbe@5 2299
jbe@5 2300 CREATE TYPE "delegation_chain_row" AS (
jbe@5 2301 "index" INT4,
jbe@5 2302 "member_id" INT4,
jbe@97 2303 "member_valid" BOOLEAN,
jbe@5 2304 "participation" BOOLEAN,
jbe@5 2305 "overridden" BOOLEAN,
jbe@5 2306 "scope_in" "delegation_scope",
jbe@5 2307 "scope_out" "delegation_scope",
jbe@86 2308 "disabled_out" BOOLEAN,
jbe@5 2309 "loop" "delegation_chain_loop_tag" );
jbe@5 2310
jbe@5 2311 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain"(...) functions';
jbe@5 2312
jbe@5 2313 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
jbe@5 2314 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 2315 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
jbe@5 2316 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
jbe@5 2317 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
jbe@86 2318 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 2319 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 2320
jbe@5 2321
jbe@5 2322 CREATE FUNCTION "delegation_chain"
jbe@5 2323 ( "member_id_p" "member"."id"%TYPE,
jbe@97 2324 "unit_id_p" "unit"."id"%TYPE,
jbe@5 2325 "area_id_p" "area"."id"%TYPE,
jbe@5 2326 "issue_id_p" "issue"."id"%TYPE,
jbe@5 2327 "simulate_trustee_id_p" "member"."id"%TYPE )
jbe@5 2328 RETURNS SETOF "delegation_chain_row"
jbe@5 2329 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 2330 DECLARE
jbe@97 2331 "scope_v" "delegation_scope";
jbe@97 2332 "unit_id_v" "unit"."id"%TYPE;
jbe@97 2333 "area_id_v" "area"."id"%TYPE;
jbe@5 2334 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
jbe@5 2335 "loop_member_id_v" "member"."id"%TYPE;
jbe@5 2336 "output_row" "delegation_chain_row";
jbe@5 2337 "output_rows" "delegation_chain_row"[];
jbe@5 2338 "delegation_row" "delegation"%ROWTYPE;
jbe@5 2339 "row_count" INT4;
jbe@5 2340 "i" INT4;
jbe@5 2341 "loop_v" BOOLEAN;
jbe@5 2342 BEGIN
jbe@97 2343 IF
jbe@97 2344 "unit_id_p" NOTNULL AND
jbe@97 2345 "area_id_p" ISNULL AND
jbe@97 2346 "issue_id_p" ISNULL
jbe@97 2347 THEN
jbe@97 2348 "scope_v" := 'unit';
jbe@97 2349 "unit_id_v" := "unit_id_p";
jbe@97 2350 ELSIF
jbe@97 2351 "unit_id_p" ISNULL AND
jbe@97 2352 "area_id_p" NOTNULL AND
jbe@97 2353 "issue_id_p" ISNULL
jbe@97 2354 THEN
jbe@97 2355 "scope_v" := 'area';
jbe@97 2356 "area_id_v" := "area_id_p";
jbe@97 2357 SELECT "unit_id" INTO "unit_id_v"
jbe@97 2358 FROM "area" WHERE "id" = "area_id_v";
jbe@97 2359 ELSIF
jbe@97 2360 "unit_id_p" ISNULL AND
jbe@97 2361 "area_id_p" ISNULL AND
jbe@97 2362 "issue_id_p" NOTNULL
jbe@97 2363 THEN
jbe@97 2364 "scope_v" := 'issue';
jbe@97 2365 SELECT "area_id" INTO "area_id_v"
jbe@97 2366 FROM "issue" WHERE "id" = "issue_id_p";
jbe@97 2367 SELECT "unit_id" INTO "unit_id_v"
jbe@97 2368 FROM "area" WHERE "id" = "area_id_v";
jbe@97 2369 ELSE
jbe@97 2370 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
jbe@97 2371 END IF;
jbe@5 2372 "visited_member_ids" := '{}';
jbe@5 2373 "loop_member_id_v" := NULL;
jbe@5 2374 "output_rows" := '{}';
jbe@5 2375 "output_row"."index" := 0;
jbe@5 2376 "output_row"."member_id" := "member_id_p";
jbe@97 2377 "output_row"."member_valid" := TRUE;
jbe@5 2378 "output_row"."participation" := FALSE;
jbe@5 2379 "output_row"."overridden" := FALSE;
jbe@86 2380 "output_row"."disabled_out" := FALSE;
jbe@5 2381 "output_row"."scope_out" := NULL;
jbe@5 2382 LOOP
jbe@5 2383 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
jbe@5 2384 "loop_member_id_v" := "output_row"."member_id";
jbe@5 2385 ELSE
jbe@5 2386 "visited_member_ids" :=
jbe@5 2387 "visited_member_ids" || "output_row"."member_id";
jbe@5 2388 END IF;
jbe@5 2389 IF "output_row"."participation" THEN
jbe@5 2390 "output_row"."overridden" := TRUE;
jbe@5 2391 END IF;
jbe@5 2392 "output_row"."scope_in" := "output_row"."scope_out";
jbe@5 2393 IF EXISTS (
jbe@97 2394 SELECT NULL FROM "member" JOIN "privilege"
jbe@97 2395 ON "privilege"."member_id" = "member"."id"
jbe@97 2396 AND "privilege"."unit_id" = "unit_id_v"
jbe@97 2397 WHERE "id" = "output_row"."member_id"
jbe@97 2398 AND "member"."active" AND "privilege"."voting_right"
jbe@5 2399 ) THEN
jbe@97 2400 IF "scope_v" = 'unit' THEN
jbe@5 2401 SELECT * INTO "delegation_row" FROM "delegation"
jbe@5 2402 WHERE "truster_id" = "output_row"."member_id"
jbe@97 2403 AND "unit_id" = "unit_id_v";
jbe@97 2404 ELSIF "scope_v" = 'area' THEN
jbe@5 2405 "output_row"."participation" := EXISTS (
jbe@5 2406 SELECT NULL FROM "membership"
jbe@5 2407 WHERE "area_id" = "area_id_p"
jbe@5 2408 AND "member_id" = "output_row"."member_id"
jbe@5 2409 );
jbe@5 2410 SELECT * INTO "delegation_row" FROM "delegation"
jbe@5 2411 WHERE "truster_id" = "output_row"."member_id"
jbe@97 2412 AND (
jbe@97 2413 "unit_id" = "unit_id_v" OR
jbe@97 2414 "area_id" = "area_id_v"
jbe@97 2415 )
jbe@10 2416 ORDER BY "scope" DESC;
jbe@97 2417 ELSIF "scope_v" = 'issue' THEN
jbe@5 2418 "output_row"."participation" := EXISTS (
jbe@5 2419 SELECT NULL FROM "interest"
jbe@5 2420 WHERE "issue_id" = "issue_id_p"
jbe@5 2421 AND "member_id" = "output_row"."member_id"
jbe@5 2422 );
jbe@5 2423 SELECT * INTO "delegation_row" FROM "delegation"
jbe@5 2424 WHERE "truster_id" = "output_row"."member_id"
jbe@97 2425 AND (
jbe@97 2426 "unit_id" = "unit_id_v" OR
jbe@97 2427 "area_id" = "area_id_v" OR
jbe@10 2428 "issue_id" = "issue_id_p"
jbe@10 2429 )
jbe@10 2430 ORDER BY "scope" DESC;
jbe@5 2431 END IF;
jbe@5 2432 ELSE
jbe@97 2433 "output_row"."member_valid" := FALSE;
jbe@5 2434 "output_row"."participation" := FALSE;
jbe@5 2435 "output_row"."scope_out" := NULL;
jbe@5 2436 "delegation_row" := ROW(NULL);
jbe@5 2437 END IF;
jbe@5 2438 IF
jbe@5 2439 "output_row"."member_id" = "member_id_p" AND
jbe@5 2440 "simulate_trustee_id_p" NOTNULL
jbe@5 2441 THEN
jbe@97 2442 "output_row"."scope_out" := "scope_v";
jbe@5 2443 "output_rows" := "output_rows" || "output_row";
jbe@5 2444 "output_row"."member_id" := "simulate_trustee_id_p";
jbe@5 2445 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
jbe@10 2446 "output_row"."scope_out" := "delegation_row"."scope";
jbe@5 2447 "output_rows" := "output_rows" || "output_row";
jbe@5 2448 "output_row"."member_id" := "delegation_row"."trustee_id";
jbe@86 2449 ELSIF "delegation_row"."scope" NOTNULL THEN
jbe@86 2450 "output_row"."scope_out" := "delegation_row"."scope";
jbe@86 2451 "output_row"."disabled_out" := TRUE;
jbe@86 2452 "output_rows" := "output_rows" || "output_row";
jbe@86 2453 EXIT;
jbe@5 2454 ELSE
jbe@5 2455 "output_row"."scope_out" := NULL;
jbe@5 2456 "output_rows" := "output_rows" || "output_row";
jbe@5 2457 EXIT;
jbe@5 2458 END IF;
jbe@5 2459 EXIT WHEN "loop_member_id_v" NOTNULL;
jbe@5 2460 "output_row"."index" := "output_row"."index" + 1;
jbe@5 2461 END LOOP;
jbe@5 2462 "row_count" := array_upper("output_rows", 1);
jbe@5 2463 "i" := 1;
jbe@5 2464 "loop_v" := FALSE;
jbe@5 2465 LOOP
jbe@5 2466 "output_row" := "output_rows"["i"];
jbe@98 2467 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
jbe@5 2468 IF "loop_v" THEN
jbe@5 2469 IF "i" + 1 = "row_count" THEN
jbe@5 2470 "output_row"."loop" := 'last';
jbe@5 2471 ELSIF "i" = "row_count" THEN
jbe@5 2472 "output_row"."loop" := 'repetition';
jbe@5 2473 ELSE
jbe@5 2474 "output_row"."loop" := 'intermediate';
jbe@5 2475 END IF;
jbe@5 2476 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
jbe@5 2477 "output_row"."loop" := 'first';
jbe@5 2478 "loop_v" := TRUE;
jbe@5 2479 END IF;
jbe@97 2480 IF "scope_v" = 'unit' THEN
jbe@5 2481 "output_row"."participation" := NULL;
jbe@5 2482 END IF;
jbe@5 2483 RETURN NEXT "output_row";
jbe@5 2484 "i" := "i" + 1;
jbe@5 2485 END LOOP;
jbe@5 2486 RETURN;
jbe@5 2487 END;
jbe@5 2488 $$;
jbe@5 2489
jbe@5 2490 COMMENT ON FUNCTION "delegation_chain"
jbe@5 2491 ( "member"."id"%TYPE,
jbe@97 2492 "unit"."id"%TYPE,
jbe@5 2493 "area"."id"%TYPE,
jbe@5 2494 "issue"."id"%TYPE,
jbe@5 2495 "member"."id"%TYPE )
jbe@5 2496 IS 'Helper function for frontends to display delegation chains; Not part of internal voting logic';
jbe@5 2497
jbe@97 2498
jbe@5 2499 CREATE FUNCTION "delegation_chain"
jbe@5 2500 ( "member_id_p" "member"."id"%TYPE,
jbe@97 2501 "unit_id_p" "unit"."id"%TYPE,
jbe@5 2502 "area_id_p" "area"."id"%TYPE,
jbe@5 2503 "issue_id_p" "issue"."id"%TYPE )
jbe@5 2504 RETURNS SETOF "delegation_chain_row"
jbe@5 2505 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 2506 DECLARE
jbe@5 2507 "result_row" "delegation_chain_row";
jbe@5 2508 BEGIN
jbe@5 2509 FOR "result_row" IN
jbe@5 2510 SELECT * FROM "delegation_chain"(
jbe@123 2511 "member_id_p", "unit_id_p", "area_id_p", "issue_id_p", NULL
jbe@5 2512 )
jbe@5 2513 LOOP
jbe@5 2514 RETURN NEXT "result_row";
jbe@5 2515 END LOOP;
jbe@5 2516 RETURN;
jbe@5 2517 END;
jbe@5 2518 $$;
jbe@5 2519
jbe@5 2520 COMMENT ON FUNCTION "delegation_chain"
jbe@5 2521 ( "member"."id"%TYPE,
jbe@97 2522 "unit"."id"%TYPE,
jbe@5 2523 "area"."id"%TYPE,
jbe@5 2524 "issue"."id"%TYPE )
jbe@5 2525 IS 'Shortcut for "delegation_chain"(...) function where 4th parameter is null';
jbe@5 2526
jbe@5 2527
jbe@5 2528
jbe@0 2529 ------------------------------
jbe@0 2530 -- Comparison by vote count --
jbe@0 2531 ------------------------------
jbe@0 2532
jbe@0 2533 CREATE FUNCTION "vote_ratio"
jbe@0 2534 ( "positive_votes_p" "initiative"."positive_votes"%TYPE,
jbe@0 2535 "negative_votes_p" "initiative"."negative_votes"%TYPE )
jbe@0 2536 RETURNS FLOAT8
jbe@0 2537 LANGUAGE 'plpgsql' STABLE AS $$
jbe@0 2538 BEGIN
jbe@30 2539 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN
jbe@30 2540 RETURN
jbe@30 2541 "positive_votes_p"::FLOAT8 /
jbe@30 2542 ("positive_votes_p" + "negative_votes_p")::FLOAT8;
jbe@30 2543 ELSIF "positive_votes_p" > 0 THEN
jbe@30 2544 RETURN "positive_votes_p";
jbe@30 2545 ELSIF "negative_votes_p" > 0 THEN
jbe@30 2546 RETURN 1 - "negative_votes_p";
jbe@0 2547 ELSE
jbe@0 2548 RETURN 0.5;
jbe@0 2549 END IF;
jbe@0 2550 END;
jbe@0 2551 $$;
jbe@0 2552
jbe@0 2553 COMMENT ON FUNCTION "vote_ratio"
jbe@0 2554 ( "initiative"."positive_votes"%TYPE,
jbe@0 2555 "initiative"."negative_votes"%TYPE )
jbe@30 2556 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 2557
jbe@0 2558
jbe@0 2559
jbe@0 2560 ------------------------------------------------
jbe@0 2561 -- Locking for snapshots and voting procedure --
jbe@0 2562 ------------------------------------------------
jbe@0 2563
jbe@67 2564
jbe@67 2565 CREATE FUNCTION "share_row_lock_issue_trigger"()
jbe@67 2566 RETURNS TRIGGER
jbe@67 2567 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@67 2568 BEGIN
jbe@67 2569 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
jbe@67 2570 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
jbe@67 2571 END IF;
jbe@67 2572 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
jbe@67 2573 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
jbe@67 2574 RETURN NEW;
jbe@67 2575 ELSE
jbe@67 2576 RETURN OLD;
jbe@67 2577 END IF;
jbe@67 2578 END;
jbe@67 2579 $$;
jbe@67 2580
jbe@67 2581 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
jbe@67 2582
jbe@67 2583
jbe@67 2584 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
jbe@67 2585 RETURNS TRIGGER
jbe@0 2586 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2587 BEGIN
jbe@67 2588 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
jbe@67 2589 PERFORM NULL FROM "issue"
jbe@67 2590 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
jbe@67 2591 WHERE "initiative"."id" = OLD."initiative_id"
jbe@67 2592 FOR SHARE OF "issue";
jbe@67 2593 END IF;
jbe@67 2594 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
jbe@67 2595 PERFORM NULL FROM "issue"
jbe@67 2596 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
jbe@67 2597 WHERE "initiative"."id" = NEW."initiative_id"
jbe@67 2598 FOR SHARE OF "issue";
jbe@67 2599 RETURN NEW;
jbe@67 2600 ELSE
jbe@67 2601 RETURN OLD;
jbe@67 2602 END IF;
jbe@67 2603 END;
jbe@67 2604 $$;
jbe@67 2605
jbe@67 2606 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
jbe@67 2607
jbe@67 2608
jbe@67 2609 CREATE TRIGGER "share_row_lock_issue"
jbe@67 2610 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
jbe@67 2611 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2612 "share_row_lock_issue_trigger"();
jbe@67 2613
jbe@67 2614 CREATE TRIGGER "share_row_lock_issue"
jbe@67 2615 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
jbe@67 2616 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2617 "share_row_lock_issue_trigger"();
jbe@67 2618
jbe@67 2619 CREATE TRIGGER "share_row_lock_issue"
jbe@67 2620 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
jbe@67 2621 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2622 "share_row_lock_issue_trigger"();
jbe@67 2623
jbe@67 2624 CREATE TRIGGER "share_row_lock_issue_via_initiative"
jbe@67 2625 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
jbe@67 2626 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2627 "share_row_lock_issue_via_initiative_trigger"();
jbe@67 2628
jbe@67 2629 CREATE TRIGGER "share_row_lock_issue"
jbe@67 2630 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
jbe@67 2631 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2632 "share_row_lock_issue_trigger"();
jbe@67 2633
jbe@67 2634 CREATE TRIGGER "share_row_lock_issue"
jbe@67 2635 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
jbe@67 2636 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2637 "share_row_lock_issue_trigger"();
jbe@67 2638
jbe@67 2639 CREATE TRIGGER "share_row_lock_issue"
jbe@67 2640 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
jbe@67 2641 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2642 "share_row_lock_issue_trigger"();
jbe@67 2643
jbe@67 2644 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
jbe@67 2645 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
jbe@67 2646 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
jbe@67 2647 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
jbe@67 2648 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
jbe@67 2649 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
jbe@67 2650 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
jbe@67 2651
jbe@67 2652
jbe@67 2653 CREATE FUNCTION "lock_issue"
jbe@67 2654 ( "issue_id_p" "issue"."id"%TYPE )
jbe@67 2655 RETURNS VOID
jbe@67 2656 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@67 2657 BEGIN
jbe@67 2658 LOCK TABLE "member" IN SHARE MODE;
jbe@97 2659 LOCK TABLE "privilege" IN SHARE MODE;
jbe@67 2660 LOCK TABLE "membership" IN SHARE MODE;
jbe@67 2661 LOCK TABLE "policy" IN SHARE MODE;
jbe@67 2662 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
jbe@67 2663 -- NOTE: The row-level exclusive lock in combination with the
jbe@67 2664 -- share_row_lock_issue(_via_initiative)_trigger functions (which
jbe@67 2665 -- acquire a row-level share lock on the issue) ensure that no data
jbe@67 2666 -- is changed, which could affect calculation of snapshots or
jbe@67 2667 -- counting of votes. Table "delegation" must be table-level-locked,
jbe@67 2668 -- as it also contains issue- and global-scope delegations.
jbe@67 2669 LOCK TABLE "delegation" IN SHARE MODE;
jbe@0 2670 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
jbe@0 2671 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
jbe@0 2672 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
jbe@0 2673 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
jbe@0 2674 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
jbe@0 2675 RETURN;
jbe@0 2676 END;
jbe@0 2677 $$;
jbe@0 2678
jbe@67 2679 COMMENT ON FUNCTION "lock_issue"
jbe@67 2680 ( "issue"."id"%TYPE )
jbe@67 2681 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
jbe@0 2682
jbe@0 2683
jbe@0 2684
jbe@103 2685 ------------------------------------------------------------------------
jbe@103 2686 -- Regular tasks, except calculcation of snapshots and voting results --
jbe@103 2687 ------------------------------------------------------------------------
jbe@103 2688
jbe@184 2689 CREATE FUNCTION "check_activity"()
jbe@103 2690 RETURNS VOID
jbe@103 2691 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@104 2692 DECLARE
jbe@104 2693 "system_setting_row" "system_setting"%ROWTYPE;
jbe@103 2694 BEGIN
jbe@104 2695 SELECT * INTO "system_setting_row" FROM "system_setting";
jbe@103 2696 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
jbe@104 2697 IF "system_setting_row"."member_ttl" NOTNULL THEN
jbe@104 2698 UPDATE "member" SET "active" = FALSE
jbe@104 2699 WHERE "active" = TRUE
jbe@184 2700 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
jbe@104 2701 END IF;
jbe@103 2702 RETURN;
jbe@103 2703 END;
jbe@103 2704 $$;
jbe@103 2705
jbe@184 2706 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
jbe@103 2707
jbe@4 2708
jbe@4 2709 CREATE FUNCTION "calculate_member_counts"()
jbe@4 2710 RETURNS VOID
jbe@4 2711 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@4 2712 BEGIN
jbe@67 2713 LOCK TABLE "member" IN SHARE MODE;
jbe@67 2714 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
jbe@97 2715 LOCK TABLE "unit" IN EXCLUSIVE MODE;
jbe@67 2716 LOCK TABLE "area" IN EXCLUSIVE MODE;
jbe@97 2717 LOCK TABLE "privilege" IN SHARE MODE;
jbe@67 2718 LOCK TABLE "membership" IN SHARE MODE;
jbe@4 2719 DELETE FROM "member_count";
jbe@5 2720 INSERT INTO "member_count" ("total_count")
jbe@5 2721 SELECT "total_count" FROM "member_count_view";
jbe@97 2722 UPDATE "unit" SET "member_count" = "view"."member_count"
jbe@97 2723 FROM "unit_member_count" AS "view"
jbe@97 2724 WHERE "view"."unit_id" = "unit"."id";
jbe@5 2725 UPDATE "area" SET
jbe@5 2726 "direct_member_count" = "view"."direct_member_count",
jbe@169 2727 "member_weight" = "view"."member_weight"
jbe@5 2728 FROM "area_member_count" AS "view"
jbe@5 2729 WHERE "view"."area_id" = "area"."id";
jbe@4 2730 RETURN;
jbe@4 2731 END;
jbe@4 2732 $$;
jbe@4 2733
jbe@4 2734 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 2735
jbe@4 2736
jbe@4 2737
jbe@0 2738 ------------------------------
jbe@0 2739 -- Calculation of snapshots --
jbe@0 2740 ------------------------------
jbe@0 2741
jbe@0 2742 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
jbe@0 2743 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 2744 "member_id_p" "member"."id"%TYPE,
jbe@0 2745 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
jbe@0 2746 RETURNS "direct_population_snapshot"."weight"%TYPE
jbe@0 2747 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2748 DECLARE
jbe@0 2749 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 2750 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
jbe@0 2751 "weight_v" INT4;
jbe@8 2752 "sub_weight_v" INT4;
jbe@0 2753 BEGIN
jbe@0 2754 "weight_v" := 0;
jbe@0 2755 FOR "issue_delegation_row" IN
jbe@0 2756 SELECT * FROM "issue_delegation"
jbe@0 2757 WHERE "trustee_id" = "member_id_p"
jbe@0 2758 AND "issue_id" = "issue_id_p"
jbe@0 2759 LOOP
jbe@0 2760 IF NOT EXISTS (
jbe@0 2761 SELECT NULL FROM "direct_population_snapshot"
jbe@0 2762 WHERE "issue_id" = "issue_id_p"
jbe@0 2763 AND "event" = 'periodic'
jbe@0 2764 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 2765 ) AND NOT EXISTS (
jbe@0 2766 SELECT NULL FROM "delegating_population_snapshot"
jbe@0 2767 WHERE "issue_id" = "issue_id_p"
jbe@0 2768 AND "event" = 'periodic'
jbe@0 2769 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 2770 ) THEN
jbe@0 2771 "delegate_member_ids_v" :=
jbe@0 2772 "member_id_p" || "delegate_member_ids_p";
jbe@10 2773 INSERT INTO "delegating_population_snapshot" (
jbe@10 2774 "issue_id",
jbe@10 2775 "event",
jbe@10 2776 "member_id",
jbe@10 2777 "scope",
jbe@10 2778 "delegate_member_ids"
jbe@10 2779 ) VALUES (
jbe@0 2780 "issue_id_p",
jbe@0 2781 'periodic',
jbe@0 2782 "issue_delegation_row"."truster_id",
jbe@10 2783 "issue_delegation_row"."scope",
jbe@0 2784 "delegate_member_ids_v"
jbe@0 2785 );
jbe@8 2786 "sub_weight_v" := 1 +
jbe@0 2787 "weight_of_added_delegations_for_population_snapshot"(
jbe@0 2788 "issue_id_p",
jbe@0 2789 "issue_delegation_row"."truster_id",
jbe@0 2790 "delegate_member_ids_v"
jbe@0 2791 );
jbe@8 2792 UPDATE "delegating_population_snapshot"
jbe@8 2793 SET "weight" = "sub_weight_v"
jbe@8 2794 WHERE "issue_id" = "issue_id_p"
jbe@8 2795 AND "event" = 'periodic'
jbe@8 2796 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 2797 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 2798 END IF;
jbe@0 2799 END LOOP;
jbe@0 2800 RETURN "weight_v";
jbe@0 2801 END;
jbe@0 2802 $$;
jbe@0 2803
jbe@0 2804 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
jbe@0 2805 ( "issue"."id"%TYPE,
jbe@0 2806 "member"."id"%TYPE,
jbe@0 2807 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
jbe@0 2808 IS 'Helper function for "create_population_snapshot" function';
jbe@0 2809
jbe@0 2810
jbe@0 2811 CREATE FUNCTION "create_population_snapshot"
jbe@0 2812 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 2813 RETURNS VOID
jbe@0 2814 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2815 DECLARE
jbe@0 2816 "member_id_v" "member"."id"%TYPE;
jbe@0 2817 BEGIN
jbe@0 2818 DELETE FROM "direct_population_snapshot"
jbe@0 2819 WHERE "issue_id" = "issue_id_p"
jbe@0 2820 AND "event" = 'periodic';
jbe@0 2821 DELETE FROM "delegating_population_snapshot"
jbe@0 2822 WHERE "issue_id" = "issue_id_p"
jbe@0 2823 AND "event" = 'periodic';
jbe@0 2824 INSERT INTO "direct_population_snapshot"
jbe@54 2825 ("issue_id", "event", "member_id")
jbe@54 2826 SELECT
jbe@54 2827 "issue_id_p" AS "issue_id",
jbe@54 2828 'periodic'::"snapshot_event" AS "event",
jbe@54 2829 "member"."id" AS "member_id"
jbe@54 2830 FROM "issue"
jbe@54 2831 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@54 2832 JOIN "membership" ON "area"."id" = "membership"."area_id"
jbe@54 2833 JOIN "member" ON "membership"."member_id" = "member"."id"
jbe@97 2834 JOIN "privilege"
jbe@97 2835 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 2836 AND "privilege"."member_id" = "member"."id"
jbe@54 2837 WHERE "issue"."id" = "issue_id_p"
jbe@97 2838 AND "member"."active" AND "privilege"."voting_right"
jbe@54 2839 UNION
jbe@54 2840 SELECT
jbe@54 2841 "issue_id_p" AS "issue_id",
jbe@54 2842 'periodic'::"snapshot_event" AS "event",
jbe@54 2843 "member"."id" AS "member_id"
jbe@97 2844 FROM "issue"
jbe@97 2845 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@97 2846 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
jbe@97 2847 JOIN "member" ON "interest"."member_id" = "member"."id"
jbe@97 2848 JOIN "privilege"
jbe@97 2849 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 2850 AND "privilege"."member_id" = "member"."id"
jbe@97 2851 WHERE "issue"."id" = "issue_id_p"
jbe@97 2852 AND "member"."active" AND "privilege"."voting_right";
jbe@0 2853 FOR "member_id_v" IN
jbe@0 2854 SELECT "member_id" FROM "direct_population_snapshot"
jbe@0 2855 WHERE "issue_id" = "issue_id_p"
jbe@0 2856 AND "event" = 'periodic'
jbe@0 2857 LOOP
jbe@0 2858 UPDATE "direct_population_snapshot" SET
jbe@0 2859 "weight" = 1 +
jbe@0 2860 "weight_of_added_delegations_for_population_snapshot"(
jbe@0 2861 "issue_id_p",
jbe@0 2862 "member_id_v",
jbe@0 2863 '{}'
jbe@0 2864 )
jbe@0 2865 WHERE "issue_id" = "issue_id_p"
jbe@0 2866 AND "event" = 'periodic'
jbe@0 2867 AND "member_id" = "member_id_v";
jbe@0 2868 END LOOP;
jbe@0 2869 RETURN;
jbe@0 2870 END;
jbe@0 2871 $$;
jbe@0 2872
jbe@0 2873 COMMENT ON FUNCTION "create_population_snapshot"
jbe@67 2874 ( "issue"."id"%TYPE )
jbe@0 2875 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 2876
jbe@0 2877
jbe@0 2878 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
jbe@0 2879 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 2880 "member_id_p" "member"."id"%TYPE,
jbe@0 2881 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@0 2882 RETURNS "direct_interest_snapshot"."weight"%TYPE
jbe@0 2883 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2884 DECLARE
jbe@0 2885 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 2886 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
jbe@0 2887 "weight_v" INT4;
jbe@8 2888 "sub_weight_v" INT4;
jbe@0 2889 BEGIN
jbe@0 2890 "weight_v" := 0;
jbe@0 2891 FOR "issue_delegation_row" IN
jbe@0 2892 SELECT * FROM "issue_delegation"
jbe@0 2893 WHERE "trustee_id" = "member_id_p"
jbe@0 2894 AND "issue_id" = "issue_id_p"
jbe@0 2895 LOOP
jbe@0 2896 IF NOT EXISTS (
jbe@0 2897 SELECT NULL FROM "direct_interest_snapshot"
jbe@0 2898 WHERE "issue_id" = "issue_id_p"
jbe@0 2899 AND "event" = 'periodic'
jbe@0 2900 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 2901 ) AND NOT EXISTS (
jbe@0 2902 SELECT NULL FROM "delegating_interest_snapshot"
jbe@0 2903 WHERE "issue_id" = "issue_id_p"
jbe@0 2904 AND "event" = 'periodic'
jbe@0 2905 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 2906 ) THEN
jbe@0 2907 "delegate_member_ids_v" :=
jbe@0 2908 "member_id_p" || "delegate_member_ids_p";
jbe@10 2909 INSERT INTO "delegating_interest_snapshot" (
jbe@10 2910 "issue_id",
jbe@10 2911 "event",
jbe@10 2912 "member_id",
jbe@10 2913 "scope",
jbe@10 2914 "delegate_member_ids"
jbe@10 2915 ) VALUES (
jbe@0 2916 "issue_id_p",
jbe@0 2917 'periodic',
jbe@0 2918 "issue_delegation_row"."truster_id",
jbe@10 2919 "issue_delegation_row"."scope",
jbe@0 2920 "delegate_member_ids_v"
jbe@0 2921 );
jbe@8 2922 "sub_weight_v" := 1 +
jbe@0 2923 "weight_of_added_delegations_for_interest_snapshot"(
jbe@0 2924 "issue_id_p",
jbe@0 2925 "issue_delegation_row"."truster_id",
jbe@0 2926 "delegate_member_ids_v"
jbe@0 2927 );
jbe@8 2928 UPDATE "delegating_interest_snapshot"
jbe@8 2929 SET "weight" = "sub_weight_v"
jbe@8 2930 WHERE "issue_id" = "issue_id_p"
jbe@8 2931 AND "event" = 'periodic'
jbe@8 2932 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 2933 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 2934 END IF;
jbe@0 2935 END LOOP;
jbe@0 2936 RETURN "weight_v";
jbe@0 2937 END;
jbe@0 2938 $$;
jbe@0 2939
jbe@0 2940 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
jbe@0 2941 ( "issue"."id"%TYPE,
jbe@0 2942 "member"."id"%TYPE,
jbe@0 2943 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@0 2944 IS 'Helper function for "create_interest_snapshot" function';
jbe@0 2945
jbe@0 2946
jbe@0 2947 CREATE FUNCTION "create_interest_snapshot"
jbe@0 2948 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 2949 RETURNS VOID
jbe@0 2950 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2951 DECLARE
jbe@0 2952 "member_id_v" "member"."id"%TYPE;
jbe@0 2953 BEGIN
jbe@0 2954 DELETE FROM "direct_interest_snapshot"
jbe@0 2955 WHERE "issue_id" = "issue_id_p"
jbe@0 2956 AND "event" = 'periodic';
jbe@0 2957 DELETE FROM "delegating_interest_snapshot"
jbe@0 2958 WHERE "issue_id" = "issue_id_p"
jbe@0 2959 AND "event" = 'periodic';
jbe@0 2960 DELETE FROM "direct_supporter_snapshot"
jbe@0 2961 WHERE "issue_id" = "issue_id_p"
jbe@0 2962 AND "event" = 'periodic';
jbe@0 2963 INSERT INTO "direct_interest_snapshot"
jbe@144 2964 ("issue_id", "event", "member_id")
jbe@0 2965 SELECT
jbe@0 2966 "issue_id_p" AS "issue_id",
jbe@0 2967 'periodic' AS "event",
jbe@144 2968 "member"."id" AS "member_id"
jbe@97 2969 FROM "issue"
jbe@97 2970 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@97 2971 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
jbe@97 2972 JOIN "member" ON "interest"."member_id" = "member"."id"
jbe@97 2973 JOIN "privilege"
jbe@97 2974 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 2975 AND "privilege"."member_id" = "member"."id"
jbe@97 2976 WHERE "issue"."id" = "issue_id_p"
jbe@97 2977 AND "member"."active" AND "privilege"."voting_right";
jbe@0 2978 FOR "member_id_v" IN
jbe@0 2979 SELECT "member_id" FROM "direct_interest_snapshot"
jbe@0 2980 WHERE "issue_id" = "issue_id_p"
jbe@0 2981 AND "event" = 'periodic'
jbe@0 2982 LOOP
jbe@0 2983 UPDATE "direct_interest_snapshot" SET
jbe@0 2984 "weight" = 1 +
jbe@0 2985 "weight_of_added_delegations_for_interest_snapshot"(
jbe@0 2986 "issue_id_p",
jbe@0 2987 "member_id_v",
jbe@0 2988 '{}'
jbe@0 2989 )
jbe@0 2990 WHERE "issue_id" = "issue_id_p"
jbe@0 2991 AND "event" = 'periodic'
jbe@0 2992 AND "member_id" = "member_id_v";
jbe@0 2993 END LOOP;
jbe@0 2994 INSERT INTO "direct_supporter_snapshot"
jbe@0 2995 ( "issue_id", "initiative_id", "event", "member_id",
jbe@204 2996 "draft_id", "informed", "satisfied" )
jbe@0 2997 SELECT
jbe@96 2998 "issue_id_p" AS "issue_id",
jbe@96 2999 "initiative"."id" AS "initiative_id",
jbe@96 3000 'periodic' AS "event",
jbe@96 3001 "supporter"."member_id" AS "member_id",
jbe@204 3002 "supporter"."draft_id" AS "draft_id",
jbe@0 3003 "supporter"."draft_id" = "current_draft"."id" AS "informed",
jbe@0 3004 NOT EXISTS (
jbe@0 3005 SELECT NULL FROM "critical_opinion"
jbe@0 3006 WHERE "initiative_id" = "initiative"."id"
jbe@96 3007 AND "member_id" = "supporter"."member_id"
jbe@0 3008 ) AS "satisfied"
jbe@96 3009 FROM "initiative"
jbe@96 3010 JOIN "supporter"
jbe@0 3011 ON "supporter"."initiative_id" = "initiative"."id"
jbe@0 3012 JOIN "current_draft"
jbe@0 3013 ON "initiative"."id" = "current_draft"."initiative_id"
jbe@0 3014 JOIN "direct_interest_snapshot"
jbe@96 3015 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
jbe@0 3016 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
jbe@3 3017 AND "event" = 'periodic'
jbe@96 3018 WHERE "initiative"."issue_id" = "issue_id_p";
jbe@0 3019 RETURN;
jbe@0 3020 END;
jbe@0 3021 $$;
jbe@0 3022
jbe@0 3023 COMMENT ON FUNCTION "create_interest_snapshot"
jbe@0 3024 ( "issue"."id"%TYPE )
jbe@0 3025 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 3026
jbe@0 3027
jbe@0 3028 CREATE FUNCTION "create_snapshot"
jbe@0 3029 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3030 RETURNS VOID
jbe@0 3031 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3032 DECLARE
jbe@0 3033 "initiative_id_v" "initiative"."id"%TYPE;
jbe@0 3034 "suggestion_id_v" "suggestion"."id"%TYPE;
jbe@0 3035 BEGIN
jbe@67 3036 PERFORM "lock_issue"("issue_id_p");
jbe@0 3037 PERFORM "create_population_snapshot"("issue_id_p");
jbe@0 3038 PERFORM "create_interest_snapshot"("issue_id_p");
jbe@0 3039 UPDATE "issue" SET
jbe@8 3040 "snapshot" = now(),
jbe@8 3041 "latest_snapshot_event" = 'periodic',
jbe@0 3042 "population" = (
jbe@0 3043 SELECT coalesce(sum("weight"), 0)
jbe@0 3044 FROM "direct_population_snapshot"
jbe@0 3045 WHERE "issue_id" = "issue_id_p"
jbe@0 3046 AND "event" = 'periodic'
jbe@0 3047 )
jbe@0 3048 WHERE "id" = "issue_id_p";
jbe@0 3049 FOR "initiative_id_v" IN
jbe@0 3050 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
jbe@0 3051 LOOP
jbe@0 3052 UPDATE "initiative" SET
jbe@0 3053 "supporter_count" = (
jbe@0 3054 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3055 FROM "direct_interest_snapshot" AS "di"
jbe@0 3056 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3057 ON "di"."member_id" = "ds"."member_id"
jbe@0 3058 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3059 AND "di"."event" = 'periodic'
jbe@0 3060 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3061 AND "ds"."event" = 'periodic'
jbe@0 3062 ),
jbe@0 3063 "informed_supporter_count" = (
jbe@0 3064 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3065 FROM "direct_interest_snapshot" AS "di"
jbe@0 3066 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3067 ON "di"."member_id" = "ds"."member_id"
jbe@0 3068 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3069 AND "di"."event" = 'periodic'
jbe@0 3070 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3071 AND "ds"."event" = 'periodic'
jbe@0 3072 AND "ds"."informed"
jbe@0 3073 ),
jbe@0 3074 "satisfied_supporter_count" = (
jbe@0 3075 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3076 FROM "direct_interest_snapshot" AS "di"
jbe@0 3077 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3078 ON "di"."member_id" = "ds"."member_id"
jbe@0 3079 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3080 AND "di"."event" = 'periodic'
jbe@0 3081 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3082 AND "ds"."event" = 'periodic'
jbe@0 3083 AND "ds"."satisfied"
jbe@0 3084 ),
jbe@0 3085 "satisfied_informed_supporter_count" = (
jbe@0 3086 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3087 FROM "direct_interest_snapshot" AS "di"
jbe@0 3088 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3089 ON "di"."member_id" = "ds"."member_id"
jbe@0 3090 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3091 AND "di"."event" = 'periodic'
jbe@0 3092 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3093 AND "ds"."event" = 'periodic'
jbe@0 3094 AND "ds"."informed"
jbe@0 3095 AND "ds"."satisfied"
jbe@0 3096 )
jbe@0 3097 WHERE "id" = "initiative_id_v";
jbe@0 3098 FOR "suggestion_id_v" IN
jbe@0 3099 SELECT "id" FROM "suggestion"
jbe@0 3100 WHERE "initiative_id" = "initiative_id_v"
jbe@0 3101 LOOP
jbe@0 3102 UPDATE "suggestion" SET
jbe@0 3103 "minus2_unfulfilled_count" = (
jbe@0 3104 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3105 FROM "issue" CROSS JOIN "opinion"
jbe@36 3106 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3107 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3108 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3109 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3110 WHERE "issue"."id" = "issue_id_p"
jbe@36 3111 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3112 AND "opinion"."degree" = -2
jbe@0 3113 AND "opinion"."fulfilled" = FALSE
jbe@0 3114 ),
jbe@0 3115 "minus2_fulfilled_count" = (
jbe@0 3116 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3117 FROM "issue" CROSS JOIN "opinion"
jbe@36 3118 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3119 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3120 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3121 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3122 WHERE "issue"."id" = "issue_id_p"
jbe@36 3123 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3124 AND "opinion"."degree" = -2
jbe@0 3125 AND "opinion"."fulfilled" = TRUE
jbe@0 3126 ),
jbe@0 3127 "minus1_unfulfilled_count" = (
jbe@0 3128 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3129 FROM "issue" CROSS JOIN "opinion"
jbe@36 3130 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3131 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3132 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3133 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3134 WHERE "issue"."id" = "issue_id_p"
jbe@36 3135 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3136 AND "opinion"."degree" = -1
jbe@0 3137 AND "opinion"."fulfilled" = FALSE
jbe@0 3138 ),
jbe@0 3139 "minus1_fulfilled_count" = (
jbe@0 3140 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3141 FROM "issue" CROSS JOIN "opinion"
jbe@36 3142 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3143 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3144 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3145 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3146 WHERE "issue"."id" = "issue_id_p"
jbe@36 3147 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3148 AND "opinion"."degree" = -1
jbe@0 3149 AND "opinion"."fulfilled" = TRUE
jbe@0 3150 ),
jbe@0 3151 "plus1_unfulfilled_count" = (
jbe@0 3152 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3153 FROM "issue" CROSS JOIN "opinion"
jbe@36 3154 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3155 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3156 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3157 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3158 WHERE "issue"."id" = "issue_id_p"
jbe@36 3159 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3160 AND "opinion"."degree" = 1
jbe@0 3161 AND "opinion"."fulfilled" = FALSE
jbe@0 3162 ),
jbe@0 3163 "plus1_fulfilled_count" = (
jbe@0 3164 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3165 FROM "issue" CROSS JOIN "opinion"
jbe@36 3166 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3167 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3168 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3169 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3170 WHERE "issue"."id" = "issue_id_p"
jbe@36 3171 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3172 AND "opinion"."degree" = 1
jbe@0 3173 AND "opinion"."fulfilled" = TRUE
jbe@0 3174 ),
jbe@0 3175 "plus2_unfulfilled_count" = (
jbe@0 3176 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3177 FROM "issue" CROSS JOIN "opinion"
jbe@36 3178 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3179 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3180 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3181 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3182 WHERE "issue"."id" = "issue_id_p"
jbe@36 3183 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3184 AND "opinion"."degree" = 2
jbe@0 3185 AND "opinion"."fulfilled" = FALSE
jbe@0 3186 ),
jbe@0 3187 "plus2_fulfilled_count" = (
jbe@0 3188 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3189 FROM "issue" CROSS JOIN "opinion"
jbe@36 3190 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3191 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3192 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3193 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3194 WHERE "issue"."id" = "issue_id_p"
jbe@36 3195 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3196 AND "opinion"."degree" = 2
jbe@0 3197 AND "opinion"."fulfilled" = TRUE
jbe@0 3198 )
jbe@0 3199 WHERE "suggestion"."id" = "suggestion_id_v";
jbe@0 3200 END LOOP;
jbe@0 3201 END LOOP;
jbe@0 3202 RETURN;
jbe@0 3203 END;
jbe@0 3204 $$;
jbe@0 3205
jbe@0 3206 COMMENT ON FUNCTION "create_snapshot"
jbe@0 3207 ( "issue"."id"%TYPE )
jbe@0 3208 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 3209
jbe@0 3210
jbe@0 3211 CREATE FUNCTION "set_snapshot_event"
jbe@0 3212 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 3213 "event_p" "snapshot_event" )
jbe@0 3214 RETURNS VOID
jbe@0 3215 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@21 3216 DECLARE
jbe@21 3217 "event_v" "issue"."latest_snapshot_event"%TYPE;
jbe@0 3218 BEGIN
jbe@21 3219 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
jbe@21 3220 WHERE "id" = "issue_id_p" FOR UPDATE;
jbe@8 3221 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
jbe@8 3222 WHERE "id" = "issue_id_p";
jbe@3 3223 UPDATE "direct_population_snapshot" SET "event" = "event_p"
jbe@21 3224 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 3225 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
jbe@21 3226 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 3227 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
jbe@21 3228 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 3229 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
jbe@21 3230 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 3231 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
jbe@21 3232 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@0 3233 RETURN;
jbe@0 3234 END;
jbe@0 3235 $$;
jbe@0 3236
jbe@0 3237 COMMENT ON FUNCTION "set_snapshot_event"
jbe@0 3238 ( "issue"."id"%TYPE,
jbe@0 3239 "snapshot_event" )
jbe@0 3240 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
jbe@0 3241
jbe@0 3242
jbe@0 3243
jbe@0 3244 ---------------------
jbe@0 3245 -- Freezing issues --
jbe@0 3246 ---------------------
jbe@0 3247
jbe@0 3248 CREATE FUNCTION "freeze_after_snapshot"
jbe@0 3249 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3250 RETURNS VOID
jbe@0 3251 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3252 DECLARE
jbe@0 3253 "issue_row" "issue"%ROWTYPE;
jbe@0 3254 "policy_row" "policy"%ROWTYPE;
jbe@0 3255 "initiative_row" "initiative"%ROWTYPE;
jbe@0 3256 BEGIN
jbe@0 3257 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@0 3258 SELECT * INTO "policy_row"
jbe@0 3259 FROM "policy" WHERE "id" = "issue_row"."policy_id";
jbe@21 3260 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
jbe@0 3261 FOR "initiative_row" IN
jbe@15 3262 SELECT * FROM "initiative"
jbe@15 3263 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@0 3264 LOOP
jbe@0 3265 IF
jbe@0 3266 "initiative_row"."satisfied_supporter_count" > 0 AND
jbe@0 3267 "initiative_row"."satisfied_supporter_count" *
jbe@0 3268 "policy_row"."initiative_quorum_den" >=
jbe@0 3269 "issue_row"."population" * "policy_row"."initiative_quorum_num"
jbe@0 3270 THEN
jbe@0 3271 UPDATE "initiative" SET "admitted" = TRUE
jbe@0 3272 WHERE "id" = "initiative_row"."id";
jbe@0 3273 ELSE
jbe@0 3274 UPDATE "initiative" SET "admitted" = FALSE
jbe@0 3275 WHERE "id" = "initiative_row"."id";
jbe@0 3276 END IF;
jbe@0 3277 END LOOP;
jbe@113 3278 IF EXISTS (
jbe@9 3279 SELECT NULL FROM "initiative"
jbe@9 3280 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
jbe@9 3281 ) THEN
jbe@113 3282 UPDATE "issue" SET
jbe@113 3283 "state" = 'voting',
jbe@113 3284 "accepted" = coalesce("accepted", now()),
jbe@113 3285 "half_frozen" = coalesce("half_frozen", now()),
jbe@113 3286 "fully_frozen" = now()
jbe@113 3287 WHERE "id" = "issue_id_p";
jbe@113 3288 ELSE
jbe@113 3289 UPDATE "issue" SET
jbe@121 3290 "state" = 'canceled_no_initiative_admitted',
jbe@121 3291 "accepted" = coalesce("accepted", now()),
jbe@121 3292 "half_frozen" = coalesce("half_frozen", now()),
jbe@121 3293 "fully_frozen" = now(),
jbe@121 3294 "closed" = now(),
jbe@121 3295 "ranks_available" = TRUE
jbe@113 3296 WHERE "id" = "issue_id_p";
jbe@113 3297 -- NOTE: The following DELETE statements have effect only when
jbe@113 3298 -- issue state has been manipulated
jbe@113 3299 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
jbe@113 3300 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
jbe@113 3301 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@9 3302 END IF;
jbe@0 3303 RETURN;
jbe@0 3304 END;
jbe@0 3305 $$;
jbe@0 3306
jbe@0 3307 COMMENT ON FUNCTION "freeze_after_snapshot"
jbe@0 3308 ( "issue"."id"%TYPE )
jbe@9 3309 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 3310
jbe@0 3311
jbe@0 3312 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
jbe@0 3313 RETURNS VOID
jbe@0 3314 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3315 DECLARE
jbe@0 3316 "issue_row" "issue"%ROWTYPE;
jbe@0 3317 BEGIN
jbe@0 3318 PERFORM "create_snapshot"("issue_id_p");
jbe@0 3319 PERFORM "freeze_after_snapshot"("issue_id_p");
jbe@0 3320 RETURN;
jbe@0 3321 END;
jbe@0 3322 $$;
jbe@0 3323
jbe@55 3324 COMMENT ON FUNCTION "manual_freeze"
jbe@0 3325 ( "issue"."id"%TYPE )
jbe@3 3326 IS 'Freeze an issue manually (fully) and start voting';
jbe@0 3327
jbe@0 3328
jbe@0 3329
jbe@0 3330 -----------------------
jbe@0 3331 -- Counting of votes --
jbe@0 3332 -----------------------
jbe@0 3333
jbe@0 3334
jbe@5 3335 CREATE FUNCTION "weight_of_added_vote_delegations"
jbe@0 3336 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 3337 "member_id_p" "member"."id"%TYPE,
jbe@0 3338 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
jbe@0 3339 RETURNS "direct_voter"."weight"%TYPE
jbe@0 3340 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3341 DECLARE
jbe@0 3342 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 3343 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
jbe@0 3344 "weight_v" INT4;
jbe@8 3345 "sub_weight_v" INT4;
jbe@0 3346 BEGIN
jbe@0 3347 "weight_v" := 0;
jbe@0 3348 FOR "issue_delegation_row" IN
jbe@0 3349 SELECT * FROM "issue_delegation"
jbe@0 3350 WHERE "trustee_id" = "member_id_p"
jbe@0 3351 AND "issue_id" = "issue_id_p"
jbe@0 3352 LOOP
jbe@0 3353 IF NOT EXISTS (
jbe@0 3354 SELECT NULL FROM "direct_voter"
jbe@0 3355 WHERE "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3356 AND "issue_id" = "issue_id_p"
jbe@0 3357 ) AND NOT EXISTS (
jbe@0 3358 SELECT NULL FROM "delegating_voter"
jbe@0 3359 WHERE "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3360 AND "issue_id" = "issue_id_p"
jbe@0 3361 ) THEN
jbe@0 3362 "delegate_member_ids_v" :=
jbe@0 3363 "member_id_p" || "delegate_member_ids_p";
jbe@10 3364 INSERT INTO "delegating_voter" (
jbe@10 3365 "issue_id",
jbe@10 3366 "member_id",
jbe@10 3367 "scope",
jbe@10 3368 "delegate_member_ids"
jbe@10 3369 ) VALUES (
jbe@5 3370 "issue_id_p",
jbe@5 3371 "issue_delegation_row"."truster_id",
jbe@10 3372 "issue_delegation_row"."scope",
jbe@5 3373 "delegate_member_ids_v"
jbe@5 3374 );
jbe@8 3375 "sub_weight_v" := 1 +
jbe@8 3376 "weight_of_added_vote_delegations"(
jbe@8 3377 "issue_id_p",
jbe@8 3378 "issue_delegation_row"."truster_id",
jbe@8 3379 "delegate_member_ids_v"
jbe@8 3380 );
jbe@8 3381 UPDATE "delegating_voter"
jbe@8 3382 SET "weight" = "sub_weight_v"
jbe@8 3383 WHERE "issue_id" = "issue_id_p"
jbe@8 3384 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 3385 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 3386 END IF;
jbe@0 3387 END LOOP;
jbe@0 3388 RETURN "weight_v";
jbe@0 3389 END;
jbe@0 3390 $$;
jbe@0 3391
jbe@5 3392 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
jbe@0 3393 ( "issue"."id"%TYPE,
jbe@0 3394 "member"."id"%TYPE,
jbe@0 3395 "delegating_voter"."delegate_member_ids"%TYPE )
jbe@0 3396 IS 'Helper function for "add_vote_delegations" function';
jbe@0 3397
jbe@0 3398
jbe@0 3399 CREATE FUNCTION "add_vote_delegations"
jbe@0 3400 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3401 RETURNS VOID
jbe@0 3402 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3403 DECLARE
jbe@0 3404 "member_id_v" "member"."id"%TYPE;
jbe@0 3405 BEGIN
jbe@0 3406 FOR "member_id_v" IN
jbe@0 3407 SELECT "member_id" FROM "direct_voter"
jbe@0 3408 WHERE "issue_id" = "issue_id_p"
jbe@0 3409 LOOP
jbe@0 3410 UPDATE "direct_voter" SET
jbe@5 3411 "weight" = "weight" + "weight_of_added_vote_delegations"(
jbe@0 3412 "issue_id_p",
jbe@0 3413 "member_id_v",
jbe@0 3414 '{}'
jbe@0 3415 )
jbe@0 3416 WHERE "member_id" = "member_id_v"
jbe@0 3417 AND "issue_id" = "issue_id_p";
jbe@0 3418 END LOOP;
jbe@0 3419 RETURN;
jbe@0 3420 END;
jbe@0 3421 $$;
jbe@0 3422
jbe@0 3423 COMMENT ON FUNCTION "add_vote_delegations"
jbe@0 3424 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3425 IS 'Helper function for "close_voting" function';
jbe@0 3426
jbe@0 3427
jbe@0 3428 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
jbe@0 3429 RETURNS VOID
jbe@0 3430 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3431 DECLARE
jbe@97 3432 "area_id_v" "area"."id"%TYPE;
jbe@97 3433 "unit_id_v" "unit"."id"%TYPE;
jbe@0 3434 "member_id_v" "member"."id"%TYPE;
jbe@0 3435 BEGIN
jbe@67 3436 PERFORM "lock_issue"("issue_id_p");
jbe@129 3437 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
jbe@129 3438 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
jbe@169 3439 -- delete delegating votes (in cases of manual reset of issue state):
jbe@0 3440 DELETE FROM "delegating_voter"
jbe@0 3441 WHERE "issue_id" = "issue_id_p";
jbe@169 3442 -- delete votes from non-privileged voters:
jbe@97 3443 DELETE FROM "direct_voter"
jbe@97 3444 USING (
jbe@97 3445 SELECT
jbe@97 3446 "direct_voter"."member_id"
jbe@97 3447 FROM "direct_voter"
jbe@97 3448 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
jbe@97 3449 LEFT JOIN "privilege"
jbe@97 3450 ON "privilege"."unit_id" = "unit_id_v"
jbe@97 3451 AND "privilege"."member_id" = "direct_voter"."member_id"
jbe@97 3452 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
jbe@97 3453 "member"."active" = FALSE OR
jbe@97 3454 "privilege"."voting_right" ISNULL OR
jbe@97 3455 "privilege"."voting_right" = FALSE
jbe@97 3456 )
jbe@97 3457 ) AS "subquery"
jbe@97 3458 WHERE "direct_voter"."issue_id" = "issue_id_p"
jbe@97 3459 AND "direct_voter"."member_id" = "subquery"."member_id";
jbe@169 3460 -- consider delegations:
jbe@0 3461 UPDATE "direct_voter" SET "weight" = 1
jbe@0 3462 WHERE "issue_id" = "issue_id_p";
jbe@0 3463 PERFORM "add_vote_delegations"("issue_id_p");
jbe@137 3464 -- set voter count and mark issue as being calculated:
jbe@4 3465 UPDATE "issue" SET
jbe@111 3466 "state" = 'calculation',
jbe@61 3467 "closed" = now(),
jbe@4 3468 "voter_count" = (
jbe@4 3469 SELECT coalesce(sum("weight"), 0)
jbe@4 3470 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
jbe@6 3471 )
jbe@6 3472 WHERE "id" = "issue_id_p";
jbe@137 3473 -- materialize battle_view:
jbe@61 3474 -- NOTE: "closed" column of issue must be set at this point
jbe@61 3475 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@61 3476 INSERT INTO "battle" (
jbe@61 3477 "issue_id",
jbe@61 3478 "winning_initiative_id", "losing_initiative_id",
jbe@61 3479 "count"
jbe@61 3480 ) SELECT
jbe@61 3481 "issue_id",
jbe@61 3482 "winning_initiative_id", "losing_initiative_id",
jbe@61 3483 "count"
jbe@61 3484 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
jbe@155 3485 -- copy "positive_votes" and "negative_votes" from "battle" table:
jbe@155 3486 UPDATE "initiative" SET
jbe@155 3487 "positive_votes" = "battle_win"."count",
jbe@155 3488 "negative_votes" = "battle_lose"."count"
jbe@155 3489 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
jbe@155 3490 WHERE
jbe@155 3491 "battle_win"."issue_id" = "issue_id_p" AND
jbe@155 3492 "battle_win"."winning_initiative_id" = "initiative"."id" AND
jbe@155 3493 "battle_win"."losing_initiative_id" ISNULL AND
jbe@155 3494 "battle_lose"."issue_id" = "issue_id_p" AND
jbe@155 3495 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
jbe@155 3496 "battle_lose"."winning_initiative_id" ISNULL;
jbe@0 3497 END;
jbe@0 3498 $$;
jbe@0 3499
jbe@0 3500 COMMENT ON FUNCTION "close_voting"
jbe@0 3501 ( "issue"."id"%TYPE )
jbe@0 3502 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 3503
jbe@0 3504
jbe@30 3505 CREATE FUNCTION "defeat_strength"
jbe@30 3506 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
jbe@30 3507 RETURNS INT8
jbe@30 3508 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@30 3509 BEGIN
jbe@30 3510 IF "positive_votes_p" > "negative_votes_p" THEN
jbe@30 3511 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
jbe@30 3512 ELSIF "positive_votes_p" = "negative_votes_p" THEN
jbe@30 3513 RETURN 0;
jbe@30 3514 ELSE
jbe@30 3515 RETURN -1;
jbe@30 3516 END IF;
jbe@30 3517 END;
jbe@30 3518 $$;
jbe@30 3519
jbe@30 3520 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 3521
jbe@30 3522
jbe@0 3523 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
jbe@0 3524 RETURNS VOID
jbe@0 3525 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3526 DECLARE
jbe@155 3527 "issue_row" "issue"%ROWTYPE;
jbe@155 3528 "policy_row" "policy"%ROWTYPE;
jbe@134 3529 "dimension_v" INTEGER;
jbe@134 3530 "vote_matrix" INT4[][]; -- absolute votes
jbe@134 3531 "matrix" INT8[][]; -- defeat strength / best paths
jbe@134 3532 "i" INTEGER;
jbe@134 3533 "j" INTEGER;
jbe@134 3534 "k" INTEGER;
jbe@134 3535 "battle_row" "battle"%ROWTYPE;
jbe@134 3536 "rank_ary" INT4[];
jbe@134 3537 "rank_v" INT4;
jbe@134 3538 "done_v" INTEGER;
jbe@134 3539 "winners_ary" INTEGER[];
jbe@134 3540 "initiative_id_v" "initiative"."id"%TYPE;
jbe@0 3541 BEGIN
jbe@155 3542 SELECT * INTO "issue_row"
jbe@155 3543 FROM "issue" WHERE "id" = "issue_id_p"
jbe@155 3544 FOR UPDATE;
jbe@155 3545 SELECT * INTO "policy_row"
jbe@155 3546 FROM "policy" WHERE "id" = "issue_row"."policy_id";
jbe@126 3547 SELECT count(1) INTO "dimension_v"
jbe@126 3548 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
jbe@170 3549 -- Create "vote_matrix" with absolute number of votes in pairwise
jbe@170 3550 -- comparison:
jbe@170 3551 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
jbe@170 3552 "i" := 1;
jbe@170 3553 "j" := 2;
jbe@170 3554 FOR "battle_row" IN
jbe@170 3555 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
jbe@170 3556 ORDER BY
jbe@170 3557 "winning_initiative_id" NULLS LAST,
jbe@170 3558 "losing_initiative_id" NULLS LAST
jbe@170 3559 LOOP
jbe@170 3560 "vote_matrix"["i"]["j"] := "battle_row"."count";
jbe@170 3561 IF "j" = "dimension_v" THEN
jbe@170 3562 "i" := "i" + 1;
jbe@170 3563 "j" := 1;
jbe@170 3564 ELSE
jbe@170 3565 "j" := "j" + 1;
jbe@170 3566 IF "j" = "i" THEN
jbe@170 3567 "j" := "j" + 1;
jbe@170 3568 END IF;
jbe@170 3569 END IF;
jbe@170 3570 END LOOP;
jbe@170 3571 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
jbe@170 3572 RAISE EXCEPTION 'Wrong battle count (should not happen)';
jbe@170 3573 END IF;
jbe@170 3574 -- Store defeat strengths in "matrix" using "defeat_strength"
jbe@170 3575 -- function:
jbe@170 3576 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
jbe@170 3577 "i" := 1;
jbe@170 3578 LOOP
jbe@170 3579 "j" := 1;
jbe@0 3580 LOOP
jbe@170 3581 IF "i" != "j" THEN
jbe@170 3582 "matrix"["i"]["j"] := "defeat_strength"(
jbe@170 3583 "vote_matrix"["i"]["j"],
jbe@170 3584 "vote_matrix"["j"]["i"]
jbe@170 3585 );
jbe@0 3586 END IF;
jbe@170 3587 EXIT WHEN "j" = "dimension_v";
jbe@170 3588 "j" := "j" + 1;
jbe@0 3589 END LOOP;
jbe@170 3590 EXIT WHEN "i" = "dimension_v";
jbe@170 3591 "i" := "i" + 1;
jbe@170 3592 END LOOP;
jbe@170 3593 -- Find best paths:
jbe@170 3594 "i" := 1;
jbe@170 3595 LOOP
jbe@170 3596 "j" := 1;
jbe@170 3597 LOOP
jbe@170 3598 IF "i" != "j" THEN
jbe@170 3599 "k" := 1;
jbe@170 3600 LOOP
jbe@170 3601 IF "i" != "k" AND "j" != "k" THEN
jbe@170 3602 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
jbe@170 3603 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
jbe@170 3604 "matrix"["j"]["k"] := "matrix"["j"]["i"];
jbe@170 3605 END IF;
jbe@170 3606 ELSE
jbe@170 3607 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
jbe@170 3608 "matrix"["j"]["k"] := "matrix"["i"]["k"];
jbe@170 3609 END IF;
jbe@170 3610 END IF;
jbe@170 3611 END IF;
jbe@170 3612 EXIT WHEN "k" = "dimension_v";
jbe@170 3613 "k" := "k" + 1;
jbe@170 3614 END LOOP;
jbe@170 3615 END IF;
jbe@170 3616 EXIT WHEN "j" = "dimension_v";
jbe@170 3617 "j" := "j" + 1;
jbe@170 3618 END LOOP;
jbe@170 3619 EXIT WHEN "i" = "dimension_v";
jbe@170 3620 "i" := "i" + 1;
jbe@170 3621 END LOOP;
jbe@170 3622 -- Determine order of winners:
jbe@170 3623 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
jbe@170 3624 "rank_v" := 1;
jbe@170 3625 "done_v" := 0;
jbe@170 3626 LOOP
jbe@170 3627 "winners_ary" := '{}';
jbe@0 3628 "i" := 1;
jbe@0 3629 LOOP
jbe@170 3630 IF "rank_ary"["i"] ISNULL THEN
jbe@170 3631 "j" := 1;
jbe@170 3632 LOOP
jbe@170 3633 IF
jbe@170 3634 "i" != "j" AND
jbe@170 3635 "rank_ary"["j"] ISNULL AND
jbe@170 3636 "matrix"["j"]["i"] > "matrix"["i"]["j"]
jbe@170 3637 THEN
jbe@170 3638 -- someone else is better
jbe@170 3639 EXIT;
jbe@170 3640 END IF;
jbe@170 3641 IF "j" = "dimension_v" THEN
jbe@170 3642 -- noone is better
jbe@170 3643 "winners_ary" := "winners_ary" || "i";
jbe@170 3644 EXIT;
jbe@170 3645 END IF;
jbe@170 3646 "j" := "j" + 1;
jbe@170 3647 END LOOP;
jbe@170 3648 END IF;
jbe@30 3649 EXIT WHEN "i" = "dimension_v";
jbe@0 3650 "i" := "i" + 1;
jbe@0 3651 END LOOP;
jbe@0 3652 "i" := 1;
jbe@0 3653 LOOP
jbe@170 3654 "rank_ary"["winners_ary"["i"]] := "rank_v";
jbe@170 3655 "done_v" := "done_v" + 1;
jbe@170 3656 EXIT WHEN "i" = array_upper("winners_ary", 1);
jbe@0 3657 "i" := "i" + 1;
jbe@0 3658 END LOOP;
jbe@170 3659 EXIT WHEN "done_v" = "dimension_v";
jbe@170 3660 "rank_v" := "rank_v" + 1;
jbe@170 3661 END LOOP;
jbe@170 3662 -- write preliminary results:
jbe@170 3663 "i" := 1;
jbe@170 3664 FOR "initiative_id_v" IN
jbe@170 3665 SELECT "id" FROM "initiative"
jbe@170 3666 WHERE "issue_id" = "issue_id_p" AND "admitted"
jbe@170 3667 ORDER BY "id"
jbe@170 3668 LOOP
jbe@170 3669 UPDATE "initiative" SET
jbe@170 3670 "direct_majority" =
jbe@170 3671 CASE WHEN "policy_row"."direct_majority_strict" THEN
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 ELSE
jbe@170 3675 "positive_votes" * "policy_row"."direct_majority_den" >=
jbe@170 3676 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 3677 END
jbe@170 3678 AND "positive_votes" >= "policy_row"."direct_majority_positive"
jbe@170 3679 AND "issue_row"."voter_count"-"negative_votes" >=
jbe@170 3680 "policy_row"."direct_majority_non_negative",
jbe@170 3681 "indirect_majority" =
jbe@170 3682 CASE WHEN "policy_row"."indirect_majority_strict" THEN
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 ELSE
jbe@170 3686 "positive_votes" * "policy_row"."indirect_majority_den" >=
jbe@170 3687 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 3688 END
jbe@170 3689 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
jbe@170 3690 AND "issue_row"."voter_count"-"negative_votes" >=
jbe@170 3691 "policy_row"."indirect_majority_non_negative",
jbe@171 3692 "schulze_rank" = "rank_ary"["i"],
jbe@170 3693 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
jbe@170 3694 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
jbe@170 3695 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
jbe@172 3696 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
jbe@172 3697 "winner" = FALSE
jbe@170 3698 WHERE "id" = "initiative_id_v";
jbe@170 3699 "i" := "i" + 1;
jbe@170 3700 END LOOP;
jbe@170 3701 IF "i" != "dimension_v" THEN
jbe@170 3702 RAISE EXCEPTION 'Wrong winner count (should not happen)';
jbe@0 3703 END IF;
jbe@170 3704 -- take indirect majorities into account:
jbe@170 3705 LOOP
jbe@170 3706 UPDATE "initiative" SET "indirect_majority" = TRUE
jbe@139 3707 FROM (
jbe@170 3708 SELECT "new_initiative"."id" AS "initiative_id"
jbe@170 3709 FROM "initiative" "old_initiative"
jbe@170 3710 JOIN "initiative" "new_initiative"
jbe@170 3711 ON "new_initiative"."issue_id" = "issue_id_p"
jbe@170 3712 AND "new_initiative"."indirect_majority" = FALSE
jbe@139 3713 JOIN "battle" "battle_win"
jbe@139 3714 ON "battle_win"."issue_id" = "issue_id_p"
jbe@170 3715 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
jbe@170 3716 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
jbe@139 3717 JOIN "battle" "battle_lose"
jbe@139 3718 ON "battle_lose"."issue_id" = "issue_id_p"
jbe@170 3719 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
jbe@170 3720 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
jbe@170 3721 WHERE "old_initiative"."issue_id" = "issue_id_p"
jbe@170 3722 AND "old_initiative"."indirect_majority" = TRUE
jbe@170 3723 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
jbe@170 3724 "battle_win"."count" * "policy_row"."indirect_majority_den" >
jbe@170 3725 "policy_row"."indirect_majority_num" *
jbe@170 3726 ("battle_win"."count"+"battle_lose"."count")
jbe@170 3727 ELSE
jbe@170 3728 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
jbe@170 3729 "policy_row"."indirect_majority_num" *
jbe@170 3730 ("battle_win"."count"+"battle_lose"."count")
jbe@170 3731 END
jbe@170 3732 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
jbe@170 3733 AND "issue_row"."voter_count"-"battle_lose"."count" >=
jbe@170 3734 "policy_row"."indirect_majority_non_negative"
jbe@139 3735 ) AS "subquery"
jbe@139 3736 WHERE "id" = "subquery"."initiative_id";
jbe@170 3737 EXIT WHEN NOT FOUND;
jbe@170 3738 END LOOP;
jbe@170 3739 -- set "multistage_majority" for remaining matching initiatives:
jbe@170 3740 UPDATE "initiative" SET "multistage_majority" = TRUE
jbe@170 3741 FROM (
jbe@170 3742 SELECT "losing_initiative"."id" AS "initiative_id"
jbe@170 3743 FROM "initiative" "losing_initiative"
jbe@170 3744 JOIN "initiative" "winning_initiative"
jbe@170 3745 ON "winning_initiative"."issue_id" = "issue_id_p"
jbe@170 3746 AND "winning_initiative"."admitted"
jbe@170 3747 JOIN "battle" "battle_win"
jbe@170 3748 ON "battle_win"."issue_id" = "issue_id_p"
jbe@170 3749 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
jbe@170 3750 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
jbe@170 3751 JOIN "battle" "battle_lose"
jbe@170 3752 ON "battle_lose"."issue_id" = "issue_id_p"
jbe@170 3753 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
jbe@170 3754 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
jbe@170 3755 WHERE "losing_initiative"."issue_id" = "issue_id_p"
jbe@170 3756 AND "losing_initiative"."admitted"
jbe@170 3757 AND "winning_initiative"."schulze_rank" <
jbe@170 3758 "losing_initiative"."schulze_rank"
jbe@170 3759 AND "battle_win"."count" > "battle_lose"."count"
jbe@170 3760 AND (
jbe@170 3761 "battle_win"."count" > "winning_initiative"."positive_votes" OR
jbe@170 3762 "battle_lose"."count" < "losing_initiative"."negative_votes" )
jbe@170 3763 ) AS "subquery"
jbe@170 3764 WHERE "id" = "subquery"."initiative_id";
jbe@170 3765 -- mark eligible initiatives:
jbe@170 3766 UPDATE "initiative" SET "eligible" = TRUE
jbe@171 3767 WHERE "issue_id" = "issue_id_p"
jbe@171 3768 AND "initiative"."direct_majority"
jbe@171 3769 AND "initiative"."indirect_majority"
jbe@171 3770 AND "initiative"."better_than_status_quo"
jbe@171 3771 AND (
jbe@171 3772 "policy_row"."no_multistage_majority" = FALSE OR
jbe@171 3773 "initiative"."multistage_majority" = FALSE )
jbe@171 3774 AND (
jbe@171 3775 "policy_row"."no_reverse_beat_path" = FALSE OR
jbe@171 3776 "initiative"."reverse_beat_path" = FALSE );
jbe@170 3777 -- mark final winner:
jbe@170 3778 UPDATE "initiative" SET "winner" = TRUE
jbe@170 3779 FROM (
jbe@170 3780 SELECT "id" AS "initiative_id"
jbe@170 3781 FROM "initiative"
jbe@170 3782 WHERE "issue_id" = "issue_id_p" AND "eligible"
jbe@170 3783 ORDER BY "schulze_rank", "id"
jbe@170 3784 LIMIT 1
jbe@170 3785 ) AS "subquery"
jbe@170 3786 WHERE "id" = "subquery"."initiative_id";
jbe@173 3787 -- write (final) ranks:
jbe@173 3788 "rank_v" := 1;
jbe@173 3789 FOR "initiative_id_v" IN
jbe@173 3790 SELECT "id"
jbe@173 3791 FROM "initiative"
jbe@173 3792 WHERE "issue_id" = "issue_id_p" AND "admitted"
jbe@174 3793 ORDER BY
jbe@174 3794 "winner" DESC,
jbe@174 3795 ("direct_majority" AND "indirect_majority") DESC,
jbe@174 3796 "schulze_rank",
jbe@174 3797 "id"
jbe@173 3798 LOOP
jbe@173 3799 UPDATE "initiative" SET "rank" = "rank_v"
jbe@173 3800 WHERE "id" = "initiative_id_v";
jbe@173 3801 "rank_v" := "rank_v" + 1;
jbe@173 3802 END LOOP;
jbe@170 3803 -- set schulze rank of status quo and mark issue as finished:
jbe@111 3804 UPDATE "issue" SET
jbe@170 3805 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
jbe@111 3806 "state" =
jbe@139 3807 CASE WHEN EXISTS (
jbe@139 3808 SELECT NULL FROM "initiative"
jbe@139 3809 WHERE "issue_id" = "issue_id_p" AND "winner"
jbe@139 3810 ) THEN
jbe@139 3811 'finished_with_winner'::"issue_state"
jbe@139 3812 ELSE
jbe@121 3813 'finished_without_winner'::"issue_state"
jbe@111 3814 END,
jbe@111 3815 "ranks_available" = TRUE
jbe@0 3816 WHERE "id" = "issue_id_p";
jbe@0 3817 RETURN;
jbe@0 3818 END;
jbe@0 3819 $$;
jbe@0 3820
jbe@0 3821 COMMENT ON FUNCTION "calculate_ranks"
jbe@0 3822 ( "issue"."id"%TYPE )
jbe@0 3823 IS 'Determine ranking (Votes have to be counted first)';
jbe@0 3824
jbe@0 3825
jbe@0 3826
jbe@0 3827 -----------------------------
jbe@0 3828 -- Automatic state changes --
jbe@0 3829 -----------------------------
jbe@0 3830
jbe@0 3831
jbe@0 3832 CREATE FUNCTION "check_issue"
jbe@0 3833 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3834 RETURNS VOID
jbe@0 3835 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3836 DECLARE
jbe@0 3837 "issue_row" "issue"%ROWTYPE;
jbe@0 3838 "policy_row" "policy"%ROWTYPE;
jbe@0 3839 BEGIN
jbe@67 3840 PERFORM "lock_issue"("issue_id_p");
jbe@0 3841 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@24 3842 -- only process open issues:
jbe@0 3843 IF "issue_row"."closed" ISNULL THEN
jbe@0 3844 SELECT * INTO "policy_row" FROM "policy"
jbe@0 3845 WHERE "id" = "issue_row"."policy_id";
jbe@24 3846 -- create a snapshot, unless issue is already fully frozen:
jbe@3 3847 IF "issue_row"."fully_frozen" ISNULL THEN
jbe@0 3848 PERFORM "create_snapshot"("issue_id_p");
jbe@0 3849 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@0 3850 END IF;
jbe@24 3851 -- eventually close or accept issues, which have not been accepted:
jbe@0 3852 IF "issue_row"."accepted" ISNULL THEN
jbe@0 3853 IF EXISTS (
jbe@0 3854 SELECT NULL FROM "initiative"
jbe@0 3855 WHERE "issue_id" = "issue_id_p"
jbe@0 3856 AND "supporter_count" > 0
jbe@0 3857 AND "supporter_count" * "policy_row"."issue_quorum_den"
jbe@0 3858 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
jbe@0 3859 ) THEN
jbe@24 3860 -- accept issues, if supporter count is high enough
jbe@3 3861 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
jbe@111 3862 -- NOTE: "issue_row" used later
jbe@111 3863 "issue_row"."state" := 'discussion';
jbe@111 3864 "issue_row"."accepted" := now();
jbe@111 3865 UPDATE "issue" SET
jbe@111 3866 "state" = "issue_row"."state",
jbe@111 3867 "accepted" = "issue_row"."accepted"
jbe@0 3868 WHERE "id" = "issue_row"."id";
jbe@0 3869 ELSIF
jbe@22 3870 now() >= "issue_row"."created" + "issue_row"."admission_time"
jbe@0 3871 THEN
jbe@24 3872 -- close issues, if admission time has expired
jbe@0 3873 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
jbe@111 3874 UPDATE "issue" SET
jbe@111 3875 "state" = 'canceled_issue_not_accepted',
jbe@111 3876 "closed" = now()
jbe@0 3877 WHERE "id" = "issue_row"."id";
jbe@0 3878 END IF;
jbe@0 3879 END IF;
jbe@24 3880 -- eventually half freeze issues:
jbe@0 3881 IF
jbe@24 3882 -- NOTE: issue can't be closed at this point, if it has been accepted
jbe@0 3883 "issue_row"."accepted" NOTNULL AND
jbe@3 3884 "issue_row"."half_frozen" ISNULL
jbe@0 3885 THEN
jbe@0 3886 IF
jbe@144 3887 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
jbe@0 3888 THEN
jbe@21 3889 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
jbe@111 3890 -- NOTE: "issue_row" used later
jbe@111 3891 "issue_row"."state" := 'verification';
jbe@111 3892 "issue_row"."half_frozen" := now();
jbe@111 3893 UPDATE "issue" SET
jbe@111 3894 "state" = "issue_row"."state",
jbe@111 3895 "half_frozen" = "issue_row"."half_frozen"
jbe@3 3896 WHERE "id" = "issue_row"."id";
jbe@0 3897 END IF;
jbe@0 3898 END IF;
jbe@24 3899 -- close issues after some time, if all initiatives have been revoked:
jbe@24 3900 IF
jbe@24 3901 "issue_row"."closed" ISNULL AND
jbe@24 3902 NOT EXISTS (
jbe@24 3903 -- all initiatives are revoked
jbe@24 3904 SELECT NULL FROM "initiative"
jbe@24 3905 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@24 3906 ) AND (
jbe@111 3907 -- and issue has not been accepted yet
jbe@111 3908 "issue_row"."accepted" ISNULL OR
jbe@24 3909 NOT EXISTS (
jbe@111 3910 -- or no initiatives have been revoked lately
jbe@24 3911 SELECT NULL FROM "initiative"
jbe@24 3912 WHERE "issue_id" = "issue_id_p"
jbe@24 3913 AND now() < "revoked" + "issue_row"."verification_time"
jbe@24 3914 ) OR (
jbe@24 3915 -- or verification time has elapsed
jbe@24 3916 "issue_row"."half_frozen" NOTNULL AND
jbe@24 3917 "issue_row"."fully_frozen" ISNULL AND
jbe@24 3918 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
jbe@24 3919 )
jbe@24 3920 )
jbe@24 3921 THEN
jbe@111 3922 -- NOTE: "issue_row" used later
jbe@113 3923 IF "issue_row"."accepted" ISNULL THEN
jbe@113 3924 "issue_row"."state" := 'canceled_revoked_before_accepted';
jbe@113 3925 ELSIF "issue_row"."half_frozen" ISNULL THEN
jbe@113 3926 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
jbe@113 3927 ELSE
jbe@113 3928 "issue_row"."state" := 'canceled_after_revocation_during_verification';
jbe@113 3929 END IF;
jbe@111 3930 "issue_row"."closed" := now();
jbe@111 3931 UPDATE "issue" SET
jbe@111 3932 "state" = "issue_row"."state",
jbe@111 3933 "closed" = "issue_row"."closed"
jbe@24 3934 WHERE "id" = "issue_row"."id";
jbe@24 3935 END IF;
jbe@24 3936 -- fully freeze issue after verification time:
jbe@0 3937 IF
jbe@3 3938 "issue_row"."half_frozen" NOTNULL AND
jbe@3 3939 "issue_row"."fully_frozen" ISNULL AND
jbe@24 3940 "issue_row"."closed" ISNULL AND
jbe@22 3941 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
jbe@3 3942 THEN
jbe@3 3943 PERFORM "freeze_after_snapshot"("issue_id_p");
jbe@24 3944 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
jbe@3 3945 END IF;
jbe@9 3946 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@24 3947 -- close issue by calling close_voting(...) after voting time:
jbe@3 3948 IF
jbe@9 3949 "issue_row"."closed" ISNULL AND
jbe@3 3950 "issue_row"."fully_frozen" NOTNULL AND
jbe@22 3951 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
jbe@0 3952 THEN
jbe@0 3953 PERFORM "close_voting"("issue_id_p");
jbe@111 3954 -- calculate ranks will not consume much time and can be done now
jbe@111 3955 PERFORM "calculate_ranks"("issue_id_p");
jbe@0 3956 END IF;
jbe@0 3957 END IF;
jbe@0 3958 RETURN;
jbe@0 3959 END;
jbe@0 3960 $$;
jbe@0 3961
jbe@0 3962 COMMENT ON FUNCTION "check_issue"
jbe@0 3963 ( "issue"."id"%TYPE )
jbe@0 3964 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 3965
jbe@0 3966
jbe@0 3967 CREATE FUNCTION "check_everything"()
jbe@0 3968 RETURNS VOID
jbe@0 3969 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3970 DECLARE
jbe@0 3971 "issue_id_v" "issue"."id"%TYPE;
jbe@0 3972 BEGIN
jbe@184 3973 PERFORM "check_activity"();
jbe@4 3974 PERFORM "calculate_member_counts"();
jbe@4 3975 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
jbe@0 3976 PERFORM "check_issue"("issue_id_v");
jbe@0 3977 END LOOP;
jbe@4 3978 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
jbe@0 3979 PERFORM "calculate_ranks"("issue_id_v");
jbe@0 3980 END LOOP;
jbe@0 3981 RETURN;
jbe@0 3982 END;
jbe@0 3983 $$;
jbe@0 3984
jbe@103 3985 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 3986
jbe@0 3987
jbe@0 3988
jbe@59 3989 ----------------------
jbe@59 3990 -- Deletion of data --
jbe@59 3991 ----------------------
jbe@59 3992
jbe@59 3993
jbe@59 3994 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
jbe@59 3995 RETURNS VOID
jbe@59 3996 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@59 3997 DECLARE
jbe@59 3998 "issue_row" "issue"%ROWTYPE;
jbe@59 3999 BEGIN
jbe@59 4000 SELECT * INTO "issue_row"
jbe@59 4001 FROM "issue" WHERE "id" = "issue_id_p"
jbe@59 4002 FOR UPDATE;
jbe@59 4003 IF "issue_row"."cleaned" ISNULL THEN
jbe@59 4004 UPDATE "issue" SET
jbe@152 4005 "state" = 'voting',
jbe@152 4006 "closed" = NULL,
jbe@59 4007 "ranks_available" = FALSE
jbe@59 4008 WHERE "id" = "issue_id_p";
jbe@163 4009 DELETE FROM "issue_comment"
jbe@163 4010 WHERE "issue_id" = "issue_id_p";
jbe@163 4011 DELETE FROM "voting_comment"
jbe@163 4012 WHERE "issue_id" = "issue_id_p";
jbe@59 4013 DELETE FROM "delegating_voter"
jbe@59 4014 WHERE "issue_id" = "issue_id_p";
jbe@59 4015 DELETE FROM "direct_voter"
jbe@59 4016 WHERE "issue_id" = "issue_id_p";
jbe@59 4017 DELETE FROM "delegating_interest_snapshot"
jbe@59 4018 WHERE "issue_id" = "issue_id_p";
jbe@59 4019 DELETE FROM "direct_interest_snapshot"
jbe@59 4020 WHERE "issue_id" = "issue_id_p";
jbe@59 4021 DELETE FROM "delegating_population_snapshot"
jbe@59 4022 WHERE "issue_id" = "issue_id_p";
jbe@59 4023 DELETE FROM "direct_population_snapshot"
jbe@59 4024 WHERE "issue_id" = "issue_id_p";
jbe@113 4025 DELETE FROM "non_voter"
jbe@94 4026 WHERE "issue_id" = "issue_id_p";
jbe@59 4027 DELETE FROM "delegation"
jbe@59 4028 WHERE "issue_id" = "issue_id_p";
jbe@59 4029 DELETE FROM "supporter"
jbe@59 4030 WHERE "issue_id" = "issue_id_p";
jbe@59 4031 UPDATE "issue" SET
jbe@152 4032 "state" = "issue_row"."state",
jbe@59 4033 "closed" = "issue_row"."closed",
jbe@59 4034 "ranks_available" = "issue_row"."ranks_available",
jbe@59 4035 "cleaned" = now()
jbe@59 4036 WHERE "id" = "issue_id_p";
jbe@59 4037 END IF;
jbe@59 4038 RETURN;
jbe@59 4039 END;
jbe@59 4040 $$;
jbe@59 4041
jbe@59 4042 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
jbe@8 4043
jbe@8 4044
jbe@54 4045 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
jbe@8 4046 RETURNS VOID
jbe@8 4047 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@8 4048 BEGIN
jbe@9 4049 UPDATE "member" SET
jbe@57 4050 "last_login" = NULL,
jbe@45 4051 "login" = NULL,
jbe@11 4052 "password" = NULL,
jbe@101 4053 "locked" = TRUE,
jbe@54 4054 "active" = FALSE,
jbe@11 4055 "notify_email" = NULL,
jbe@11 4056 "notify_email_unconfirmed" = NULL,
jbe@11 4057 "notify_email_secret" = NULL,
jbe@11 4058 "notify_email_secret_expiry" = NULL,
jbe@57 4059 "notify_email_lock_expiry" = NULL,
jbe@11 4060 "password_reset_secret" = NULL,
jbe@11 4061 "password_reset_secret_expiry" = NULL,
jbe@11 4062 "organizational_unit" = NULL,
jbe@11 4063 "internal_posts" = NULL,
jbe@11 4064 "realname" = NULL,
jbe@11 4065 "birthday" = NULL,
jbe@11 4066 "address" = NULL,
jbe@11 4067 "email" = NULL,
jbe@11 4068 "xmpp_address" = NULL,
jbe@11 4069 "website" = NULL,
jbe@11 4070 "phone" = NULL,
jbe@11 4071 "mobile_phone" = NULL,
jbe@11 4072 "profession" = NULL,
jbe@11 4073 "external_memberships" = NULL,
jbe@11 4074 "external_posts" = NULL,
jbe@45 4075 "statement" = NULL
jbe@45 4076 WHERE "id" = "member_id_p";
jbe@11 4077 -- "text_search_data" is updated by triggers
jbe@45 4078 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
jbe@45 4079 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
jbe@45 4080 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
jbe@45 4081 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
jbe@45 4082 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
jbe@113 4083 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
jbe@45 4084 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
jbe@45 4085 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
jbe@113 4086 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
jbe@45 4087 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
jbe@45 4088 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
jbe@54 4089 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
jbe@54 4090 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
jbe@113 4091 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
jbe@57 4092 DELETE FROM "direct_voter" USING "issue"
jbe@57 4093 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@57 4094 AND "issue"."closed" ISNULL
jbe@57 4095 AND "member_id" = "member_id_p";
jbe@45 4096 RETURN;
jbe@45 4097 END;
jbe@45 4098 $$;
jbe@45 4099
jbe@57 4100 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 4101
jbe@45 4102
jbe@45 4103 CREATE FUNCTION "delete_private_data"()
jbe@45 4104 RETURNS VOID
jbe@45 4105 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@45 4106 BEGIN
jbe@50 4107 UPDATE "member" SET
jbe@206 4108 "invite_code" = NULL,
jbe@57 4109 "last_login" = NULL,
jbe@50 4110 "login" = NULL,
jbe@50 4111 "password" = NULL,
jbe@50 4112 "notify_email" = NULL,
jbe@50 4113 "notify_email_unconfirmed" = NULL,
jbe@50 4114 "notify_email_secret" = NULL,
jbe@50 4115 "notify_email_secret_expiry" = NULL,
jbe@57 4116 "notify_email_lock_expiry" = NULL,
jbe@50 4117 "password_reset_secret" = NULL,
jbe@50 4118 "password_reset_secret_expiry" = NULL,
jbe@50 4119 "organizational_unit" = NULL,
jbe@50 4120 "internal_posts" = NULL,
jbe@50 4121 "realname" = NULL,
jbe@50 4122 "birthday" = NULL,
jbe@50 4123 "address" = NULL,
jbe@50 4124 "email" = NULL,
jbe@50 4125 "xmpp_address" = NULL,
jbe@50 4126 "website" = NULL,
jbe@50 4127 "phone" = NULL,
jbe@50 4128 "mobile_phone" = NULL,
jbe@50 4129 "profession" = NULL,
jbe@50 4130 "external_memberships" = NULL,
jbe@50 4131 "external_posts" = NULL,
jbe@50 4132 "statement" = NULL;
jbe@50 4133 -- "text_search_data" is updated by triggers
jbe@50 4134 DELETE FROM "setting";
jbe@50 4135 DELETE FROM "setting_map";
jbe@50 4136 DELETE FROM "member_relation_setting";
jbe@50 4137 DELETE FROM "member_image";
jbe@50 4138 DELETE FROM "contact";
jbe@113 4139 DELETE FROM "ignored_member";
jbe@50 4140 DELETE FROM "area_setting";
jbe@50 4141 DELETE FROM "issue_setting";
jbe@113 4142 DELETE FROM "ignored_initiative";
jbe@50 4143 DELETE FROM "initiative_setting";
jbe@50 4144 DELETE FROM "suggestion_setting";
jbe@113 4145 DELETE FROM "non_voter";
jbe@8 4146 DELETE FROM "direct_voter" USING "issue"
jbe@8 4147 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@8 4148 AND "issue"."closed" ISNULL;
jbe@8 4149 RETURN;
jbe@8 4150 END;
jbe@8 4151 $$;
jbe@8 4152
jbe@103 4153 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 4154
jbe@8 4155
jbe@8 4156
jbe@0 4157 COMMIT;

Impressum / About Us