liquid_feedback_core

annotate core.sql @ 170:b52f3281e769

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

Impressum / About Us