liquid_feedback_core

annotate core.sql @ 289:f2292b94fc58

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

Impressum / About Us