liquid_feedback_core

annotate core.sql @ 185:b0b7e0b18d78

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

Impressum / About Us