liquid_feedback_core

annotate core.sql @ 284:4f935e989ff6

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

Impressum / About Us