liquid_feedback_core

annotate core.sql @ 220:4e3d8f1ca3a9

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

Impressum / About Us