liquid_feedback_core

annotate core.sql @ 173:d8e11e6cfa1d

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

Impressum / About Us