liquid_feedback_core

annotate core.sql @ 291:86f231bd6906

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

Impressum / About Us