liquid_feedback_core

annotate core.sql @ 33:959e5453e6c7

Added tag beta21 for changeset 3ccab7349f28
author jbe
date Sun Feb 21 15:03:59 2010 +0100 (2010-02-21)
parents 3ccab7349f28
children 9970f73c1140
rev   line source
jbe@0 1
jbe@0 2 CREATE LANGUAGE plpgsql; -- Triggers are implemented in PL/pgSQL
jbe@0 3
jbe@0 4 -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index
jbe@0 5
jbe@0 6 BEGIN;
jbe@0 7
jbe@5 8 CREATE VIEW "liquid_feedback_version" AS
jbe@32 9 SELECT * FROM (VALUES ('beta21', NULL, NULL, NULL))
jbe@5 10 AS "subquery"("string", "major", "minor", "revision");
jbe@5 11
jbe@0 12
jbe@0 13
jbe@7 14 ----------------------
jbe@7 15 -- Full text search --
jbe@7 16 ----------------------
jbe@7 17
jbe@7 18
jbe@7 19 CREATE FUNCTION "text_search_query"("query_text_p" TEXT)
jbe@7 20 RETURNS TSQUERY
jbe@7 21 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@7 22 BEGIN
jbe@7 23 RETURN plainto_tsquery('pg_catalog.simple', "query_text_p");
jbe@7 24 END;
jbe@7 25 $$;
jbe@7 26
jbe@7 27 COMMENT ON FUNCTION "text_search_query"(TEXT) IS 'Usage: WHERE "text_search_data" @@ "text_search_query"(''<user query>'')';
jbe@7 28
jbe@7 29
jbe@7 30 CREATE FUNCTION "highlight"
jbe@7 31 ( "body_p" TEXT,
jbe@7 32 "query_text_p" TEXT )
jbe@7 33 RETURNS TEXT
jbe@7 34 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@7 35 BEGIN
jbe@7 36 RETURN ts_headline(
jbe@7 37 'pg_catalog.simple',
jbe@8 38 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
jbe@7 39 "text_search_query"("query_text_p"),
jbe@7 40 'StartSel=* StopSel=* HighlightAll=TRUE' );
jbe@7 41 END;
jbe@7 42 $$;
jbe@7 43
jbe@7 44 COMMENT ON FUNCTION "highlight"
jbe@7 45 ( "body_p" TEXT,
jbe@7 46 "query_text_p" TEXT )
jbe@7 47 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 48
jbe@7 49
jbe@7 50
jbe@0 51 -------------------------
jbe@0 52 -- Tables and indicies --
jbe@0 53 -------------------------
jbe@0 54
jbe@8 55
jbe@0 56 CREATE TABLE "member" (
jbe@0 57 "id" SERIAL4 PRIMARY KEY,
jbe@13 58 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 59 "login" TEXT NOT NULL UNIQUE,
jbe@0 60 "password" TEXT,
jbe@0 61 "active" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@0 62 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@7 63 "notify_email" TEXT,
jbe@11 64 "notify_email_unconfirmed" TEXT,
jbe@11 65 "notify_email_secret" TEXT UNIQUE,
jbe@11 66 "notify_email_secret_expiry" TIMESTAMPTZ,
jbe@11 67 "password_reset_secret" TEXT UNIQUE,
jbe@11 68 "password_reset_secret_expiry" TIMESTAMPTZ,
jbe@7 69 "name" TEXT NOT NULL UNIQUE,
jbe@7 70 "identification" TEXT UNIQUE,
jbe@7 71 "organizational_unit" TEXT,
jbe@7 72 "internal_posts" TEXT,
jbe@7 73 "realname" TEXT,
jbe@7 74 "birthday" DATE,
jbe@7 75 "address" TEXT,
jbe@7 76 "email" TEXT,
jbe@7 77 "xmpp_address" TEXT,
jbe@7 78 "website" TEXT,
jbe@7 79 "phone" TEXT,
jbe@7 80 "mobile_phone" TEXT,
jbe@7 81 "profession" TEXT,
jbe@7 82 "external_memberships" TEXT,
jbe@7 83 "external_posts" TEXT,
jbe@7 84 "statement" TEXT,
jbe@10 85 "text_search_data" TSVECTOR );
jbe@0 86 CREATE INDEX "member_active_idx" ON "member" ("active");
jbe@8 87 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
jbe@7 88 CREATE TRIGGER "update_text_search_data"
jbe@7 89 BEFORE INSERT OR UPDATE ON "member"
jbe@7 90 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 91 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@7 92 "name", "identification", "organizational_unit", "internal_posts",
jbe@7 93 "realname", "external_memberships", "external_posts", "statement" );
jbe@0 94
jbe@0 95 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
jbe@0 96
jbe@10 97 COMMENT ON COLUMN "member"."login" IS 'Login name';
jbe@10 98 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
jbe@10 99 COMMENT ON COLUMN "member"."active" IS 'Inactive members can not login and their supports/votes are not counted by the system.';
jbe@10 100 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
jbe@10 101 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
jbe@10 102 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 103 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
jbe@10 104 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
jbe@10 105 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member';
jbe@10 106 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
jbe@10 107 COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to';
jbe@10 108 COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization';
jbe@10 109 COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"';
jbe@10 110 COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications';
jbe@10 111 COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in';
jbe@10 112 COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization';
jbe@10 113 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his homepage within the system';
jbe@7 114
jbe@7 115
jbe@13 116 CREATE TABLE "member_history" (
jbe@13 117 "id" SERIAL8 PRIMARY KEY,
jbe@13 118 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@13 119 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@13 120 "login" TEXT NOT NULL,
jbe@13 121 "name" TEXT NOT NULL );
jbe@13 122
jbe@13 123 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and login names of members';
jbe@13 124
jbe@13 125 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
jbe@13 126 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the name and login had been valid';
jbe@13 127
jbe@13 128
jbe@9 129 CREATE TABLE "invite_code" (
jbe@9 130 "code" TEXT PRIMARY KEY,
jbe@9 131 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@9 132 "used" TIMESTAMPTZ,
jbe@9 133 "member_id" INT4 UNIQUE REFERENCES "member" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
jbe@9 134 "comment" TEXT,
jbe@9 135 CONSTRAINT "only_used_codes_may_refer_to_member" CHECK ("used" NOTNULL OR "member_id" ISNULL) );
jbe@9 136
jbe@9 137 COMMENT ON TABLE "invite_code" IS 'Invite codes can be used once to create a new member account.';
jbe@9 138
jbe@9 139 COMMENT ON COLUMN "invite_code"."code" IS 'Secret code';
jbe@9 140 COMMENT ON COLUMN "invite_code"."created" IS 'Time of creation of the secret code';
jbe@9 141 COMMENT ON COLUMN "invite_code"."used" IS 'NULL, if not used yet, otherwise tells when this code was used to create a member account';
jbe@9 142 COMMENT ON COLUMN "invite_code"."member_id" IS 'References the member whose account was created with this code';
jbe@9 143 COMMENT ON COLUMN "invite_code"."comment" IS 'Comment on the code, which is to be used for administrative reasons only';
jbe@9 144
jbe@9 145
jbe@9 146 CREATE TABLE "setting" (
jbe@9 147 PRIMARY KEY ("member_id", "key"),
jbe@9 148 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@9 149 "key" TEXT NOT NULL,
jbe@9 150 "value" TEXT NOT NULL );
jbe@9 151 CREATE INDEX "setting_key_idx" ON "setting" ("key");
jbe@9 152
jbe@23 153 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific settings for members as a string';
jbe@9 154
jbe@9 155 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
jbe@9 156
jbe@9 157
jbe@16 158 CREATE TABLE "setting_map" (
jbe@16 159 PRIMARY KEY ("member_id", "key", "subkey"),
jbe@16 160 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@16 161 "key" TEXT NOT NULL,
jbe@16 162 "subkey" TEXT NOT NULL,
jbe@16 163 "value" TEXT NOT NULL );
jbe@16 164 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
jbe@16 165
jbe@23 166 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
jbe@16 167
jbe@16 168 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
jbe@16 169 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
jbe@16 170 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
jbe@16 171
jbe@16 172
jbe@23 173 CREATE TABLE "member_relation_setting" (
jbe@23 174 PRIMARY KEY ("member_id", "key", "other_member_id"),
jbe@23 175 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 176 "key" TEXT NOT NULL,
jbe@23 177 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 178 "value" TEXT NOT NULL );
jbe@23 179
jbe@23 180 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific settings related to relations between members as a string';
jbe@23 181
jbe@23 182
jbe@7 183 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
jbe@7 184
jbe@7 185 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
jbe@7 186
jbe@7 187
jbe@7 188 CREATE TABLE "member_image" (
jbe@7 189 PRIMARY KEY ("member_id", "image_type", "scaled"),
jbe@7 190 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@7 191 "image_type" "member_image_type",
jbe@7 192 "scaled" BOOLEAN,
jbe@7 193 "content_type" TEXT,
jbe@7 194 "data" BYTEA NOT NULL );
jbe@7 195
jbe@7 196 COMMENT ON TABLE "member_image" IS 'Images of members';
jbe@7 197
jbe@7 198 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
jbe@0 199
jbe@0 200
jbe@4 201 CREATE TABLE "member_count" (
jbe@5 202 "calculated" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
jbe@5 203 "total_count" INT4 NOT NULL );
jbe@4 204
jbe@5 205 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 206
jbe@5 207 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
jbe@5 208 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
jbe@4 209
jbe@4 210
jbe@0 211 CREATE TABLE "contact" (
jbe@0 212 PRIMARY KEY ("member_id", "other_member_id"),
jbe@0 213 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 214 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@11 215 "public" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@11 216 CONSTRAINT "cant_save_yourself_as_contact"
jbe@11 217 CHECK ("member_id" != "other_member_id") );
jbe@0 218
jbe@0 219 COMMENT ON TABLE "contact" IS 'Contact lists';
jbe@0 220
jbe@0 221 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
jbe@0 222 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
jbe@0 223 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
jbe@0 224
jbe@0 225
jbe@0 226 CREATE TABLE "session" (
jbe@0 227 "ident" TEXT PRIMARY KEY,
jbe@0 228 "additional_secret" TEXT,
jbe@0 229 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
jbe@0 230 "member_id" INT8 REFERENCES "member" ("id") ON DELETE SET NULL,
jbe@0 231 "lang" TEXT );
jbe@0 232 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
jbe@0 233
jbe@0 234 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend';
jbe@0 235
jbe@0 236 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
jbe@0 237 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
jbe@0 238 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
jbe@0 239 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
jbe@0 240
jbe@0 241
jbe@0 242 CREATE TABLE "policy" (
jbe@0 243 "id" SERIAL4 PRIMARY KEY,
jbe@9 244 "index" INT4 NOT NULL,
jbe@0 245 "active" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@0 246 "name" TEXT NOT NULL UNIQUE,
jbe@0 247 "description" TEXT NOT NULL DEFAULT '',
jbe@0 248 "admission_time" INTERVAL NOT NULL,
jbe@0 249 "discussion_time" INTERVAL NOT NULL,
jbe@3 250 "verification_time" INTERVAL NOT NULL,
jbe@0 251 "voting_time" INTERVAL NOT NULL,
jbe@0 252 "issue_quorum_num" INT4 NOT NULL,
jbe@0 253 "issue_quorum_den" INT4 NOT NULL,
jbe@0 254 "initiative_quorum_num" INT4 NOT NULL,
jbe@10 255 "initiative_quorum_den" INT4 NOT NULL,
jbe@10 256 "majority_num" INT4 NOT NULL DEFAULT 1,
jbe@10 257 "majority_den" INT4 NOT NULL DEFAULT 2,
jbe@10 258 "majority_strict" BOOLEAN NOT NULL DEFAULT TRUE );
jbe@0 259 CREATE INDEX "policy_active_idx" ON "policy" ("active");
jbe@0 260
jbe@0 261 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
jbe@0 262
jbe@9 263 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
jbe@0 264 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
jbe@0 265 COMMENT ON COLUMN "policy"."admission_time" IS 'Maximum time an issue stays open without being "accepted"';
jbe@3 266 COMMENT ON COLUMN "policy"."discussion_time" IS 'Regular time until an issue is "half_frozen" after being "accepted"';
jbe@3 267 COMMENT ON COLUMN "policy"."verification_time" IS 'Regular time until an issue is "fully_frozen" after being "half_frozen"';
jbe@3 268 COMMENT ON COLUMN "policy"."voting_time" IS 'Time after an issue is "fully_frozen" but not "closed"';
jbe@10 269 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 270 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 271 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 272 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@10 273 COMMENT ON COLUMN "policy"."majority_num" IS 'Numerator of fraction of majority to be reached during voting by an initiative to be aggreed upon';
jbe@10 274 COMMENT ON COLUMN "policy"."majority_den" IS 'Denominator of fraction of majority to be reached during voting by an initiative to be aggreed upon';
jbe@10 275 COMMENT ON COLUMN "policy"."majority_strict" IS 'If TRUE, then the majority must be strictly greater than "majority_num"/"majority_den", otherwise it may also be equal.';
jbe@0 276
jbe@0 277
jbe@0 278 CREATE TABLE "area" (
jbe@0 279 "id" SERIAL4 PRIMARY KEY,
jbe@0 280 "active" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@0 281 "name" TEXT NOT NULL,
jbe@4 282 "description" TEXT NOT NULL DEFAULT '',
jbe@5 283 "direct_member_count" INT4,
jbe@5 284 "member_weight" INT4,
jbe@7 285 "autoreject_weight" INT4,
jbe@7 286 "text_search_data" TSVECTOR );
jbe@0 287 CREATE INDEX "area_active_idx" ON "area" ("active");
jbe@8 288 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
jbe@7 289 CREATE TRIGGER "update_text_search_data"
jbe@7 290 BEFORE INSERT OR UPDATE ON "area"
jbe@7 291 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 292 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@7 293 "name", "description" );
jbe@0 294
jbe@0 295 COMMENT ON TABLE "area" IS 'Subject areas';
jbe@0 296
jbe@5 297 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
jbe@5 298 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 299 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
jbe@5 300 COMMENT ON COLUMN "area"."autoreject_weight" IS 'Sum of weight of members using the autoreject feature';
jbe@0 301
jbe@0 302
jbe@23 303 CREATE TABLE "area_setting" (
jbe@23 304 PRIMARY KEY ("member_id", "key", "area_id"),
jbe@23 305 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 306 "key" TEXT NOT NULL,
jbe@23 307 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 308 "value" TEXT NOT NULL );
jbe@23 309
jbe@23 310 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
jbe@23 311
jbe@23 312
jbe@9 313 CREATE TABLE "allowed_policy" (
jbe@9 314 PRIMARY KEY ("area_id", "policy_id"),
jbe@9 315 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@9 316 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@9 317 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
jbe@9 318 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
jbe@9 319
jbe@9 320 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
jbe@9 321
jbe@9 322 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
jbe@9 323
jbe@9 324
jbe@21 325 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
jbe@21 326
jbe@21 327 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 328
jbe@8 329
jbe@0 330 CREATE TABLE "issue" (
jbe@0 331 "id" SERIAL4 PRIMARY KEY,
jbe@0 332 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 333 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@0 334 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 335 "accepted" TIMESTAMPTZ,
jbe@3 336 "half_frozen" TIMESTAMPTZ,
jbe@3 337 "fully_frozen" TIMESTAMPTZ,
jbe@0 338 "closed" TIMESTAMPTZ,
jbe@0 339 "ranks_available" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@22 340 "admission_time" INTERVAL NOT NULL,
jbe@22 341 "discussion_time" INTERVAL NOT NULL,
jbe@22 342 "verification_time" INTERVAL NOT NULL,
jbe@22 343 "voting_time" INTERVAL NOT NULL,
jbe@0 344 "snapshot" TIMESTAMPTZ,
jbe@8 345 "latest_snapshot_event" "snapshot_event",
jbe@0 346 "population" INT4,
jbe@0 347 "vote_now" INT4,
jbe@0 348 "vote_later" INT4,
jbe@4 349 "voter_count" INT4,
jbe@0 350 CONSTRAINT "valid_state" CHECK (
jbe@3 351 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
jbe@3 352 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
jbe@3 353 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
jbe@3 354 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
jbe@3 355 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
jbe@3 356 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
jbe@3 357 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = TRUE) ),
jbe@3 358 CONSTRAINT "state_change_order" CHECK (
jbe@10 359 "created" <= "accepted" AND
jbe@10 360 "accepted" <= "half_frozen" AND
jbe@10 361 "half_frozen" <= "fully_frozen" AND
jbe@3 362 "fully_frozen" <= "closed" ),
jbe@10 363 CONSTRAINT "last_snapshot_on_full_freeze"
jbe@10 364 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
jbe@10 365 CONSTRAINT "freeze_requires_snapshot"
jbe@10 366 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
jbe@10 367 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
jbe@10 368 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) );
jbe@0 369 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
jbe@0 370 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
jbe@16 371 CREATE INDEX "issue_created_idx" ON "issue" ("created");
jbe@16 372 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
jbe@16 373 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
jbe@16 374 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
jbe@16 375 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
jbe@0 376 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
jbe@16 377 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
jbe@0 378
jbe@0 379 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
jbe@0 380
jbe@8 381 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
jbe@10 382 COMMENT ON COLUMN "issue"."half_frozen" IS 'Point in time, when "discussion_time" has elapsed, or members voted for voting; 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@10 383 COMMENT ON COLUMN "issue"."fully_frozen" IS 'Point in time, when "verification_time" has elapsed; Frontends must ensure that for fully_frozen issues additionally to the restrictions for half_frozen issues a) initiatives are not created, b) no interest is created or removed, c) no supporters are added or removed, d) no opinions are created, changed or deleted.';
jbe@10 384 COMMENT ON COLUMN "issue"."closed" IS 'Point in time, when "admission_time" or "voting_time" have elapsed, and issue is no longer active; Frontends must ensure that for closed issues additionally to the restrictions for half_frozen and fully_frozen issues a) no voter is added or removed to/from the direct_voter table, b) no votes are added, modified or removed.';
jbe@8 385 COMMENT ON COLUMN "issue"."ranks_available" IS 'TRUE = ranks have been calculated';
jbe@22 386 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue';
jbe@22 387 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
jbe@22 388 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
jbe@22 389 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
jbe@8 390 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population", "vote_now", "vote_later" and *_count values were precalculated';
jbe@8 391 COMMENT ON COLUMN "issue"."latest_snapshot_event" IS 'Event type of latest snapshot for issue; Can be used to select the latest snapshot data in the snapshot tables';
jbe@8 392 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
jbe@8 393 COMMENT ON COLUMN "issue"."vote_now" IS 'Number of votes in favor of voting now, as calculated from table "direct_interest_snapshot"';
jbe@8 394 COMMENT ON COLUMN "issue"."vote_later" IS 'Number of votes against voting now, as calculated from table "direct_interest_snapshot"';
jbe@8 395 COMMENT ON COLUMN "issue"."voter_count" IS 'Total number of direct and delegating voters; This value is related to the final voting, while "population" is related to snapshots before the final voting';
jbe@0 396
jbe@0 397
jbe@23 398 CREATE TABLE "issue_setting" (
jbe@23 399 PRIMARY KEY ("member_id", "key", "issue_id"),
jbe@23 400 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 401 "key" TEXT NOT NULL,
jbe@23 402 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 403 "value" TEXT NOT NULL );
jbe@23 404
jbe@23 405 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
jbe@23 406
jbe@23 407
jbe@0 408 CREATE TABLE "initiative" (
jbe@0 409 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
jbe@0 410 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 411 "id" SERIAL4 PRIMARY KEY,
jbe@0 412 "name" TEXT NOT NULL,
jbe@8 413 "discussion_url" TEXT,
jbe@0 414 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 415 "revoked" TIMESTAMPTZ,
jbe@14 416 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 417 "admitted" BOOLEAN,
jbe@0 418 "supporter_count" INT4,
jbe@0 419 "informed_supporter_count" INT4,
jbe@0 420 "satisfied_supporter_count" INT4,
jbe@0 421 "satisfied_informed_supporter_count" INT4,
jbe@0 422 "positive_votes" INT4,
jbe@0 423 "negative_votes" INT4,
jbe@10 424 "agreed" BOOLEAN,
jbe@0 425 "rank" INT4,
jbe@7 426 "text_search_data" TSVECTOR,
jbe@14 427 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
jbe@14 428 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
jbe@0 429 CONSTRAINT "revoked_initiatives_cant_be_admitted"
jbe@0 430 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
jbe@0 431 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results"
jbe@10 432 CHECK (("admitted" NOTNULL AND "admitted" = TRUE) OR ("positive_votes" ISNULL AND "negative_votes" ISNULL AND "agreed" ISNULL)),
jbe@10 433 CONSTRAINT "all_or_none_of_positive_votes_negative_votes_and_agreed_must_be_null"
jbe@10 434 CHECK ("positive_votes" NOTNULL = "negative_votes" NOTNULL AND "positive_votes" NOTNULL = "agreed" NOTNULL),
jbe@10 435 CONSTRAINT "non_agreed_initiatives_cant_get_a_rank"
jbe@10 436 CHECK (("agreed" NOTNULL AND "agreed" = TRUE) OR "rank" ISNULL) );
jbe@16 437 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
jbe@16 438 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
jbe@8 439 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
jbe@7 440 CREATE TRIGGER "update_text_search_data"
jbe@7 441 BEFORE INSERT OR UPDATE ON "initiative"
jbe@7 442 FOR EACH ROW EXECUTE PROCEDURE
jbe@8 443 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@8 444 "name", "discussion_url");
jbe@0 445
jbe@10 446 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 447
jbe@8 448 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
jbe@0 449 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
jbe@10 450 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
jbe@0 451 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@0 452 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@0 453 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@0 454 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@0 455 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
jbe@0 456 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
jbe@10 457 COMMENT ON COLUMN "initiative"."agreed" IS 'TRUE, if "positive_votes"/("positive_votes"+"negative_votes") is strictly greater or greater-equal than "majority_num"/"majority_den"';
jbe@0 458 COMMENT ON COLUMN "initiative"."rank" IS 'Rank of approved initiatives (winner is 1), calculated from table "direct_voter"';
jbe@0 459
jbe@0 460
jbe@23 461 CREATE TABLE "initiative_setting" (
jbe@23 462 PRIMARY KEY ("member_id", "key", "initiative_id"),
jbe@23 463 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 464 "key" TEXT NOT NULL,
jbe@23 465 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 466 "value" TEXT NOT NULL );
jbe@23 467
jbe@23 468 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
jbe@23 469
jbe@23 470
jbe@0 471 CREATE TABLE "draft" (
jbe@0 472 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
jbe@0 473 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 474 "id" SERIAL8 PRIMARY KEY,
jbe@0 475 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 476 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@9 477 "formatting_engine" TEXT,
jbe@7 478 "content" TEXT NOT NULL,
jbe@7 479 "text_search_data" TSVECTOR );
jbe@16 480 CREATE INDEX "draft_created_idx" ON "draft" ("created");
jbe@9 481 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
jbe@8 482 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
jbe@7 483 CREATE TRIGGER "update_text_search_data"
jbe@7 484 BEFORE INSERT OR UPDATE ON "draft"
jbe@7 485 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 486 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
jbe@0 487
jbe@10 488 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 489
jbe@9 490 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
jbe@9 491 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
jbe@9 492
jbe@0 493
jbe@0 494 CREATE TABLE "suggestion" (
jbe@0 495 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
jbe@0 496 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 497 "id" SERIAL8 PRIMARY KEY,
jbe@0 498 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 499 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@0 500 "name" TEXT NOT NULL,
jbe@0 501 "description" TEXT NOT NULL DEFAULT '',
jbe@7 502 "text_search_data" TSVECTOR,
jbe@0 503 "minus2_unfulfilled_count" INT4,
jbe@0 504 "minus2_fulfilled_count" INT4,
jbe@0 505 "minus1_unfulfilled_count" INT4,
jbe@0 506 "minus1_fulfilled_count" INT4,
jbe@0 507 "plus1_unfulfilled_count" INT4,
jbe@0 508 "plus1_fulfilled_count" INT4,
jbe@0 509 "plus2_unfulfilled_count" INT4,
jbe@0 510 "plus2_fulfilled_count" INT4 );
jbe@16 511 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
jbe@9 512 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
jbe@8 513 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
jbe@7 514 CREATE TRIGGER "update_text_search_data"
jbe@7 515 BEFORE INSERT OR UPDATE ON "suggestion"
jbe@7 516 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 517 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@7 518 "name", "description");
jbe@0 519
jbe@10 520 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 521
jbe@0 522 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 523 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 524 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 525 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 526 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 527 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 528 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 529 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 530
jbe@0 531
jbe@23 532 CREATE TABLE "suggestion_setting" (
jbe@23 533 PRIMARY KEY ("member_id", "key", "suggestion_id"),
jbe@23 534 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 535 "key" TEXT NOT NULL,
jbe@23 536 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 537 "value" TEXT NOT NULL );
jbe@23 538
jbe@23 539 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
jbe@23 540
jbe@23 541
jbe@0 542 CREATE TABLE "membership" (
jbe@0 543 PRIMARY KEY ("area_id", "member_id"),
jbe@0 544 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 545 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 546 "autoreject" BOOLEAN NOT NULL DEFAULT FALSE );
jbe@0 547 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
jbe@0 548
jbe@0 549 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
jbe@0 550
jbe@0 551 COMMENT ON COLUMN "membership"."autoreject" IS 'TRUE = member votes against all initiatives in case of not explicitly taking part in the voting procedure; If there exists an "interest" entry, the interest entry has precedence';
jbe@0 552
jbe@0 553
jbe@0 554 CREATE TABLE "interest" (
jbe@0 555 PRIMARY KEY ("issue_id", "member_id"),
jbe@0 556 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 557 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 558 "autoreject" BOOLEAN NOT NULL,
jbe@0 559 "voting_requested" BOOLEAN );
jbe@0 560 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
jbe@0 561
jbe@10 562 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 563
jbe@0 564 COMMENT ON COLUMN "interest"."autoreject" IS 'TRUE = member votes against all initiatives in case of not explicitly taking part in the voting procedure';
jbe@0 565 COMMENT ON COLUMN "interest"."voting_requested" IS 'TRUE = member wants to vote now, FALSE = member wants to vote later, NULL = policy rules should apply';
jbe@0 566
jbe@0 567
jbe@0 568 CREATE TABLE "initiator" (
jbe@0 569 PRIMARY KEY ("initiative_id", "member_id"),
jbe@0 570 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 571 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@14 572 "accepted" BOOLEAN );
jbe@0 573 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
jbe@0 574
jbe@10 575 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 576
jbe@14 577 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 578
jbe@0 579
jbe@0 580 CREATE TABLE "supporter" (
jbe@0 581 "issue_id" INT4 NOT NULL,
jbe@0 582 PRIMARY KEY ("initiative_id", "member_id"),
jbe@0 583 "initiative_id" INT4,
jbe@0 584 "member_id" INT4,
jbe@0 585 "draft_id" INT8 NOT NULL,
jbe@10 586 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 587 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@0 588 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
jbe@0 589
jbe@10 590 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 591
jbe@2 592 COMMENT ON COLUMN "supporter"."draft_id" IS 'Latest seen draft, defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
jbe@0 593
jbe@0 594
jbe@0 595 CREATE TABLE "opinion" (
jbe@0 596 "initiative_id" INT4 NOT NULL,
jbe@0 597 PRIMARY KEY ("suggestion_id", "member_id"),
jbe@0 598 "suggestion_id" INT8,
jbe@0 599 "member_id" INT4,
jbe@0 600 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
jbe@0 601 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@0 602 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@0 603 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@10 604 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
jbe@0 605
jbe@10 606 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 607
jbe@0 608 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
jbe@0 609
jbe@0 610
jbe@10 611 CREATE TYPE "delegation_scope" AS ENUM ('global', 'area', 'issue');
jbe@10 612
jbe@10 613 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''global'', ''area'', or ''issue'' (order is relevant)';
jbe@10 614
jbe@10 615
jbe@0 616 CREATE TABLE "delegation" (
jbe@0 617 "id" SERIAL8 PRIMARY KEY,
jbe@0 618 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 619 "trustee_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@10 620 "scope" "delegation_scope" NOT NULL,
jbe@0 621 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 622 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 623 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
jbe@10 624 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
jbe@10 625 ("scope" = 'global' AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
jbe@10 626 ("scope" = 'area' AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
jbe@10 627 ("scope" = 'issue' AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
jbe@0 628 UNIQUE ("area_id", "truster_id", "trustee_id"),
jbe@0 629 UNIQUE ("issue_id", "truster_id", "trustee_id") );
jbe@10 630 CREATE UNIQUE INDEX "delegation_global_truster_id_trustee_id_unique_idx"
jbe@10 631 ON "delegation" ("truster_id", "trustee_id") WHERE "scope" = 'global';
jbe@0 632 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
jbe@0 633 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
jbe@0 634
jbe@0 635 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
jbe@0 636
jbe@0 637 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
jbe@0 638 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
jbe@0 639
jbe@0 640
jbe@0 641 CREATE TABLE "direct_population_snapshot" (
jbe@0 642 PRIMARY KEY ("issue_id", "event", "member_id"),
jbe@0 643 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 644 "event" "snapshot_event",
jbe@0 645 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@0 646 "weight" INT4,
jbe@0 647 "interest_exists" BOOLEAN NOT NULL );
jbe@0 648 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
jbe@0 649
jbe@0 650 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@0 651
jbe@0 652 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
jbe@0 653 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
jbe@0 654 COMMENT ON COLUMN "direct_population_snapshot"."interest_exists" IS 'TRUE if entry is due to interest in issue, FALSE if entry is only due to membership in area';
jbe@0 655
jbe@0 656
jbe@0 657 CREATE TABLE "delegating_population_snapshot" (
jbe@0 658 PRIMARY KEY ("issue_id", "event", "member_id"),
jbe@0 659 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 660 "event" "snapshot_event",
jbe@0 661 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@8 662 "weight" INT4,
jbe@10 663 "scope" "delegation_scope" NOT NULL,
jbe@0 664 "delegate_member_ids" INT4[] NOT NULL );
jbe@0 665 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
jbe@0 666
jbe@0 667 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table';
jbe@0 668
jbe@0 669 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
jbe@0 670 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
jbe@8 671 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
jbe@0 672 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 673
jbe@0 674
jbe@0 675 CREATE TABLE "direct_interest_snapshot" (
jbe@0 676 PRIMARY KEY ("issue_id", "event", "member_id"),
jbe@0 677 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 678 "event" "snapshot_event",
jbe@0 679 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@0 680 "weight" INT4,
jbe@0 681 "voting_requested" BOOLEAN );
jbe@0 682 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
jbe@0 683
jbe@0 684 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"';
jbe@0 685
jbe@0 686 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
jbe@0 687 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
jbe@0 688 COMMENT ON COLUMN "direct_interest_snapshot"."voting_requested" IS 'Copied from column "voting_requested" of table "interest"';
jbe@0 689
jbe@0 690
jbe@0 691 CREATE TABLE "delegating_interest_snapshot" (
jbe@0 692 PRIMARY KEY ("issue_id", "event", "member_id"),
jbe@0 693 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 694 "event" "snapshot_event",
jbe@0 695 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@8 696 "weight" INT4,
jbe@10 697 "scope" "delegation_scope" NOT NULL,
jbe@0 698 "delegate_member_ids" INT4[] NOT NULL );
jbe@0 699 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
jbe@0 700
jbe@0 701 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table';
jbe@0 702
jbe@0 703 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
jbe@0 704 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
jbe@8 705 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
jbe@0 706 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 707
jbe@0 708
jbe@0 709 CREATE TABLE "direct_supporter_snapshot" (
jbe@0 710 "issue_id" INT4 NOT NULL,
jbe@0 711 PRIMARY KEY ("initiative_id", "event", "member_id"),
jbe@0 712 "initiative_id" INT4,
jbe@0 713 "event" "snapshot_event",
jbe@0 714 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@0 715 "informed" BOOLEAN NOT NULL,
jbe@0 716 "satisfied" BOOLEAN NOT NULL,
jbe@0 717 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 718 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@0 719 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
jbe@0 720
jbe@8 721 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
jbe@0 722
jbe@0 723 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
jbe@0 724 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
jbe@0 725 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
jbe@0 726
jbe@0 727
jbe@0 728 CREATE TABLE "direct_voter" (
jbe@0 729 PRIMARY KEY ("issue_id", "member_id"),
jbe@0 730 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 731 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@0 732 "weight" INT4,
jbe@0 733 "autoreject" BOOLEAN NOT NULL DEFAULT FALSE );
jbe@0 734 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
jbe@0 735
jbe@10 736 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 737
jbe@0 738 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
jbe@0 739 COMMENT ON COLUMN "direct_voter"."autoreject" IS 'Votes were inserted due to "autoreject" feature';
jbe@0 740
jbe@0 741
jbe@0 742 CREATE TABLE "delegating_voter" (
jbe@0 743 PRIMARY KEY ("issue_id", "member_id"),
jbe@0 744 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 745 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@8 746 "weight" INT4,
jbe@10 747 "scope" "delegation_scope" NOT NULL,
jbe@0 748 "delegate_member_ids" INT4[] NOT NULL );
jbe@0 749 CREATE INDEX "delegating_voter_member_id_idx" ON "direct_voter" ("member_id");
jbe@0 750
jbe@0 751 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
jbe@0 752
jbe@0 753 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
jbe@8 754 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
jbe@0 755 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 756
jbe@0 757
jbe@0 758 CREATE TABLE "vote" (
jbe@0 759 "issue_id" INT4 NOT NULL,
jbe@0 760 PRIMARY KEY ("initiative_id", "member_id"),
jbe@0 761 "initiative_id" INT4,
jbe@0 762 "member_id" INT4,
jbe@0 763 "grade" INT4,
jbe@0 764 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 765 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@0 766 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
jbe@0 767
jbe@10 768 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 769
jbe@0 770 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 771
jbe@0 772
jbe@9 773 CREATE TABLE "contingent" (
jbe@9 774 "time_frame" INTERVAL PRIMARY KEY,
jbe@9 775 "text_entry_limit" INT4,
jbe@9 776 "initiative_limit" INT4 );
jbe@9 777
jbe@9 778 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@9 779
jbe@9 780 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@9 781 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame';
jbe@9 782
jbe@9 783
jbe@0 784
jbe@13 785 --------------------------------
jbe@13 786 -- Writing of history entries --
jbe@13 787 --------------------------------
jbe@13 788
jbe@13 789 CREATE FUNCTION "write_member_history_trigger"()
jbe@13 790 RETURNS TRIGGER
jbe@13 791 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@13 792 BEGIN
jbe@13 793 IF NEW."login" != OLD."login" OR NEW."name" != OLD."name" THEN
jbe@13 794 INSERT INTO "member_history" ("member_id", "login", "name")
jbe@13 795 VALUES (NEW."id", OLD."login", OLD."name");
jbe@13 796 END IF;
jbe@13 797 RETURN NULL;
jbe@13 798 END;
jbe@13 799 $$;
jbe@13 800
jbe@13 801 CREATE TRIGGER "write_member_history"
jbe@13 802 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
jbe@13 803 "write_member_history_trigger"();
jbe@13 804
jbe@13 805 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
jbe@13 806 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing name or login of a member, create a history entry in "member_history" table';
jbe@13 807
jbe@13 808
jbe@13 809
jbe@0 810 ----------------------------
jbe@0 811 -- Additional constraints --
jbe@0 812 ----------------------------
jbe@0 813
jbe@0 814
jbe@0 815 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
jbe@0 816 RETURNS TRIGGER
jbe@0 817 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 818 BEGIN
jbe@0 819 IF NOT EXISTS (
jbe@0 820 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
jbe@0 821 ) THEN
jbe@0 822 --RAISE 'Cannot create issue without an initial initiative.' USING
jbe@0 823 -- ERRCODE = 'integrity_constraint_violation',
jbe@0 824 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
jbe@0 825 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
jbe@0 826 END IF;
jbe@0 827 RETURN NULL;
jbe@0 828 END;
jbe@0 829 $$;
jbe@0 830
jbe@0 831 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
jbe@0 832 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
jbe@0 833 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 834 "issue_requires_first_initiative_trigger"();
jbe@0 835
jbe@0 836 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
jbe@0 837 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
jbe@0 838
jbe@0 839
jbe@0 840 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
jbe@0 841 RETURNS TRIGGER
jbe@0 842 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 843 DECLARE
jbe@0 844 "reference_lost" BOOLEAN;
jbe@0 845 BEGIN
jbe@0 846 IF TG_OP = 'DELETE' THEN
jbe@0 847 "reference_lost" := TRUE;
jbe@0 848 ELSE
jbe@0 849 "reference_lost" := NEW."issue_id" != OLD."issue_id";
jbe@0 850 END IF;
jbe@0 851 IF
jbe@0 852 "reference_lost" AND NOT EXISTS (
jbe@0 853 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
jbe@0 854 )
jbe@0 855 THEN
jbe@0 856 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
jbe@0 857 END IF;
jbe@0 858 RETURN NULL;
jbe@0 859 END;
jbe@0 860 $$;
jbe@0 861
jbe@0 862 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
jbe@0 863 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
jbe@0 864 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 865 "last_initiative_deletes_issue_trigger"();
jbe@0 866
jbe@0 867 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
jbe@0 868 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
jbe@0 869
jbe@0 870
jbe@0 871 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
jbe@0 872 RETURNS TRIGGER
jbe@0 873 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 874 BEGIN
jbe@0 875 IF NOT EXISTS (
jbe@0 876 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
jbe@0 877 ) THEN
jbe@0 878 --RAISE 'Cannot create initiative without an initial draft.' USING
jbe@0 879 -- ERRCODE = 'integrity_constraint_violation',
jbe@0 880 -- HINT = 'Create issue, initiative and draft within the same transaction.';
jbe@0 881 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
jbe@0 882 END IF;
jbe@0 883 RETURN NULL;
jbe@0 884 END;
jbe@0 885 $$;
jbe@0 886
jbe@0 887 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
jbe@0 888 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
jbe@0 889 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 890 "initiative_requires_first_draft_trigger"();
jbe@0 891
jbe@0 892 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
jbe@0 893 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
jbe@0 894
jbe@0 895
jbe@0 896 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
jbe@0 897 RETURNS TRIGGER
jbe@0 898 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 899 DECLARE
jbe@0 900 "reference_lost" BOOLEAN;
jbe@0 901 BEGIN
jbe@0 902 IF TG_OP = 'DELETE' THEN
jbe@0 903 "reference_lost" := TRUE;
jbe@0 904 ELSE
jbe@0 905 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
jbe@0 906 END IF;
jbe@0 907 IF
jbe@0 908 "reference_lost" AND NOT EXISTS (
jbe@0 909 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
jbe@0 910 )
jbe@0 911 THEN
jbe@0 912 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
jbe@0 913 END IF;
jbe@0 914 RETURN NULL;
jbe@0 915 END;
jbe@0 916 $$;
jbe@0 917
jbe@0 918 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
jbe@0 919 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
jbe@0 920 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 921 "last_draft_deletes_initiative_trigger"();
jbe@0 922
jbe@0 923 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
jbe@0 924 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
jbe@0 925
jbe@0 926
jbe@0 927 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
jbe@0 928 RETURNS TRIGGER
jbe@0 929 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 930 BEGIN
jbe@0 931 IF NOT EXISTS (
jbe@0 932 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
jbe@0 933 ) THEN
jbe@0 934 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
jbe@0 935 END IF;
jbe@0 936 RETURN NULL;
jbe@0 937 END;
jbe@0 938 $$;
jbe@0 939
jbe@0 940 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
jbe@0 941 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
jbe@0 942 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 943 "suggestion_requires_first_opinion_trigger"();
jbe@0 944
jbe@0 945 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
jbe@0 946 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
jbe@0 947
jbe@0 948
jbe@0 949 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
jbe@0 950 RETURNS TRIGGER
jbe@0 951 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 952 DECLARE
jbe@0 953 "reference_lost" BOOLEAN;
jbe@0 954 BEGIN
jbe@0 955 IF TG_OP = 'DELETE' THEN
jbe@0 956 "reference_lost" := TRUE;
jbe@0 957 ELSE
jbe@0 958 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
jbe@0 959 END IF;
jbe@0 960 IF
jbe@0 961 "reference_lost" AND NOT EXISTS (
jbe@0 962 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
jbe@0 963 )
jbe@0 964 THEN
jbe@0 965 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
jbe@0 966 END IF;
jbe@0 967 RETURN NULL;
jbe@0 968 END;
jbe@0 969 $$;
jbe@0 970
jbe@0 971 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
jbe@0 972 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
jbe@0 973 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 974 "last_opinion_deletes_suggestion_trigger"();
jbe@0 975
jbe@0 976 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
jbe@0 977 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
jbe@0 978
jbe@0 979
jbe@0 980
jbe@20 981 ---------------------------------------------------------------
jbe@20 982 -- Ensure that votes are not modified when issues are frozen --
jbe@20 983 ---------------------------------------------------------------
jbe@20 984
jbe@20 985 -- NOTE: Frontends should ensure this anyway, but in case of programming
jbe@20 986 -- errors the following triggers ensure data integrity.
jbe@20 987
jbe@20 988
jbe@20 989 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
jbe@20 990 RETURNS TRIGGER
jbe@20 991 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@20 992 DECLARE
jbe@32 993 "issue_id_v" "issue"."id"%TYPE;
jbe@32 994 "issue_row" "issue"%ROWTYPE;
jbe@20 995 BEGIN
jbe@32 996 IF TG_OP = 'DELETE' THEN
jbe@32 997 "issue_id_v" := OLD."issue_id";
jbe@32 998 ELSE
jbe@32 999 "issue_id_v" := NEW."issue_id";
jbe@32 1000 END IF;
jbe@20 1001 SELECT INTO "issue_row" * FROM "issue"
jbe@32 1002 WHERE "id" = "issue_id_v" FOR SHARE;
jbe@20 1003 IF "issue_row"."closed" NOTNULL THEN
jbe@20 1004 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
jbe@20 1005 END IF;
jbe@20 1006 RETURN NULL;
jbe@20 1007 END;
jbe@20 1008 $$;
jbe@20 1009
jbe@20 1010 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 1011 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
jbe@20 1012 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 1013 "forbid_changes_on_closed_issue_trigger"();
jbe@20 1014
jbe@20 1015 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 1016 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
jbe@20 1017 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 1018 "forbid_changes_on_closed_issue_trigger"();
jbe@20 1019
jbe@20 1020 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 1021 AFTER INSERT OR UPDATE OR DELETE ON "vote"
jbe@20 1022 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 1023 "forbid_changes_on_closed_issue_trigger"();
jbe@20 1024
jbe@20 1025 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 1026 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 1027 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 1028 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 1029
jbe@20 1030
jbe@20 1031
jbe@0 1032 --------------------------------------------------------------------
jbe@0 1033 -- Auto-retrieval of fields only needed for referential integrity --
jbe@0 1034 --------------------------------------------------------------------
jbe@0 1035
jbe@20 1036
jbe@0 1037 CREATE FUNCTION "autofill_issue_id_trigger"()
jbe@0 1038 RETURNS TRIGGER
jbe@0 1039 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1040 BEGIN
jbe@0 1041 IF NEW."issue_id" ISNULL THEN
jbe@0 1042 SELECT "issue_id" INTO NEW."issue_id"
jbe@0 1043 FROM "initiative" WHERE "id" = NEW."initiative_id";
jbe@0 1044 END IF;
jbe@0 1045 RETURN NEW;
jbe@0 1046 END;
jbe@0 1047 $$;
jbe@0 1048
jbe@0 1049 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
jbe@0 1050 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
jbe@0 1051
jbe@0 1052 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
jbe@0 1053 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
jbe@0 1054
jbe@0 1055 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
jbe@0 1056 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
jbe@0 1057 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
jbe@0 1058
jbe@0 1059
jbe@0 1060 CREATE FUNCTION "autofill_initiative_id_trigger"()
jbe@0 1061 RETURNS TRIGGER
jbe@0 1062 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1063 BEGIN
jbe@0 1064 IF NEW."initiative_id" ISNULL THEN
jbe@0 1065 SELECT "initiative_id" INTO NEW."initiative_id"
jbe@0 1066 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
jbe@0 1067 END IF;
jbe@0 1068 RETURN NEW;
jbe@0 1069 END;
jbe@0 1070 $$;
jbe@0 1071
jbe@0 1072 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
jbe@0 1073 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
jbe@0 1074
jbe@0 1075 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
jbe@0 1076 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
jbe@0 1077
jbe@0 1078
jbe@0 1079
jbe@4 1080 -----------------------------------------------------
jbe@4 1081 -- Automatic calculation of certain default values --
jbe@4 1082 -----------------------------------------------------
jbe@0 1083
jbe@22 1084
jbe@22 1085 CREATE FUNCTION "copy_timings_trigger"()
jbe@22 1086 RETURNS TRIGGER
jbe@22 1087 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@22 1088 DECLARE
jbe@22 1089 "policy_row" "policy"%ROWTYPE;
jbe@22 1090 BEGIN
jbe@22 1091 SELECT * INTO "policy_row" FROM "policy"
jbe@22 1092 WHERE "id" = NEW."policy_id";
jbe@22 1093 IF NEW."admission_time" ISNULL THEN
jbe@22 1094 NEW."admission_time" := "policy_row"."admission_time";
jbe@22 1095 END IF;
jbe@22 1096 IF NEW."discussion_time" ISNULL THEN
jbe@22 1097 NEW."discussion_time" := "policy_row"."discussion_time";
jbe@22 1098 END IF;
jbe@22 1099 IF NEW."verification_time" ISNULL THEN
jbe@22 1100 NEW."verification_time" := "policy_row"."verification_time";
jbe@22 1101 END IF;
jbe@22 1102 IF NEW."voting_time" ISNULL THEN
jbe@22 1103 NEW."voting_time" := "policy_row"."voting_time";
jbe@22 1104 END IF;
jbe@22 1105 RETURN NEW;
jbe@22 1106 END;
jbe@22 1107 $$;
jbe@22 1108
jbe@22 1109 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
jbe@22 1110 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
jbe@22 1111
jbe@22 1112 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
jbe@22 1113 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
jbe@22 1114
jbe@22 1115
jbe@0 1116 CREATE FUNCTION "copy_autoreject_trigger"()
jbe@0 1117 RETURNS TRIGGER
jbe@0 1118 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1119 BEGIN
jbe@0 1120 IF NEW."autoreject" ISNULL THEN
jbe@0 1121 SELECT "membership"."autoreject" INTO NEW."autoreject"
jbe@0 1122 FROM "issue" JOIN "membership"
jbe@0 1123 ON "issue"."area_id" = "membership"."area_id"
jbe@0 1124 WHERE "issue"."id" = NEW."issue_id"
jbe@0 1125 AND "membership"."member_id" = NEW."member_id";
jbe@0 1126 END IF;
jbe@0 1127 IF NEW."autoreject" ISNULL THEN
jbe@0 1128 NEW."autoreject" := FALSE;
jbe@0 1129 END IF;
jbe@0 1130 RETURN NEW;
jbe@0 1131 END;
jbe@0 1132 $$;
jbe@0 1133
jbe@0 1134 CREATE TRIGGER "copy_autoreject" BEFORE INSERT OR UPDATE ON "interest"
jbe@0 1135 FOR EACH ROW EXECUTE PROCEDURE "copy_autoreject_trigger"();
jbe@0 1136
jbe@0 1137 COMMENT ON FUNCTION "copy_autoreject_trigger"() IS 'Implementation of trigger "copy_autoreject" on table "interest"';
jbe@0 1138 COMMENT ON TRIGGER "copy_autoreject" ON "interest" IS 'If "autoreject" is NULL, then copy it from the area setting, or set to FALSE, if no membership existent';
jbe@0 1139
jbe@0 1140
jbe@2 1141 CREATE FUNCTION "supporter_default_for_draft_id_trigger"()
jbe@2 1142 RETURNS TRIGGER
jbe@2 1143 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@2 1144 BEGIN
jbe@2 1145 IF NEW."draft_id" ISNULL THEN
jbe@2 1146 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
jbe@2 1147 WHERE "initiative_id" = NEW."initiative_id";
jbe@2 1148 END IF;
jbe@2 1149 RETURN NEW;
jbe@2 1150 END;
jbe@2 1151 $$;
jbe@2 1152
jbe@2 1153 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
jbe@2 1154 FOR EACH ROW EXECUTE PROCEDURE "supporter_default_for_draft_id_trigger"();
jbe@2 1155
jbe@2 1156 COMMENT ON FUNCTION "supporter_default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on table "supporter"';
jbe@2 1157 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 1158
jbe@2 1159
jbe@0 1160
jbe@0 1161 ----------------------------------------
jbe@0 1162 -- Automatic creation of dependencies --
jbe@0 1163 ----------------------------------------
jbe@0 1164
jbe@22 1165
jbe@0 1166 CREATE FUNCTION "autocreate_interest_trigger"()
jbe@0 1167 RETURNS TRIGGER
jbe@0 1168 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1169 BEGIN
jbe@0 1170 IF NOT EXISTS (
jbe@0 1171 SELECT NULL FROM "initiative" JOIN "interest"
jbe@0 1172 ON "initiative"."issue_id" = "interest"."issue_id"
jbe@0 1173 WHERE "initiative"."id" = NEW."initiative_id"
jbe@0 1174 AND "interest"."member_id" = NEW."member_id"
jbe@0 1175 ) THEN
jbe@0 1176 BEGIN
jbe@0 1177 INSERT INTO "interest" ("issue_id", "member_id")
jbe@0 1178 SELECT "issue_id", NEW."member_id"
jbe@0 1179 FROM "initiative" WHERE "id" = NEW."initiative_id";
jbe@0 1180 EXCEPTION WHEN unique_violation THEN END;
jbe@0 1181 END IF;
jbe@0 1182 RETURN NEW;
jbe@0 1183 END;
jbe@0 1184 $$;
jbe@0 1185
jbe@0 1186 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
jbe@0 1187 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
jbe@0 1188
jbe@0 1189 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
jbe@0 1190 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 1191
jbe@0 1192
jbe@0 1193 CREATE FUNCTION "autocreate_supporter_trigger"()
jbe@0 1194 RETURNS TRIGGER
jbe@0 1195 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1196 BEGIN
jbe@0 1197 IF NOT EXISTS (
jbe@0 1198 SELECT NULL FROM "suggestion" JOIN "supporter"
jbe@0 1199 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
jbe@0 1200 WHERE "suggestion"."id" = NEW."suggestion_id"
jbe@0 1201 AND "supporter"."member_id" = NEW."member_id"
jbe@0 1202 ) THEN
jbe@0 1203 BEGIN
jbe@0 1204 INSERT INTO "supporter" ("initiative_id", "member_id")
jbe@0 1205 SELECT "initiative_id", NEW."member_id"
jbe@0 1206 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
jbe@0 1207 EXCEPTION WHEN unique_violation THEN END;
jbe@0 1208 END IF;
jbe@0 1209 RETURN NEW;
jbe@0 1210 END;
jbe@0 1211 $$;
jbe@0 1212
jbe@0 1213 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
jbe@0 1214 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
jbe@0 1215
jbe@0 1216 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
jbe@0 1217 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 1218
jbe@0 1219
jbe@0 1220
jbe@0 1221 ------------------------------------------
jbe@0 1222 -- Views and helper functions for views --
jbe@0 1223 ------------------------------------------
jbe@0 1224
jbe@5 1225
jbe@5 1226 CREATE VIEW "global_delegation" AS
jbe@5 1227 SELECT
jbe@5 1228 "delegation"."id",
jbe@5 1229 "delegation"."truster_id",
jbe@5 1230 "delegation"."trustee_id"
jbe@5 1231 FROM "delegation" JOIN "member"
jbe@5 1232 ON "delegation"."trustee_id" = "member"."id"
jbe@10 1233 WHERE "delegation"."scope" = 'global' AND "member"."active";
jbe@5 1234
jbe@5 1235 COMMENT ON VIEW "global_delegation" IS 'Global delegations to active members';
jbe@5 1236
jbe@5 1237
jbe@5 1238 CREATE VIEW "area_delegation" AS
jbe@5 1239 SELECT "subquery".* FROM (
jbe@5 1240 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
jbe@10 1241 "area"."id" AS "area_id",
jbe@10 1242 "delegation"."id",
jbe@10 1243 "delegation"."truster_id",
jbe@10 1244 "delegation"."trustee_id",
jbe@10 1245 "delegation"."scope"
jbe@5 1246 FROM "area" JOIN "delegation"
jbe@10 1247 ON "delegation"."scope" = 'global'
jbe@10 1248 OR "delegation"."area_id" = "area"."id"
jbe@5 1249 ORDER BY
jbe@5 1250 "area"."id",
jbe@5 1251 "delegation"."truster_id",
jbe@10 1252 "delegation"."scope" DESC
jbe@5 1253 ) AS "subquery"
jbe@5 1254 JOIN "member" ON "subquery"."trustee_id" = "member"."id"
jbe@5 1255 WHERE "member"."active";
jbe@5 1256
jbe@5 1257 COMMENT ON VIEW "area_delegation" IS 'Active delegations for areas';
jbe@5 1258
jbe@5 1259
jbe@5 1260 CREATE VIEW "issue_delegation" AS
jbe@5 1261 SELECT "subquery".* FROM (
jbe@5 1262 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
jbe@10 1263 "issue"."id" AS "issue_id",
jbe@10 1264 "delegation"."id",
jbe@10 1265 "delegation"."truster_id",
jbe@10 1266 "delegation"."trustee_id",
jbe@10 1267 "delegation"."scope"
jbe@5 1268 FROM "issue" JOIN "delegation"
jbe@10 1269 ON "delegation"."scope" = 'global'
jbe@10 1270 OR "delegation"."area_id" = "issue"."area_id"
jbe@10 1271 OR "delegation"."issue_id" = "issue"."id"
jbe@5 1272 ORDER BY
jbe@5 1273 "issue"."id",
jbe@5 1274 "delegation"."truster_id",
jbe@10 1275 "delegation"."scope" DESC
jbe@5 1276 ) AS "subquery"
jbe@5 1277 JOIN "member" ON "subquery"."trustee_id" = "member"."id"
jbe@5 1278 WHERE "member"."active";
jbe@5 1279
jbe@5 1280 COMMENT ON VIEW "issue_delegation" IS 'Active delegations for issues';
jbe@5 1281
jbe@5 1282
jbe@5 1283 CREATE FUNCTION "membership_weight_with_skipping"
jbe@5 1284 ( "area_id_p" "area"."id"%TYPE,
jbe@5 1285 "member_id_p" "member"."id"%TYPE,
jbe@5 1286 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
jbe@5 1287 RETURNS INT4
jbe@5 1288 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 1289 DECLARE
jbe@5 1290 "sum_v" INT4;
jbe@5 1291 "delegation_row" "area_delegation"%ROWTYPE;
jbe@5 1292 BEGIN
jbe@5 1293 "sum_v" := 1;
jbe@5 1294 FOR "delegation_row" IN
jbe@5 1295 SELECT "area_delegation".*
jbe@5 1296 FROM "area_delegation" LEFT JOIN "membership"
jbe@5 1297 ON "membership"."area_id" = "area_id_p"
jbe@5 1298 AND "membership"."member_id" = "area_delegation"."truster_id"
jbe@5 1299 WHERE "area_delegation"."area_id" = "area_id_p"
jbe@5 1300 AND "area_delegation"."trustee_id" = "member_id_p"
jbe@5 1301 AND "membership"."member_id" ISNULL
jbe@5 1302 LOOP
jbe@5 1303 IF NOT
jbe@5 1304 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
jbe@5 1305 THEN
jbe@5 1306 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
jbe@5 1307 "area_id_p",
jbe@5 1308 "delegation_row"."truster_id",
jbe@5 1309 "skip_member_ids_p" || "delegation_row"."truster_id"
jbe@5 1310 );
jbe@5 1311 END IF;
jbe@5 1312 END LOOP;
jbe@5 1313 RETURN "sum_v";
jbe@5 1314 END;
jbe@5 1315 $$;
jbe@5 1316
jbe@8 1317 COMMENT ON FUNCTION "membership_weight_with_skipping"
jbe@8 1318 ( "area"."id"%TYPE,
jbe@8 1319 "member"."id"%TYPE,
jbe@8 1320 INT4[] )
jbe@8 1321 IS 'Helper function for "membership_weight" function';
jbe@8 1322
jbe@8 1323
jbe@5 1324 CREATE FUNCTION "membership_weight"
jbe@5 1325 ( "area_id_p" "area"."id"%TYPE,
jbe@5 1326 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
jbe@5 1327 RETURNS INT4
jbe@5 1328 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 1329 BEGIN
jbe@5 1330 RETURN "membership_weight_with_skipping"(
jbe@5 1331 "area_id_p",
jbe@5 1332 "member_id_p",
jbe@5 1333 ARRAY["member_id_p"]
jbe@5 1334 );
jbe@5 1335 END;
jbe@5 1336 $$;
jbe@5 1337
jbe@8 1338 COMMENT ON FUNCTION "membership_weight"
jbe@8 1339 ( "area"."id"%TYPE,
jbe@8 1340 "member"."id"%TYPE )
jbe@8 1341 IS 'Calculates the potential voting weight of a member in a given area';
jbe@8 1342
jbe@5 1343
jbe@4 1344 CREATE VIEW "member_count_view" AS
jbe@5 1345 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
jbe@4 1346
jbe@4 1347 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
jbe@4 1348
jbe@4 1349
jbe@4 1350 CREATE VIEW "area_member_count" AS
jbe@5 1351 SELECT
jbe@5 1352 "area"."id" AS "area_id",
jbe@5 1353 count("member"."id") AS "direct_member_count",
jbe@5 1354 coalesce(
jbe@5 1355 sum(
jbe@5 1356 CASE WHEN "member"."id" NOTNULL THEN
jbe@5 1357 "membership_weight"("area"."id", "member"."id")
jbe@5 1358 ELSE 0 END
jbe@5 1359 )
jbe@5 1360 ) AS "member_weight",
jbe@5 1361 coalesce(
jbe@5 1362 sum(
jbe@5 1363 CASE WHEN "member"."id" NOTNULL AND "membership"."autoreject" THEN
jbe@5 1364 "membership_weight"("area"."id", "member"."id")
jbe@5 1365 ELSE 0 END
jbe@5 1366 )
jbe@5 1367 ) AS "autoreject_weight"
jbe@4 1368 FROM "area"
jbe@4 1369 LEFT JOIN "membership"
jbe@4 1370 ON "area"."id" = "membership"."area_id"
jbe@4 1371 LEFT JOIN "member"
jbe@4 1372 ON "membership"."member_id" = "member"."id"
jbe@4 1373 AND "member"."active"
jbe@4 1374 GROUP BY "area"."id";
jbe@4 1375
jbe@4 1376 COMMENT ON VIEW "area_member_count" IS 'View used to update "member_count" column of table "area"';
jbe@4 1377
jbe@4 1378
jbe@9 1379 CREATE VIEW "opening_draft" AS
jbe@9 1380 SELECT "draft".* FROM (
jbe@9 1381 SELECT
jbe@9 1382 "initiative"."id" AS "initiative_id",
jbe@9 1383 min("draft"."id") AS "draft_id"
jbe@9 1384 FROM "initiative" JOIN "draft"
jbe@9 1385 ON "initiative"."id" = "draft"."initiative_id"
jbe@9 1386 GROUP BY "initiative"."id"
jbe@9 1387 ) AS "subquery"
jbe@9 1388 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
jbe@9 1389
jbe@9 1390 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
jbe@9 1391
jbe@9 1392
jbe@0 1393 CREATE VIEW "current_draft" AS
jbe@0 1394 SELECT "draft".* FROM (
jbe@0 1395 SELECT
jbe@0 1396 "initiative"."id" AS "initiative_id",
jbe@0 1397 max("draft"."id") AS "draft_id"
jbe@0 1398 FROM "initiative" JOIN "draft"
jbe@0 1399 ON "initiative"."id" = "draft"."initiative_id"
jbe@0 1400 GROUP BY "initiative"."id"
jbe@0 1401 ) AS "subquery"
jbe@0 1402 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
jbe@0 1403
jbe@0 1404 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
jbe@0 1405
jbe@0 1406
jbe@0 1407 CREATE VIEW "critical_opinion" AS
jbe@0 1408 SELECT * FROM "opinion"
jbe@0 1409 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
jbe@0 1410 OR ("degree" = -2 AND "fulfilled" = TRUE);
jbe@0 1411
jbe@0 1412 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
jbe@0 1413
jbe@0 1414
jbe@0 1415 CREATE VIEW "battle" AS
jbe@0 1416 SELECT
jbe@0 1417 "issue"."id" AS "issue_id",
jbe@10 1418 "winning_initiative"."id" AS "winning_initiative_id",
jbe@10 1419 "losing_initiative"."id" AS "losing_initiative_id",
jbe@0 1420 sum(
jbe@0 1421 CASE WHEN
jbe@0 1422 coalesce("better_vote"."grade", 0) >
jbe@0 1423 coalesce("worse_vote"."grade", 0)
jbe@0 1424 THEN "direct_voter"."weight" ELSE 0 END
jbe@0 1425 ) AS "count"
jbe@0 1426 FROM "issue"
jbe@0 1427 LEFT JOIN "direct_voter"
jbe@0 1428 ON "issue"."id" = "direct_voter"."issue_id"
jbe@10 1429 JOIN "initiative" AS "winning_initiative"
jbe@10 1430 ON "issue"."id" = "winning_initiative"."issue_id"
jbe@10 1431 AND "winning_initiative"."agreed"
jbe@10 1432 JOIN "initiative" AS "losing_initiative"
jbe@10 1433 ON "issue"."id" = "losing_initiative"."issue_id"
jbe@10 1434 AND "losing_initiative"."agreed"
jbe@0 1435 LEFT JOIN "vote" AS "better_vote"
jbe@10 1436 ON "direct_voter"."member_id" = "better_vote"."member_id"
jbe@10 1437 AND "winning_initiative"."id" = "better_vote"."initiative_id"
jbe@0 1438 LEFT JOIN "vote" AS "worse_vote"
jbe@10 1439 ON "direct_voter"."member_id" = "worse_vote"."member_id"
jbe@10 1440 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
jbe@0 1441 WHERE
jbe@10 1442 "winning_initiative"."id" != "losing_initiative"."id"
jbe@0 1443 GROUP BY
jbe@0 1444 "issue"."id",
jbe@10 1445 "winning_initiative"."id",
jbe@10 1446 "losing_initiative"."id";
jbe@0 1447
jbe@0 1448 COMMENT ON VIEW "battle" IS 'Number of members preferring one initiative over another';
jbe@0 1449
jbe@0 1450
jbe@1 1451 CREATE VIEW "expired_session" AS
jbe@1 1452 SELECT * FROM "session" WHERE now() > "expiry";
jbe@1 1453
jbe@1 1454 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
jbe@1 1455 DELETE FROM "session" WHERE "ident" = OLD."ident";
jbe@1 1456
jbe@1 1457 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
jbe@1 1458 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 1459
jbe@1 1460
jbe@0 1461 CREATE VIEW "open_issue" AS
jbe@0 1462 SELECT * FROM "issue" WHERE "closed" ISNULL;
jbe@0 1463
jbe@0 1464 COMMENT ON VIEW "open_issue" IS 'All open issues';
jbe@0 1465
jbe@0 1466
jbe@0 1467 CREATE VIEW "issue_with_ranks_missing" AS
jbe@0 1468 SELECT * FROM "issue"
jbe@3 1469 WHERE "fully_frozen" NOTNULL
jbe@0 1470 AND "closed" NOTNULL
jbe@0 1471 AND "ranks_available" = FALSE;
jbe@0 1472
jbe@0 1473 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
jbe@0 1474
jbe@0 1475
jbe@9 1476 CREATE VIEW "member_contingent" AS
jbe@9 1477 SELECT
jbe@9 1478 "member"."id" AS "member_id",
jbe@9 1479 "contingent"."time_frame",
jbe@9 1480 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
jbe@9 1481 (
jbe@9 1482 SELECT count(1) FROM "draft"
jbe@9 1483 WHERE "draft"."author_id" = "member"."id"
jbe@9 1484 AND "draft"."created" > now() - "contingent"."time_frame"
jbe@9 1485 ) + (
jbe@9 1486 SELECT count(1) FROM "suggestion"
jbe@9 1487 WHERE "suggestion"."author_id" = "member"."id"
jbe@9 1488 AND "suggestion"."created" > now() - "contingent"."time_frame"
jbe@9 1489 )
jbe@9 1490 ELSE NULL END AS "text_entry_count",
jbe@9 1491 "contingent"."text_entry_limit",
jbe@9 1492 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
jbe@9 1493 SELECT count(1) FROM "opening_draft"
jbe@9 1494 WHERE "opening_draft"."author_id" = "member"."id"
jbe@9 1495 AND "opening_draft"."created" > now() - "contingent"."time_frame"
jbe@9 1496 ) ELSE NULL END AS "initiative_count",
jbe@9 1497 "contingent"."initiative_limit"
jbe@9 1498 FROM "member" CROSS JOIN "contingent";
jbe@9 1499
jbe@9 1500 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 1501
jbe@9 1502 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
jbe@9 1503 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
jbe@9 1504
jbe@9 1505
jbe@9 1506 CREATE VIEW "member_contingent_left" AS
jbe@9 1507 SELECT
jbe@9 1508 "member_id",
jbe@9 1509 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
jbe@9 1510 max("initiative_limit" - "initiative_count") AS "initiatives_left"
jbe@9 1511 FROM "member_contingent" GROUP BY "member_id";
jbe@9 1512
jbe@9 1513 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 1514
jbe@9 1515
jbe@16 1516 CREATE TYPE "timeline_event" AS ENUM (
jbe@16 1517 'issue_created',
jbe@16 1518 'issue_canceled',
jbe@16 1519 'issue_accepted',
jbe@16 1520 'issue_half_frozen',
jbe@16 1521 'issue_finished_without_voting',
jbe@16 1522 'issue_voting_started',
jbe@16 1523 'issue_finished_after_voting',
jbe@16 1524 'initiative_created',
jbe@16 1525 'initiative_revoked',
jbe@16 1526 'draft_created',
jbe@16 1527 'suggestion_created');
jbe@16 1528
jbe@16 1529 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables';
jbe@16 1530
jbe@16 1531
jbe@16 1532 CREATE VIEW "timeline_issue" AS
jbe@16 1533 SELECT
jbe@16 1534 "created" AS "occurrence",
jbe@16 1535 'issue_created'::"timeline_event" AS "event",
jbe@16 1536 "id" AS "issue_id"
jbe@16 1537 FROM "issue"
jbe@16 1538 UNION ALL
jbe@16 1539 SELECT
jbe@16 1540 "closed" AS "occurrence",
jbe@16 1541 'issue_canceled'::"timeline_event" AS "event",
jbe@16 1542 "id" AS "issue_id"
jbe@16 1543 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
jbe@16 1544 UNION ALL
jbe@16 1545 SELECT
jbe@16 1546 "accepted" AS "occurrence",
jbe@16 1547 'issue_accepted'::"timeline_event" AS "event",
jbe@16 1548 "id" AS "issue_id"
jbe@16 1549 FROM "issue" WHERE "accepted" NOTNULL
jbe@16 1550 UNION ALL
jbe@16 1551 SELECT
jbe@16 1552 "half_frozen" AS "occurrence",
jbe@16 1553 'issue_half_frozen'::"timeline_event" AS "event",
jbe@16 1554 "id" AS "issue_id"
jbe@16 1555 FROM "issue" WHERE "half_frozen" NOTNULL
jbe@16 1556 UNION ALL
jbe@16 1557 SELECT
jbe@16 1558 "fully_frozen" AS "occurrence",
jbe@16 1559 'issue_voting_started'::"timeline_event" AS "event",
jbe@16 1560 "id" AS "issue_id"
jbe@16 1561 FROM "issue"
jbe@17 1562 WHERE "fully_frozen" NOTNULL
jbe@17 1563 AND ("closed" ISNULL OR "closed" != "fully_frozen")
jbe@16 1564 UNION ALL
jbe@16 1565 SELECT
jbe@16 1566 "closed" AS "occurrence",
jbe@16 1567 CASE WHEN "fully_frozen" = "closed" THEN
jbe@16 1568 'issue_finished_without_voting'::"timeline_event"
jbe@16 1569 ELSE
jbe@16 1570 'issue_finished_after_voting'::"timeline_event"
jbe@16 1571 END AS "event",
jbe@16 1572 "id" AS "issue_id"
jbe@16 1573 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
jbe@16 1574
jbe@16 1575 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view';
jbe@16 1576
jbe@16 1577
jbe@16 1578 CREATE VIEW "timeline_initiative" AS
jbe@16 1579 SELECT
jbe@16 1580 "created" AS "occurrence",
jbe@16 1581 'initiative_created'::"timeline_event" AS "event",
jbe@16 1582 "id" AS "initiative_id"
jbe@16 1583 FROM "initiative"
jbe@16 1584 UNION ALL
jbe@16 1585 SELECT
jbe@16 1586 "revoked" AS "occurrence",
jbe@16 1587 'initiative_revoked'::"timeline_event" AS "event",
jbe@16 1588 "id" AS "initiative_id"
jbe@16 1589 FROM "initiative" WHERE "revoked" NOTNULL;
jbe@16 1590
jbe@16 1591 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view';
jbe@16 1592
jbe@16 1593
jbe@16 1594 CREATE VIEW "timeline_draft" AS
jbe@16 1595 SELECT
jbe@16 1596 "created" AS "occurrence",
jbe@16 1597 'draft_created'::"timeline_event" AS "event",
jbe@16 1598 "id" AS "draft_id"
jbe@16 1599 FROM "draft";
jbe@16 1600
jbe@16 1601 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view';
jbe@16 1602
jbe@16 1603
jbe@16 1604 CREATE VIEW "timeline_suggestion" AS
jbe@16 1605 SELECT
jbe@16 1606 "created" AS "occurrence",
jbe@16 1607 'suggestion_created'::"timeline_event" AS "event",
jbe@16 1608 "id" AS "suggestion_id"
jbe@16 1609 FROM "suggestion";
jbe@16 1610
jbe@16 1611 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view';
jbe@16 1612
jbe@16 1613
jbe@16 1614 CREATE VIEW "timeline" AS
jbe@16 1615 SELECT
jbe@16 1616 "occurrence",
jbe@16 1617 "event",
jbe@16 1618 "issue_id",
jbe@16 1619 NULL AS "initiative_id",
jbe@16 1620 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
jbe@16 1621 NULL::INT8 AS "suggestion_id"
jbe@16 1622 FROM "timeline_issue"
jbe@16 1623 UNION ALL
jbe@16 1624 SELECT
jbe@16 1625 "occurrence",
jbe@16 1626 "event",
jbe@16 1627 NULL AS "issue_id",
jbe@16 1628 "initiative_id",
jbe@16 1629 NULL AS "draft_id",
jbe@16 1630 NULL AS "suggestion_id"
jbe@16 1631 FROM "timeline_initiative"
jbe@16 1632 UNION ALL
jbe@16 1633 SELECT
jbe@16 1634 "occurrence",
jbe@16 1635 "event",
jbe@16 1636 NULL AS "issue_id",
jbe@16 1637 NULL AS "initiative_id",
jbe@16 1638 "draft_id",
jbe@16 1639 NULL AS "suggestion_id"
jbe@16 1640 FROM "timeline_draft"
jbe@16 1641 UNION ALL
jbe@16 1642 SELECT
jbe@16 1643 "occurrence",
jbe@16 1644 "event",
jbe@16 1645 NULL AS "issue_id",
jbe@16 1646 NULL AS "initiative_id",
jbe@16 1647 NULL AS "draft_id",
jbe@16 1648 "suggestion_id"
jbe@16 1649 FROM "timeline_suggestion";
jbe@16 1650
jbe@16 1651 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system';
jbe@16 1652
jbe@16 1653
jbe@0 1654
jbe@5 1655 --------------------------------------------------
jbe@5 1656 -- Set returning function for delegation chains --
jbe@5 1657 --------------------------------------------------
jbe@5 1658
jbe@5 1659
jbe@5 1660 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
jbe@5 1661 ('first', 'intermediate', 'last', 'repetition');
jbe@5 1662
jbe@5 1663 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
jbe@5 1664
jbe@5 1665
jbe@5 1666 CREATE TYPE "delegation_chain_row" AS (
jbe@5 1667 "index" INT4,
jbe@5 1668 "member_id" INT4,
jbe@5 1669 "member_active" BOOLEAN,
jbe@5 1670 "participation" BOOLEAN,
jbe@5 1671 "overridden" BOOLEAN,
jbe@5 1672 "scope_in" "delegation_scope",
jbe@5 1673 "scope_out" "delegation_scope",
jbe@5 1674 "loop" "delegation_chain_loop_tag" );
jbe@5 1675
jbe@5 1676 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain"(...) functions';
jbe@5 1677
jbe@5 1678 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
jbe@5 1679 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 1680 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
jbe@5 1681 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
jbe@5 1682 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
jbe@5 1683 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 1684
jbe@5 1685
jbe@5 1686 CREATE FUNCTION "delegation_chain"
jbe@5 1687 ( "member_id_p" "member"."id"%TYPE,
jbe@5 1688 "area_id_p" "area"."id"%TYPE,
jbe@5 1689 "issue_id_p" "issue"."id"%TYPE,
jbe@5 1690 "simulate_trustee_id_p" "member"."id"%TYPE )
jbe@5 1691 RETURNS SETOF "delegation_chain_row"
jbe@5 1692 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 1693 DECLARE
jbe@5 1694 "issue_row" "issue"%ROWTYPE;
jbe@5 1695 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
jbe@5 1696 "loop_member_id_v" "member"."id"%TYPE;
jbe@5 1697 "output_row" "delegation_chain_row";
jbe@5 1698 "output_rows" "delegation_chain_row"[];
jbe@5 1699 "delegation_row" "delegation"%ROWTYPE;
jbe@5 1700 "row_count" INT4;
jbe@5 1701 "i" INT4;
jbe@5 1702 "loop_v" BOOLEAN;
jbe@5 1703 BEGIN
jbe@5 1704 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@5 1705 "visited_member_ids" := '{}';
jbe@5 1706 "loop_member_id_v" := NULL;
jbe@5 1707 "output_rows" := '{}';
jbe@5 1708 "output_row"."index" := 0;
jbe@5 1709 "output_row"."member_id" := "member_id_p";
jbe@5 1710 "output_row"."member_active" := TRUE;
jbe@5 1711 "output_row"."participation" := FALSE;
jbe@5 1712 "output_row"."overridden" := FALSE;
jbe@5 1713 "output_row"."scope_out" := NULL;
jbe@5 1714 LOOP
jbe@5 1715 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
jbe@5 1716 "loop_member_id_v" := "output_row"."member_id";
jbe@5 1717 ELSE
jbe@5 1718 "visited_member_ids" :=
jbe@5 1719 "visited_member_ids" || "output_row"."member_id";
jbe@5 1720 END IF;
jbe@5 1721 IF "output_row"."participation" THEN
jbe@5 1722 "output_row"."overridden" := TRUE;
jbe@5 1723 END IF;
jbe@5 1724 "output_row"."scope_in" := "output_row"."scope_out";
jbe@5 1725 IF EXISTS (
jbe@5 1726 SELECT NULL FROM "member"
jbe@5 1727 WHERE "id" = "output_row"."member_id" AND "active"
jbe@5 1728 ) THEN
jbe@5 1729 IF "area_id_p" ISNULL AND "issue_id_p" ISNULL THEN
jbe@5 1730 SELECT * INTO "delegation_row" FROM "delegation"
jbe@5 1731 WHERE "truster_id" = "output_row"."member_id"
jbe@10 1732 AND "scope" = 'global';
jbe@5 1733 ELSIF "area_id_p" NOTNULL AND "issue_id_p" ISNULL THEN
jbe@5 1734 "output_row"."participation" := EXISTS (
jbe@5 1735 SELECT NULL FROM "membership"
jbe@5 1736 WHERE "area_id" = "area_id_p"
jbe@5 1737 AND "member_id" = "output_row"."member_id"
jbe@5 1738 );
jbe@5 1739 SELECT * INTO "delegation_row" FROM "delegation"
jbe@5 1740 WHERE "truster_id" = "output_row"."member_id"
jbe@10 1741 AND ("scope" = 'global' OR "area_id" = "area_id_p")
jbe@10 1742 ORDER BY "scope" DESC;
jbe@5 1743 ELSIF "area_id_p" ISNULL AND "issue_id_p" NOTNULL THEN
jbe@5 1744 "output_row"."participation" := EXISTS (
jbe@5 1745 SELECT NULL FROM "interest"
jbe@5 1746 WHERE "issue_id" = "issue_id_p"
jbe@5 1747 AND "member_id" = "output_row"."member_id"
jbe@5 1748 );
jbe@5 1749 SELECT * INTO "delegation_row" FROM "delegation"
jbe@5 1750 WHERE "truster_id" = "output_row"."member_id"
jbe@10 1751 AND ("scope" = 'global' OR
jbe@10 1752 "area_id" = "issue_row"."area_id" OR
jbe@10 1753 "issue_id" = "issue_id_p"
jbe@10 1754 )
jbe@10 1755 ORDER BY "scope" DESC;
jbe@5 1756 ELSE
jbe@5 1757 RAISE EXCEPTION 'Either area_id or issue_id or both must be NULL.';
jbe@5 1758 END IF;
jbe@5 1759 ELSE
jbe@5 1760 "output_row"."member_active" := FALSE;
jbe@5 1761 "output_row"."participation" := FALSE;
jbe@5 1762 "output_row"."scope_out" := NULL;
jbe@5 1763 "delegation_row" := ROW(NULL);
jbe@5 1764 END IF;
jbe@5 1765 IF
jbe@5 1766 "output_row"."member_id" = "member_id_p" AND
jbe@5 1767 "simulate_trustee_id_p" NOTNULL
jbe@5 1768 THEN
jbe@5 1769 "output_row"."scope_out" := CASE
jbe@5 1770 WHEN "area_id_p" ISNULL AND "issue_id_p" ISNULL THEN 'global'
jbe@5 1771 WHEN "area_id_p" NOTNULL AND "issue_id_p" ISNULL THEN 'area'
jbe@5 1772 WHEN "area_id_p" ISNULL AND "issue_id_p" NOTNULL THEN 'issue'
jbe@5 1773 END;
jbe@5 1774 "output_rows" := "output_rows" || "output_row";
jbe@5 1775 "output_row"."member_id" := "simulate_trustee_id_p";
jbe@5 1776 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
jbe@10 1777 "output_row"."scope_out" := "delegation_row"."scope";
jbe@5 1778 "output_rows" := "output_rows" || "output_row";
jbe@5 1779 "output_row"."member_id" := "delegation_row"."trustee_id";
jbe@5 1780 ELSE
jbe@5 1781 "output_row"."scope_out" := NULL;
jbe@5 1782 "output_rows" := "output_rows" || "output_row";
jbe@5 1783 EXIT;
jbe@5 1784 END IF;
jbe@5 1785 EXIT WHEN "loop_member_id_v" NOTNULL;
jbe@5 1786 "output_row"."index" := "output_row"."index" + 1;
jbe@5 1787 END LOOP;
jbe@5 1788 "row_count" := array_upper("output_rows", 1);
jbe@5 1789 "i" := 1;
jbe@5 1790 "loop_v" := FALSE;
jbe@5 1791 LOOP
jbe@5 1792 "output_row" := "output_rows"["i"];
jbe@5 1793 EXIT WHEN "output_row"."member_id" ISNULL;
jbe@5 1794 IF "loop_v" THEN
jbe@5 1795 IF "i" + 1 = "row_count" THEN
jbe@5 1796 "output_row"."loop" := 'last';
jbe@5 1797 ELSIF "i" = "row_count" THEN
jbe@5 1798 "output_row"."loop" := 'repetition';
jbe@5 1799 ELSE
jbe@5 1800 "output_row"."loop" := 'intermediate';
jbe@5 1801 END IF;
jbe@5 1802 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
jbe@5 1803 "output_row"."loop" := 'first';
jbe@5 1804 "loop_v" := TRUE;
jbe@5 1805 END IF;
jbe@5 1806 IF "area_id_p" ISNULL AND "issue_id_p" ISNULL THEN
jbe@5 1807 "output_row"."participation" := NULL;
jbe@5 1808 END IF;
jbe@5 1809 RETURN NEXT "output_row";
jbe@5 1810 "i" := "i" + 1;
jbe@5 1811 END LOOP;
jbe@5 1812 RETURN;
jbe@5 1813 END;
jbe@5 1814 $$;
jbe@5 1815
jbe@5 1816 COMMENT ON FUNCTION "delegation_chain"
jbe@5 1817 ( "member"."id"%TYPE,
jbe@5 1818 "area"."id"%TYPE,
jbe@5 1819 "issue"."id"%TYPE,
jbe@5 1820 "member"."id"%TYPE )
jbe@5 1821 IS 'Helper function for frontends to display delegation chains; Not part of internal voting logic';
jbe@5 1822
jbe@5 1823 CREATE FUNCTION "delegation_chain"
jbe@5 1824 ( "member_id_p" "member"."id"%TYPE,
jbe@5 1825 "area_id_p" "area"."id"%TYPE,
jbe@5 1826 "issue_id_p" "issue"."id"%TYPE )
jbe@5 1827 RETURNS SETOF "delegation_chain_row"
jbe@5 1828 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 1829 DECLARE
jbe@5 1830 "result_row" "delegation_chain_row";
jbe@5 1831 BEGIN
jbe@5 1832 FOR "result_row" IN
jbe@5 1833 SELECT * FROM "delegation_chain"(
jbe@5 1834 "member_id_p", "area_id_p", "issue_id_p", NULL
jbe@5 1835 )
jbe@5 1836 LOOP
jbe@5 1837 RETURN NEXT "result_row";
jbe@5 1838 END LOOP;
jbe@5 1839 RETURN;
jbe@5 1840 END;
jbe@5 1841 $$;
jbe@5 1842
jbe@5 1843 COMMENT ON FUNCTION "delegation_chain"
jbe@5 1844 ( "member"."id"%TYPE,
jbe@5 1845 "area"."id"%TYPE,
jbe@5 1846 "issue"."id"%TYPE )
jbe@5 1847 IS 'Shortcut for "delegation_chain"(...) function where 4th parameter is null';
jbe@5 1848
jbe@5 1849
jbe@5 1850
jbe@0 1851 ------------------------------
jbe@0 1852 -- Comparison by vote count --
jbe@0 1853 ------------------------------
jbe@0 1854
jbe@0 1855 CREATE FUNCTION "vote_ratio"
jbe@0 1856 ( "positive_votes_p" "initiative"."positive_votes"%TYPE,
jbe@0 1857 "negative_votes_p" "initiative"."negative_votes"%TYPE )
jbe@0 1858 RETURNS FLOAT8
jbe@0 1859 LANGUAGE 'plpgsql' STABLE AS $$
jbe@0 1860 BEGIN
jbe@30 1861 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN
jbe@30 1862 RETURN
jbe@30 1863 "positive_votes_p"::FLOAT8 /
jbe@30 1864 ("positive_votes_p" + "negative_votes_p")::FLOAT8;
jbe@30 1865 ELSIF "positive_votes_p" > 0 THEN
jbe@30 1866 RETURN "positive_votes_p";
jbe@30 1867 ELSIF "negative_votes_p" > 0 THEN
jbe@30 1868 RETURN 1 - "negative_votes_p";
jbe@0 1869 ELSE
jbe@0 1870 RETURN 0.5;
jbe@0 1871 END IF;
jbe@0 1872 END;
jbe@0 1873 $$;
jbe@0 1874
jbe@0 1875 COMMENT ON FUNCTION "vote_ratio"
jbe@0 1876 ( "initiative"."positive_votes"%TYPE,
jbe@0 1877 "initiative"."negative_votes"%TYPE )
jbe@30 1878 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 1879
jbe@0 1880
jbe@0 1881
jbe@0 1882 ------------------------------------------------
jbe@0 1883 -- Locking for snapshots and voting procedure --
jbe@0 1884 ------------------------------------------------
jbe@0 1885
jbe@0 1886 CREATE FUNCTION "global_lock"() RETURNS VOID
jbe@0 1887 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1888 BEGIN
jbe@0 1889 -- NOTE: PostgreSQL allows reading, while tables are locked in
jbe@0 1890 -- exclusive move. Transactions should be kept short anyway!
jbe@0 1891 LOCK TABLE "member" IN EXCLUSIVE MODE;
jbe@4 1892 LOCK TABLE "area" IN EXCLUSIVE MODE;
jbe@4 1893 LOCK TABLE "membership" IN EXCLUSIVE MODE;
jbe@4 1894 -- NOTE: "member", "area" and "membership" are locked first to
jbe@4 1895 -- prevent deadlocks in combination with "calculate_member_counts"()
jbe@0 1896 LOCK TABLE "policy" IN EXCLUSIVE MODE;
jbe@0 1897 LOCK TABLE "issue" IN EXCLUSIVE MODE;
jbe@0 1898 LOCK TABLE "initiative" IN EXCLUSIVE MODE;
jbe@0 1899 LOCK TABLE "draft" IN EXCLUSIVE MODE;
jbe@0 1900 LOCK TABLE "suggestion" IN EXCLUSIVE MODE;
jbe@0 1901 LOCK TABLE "interest" IN EXCLUSIVE MODE;
jbe@0 1902 LOCK TABLE "initiator" IN EXCLUSIVE MODE;
jbe@0 1903 LOCK TABLE "supporter" IN EXCLUSIVE MODE;
jbe@0 1904 LOCK TABLE "opinion" IN EXCLUSIVE MODE;
jbe@0 1905 LOCK TABLE "delegation" IN EXCLUSIVE MODE;
jbe@0 1906 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
jbe@0 1907 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
jbe@0 1908 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
jbe@0 1909 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
jbe@0 1910 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
jbe@0 1911 LOCK TABLE "direct_voter" IN EXCLUSIVE MODE;
jbe@0 1912 LOCK TABLE "delegating_voter" IN EXCLUSIVE MODE;
jbe@0 1913 LOCK TABLE "vote" IN EXCLUSIVE MODE;
jbe@0 1914 RETURN;
jbe@0 1915 END;
jbe@0 1916 $$;
jbe@0 1917
jbe@0 1918 COMMENT ON FUNCTION "global_lock"() IS 'Locks all tables related to support/voting until end of transaction; read access is still possible though';
jbe@0 1919
jbe@0 1920
jbe@0 1921
jbe@4 1922 -------------------------------
jbe@4 1923 -- Materialize member counts --
jbe@4 1924 -------------------------------
jbe@4 1925
jbe@4 1926 CREATE FUNCTION "calculate_member_counts"()
jbe@4 1927 RETURNS VOID
jbe@4 1928 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@4 1929 BEGIN
jbe@4 1930 LOCK TABLE "member" IN EXCLUSIVE MODE;
jbe@4 1931 LOCK TABLE "area" IN EXCLUSIVE MODE;
jbe@4 1932 LOCK TABLE "membership" IN EXCLUSIVE MODE;
jbe@4 1933 DELETE FROM "member_count";
jbe@5 1934 INSERT INTO "member_count" ("total_count")
jbe@5 1935 SELECT "total_count" FROM "member_count_view";
jbe@5 1936 UPDATE "area" SET
jbe@5 1937 "direct_member_count" = "view"."direct_member_count",
jbe@5 1938 "member_weight" = "view"."member_weight",
jbe@5 1939 "autoreject_weight" = "view"."autoreject_weight"
jbe@5 1940 FROM "area_member_count" AS "view"
jbe@5 1941 WHERE "view"."area_id" = "area"."id";
jbe@4 1942 RETURN;
jbe@4 1943 END;
jbe@4 1944 $$;
jbe@4 1945
jbe@4 1946 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 1947
jbe@4 1948
jbe@4 1949
jbe@0 1950 ------------------------------
jbe@0 1951 -- Calculation of snapshots --
jbe@0 1952 ------------------------------
jbe@0 1953
jbe@0 1954 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
jbe@0 1955 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 1956 "member_id_p" "member"."id"%TYPE,
jbe@0 1957 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
jbe@0 1958 RETURNS "direct_population_snapshot"."weight"%TYPE
jbe@0 1959 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1960 DECLARE
jbe@0 1961 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 1962 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
jbe@0 1963 "weight_v" INT4;
jbe@8 1964 "sub_weight_v" INT4;
jbe@0 1965 BEGIN
jbe@0 1966 "weight_v" := 0;
jbe@0 1967 FOR "issue_delegation_row" IN
jbe@0 1968 SELECT * FROM "issue_delegation"
jbe@0 1969 WHERE "trustee_id" = "member_id_p"
jbe@0 1970 AND "issue_id" = "issue_id_p"
jbe@0 1971 LOOP
jbe@0 1972 IF NOT EXISTS (
jbe@0 1973 SELECT NULL FROM "direct_population_snapshot"
jbe@0 1974 WHERE "issue_id" = "issue_id_p"
jbe@0 1975 AND "event" = 'periodic'
jbe@0 1976 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 1977 ) AND NOT EXISTS (
jbe@0 1978 SELECT NULL FROM "delegating_population_snapshot"
jbe@0 1979 WHERE "issue_id" = "issue_id_p"
jbe@0 1980 AND "event" = 'periodic'
jbe@0 1981 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 1982 ) THEN
jbe@0 1983 "delegate_member_ids_v" :=
jbe@0 1984 "member_id_p" || "delegate_member_ids_p";
jbe@10 1985 INSERT INTO "delegating_population_snapshot" (
jbe@10 1986 "issue_id",
jbe@10 1987 "event",
jbe@10 1988 "member_id",
jbe@10 1989 "scope",
jbe@10 1990 "delegate_member_ids"
jbe@10 1991 ) VALUES (
jbe@0 1992 "issue_id_p",
jbe@0 1993 'periodic',
jbe@0 1994 "issue_delegation_row"."truster_id",
jbe@10 1995 "issue_delegation_row"."scope",
jbe@0 1996 "delegate_member_ids_v"
jbe@0 1997 );
jbe@8 1998 "sub_weight_v" := 1 +
jbe@0 1999 "weight_of_added_delegations_for_population_snapshot"(
jbe@0 2000 "issue_id_p",
jbe@0 2001 "issue_delegation_row"."truster_id",
jbe@0 2002 "delegate_member_ids_v"
jbe@0 2003 );
jbe@8 2004 UPDATE "delegating_population_snapshot"
jbe@8 2005 SET "weight" = "sub_weight_v"
jbe@8 2006 WHERE "issue_id" = "issue_id_p"
jbe@8 2007 AND "event" = 'periodic'
jbe@8 2008 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 2009 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 2010 END IF;
jbe@0 2011 END LOOP;
jbe@0 2012 RETURN "weight_v";
jbe@0 2013 END;
jbe@0 2014 $$;
jbe@0 2015
jbe@0 2016 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
jbe@0 2017 ( "issue"."id"%TYPE,
jbe@0 2018 "member"."id"%TYPE,
jbe@0 2019 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
jbe@0 2020 IS 'Helper function for "create_population_snapshot" function';
jbe@0 2021
jbe@0 2022
jbe@0 2023 CREATE FUNCTION "create_population_snapshot"
jbe@0 2024 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 2025 RETURNS VOID
jbe@0 2026 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2027 DECLARE
jbe@0 2028 "member_id_v" "member"."id"%TYPE;
jbe@0 2029 BEGIN
jbe@0 2030 DELETE FROM "direct_population_snapshot"
jbe@0 2031 WHERE "issue_id" = "issue_id_p"
jbe@0 2032 AND "event" = 'periodic';
jbe@0 2033 DELETE FROM "delegating_population_snapshot"
jbe@0 2034 WHERE "issue_id" = "issue_id_p"
jbe@0 2035 AND "event" = 'periodic';
jbe@0 2036 INSERT INTO "direct_population_snapshot"
jbe@0 2037 ("issue_id", "event", "member_id", "interest_exists")
jbe@0 2038 SELECT DISTINCT ON ("issue_id", "member_id")
jbe@0 2039 "issue_id_p" AS "issue_id",
jbe@0 2040 'periodic' AS "event",
jbe@0 2041 "subquery"."member_id",
jbe@0 2042 "subquery"."interest_exists"
jbe@0 2043 FROM (
jbe@0 2044 SELECT
jbe@0 2045 "member"."id" AS "member_id",
jbe@0 2046 FALSE AS "interest_exists"
jbe@0 2047 FROM "issue"
jbe@0 2048 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@0 2049 JOIN "membership" ON "area"."id" = "membership"."area_id"
jbe@0 2050 JOIN "member" ON "membership"."member_id" = "member"."id"
jbe@0 2051 WHERE "issue"."id" = "issue_id_p"
jbe@0 2052 AND "member"."active"
jbe@0 2053 UNION
jbe@0 2054 SELECT
jbe@0 2055 "member"."id" AS "member_id",
jbe@0 2056 TRUE AS "interest_exists"
jbe@0 2057 FROM "interest" JOIN "member"
jbe@0 2058 ON "interest"."member_id" = "member"."id"
jbe@0 2059 WHERE "interest"."issue_id" = "issue_id_p"
jbe@0 2060 AND "member"."active"
jbe@0 2061 ) AS "subquery"
jbe@0 2062 ORDER BY
jbe@0 2063 "issue_id_p",
jbe@0 2064 "subquery"."member_id",
jbe@0 2065 "subquery"."interest_exists" DESC;
jbe@0 2066 FOR "member_id_v" IN
jbe@0 2067 SELECT "member_id" FROM "direct_population_snapshot"
jbe@0 2068 WHERE "issue_id" = "issue_id_p"
jbe@0 2069 AND "event" = 'periodic'
jbe@0 2070 LOOP
jbe@0 2071 UPDATE "direct_population_snapshot" SET
jbe@0 2072 "weight" = 1 +
jbe@0 2073 "weight_of_added_delegations_for_population_snapshot"(
jbe@0 2074 "issue_id_p",
jbe@0 2075 "member_id_v",
jbe@0 2076 '{}'
jbe@0 2077 )
jbe@0 2078 WHERE "issue_id" = "issue_id_p"
jbe@0 2079 AND "event" = 'periodic'
jbe@0 2080 AND "member_id" = "member_id_v";
jbe@0 2081 END LOOP;
jbe@0 2082 RETURN;
jbe@0 2083 END;
jbe@0 2084 $$;
jbe@0 2085
jbe@0 2086 COMMENT ON FUNCTION "create_population_snapshot"
jbe@0 2087 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 2088 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 2089
jbe@0 2090
jbe@0 2091 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
jbe@0 2092 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 2093 "member_id_p" "member"."id"%TYPE,
jbe@0 2094 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@0 2095 RETURNS "direct_interest_snapshot"."weight"%TYPE
jbe@0 2096 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2097 DECLARE
jbe@0 2098 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 2099 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
jbe@0 2100 "weight_v" INT4;
jbe@8 2101 "sub_weight_v" INT4;
jbe@0 2102 BEGIN
jbe@0 2103 "weight_v" := 0;
jbe@0 2104 FOR "issue_delegation_row" IN
jbe@0 2105 SELECT * FROM "issue_delegation"
jbe@0 2106 WHERE "trustee_id" = "member_id_p"
jbe@0 2107 AND "issue_id" = "issue_id_p"
jbe@0 2108 LOOP
jbe@0 2109 IF NOT EXISTS (
jbe@0 2110 SELECT NULL FROM "direct_interest_snapshot"
jbe@0 2111 WHERE "issue_id" = "issue_id_p"
jbe@0 2112 AND "event" = 'periodic'
jbe@0 2113 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 2114 ) AND NOT EXISTS (
jbe@0 2115 SELECT NULL FROM "delegating_interest_snapshot"
jbe@0 2116 WHERE "issue_id" = "issue_id_p"
jbe@0 2117 AND "event" = 'periodic'
jbe@0 2118 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 2119 ) THEN
jbe@0 2120 "delegate_member_ids_v" :=
jbe@0 2121 "member_id_p" || "delegate_member_ids_p";
jbe@10 2122 INSERT INTO "delegating_interest_snapshot" (
jbe@10 2123 "issue_id",
jbe@10 2124 "event",
jbe@10 2125 "member_id",
jbe@10 2126 "scope",
jbe@10 2127 "delegate_member_ids"
jbe@10 2128 ) VALUES (
jbe@0 2129 "issue_id_p",
jbe@0 2130 'periodic',
jbe@0 2131 "issue_delegation_row"."truster_id",
jbe@10 2132 "issue_delegation_row"."scope",
jbe@0 2133 "delegate_member_ids_v"
jbe@0 2134 );
jbe@8 2135 "sub_weight_v" := 1 +
jbe@0 2136 "weight_of_added_delegations_for_interest_snapshot"(
jbe@0 2137 "issue_id_p",
jbe@0 2138 "issue_delegation_row"."truster_id",
jbe@0 2139 "delegate_member_ids_v"
jbe@0 2140 );
jbe@8 2141 UPDATE "delegating_interest_snapshot"
jbe@8 2142 SET "weight" = "sub_weight_v"
jbe@8 2143 WHERE "issue_id" = "issue_id_p"
jbe@8 2144 AND "event" = 'periodic'
jbe@8 2145 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 2146 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 2147 END IF;
jbe@0 2148 END LOOP;
jbe@0 2149 RETURN "weight_v";
jbe@0 2150 END;
jbe@0 2151 $$;
jbe@0 2152
jbe@0 2153 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
jbe@0 2154 ( "issue"."id"%TYPE,
jbe@0 2155 "member"."id"%TYPE,
jbe@0 2156 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@0 2157 IS 'Helper function for "create_interest_snapshot" function';
jbe@0 2158
jbe@0 2159
jbe@0 2160 CREATE FUNCTION "create_interest_snapshot"
jbe@0 2161 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 2162 RETURNS VOID
jbe@0 2163 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2164 DECLARE
jbe@0 2165 "member_id_v" "member"."id"%TYPE;
jbe@0 2166 BEGIN
jbe@0 2167 DELETE FROM "direct_interest_snapshot"
jbe@0 2168 WHERE "issue_id" = "issue_id_p"
jbe@0 2169 AND "event" = 'periodic';
jbe@0 2170 DELETE FROM "delegating_interest_snapshot"
jbe@0 2171 WHERE "issue_id" = "issue_id_p"
jbe@0 2172 AND "event" = 'periodic';
jbe@0 2173 DELETE FROM "direct_supporter_snapshot"
jbe@0 2174 WHERE "issue_id" = "issue_id_p"
jbe@0 2175 AND "event" = 'periodic';
jbe@0 2176 INSERT INTO "direct_interest_snapshot"
jbe@0 2177 ("issue_id", "event", "member_id", "voting_requested")
jbe@0 2178 SELECT
jbe@0 2179 "issue_id_p" AS "issue_id",
jbe@0 2180 'periodic' AS "event",
jbe@0 2181 "member"."id" AS "member_id",
jbe@0 2182 "interest"."voting_requested"
jbe@0 2183 FROM "interest" JOIN "member"
jbe@0 2184 ON "interest"."member_id" = "member"."id"
jbe@0 2185 WHERE "interest"."issue_id" = "issue_id_p"
jbe@0 2186 AND "member"."active";
jbe@0 2187 FOR "member_id_v" IN
jbe@0 2188 SELECT "member_id" FROM "direct_interest_snapshot"
jbe@0 2189 WHERE "issue_id" = "issue_id_p"
jbe@0 2190 AND "event" = 'periodic'
jbe@0 2191 LOOP
jbe@0 2192 UPDATE "direct_interest_snapshot" SET
jbe@0 2193 "weight" = 1 +
jbe@0 2194 "weight_of_added_delegations_for_interest_snapshot"(
jbe@0 2195 "issue_id_p",
jbe@0 2196 "member_id_v",
jbe@0 2197 '{}'
jbe@0 2198 )
jbe@0 2199 WHERE "issue_id" = "issue_id_p"
jbe@0 2200 AND "event" = 'periodic'
jbe@0 2201 AND "member_id" = "member_id_v";
jbe@0 2202 END LOOP;
jbe@0 2203 INSERT INTO "direct_supporter_snapshot"
jbe@0 2204 ( "issue_id", "initiative_id", "event", "member_id",
jbe@0 2205 "informed", "satisfied" )
jbe@0 2206 SELECT
jbe@0 2207 "issue_id_p" AS "issue_id",
jbe@0 2208 "initiative"."id" AS "initiative_id",
jbe@0 2209 'periodic' AS "event",
jbe@0 2210 "member"."id" AS "member_id",
jbe@0 2211 "supporter"."draft_id" = "current_draft"."id" AS "informed",
jbe@0 2212 NOT EXISTS (
jbe@0 2213 SELECT NULL FROM "critical_opinion"
jbe@0 2214 WHERE "initiative_id" = "initiative"."id"
jbe@0 2215 AND "member_id" = "member"."id"
jbe@0 2216 ) AS "satisfied"
jbe@0 2217 FROM "supporter"
jbe@0 2218 JOIN "member"
jbe@0 2219 ON "supporter"."member_id" = "member"."id"
jbe@0 2220 JOIN "initiative"
jbe@0 2221 ON "supporter"."initiative_id" = "initiative"."id"
jbe@0 2222 JOIN "current_draft"
jbe@0 2223 ON "initiative"."id" = "current_draft"."initiative_id"
jbe@0 2224 JOIN "direct_interest_snapshot"
jbe@0 2225 ON "member"."id" = "direct_interest_snapshot"."member_id"
jbe@0 2226 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
jbe@3 2227 AND "event" = 'periodic'
jbe@0 2228 WHERE "member"."active"
jbe@0 2229 AND "initiative"."issue_id" = "issue_id_p";
jbe@0 2230 RETURN;
jbe@0 2231 END;
jbe@0 2232 $$;
jbe@0 2233
jbe@0 2234 COMMENT ON FUNCTION "create_interest_snapshot"
jbe@0 2235 ( "issue"."id"%TYPE )
jbe@0 2236 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 2237
jbe@0 2238
jbe@0 2239 CREATE FUNCTION "create_snapshot"
jbe@0 2240 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 2241 RETURNS VOID
jbe@0 2242 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2243 DECLARE
jbe@0 2244 "initiative_id_v" "initiative"."id"%TYPE;
jbe@0 2245 "suggestion_id_v" "suggestion"."id"%TYPE;
jbe@0 2246 BEGIN
jbe@0 2247 PERFORM "global_lock"();
jbe@0 2248 PERFORM "create_population_snapshot"("issue_id_p");
jbe@0 2249 PERFORM "create_interest_snapshot"("issue_id_p");
jbe@0 2250 UPDATE "issue" SET
jbe@8 2251 "snapshot" = now(),
jbe@8 2252 "latest_snapshot_event" = 'periodic',
jbe@0 2253 "population" = (
jbe@0 2254 SELECT coalesce(sum("weight"), 0)
jbe@0 2255 FROM "direct_population_snapshot"
jbe@0 2256 WHERE "issue_id" = "issue_id_p"
jbe@0 2257 AND "event" = 'periodic'
jbe@0 2258 ),
jbe@8 2259 "vote_now" = (
jbe@0 2260 SELECT coalesce(sum("weight"), 0)
jbe@0 2261 FROM "direct_interest_snapshot"
jbe@0 2262 WHERE "issue_id" = "issue_id_p"
jbe@0 2263 AND "event" = 'periodic'
jbe@0 2264 AND "voting_requested" = TRUE
jbe@0 2265 ),
jbe@0 2266 "vote_later" = (
jbe@0 2267 SELECT coalesce(sum("weight"), 0)
jbe@0 2268 FROM "direct_interest_snapshot"
jbe@0 2269 WHERE "issue_id" = "issue_id_p"
jbe@0 2270 AND "event" = 'periodic'
jbe@0 2271 AND "voting_requested" = FALSE
jbe@0 2272 )
jbe@0 2273 WHERE "id" = "issue_id_p";
jbe@0 2274 FOR "initiative_id_v" IN
jbe@0 2275 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
jbe@0 2276 LOOP
jbe@0 2277 UPDATE "initiative" SET
jbe@0 2278 "supporter_count" = (
jbe@0 2279 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 2280 FROM "direct_interest_snapshot" AS "di"
jbe@0 2281 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 2282 ON "di"."member_id" = "ds"."member_id"
jbe@0 2283 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 2284 AND "di"."event" = 'periodic'
jbe@0 2285 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 2286 AND "ds"."event" = 'periodic'
jbe@0 2287 ),
jbe@0 2288 "informed_supporter_count" = (
jbe@0 2289 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 2290 FROM "direct_interest_snapshot" AS "di"
jbe@0 2291 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 2292 ON "di"."member_id" = "ds"."member_id"
jbe@0 2293 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 2294 AND "di"."event" = 'periodic'
jbe@0 2295 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 2296 AND "ds"."event" = 'periodic'
jbe@0 2297 AND "ds"."informed"
jbe@0 2298 ),
jbe@0 2299 "satisfied_supporter_count" = (
jbe@0 2300 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 2301 FROM "direct_interest_snapshot" AS "di"
jbe@0 2302 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 2303 ON "di"."member_id" = "ds"."member_id"
jbe@0 2304 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 2305 AND "di"."event" = 'periodic'
jbe@0 2306 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 2307 AND "ds"."event" = 'periodic'
jbe@0 2308 AND "ds"."satisfied"
jbe@0 2309 ),
jbe@0 2310 "satisfied_informed_supporter_count" = (
jbe@0 2311 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 2312 FROM "direct_interest_snapshot" AS "di"
jbe@0 2313 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 2314 ON "di"."member_id" = "ds"."member_id"
jbe@0 2315 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 2316 AND "di"."event" = 'periodic'
jbe@0 2317 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 2318 AND "ds"."event" = 'periodic'
jbe@0 2319 AND "ds"."informed"
jbe@0 2320 AND "ds"."satisfied"
jbe@0 2321 )
jbe@0 2322 WHERE "id" = "initiative_id_v";
jbe@0 2323 FOR "suggestion_id_v" IN
jbe@0 2324 SELECT "id" FROM "suggestion"
jbe@0 2325 WHERE "initiative_id" = "initiative_id_v"
jbe@0 2326 LOOP
jbe@0 2327 UPDATE "suggestion" SET
jbe@0 2328 "minus2_unfulfilled_count" = (
jbe@0 2329 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@0 2330 FROM "opinion" JOIN "direct_interest_snapshot" AS "snapshot"
jbe@0 2331 ON "opinion"."member_id" = "snapshot"."member_id"
jbe@1 2332 WHERE "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 2333 AND "snapshot"."issue_id" = "issue_id_p"
jbe@0 2334 AND "opinion"."degree" = -2
jbe@0 2335 AND "opinion"."fulfilled" = FALSE
jbe@0 2336 ),
jbe@0 2337 "minus2_fulfilled_count" = (
jbe@0 2338 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@0 2339 FROM "opinion" JOIN "direct_interest_snapshot" AS "snapshot"
jbe@0 2340 ON "opinion"."member_id" = "snapshot"."member_id"
jbe@1 2341 WHERE "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 2342 AND "snapshot"."issue_id" = "issue_id_p"
jbe@0 2343 AND "opinion"."degree" = -2
jbe@0 2344 AND "opinion"."fulfilled" = TRUE
jbe@0 2345 ),
jbe@0 2346 "minus1_unfulfilled_count" = (
jbe@0 2347 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@0 2348 FROM "opinion" JOIN "direct_interest_snapshot" AS "snapshot"
jbe@0 2349 ON "opinion"."member_id" = "snapshot"."member_id"
jbe@1 2350 WHERE "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 2351 AND "snapshot"."issue_id" = "issue_id_p"
jbe@0 2352 AND "opinion"."degree" = -1
jbe@0 2353 AND "opinion"."fulfilled" = FALSE
jbe@0 2354 ),
jbe@0 2355 "minus1_fulfilled_count" = (
jbe@0 2356 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@0 2357 FROM "opinion" JOIN "direct_interest_snapshot" AS "snapshot"
jbe@0 2358 ON "opinion"."member_id" = "snapshot"."member_id"
jbe@1 2359 WHERE "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 2360 AND "snapshot"."issue_id" = "issue_id_p"
jbe@0 2361 AND "opinion"."degree" = -1
jbe@0 2362 AND "opinion"."fulfilled" = TRUE
jbe@0 2363 ),
jbe@0 2364 "plus1_unfulfilled_count" = (
jbe@0 2365 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@0 2366 FROM "opinion" JOIN "direct_interest_snapshot" AS "snapshot"
jbe@0 2367 ON "opinion"."member_id" = "snapshot"."member_id"
jbe@1 2368 WHERE "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 2369 AND "snapshot"."issue_id" = "issue_id_p"
jbe@0 2370 AND "opinion"."degree" = 1
jbe@0 2371 AND "opinion"."fulfilled" = FALSE
jbe@0 2372 ),
jbe@0 2373 "plus1_fulfilled_count" = (
jbe@0 2374 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@0 2375 FROM "opinion" JOIN "direct_interest_snapshot" AS "snapshot"
jbe@0 2376 ON "opinion"."member_id" = "snapshot"."member_id"
jbe@1 2377 WHERE "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 2378 AND "snapshot"."issue_id" = "issue_id_p"
jbe@0 2379 AND "opinion"."degree" = 1
jbe@0 2380 AND "opinion"."fulfilled" = TRUE
jbe@0 2381 ),
jbe@0 2382 "plus2_unfulfilled_count" = (
jbe@0 2383 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@0 2384 FROM "opinion" JOIN "direct_interest_snapshot" AS "snapshot"
jbe@0 2385 ON "opinion"."member_id" = "snapshot"."member_id"
jbe@1 2386 WHERE "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 2387 AND "snapshot"."issue_id" = "issue_id_p"
jbe@0 2388 AND "opinion"."degree" = 2
jbe@0 2389 AND "opinion"."fulfilled" = FALSE
jbe@0 2390 ),
jbe@0 2391 "plus2_fulfilled_count" = (
jbe@0 2392 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@0 2393 FROM "opinion" JOIN "direct_interest_snapshot" AS "snapshot"
jbe@0 2394 ON "opinion"."member_id" = "snapshot"."member_id"
jbe@1 2395 WHERE "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 2396 AND "snapshot"."issue_id" = "issue_id_p"
jbe@0 2397 AND "opinion"."degree" = 2
jbe@0 2398 AND "opinion"."fulfilled" = TRUE
jbe@0 2399 )
jbe@0 2400 WHERE "suggestion"."id" = "suggestion_id_v";
jbe@0 2401 END LOOP;
jbe@0 2402 END LOOP;
jbe@0 2403 RETURN;
jbe@0 2404 END;
jbe@0 2405 $$;
jbe@0 2406
jbe@0 2407 COMMENT ON FUNCTION "create_snapshot"
jbe@0 2408 ( "issue"."id"%TYPE )
jbe@0 2409 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 2410
jbe@0 2411
jbe@0 2412 CREATE FUNCTION "set_snapshot_event"
jbe@0 2413 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 2414 "event_p" "snapshot_event" )
jbe@0 2415 RETURNS VOID
jbe@0 2416 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@21 2417 DECLARE
jbe@21 2418 "event_v" "issue"."latest_snapshot_event"%TYPE;
jbe@0 2419 BEGIN
jbe@21 2420 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
jbe@21 2421 WHERE "id" = "issue_id_p" FOR UPDATE;
jbe@8 2422 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
jbe@8 2423 WHERE "id" = "issue_id_p";
jbe@3 2424 UPDATE "direct_population_snapshot" SET "event" = "event_p"
jbe@21 2425 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 2426 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
jbe@21 2427 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 2428 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
jbe@21 2429 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 2430 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
jbe@21 2431 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 2432 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
jbe@21 2433 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@0 2434 RETURN;
jbe@0 2435 END;
jbe@0 2436 $$;
jbe@0 2437
jbe@0 2438 COMMENT ON FUNCTION "set_snapshot_event"
jbe@0 2439 ( "issue"."id"%TYPE,
jbe@0 2440 "snapshot_event" )
jbe@0 2441 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
jbe@0 2442
jbe@0 2443
jbe@0 2444
jbe@0 2445 ---------------------
jbe@0 2446 -- Freezing issues --
jbe@0 2447 ---------------------
jbe@0 2448
jbe@0 2449 CREATE FUNCTION "freeze_after_snapshot"
jbe@0 2450 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 2451 RETURNS VOID
jbe@0 2452 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2453 DECLARE
jbe@0 2454 "issue_row" "issue"%ROWTYPE;
jbe@0 2455 "policy_row" "policy"%ROWTYPE;
jbe@0 2456 "initiative_row" "initiative"%ROWTYPE;
jbe@0 2457 BEGIN
jbe@0 2458 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@0 2459 SELECT * INTO "policy_row"
jbe@0 2460 FROM "policy" WHERE "id" = "issue_row"."policy_id";
jbe@21 2461 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
jbe@3 2462 UPDATE "issue" SET
jbe@4 2463 "accepted" = coalesce("accepted", now()),
jbe@4 2464 "half_frozen" = coalesce("half_frozen", now()),
jbe@3 2465 "fully_frozen" = now()
jbe@3 2466 WHERE "id" = "issue_id_p";
jbe@0 2467 FOR "initiative_row" IN
jbe@15 2468 SELECT * FROM "initiative"
jbe@15 2469 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@0 2470 LOOP
jbe@0 2471 IF
jbe@0 2472 "initiative_row"."satisfied_supporter_count" > 0 AND
jbe@0 2473 "initiative_row"."satisfied_supporter_count" *
jbe@0 2474 "policy_row"."initiative_quorum_den" >=
jbe@0 2475 "issue_row"."population" * "policy_row"."initiative_quorum_num"
jbe@0 2476 THEN
jbe@0 2477 UPDATE "initiative" SET "admitted" = TRUE
jbe@0 2478 WHERE "id" = "initiative_row"."id";
jbe@0 2479 ELSE
jbe@0 2480 UPDATE "initiative" SET "admitted" = FALSE
jbe@0 2481 WHERE "id" = "initiative_row"."id";
jbe@0 2482 END IF;
jbe@0 2483 END LOOP;
jbe@9 2484 IF NOT EXISTS (
jbe@9 2485 SELECT NULL FROM "initiative"
jbe@9 2486 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
jbe@9 2487 ) THEN
jbe@9 2488 PERFORM "close_voting"("issue_id_p");
jbe@9 2489 END IF;
jbe@0 2490 RETURN;
jbe@0 2491 END;
jbe@0 2492 $$;
jbe@0 2493
jbe@0 2494 COMMENT ON FUNCTION "freeze_after_snapshot"
jbe@0 2495 ( "issue"."id"%TYPE )
jbe@9 2496 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 2497
jbe@0 2498
jbe@0 2499 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
jbe@0 2500 RETURNS VOID
jbe@0 2501 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2502 DECLARE
jbe@0 2503 "issue_row" "issue"%ROWTYPE;
jbe@0 2504 BEGIN
jbe@0 2505 PERFORM "create_snapshot"("issue_id_p");
jbe@0 2506 PERFORM "freeze_after_snapshot"("issue_id_p");
jbe@0 2507 RETURN;
jbe@0 2508 END;
jbe@0 2509 $$;
jbe@0 2510
jbe@0 2511 COMMENT ON FUNCTION "freeze_after_snapshot"
jbe@0 2512 ( "issue"."id"%TYPE )
jbe@3 2513 IS 'Freeze an issue manually (fully) and start voting';
jbe@0 2514
jbe@0 2515
jbe@0 2516
jbe@0 2517 -----------------------
jbe@0 2518 -- Counting of votes --
jbe@0 2519 -----------------------
jbe@0 2520
jbe@0 2521
jbe@5 2522 CREATE FUNCTION "weight_of_added_vote_delegations"
jbe@0 2523 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 2524 "member_id_p" "member"."id"%TYPE,
jbe@0 2525 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
jbe@0 2526 RETURNS "direct_voter"."weight"%TYPE
jbe@0 2527 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2528 DECLARE
jbe@0 2529 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 2530 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
jbe@0 2531 "weight_v" INT4;
jbe@8 2532 "sub_weight_v" INT4;
jbe@0 2533 BEGIN
jbe@0 2534 "weight_v" := 0;
jbe@0 2535 FOR "issue_delegation_row" IN
jbe@0 2536 SELECT * FROM "issue_delegation"
jbe@0 2537 WHERE "trustee_id" = "member_id_p"
jbe@0 2538 AND "issue_id" = "issue_id_p"
jbe@0 2539 LOOP
jbe@0 2540 IF NOT EXISTS (
jbe@0 2541 SELECT NULL FROM "direct_voter"
jbe@0 2542 WHERE "member_id" = "issue_delegation_row"."truster_id"
jbe@0 2543 AND "issue_id" = "issue_id_p"
jbe@0 2544 ) AND NOT EXISTS (
jbe@0 2545 SELECT NULL FROM "delegating_voter"
jbe@0 2546 WHERE "member_id" = "issue_delegation_row"."truster_id"
jbe@0 2547 AND "issue_id" = "issue_id_p"
jbe@0 2548 ) THEN
jbe@0 2549 "delegate_member_ids_v" :=
jbe@0 2550 "member_id_p" || "delegate_member_ids_p";
jbe@10 2551 INSERT INTO "delegating_voter" (
jbe@10 2552 "issue_id",
jbe@10 2553 "member_id",
jbe@10 2554 "scope",
jbe@10 2555 "delegate_member_ids"
jbe@10 2556 ) VALUES (
jbe@5 2557 "issue_id_p",
jbe@5 2558 "issue_delegation_row"."truster_id",
jbe@10 2559 "issue_delegation_row"."scope",
jbe@5 2560 "delegate_member_ids_v"
jbe@5 2561 );
jbe@8 2562 "sub_weight_v" := 1 +
jbe@8 2563 "weight_of_added_vote_delegations"(
jbe@8 2564 "issue_id_p",
jbe@8 2565 "issue_delegation_row"."truster_id",
jbe@8 2566 "delegate_member_ids_v"
jbe@8 2567 );
jbe@8 2568 UPDATE "delegating_voter"
jbe@8 2569 SET "weight" = "sub_weight_v"
jbe@8 2570 WHERE "issue_id" = "issue_id_p"
jbe@8 2571 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 2572 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 2573 END IF;
jbe@0 2574 END LOOP;
jbe@0 2575 RETURN "weight_v";
jbe@0 2576 END;
jbe@0 2577 $$;
jbe@0 2578
jbe@5 2579 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
jbe@0 2580 ( "issue"."id"%TYPE,
jbe@0 2581 "member"."id"%TYPE,
jbe@0 2582 "delegating_voter"."delegate_member_ids"%TYPE )
jbe@0 2583 IS 'Helper function for "add_vote_delegations" function';
jbe@0 2584
jbe@0 2585
jbe@0 2586 CREATE FUNCTION "add_vote_delegations"
jbe@0 2587 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 2588 RETURNS VOID
jbe@0 2589 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2590 DECLARE
jbe@0 2591 "member_id_v" "member"."id"%TYPE;
jbe@0 2592 BEGIN
jbe@0 2593 FOR "member_id_v" IN
jbe@0 2594 SELECT "member_id" FROM "direct_voter"
jbe@0 2595 WHERE "issue_id" = "issue_id_p"
jbe@0 2596 LOOP
jbe@0 2597 UPDATE "direct_voter" SET
jbe@5 2598 "weight" = "weight" + "weight_of_added_vote_delegations"(
jbe@0 2599 "issue_id_p",
jbe@0 2600 "member_id_v",
jbe@0 2601 '{}'
jbe@0 2602 )
jbe@0 2603 WHERE "member_id" = "member_id_v"
jbe@0 2604 AND "issue_id" = "issue_id_p";
jbe@0 2605 END LOOP;
jbe@0 2606 RETURN;
jbe@0 2607 END;
jbe@0 2608 $$;
jbe@0 2609
jbe@0 2610 COMMENT ON FUNCTION "add_vote_delegations"
jbe@0 2611 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 2612 IS 'Helper function for "close_voting" function';
jbe@0 2613
jbe@0 2614
jbe@0 2615 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
jbe@0 2616 RETURNS VOID
jbe@0 2617 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2618 DECLARE
jbe@0 2619 "issue_row" "issue"%ROWTYPE;
jbe@0 2620 "member_id_v" "member"."id"%TYPE;
jbe@0 2621 BEGIN
jbe@0 2622 PERFORM "global_lock"();
jbe@0 2623 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@0 2624 DELETE FROM "delegating_voter"
jbe@0 2625 WHERE "issue_id" = "issue_id_p";
jbe@0 2626 DELETE FROM "direct_voter"
jbe@0 2627 WHERE "issue_id" = "issue_id_p"
jbe@0 2628 AND "autoreject" = TRUE;
jbe@0 2629 DELETE FROM "direct_voter" USING "member"
jbe@0 2630 WHERE "direct_voter"."member_id" = "member"."id"
jbe@0 2631 AND "direct_voter"."issue_id" = "issue_id_p"
jbe@0 2632 AND "member"."active" = FALSE;
jbe@0 2633 UPDATE "direct_voter" SET "weight" = 1
jbe@0 2634 WHERE "issue_id" = "issue_id_p";
jbe@0 2635 PERFORM "add_vote_delegations"("issue_id_p");
jbe@0 2636 FOR "member_id_v" IN
jbe@0 2637 SELECT "interest"."member_id"
jbe@0 2638 FROM "interest"
jbe@0 2639 LEFT JOIN "direct_voter"
jbe@0 2640 ON "interest"."member_id" = "direct_voter"."member_id"
jbe@0 2641 AND "interest"."issue_id" = "direct_voter"."issue_id"
jbe@0 2642 LEFT JOIN "delegating_voter"
jbe@0 2643 ON "interest"."member_id" = "delegating_voter"."member_id"
jbe@0 2644 AND "interest"."issue_id" = "delegating_voter"."issue_id"
jbe@0 2645 WHERE "interest"."issue_id" = "issue_id_p"
jbe@0 2646 AND "interest"."autoreject" = TRUE
jbe@0 2647 AND "direct_voter"."member_id" ISNULL
jbe@0 2648 AND "delegating_voter"."member_id" ISNULL
jbe@0 2649 UNION SELECT "membership"."member_id"
jbe@0 2650 FROM "membership"
jbe@0 2651 LEFT JOIN "interest"
jbe@0 2652 ON "membership"."member_id" = "interest"."member_id"
jbe@0 2653 AND "interest"."issue_id" = "issue_id_p"
jbe@0 2654 LEFT JOIN "direct_voter"
jbe@0 2655 ON "membership"."member_id" = "direct_voter"."member_id"
jbe@0 2656 AND "direct_voter"."issue_id" = "issue_id_p"
jbe@0 2657 LEFT JOIN "delegating_voter"
jbe@0 2658 ON "membership"."member_id" = "delegating_voter"."member_id"
jbe@0 2659 AND "delegating_voter"."issue_id" = "issue_id_p"
jbe@0 2660 WHERE "membership"."area_id" = "issue_row"."area_id"
jbe@0 2661 AND "membership"."autoreject" = TRUE
jbe@0 2662 AND "interest"."autoreject" ISNULL
jbe@0 2663 AND "direct_voter"."member_id" ISNULL
jbe@0 2664 AND "delegating_voter"."member_id" ISNULL
jbe@0 2665 LOOP
jbe@11 2666 INSERT INTO "direct_voter"
jbe@11 2667 ("member_id", "issue_id", "weight", "autoreject") VALUES
jbe@11 2668 ("member_id_v", "issue_id_p", 1, TRUE);
jbe@0 2669 INSERT INTO "vote" (
jbe@0 2670 "member_id",
jbe@0 2671 "issue_id",
jbe@0 2672 "initiative_id",
jbe@0 2673 "grade"
jbe@0 2674 ) SELECT
jbe@0 2675 "member_id_v" AS "member_id",
jbe@0 2676 "issue_id_p" AS "issue_id",
jbe@0 2677 "id" AS "initiative_id",
jbe@0 2678 -1 AS "grade"
jbe@0 2679 FROM "initiative" WHERE "issue_id" = "issue_id_p";
jbe@0 2680 END LOOP;
jbe@0 2681 PERFORM "add_vote_delegations"("issue_id_p");
jbe@4 2682 UPDATE "issue" SET
jbe@4 2683 "voter_count" = (
jbe@4 2684 SELECT coalesce(sum("weight"), 0)
jbe@4 2685 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
jbe@6 2686 )
jbe@6 2687 WHERE "id" = "issue_id_p";
jbe@0 2688 UPDATE "initiative" SET
jbe@10 2689 "positive_votes" = "vote_counts"."positive_votes",
jbe@10 2690 "negative_votes" = "vote_counts"."negative_votes",
jbe@10 2691 "agreed" = CASE WHEN "majority_strict" THEN
jbe@10 2692 "vote_counts"."positive_votes" * "majority_den" >
jbe@10 2693 "majority_num" *
jbe@10 2694 ("vote_counts"."positive_votes"+"vote_counts"."negative_votes")
jbe@10 2695 ELSE
jbe@10 2696 "vote_counts"."positive_votes" * "majority_den" >=
jbe@10 2697 "majority_num" *
jbe@10 2698 ("vote_counts"."positive_votes"+"vote_counts"."negative_votes")
jbe@10 2699 END
jbe@10 2700 FROM
jbe@10 2701 ( SELECT
jbe@10 2702 "initiative"."id" AS "initiative_id",
jbe@10 2703 coalesce(
jbe@10 2704 sum(
jbe@10 2705 CASE WHEN "grade" > 0 THEN "direct_voter"."weight" ELSE 0 END
jbe@10 2706 ),
jbe@10 2707 0
jbe@10 2708 ) AS "positive_votes",
jbe@10 2709 coalesce(
jbe@10 2710 sum(
jbe@10 2711 CASE WHEN "grade" < 0 THEN "direct_voter"."weight" ELSE 0 END
jbe@10 2712 ),
jbe@10 2713 0
jbe@10 2714 ) AS "negative_votes"
jbe@10 2715 FROM "initiative"
jbe@10 2716 JOIN "issue" ON "initiative"."issue_id" = "issue"."id"
jbe@10 2717 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
jbe@10 2718 LEFT JOIN "direct_voter"
jbe@10 2719 ON "direct_voter"."issue_id" = "initiative"."issue_id"
jbe@10 2720 LEFT JOIN "vote"
jbe@10 2721 ON "vote"."initiative_id" = "initiative"."id"
jbe@10 2722 AND "vote"."member_id" = "direct_voter"."member_id"
jbe@10 2723 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@15 2724 AND "initiative"."admitted" -- NOTE: NULL case is handled too
jbe@10 2725 GROUP BY "initiative"."id"
jbe@10 2726 ) AS "vote_counts",
jbe@10 2727 "issue",
jbe@10 2728 "policy"
jbe@10 2729 WHERE "vote_counts"."initiative_id" = "initiative"."id"
jbe@10 2730 AND "issue"."id" = "initiative"."issue_id"
jbe@10 2731 AND "policy"."id" = "issue"."policy_id";
jbe@0 2732 UPDATE "issue" SET "closed" = now() WHERE "id" = "issue_id_p";
jbe@0 2733 END;
jbe@0 2734 $$;
jbe@0 2735
jbe@0 2736 COMMENT ON FUNCTION "close_voting"
jbe@0 2737 ( "issue"."id"%TYPE )
jbe@0 2738 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 2739
jbe@0 2740
jbe@30 2741 CREATE FUNCTION "defeat_strength"
jbe@30 2742 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
jbe@30 2743 RETURNS INT8
jbe@30 2744 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@30 2745 BEGIN
jbe@30 2746 IF "positive_votes_p" > "negative_votes_p" THEN
jbe@30 2747 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
jbe@30 2748 ELSIF "positive_votes_p" = "negative_votes_p" THEN
jbe@30 2749 RETURN 0;
jbe@30 2750 ELSE
jbe@30 2751 RETURN -1;
jbe@30 2752 END IF;
jbe@30 2753 END;
jbe@30 2754 $$;
jbe@30 2755
jbe@30 2756 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 2757
jbe@30 2758
jbe@30 2759 CREATE FUNCTION "array_init_string"("dim_p" INTEGER)
jbe@30 2760 RETURNS TEXT
jbe@0 2761 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@0 2762 DECLARE
jbe@0 2763 "i" INTEGER;
jbe@0 2764 "ary_text_v" TEXT;
jbe@0 2765 BEGIN
jbe@0 2766 IF "dim_p" >= 1 THEN
jbe@0 2767 "ary_text_v" := '{NULL';
jbe@0 2768 "i" := "dim_p";
jbe@0 2769 LOOP
jbe@0 2770 "i" := "i" - 1;
jbe@0 2771 EXIT WHEN "i" = 0;
jbe@0 2772 "ary_text_v" := "ary_text_v" || ',NULL';
jbe@0 2773 END LOOP;
jbe@0 2774 "ary_text_v" := "ary_text_v" || '}';
jbe@30 2775 RETURN "ary_text_v";
jbe@0 2776 ELSE
jbe@0 2777 RAISE EXCEPTION 'Dimension needs to be at least 1.';
jbe@0 2778 END IF;
jbe@0 2779 END;
jbe@0 2780 $$;
jbe@0 2781
jbe@30 2782 COMMENT ON FUNCTION "array_init_string"(INTEGER) IS 'Needed for PostgreSQL < 8.4, due to missing "array_fill" function';
jbe@30 2783
jbe@30 2784
jbe@30 2785 CREATE FUNCTION "square_matrix_init_string"("dim_p" INTEGER)
jbe@30 2786 RETURNS TEXT
jbe@0 2787 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@0 2788 DECLARE
jbe@0 2789 "i" INTEGER;
jbe@0 2790 "row_text_v" TEXT;
jbe@0 2791 "ary_text_v" TEXT;
jbe@0 2792 BEGIN
jbe@0 2793 IF "dim_p" >= 1 THEN
jbe@0 2794 "row_text_v" := '{NULL';
jbe@0 2795 "i" := "dim_p";
jbe@0 2796 LOOP
jbe@0 2797 "i" := "i" - 1;
jbe@0 2798 EXIT WHEN "i" = 0;
jbe@0 2799 "row_text_v" := "row_text_v" || ',NULL';
jbe@0 2800 END LOOP;
jbe@0 2801 "row_text_v" := "row_text_v" || '}';
jbe@0 2802 "ary_text_v" := '{' || "row_text_v";
jbe@0 2803 "i" := "dim_p";
jbe@0 2804 LOOP
jbe@0 2805 "i" := "i" - 1;
jbe@0 2806 EXIT WHEN "i" = 0;
jbe@0 2807 "ary_text_v" := "ary_text_v" || ',' || "row_text_v";
jbe@0 2808 END LOOP;
jbe@0 2809 "ary_text_v" := "ary_text_v" || '}';
jbe@30 2810 RETURN "ary_text_v";
jbe@0 2811 ELSE
jbe@0 2812 RAISE EXCEPTION 'Dimension needs to be at least 1.';
jbe@0 2813 END IF;
jbe@0 2814 END;
jbe@0 2815 $$;
jbe@0 2816
jbe@30 2817 COMMENT ON FUNCTION "square_matrix_init_string"(INTEGER) IS 'Needed for PostgreSQL < 8.4, due to missing "array_fill" function';
jbe@0 2818
jbe@0 2819
jbe@0 2820 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
jbe@0 2821 RETURNS VOID
jbe@0 2822 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2823 DECLARE
jbe@0 2824 "dimension_v" INTEGER;
jbe@30 2825 "vote_matrix" INT4[][]; -- absolute votes
jbe@30 2826 "matrix" INT8[][]; -- defeat strength / best paths
jbe@0 2827 "i" INTEGER;
jbe@0 2828 "j" INTEGER;
jbe@0 2829 "k" INTEGER;
jbe@0 2830 "battle_row" "battle"%ROWTYPE;
jbe@0 2831 "rank_ary" INT4[];
jbe@0 2832 "rank_v" INT4;
jbe@0 2833 "done_v" INTEGER;
jbe@0 2834 "winners_ary" INTEGER[];
jbe@0 2835 "initiative_id_v" "initiative"."id"%TYPE;
jbe@0 2836 BEGIN
jbe@0 2837 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
jbe@10 2838 SELECT count(1) INTO "dimension_v" FROM "initiative"
jbe@10 2839 WHERE "issue_id" = "issue_id_p" AND "agreed";
jbe@0 2840 IF "dimension_v" = 1 THEN
jbe@10 2841 UPDATE "initiative" SET "rank" = 1
jbe@10 2842 WHERE "issue_id" = "issue_id_p" AND "agreed";
jbe@0 2843 ELSIF "dimension_v" > 1 THEN
jbe@30 2844 -- Create "vote_matrix" with absolute number of votes in pairwise
jbe@30 2845 -- comparison:
jbe@30 2846 "vote_matrix" := "square_matrix_init_string"("dimension_v"); -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
jbe@0 2847 "i" := 1;
jbe@0 2848 "j" := 2;
jbe@0 2849 FOR "battle_row" IN
jbe@0 2850 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
jbe@0 2851 ORDER BY "winning_initiative_id", "losing_initiative_id"
jbe@0 2852 LOOP
jbe@30 2853 "vote_matrix"["i"]["j"] := "battle_row"."count";
jbe@0 2854 IF "j" = "dimension_v" THEN
jbe@0 2855 "i" := "i" + 1;
jbe@0 2856 "j" := 1;
jbe@0 2857 ELSE
jbe@0 2858 "j" := "j" + 1;
jbe@0 2859 IF "j" = "i" THEN
jbe@0 2860 "j" := "j" + 1;
jbe@0 2861 END IF;
jbe@0 2862 END IF;
jbe@0 2863 END LOOP;
jbe@0 2864 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
jbe@0 2865 RAISE EXCEPTION 'Wrong battle count (should not happen)';
jbe@0 2866 END IF;
jbe@30 2867 -- Store defeat strengths in "matrix" using "defeat_strength"
jbe@30 2868 -- function:
jbe@30 2869 "matrix" := "square_matrix_init_string"("dimension_v"); -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
jbe@0 2870 "i" := 1;
jbe@0 2871 LOOP
jbe@30 2872 "j" := 1;
jbe@0 2873 LOOP
jbe@0 2874 IF "i" != "j" THEN
jbe@30 2875 "matrix"["i"]["j"] := "defeat_strength"(
jbe@30 2876 "vote_matrix"["i"]["j"],
jbe@30 2877 "vote_matrix"["j"]["i"]
jbe@30 2878 );
jbe@0 2879 END IF;
jbe@0 2880 EXIT WHEN "j" = "dimension_v";
jbe@0 2881 "j" := "j" + 1;
jbe@0 2882 END LOOP;
jbe@30 2883 EXIT WHEN "i" = "dimension_v";
jbe@0 2884 "i" := "i" + 1;
jbe@0 2885 END LOOP;
jbe@0 2886 -- Find best paths:
jbe@0 2887 "i" := 1;
jbe@0 2888 LOOP
jbe@0 2889 "j" := 1;
jbe@0 2890 LOOP
jbe@0 2891 IF "i" != "j" THEN
jbe@0 2892 "k" := 1;
jbe@0 2893 LOOP
jbe@0 2894 IF "i" != "k" AND "j" != "k" THEN
jbe@0 2895 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
jbe@0 2896 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
jbe@0 2897 "matrix"["j"]["k"] := "matrix"["j"]["i"];
jbe@0 2898 END IF;
jbe@0 2899 ELSE
jbe@0 2900 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
jbe@0 2901 "matrix"["j"]["k"] := "matrix"["i"]["k"];
jbe@0 2902 END IF;
jbe@0 2903 END IF;
jbe@0 2904 END IF;
jbe@0 2905 EXIT WHEN "k" = "dimension_v";
jbe@0 2906 "k" := "k" + 1;
jbe@0 2907 END LOOP;
jbe@0 2908 END IF;
jbe@0 2909 EXIT WHEN "j" = "dimension_v";
jbe@0 2910 "j" := "j" + 1;
jbe@0 2911 END LOOP;
jbe@0 2912 EXIT WHEN "i" = "dimension_v";
jbe@0 2913 "i" := "i" + 1;
jbe@0 2914 END LOOP;
jbe@0 2915 -- Determine order of winners:
jbe@30 2916 "rank_ary" := "array_init_string"("dimension_v"); -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
jbe@0 2917 "rank_v" := 1;
jbe@0 2918 "done_v" := 0;
jbe@0 2919 LOOP
jbe@0 2920 "winners_ary" := '{}';
jbe@0 2921 "i" := 1;
jbe@0 2922 LOOP
jbe@0 2923 IF "rank_ary"["i"] ISNULL THEN
jbe@0 2924 "j" := 1;
jbe@0 2925 LOOP
jbe@0 2926 IF
jbe@0 2927 "i" != "j" AND
jbe@0 2928 "rank_ary"["j"] ISNULL AND
jbe@0 2929 "matrix"["j"]["i"] > "matrix"["i"]["j"]
jbe@0 2930 THEN
jbe@0 2931 -- someone else is better
jbe@0 2932 EXIT;
jbe@0 2933 END IF;
jbe@0 2934 IF "j" = "dimension_v" THEN
jbe@0 2935 -- noone is better
jbe@0 2936 "winners_ary" := "winners_ary" || "i";
jbe@0 2937 EXIT;
jbe@0 2938 END IF;
jbe@0 2939 "j" := "j" + 1;
jbe@0 2940 END LOOP;
jbe@0 2941 END IF;
jbe@0 2942 EXIT WHEN "i" = "dimension_v";
jbe@0 2943 "i" := "i" + 1;
jbe@0 2944 END LOOP;
jbe@0 2945 "i" := 1;
jbe@0 2946 LOOP
jbe@0 2947 "rank_ary"["winners_ary"["i"]] := "rank_v";
jbe@0 2948 "done_v" := "done_v" + 1;
jbe@0 2949 EXIT WHEN "i" = array_upper("winners_ary", 1);
jbe@0 2950 "i" := "i" + 1;
jbe@0 2951 END LOOP;
jbe@0 2952 EXIT WHEN "done_v" = "dimension_v";
jbe@0 2953 "rank_v" := "rank_v" + 1;
jbe@0 2954 END LOOP;
jbe@0 2955 -- write preliminary ranks:
jbe@0 2956 "i" := 1;
jbe@0 2957 FOR "initiative_id_v" IN
jbe@10 2958 SELECT "id" FROM "initiative"
jbe@10 2959 WHERE "issue_id" = "issue_id_p" AND "agreed"
jbe@10 2960 ORDER BY "id"
jbe@0 2961 LOOP
jbe@0 2962 UPDATE "initiative" SET "rank" = "rank_ary"["i"]
jbe@0 2963 WHERE "id" = "initiative_id_v";
jbe@0 2964 "i" := "i" + 1;
jbe@0 2965 END LOOP;
jbe@0 2966 IF "i" != "dimension_v" + 1 THEN
jbe@0 2967 RAISE EXCEPTION 'Wrong winner count (should not happen)';
jbe@0 2968 END IF;
jbe@0 2969 -- straighten ranks (start counting with 1, no equal ranks):
jbe@0 2970 "rank_v" := 1;
jbe@0 2971 FOR "initiative_id_v" IN
jbe@0 2972 SELECT "id" FROM "initiative"
jbe@0 2973 WHERE "issue_id" = "issue_id_p" AND "rank" NOTNULL
jbe@0 2974 ORDER BY
jbe@0 2975 "rank",
jbe@0 2976 "vote_ratio"("positive_votes", "negative_votes") DESC,
jbe@0 2977 "id"
jbe@0 2978 LOOP
jbe@0 2979 UPDATE "initiative" SET "rank" = "rank_v"
jbe@0 2980 WHERE "id" = "initiative_id_v";
jbe@0 2981 "rank_v" := "rank_v" + 1;
jbe@0 2982 END LOOP;
jbe@0 2983 END IF;
jbe@0 2984 -- mark issue as finished
jbe@0 2985 UPDATE "issue" SET "ranks_available" = TRUE
jbe@0 2986 WHERE "id" = "issue_id_p";
jbe@0 2987 RETURN;
jbe@0 2988 END;
jbe@0 2989 $$;
jbe@0 2990
jbe@0 2991 COMMENT ON FUNCTION "calculate_ranks"
jbe@0 2992 ( "issue"."id"%TYPE )
jbe@0 2993 IS 'Determine ranking (Votes have to be counted first)';
jbe@0 2994
jbe@0 2995
jbe@0 2996
jbe@0 2997 -----------------------------
jbe@0 2998 -- Automatic state changes --
jbe@0 2999 -----------------------------
jbe@0 3000
jbe@0 3001
jbe@0 3002 CREATE FUNCTION "check_issue"
jbe@0 3003 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3004 RETURNS VOID
jbe@0 3005 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3006 DECLARE
jbe@0 3007 "issue_row" "issue"%ROWTYPE;
jbe@0 3008 "policy_row" "policy"%ROWTYPE;
jbe@0 3009 "voting_requested_v" BOOLEAN;
jbe@0 3010 BEGIN
jbe@0 3011 PERFORM "global_lock"();
jbe@0 3012 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@24 3013 -- only process open issues:
jbe@0 3014 IF "issue_row"."closed" ISNULL THEN
jbe@0 3015 SELECT * INTO "policy_row" FROM "policy"
jbe@0 3016 WHERE "id" = "issue_row"."policy_id";
jbe@24 3017 -- create a snapshot, unless issue is already fully frozen:
jbe@3 3018 IF "issue_row"."fully_frozen" ISNULL THEN
jbe@0 3019 PERFORM "create_snapshot"("issue_id_p");
jbe@0 3020 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@0 3021 END IF;
jbe@24 3022 -- eventually close or accept issues, which have not been accepted:
jbe@0 3023 IF "issue_row"."accepted" ISNULL THEN
jbe@0 3024 IF EXISTS (
jbe@0 3025 SELECT NULL FROM "initiative"
jbe@0 3026 WHERE "issue_id" = "issue_id_p"
jbe@0 3027 AND "supporter_count" > 0
jbe@0 3028 AND "supporter_count" * "policy_row"."issue_quorum_den"
jbe@0 3029 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
jbe@0 3030 ) THEN
jbe@24 3031 -- accept issues, if supporter count is high enough
jbe@3 3032 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
jbe@0 3033 "issue_row"."accepted" = now(); -- NOTE: "issue_row" used later
jbe@0 3034 UPDATE "issue" SET "accepted" = "issue_row"."accepted"
jbe@0 3035 WHERE "id" = "issue_row"."id";
jbe@0 3036 ELSIF
jbe@22 3037 now() >= "issue_row"."created" + "issue_row"."admission_time"
jbe@0 3038 THEN
jbe@24 3039 -- close issues, if admission time has expired
jbe@0 3040 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
jbe@0 3041 UPDATE "issue" SET "closed" = now()
jbe@0 3042 WHERE "id" = "issue_row"."id";
jbe@0 3043 END IF;
jbe@0 3044 END IF;
jbe@24 3045 -- eventually half freeze issues:
jbe@0 3046 IF
jbe@24 3047 -- NOTE: issue can't be closed at this point, if it has been accepted
jbe@0 3048 "issue_row"."accepted" NOTNULL AND
jbe@3 3049 "issue_row"."half_frozen" ISNULL
jbe@0 3050 THEN
jbe@0 3051 SELECT
jbe@0 3052 CASE
jbe@0 3053 WHEN "vote_now" * 2 > "issue_row"."population" THEN
jbe@0 3054 TRUE
jbe@0 3055 WHEN "vote_later" * 2 > "issue_row"."population" THEN
jbe@0 3056 FALSE
jbe@0 3057 ELSE NULL
jbe@0 3058 END
jbe@0 3059 INTO "voting_requested_v"
jbe@0 3060 FROM "issue" WHERE "id" = "issue_id_p";
jbe@0 3061 IF
jbe@0 3062 "voting_requested_v" OR (
jbe@3 3063 "voting_requested_v" ISNULL AND
jbe@22 3064 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
jbe@0 3065 )
jbe@0 3066 THEN
jbe@21 3067 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
jbe@3 3068 "issue_row"."half_frozen" = now(); -- NOTE: "issue_row" used later
jbe@3 3069 UPDATE "issue" SET "half_frozen" = "issue_row"."half_frozen"
jbe@3 3070 WHERE "id" = "issue_row"."id";
jbe@0 3071 END IF;
jbe@0 3072 END IF;
jbe@24 3073 -- close issues after some time, if all initiatives have been revoked:
jbe@24 3074 IF
jbe@24 3075 "issue_row"."closed" ISNULL AND
jbe@24 3076 NOT EXISTS (
jbe@24 3077 -- all initiatives are revoked
jbe@24 3078 SELECT NULL FROM "initiative"
jbe@24 3079 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@24 3080 ) AND (
jbe@24 3081 NOT EXISTS (
jbe@24 3082 -- and no initiatives have been revoked lately
jbe@24 3083 SELECT NULL FROM "initiative"
jbe@24 3084 WHERE "issue_id" = "issue_id_p"
jbe@24 3085 AND now() < "revoked" + "issue_row"."verification_time"
jbe@24 3086 ) OR (
jbe@24 3087 -- or verification time has elapsed
jbe@24 3088 "issue_row"."half_frozen" NOTNULL AND
jbe@24 3089 "issue_row"."fully_frozen" ISNULL AND
jbe@24 3090 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
jbe@24 3091 )
jbe@24 3092 )
jbe@24 3093 THEN
jbe@24 3094 "issue_row"."closed" = now(); -- NOTE: "issue_row" used later
jbe@24 3095 UPDATE "issue" SET "closed" = "issue_row"."closed"
jbe@24 3096 WHERE "id" = "issue_row"."id";
jbe@24 3097 END IF;
jbe@24 3098 -- fully freeze issue after verification time:
jbe@0 3099 IF
jbe@3 3100 "issue_row"."half_frozen" NOTNULL AND
jbe@3 3101 "issue_row"."fully_frozen" ISNULL AND
jbe@24 3102 "issue_row"."closed" ISNULL AND
jbe@22 3103 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
jbe@3 3104 THEN
jbe@3 3105 PERFORM "freeze_after_snapshot"("issue_id_p");
jbe@24 3106 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
jbe@3 3107 END IF;
jbe@9 3108 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@24 3109 -- close issue by calling close_voting(...) after voting time:
jbe@3 3110 IF
jbe@9 3111 "issue_row"."closed" ISNULL AND
jbe@3 3112 "issue_row"."fully_frozen" NOTNULL AND
jbe@22 3113 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
jbe@0 3114 THEN
jbe@0 3115 PERFORM "close_voting"("issue_id_p");
jbe@0 3116 END IF;
jbe@0 3117 END IF;
jbe@0 3118 RETURN;
jbe@0 3119 END;
jbe@0 3120 $$;
jbe@0 3121
jbe@0 3122 COMMENT ON FUNCTION "check_issue"
jbe@0 3123 ( "issue"."id"%TYPE )
jbe@0 3124 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 3125
jbe@0 3126
jbe@0 3127 CREATE FUNCTION "check_everything"()
jbe@0 3128 RETURNS VOID
jbe@0 3129 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3130 DECLARE
jbe@0 3131 "issue_id_v" "issue"."id"%TYPE;
jbe@0 3132 BEGIN
jbe@1 3133 DELETE FROM "expired_session";
jbe@4 3134 PERFORM "calculate_member_counts"();
jbe@4 3135 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
jbe@0 3136 PERFORM "check_issue"("issue_id_v");
jbe@0 3137 END LOOP;
jbe@4 3138 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
jbe@0 3139 PERFORM "calculate_ranks"("issue_id_v");
jbe@0 3140 END LOOP;
jbe@0 3141 RETURN;
jbe@0 3142 END;
jbe@0 3143 $$;
jbe@0 3144
jbe@0 3145 COMMENT ON FUNCTION "check_everything"() IS 'Perform "check_issue" for every open issue, and if possible, automatically calculate ranks. Use this function only for development and debugging purposes, as long transactions with exclusive locking may result.';
jbe@0 3146
jbe@0 3147
jbe@0 3148
jbe@8 3149 ------------------------------
jbe@8 3150 -- Deletion of private data --
jbe@8 3151 ------------------------------
jbe@8 3152
jbe@8 3153
jbe@8 3154 CREATE FUNCTION "delete_private_data"()
jbe@8 3155 RETURNS VOID
jbe@8 3156 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@8 3157 DECLARE
jbe@8 3158 "issue_id_v" "issue"."id"%TYPE;
jbe@8 3159 BEGIN
jbe@9 3160 UPDATE "member" SET
jbe@11 3161 "login" = 'login' || "id"::text,
jbe@11 3162 "password" = NULL,
jbe@11 3163 "notify_email" = NULL,
jbe@11 3164 "notify_email_unconfirmed" = NULL,
jbe@11 3165 "notify_email_secret" = NULL,
jbe@11 3166 "notify_email_secret_expiry" = NULL,
jbe@11 3167 "password_reset_secret" = NULL,
jbe@11 3168 "password_reset_secret_expiry" = NULL,
jbe@11 3169 "organizational_unit" = NULL,
jbe@11 3170 "internal_posts" = NULL,
jbe@11 3171 "realname" = NULL,
jbe@11 3172 "birthday" = NULL,
jbe@11 3173 "address" = NULL,
jbe@11 3174 "email" = NULL,
jbe@11 3175 "xmpp_address" = NULL,
jbe@11 3176 "website" = NULL,
jbe@11 3177 "phone" = NULL,
jbe@11 3178 "mobile_phone" = NULL,
jbe@11 3179 "profession" = NULL,
jbe@11 3180 "external_memberships" = NULL,
jbe@11 3181 "external_posts" = NULL,
jbe@11 3182 "statement" = NULL;
jbe@11 3183 -- "text_search_data" is updated by triggers
jbe@8 3184 DELETE FROM "session";
jbe@12 3185 DELETE FROM "invite_code";
jbe@13 3186 DELETE FROM "contact";
jbe@11 3187 DELETE FROM "setting";
jbe@11 3188 DELETE FROM "member_image";
jbe@8 3189 DELETE FROM "direct_voter" USING "issue"
jbe@8 3190 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@8 3191 AND "issue"."closed" ISNULL;
jbe@8 3192 RETURN;
jbe@8 3193 END;
jbe@8 3194 $$;
jbe@8 3195
jbe@8 3196 COMMENT ON FUNCTION "delete_private_data"() IS '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 3197
jbe@8 3198
jbe@8 3199
jbe@0 3200 COMMIT;

Impressum / About Us