liquid_feedback_core

annotate core.sql @ 169:ddd8e17d8f82

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

Impressum / About Us