liquid_feedback_core

annotate core.sql @ 182:4c03ef70dd92

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