liquid_feedback_core

annotate core.sql @ 167:de59f6b1daf3

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

Impressum / About Us