liquid_feedback_core

annotate core.sql @ 176:b2d87fbb123b

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

Impressum / About Us