liquid_feedback_core

annotate core.sql @ 181:e3b0ea7ab2ad

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

Impressum / About Us