liquid_feedback_core

view core.sql @ 580:78f6833f5f19

Further work on role accounts (role_verification, real_member_id)
author jbe
date Sun Mar 04 17:59:11 2018 +0100 (2018-03-04)
parents f6b84db4dd0c
children 1cb6710fc429
line source
2 -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index
4 BEGIN;
6 CREATE EXTENSION IF NOT EXISTS latlon; -- load pgLatLon extenstion
8 CREATE VIEW "liquid_feedback_version" AS
9 SELECT * FROM (VALUES ('4.1-dev', 4, 1, -1))
10 AS "subquery"("string", "major", "minor", "revision");
14 ----------------------
15 -- Full text search --
16 ----------------------
19 CREATE FUNCTION "text_search_query"("query_text_p" TEXT)
20 RETURNS TSQUERY
21 LANGUAGE 'plpgsql' IMMUTABLE AS $$
22 BEGIN
23 RETURN plainto_tsquery('pg_catalog.simple', "query_text_p");
24 END;
25 $$;
27 COMMENT ON FUNCTION "text_search_query"(TEXT) IS 'Usage: WHERE "text_search_data" @@ "text_search_query"(''<user query>'')';
30 CREATE FUNCTION "highlight"
31 ( "body_p" TEXT,
32 "query_text_p" TEXT )
33 RETURNS TEXT
34 LANGUAGE 'plpgsql' IMMUTABLE AS $$
35 BEGIN
36 RETURN ts_headline(
37 'pg_catalog.simple',
38 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
39 "text_search_query"("query_text_p"),
40 'StartSel=* StopSel=* HighlightAll=TRUE' );
41 END;
42 $$;
44 COMMENT ON FUNCTION "highlight"
45 ( "body_p" TEXT,
46 "query_text_p" TEXT )
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.';
51 -------------------------
52 -- Tables and indicies --
53 -------------------------
56 CREATE TABLE "temporary_transaction_data" (
57 PRIMARY KEY ("txid", "key"),
58 "txid" INT8 DEFAULT txid_current(),
59 "key" TEXT,
60 "value" TEXT NOT NULL );
62 COMMENT ON TABLE "temporary_transaction_data" IS 'Table to store temporary transaction data; shall be emptied before a transaction is committed';
64 COMMENT ON COLUMN "temporary_transaction_data"."txid" IS 'Value returned by function txid_current(); should be added to WHERE clause, when doing SELECT on this table, but ignored when doing DELETE on this table';
67 CREATE TABLE "system_setting" (
68 "member_ttl" INTERVAL,
69 "snapshot_retention" INTERVAL );
70 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1));
72 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.';
73 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.';
75 COMMENT ON COLUMN "system_setting"."member_ttl" IS 'Time after members get their "active" flag set to FALSE, if they do not show any activity.';
76 COMMENT ON COLUMN "system_setting"."snapshot_retention" IS 'Unreferenced snapshots are retained for the given period of time after creation; set to NULL for infinite retention.';
79 CREATE TABLE "contingent" (
80 PRIMARY KEY ("polling", "time_frame"),
81 "polling" BOOLEAN,
82 "time_frame" INTERVAL,
83 "text_entry_limit" INT4,
84 "initiative_limit" INT4 );
86 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.';
88 COMMENT ON COLUMN "contingent"."polling" IS 'Determines if settings are for creating initiatives and new drafts of initiatives with "polling" flag set';
89 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';
90 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame';
93 CREATE TABLE "member" (
94 "id" SERIAL4 PRIMARY KEY,
95 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
96 "deleted" TIMESTAMPTZ,
97 "invite_code" TEXT UNIQUE,
98 "invite_code_expiry" TIMESTAMPTZ,
99 "admin_comment" TEXT,
100 "activated" TIMESTAMPTZ,
101 "last_activity" DATE,
102 "last_login" TIMESTAMPTZ,
103 "last_delegation_check" TIMESTAMPTZ,
104 "login" TEXT UNIQUE,
105 "password" TEXT,
106 "authority" TEXT,
107 "authority_uid" TEXT,
108 "authority_login" TEXT,
109 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
110 "active" BOOLEAN NOT NULL DEFAULT FALSE,
111 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
112 "lang" TEXT,
113 "notify_email" TEXT,
114 "notify_email_unconfirmed" TEXT,
115 "notify_email_secret" TEXT UNIQUE,
116 "notify_email_secret_expiry" TIMESTAMPTZ,
117 "notify_email_lock_expiry" TIMESTAMPTZ,
118 "disable_notifications" BOOLEAN NOT NULL DEFAULT FALSE,
119 "notification_counter" INT4 NOT NULL DEFAULT 1,
120 "notification_sample_size" INT4 NOT NULL DEFAULT 3,
121 "notification_dow" INT4 CHECK ("notification_dow" BETWEEN 0 AND 6),
122 "notification_hour" INT4 DEFAULT floor(random() * 24) CHECK ("notification_hour" BETWEEN 0 AND 23),
123 "notification_sent" TIMESTAMP,
124 "login_recovery_expiry" TIMESTAMPTZ,
125 "password_reset_secret" TEXT UNIQUE,
126 "password_reset_secret_expiry" TIMESTAMPTZ,
127 "name" TEXT UNIQUE,
128 "identification" TEXT UNIQUE,
129 "authentication" TEXT,
130 "role" BOOLEAN NOT NULL DEFAULT FALSE,
131 "location" JSONB,
132 "text_search_data" TSVECTOR,
133 CONSTRAINT "deleted_requires_locked"
134 CHECK ("deleted" ISNULL OR "locked" = TRUE),
135 CONSTRAINT "active_requires_activated_and_last_activity"
136 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)),
137 CONSTRAINT "authority_requires_uid_and_vice_versa"
138 CHECK (("authority" NOTNULL) = ("authority_uid" NOTNULL)),
139 CONSTRAINT "authority_uid_unique_per_authority"
140 UNIQUE ("authority", "authority_uid"),
141 CONSTRAINT "authority_login_requires_authority"
142 CHECK ("authority" NOTNULL OR "authority_login" ISNULL),
143 CONSTRAINT "notification_dow_requires_notification_hour"
144 CHECK ("notification_dow" ISNULL OR "notification_hour" NOTNULL),
145 CONSTRAINT "name_not_null_if_activated"
146 CHECK ("activated" ISNULL OR "name" NOTNULL) );
147 CREATE INDEX "member_authority_login_idx" ON "member" ("authority_login");
148 CREATE INDEX "member_active_idx" ON "member" ("active");
149 CREATE INDEX "member_location_idx" ON "member" USING gist ((GeoJSON_to_ecluster("location")));
150 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
151 CREATE TRIGGER "update_text_search_data"
152 BEFORE INSERT OR UPDATE ON "member"
153 FOR EACH ROW EXECUTE PROCEDURE
154 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
155 "name", "identification");
157 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
159 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
160 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
161 COMMENT ON COLUMN "member"."invite_code_expiry" IS 'Expiry data/time for "invite_code"';
162 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
163 COMMENT ON COLUMN "member"."activated" IS 'Timestamp of first activation of account (i.e. usage of "invite_code"); required to be set for "active" members';
164 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
165 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
166 COMMENT ON COLUMN "member"."last_delegation_check" IS 'Timestamp of last delegation check (i.e. confirmation of all unit and area delegations)';
167 COMMENT ON COLUMN "member"."login" IS 'Login name';
168 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
169 COMMENT ON COLUMN "member"."authority" IS 'NULL if LiquidFeedback Core is authoritative for the member account; otherwise a string that indicates the source/authority of the external account (e.g. ''LDAP'' for an LDAP account)';
170 COMMENT ON COLUMN "member"."authority_uid" IS 'Unique identifier (unique per "authority") that allows to identify an external account (e.g. even if the login name changes)';
171 COMMENT ON COLUMN "member"."authority_login" IS 'Login name for external accounts (field is not unique!)';
172 COMMENT ON COLUMN "member"."deleted" IS 'Timestamp of deletion (set by "delete_member" function)';
173 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
174 COMMENT ON COLUMN "member"."active" IS 'Memberships, support and votes are taken into account when corresponding members are marked as active. Automatically set to FALSE, if "last_activity" is older than "system_setting"."member_ttl".';
175 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
176 COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member';
177 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
178 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
179 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
180 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
181 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
182 COMMENT ON COLUMN "member"."disable_notifications" IS 'TRUE if member does not want to receive notifications';
183 COMMENT ON COLUMN "member"."notification_counter" IS 'Sequential number of next scheduled notification message (used as a seed for pseudo-random initiative selection algorithm)';
184 COMMENT ON COLUMN "member"."notification_sample_size" IS 'Number of featured initiatives per issue in scheduled notification messages';
185 COMMENT ON COLUMN "member"."notification_dow" IS 'Day of week for scheduled notifications (NULL to receive a daily digest)';
186 COMMENT ON COLUMN "member"."notification_hour" IS 'Time of day when scheduled notifications are sent out';
187 COMMENT ON COLUMN "member"."notification_sent" IS 'Timestamp of last scheduled notification mail that has been sent out';
188 COMMENT ON COLUMN "member"."login_recovery_expiry" IS 'Date/time after which another login recovery attempt is allowed';
189 COMMENT ON COLUMN "member"."password_reset_secret" IS 'Secret string sent via e-mail for password recovery';
190 COMMENT ON COLUMN "member"."password_reset_secret_expiry" IS 'Date/time until the password recovery secret is valid, and date/time after which another password recovery attempt is allowed';
191 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member, may be NULL if account has not been activated yet';
192 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
193 COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated';
194 COMMENT ON COLUMN "member"."location" IS 'Geographic location on earth as GeoJSON object';
197 CREATE TABLE "member_history" ( -- TODO: redundancy with new "event" table
198 "id" SERIAL8 PRIMARY KEY,
199 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
200 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
201 "active" BOOLEAN NOT NULL,
202 "name" TEXT NOT NULL );
203 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
205 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
207 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
208 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
211 CREATE TABLE "agent" (
212 PRIMARY KEY ("controlled_id", "controller_id"),
213 "controlled_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
214 "controller_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
215 CONSTRAINT "controlled_id_and_controller_id_differ" CHECK (
216 "controlled_id" != "controller_id" ) );
217 CREATE INDEX "agent_controller_id_idx" ON "agent" ("controller_id");
219 COMMENT ON TABLE "agent" IS 'Privileges for role accounts';
222 CREATE TABLE "verification" (
223 "id" SERIAL8 PRIMARY KEY,
224 "requested" TIMESTAMPTZ,
225 "request_origin" JSONB,
226 "request_data" JSONB,
227 "requesting_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
228 "verifying_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
229 "verified_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
230 "verified" TIMESTAMPTZ,
231 "verification_data" JSONB,
232 "denied" TIMESTAMPTZ,
233 "comment" TEXT,
234 CONSTRAINT "verified_and_denied_conflict" CHECK (
235 "verified" ISNULL OR "denied" ISNULL ) );
236 CREATE INDEX "verification_requested_idx" ON "verification" ("requested");
237 CREATE INDEX "verification_open_request_idx" ON "verification" ("requested") WHERE "verified" ISNULL AND "denied" ISNULL;
238 CREATE INDEX "verification_requesting_member_id_idx" ON "verification" ("requesting_member_id");
239 CREATE INDEX "verification_verified_member_id_idx" ON "verification" ("verified_member_id");
240 CREATE INDEX "verification_verified_idx" ON "verification" ("verified");
241 CREATE INDEX "verification_denied_idx" ON "verification" ("denied");
243 COMMENT ON TABLE "verification" IS 'Request to verify a participant';
245 COMMENT ON COLUMN "verification"."requested" IS 'Timestamp when request for verification has been submitted';
246 COMMENT ON COLUMN "verification"."request_origin" IS 'JSON data containing information about the origin of the request (e.g. IP address or hostname)';
247 COMMENT ON COLUMN "verification"."request_data" IS 'JSON data containing information about the entity to be verified (e.g. real name, address, etc.)';
248 COMMENT ON COLUMN "verification"."requesting_member_id" IS 'Member who requested verification';
249 COMMENT ON COLUMN "verification"."verifying_member_id" IS 'Member who processed the verification request (i.e. who accepted or denied the request)';
250 COMMENT ON COLUMN "verification"."verified_member_id" IS 'Member entry containing verified information (not necessarily equal to "requesting_member_id" but may be merged with requesting member later)';
251 COMMENT ON COLUMN "verification"."verified" IS 'Timestamp when request for verification has been accepted by authority';
252 COMMENT ON COLUMN "verification"."verification_data" IS 'JSON data containing additional verified data or information about the authority or operator who accepted or denied the request, but all public information shall be copied to "member"."identification", "member"."verification" and/or "member"."name" if applicable for setup';
253 COMMENT ON COLUMN "verification"."denied" IS 'Timestamp when request for verification has been denied by authority';
254 COMMENT ON COLUMN "verification"."comment" IS 'Administrative comment';
257 -- TODO: merge tables "verification" and "role_verification"
259 CREATE TABLE "role_verification" (
260 "id" SERIAL8 PRIMARY KEY,
261 "requested" TIMESTAMPTZ,
262 "request_origin" JSONB,
263 "request_data" JSONB,
264 "requesting_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
265 "requesting_real_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
266 "verifying_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
267 "verified_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
268 "verified" TIMESTAMPTZ,
269 "verification_data" JSONB,
270 "denied" TIMESTAMPTZ,
271 "comment" TEXT,
272 CONSTRAINT "verified_and_denied_conflict" CHECK (
273 "verified" ISNULL OR "denied" ISNULL ) );
274 CREATE INDEX "role_verification_requested_idx" ON "role_verification" ("requested");
275 CREATE INDEX "role_verification_open_request_idx" ON "role_verification" ("requested") WHERE "verified" ISNULL AND "denied" ISNULL;
276 CREATE INDEX "role_verification_requesting_member_id_idx" ON "role_verification" ("requesting_member_id");
277 CREATE INDEX "role_verification_verified_member_id_idx" ON "role_verification" ("verified_member_id");
278 CREATE INDEX "role_verification_verified_idx" ON "role_verification" ("verified");
279 CREATE INDEX "role_verification_denied_idx" ON "role_verification" ("denied");
281 COMMENT ON TABLE "role_verification" IS 'Request to verify a role account (see table "verification" for documentation of columns not documented for this table)';
283 COMMENT ON COLUMN "role_verification"."requesting_member_id" IS 'Member role account to verify';
284 COMMENT ON COLUMN "role_verification"."requesting_real_member_id" IS 'Member account of real person who requested verification';
287 CREATE TABLE "member_settings" (
288 "member_id" INT4 PRIMARY KEY REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
289 "settings" JSONB NOT NULL CHECK (jsonb_typeof("settings") = 'object') );
291 COMMENT ON TABLE "member_settings" IS 'Stores a JSON document for each member containing optional (additional) settings for the respective member';
294 CREATE TABLE "member_useterms" (
295 "id" SERIAL8 PRIMARY KEY,
296 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
297 "accepted" TIMESTAMPTZ NOT NULL DEFAULT now(),
298 "contract_identifier" TEXT NOT NULL );
300 COMMENT ON TABLE "member_useterms" IS 'Keeps record of accepted terms of use; may contain multiple rows per member';
302 COMMENT ON COLUMN "member_useterms"."accepted" IS 'Point in time when user accepted the terms of use';
303 COMMENT ON COLUMN "member_useterms"."contract_identifier" IS 'String identifier to denote the accepted terms of use, including their version or revision';
306 CREATE TABLE "member_profile" (
307 "member_id" INT4 PRIMARY KEY REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
308 "formatting_engine" TEXT,
309 "statement" TEXT,
310 "profile" JSONB NOT NULL DEFAULT '{}' CHECK (jsonb_typeof("profile") = 'object'),
311 "profile_text_data" TEXT,
312 "text_search_data" TSVECTOR );
313 CREATE INDEX "member_profile_text_search_data_idx" ON "member_profile" USING gin ("text_search_data");
314 CREATE TRIGGER "update_text_search_data"
315 BEFORE INSERT OR UPDATE ON "member_profile"
316 FOR EACH ROW EXECUTE PROCEDURE
317 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
318 'statement', 'profile_text_data');
320 COMMENT ON COLUMN "member_profile"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member_profile"."statement"';
321 COMMENT ON COLUMN "member_profile"."statement" IS 'Freely chosen text of the member for his/her profile';
322 COMMENT ON COLUMN "member_profile"."profile" IS 'Additional profile data as JSON document';
323 COMMENT ON COLUMN "member_profile"."profile_text_data" IS 'Text data from "profile" field for full text search';
326 CREATE TABLE "rendered_member_statement" (
327 PRIMARY KEY ("member_id", "format"),
328 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
329 "format" TEXT,
330 "content" TEXT NOT NULL );
332 COMMENT ON TABLE "rendered_member_statement" IS 'This table may be used by frontends to cache "rendered" member statements (e.g. HTML output generated from wiki text)';
335 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
337 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
340 CREATE TABLE "member_image" (
341 PRIMARY KEY ("member_id", "image_type", "scaled"),
342 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
343 "image_type" "member_image_type",
344 "scaled" BOOLEAN,
345 "content_type" TEXT,
346 "data" BYTEA NOT NULL );
348 COMMENT ON TABLE "member_image" IS 'Images of members';
350 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
353 CREATE TABLE "member_count" (
354 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
355 "total_count" INT4 NOT NULL );
357 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';
359 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
360 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
363 CREATE TABLE "contact" (
364 PRIMARY KEY ("member_id", "other_member_id"),
365 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
366 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
367 "public" BOOLEAN NOT NULL DEFAULT FALSE,
368 CONSTRAINT "cant_save_yourself_as_contact"
369 CHECK ("member_id" != "other_member_id") );
370 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
372 COMMENT ON TABLE "contact" IS 'Contact lists';
374 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
375 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
376 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
379 CREATE TABLE "ignored_member" (
380 PRIMARY KEY ("member_id", "other_member_id"),
381 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
382 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
383 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
385 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
387 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
388 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
391 CREATE TABLE "session" (
392 UNIQUE ("member_id", "id"), -- index needed for foreign-key on table "token"
393 "id" SERIAL8 PRIMARY KEY,
394 "ident" TEXT NOT NULL UNIQUE,
395 "additional_secret" TEXT,
396 "logout_token" TEXT,
397 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
398 "member_id" INT4 REFERENCES "member" ("id") ON DELETE SET NULL,
399 "real_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
400 "authority" TEXT,
401 "authority_uid" TEXT,
402 "authority_login" TEXT,
403 "needs_delegation_check" BOOLEAN NOT NULL DEFAULT FALSE,
404 "lang" TEXT );
405 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
407 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
409 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
410 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
411 COMMENT ON COLUMN "session"."logout_token" IS 'Optional token to authorize logout through external component';
412 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in, or role account in use';
413 COMMENT ON COLUMN "session"."real_member_id" IS 'Reference to member, who is really logged in (real person rather than role account)';
414 COMMENT ON COLUMN "session"."authority" IS 'Temporary store for "member"."authority" during member account creation';
415 COMMENT ON COLUMN "session"."authority_uid" IS 'Temporary store for "member"."authority_uid" during member account creation';
416 COMMENT ON COLUMN "session"."authority_login" IS 'Temporary store for "member"."authority_login" during member account creation';
417 COMMENT ON COLUMN "session"."needs_delegation_check" IS 'Set to TRUE, if member must perform a delegation check to proceed with login; see column "last_delegation_check" in "member" table';
418 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
421 CREATE TYPE "authflow" AS ENUM ('code', 'token');
423 COMMENT ON TYPE "authflow" IS 'OAuth 2.0 flows: ''code'' = Authorization Code flow, ''token'' = Implicit flow';
426 CREATE TABLE "system_application" (
427 "id" SERIAL4 PRIMARY KEY,
428 "name" TEXT NOT NULL,
429 "base_url" TEXT,
430 "manifest_url" TEXT,
431 "client_id" TEXT NOT NULL UNIQUE,
432 "default_redirect_uri" TEXT NOT NULL,
433 "cert_common_name" TEXT,
434 "client_cred_scope" TEXT,
435 "flow" "authflow",
436 "automatic_scope" TEXT,
437 "permitted_scope" TEXT,
438 "forbidden_scope" TEXT );
440 COMMENT ON TABLE "system_application" IS 'OAuth 2.0 clients that are registered by the system administrator';
442 COMMENT ON COLUMN "system_application"."name" IS 'Human readable name of application';
443 COMMENT ON COLUMN "system_application"."base_url" IS 'Base URL for users';
444 COMMENT ON COLUMN "system_application"."manifest_url" IS 'URL referring to a manifest that can be used for application (type/version) discovery';
445 COMMENT ON COLUMN "system_application"."client_id" IS 'OAuth 2.0 "client_id"';
446 COMMENT ON COLUMN "system_application"."cert_common_name" IS 'Value for CN field of TLS client certificate';
447 COMMENT ON COLUMN "system_application"."client_cred_scope" IS 'Space-separated list of scopes; If set, Client Credentials Grant is allowed; value determines scope';
448 COMMENT ON COLUMN "system_application"."flow" IS 'If set to ''code'' or ''token'', then Authorization Code or Implicit flow is allowed respectively';
449 COMMENT ON COLUMN "system_application"."automatic_scope" IS 'Space-separated list of scopes; Automatically granted scope for Authorization Code or Implicit flow';
450 COMMENT ON COLUMN "system_application"."permitted_scope" IS 'Space-separated list of scopes; If set, scope that members may grant to the application is limited to the given value';
451 COMMENT ON COLUMN "system_application"."forbidden_scope" IS 'Space-separated list of scopes that may not be granted to the application by a member';
454 CREATE TABLE "system_application_redirect_uri" (
455 PRIMARY KEY ("system_application_id", "redirect_uri"),
456 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
457 "redirect_uri" TEXT );
459 COMMENT ON TABLE "system_application_redirect_uri" IS 'Additional OAuth 2.0 redirection endpoints, which may be selected through the "redirect_uri" GET parameter';
462 CREATE TABLE "dynamic_application_scope" (
463 PRIMARY KEY ("redirect_uri", "flow", "scope"),
464 "redirect_uri" TEXT,
465 "flow" TEXT,
466 "scope" TEXT,
467 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours' );
468 CREATE INDEX "dynamic_application_scope_redirect_uri_scope_idx" ON "dynamic_application_scope" ("redirect_uri", "flow", "scope");
469 CREATE INDEX "dynamic_application_scope_expiry_idx" ON "dynamic_application_scope" ("expiry");
471 COMMENT ON TABLE "dynamic_application_scope" IS 'Dynamic OAuth 2.0 client registration data';
473 COMMENT ON COLUMN "dynamic_application_scope"."redirect_uri" IS 'Redirection endpoint for which the registration has been done';
474 COMMENT ON COLUMN "dynamic_application_scope"."flow" IS 'OAuth 2.0 flow for which the registration has been done (see also "system_application"."flow")';
475 COMMENT ON COLUMN "dynamic_application_scope"."scope" IS 'Single scope without space characters (use multiple rows for more scopes)';
476 COMMENT ON COLUMN "dynamic_application_scope"."expiry" IS 'Expiry unless renewed';
479 CREATE TABLE "member_application" (
480 "id" SERIAL4 PRIMARY KEY,
481 UNIQUE ("system_application_id", "member_id"),
482 UNIQUE ("domain", "member_id"),
483 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
484 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
485 "domain" TEXT,
486 "session_id" INT8,
487 FOREIGN KEY ("member_id", "session_id") REFERENCES "session" ("member_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
488 "scope" TEXT NOT NULL,
489 CONSTRAINT "system_application_or_domain_but_not_both" CHECK (
490 ("system_application_id" NOTNULL AND "domain" ISNULL) OR
491 ("system_application_id" ISNULL AND "domain" NOTNULL) ) );
492 CREATE INDEX "member_application_member_id_idx" ON "member_application" ("member_id");
494 COMMENT ON TABLE "member_application" IS 'Application authorized by a member';
496 COMMENT ON COLUMN "member_application"."system_application_id" IS 'If set, then application is a system application';
497 COMMENT ON COLUMN "member_application"."domain" IS 'If set, then application is a dynamically registered OAuth 2.0 client; value is set to client''s domain';
498 COMMENT ON COLUMN "member_application"."session_id" IS 'If set, registration ends with session';
499 COMMENT ON COLUMN "member_application"."scope" IS 'Granted scope as space-separated list of strings';
502 CREATE TYPE "token_type" AS ENUM ('authorization', 'refresh', 'access');
504 COMMENT ON TYPE "token_type" IS 'Types for entries in "token" table';
507 CREATE TABLE "token" (
508 "id" SERIAL8 PRIMARY KEY,
509 "token" TEXT NOT NULL UNIQUE,
510 "token_type" "token_type" NOT NULL,
511 "authorization_token_id" INT8 REFERENCES "token" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
512 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
513 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
514 "domain" TEXT,
515 FOREIGN KEY ("member_id", "domain") REFERENCES "member_application" ("member_id", "domain") ON DELETE CASCADE ON UPDATE CASCADE,
516 "session_id" INT8,
517 FOREIGN KEY ("member_id", "session_id") REFERENCES "session" ("member_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE, -- NOTE: deletion through "detach_token_from_session" trigger on table "session"
518 "redirect_uri" TEXT,
519 "redirect_uri_explicit" BOOLEAN,
520 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
521 "expiry" TIMESTAMPTZ DEFAULT now() + '1 hour',
522 "used" BOOLEAN NOT NULL DEFAULT FALSE,
523 "scope" TEXT NOT NULL,
524 CONSTRAINT "access_token_needs_expiry"
525 CHECK ("token_type" != 'access'::"token_type" OR "expiry" NOTNULL),
526 CONSTRAINT "authorization_token_needs_redirect_uri"
527 CHECK ("token_type" != 'authorization'::"token_type" OR ("redirect_uri" NOTNULL AND "redirect_uri_explicit" NOTNULL) ) );
528 CREATE INDEX "token_member_id_idx" ON "token" ("member_id");
529 CREATE INDEX "token_authorization_token_id_idx" ON "token" ("authorization_token_id");
530 CREATE INDEX "token_expiry_idx" ON "token" ("expiry");
532 COMMENT ON TABLE "token" IS 'Issued OAuth 2.0 authorization codes and access/refresh tokens';
534 COMMENT ON COLUMN "token"."token" IS 'String secret (the actual token)';
535 COMMENT ON COLUMN "token"."authorization_token_id" IS 'Reference to authorization token if tokens were originally created by Authorization Code flow (allows deletion if code is used twice)';
536 COMMENT ON COLUMN "token"."system_application_id" IS 'If set, then application is a system application';
537 COMMENT ON COLUMN "token"."domain" IS 'If set, then application is a dynamically registered OAuth 2.0 client; value is set to client''s domain';
538 COMMENT ON COLUMN "token"."session_id" IS 'If set, then token is tied to a session; Deletion of session sets value to NULL (via trigger) and removes all scopes without suffix ''_detached''';
539 COMMENT ON COLUMN "token"."redirect_uri" IS 'Authorization codes must be bound to a specific redirect URI';
540 COMMENT ON COLUMN "token"."redirect_uri_explicit" IS 'True if ''redirect_uri'' parameter was explicitly specified during authorization request of the Authorization Code flow (since RFC 6749 requires it to be included in the access token request in this case)';
541 COMMENT ON COLUMN "token"."expiry" IS 'Point in time when code or token expired; In case of "used" authorization codes, authorization code must not be deleted as long as tokens exist which refer to the authorization code';
542 COMMENT ON COLUMN "token"."used" IS 'Can be set to TRUE for authorization codes that have been used (enables deletion of authorization codes that were used twice)';
543 COMMENT ON COLUMN "token"."scope" IS 'Scope as space-separated list of strings (detached scopes are marked with ''_detached'' suffix)';
546 CREATE TABLE "token_scope" (
547 PRIMARY KEY ("token_id", "index"),
548 "token_id" INT8 REFERENCES "token" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
549 "index" INT4,
550 "scope" TEXT NOT NULL );
552 COMMENT ON TABLE "token_scope" IS 'Additional scopes for an authorization code if ''scope1'', ''scope2'', etc. parameters were used during Authorization Code flow to request several access and refresh tokens at once';
555 CREATE TYPE "defeat_strength" AS ENUM ('simple', 'tuple');
557 COMMENT ON TYPE "defeat_strength" IS 'How pairwise defeats are measured for the Schulze method: ''simple'' = only the number of winning votes, ''tuple'' = primarily the number of winning votes, secondarily the number of losing votes';
560 CREATE TYPE "tie_breaking" AS ENUM ('simple', 'variant1', 'variant2');
562 COMMENT ON TYPE "tie_breaking" IS 'Tie-breaker for the Schulze method: ''simple'' = only initiative ids are used, ''variant1'' = use initiative ids in variant 1 for tie breaking of the links (TBRL) and sequentially forbid shared links, ''variant2'' = use initiative ids in variant 2 for tie breaking of the links (TBRL) and sequentially forbid shared links';
565 CREATE TABLE "policy" (
566 "id" SERIAL4 PRIMARY KEY,
567 "index" INT4 NOT NULL,
568 "active" BOOLEAN NOT NULL DEFAULT TRUE,
569 "name" TEXT NOT NULL UNIQUE,
570 "description" TEXT NOT NULL DEFAULT '',
571 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
572 "min_admission_time" INTERVAL,
573 "max_admission_time" INTERVAL,
574 "discussion_time" INTERVAL,
575 "verification_time" INTERVAL,
576 "voting_time" INTERVAL,
577 "issue_quorum" INT4 CHECK ("issue_quorum" >= 1),
578 "issue_quorum_num" INT4,
579 "issue_quorum_den" INT4,
580 "initiative_quorum" INT4 NOT NULL CHECK ("initiative_quorum" >= 1),
581 "initiative_quorum_num" INT4 NOT NULL,
582 "initiative_quorum_den" INT4 NOT NULL,
583 "defeat_strength" "defeat_strength" NOT NULL DEFAULT 'tuple',
584 "tie_breaking" "tie_breaking" NOT NULL DEFAULT 'variant1',
585 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
586 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
587 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
588 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
589 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
590 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
591 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
592 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
593 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
594 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
595 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT FALSE,
596 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
597 CONSTRAINT "issue_quorum_if_and_only_if_not_polling" CHECK (
598 "polling" = ("issue_quorum" ISNULL) AND
599 "polling" = ("issue_quorum_num" ISNULL) AND
600 "polling" = ("issue_quorum_den" ISNULL) ),
601 CONSTRAINT "min_admission_time_smaller_than_max_admission_time" CHECK (
602 "min_admission_time" < "max_admission_time" ),
603 CONSTRAINT "timing_null_or_not_null_constraints" CHECK (
604 ( "polling" = FALSE AND
605 "min_admission_time" NOTNULL AND "max_admission_time" NOTNULL AND
606 "discussion_time" NOTNULL AND
607 "verification_time" NOTNULL AND
608 "voting_time" NOTNULL ) OR
609 ( "polling" = TRUE AND
610 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
611 "discussion_time" NOTNULL AND
612 "verification_time" NOTNULL AND
613 "voting_time" NOTNULL ) OR
614 ( "polling" = TRUE AND
615 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
616 "discussion_time" ISNULL AND
617 "verification_time" ISNULL AND
618 "voting_time" ISNULL ) ),
619 CONSTRAINT "no_reverse_beat_path_requires_tuple_defeat_strength" CHECK (
620 "defeat_strength" = 'tuple'::"defeat_strength" OR
621 "no_reverse_beat_path" = FALSE ) );
622 CREATE INDEX "policy_active_idx" ON "policy" ("active");
624 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
626 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
627 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
628 COMMENT ON COLUMN "policy"."polling" IS 'TRUE = special policy for non-user-generated issues without issue quorum, where certain initiatives (those having the "polling" flag set) do not need to pass the initiative quorum; "min_admission_time" and "max_admission_time" MUST be set to NULL, the other timings may be set to NULL altogether, allowing individual timing for those issues';
629 COMMENT ON COLUMN "policy"."min_admission_time" IS 'Minimum duration of issue state ''admission''; Minimum time an issue stays open; Note: should be considerably smaller than "max_admission_time"';
630 COMMENT ON COLUMN "policy"."max_admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
631 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
632 COMMENT ON COLUMN "policy"."verification_time" IS 'Duration of issue state ''verification''; Regular time until an issue is "fully_frozen" (e.g. entering issue state ''voting'') after being "half_frozen"';
633 COMMENT ON COLUMN "policy"."voting_time" IS 'Duration of issue state ''voting''; Time after an issue is "fully_frozen" but not "closed" (duration of issue state ''voting'')';
634 COMMENT ON COLUMN "policy"."issue_quorum" IS 'Absolute number of supporters needed by an initiative to be "accepted", i.e. pass from ''admission'' to ''discussion'' state';
635 COMMENT ON COLUMN "policy"."issue_quorum_num" IS 'Numerator of supporter quorum to be reached by an initiative to be "accepted", i.e. pass from ''admission'' to ''discussion'' state (Note: further requirements apply, see quorum columns of "area" table)';
636 COMMENT ON COLUMN "policy"."issue_quorum_den" IS 'Denominator of supporter quorum to be reached by an initiative to be "accepted", i.e. pass from ''admission'' to ''discussion'' state (Note: further requirements apply, see quorum columns of "area" table)';
637 COMMENT ON COLUMN "policy"."initiative_quorum" IS 'Absolute number of satisfied supporters to be reached by an initiative to be "admitted" for voting';
638 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
639 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
640 COMMENT ON COLUMN "policy"."defeat_strength" IS 'How pairwise defeats are measured for the Schulze method; see type "defeat_strength"; ''tuple'' is the recommended setting';
641 COMMENT ON COLUMN "policy"."tie_breaking" IS 'Tie-breaker for the Schulze method; see type "tie_breaking"; ''variant1'' or ''variant2'' are recommended';
642 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
643 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
644 COMMENT ON COLUMN "policy"."direct_majority_strict" IS 'If TRUE, then the direct majority must be strictly greater than "direct_majority_num"/"direct_majority_den", otherwise it may also be equal.';
645 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
646 COMMENT ON COLUMN "policy"."direct_majority_non_negative" IS 'Absolute number of sum of "positive_votes" and abstentions neccessary for an initiative to be attainable as winner';
647 COMMENT ON COLUMN "policy"."indirect_majority_num" IS 'Numerator of fraction of neccessary indirect majority (through beat path) for initiatives to be attainable as winner';
648 COMMENT ON COLUMN "policy"."indirect_majority_den" IS 'Denominator of fraction of neccessary indirect majority (through beat path) for initiatives to be attainable as winner';
649 COMMENT ON COLUMN "policy"."indirect_majority_strict" IS 'If TRUE, then the indirect majority must be strictly greater than "indirect_majority_num"/"indirect_majority_den", otherwise it may also be equal.';
650 COMMENT ON COLUMN "policy"."indirect_majority_positive" IS 'Absolute number of votes in favor of the winner neccessary in a beat path to the status quo for an initaitive to be attainable as winner';
651 COMMENT ON COLUMN "policy"."indirect_majority_non_negative" IS 'Absolute number of sum of votes in favor and abstentions in a beat path to the status quo for an initiative to be attainable as winner';
652 COMMENT ON COLUMN "policy"."no_reverse_beat_path" IS 'EXPERIMENTAL FEATURE: Causes initiatives with "reverse_beat_path" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."reverse_beat_path". This option ensures both that a winning initiative is never tied in a (weak) condorcet paradox with the status quo and a winning initiative always beats the status quo directly with a simple majority.';
653 COMMENT ON COLUMN "policy"."no_multistage_majority" IS 'EXPERIMENTAL FEATURE: Causes initiatives with "multistage_majority" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."multistage_majority". This disqualifies initiatives which could cause an instable result. An instable result in this meaning is a result such that repeating the ballot with same preferences but with the winner of the first ballot as status quo would lead to a different winner in the second ballot. If there are no direct majorities required for the winner, or if in direct comparison only simple majorities are required and "no_reverse_beat_path" is true, then results are always stable and this flag does not have any effect on the winner (but still affects the "eligible" flag of an "initiative").';
656 CREATE TABLE "unit" (
657 "id" SERIAL4 PRIMARY KEY,
658 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
659 "active" BOOLEAN NOT NULL DEFAULT TRUE,
660 "name" TEXT NOT NULL,
661 "description" TEXT NOT NULL DEFAULT '',
662 "external_reference" TEXT,
663 "member_count" INT4,
664 "location" JSONB,
665 "text_search_data" TSVECTOR );
666 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
667 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
668 CREATE INDEX "unit_active_idx" ON "unit" ("active");
669 CREATE INDEX "unit_location_idx" ON "unit" USING gist ((GeoJSON_to_ecluster("location")));
670 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
671 CREATE TRIGGER "update_text_search_data"
672 BEFORE INSERT OR UPDATE ON "unit"
673 FOR EACH ROW EXECUTE PROCEDURE
674 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
675 "name", "description" );
677 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
679 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
680 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
681 COMMENT ON COLUMN "unit"."external_reference" IS 'Opaque data field to store an external reference';
682 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege" (only active members counted)';
683 COMMENT ON COLUMN "unit"."location" IS 'Geographic location on earth as GeoJSON object indicating valid coordinates for initiatives of issues with this policy';
686 CREATE TABLE "subscription" (
687 PRIMARY KEY ("member_id", "unit_id"),
688 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
689 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
690 CREATE INDEX "subscription_unit_id_idx" ON "subscription" ("unit_id");
692 COMMENT ON TABLE "subscription" IS 'An entry in this table denotes that the member wishes to receive notifications regardless of his/her privileges in the given unit';
695 CREATE TABLE "area" (
696 UNIQUE ("unit_id", "id"), -- index needed for foreign-key on table "event"
697 "id" SERIAL4 PRIMARY KEY,
698 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
699 "active" BOOLEAN NOT NULL DEFAULT TRUE,
700 "name" TEXT NOT NULL,
701 "description" TEXT NOT NULL DEFAULT '',
702 "quorum_standard" NUMERIC NOT NULL DEFAULT 2 CHECK ("quorum_standard" >= 0),
703 "quorum_issues" NUMERIC NOT NULL DEFAULT 1 CHECK ("quorum_issues" > 0),
704 "quorum_time" INTERVAL NOT NULL DEFAULT '1 day' CHECK ("quorum_time" > '0'::INTERVAL),
705 "quorum_exponent" NUMERIC NOT NULL DEFAULT 0.5 CHECK ("quorum_exponent" BETWEEN 0 AND 1),
706 "quorum_factor" NUMERIC NOT NULL DEFAULT 2 CHECK ("quorum_factor" >= 1),
707 "quorum_den" INT4 CHECK ("quorum_den" > 0),
708 "issue_quorum" INT4,
709 "external_reference" TEXT,
710 "location" JSONB,
711 "text_search_data" TSVECTOR );
712 CREATE INDEX "area_active_idx" ON "area" ("active");
713 CREATE INDEX "area_location_idx" ON "area" USING gist ((GeoJSON_to_ecluster("location")));
714 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
715 CREATE TRIGGER "update_text_search_data"
716 BEFORE INSERT OR UPDATE ON "area"
717 FOR EACH ROW EXECUTE PROCEDURE
718 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
719 "name", "description" );
721 COMMENT ON TABLE "area" IS 'Subject areas';
723 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
724 COMMENT ON COLUMN "area"."quorum_standard" IS 'Parameter for dynamic issue quorum: default quorum';
725 COMMENT ON COLUMN "area"."quorum_issues" IS 'Parameter for dynamic issue quorum: number of open issues for default quorum';
726 COMMENT ON COLUMN "area"."quorum_time" IS 'Parameter for dynamic issue quorum: discussion, verification, and voting time of open issues to result in the given default quorum (open issues with shorter time will increase quorum and open issues with longer time will reduce quorum if "quorum_exponent" is greater than zero)';
727 COMMENT ON COLUMN "area"."quorum_exponent" IS 'Parameter for dynamic issue quorum: set to zero to ignore duration of open issues, set to one to fully take duration of open issues into account; defaults to 0.5';
728 COMMENT ON COLUMN "area"."quorum_factor" IS 'Parameter for dynamic issue quorum: factor to increase dynamic quorum when a number of "quorum_issues" issues with "quorum_time" duration of discussion, verification, and voting phase are added to the number of open admitted issues';
729 COMMENT ON COLUMN "area"."quorum_den" IS 'Parameter for dynamic issue quorum: when set, dynamic quorum is multiplied with "issue"."population" and divided by "quorum_den" (and then rounded up)';
730 COMMENT ON COLUMN "area"."issue_quorum" IS 'Additional dynamic issue quorum based on the number of open accepted issues; automatically calculated by function "issue_admission"';
731 COMMENT ON COLUMN "area"."external_reference" IS 'Opaque data field to store an external reference';
732 COMMENT ON COLUMN "area"."location" IS 'Geographic location on earth as GeoJSON object indicating valid coordinates for initiatives of issues with this policy';
735 CREATE TABLE "ignored_area" (
736 PRIMARY KEY ("member_id", "area_id"),
737 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
738 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
739 CREATE INDEX "ignored_area_area_id_idx" ON "ignored_area" ("area_id");
741 COMMENT ON TABLE "ignored_area" IS 'An entry in this table denotes that the member does not wish to receive notifications for the given subject area unless he/she declared interested in a particular issue';
744 CREATE TABLE "allowed_policy" (
745 PRIMARY KEY ("area_id", "policy_id"),
746 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
747 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
748 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
749 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
751 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
753 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
756 CREATE TABLE "snapshot" (
757 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "issue"
758 "id" SERIAL8 PRIMARY KEY,
759 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
760 "population" INT4,
761 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
762 "issue_id" INT4 ); -- NOTE: following (cyclic) reference is added later through ALTER command: REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE
764 COMMENT ON TABLE "snapshot" IS 'Point in time when a snapshot of one or more issues (see table "snapshot_issue") and their supporter situation is taken';
767 CREATE TABLE "snapshot_population" (
768 PRIMARY KEY ("snapshot_id", "member_id"),
769 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
770 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE );
772 COMMENT ON TABLE "snapshot_population" IS 'Members with voting right relevant for a snapshot';
775 CREATE TYPE "issue_state" AS ENUM (
776 'admission', 'discussion', 'verification', 'voting',
777 'canceled_by_admin',
778 'canceled_revoked_before_accepted',
779 'canceled_issue_not_accepted',
780 'canceled_after_revocation_during_discussion',
781 'canceled_after_revocation_during_verification',
782 'canceled_no_initiative_admitted',
783 'finished_without_winner', 'finished_with_winner');
785 COMMENT ON TYPE "issue_state" IS 'State of issues';
788 CREATE TABLE "issue" (
789 UNIQUE ("area_id", "id"), -- index needed for foreign-key on table "event"
790 UNIQUE ("policy_id", "id"), -- index needed for foreign-key on table "event"
791 "id" SERIAL4 PRIMARY KEY,
792 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
793 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
794 "admin_notice" TEXT,
795 "external_reference" TEXT,
796 "state" "issue_state" NOT NULL DEFAULT 'admission',
797 "phase_finished" TIMESTAMPTZ,
798 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
799 "accepted" TIMESTAMPTZ,
800 "half_frozen" TIMESTAMPTZ,
801 "fully_frozen" TIMESTAMPTZ,
802 "closed" TIMESTAMPTZ,
803 "cleaned" TIMESTAMPTZ,
804 "min_admission_time" INTERVAL,
805 "max_admission_time" INTERVAL,
806 "discussion_time" INTERVAL NOT NULL,
807 "verification_time" INTERVAL NOT NULL,
808 "voting_time" INTERVAL NOT NULL,
809 "calculated" TIMESTAMPTZ, -- NOTE: copy of "calculated" column of latest snapshot, but no referential integrity to avoid overhead
810 "latest_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
811 "admission_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
812 "half_freeze_snapshot_id" INT8,
813 FOREIGN KEY ("id", "half_freeze_snapshot_id")
814 REFERENCES "snapshot" ("issue_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE,
815 "full_freeze_snapshot_id" INT8,
816 FOREIGN KEY ("id", "full_freeze_snapshot_id")
817 REFERENCES "snapshot" ("issue_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE,
818 "issue_quorum" INT4,
819 "initiative_quorum" INT4,
820 "population" INT4,
821 "voter_count" INT4,
822 "status_quo_schulze_rank" INT4,
823 CONSTRAINT "admission_time_not_null_unless_instantly_accepted" CHECK (
824 ("min_admission_time" NOTNULL) = ("max_admission_time" NOTNULL) AND
825 ("min_admission_time" NOTNULL OR ("accepted" NOTNULL AND "accepted" = "created")) ),
826 CONSTRAINT "valid_state" CHECK (
827 (
828 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
829 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
830 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL ) OR
831 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL)
832 ) AND (
833 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
834 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
835 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
836 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
837 ("state" = 'canceled_by_admin' AND "closed" NOTNULL) OR
838 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
839 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
840 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
841 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
842 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" = "fully_frozen") OR
843 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen") OR
844 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen")
845 )),
846 CONSTRAINT "phase_finished_only_when_not_closed" CHECK (
847 "phase_finished" ISNULL OR "closed" ISNULL ),
848 CONSTRAINT "state_change_order" CHECK (
849 "created" <= "accepted" AND
850 "accepted" <= "half_frozen" AND
851 "half_frozen" <= "fully_frozen" AND
852 "fully_frozen" <= "closed" ),
853 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
854 "cleaned" ISNULL OR "closed" NOTNULL ),
855 CONSTRAINT "snapshot_required" CHECK (
856 --("accepted" ISNULL OR "admission_snapshot_id" NOTNULL) AND
857 ("half_frozen" ISNULL OR "half_freeze_snapshot_id" NOTNULL) AND
858 ("fully_frozen" ISNULL OR "full_freeze_snapshot_id" NOTNULL) ) );
859 CREATE INDEX "issue_state_idx" ON "issue" ("state");
860 CREATE INDEX "issue_created_idx" ON "issue" ("created");
861 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
862 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
863 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
864 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
865 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
866 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
867 CREATE INDEX "issue_latest_snapshot_id" ON "issue" ("latest_snapshot_id");
868 CREATE INDEX "issue_admission_snapshot_id" ON "issue" ("admission_snapshot_id");
869 CREATE INDEX "issue_half_freeze_snapshot_id" ON "issue" ("half_freeze_snapshot_id");
870 CREATE INDEX "issue_full_freeze_snapshot_id" ON "issue" ("full_freeze_snapshot_id");
872 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
874 COMMENT ON COLUMN "issue"."admin_notice" IS 'Public notice by admin to explain manual interventions, or to announce corrections';
875 COMMENT ON COLUMN "issue"."external_reference" IS 'Opaque data field to store an external reference';
876 COMMENT ON COLUMN "issue"."phase_finished" IS 'Set to a value NOTNULL, if the current phase has finished, but calculations are pending; No changes in this issue shall be made by the frontend or API when this value is set';
877 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when the issue was accepted for further discussion (see columns "issue_quorum_num" and "issue_quorum_den" of table "policy" and quorum columns of table "area")';
878 COMMENT ON COLUMN "issue"."half_frozen" IS 'Point in time, when "discussion_time" has elapsed; Frontends must ensure that for half_frozen issues a) initiatives are not revoked, b) no new drafts are created, c) no initiators are added or removed.';
879 COMMENT ON COLUMN "issue"."fully_frozen" IS 'Point in time, when "verification_time" has elapsed and voting has started; Frontends must ensure that for fully_frozen issues additionally to the restrictions for half_frozen issues a) initiatives are not created, b) no interest is created or removed, c) no supporters are added or removed, d) no opinions are created, changed or deleted.';
880 COMMENT ON COLUMN "issue"."closed" IS 'Point in time, when "max_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.';
881 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
882 COMMENT ON COLUMN "issue"."min_admission_time" IS 'Copied from "policy" table at creation of issue';
883 COMMENT ON COLUMN "issue"."max_admission_time" IS 'Copied from "policy" table at creation of issue';
884 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
885 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
886 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
887 COMMENT ON COLUMN "issue"."calculated" IS 'Point in time, when most recent snapshot and "population" and *_count values were calculated (NOTE: value is equal to "snapshot"."calculated" of snapshot with "id"="issue"."latest_snapshot_id")';
888 COMMENT ON COLUMN "issue"."latest_snapshot_id" IS 'Snapshot id of most recent snapshot';
889 COMMENT ON COLUMN "issue"."admission_snapshot_id" IS 'Snapshot id when issue as accepted or canceled in admission phase';
890 COMMENT ON COLUMN "issue"."half_freeze_snapshot_id" IS 'Snapshot id at end of discussion phase';
891 COMMENT ON COLUMN "issue"."full_freeze_snapshot_id" IS 'Snapshot id at end of verification phase';
892 COMMENT ON COLUMN "issue"."issue_quorum" IS 'Calculated number of supporters needed by an initiative of the issue to be "accepted", i.e. pass from ''admission'' to ''discussion'' state';
893 COMMENT ON COLUMN "issue"."initiative_quorum" IS 'Calculated number of satisfied supporters to be reached by an initiative to be "admitted" for voting';
894 COMMENT ON COLUMN "issue"."population" IS 'Count of members in "snapshot_population" table with "snapshot_id" equal to "issue"."latest_snapshot_id"';
895 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';
896 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
899 ALTER TABLE "snapshot" ADD FOREIGN KEY ("issue_id") REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE;
902 CREATE TABLE "issue_order_in_admission_state" (
903 "id" INT8 PRIMARY KEY, -- NOTE: no referential integrity due to performans/locking issues; REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
904 "order_in_area" INT4,
905 "order_in_unit" INT4 );
907 COMMENT ON TABLE "issue_order_in_admission_state" IS 'Ordering information for issues that are not stored in the "issue" table to avoid locking of multiple issues at once; Filled/updated by "lf_update_issue_order"';
909 COMMENT ON COLUMN "issue_order_in_admission_state"."id" IS 'References "issue" ("id") but has no referential integrity trigger associated, due to performance/locking issues';
910 COMMENT ON COLUMN "issue_order_in_admission_state"."order_in_area" IS 'Order of issues in admission state within a single area; NULL values sort last';
911 COMMENT ON COLUMN "issue_order_in_admission_state"."order_in_unit" IS 'Order of issues in admission state within all areas of a unit; NULL values sort last';
914 CREATE TABLE "initiative" (
915 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
916 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
917 "id" SERIAL4 PRIMARY KEY,
918 "name" TEXT NOT NULL,
919 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
920 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
921 "revoked" TIMESTAMPTZ,
922 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
923 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
924 "location" JSONB,
925 "external_reference" TEXT,
926 "admitted" BOOLEAN,
927 "supporter_count" INT4,
928 "informed_supporter_count" INT4,
929 "satisfied_supporter_count" INT4,
930 "satisfied_informed_supporter_count" INT4,
931 "harmonic_weight" NUMERIC(12, 3),
932 "final_suggestion_order_calculated" BOOLEAN NOT NULL DEFAULT FALSE,
933 "first_preference_votes" INT4,
934 "positive_votes" INT4,
935 "negative_votes" INT4,
936 "direct_majority" BOOLEAN,
937 "indirect_majority" BOOLEAN,
938 "schulze_rank" INT4,
939 "better_than_status_quo" BOOLEAN,
940 "worse_than_status_quo" BOOLEAN,
941 "reverse_beat_path" BOOLEAN,
942 "multistage_majority" BOOLEAN,
943 "eligible" BOOLEAN,
944 "winner" BOOLEAN,
945 "rank" INT4,
946 "text_search_data" TSVECTOR,
947 "draft_text_search_data" TSVECTOR,
948 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
949 CHECK (("revoked" NOTNULL) = ("revoked_by_member_id" NOTNULL)),
950 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
951 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
952 CONSTRAINT "revoked_initiatives_cant_be_admitted"
953 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
954 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
955 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
956 ( "first_preference_votes" ISNULL AND
957 "positive_votes" ISNULL AND "negative_votes" ISNULL AND
958 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
959 "schulze_rank" ISNULL AND
960 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
961 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
962 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
963 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
964 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
965 "eligible" = FALSE OR
966 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
967 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
968 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
969 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
970 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
971 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
972 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
973 CREATE INDEX "initiative_location_idx" ON "initiative" USING gist ((GeoJSON_to_ecluster("location")));
974 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
975 CREATE INDEX "initiative_draft_text_search_data_idx" ON "initiative" USING gin ("draft_text_search_data");
976 CREATE TRIGGER "update_text_search_data"
977 BEFORE INSERT OR UPDATE ON "initiative"
978 FOR EACH ROW EXECUTE PROCEDURE
979 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "name");
981 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.';
983 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
984 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
985 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
986 COMMENT ON COLUMN "initiative"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied from most recent draft)';
987 COMMENT ON COLUMN "initiative"."external_reference" IS 'Opaque data field to store an external reference';
988 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
989 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
990 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
991 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
992 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
993 COMMENT ON COLUMN "initiative"."harmonic_weight" IS 'Indicates the relevancy of the initiative, calculated from the potential supporters weighted with the harmonic series to avoid a large number of clones affecting other initiative''s sorting positions too much; shall be used as secondary sorting key after "admitted" as primary sorting key';
994 COMMENT ON COLUMN "initiative"."final_suggestion_order_calculated" IS 'Set to TRUE, when "proportional_order" of suggestions has been calculated the last time';
995 COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice';
996 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo';
997 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo';
998 COMMENT ON COLUMN "initiative"."direct_majority" IS 'TRUE, if "positive_votes"/("positive_votes"+"negative_votes") is strictly greater or greater-equal than "direct_majority_num"/"direct_majority_den", and "positive_votes" is greater-equal than "direct_majority_positive", and ("positive_votes"+abstentions) is greater-equal than "direct_majority_non_negative"';
999 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
1000 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking';
1001 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo';
1002 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (DEPRECATED, since schulze-ranking is unique per issue; use "better_than_status_quo"=FALSE)';
1003 COMMENT ON COLUMN "initiative"."reverse_beat_path" IS 'TRUE, if there is a beat path (may include ties) from this initiative to the status quo; set to NULL if "policy"."defeat_strength" is set to ''simple''';
1004 COMMENT ON COLUMN "initiative"."multistage_majority" IS 'TRUE, if either (a) this initiative has no better rank than the status quo, or (b) there exists a better ranked initiative X, which directly beats this initiative, and either more voters prefer X to this initiative than voters preferring X to the status quo or less voters prefer this initiative to X than voters preferring the status quo to X';
1005 COMMENT ON COLUMN "initiative"."eligible" IS 'Initiative has a "direct_majority" and an "indirect_majority", is "better_than_status_quo" and depending on selected policy the initiative has no "reverse_beat_path" or "multistage_majority"';
1006 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank"';
1007 COMMENT ON COLUMN "initiative"."rank" IS 'Unique ranking for all "admitted" initiatives per issue; lower rank is better; a winner always has rank 1, but rank 1 does not imply that an initiative is winner; initiatives with "direct_majority" AND "indirect_majority" always have a better (lower) rank than other initiatives';
1010 CREATE TABLE "battle" (
1011 "issue_id" INT4 NOT NULL,
1012 "winning_initiative_id" INT4,
1013 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1014 "losing_initiative_id" INT4,
1015 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1016 "count" INT4 NOT NULL,
1017 CONSTRAINT "initiative_ids_not_equal" CHECK (
1018 "winning_initiative_id" != "losing_initiative_id" OR
1019 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
1020 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
1021 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
1022 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
1023 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
1025 COMMENT ON TABLE "battle" IS 'Number of members preferring one initiative to another; Filled by "battle_view" when closing an issue; NULL as initiative_id denotes virtual "status-quo" initiative';
1028 CREATE TABLE "ignored_initiative" (
1029 PRIMARY KEY ("member_id", "initiative_id"),
1030 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1031 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1032 CREATE INDEX "ignored_initiative_initiative_id_idx" ON "ignored_initiative" ("initiative_id");
1034 COMMENT ON TABLE "ignored_initiative" IS 'An entry in this table denotes that the member does not wish to receive notifications for the given initiative';
1037 CREATE TABLE "draft" (
1038 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
1039 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1040 "id" SERIAL8 PRIMARY KEY,
1041 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
1042 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1043 "formatting_engine" TEXT,
1044 "content" TEXT NOT NULL,
1045 "location" JSONB,
1046 "external_reference" TEXT,
1047 "text_search_data" TSVECTOR );
1048 CREATE INDEX "draft_created_idx" ON "draft" ("created");
1049 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
1050 CREATE INDEX "draft_location_idx" ON "draft" USING gist ((GeoJSON_to_ecluster("location")));
1051 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
1052 CREATE TRIGGER "update_text_search_data"
1053 BEFORE INSERT OR UPDATE ON "draft"
1054 FOR EACH ROW EXECUTE PROCEDURE
1055 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1057 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.';
1059 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
1060 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
1061 COMMENT ON COLUMN "draft"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied to "initiative" table if draft is most recent)';
1062 COMMENT ON COLUMN "draft"."external_reference" IS 'Opaque data field to store an external reference';
1065 CREATE TABLE "rendered_draft" (
1066 PRIMARY KEY ("draft_id", "format"),
1067 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1068 "format" TEXT,
1069 "content" TEXT NOT NULL );
1071 COMMENT ON TABLE "rendered_draft" IS 'This table may be used by frontends to cache "rendered" drafts (e.g. HTML output generated from wiki text)';
1074 CREATE TABLE "suggestion" (
1075 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
1076 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1077 "id" SERIAL8 PRIMARY KEY,
1078 "draft_id" INT8 NOT NULL,
1079 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1080 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
1081 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1082 "name" TEXT NOT NULL,
1083 "formatting_engine" TEXT,
1084 "content" TEXT NOT NULL DEFAULT '',
1085 "location" JSONB,
1086 "external_reference" TEXT,
1087 "text_search_data" TSVECTOR,
1088 "minus2_unfulfilled_count" INT4,
1089 "minus2_fulfilled_count" INT4,
1090 "minus1_unfulfilled_count" INT4,
1091 "minus1_fulfilled_count" INT4,
1092 "plus1_unfulfilled_count" INT4,
1093 "plus1_fulfilled_count" INT4,
1094 "plus2_unfulfilled_count" INT4,
1095 "plus2_fulfilled_count" INT4,
1096 "proportional_order" INT4 );
1097 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
1098 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
1099 CREATE INDEX "suggestion_location_idx" ON "suggestion" USING gist ((GeoJSON_to_ecluster("location")));
1100 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
1101 CREATE TRIGGER "update_text_search_data"
1102 BEFORE INSERT OR UPDATE ON "suggestion"
1103 FOR EACH ROW EXECUTE PROCEDURE
1104 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
1105 "name", "content");
1107 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';
1109 COMMENT ON COLUMN "suggestion"."draft_id" IS 'Draft, which the author has seen when composing the suggestion; should always be set by a frontend, but defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
1110 COMMENT ON COLUMN "suggestion"."location" IS 'Geographic location of suggestion as GeoJSON object';
1111 COMMENT ON COLUMN "suggestion"."external_reference" IS 'Opaque data field to store an external reference';
1112 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1113 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1114 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1115 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1116 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1117 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1118 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1119 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1120 COMMENT ON COLUMN "suggestion"."proportional_order" IS 'To be used for sorting suggestions within an initiative; NULL values sort last; updated by "lf_update_suggestion_order"';
1123 CREATE TABLE "rendered_suggestion" (
1124 PRIMARY KEY ("suggestion_id", "format"),
1125 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1126 "format" TEXT,
1127 "content" TEXT NOT NULL );
1129 COMMENT ON TABLE "rendered_suggestion" IS 'This table may be used by frontends to cache "rendered" drafts (e.g. HTML output generated from wiki text)';
1132 CREATE TABLE "temporary_suggestion_counts" (
1133 "id" INT8 PRIMARY KEY, -- NOTE: no referential integrity due to performance/locking issues; REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1134 "minus2_unfulfilled_count" INT4 NOT NULL,
1135 "minus2_fulfilled_count" INT4 NOT NULL,
1136 "minus1_unfulfilled_count" INT4 NOT NULL,
1137 "minus1_fulfilled_count" INT4 NOT NULL,
1138 "plus1_unfulfilled_count" INT4 NOT NULL,
1139 "plus1_fulfilled_count" INT4 NOT NULL,
1140 "plus2_unfulfilled_count" INT4 NOT NULL,
1141 "plus2_fulfilled_count" INT4 NOT NULL );
1143 COMMENT ON TABLE "temporary_suggestion_counts" IS 'Holds certain calculated values (suggestion counts) temporarily until they can be copied into table "suggestion"';
1145 COMMENT ON COLUMN "temporary_suggestion_counts"."id" IS 'References "suggestion" ("id") but has no referential integrity trigger associated, due to performance/locking issues';
1148 CREATE TABLE "privilege" (
1149 PRIMARY KEY ("unit_id", "member_id"),
1150 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1151 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1152 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1153 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1154 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1155 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1156 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
1157 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
1158 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
1160 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
1162 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
1163 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
1164 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
1165 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
1166 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
1167 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
1168 COMMENT ON COLUMN "privilege"."polling_right" IS 'Right to create issues with policies having the "policy"."polling" flag set, and to add initiatives having the "initiative"."polling" flag set to those issues';
1171 CREATE TABLE "interest" (
1172 PRIMARY KEY ("issue_id", "member_id"),
1173 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1174 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE );
1175 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
1177 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.';
1180 CREATE TABLE "initiator" (
1181 PRIMARY KEY ("initiative_id", "member_id"),
1182 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1183 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1184 "accepted" BOOLEAN );
1185 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
1187 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.';
1189 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.';
1192 CREATE TABLE "supporter" (
1193 "issue_id" INT4 NOT NULL,
1194 PRIMARY KEY ("initiative_id", "member_id"),
1195 "initiative_id" INT4,
1196 "member_id" INT4,
1197 "draft_id" INT8 NOT NULL,
1198 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1199 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
1200 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
1202 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.';
1204 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1205 COMMENT ON COLUMN "supporter"."draft_id" IS 'Latest seen draft; should always be set by a frontend, but defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
1208 CREATE TABLE "opinion" (
1209 "initiative_id" INT4 NOT NULL,
1210 PRIMARY KEY ("suggestion_id", "member_id"),
1211 "suggestion_id" INT8,
1212 "member_id" INT4,
1213 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
1214 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
1215 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1216 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1217 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
1219 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.';
1221 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
1224 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
1226 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
1229 CREATE TABLE "delegation" (
1230 "id" SERIAL8 PRIMARY KEY,
1231 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1232 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1233 "scope" "delegation_scope" NOT NULL,
1234 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1235 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1236 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1237 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
1238 CONSTRAINT "no_unit_delegation_to_null"
1239 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
1240 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
1241 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
1242 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
1243 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
1244 UNIQUE ("unit_id", "truster_id"),
1245 UNIQUE ("area_id", "truster_id"),
1246 UNIQUE ("issue_id", "truster_id") );
1247 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
1248 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
1250 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
1252 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
1253 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
1254 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
1257 CREATE TABLE "snapshot_issue" (
1258 PRIMARY KEY ("snapshot_id", "issue_id"),
1259 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1260 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); -- NOTE: trigger "delete_snapshot_on_partial_delete" will delete whole "snapshot"
1261 CREATE INDEX "snapshot_issue_issue_id_idx" ON "snapshot_issue" ("issue_id");
1263 COMMENT ON TABLE "snapshot_issue" IS 'List of issues included in a snapshot';
1265 COMMENT ON COLUMN "snapshot_issue"."issue_id" IS 'Issue being part of the snapshot; Trigger "delete_snapshot_on_partial_delete" on "snapshot_issue" table will delete snapshot if an issue of the snapshot is deleted.';
1268 CREATE TABLE "direct_interest_snapshot" (
1269 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
1270 "snapshot_id" INT8,
1271 "issue_id" INT4,
1272 FOREIGN KEY ("snapshot_id", "issue_id")
1273 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1274 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1275 "weight" INT4 );
1276 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
1278 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"; for corrections refer to column "issue_notice" of "issue" table';
1280 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
1283 CREATE TABLE "delegating_interest_snapshot" (
1284 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
1285 "snapshot_id" INT8,
1286 "issue_id" INT4,
1287 FOREIGN KEY ("snapshot_id", "issue_id")
1288 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1289 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1290 "weight" INT4,
1291 "scope" "delegation_scope" NOT NULL,
1292 "delegate_member_ids" INT4[] NOT NULL );
1293 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
1295 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table; for corrections refer to column "issue_notice" of "issue" table';
1297 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
1298 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
1299 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"';
1302 CREATE TABLE "direct_supporter_snapshot" (
1303 PRIMARY KEY ("snapshot_id", "initiative_id", "member_id"),
1304 "snapshot_id" INT8,
1305 "issue_id" INT4 NOT NULL,
1306 FOREIGN KEY ("snapshot_id", "issue_id")
1307 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1308 "initiative_id" INT4,
1309 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1310 "draft_id" INT8 NOT NULL,
1311 "informed" BOOLEAN NOT NULL,
1312 "satisfied" BOOLEAN NOT NULL,
1313 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1314 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1315 FOREIGN KEY ("snapshot_id", "issue_id", "member_id") REFERENCES "direct_interest_snapshot" ("snapshot_id", "issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1316 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1318 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot"); for corrections refer to column "issue_notice" of "issue" table';
1320 COMMENT ON COLUMN "direct_supporter_snapshot"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1321 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1322 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1325 CREATE TABLE "non_voter" (
1326 PRIMARY KEY ("member_id", "issue_id"),
1327 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1328 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1329 CREATE INDEX "non_voter_issue_id_idx" ON "non_voter" ("issue_id");
1331 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1334 CREATE TABLE "direct_voter" (
1335 PRIMARY KEY ("issue_id", "member_id"),
1336 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1337 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1338 "weight" INT4,
1339 "comment_changed" TIMESTAMPTZ,
1340 "formatting_engine" TEXT,
1341 "comment" TEXT,
1342 "text_search_data" TSVECTOR );
1343 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1344 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
1345 CREATE TRIGGER "update_text_search_data"
1346 BEFORE INSERT OR UPDATE ON "direct_voter"
1347 FOR EACH ROW EXECUTE PROCEDURE
1348 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
1350 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; for corrections refer to column "issue_notice" of "issue" table';
1352 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1353 COMMENT ON COLUMN "direct_voter"."comment_changed" IS 'Shall be set on comment change, to indicate a comment being modified after voting has been finished; Automatically set to NULL after voting phase; Automatically set to NULL by trigger, if "comment" is set to NULL';
1354 COMMENT ON COLUMN "direct_voter"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "direct_voter"."comment"; Automatically set to NULL by trigger, if "comment" is set to NULL';
1355 COMMENT ON COLUMN "direct_voter"."comment" IS 'Is to be set or updated by the frontend, if comment was inserted or updated AFTER the issue has been closed. Otherwise it shall be set to NULL.';
1358 CREATE TABLE "rendered_voter_comment" (
1359 PRIMARY KEY ("issue_id", "member_id", "format"),
1360 FOREIGN KEY ("issue_id", "member_id")
1361 REFERENCES "direct_voter" ("issue_id", "member_id")
1362 ON DELETE CASCADE ON UPDATE CASCADE,
1363 "issue_id" INT4,
1364 "member_id" INT4,
1365 "format" TEXT,
1366 "content" TEXT NOT NULL );
1368 COMMENT ON TABLE "rendered_voter_comment" IS 'This table may be used by frontends to cache "rendered" voter comments (e.g. HTML output generated from wiki text)';
1371 CREATE TABLE "delegating_voter" (
1372 PRIMARY KEY ("issue_id", "member_id"),
1373 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1374 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1375 "weight" INT4,
1376 "scope" "delegation_scope" NOT NULL,
1377 "delegate_member_ids" INT4[] NOT NULL );
1378 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1380 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table; for corrections refer to column "issue_notice" of "issue" table';
1382 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1383 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1384 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"';
1387 CREATE TABLE "vote" (
1388 "issue_id" INT4 NOT NULL,
1389 PRIMARY KEY ("initiative_id", "member_id"),
1390 "initiative_id" INT4,
1391 "member_id" INT4,
1392 "grade" INT4 NOT NULL,
1393 "first_preference" BOOLEAN,
1394 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1395 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1396 CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
1397 CHECK ("grade" > 0 OR "first_preference" ISNULL) );
1398 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1400 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; for corrections refer to column "issue_notice" of "issue" table';
1402 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1403 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.';
1404 COMMENT ON COLUMN "vote"."first_preference" IS 'Value is automatically set after voting is finished. For positive grades, this value is set to true for the highest (i.e. best) grade.';
1407 CREATE TYPE "event_type" AS ENUM (
1408 'unit_created',
1409 'unit_updated',
1410 'area_created',
1411 'area_updated',
1412 'policy_created',
1413 'policy_updated',
1414 'issue_state_changed',
1415 'initiative_created_in_new_issue',
1416 'initiative_created_in_existing_issue',
1417 'initiative_revoked',
1418 'new_draft_created',
1419 'suggestion_created',
1420 'suggestion_deleted',
1421 'member_activated',
1422 'member_deleted',
1423 'member_active',
1424 'member_name_updated',
1425 'member_profile_updated',
1426 'member_image_updated',
1427 'interest',
1428 'initiator',
1429 'support',
1430 'support_updated',
1431 'suggestion_rated',
1432 'delegation',
1433 'contact' );
1435 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1438 CREATE TABLE "event" (
1439 "id" SERIAL8 PRIMARY KEY,
1440 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1441 "event" "event_type" NOT NULL,
1442 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1443 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1444 "scope" "delegation_scope",
1445 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1446 "area_id" INT4,
1447 FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1448 "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1449 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1450 FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1451 FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1452 "state" "issue_state",
1453 "initiative_id" INT4,
1454 "draft_id" INT8,
1455 "suggestion_id" INT8,
1456 "boolean_value" BOOLEAN,
1457 "numeric_value" INT4,
1458 "text_value" TEXT,
1459 "old_text_value" TEXT,
1460 FOREIGN KEY ("issue_id", "initiative_id")
1461 REFERENCES "initiative" ("issue_id", "id")
1462 ON DELETE CASCADE ON UPDATE CASCADE,
1463 FOREIGN KEY ("initiative_id", "draft_id")
1464 REFERENCES "draft" ("initiative_id", "id")
1465 ON DELETE CASCADE ON UPDATE CASCADE,
1466 -- NOTE: no referential integrity for suggestions because those are
1467 -- actually deleted
1468 -- FOREIGN KEY ("initiative_id", "suggestion_id")
1469 -- REFERENCES "suggestion" ("initiative_id", "id")
1470 -- ON DELETE CASCADE ON UPDATE CASCADE,
1471 CONSTRAINT "constr_for_issue_state_changed" CHECK (
1472 "event" != 'issue_state_changed' OR (
1473 "member_id" ISNULL AND
1474 "other_member_id" ISNULL AND
1475 "scope" ISNULL AND
1476 "unit_id" NOTNULL AND
1477 "area_id" NOTNULL AND
1478 "policy_id" NOTNULL AND
1479 "issue_id" NOTNULL AND
1480 "state" NOTNULL AND
1481 "initiative_id" ISNULL AND
1482 "draft_id" ISNULL AND
1483 "suggestion_id" ISNULL AND
1484 "boolean_value" ISNULL AND
1485 "numeric_value" ISNULL AND
1486 "text_value" ISNULL AND
1487 "old_text_value" ISNULL )),
1488 CONSTRAINT "constr_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1489 "event" NOT IN (
1490 'initiative_created_in_new_issue',
1491 'initiative_created_in_existing_issue',
1492 'initiative_revoked',
1493 'new_draft_created'
1494 ) OR (
1495 "member_id" NOTNULL AND
1496 "other_member_id" ISNULL AND
1497 "scope" ISNULL AND
1498 "unit_id" NOTNULL AND
1499 "area_id" NOTNULL AND
1500 "policy_id" NOTNULL AND
1501 "issue_id" NOTNULL AND
1502 "state" NOTNULL AND
1503 "initiative_id" NOTNULL AND
1504 "draft_id" NOTNULL AND
1505 "suggestion_id" ISNULL AND
1506 "boolean_value" ISNULL AND
1507 "numeric_value" ISNULL AND
1508 "text_value" ISNULL AND
1509 "old_text_value" ISNULL )),
1510 CONSTRAINT "constr_for_suggestion_creation" CHECK (
1511 "event" != 'suggestion_created' OR (
1512 "member_id" NOTNULL AND
1513 "other_member_id" ISNULL AND
1514 "scope" ISNULL AND
1515 "unit_id" NOTNULL AND
1516 "area_id" NOTNULL AND
1517 "policy_id" NOTNULL AND
1518 "issue_id" NOTNULL AND
1519 "state" NOTNULL AND
1520 "initiative_id" NOTNULL AND
1521 "draft_id" ISNULL AND
1522 "suggestion_id" NOTNULL AND
1523 "boolean_value" ISNULL AND
1524 "numeric_value" ISNULL AND
1525 "text_value" ISNULL AND
1526 "old_text_value" ISNULL )),
1527 CONSTRAINT "constr_for_suggestion_removal" CHECK (
1528 "event" != 'suggestion_deleted' OR (
1529 "member_id" ISNULL AND
1530 "other_member_id" ISNULL AND
1531 "scope" ISNULL AND
1532 "unit_id" NOTNULL AND
1533 "area_id" NOTNULL AND
1534 "policy_id" NOTNULL AND
1535 "issue_id" NOTNULL AND
1536 "state" NOTNULL AND
1537 "initiative_id" NOTNULL AND
1538 "draft_id" ISNULL AND
1539 "suggestion_id" NOTNULL AND
1540 "boolean_value" ISNULL AND
1541 "numeric_value" ISNULL AND
1542 "text_value" ISNULL AND
1543 "old_text_value" ISNULL )),
1544 CONSTRAINT "constr_for_value_less_member_event" CHECK (
1545 "event" NOT IN (
1546 'member_activated',
1547 'member_deleted',
1548 'member_profile_updated',
1549 'member_image_updated'
1550 ) OR (
1551 "member_id" NOTNULL AND
1552 "other_member_id" ISNULL AND
1553 "scope" ISNULL AND
1554 "unit_id" ISNULL AND
1555 "area_id" ISNULL AND
1556 "policy_id" ISNULL AND
1557 "issue_id" ISNULL AND
1558 "state" ISNULL AND
1559 "initiative_id" ISNULL AND
1560 "draft_id" ISNULL AND
1561 "suggestion_id" ISNULL AND
1562 "boolean_value" ISNULL AND
1563 "numeric_value" ISNULL AND
1564 "text_value" ISNULL AND
1565 "old_text_value" ISNULL )),
1566 CONSTRAINT "constr_for_member_active" CHECK (
1567 "event" != 'member_active' OR (
1568 "member_id" NOTNULL AND
1569 "other_member_id" ISNULL AND
1570 "scope" ISNULL AND
1571 "unit_id" ISNULL AND
1572 "area_id" ISNULL AND
1573 "policy_id" ISNULL AND
1574 "issue_id" ISNULL AND
1575 "state" ISNULL AND
1576 "initiative_id" ISNULL AND
1577 "draft_id" ISNULL AND
1578 "suggestion_id" ISNULL AND
1579 "boolean_value" NOTNULL AND
1580 "numeric_value" ISNULL AND
1581 "text_value" ISNULL AND
1582 "old_text_value" ISNULL )),
1583 CONSTRAINT "constr_for_member_name_updated" CHECK (
1584 "event" != 'member_name_updated' OR (
1585 "member_id" NOTNULL AND
1586 "other_member_id" ISNULL AND
1587 "scope" ISNULL AND
1588 "unit_id" ISNULL AND
1589 "area_id" ISNULL AND
1590 "policy_id" ISNULL AND
1591 "issue_id" ISNULL AND
1592 "state" ISNULL AND
1593 "initiative_id" ISNULL AND
1594 "draft_id" ISNULL AND
1595 "suggestion_id" ISNULL AND
1596 "boolean_value" ISNULL AND
1597 "numeric_value" ISNULL AND
1598 "text_value" NOTNULL AND
1599 "old_text_value" NOTNULL )),
1600 CONSTRAINT "constr_for_interest" CHECK (
1601 "event" != 'interest' OR (
1602 "member_id" NOTNULL AND
1603 "other_member_id" ISNULL AND
1604 "scope" ISNULL AND
1605 "unit_id" NOTNULL AND
1606 "area_id" NOTNULL AND
1607 "policy_id" NOTNULL AND
1608 "issue_id" NOTNULL AND
1609 "state" NOTNULL AND
1610 "initiative_id" ISNULL AND
1611 "draft_id" ISNULL AND
1612 "suggestion_id" ISNULL AND
1613 "boolean_value" NOTNULL AND
1614 "numeric_value" ISNULL AND
1615 "text_value" ISNULL AND
1616 "old_text_value" ISNULL )),
1617 CONSTRAINT "constr_for_initiator" CHECK (
1618 "event" != 'initiator' OR (
1619 "member_id" NOTNULL AND
1620 "other_member_id" ISNULL AND
1621 "scope" ISNULL AND
1622 "unit_id" NOTNULL AND
1623 "area_id" NOTNULL AND
1624 "policy_id" NOTNULL AND
1625 "issue_id" NOTNULL AND
1626 "state" NOTNULL AND
1627 "initiative_id" NOTNULL AND
1628 "draft_id" ISNULL AND
1629 "suggestion_id" ISNULL AND
1630 "boolean_value" NOTNULL AND
1631 "numeric_value" ISNULL AND
1632 "text_value" ISNULL AND
1633 "old_text_value" ISNULL )),
1634 CONSTRAINT "constr_for_support" CHECK (
1635 "event" != 'support' OR (
1636 "member_id" NOTNULL AND
1637 "other_member_id" ISNULL AND
1638 "scope" ISNULL AND
1639 "unit_id" NOTNULL AND
1640 "area_id" NOTNULL AND
1641 "policy_id" NOTNULL AND
1642 "issue_id" NOTNULL AND
1643 "state" NOTNULL AND
1644 "initiative_id" NOTNULL AND
1645 ("draft_id" NOTNULL) = ("boolean_value" = TRUE) AND
1646 "suggestion_id" ISNULL AND
1647 "boolean_value" NOTNULL AND
1648 "numeric_value" ISNULL AND
1649 "text_value" ISNULL AND
1650 "old_text_value" ISNULL )),
1651 CONSTRAINT "constr_for_support_updated" CHECK (
1652 "event" != 'support_updated' OR (
1653 "member_id" NOTNULL AND
1654 "other_member_id" ISNULL AND
1655 "scope" ISNULL AND
1656 "unit_id" NOTNULL AND
1657 "area_id" NOTNULL AND
1658 "policy_id" NOTNULL AND
1659 "issue_id" NOTNULL AND
1660 "state" NOTNULL AND
1661 "initiative_id" NOTNULL AND
1662 "draft_id" NOTNULL AND
1663 "suggestion_id" ISNULL AND
1664 "boolean_value" ISNULL AND
1665 "numeric_value" ISNULL AND
1666 "text_value" ISNULL AND
1667 "old_text_value" ISNULL )),
1668 CONSTRAINT "constr_for_suggestion_rated" CHECK (
1669 "event" != 'suggestion_rated' OR (
1670 "member_id" NOTNULL AND
1671 "other_member_id" ISNULL AND
1672 "scope" ISNULL AND
1673 "unit_id" NOTNULL AND
1674 "area_id" NOTNULL AND
1675 "policy_id" NOTNULL AND
1676 "issue_id" NOTNULL AND
1677 "state" NOTNULL AND
1678 "initiative_id" NOTNULL AND
1679 "draft_id" ISNULL AND
1680 "suggestion_id" NOTNULL AND
1681 ("boolean_value" NOTNULL) = ("numeric_value" != 0) AND
1682 "numeric_value" NOTNULL AND
1683 "numeric_value" IN (-2, -1, 0, 1, 2) AND
1684 "text_value" ISNULL AND
1685 "old_text_value" ISNULL )),
1686 CONSTRAINT "constr_for_delegation" CHECK (
1687 "event" != 'delegation' OR (
1688 "member_id" NOTNULL AND
1689 (("other_member_id" ISNULL) OR ("boolean_value" = TRUE)) AND
1690 "scope" NOTNULL AND
1691 "unit_id" NOTNULL AND
1692 ("area_id" NOTNULL) = ("scope" != 'unit'::"delegation_scope") AND
1693 "policy_id" ISNULL AND
1694 ("issue_id" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1695 ("state" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1696 "initiative_id" ISNULL AND
1697 "draft_id" ISNULL AND
1698 "suggestion_id" ISNULL AND
1699 "boolean_value" NOTNULL AND
1700 "numeric_value" ISNULL AND
1701 "text_value" ISNULL AND
1702 "old_text_value" ISNULL )),
1703 CONSTRAINT "constr_for_contact" CHECK (
1704 "event" != 'contact' OR (
1705 "member_id" NOTNULL AND
1706 "other_member_id" NOTNULL AND
1707 "scope" ISNULL AND
1708 "unit_id" ISNULL AND
1709 "area_id" ISNULL AND
1710 "policy_id" ISNULL AND
1711 "issue_id" ISNULL AND
1712 "state" ISNULL AND
1713 "initiative_id" ISNULL AND
1714 "draft_id" ISNULL AND
1715 "suggestion_id" ISNULL AND
1716 "boolean_value" NOTNULL AND
1717 "numeric_value" ISNULL AND
1718 "text_value" ISNULL AND
1719 "old_text_value" ISNULL )) );
1720 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1722 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1724 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1725 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1726 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1727 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1730 CREATE TABLE "event_processed" (
1731 "event_id" INT8 NOT NULL );
1732 CREATE UNIQUE INDEX "event_processed_singleton_idx" ON "event_processed" ((1));
1734 COMMENT ON TABLE "event_processed" IS 'This table stores one row with the last event_id, for which event handlers have been executed (e.g. notifications having been sent out)';
1735 COMMENT ON INDEX "event_processed_singleton_idx" IS 'This index ensures that "event_processed" only contains one row maximum.';
1738 CREATE TABLE "notification_initiative_sent" (
1739 PRIMARY KEY ("member_id", "initiative_id"),
1740 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1741 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1742 "last_draft_id" INT8 NOT NULL,
1743 "last_suggestion_id" INT8 );
1744 CREATE INDEX "notification_initiative_sent_initiative_idx" ON "notification_initiative_sent" ("initiative_id");
1746 COMMENT ON TABLE "notification_initiative_sent" IS 'Information which initiatives have been promoted to a member in a scheduled notification mail';
1748 COMMENT ON COLUMN "notification_initiative_sent"."last_draft_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1749 COMMENT ON COLUMN "notification_initiative_sent"."last_suggestion_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1752 CREATE TABLE "newsletter" (
1753 "id" SERIAL4 PRIMARY KEY,
1754 "published" TIMESTAMPTZ NOT NULL,
1755 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1756 "include_all_members" BOOLEAN NOT NULL,
1757 "sent" TIMESTAMPTZ,
1758 "subject" TEXT NOT NULL,
1759 "content" TEXT NOT NULL );
1760 CREATE INDEX "newsletter_unit_id_idx" ON "newsletter" ("unit_id", "published");
1761 CREATE INDEX "newsletter_all_units_published_idx" ON "newsletter" ("published") WHERE "unit_id" ISNULL;
1762 CREATE INDEX "newsletter_published_idx" ON "newsletter" ("published");
1764 COMMENT ON TABLE "newsletter" IS 'Contains newsletters created by administrators to be sent out and for further reference';
1766 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter is to be sent out (and made available in the frontend)';
1767 COMMENT ON COLUMN "newsletter"."unit_id" IS 'If set, only members with voting right in the given unit are considered to be recipients';
1768 COMMENT ON COLUMN "newsletter"."include_all_members" IS 'TRUE = include all members regardless of their ''disable_notifications'' setting';
1769 COMMENT ON COLUMN "newsletter"."sent" IS 'Timestamp when the newsletter has been mailed out';
1770 COMMENT ON COLUMN "newsletter"."subject" IS 'Subject line (e.g. to be used for the email)';
1771 COMMENT ON COLUMN "newsletter"."content" IS 'Plain text content of the newsletter';
1775 ----------------------------------------------
1776 -- Writing of history entries and event log --
1777 ----------------------------------------------
1780 CREATE FUNCTION "write_member_history_trigger"()
1781 RETURNS TRIGGER
1782 LANGUAGE 'plpgsql' VOLATILE AS $$
1783 BEGIN
1784 IF
1785 ( NEW."active" != OLD."active" OR
1786 NEW."name" != OLD."name" ) AND
1787 OLD."activated" NOTNULL
1788 THEN
1789 INSERT INTO "member_history"
1790 ("member_id", "active", "name")
1791 VALUES (NEW."id", OLD."active", OLD."name");
1792 END IF;
1793 RETURN NULL;
1794 END;
1795 $$;
1797 CREATE TRIGGER "write_member_history"
1798 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1799 "write_member_history_trigger"();
1801 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1802 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1805 CREATE FUNCTION "write_event_unit_trigger"()
1806 RETURNS TRIGGER
1807 LANGUAGE 'plpgsql' VOLATILE AS $$
1808 DECLARE
1809 "event_v" "event_type";
1810 BEGIN
1811 IF TG_OP = 'UPDATE' THEN
1812 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1813 RETURN NULL;
1814 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1815 -- "event_v" := 'unit_created';
1816 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1817 -- "event_v" := 'unit_deleted';
1818 ELSIF OLD != NEW THEN
1819 "event_v" := 'unit_updated';
1820 ELSE
1821 RETURN NULL;
1822 END IF;
1823 ELSE
1824 "event_v" := 'unit_created';
1825 END IF;
1826 INSERT INTO "event" ("event", "unit_id") VALUES ("event_v", NEW."id");
1827 RETURN NULL;
1828 END;
1829 $$;
1831 CREATE TRIGGER "write_event_unit" AFTER INSERT OR UPDATE ON "unit"
1832 FOR EACH ROW EXECUTE PROCEDURE "write_event_unit_trigger"();
1834 COMMENT ON FUNCTION "write_event_unit_trigger"() IS 'Implementation of trigger "write_event_unit" on table "unit"';
1835 COMMENT ON TRIGGER "write_event_unit" ON "unit" IS 'Create entry in "event" table on new or changed/disabled units';
1838 CREATE FUNCTION "write_event_area_trigger"()
1839 RETURNS TRIGGER
1840 LANGUAGE 'plpgsql' VOLATILE AS $$
1841 DECLARE
1842 "event_v" "event_type";
1843 BEGIN
1844 IF TG_OP = 'UPDATE' THEN
1845 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1846 RETURN NULL;
1847 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1848 -- "event_v" := 'area_created';
1849 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1850 -- "event_v" := 'area_deleted';
1851 ELSIF OLD != NEW THEN
1852 "event_v" := 'area_updated';
1853 ELSE
1854 RETURN NULL;
1855 END IF;
1856 ELSE
1857 "event_v" := 'area_created';
1858 END IF;
1859 INSERT INTO "event" ("event", "area_id") VALUES ("event_v", NEW."id");
1860 RETURN NULL;
1861 END;
1862 $$;
1864 CREATE TRIGGER "write_event_area" AFTER INSERT OR UPDATE ON "area"
1865 FOR EACH ROW EXECUTE PROCEDURE "write_event_area_trigger"();
1867 COMMENT ON FUNCTION "write_event_area_trigger"() IS 'Implementation of trigger "write_event_area" on table "area"';
1868 COMMENT ON TRIGGER "write_event_area" ON "area" IS 'Create entry in "event" table on new or changed/disabled areas';
1871 CREATE FUNCTION "write_event_policy_trigger"()
1872 RETURNS TRIGGER
1873 LANGUAGE 'plpgsql' VOLATILE AS $$
1874 DECLARE
1875 "event_v" "event_type";
1876 BEGIN
1877 IF TG_OP = 'UPDATE' THEN
1878 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1879 RETURN NULL;
1880 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1881 -- "event_v" := 'policy_created';
1882 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1883 -- "event_v" := 'policy_deleted';
1884 ELSIF OLD != NEW THEN
1885 "event_v" := 'policy_updated';
1886 ELSE
1887 RETURN NULL;
1888 END IF;
1889 ELSE
1890 "event_v" := 'policy_created';
1891 END IF;
1892 INSERT INTO "event" ("event", "policy_id") VALUES ("event_v", NEW."id");
1893 RETURN NULL;
1894 END;
1895 $$;
1897 CREATE TRIGGER "write_event_policy" AFTER INSERT OR UPDATE ON "policy"
1898 FOR EACH ROW EXECUTE PROCEDURE "write_event_policy_trigger"();
1900 COMMENT ON FUNCTION "write_event_policy_trigger"() IS 'Implementation of trigger "write_event_policy" on table "policy"';
1901 COMMENT ON TRIGGER "write_event_policy" ON "policy" IS 'Create entry in "event" table on new or changed/disabled policies';
1904 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1905 RETURNS TRIGGER
1906 LANGUAGE 'plpgsql' VOLATILE AS $$
1907 DECLARE
1908 "area_row" "area"%ROWTYPE;
1909 BEGIN
1910 IF NEW."state" != OLD."state" THEN
1911 SELECT * INTO "area_row" FROM "area" WHERE "id" = NEW."area_id"
1912 FOR SHARE;
1913 INSERT INTO "event" (
1914 "event",
1915 "unit_id", "area_id", "policy_id", "issue_id", "state"
1916 ) VALUES (
1917 'issue_state_changed',
1918 "area_row"."unit_id", NEW."area_id", NEW."policy_id",
1919 NEW."id", NEW."state"
1920 );
1921 END IF;
1922 RETURN NULL;
1923 END;
1924 $$;
1926 CREATE TRIGGER "write_event_issue_state_changed"
1927 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1928 "write_event_issue_state_changed_trigger"();
1930 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1931 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1934 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1935 RETURNS TRIGGER
1936 LANGUAGE 'plpgsql' VOLATILE AS $$
1937 DECLARE
1938 "initiative_row" "initiative"%ROWTYPE;
1939 "issue_row" "issue"%ROWTYPE;
1940 "area_row" "area"%ROWTYPE;
1941 "event_v" "event_type";
1942 BEGIN
1943 SELECT * INTO "initiative_row" FROM "initiative"
1944 WHERE "id" = NEW."initiative_id" FOR SHARE;
1945 SELECT * INTO "issue_row" FROM "issue"
1946 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
1947 SELECT * INTO "area_row" FROM "area"
1948 WHERE "id" = "issue_row"."area_id" FOR SHARE;
1949 IF EXISTS (
1950 SELECT NULL FROM "draft"
1951 WHERE "initiative_id" = NEW."initiative_id" AND "id" != NEW."id"
1952 FOR SHARE
1953 ) THEN
1954 "event_v" := 'new_draft_created';
1955 ELSE
1956 IF EXISTS (
1957 SELECT NULL FROM "initiative"
1958 WHERE "issue_id" = "initiative_row"."issue_id"
1959 AND "id" != "initiative_row"."id"
1960 FOR SHARE
1961 ) THEN
1962 "event_v" := 'initiative_created_in_existing_issue';
1963 ELSE
1964 "event_v" := 'initiative_created_in_new_issue';
1965 END IF;
1966 END IF;
1967 INSERT INTO "event" (
1968 "event", "member_id",
1969 "unit_id", "area_id", "policy_id", "issue_id", "state",
1970 "initiative_id", "draft_id"
1971 ) VALUES (
1972 "event_v", NEW."author_id",
1973 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
1974 "initiative_row"."issue_id", "issue_row"."state",
1975 NEW."initiative_id", NEW."id"
1976 );
1977 RETURN NULL;
1978 END;
1979 $$;
1981 CREATE TRIGGER "write_event_initiative_or_draft_created"
1982 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1983 "write_event_initiative_or_draft_created_trigger"();
1985 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1986 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1989 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1990 RETURNS TRIGGER
1991 LANGUAGE 'plpgsql' VOLATILE AS $$
1992 DECLARE
1993 "issue_row" "issue"%ROWTYPE;
1994 "area_row" "area"%ROWTYPE;
1995 "draft_id_v" "draft"."id"%TYPE;
1996 BEGIN
1997 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1998 -- NOTE: lock for primary key update to avoid new drafts
1999 SELECT NULL FROM "initiative" WHERE "id" = NEW."id" FOR UPDATE;
2000 SELECT * INTO "issue_row" FROM "issue"
2001 WHERE "id" = NEW."issue_id" FOR SHARE;
2002 SELECT * INTO "area_row" FROM "area"
2003 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2004 -- NOTE: FOR SHARE cannot be used with DISTINCT in view "current_draft"
2005 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id" FOR SHARE;
2006 SELECT "id" INTO "draft_id_v" FROM "current_draft"
2007 WHERE "initiative_id" = NEW."id";
2008 INSERT INTO "event" (
2009 "event", "member_id",
2010 "unit_id", "area_id", "policy_id", "issue_id", "state",
2011 "initiative_id", "draft_id"
2012 ) VALUES (
2013 'initiative_revoked', NEW."revoked_by_member_id",
2014 "area_row"."unit_id", "issue_row"."area_id",
2015 "issue_row"."policy_id",
2016 NEW."issue_id", "issue_row"."state",
2017 NEW."id", "draft_id_v"
2018 );
2019 END IF;
2020 RETURN NULL;
2021 END;
2022 $$;
2024 CREATE TRIGGER "write_event_initiative_revoked"
2025 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
2026 "write_event_initiative_revoked_trigger"();
2028 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
2029 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
2032 CREATE FUNCTION "write_event_suggestion_created_trigger"()
2033 RETURNS TRIGGER
2034 LANGUAGE 'plpgsql' VOLATILE AS $$
2035 DECLARE
2036 "initiative_row" "initiative"%ROWTYPE;
2037 "issue_row" "issue"%ROWTYPE;
2038 "area_row" "area"%ROWTYPE;
2039 BEGIN
2040 SELECT * INTO "initiative_row" FROM "initiative"
2041 WHERE "id" = NEW."initiative_id" FOR SHARE;
2042 SELECT * INTO "issue_row" FROM "issue"
2043 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2044 SELECT * INTO "area_row" FROM "area"
2045 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2046 INSERT INTO "event" (
2047 "event", "member_id",
2048 "unit_id", "area_id", "policy_id", "issue_id", "state",
2049 "initiative_id", "suggestion_id"
2050 ) VALUES (
2051 'suggestion_created', NEW."author_id",
2052 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
2053 "initiative_row"."issue_id", "issue_row"."state",
2054 NEW."initiative_id", NEW."id"
2055 );
2056 RETURN NULL;
2057 END;
2058 $$;
2060 CREATE TRIGGER "write_event_suggestion_created"
2061 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2062 "write_event_suggestion_created_trigger"();
2064 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
2065 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2068 CREATE FUNCTION "write_event_suggestion_removed_trigger"()
2069 RETURNS TRIGGER
2070 LANGUAGE 'plpgsql' VOLATILE AS $$
2071 DECLARE
2072 "initiative_row" "initiative"%ROWTYPE;
2073 "issue_row" "issue"%ROWTYPE;
2074 "area_row" "area"%ROWTYPE;
2075 BEGIN
2076 SELECT * INTO "initiative_row" FROM "initiative"
2077 WHERE "id" = OLD."initiative_id" FOR SHARE;
2078 IF "initiative_row"."id" NOTNULL THEN
2079 SELECT * INTO "issue_row" FROM "issue"
2080 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2081 SELECT * INTO "area_row" FROM "area"
2082 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2083 INSERT INTO "event" (
2084 "event",
2085 "unit_id", "area_id", "policy_id", "issue_id", "state",
2086 "initiative_id", "suggestion_id"
2087 ) VALUES (
2088 'suggestion_deleted',
2089 "area_row"."unit_id", "issue_row"."area_id",
2090 "issue_row"."policy_id",
2091 "initiative_row"."issue_id", "issue_row"."state",
2092 OLD."initiative_id", OLD."id"
2093 );
2094 END IF;
2095 RETURN NULL;
2096 END;
2097 $$;
2099 CREATE TRIGGER "write_event_suggestion_removed"
2100 AFTER DELETE ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2101 "write_event_suggestion_removed_trigger"();
2103 COMMENT ON FUNCTION "write_event_suggestion_removed_trigger"() IS 'Implementation of trigger "write_event_suggestion_removed" on table "issue"';
2104 COMMENT ON TRIGGER "write_event_suggestion_removed" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2107 CREATE FUNCTION "write_event_member_trigger"()
2108 RETURNS TRIGGER
2109 LANGUAGE 'plpgsql' VOLATILE AS $$
2110 BEGIN
2111 IF TG_OP = 'INSERT' THEN
2112 IF NEW."activated" NOTNULL AND NEW."deleted" ISNULL THEN
2113 INSERT INTO "event" ("event", "member_id")
2114 VALUES ('member_activated', NEW."id");
2115 END IF;
2116 IF NEW."active" THEN
2117 INSERT INTO "event" ("event", "member_id", "boolean_value")
2118 VALUES ('member_active', NEW."id", TRUE);
2119 END IF;
2120 ELSIF TG_OP = 'UPDATE' THEN
2121 IF OLD."id" != NEW."id" THEN
2122 RAISE EXCEPTION 'Cannot change member ID';
2123 END IF;
2124 IF
2125 (OLD."activated" ISNULL OR OLD."deleted" NOTNULL) AND
2126 NEW."activated" NOTNULL AND NEW."deleted" ISNULL
2127 THEN
2128 INSERT INTO "event" ("event", "member_id")
2129 VALUES ('member_activated', NEW."id");
2130 END IF;
2131 IF OLD."active" != NEW."active" THEN
2132 INSERT INTO "event" ("event", "member_id", "boolean_value") VALUES (
2133 'member_active', NEW."id", NEW."active"
2134 );
2135 END IF;
2136 IF OLD."name" != NEW."name" THEN
2137 INSERT INTO "event" (
2138 "event", "member_id", "text_value", "old_text_value"
2139 ) VALUES (
2140 'member_name_updated', NEW."id", NEW."name", OLD."name"
2141 );
2142 END IF;
2143 IF
2144 OLD."activated" NOTNULL AND OLD."deleted" ISNULL AND
2145 (NEW."activated" ISNULL OR NEW."deleted" NOTNULL)
2146 THEN
2147 INSERT INTO "event" ("event", "member_id")
2148 VALUES ('member_deleted', NEW."id");
2149 END IF;
2150 END IF;
2151 RETURN NULL;
2152 END;
2153 $$;
2155 CREATE TRIGGER "write_event_member"
2156 AFTER INSERT OR UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
2157 "write_event_member_trigger"();
2159 COMMENT ON FUNCTION "write_event_member_trigger"() IS 'Implementation of trigger "write_event_member" on table "member"';
2160 COMMENT ON TRIGGER "write_event_member" ON "member" IS 'Create entries in "event" table on insertion to member table';
2163 CREATE FUNCTION "write_event_member_profile_updated_trigger"()
2164 RETURNS TRIGGER
2165 LANGUAGE 'plpgsql' VOLATILE AS $$
2166 BEGIN
2167 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2168 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2169 INSERT INTO "event" ("event", "member_id") VALUES (
2170 'member_profile_updated', OLD."member_id"
2171 );
2172 END IF;
2173 END IF;
2174 IF TG_OP = 'UPDATE' THEN
2175 IF OLD."member_id" = NEW."member_id" THEN
2176 RETURN NULL;
2177 END IF;
2178 END IF;
2179 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2180 INSERT INTO "event" ("event", "member_id") VALUES (
2181 'member_profile_updated', NEW."member_id"
2182 );
2183 END IF;
2184 RETURN NULL;
2185 END;
2186 $$;
2188 CREATE TRIGGER "write_event_member_profile_updated"
2189 AFTER INSERT OR UPDATE OR DELETE ON "member_profile"
2190 FOR EACH ROW EXECUTE PROCEDURE
2191 "write_event_member_profile_updated_trigger"();
2193 COMMENT ON FUNCTION "write_event_member_profile_updated_trigger"() IS 'Implementation of trigger "write_event_member_profile_updated" on table "member_profile"';
2194 COMMENT ON TRIGGER "write_event_member_profile_updated" ON "member_profile" IS 'Creates entries in "event" table on member profile update';
2197 CREATE FUNCTION "write_event_member_image_updated_trigger"()
2198 RETURNS TRIGGER
2199 LANGUAGE 'plpgsql' VOLATILE AS $$
2200 BEGIN
2201 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2202 IF NOT OLD."scaled" THEN
2203 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2204 INSERT INTO "event" ("event", "member_id") VALUES (
2205 'member_image_updated', OLD."member_id"
2206 );
2207 END IF;
2208 END IF;
2209 END IF;
2210 IF TG_OP = 'UPDATE' THEN
2211 IF
2212 OLD."member_id" = NEW."member_id" AND
2213 OLD."scaled" = NEW."scaled"
2214 THEN
2215 RETURN NULL;
2216 END IF;
2217 END IF;
2218 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2219 IF NOT NEW."scaled" THEN
2220 INSERT INTO "event" ("event", "member_id") VALUES (
2221 'member_image_updated', NEW."member_id"
2222 );
2223 END IF;
2224 END IF;
2225 RETURN NULL;
2226 END;
2227 $$;
2229 CREATE TRIGGER "write_event_member_image_updated"
2230 AFTER INSERT OR UPDATE OR DELETE ON "member_image"
2231 FOR EACH ROW EXECUTE PROCEDURE
2232 "write_event_member_image_updated_trigger"();
2234 COMMENT ON FUNCTION "write_event_member_image_updated_trigger"() IS 'Implementation of trigger "write_event_member_image_updated" on table "member_image"';
2235 COMMENT ON TRIGGER "write_event_member_image_updated" ON "member_image" IS 'Creates entries in "event" table on member image update';
2238 CREATE FUNCTION "write_event_interest_trigger"()
2239 RETURNS TRIGGER
2240 LANGUAGE 'plpgsql' VOLATILE AS $$
2241 DECLARE
2242 "issue_row" "issue"%ROWTYPE;
2243 "area_row" "area"%ROWTYPE;
2244 BEGIN
2245 IF TG_OP = 'UPDATE' THEN
2246 IF OLD = NEW THEN
2247 RETURN NULL;
2248 END IF;
2249 END IF;
2250 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2251 SELECT * INTO "issue_row" FROM "issue"
2252 WHERE "id" = OLD."issue_id" FOR SHARE;
2253 SELECT * INTO "area_row" FROM "area"
2254 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2255 IF "issue_row"."id" NOTNULL THEN
2256 INSERT INTO "event" (
2257 "event", "member_id",
2258 "unit_id", "area_id", "policy_id", "issue_id", "state",
2259 "boolean_value"
2260 ) VALUES (
2261 'interest', OLD."member_id",
2262 "area_row"."unit_id", "issue_row"."area_id",
2263 "issue_row"."policy_id",
2264 OLD."issue_id", "issue_row"."state",
2265 FALSE
2266 );
2267 END IF;
2268 END IF;
2269 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2270 SELECT * INTO "issue_row" FROM "issue"
2271 WHERE "id" = NEW."issue_id" FOR SHARE;
2272 SELECT * INTO "area_row" FROM "area"
2273 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2274 INSERT INTO "event" (
2275 "event", "member_id",
2276 "unit_id", "area_id", "policy_id", "issue_id", "state",
2277 "boolean_value"
2278 ) VALUES (
2279 'interest', NEW."member_id",
2280 "area_row"."unit_id", "issue_row"."area_id",
2281 "issue_row"."policy_id",
2282 NEW."issue_id", "issue_row"."state",
2283 TRUE
2284 );
2285 END IF;
2286 RETURN NULL;
2287 END;
2288 $$;
2290 CREATE TRIGGER "write_event_interest"
2291 AFTER INSERT OR UPDATE OR DELETE ON "interest" FOR EACH ROW EXECUTE PROCEDURE
2292 "write_event_interest_trigger"();
2294 COMMENT ON FUNCTION "write_event_interest_trigger"() IS 'Implementation of trigger "write_event_interest_inserted" on table "interest"';
2295 COMMENT ON TRIGGER "write_event_interest" ON "interest" IS 'Create entry in "event" table on adding or removing interest';
2298 CREATE FUNCTION "write_event_initiator_trigger"()
2299 RETURNS TRIGGER
2300 LANGUAGE 'plpgsql' VOLATILE AS $$
2301 DECLARE
2302 "initiative_row" "initiative"%ROWTYPE;
2303 "issue_row" "issue"%ROWTYPE;
2304 "area_row" "area"%ROWTYPE;
2305 "accepted_v" BOOLEAN = FALSE;
2306 "rejected_v" BOOLEAN = FALSE;
2307 BEGIN
2308 IF TG_OP = 'UPDATE' THEN
2309 IF
2310 OLD."initiative_id" = NEW."initiative_id" AND
2311 OLD."member_id" = NEW."member_id"
2312 THEN
2313 IF
2314 coalesce(OLD."accepted", FALSE) = coalesce(NEW."accepted", FALSE)
2315 THEN
2316 RETURN NULL;
2317 END IF;
2318 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2319 "accepted_v" := TRUE;
2320 ELSE
2321 "rejected_v" := TRUE;
2322 END IF;
2323 END IF;
2324 END IF;
2325 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "accepted_v" THEN
2326 IF coalesce(OLD."accepted", FALSE) = TRUE THEN
2327 SELECT * INTO "initiative_row" FROM "initiative"
2328 WHERE "id" = OLD."initiative_id" FOR SHARE;
2329 IF "initiative_row"."id" NOTNULL THEN
2330 SELECT * INTO "issue_row" FROM "issue"
2331 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2332 SELECT * INTO "area_row" FROM "area"
2333 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2334 INSERT INTO "event" (
2335 "event", "member_id",
2336 "unit_id", "area_id", "policy_id", "issue_id", "state",
2337 "initiative_id", "boolean_value"
2338 ) VALUES (
2339 'initiator', OLD."member_id",
2340 "area_row"."unit_id", "issue_row"."area_id",
2341 "issue_row"."policy_id",
2342 "issue_row"."id", "issue_row"."state",
2343 OLD."initiative_id", FALSE
2344 );
2345 END IF;
2346 END IF;
2347 END IF;
2348 IF TG_OP = 'UPDATE' AND NOT "rejected_v" THEN
2349 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2350 SELECT * INTO "initiative_row" FROM "initiative"
2351 WHERE "id" = NEW."initiative_id" FOR SHARE;
2352 SELECT * INTO "issue_row" FROM "issue"
2353 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2354 SELECT * INTO "area_row" FROM "area"
2355 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2356 INSERT INTO "event" (
2357 "event", "member_id",
2358 "unit_id", "area_id", "policy_id", "issue_id", "state",
2359 "initiative_id", "boolean_value"
2360 ) VALUES (
2361 'initiator', NEW."member_id",
2362 "area_row"."unit_id", "issue_row"."area_id",
2363 "issue_row"."policy_id",
2364 "issue_row"."id", "issue_row"."state",
2365 NEW."initiative_id", TRUE
2366 );
2367 END IF;
2368 END IF;
2369 RETURN NULL;
2370 END;
2371 $$;
2373 CREATE TRIGGER "write_event_initiator"
2374 AFTER UPDATE OR DELETE ON "initiator" FOR EACH ROW EXECUTE PROCEDURE
2375 "write_event_initiator_trigger"();
2377 COMMENT ON FUNCTION "write_event_initiator_trigger"() IS 'Implementation of trigger "write_event_initiator" on table "initiator"';
2378 COMMENT ON TRIGGER "write_event_initiator" ON "initiator" IS 'Create entry in "event" table when accepting or removing initiatorship (NOTE: trigger does not fire on INSERT to avoid events on initiative creation)';
2381 CREATE FUNCTION "write_event_support_trigger"()
2382 RETURNS TRIGGER
2383 LANGUAGE 'plpgsql' VOLATILE AS $$
2384 DECLARE
2385 "issue_row" "issue"%ROWTYPE;
2386 "area_row" "area"%ROWTYPE;
2387 BEGIN
2388 IF TG_OP = 'UPDATE' THEN
2389 IF
2390 OLD."initiative_id" = NEW."initiative_id" AND
2391 OLD."member_id" = NEW."member_id"
2392 THEN
2393 IF OLD."draft_id" != NEW."draft_id" THEN
2394 SELECT * INTO "issue_row" FROM "issue"
2395 WHERE "id" = NEW."issue_id" FOR SHARE;
2396 SELECT * INTO "area_row" FROM "area"
2397 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2398 INSERT INTO "event" (
2399 "event", "member_id",
2400 "unit_id", "area_id", "policy_id", "issue_id", "state",
2401 "initiative_id", "draft_id"
2402 ) VALUES (
2403 'support_updated', NEW."member_id",
2404 "area_row"."unit_id", "issue_row"."area_id",
2405 "issue_row"."policy_id",
2406 "issue_row"."id", "issue_row"."state",
2407 NEW."initiative_id", NEW."draft_id"
2408 );
2409 END IF;
2410 RETURN NULL;
2411 END IF;
2412 END IF;
2413 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2414 IF EXISTS (
2415 SELECT NULL FROM "initiative" WHERE "id" = OLD."initiative_id"
2416 FOR SHARE
2417 ) THEN
2418 SELECT * INTO "issue_row" FROM "issue"
2419 WHERE "id" = OLD."issue_id" FOR SHARE;
2420 SELECT * INTO "area_row" FROM "area"
2421 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2422 INSERT INTO "event" (
2423 "event", "member_id",
2424 "unit_id", "area_id", "policy_id", "issue_id", "state",
2425 "initiative_id", "boolean_value"
2426 ) VALUES (
2427 'support', OLD."member_id",
2428 "area_row"."unit_id", "issue_row"."area_id",
2429 "issue_row"."policy_id",
2430 "issue_row"."id", "issue_row"."state",
2431 OLD."initiative_id", FALSE
2432 );
2433 END IF;
2434 END IF;
2435 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2436 SELECT * INTO "issue_row" FROM "issue"
2437 WHERE "id" = NEW."issue_id" FOR SHARE;
2438 SELECT * INTO "area_row" FROM "area"
2439 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2440 INSERT INTO "event" (
2441 "event", "member_id",
2442 "unit_id", "area_id", "policy_id", "issue_id", "state",
2443 "initiative_id", "draft_id", "boolean_value"
2444 ) VALUES (
2445 'support', NEW."member_id",
2446 "area_row"."unit_id", "issue_row"."area_id",
2447 "issue_row"."policy_id",
2448 "issue_row"."id", "issue_row"."state",
2449 NEW."initiative_id", NEW."draft_id", TRUE
2450 );
2451 END IF;
2452 RETURN NULL;
2453 END;
2454 $$;
2456 CREATE TRIGGER "write_event_support"
2457 AFTER INSERT OR UPDATE OR DELETE ON "supporter" FOR EACH ROW EXECUTE PROCEDURE
2458 "write_event_support_trigger"();
2460 COMMENT ON FUNCTION "write_event_support_trigger"() IS 'Implementation of trigger "write_event_support" on table "supporter"';
2461 COMMENT ON TRIGGER "write_event_support" ON "supporter" IS 'Create entry in "event" table when adding, updating, or removing support';
2464 CREATE FUNCTION "write_event_suggestion_rated_trigger"()
2465 RETURNS TRIGGER
2466 LANGUAGE 'plpgsql' VOLATILE AS $$
2467 DECLARE
2468 "same_pkey_v" BOOLEAN = FALSE;
2469 "initiative_row" "initiative"%ROWTYPE;
2470 "issue_row" "issue"%ROWTYPE;
2471 "area_row" "area"%ROWTYPE;
2472 BEGIN
2473 IF TG_OP = 'UPDATE' THEN
2474 IF
2475 OLD."suggestion_id" = NEW."suggestion_id" AND
2476 OLD."member_id" = NEW."member_id"
2477 THEN
2478 IF
2479 OLD."degree" = NEW."degree" AND
2480 OLD."fulfilled" = NEW."fulfilled"
2481 THEN
2482 RETURN NULL;
2483 END IF;
2484 "same_pkey_v" := TRUE;
2485 END IF;
2486 END IF;
2487 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "same_pkey_v" THEN
2488 IF EXISTS (
2489 SELECT NULL FROM "suggestion" WHERE "id" = OLD."suggestion_id"
2490 FOR SHARE
2491 ) THEN
2492 SELECT * INTO "initiative_row" FROM "initiative"
2493 WHERE "id" = OLD."initiative_id" FOR SHARE;
2494 SELECT * INTO "issue_row" FROM "issue"
2495 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2496 SELECT * INTO "area_row" FROM "area"
2497 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2498 INSERT INTO "event" (
2499 "event", "member_id",
2500 "unit_id", "area_id", "policy_id", "issue_id", "state",
2501 "initiative_id", "suggestion_id",
2502 "boolean_value", "numeric_value"
2503 ) VALUES (
2504 'suggestion_rated', OLD."member_id",
2505 "area_row"."unit_id", "issue_row"."area_id",
2506 "issue_row"."policy_id",
2507 "initiative_row"."issue_id", "issue_row"."state",
2508 OLD."initiative_id", OLD."suggestion_id",
2509 NULL, 0
2510 );
2511 END IF;
2512 END IF;
2513 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2514 SELECT * INTO "initiative_row" FROM "initiative"
2515 WHERE "id" = NEW."initiative_id" FOR SHARE;
2516 SELECT * INTO "issue_row" FROM "issue"
2517 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2518 SELECT * INTO "area_row" FROM "area"
2519 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2520 INSERT INTO "event" (
2521 "event", "member_id",
2522 "unit_id", "area_id", "policy_id", "issue_id", "state",
2523 "initiative_id", "suggestion_id",
2524 "boolean_value", "numeric_value"
2525 ) VALUES (
2526 'suggestion_rated', NEW."member_id",
2527 "area_row"."unit_id", "issue_row"."area_id",
2528 "issue_row"."policy_id",
2529 "initiative_row"."issue_id", "issue_row"."state",
2530 NEW."initiative_id", NEW."suggestion_id",
2531 NEW."fulfilled", NEW."degree"
2532 );
2533 END IF;
2534 RETURN NULL;
2535 END;
2536 $$;
2538 CREATE TRIGGER "write_event_suggestion_rated"
2539 AFTER INSERT OR UPDATE OR DELETE ON "opinion" FOR EACH ROW EXECUTE PROCEDURE
2540 "write_event_suggestion_rated_trigger"();
2542 COMMENT ON FUNCTION "write_event_suggestion_rated_trigger"() IS 'Implementation of trigger "write_event_suggestion_rated" on table "opinion"';
2543 COMMENT ON TRIGGER "write_event_suggestion_rated" ON "opinion" IS 'Create entry in "event" table when adding, updating, or removing support';
2546 CREATE FUNCTION "write_event_delegation_trigger"()
2547 RETURNS TRIGGER
2548 LANGUAGE 'plpgsql' VOLATILE AS $$
2549 DECLARE
2550 "issue_row" "issue"%ROWTYPE;
2551 "area_row" "area"%ROWTYPE;
2552 BEGIN
2553 IF TG_OP = 'DELETE' THEN
2554 IF EXISTS (
2555 SELECT NULL FROM "member" WHERE "id" = OLD."truster_id"
2556 ) AND (CASE OLD."scope"
2557 WHEN 'unit'::"delegation_scope" THEN EXISTS (
2558 SELECT NULL FROM "unit" WHERE "id" = OLD."unit_id"
2560 WHEN 'area'::"delegation_scope" THEN EXISTS (
2561 SELECT NULL FROM "area" WHERE "id" = OLD."area_id"
2563 WHEN 'issue'::"delegation_scope" THEN EXISTS (
2564 SELECT NULL FROM "issue" WHERE "id" = OLD."issue_id"
2566 END) THEN
2567 SELECT * INTO "issue_row" FROM "issue"
2568 WHERE "id" = OLD."issue_id" FOR SHARE;
2569 SELECT * INTO "area_row" FROM "area"
2570 WHERE "id" = COALESCE(OLD."area_id", "issue_row"."area_id")
2571 FOR SHARE;
2572 INSERT INTO "event" (
2573 "event", "member_id", "scope",
2574 "unit_id", "area_id", "issue_id", "state",
2575 "boolean_value"
2576 ) VALUES (
2577 'delegation', OLD."truster_id", OLD."scope",
2578 COALESCE(OLD."unit_id", "area_row"."unit_id"), "area_row"."id",
2579 OLD."issue_id", "issue_row"."state",
2580 FALSE
2581 );
2582 END IF;
2583 ELSE
2584 SELECT * INTO "issue_row" FROM "issue"
2585 WHERE "id" = NEW."issue_id" FOR SHARE;
2586 SELECT * INTO "area_row" FROM "area"
2587 WHERE "id" = COALESCE(NEW."area_id", "issue_row"."area_id")
2588 FOR SHARE;
2589 INSERT INTO "event" (
2590 "event", "member_id", "other_member_id", "scope",
2591 "unit_id", "area_id", "issue_id", "state",
2592 "boolean_value"
2593 ) VALUES (
2594 'delegation', NEW."truster_id", NEW."trustee_id", NEW."scope",
2595 COALESCE(NEW."unit_id", "area_row"."unit_id"), "area_row"."id",
2596 NEW."issue_id", "issue_row"."state",
2597 TRUE
2598 );
2599 END IF;
2600 RETURN NULL;
2601 END;
2602 $$;
2604 CREATE TRIGGER "write_event_delegation"
2605 AFTER INSERT OR UPDATE OR DELETE ON "delegation" FOR EACH ROW EXECUTE PROCEDURE
2606 "write_event_delegation_trigger"();
2608 COMMENT ON FUNCTION "write_event_delegation_trigger"() IS 'Implementation of trigger "write_event_delegation" on table "delegation"';
2609 COMMENT ON TRIGGER "write_event_delegation" ON "delegation" IS 'Create entry in "event" table when adding, updating, or removing a delegation';
2612 CREATE FUNCTION "write_event_contact_trigger"()
2613 RETURNS TRIGGER
2614 LANGUAGE 'plpgsql' VOLATILE AS $$
2615 BEGIN
2616 IF TG_OP = 'UPDATE' THEN
2617 IF
2618 OLD."member_id" = NEW."member_id" AND
2619 OLD."other_member_id" = NEW."other_member_id" AND
2620 OLD."public" = NEW."public"
2621 THEN
2622 RETURN NULL;
2623 END IF;
2624 END IF;
2625 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2626 IF OLD."public" THEN
2627 IF EXISTS (
2628 SELECT NULL FROM "member" WHERE "id" = OLD."member_id"
2629 FOR SHARE
2630 ) AND EXISTS (
2631 SELECT NULL FROM "member" WHERE "id" = OLD."other_member_id"
2632 FOR SHARE
2633 ) THEN
2634 INSERT INTO "event" (
2635 "event", "member_id", "other_member_id", "boolean_value"
2636 ) VALUES (
2637 'contact', OLD."member_id", OLD."other_member_id", FALSE
2638 );
2639 END IF;
2640 END IF;
2641 END IF;
2642 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2643 IF NEW."public" THEN
2644 INSERT INTO "event" (
2645 "event", "member_id", "other_member_id", "boolean_value"
2646 ) VALUES (
2647 'contact', NEW."member_id", NEW."other_member_id", TRUE
2648 );
2649 END IF;
2650 END IF;
2651 RETURN NULL;
2652 END;
2653 $$;
2655 CREATE TRIGGER "write_event_contact"
2656 AFTER INSERT OR UPDATE OR DELETE ON "contact" FOR EACH ROW EXECUTE PROCEDURE
2657 "write_event_contact_trigger"();
2659 COMMENT ON FUNCTION "write_event_contact_trigger"() IS 'Implementation of trigger "write_event_contact" on table "contact"';
2660 COMMENT ON TRIGGER "write_event_contact" ON "contact" IS 'Create entry in "event" table when adding or removing public contacts';
2663 CREATE FUNCTION "send_event_notify_trigger"()
2664 RETURNS TRIGGER
2665 LANGUAGE 'plpgsql' VOLATILE AS $$
2666 BEGIN
2667 EXECUTE 'NOTIFY "event", ''' || NEW."event" || '''';
2668 RETURN NULL;
2669 END;
2670 $$;
2672 CREATE TRIGGER "send_notify"
2673 AFTER INSERT OR UPDATE ON "event" FOR EACH ROW EXECUTE PROCEDURE
2674 "send_event_notify_trigger"();
2678 ----------------------------
2679 -- Additional constraints --
2680 ----------------------------
2683 CREATE FUNCTION "delete_extended_scope_tokens_trigger"()
2684 RETURNS TRIGGER
2685 LANGUAGE 'plpgsql' VOLATILE AS $$
2686 DECLARE
2687 "system_application_row" "system_application"%ROWTYPE;
2688 BEGIN
2689 IF OLD."system_application_id" NOTNULL THEN
2690 SELECT * FROM "system_application" INTO "system_application_row"
2691 WHERE "id" = OLD."system_application_id";
2692 DELETE FROM "token"
2693 WHERE "member_id" = OLD."member_id"
2694 AND "system_application_id" = OLD."system_application_id"
2695 AND NOT COALESCE(
2696 regexp_split_to_array("scope", E'\\s+') <@
2697 regexp_split_to_array(
2698 "system_application_row"."automatic_scope", E'\\s+'
2699 ),
2700 FALSE
2701 );
2702 END IF;
2703 RETURN OLD;
2704 END;
2705 $$;
2707 CREATE TRIGGER "delete_extended_scope_tokens"
2708 BEFORE DELETE ON "member_application" FOR EACH ROW EXECUTE PROCEDURE
2709 "delete_extended_scope_tokens_trigger"();
2712 CREATE FUNCTION "detach_token_from_session_trigger"()
2713 RETURNS TRIGGER
2714 LANGUAGE 'plpgsql' VOLATILE AS $$
2715 BEGIN
2716 UPDATE "token" SET "session_id" = NULL
2717 WHERE "session_id" = OLD."id";
2718 RETURN OLD;
2719 END;
2720 $$;
2722 CREATE TRIGGER "detach_token_from_session"
2723 BEFORE DELETE ON "session" FOR EACH ROW EXECUTE PROCEDURE
2724 "detach_token_from_session_trigger"();
2727 CREATE FUNCTION "delete_non_detached_scope_with_session_trigger"()
2728 RETURNS TRIGGER
2729 LANGUAGE 'plpgsql' VOLATILE AS $$
2730 BEGIN
2731 IF NEW."session_id" ISNULL THEN
2732 SELECT coalesce(string_agg("element", ' '), '') INTO NEW."scope"
2733 FROM unnest(regexp_split_to_array(NEW."scope", E'\\s+')) AS "element"
2734 WHERE "element" LIKE '%_detached';
2735 END IF;
2736 RETURN NEW;
2737 END;
2738 $$;
2740 CREATE TRIGGER "delete_non_detached_scope_with_session"
2741 BEFORE INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2742 "delete_non_detached_scope_with_session_trigger"();
2745 CREATE FUNCTION "delete_token_with_empty_scope_trigger"()
2746 RETURNS TRIGGER
2747 LANGUAGE 'plpgsql' VOLATILE AS $$
2748 BEGIN
2749 IF NEW."scope" = '' THEN
2750 DELETE FROM "token" WHERE "id" = NEW."id";
2751 END IF;
2752 RETURN NULL;
2753 END;
2754 $$;
2756 CREATE TRIGGER "delete_token_with_empty_scope"
2757 AFTER INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2758 "delete_token_with_empty_scope_trigger"();
2761 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
2762 RETURNS TRIGGER
2763 LANGUAGE 'plpgsql' VOLATILE AS $$
2764 BEGIN
2765 IF NOT EXISTS (
2766 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
2767 ) THEN
2768 RAISE EXCEPTION 'Cannot create issue without an initial initiative.' USING
2769 ERRCODE = 'integrity_constraint_violation',
2770 HINT = 'Create issue, initiative, and draft within the same transaction.';
2771 END IF;
2772 RETURN NULL;
2773 END;
2774 $$;
2776 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
2777 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
2778 FOR EACH ROW EXECUTE PROCEDURE
2779 "issue_requires_first_initiative_trigger"();
2781 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
2782 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
2785 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
2786 RETURNS TRIGGER
2787 LANGUAGE 'plpgsql' VOLATILE AS $$
2788 DECLARE
2789 "reference_lost" BOOLEAN;
2790 BEGIN
2791 IF TG_OP = 'DELETE' THEN
2792 "reference_lost" := TRUE;
2793 ELSE
2794 "reference_lost" := NEW."issue_id" != OLD."issue_id";
2795 END IF;
2796 IF
2797 "reference_lost" AND NOT EXISTS (
2798 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
2800 THEN
2801 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
2802 END IF;
2803 RETURN NULL;
2804 END;
2805 $$;
2807 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
2808 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
2809 FOR EACH ROW EXECUTE PROCEDURE
2810 "last_initiative_deletes_issue_trigger"();
2812 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
2813 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
2816 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
2817 RETURNS TRIGGER
2818 LANGUAGE 'plpgsql' VOLATILE AS $$
2819 BEGIN
2820 IF NOT EXISTS (
2821 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
2822 ) THEN
2823 RAISE EXCEPTION 'Cannot create initiative without an initial draft.' USING
2824 ERRCODE = 'integrity_constraint_violation',
2825 HINT = 'Create issue, initiative and draft within the same transaction.';
2826 END IF;
2827 RETURN NULL;
2828 END;
2829 $$;
2831 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
2832 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
2833 FOR EACH ROW EXECUTE PROCEDURE
2834 "initiative_requires_first_draft_trigger"();
2836 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
2837 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
2840 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
2841 RETURNS TRIGGER
2842 LANGUAGE 'plpgsql' VOLATILE AS $$
2843 DECLARE
2844 "reference_lost" BOOLEAN;
2845 BEGIN
2846 IF TG_OP = 'DELETE' THEN
2847 "reference_lost" := TRUE;
2848 ELSE
2849 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
2850 END IF;
2851 IF
2852 "reference_lost" AND NOT EXISTS (
2853 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
2855 THEN
2856 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
2857 END IF;
2858 RETURN NULL;
2859 END;
2860 $$;
2862 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
2863 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
2864 FOR EACH ROW EXECUTE PROCEDURE
2865 "last_draft_deletes_initiative_trigger"();
2867 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
2868 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
2871 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
2872 RETURNS TRIGGER
2873 LANGUAGE 'plpgsql' VOLATILE AS $$
2874 BEGIN
2875 IF NOT EXISTS (
2876 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
2877 ) THEN
2878 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.' USING
2879 ERRCODE = 'integrity_constraint_violation',
2880 HINT = 'Create suggestion and opinion within the same transaction.';
2881 END IF;
2882 RETURN NULL;
2883 END;
2884 $$;
2886 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
2887 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
2888 FOR EACH ROW EXECUTE PROCEDURE
2889 "suggestion_requires_first_opinion_trigger"();
2891 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
2892 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
2895 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
2896 RETURNS TRIGGER
2897 LANGUAGE 'plpgsql' VOLATILE AS $$
2898 DECLARE
2899 "reference_lost" BOOLEAN;
2900 BEGIN
2901 IF TG_OP = 'DELETE' THEN
2902 "reference_lost" := TRUE;
2903 ELSE
2904 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
2905 END IF;
2906 IF
2907 "reference_lost" AND NOT EXISTS (
2908 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
2910 THEN
2911 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
2912 END IF;
2913 RETURN NULL;
2914 END;
2915 $$;
2917 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
2918 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
2919 FOR EACH ROW EXECUTE PROCEDURE
2920 "last_opinion_deletes_suggestion_trigger"();
2922 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
2923 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
2926 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
2927 RETURNS TRIGGER
2928 LANGUAGE 'plpgsql' VOLATILE AS $$
2929 BEGIN
2930 DELETE FROM "direct_voter"
2931 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
2932 RETURN NULL;
2933 END;
2934 $$;
2936 CREATE TRIGGER "non_voter_deletes_direct_voter"
2937 AFTER INSERT OR UPDATE ON "non_voter"
2938 FOR EACH ROW EXECUTE PROCEDURE
2939 "non_voter_deletes_direct_voter_trigger"();
2941 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
2942 COMMENT ON TRIGGER "non_voter_deletes_direct_voter" ON "non_voter" IS 'An entry in the "non_voter" table deletes an entry in the "direct_voter" table (and vice versa due to trigger "direct_voter_deletes_non_voter" on table "direct_voter")';
2945 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
2946 RETURNS TRIGGER
2947 LANGUAGE 'plpgsql' VOLATILE AS $$
2948 BEGIN
2949 DELETE FROM "non_voter"
2950 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
2951 RETURN NULL;
2952 END;
2953 $$;
2955 CREATE TRIGGER "direct_voter_deletes_non_voter"
2956 AFTER INSERT OR UPDATE ON "direct_voter"
2957 FOR EACH ROW EXECUTE PROCEDURE
2958 "direct_voter_deletes_non_voter_trigger"();
2960 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
2961 COMMENT ON TRIGGER "direct_voter_deletes_non_voter" ON "direct_voter" IS 'An entry in the "direct_voter" table deletes an entry in the "non_voter" table (and vice versa due to trigger "non_voter_deletes_direct_voter" on table "non_voter")';
2964 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
2965 RETURNS TRIGGER
2966 LANGUAGE 'plpgsql' VOLATILE AS $$
2967 BEGIN
2968 IF NEW."comment" ISNULL THEN
2969 NEW."comment_changed" := NULL;
2970 NEW."formatting_engine" := NULL;
2971 END IF;
2972 RETURN NEW;
2973 END;
2974 $$;
2976 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
2977 BEFORE INSERT OR UPDATE ON "direct_voter"
2978 FOR EACH ROW EXECUTE PROCEDURE
2979 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
2981 COMMENT ON FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"() IS 'Implementation of trigger "voter_comment_fields_only_set_when_voter_comment_is_set" ON table "direct_voter"';
2982 COMMENT ON TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set" ON "direct_voter" IS 'If "comment" is set to NULL, then other comment related fields are also set to NULL.';
2986 ---------------------------------
2987 -- Delete incomplete snapshots --
2988 ---------------------------------
2991 CREATE FUNCTION "delete_snapshot_on_partial_delete_trigger"()
2992 RETURNS TRIGGER
2993 LANGUAGE 'plpgsql' VOLATILE AS $$
2994 BEGIN
2995 IF TG_OP = 'UPDATE' THEN
2996 IF
2997 OLD."snapshot_id" = NEW."snapshot_id" AND
2998 OLD."issue_id" = NEW."issue_id"
2999 THEN
3000 RETURN NULL;
3001 END IF;
3002 END IF;
3003 DELETE FROM "snapshot" WHERE "id" = OLD."snapshot_id";
3004 RETURN NULL;
3005 END;
3006 $$;
3008 CREATE TRIGGER "delete_snapshot_on_partial_delete"
3009 AFTER UPDATE OR DELETE ON "snapshot_issue"
3010 FOR EACH ROW EXECUTE PROCEDURE
3011 "delete_snapshot_on_partial_delete_trigger"();
3013 COMMENT ON FUNCTION "delete_snapshot_on_partial_delete_trigger"() IS 'Implementation of trigger "delete_snapshot_on_partial_delete" on table "snapshot_issue"';
3014 COMMENT ON TRIGGER "delete_snapshot_on_partial_delete" ON "snapshot_issue" IS 'Deletes whole snapshot if one issue is deleted from the snapshot';
3018 ---------------------------------------------------------------
3019 -- Ensure that votes are not modified when issues are closed --
3020 ---------------------------------------------------------------
3022 -- NOTE: Frontends should ensure this anyway, but in case of programming
3023 -- errors the following triggers ensure data integrity.
3026 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
3027 RETURNS TRIGGER
3028 LANGUAGE 'plpgsql' VOLATILE AS $$
3029 DECLARE
3030 "issue_id_v" "issue"."id"%TYPE;
3031 "issue_row" "issue"%ROWTYPE;
3032 BEGIN
3033 IF EXISTS (
3034 SELECT NULL FROM "temporary_transaction_data"
3035 WHERE "txid" = txid_current()
3036 AND "key" = 'override_protection_triggers'
3037 AND "value" = TRUE::TEXT
3038 ) THEN
3039 RETURN NULL;
3040 END IF;
3041 IF TG_OP = 'DELETE' THEN
3042 "issue_id_v" := OLD."issue_id";
3043 ELSE
3044 "issue_id_v" := NEW."issue_id";
3045 END IF;
3046 SELECT INTO "issue_row" * FROM "issue"
3047 WHERE "id" = "issue_id_v" FOR SHARE;
3048 IF (
3049 "issue_row"."closed" NOTNULL OR (
3050 "issue_row"."state" = 'voting' AND
3051 "issue_row"."phase_finished" NOTNULL
3053 ) THEN
3054 IF
3055 TG_RELID = 'direct_voter'::regclass AND
3056 TG_OP = 'UPDATE'
3057 THEN
3058 IF
3059 OLD."issue_id" = NEW."issue_id" AND
3060 OLD."member_id" = NEW."member_id" AND
3061 OLD."weight" = NEW."weight"
3062 THEN
3063 RETURN NULL; -- allows changing of voter comment
3064 END IF;
3065 END IF;
3066 RAISE EXCEPTION 'Tried to modify data after voting has been closed.' USING
3067 ERRCODE = 'integrity_constraint_violation';
3068 END IF;
3069 RETURN NULL;
3070 END;
3071 $$;
3073 CREATE TRIGGER "forbid_changes_on_closed_issue"
3074 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
3075 FOR EACH ROW EXECUTE PROCEDURE
3076 "forbid_changes_on_closed_issue_trigger"();
3078 CREATE TRIGGER "forbid_changes_on_closed_issue"
3079 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
3080 FOR EACH ROW EXECUTE PROCEDURE
3081 "forbid_changes_on_closed_issue_trigger"();
3083 CREATE TRIGGER "forbid_changes_on_closed_issue"
3084 AFTER INSERT OR UPDATE OR DELETE ON "vote"
3085 FOR EACH ROW EXECUTE PROCEDURE
3086 "forbid_changes_on_closed_issue_trigger"();
3088 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"';
3089 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';
3090 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';
3091 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';
3095 --------------------------------------------------------------------
3096 -- Auto-retrieval of fields only needed for referential integrity --
3097 --------------------------------------------------------------------
3100 CREATE FUNCTION "autofill_issue_id_trigger"()
3101 RETURNS TRIGGER
3102 LANGUAGE 'plpgsql' VOLATILE AS $$
3103 BEGIN
3104 IF NEW."issue_id" ISNULL THEN
3105 SELECT "issue_id" INTO NEW."issue_id"
3106 FROM "initiative" WHERE "id" = NEW."initiative_id";
3107 END IF;
3108 RETURN NEW;
3109 END;
3110 $$;
3112 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
3113 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3115 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
3116 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3118 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
3119 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
3120 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
3123 CREATE FUNCTION "autofill_initiative_id_trigger"()
3124 RETURNS TRIGGER
3125 LANGUAGE 'plpgsql' VOLATILE AS $$
3126 BEGIN
3127 IF NEW."initiative_id" ISNULL THEN
3128 SELECT "initiative_id" INTO NEW."initiative_id"
3129 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3130 END IF;
3131 RETURN NEW;
3132 END;
3133 $$;
3135 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
3136 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
3138 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
3139 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
3143 -------------------------------------------------------
3144 -- Automatic copying of values for indexing purposes --
3145 -------------------------------------------------------
3148 CREATE FUNCTION "copy_current_draft_data"
3149 ("initiative_id_p" "initiative"."id"%TYPE )
3150 RETURNS VOID
3151 LANGUAGE 'plpgsql' VOLATILE AS $$
3152 BEGIN
3153 PERFORM NULL FROM "initiative" WHERE "id" = "initiative_id_p"
3154 FOR UPDATE;
3155 UPDATE "initiative" SET
3156 "location" = "draft"."location",
3157 "draft_text_search_data" = "draft"."text_search_data"
3158 FROM "current_draft" AS "draft"
3159 WHERE "initiative"."id" = "initiative_id_p"
3160 AND "draft"."initiative_id" = "initiative_id_p";
3161 END;
3162 $$;
3164 COMMENT ON FUNCTION "copy_current_draft_data"
3165 ( "initiative"."id"%TYPE )
3166 IS 'Helper function for function "copy_current_draft_data_trigger"';
3169 CREATE FUNCTION "copy_current_draft_data_trigger"()
3170 RETURNS TRIGGER
3171 LANGUAGE 'plpgsql' VOLATILE AS $$
3172 BEGIN
3173 IF TG_OP='DELETE' THEN
3174 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3175 ELSE
3176 IF TG_OP='UPDATE' THEN
3177 IF COALESCE(OLD."inititiave_id" != NEW."initiative_id", TRUE) THEN
3178 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3179 END IF;
3180 END IF;
3181 PERFORM "copy_current_draft_data"(NEW."initiative_id");
3182 END IF;
3183 RETURN NULL;
3184 END;
3185 $$;
3187 CREATE TRIGGER "copy_current_draft_data"
3188 AFTER INSERT OR UPDATE OR DELETE ON "draft"
3189 FOR EACH ROW EXECUTE PROCEDURE
3190 "copy_current_draft_data_trigger"();
3192 COMMENT ON FUNCTION "copy_current_draft_data_trigger"() IS 'Implementation of trigger "copy_current_draft_data" on table "draft"';
3193 COMMENT ON TRIGGER "copy_current_draft_data" ON "draft" IS 'Copy certain fields from most recent "draft" to "initiative"';
3197 -----------------------------------------------------
3198 -- Automatic calculation of certain default values --
3199 -----------------------------------------------------
3202 CREATE FUNCTION "copy_timings_trigger"()
3203 RETURNS TRIGGER
3204 LANGUAGE 'plpgsql' VOLATILE AS $$
3205 DECLARE
3206 "policy_row" "policy"%ROWTYPE;
3207 BEGIN
3208 SELECT * INTO "policy_row" FROM "policy"
3209 WHERE "id" = NEW."policy_id";
3210 IF NEW."min_admission_time" ISNULL THEN
3211 NEW."min_admission_time" := "policy_row"."min_admission_time";
3212 END IF;
3213 IF NEW."max_admission_time" ISNULL THEN
3214 NEW."max_admission_time" := "policy_row"."max_admission_time";
3215 END IF;
3216 IF NEW."discussion_time" ISNULL THEN
3217 NEW."discussion_time" := "policy_row"."discussion_time";
3218 END IF;
3219 IF NEW."verification_time" ISNULL THEN
3220 NEW."verification_time" := "policy_row"."verification_time";
3221 END IF;
3222 IF NEW."voting_time" ISNULL THEN
3223 NEW."voting_time" := "policy_row"."voting_time";
3224 END IF;
3225 RETURN NEW;
3226 END;
3227 $$;
3229 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
3230 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
3232 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
3233 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
3236 CREATE FUNCTION "default_for_draft_id_trigger"()
3237 RETURNS TRIGGER
3238 LANGUAGE 'plpgsql' VOLATILE AS $$
3239 BEGIN
3240 IF NEW."draft_id" ISNULL THEN
3241 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
3242 WHERE "initiative_id" = NEW."initiative_id";
3243 END IF;
3244 RETURN NEW;
3245 END;
3246 $$;
3248 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
3249 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3250 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
3251 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3253 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
3254 COMMENT ON TRIGGER "default_for_draft_id" ON "suggestion" IS 'If "draft_id" is NULL, then use the current draft of the initiative as default';
3255 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';
3259 ----------------------------------------
3260 -- Automatic creation of dependencies --
3261 ----------------------------------------
3264 CREATE FUNCTION "autocreate_interest_trigger"()
3265 RETURNS TRIGGER
3266 LANGUAGE 'plpgsql' VOLATILE AS $$
3267 BEGIN
3268 IF NOT EXISTS (
3269 SELECT NULL FROM "initiative" JOIN "interest"
3270 ON "initiative"."issue_id" = "interest"."issue_id"
3271 WHERE "initiative"."id" = NEW."initiative_id"
3272 AND "interest"."member_id" = NEW."member_id"
3273 ) THEN
3274 BEGIN
3275 INSERT INTO "interest" ("issue_id", "member_id")
3276 SELECT "issue_id", NEW."member_id"
3277 FROM "initiative" WHERE "id" = NEW."initiative_id";
3278 EXCEPTION WHEN unique_violation THEN END;
3279 END IF;
3280 RETURN NEW;
3281 END;
3282 $$;
3284 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
3285 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
3287 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
3288 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';
3291 CREATE FUNCTION "autocreate_supporter_trigger"()
3292 RETURNS TRIGGER
3293 LANGUAGE 'plpgsql' VOLATILE AS $$
3294 BEGIN
3295 IF NOT EXISTS (
3296 SELECT NULL FROM "suggestion" JOIN "supporter"
3297 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
3298 WHERE "suggestion"."id" = NEW."suggestion_id"
3299 AND "supporter"."member_id" = NEW."member_id"
3300 ) THEN
3301 BEGIN
3302 INSERT INTO "supporter" ("initiative_id", "member_id")
3303 SELECT "initiative_id", NEW."member_id"
3304 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3305 EXCEPTION WHEN unique_violation THEN END;
3306 END IF;
3307 RETURN NEW;
3308 END;
3309 $$;
3311 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
3312 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
3314 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
3315 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.';
3319 ------------------------------------------
3320 -- Views and helper functions for views --
3321 ------------------------------------------
3324 CREATE VIEW "member_eligible_to_be_notified" AS
3325 SELECT * FROM "member"
3326 WHERE "activated" NOTNULL AND "locked" = FALSE;
3328 COMMENT ON VIEW "member_eligible_to_be_notified" IS 'Filtered "member" table containing only activated and non-locked members (used as helper view for "member_to_notify" and "newsletter_to_send")';
3331 CREATE VIEW "member_to_notify" AS
3332 SELECT * FROM "member_eligible_to_be_notified"
3333 WHERE "disable_notifications" = FALSE;
3335 COMMENT ON VIEW "member_to_notify" IS 'Filtered "member" table containing only members that are eligible to and wish to receive notifications; NOTE: "notify_email" may still be NULL and might need to be checked by frontend (this allows other means of messaging)';
3338 CREATE VIEW "area_quorum" AS
3339 SELECT
3340 "area"."id" AS "area_id",
3341 ceil(
3342 "area"."quorum_standard"::FLOAT8 * "quorum_factor"::FLOAT8 ^ (
3343 coalesce(
3344 ( SELECT sum(
3345 ( extract(epoch from "area"."quorum_time")::FLOAT8 /
3346 extract(epoch from
3347 ("issue"."accepted"-"issue"."created") +
3348 "issue"."discussion_time" +
3349 "issue"."verification_time" +
3350 "issue"."voting_time"
3351 )::FLOAT8
3352 ) ^ "area"."quorum_exponent"::FLOAT8
3354 FROM "issue" JOIN "policy"
3355 ON "issue"."policy_id" = "policy"."id"
3356 WHERE "issue"."area_id" = "area"."id"
3357 AND "issue"."accepted" NOTNULL
3358 AND "issue"."closed" ISNULL
3359 AND "policy"."polling" = FALSE
3360 )::FLOAT8, 0::FLOAT8
3361 ) / "area"."quorum_issues"::FLOAT8 - 1::FLOAT8
3362 ) * CASE WHEN "area"."quorum_den" ISNULL THEN 1 ELSE (
3363 SELECT "snapshot"."population"
3364 FROM "snapshot"
3365 WHERE "snapshot"."area_id" = "area"."id"
3366 AND "snapshot"."issue_id" ISNULL
3367 ORDER BY "snapshot"."id" DESC
3368 LIMIT 1
3369 ) END / coalesce("area"."quorum_den", 1)
3371 )::INT4 AS "issue_quorum"
3372 FROM "area";
3374 COMMENT ON VIEW "area_quorum" IS 'Area-based quorum considering number of open (accepted) issues';
3377 CREATE VIEW "issue_quorum" AS
3378 SELECT DISTINCT ON ("issue_id")
3379 "issue"."id" AS "issue_id",
3380 "subquery"."issue_quorum"
3381 FROM "issue"
3382 CROSS JOIN LATERAL (
3383 SELECT "area_quorum"."issue_quorum"
3384 FROM "area_quorum" WHERE "area_quorum"."area_id" = "issue"."area_id"
3385 UNION ALL
3386 SELECT "policy"."issue_quorum"
3387 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3388 UNION ALL
3389 SELECT
3390 ceil(
3391 ("issue"."population"::INT8 * "policy"."issue_quorum_num"::INT8) /
3392 "policy"."issue_quorum_den"::FLOAT8
3393 )::INT4
3394 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3395 ) AS "subquery"
3396 ORDER BY "issue_id", "issue_quorum" DESC;
3398 COMMENT ON VIEW "issue_quorum" IS 'Effective quorum for issue admission';
3401 CREATE VIEW "area_with_unaccepted_issues" AS
3402 SELECT DISTINCT ON ("area"."id") "area".*
3403 FROM "area" JOIN "issue" ON "area"."id" = "issue"."area_id"
3404 WHERE "issue"."state" = 'admission';
3406 COMMENT ON VIEW "area_with_unaccepted_issues" IS 'All areas with unaccepted open issues (needed for issue admission system)';
3409 CREATE VIEW "issue_for_admission" AS
3410 SELECT DISTINCT ON ("issue"."area_id")
3411 "issue".*,
3412 max("initiative"."supporter_count") AS "max_supporter_count"
3413 FROM "issue"
3414 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
3415 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
3416 JOIN "area" ON "issue"."area_id" = "area"."id"
3417 WHERE "issue"."state" = 'admission'::"issue_state"
3418 AND now() >= "issue"."created" + "issue"."min_admission_time"
3419 AND "initiative"."supporter_count" >= "policy"."issue_quorum"
3420 AND "initiative"."supporter_count" * "policy"."issue_quorum_den" >=
3421 "issue"."population" * "policy"."issue_quorum_num"
3422 AND "initiative"."supporter_count" >= "area"."issue_quorum"
3423 AND "initiative"."revoked" ISNULL
3424 GROUP BY "issue"."id"
3425 ORDER BY "issue"."area_id", "max_supporter_count" DESC, "issue"."id";
3427 COMMENT ON VIEW "issue_for_admission" IS 'Contains up to 1 issue per area eligible to pass from ''admission'' to ''discussion'' state; needs to be recalculated after admitting the issue in this view';
3430 CREATE VIEW "unit_delegation" AS
3431 SELECT
3432 "unit"."id" AS "unit_id",
3433 "delegation"."id",
3434 "delegation"."truster_id",
3435 "delegation"."trustee_id",
3436 "delegation"."scope"
3437 FROM "unit"
3438 JOIN "delegation"
3439 ON "delegation"."unit_id" = "unit"."id"
3440 JOIN "member"
3441 ON "delegation"."truster_id" = "member"."id"
3442 JOIN "privilege"
3443 ON "delegation"."unit_id" = "privilege"."unit_id"
3444 AND "delegation"."truster_id" = "privilege"."member_id"
3445 WHERE "member"."active" AND "privilege"."voting_right";
3447 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
3450 CREATE VIEW "area_delegation" AS
3451 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
3452 "area"."id" AS "area_id",
3453 "delegation"."id",
3454 "delegation"."truster_id",
3455 "delegation"."trustee_id",
3456 "delegation"."scope"
3457 FROM "area"
3458 JOIN "delegation"
3459 ON "delegation"."unit_id" = "area"."unit_id"
3460 OR "delegation"."area_id" = "area"."id"
3461 JOIN "member"
3462 ON "delegation"."truster_id" = "member"."id"
3463 JOIN "privilege"
3464 ON "area"."unit_id" = "privilege"."unit_id"
3465 AND "delegation"."truster_id" = "privilege"."member_id"
3466 WHERE "member"."active" AND "privilege"."voting_right"
3467 ORDER BY
3468 "area"."id",
3469 "delegation"."truster_id",
3470 "delegation"."scope" DESC;
3472 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
3475 CREATE VIEW "issue_delegation" AS
3476 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
3477 "issue"."id" AS "issue_id",
3478 "delegation"."id",
3479 "delegation"."truster_id",
3480 "delegation"."trustee_id",
3481 "delegation"."scope"
3482 FROM "issue"
3483 JOIN "area"
3484 ON "area"."id" = "issue"."area_id"
3485 JOIN "delegation"
3486 ON "delegation"."unit_id" = "area"."unit_id"
3487 OR "delegation"."area_id" = "area"."id"
3488 OR "delegation"."issue_id" = "issue"."id"
3489 JOIN "member"
3490 ON "delegation"."truster_id" = "member"."id"
3491 JOIN "privilege"
3492 ON "area"."unit_id" = "privilege"."unit_id"
3493 AND "delegation"."truster_id" = "privilege"."member_id"
3494 WHERE "member"."active" AND "privilege"."voting_right"
3495 ORDER BY
3496 "issue"."id",
3497 "delegation"."truster_id",
3498 "delegation"."scope" DESC;
3500 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
3503 CREATE VIEW "member_count_view" AS
3504 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
3506 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
3509 CREATE VIEW "unit_member" AS
3510 SELECT
3511 "unit"."id" AS "unit_id",
3512 "member"."id" AS "member_id"
3513 FROM "privilege"
3514 JOIN "unit" ON "unit"."id" = "privilege"."unit_id"
3515 JOIN "member" ON "member"."id" = "privilege"."member_id"
3516 WHERE "privilege"."voting_right" AND "member"."active";
3518 COMMENT ON VIEW "unit_member" IS 'Active members with voting right in a unit';
3521 CREATE VIEW "unit_member_count" AS
3522 SELECT
3523 "unit"."id" AS "unit_id",
3524 count("unit_member"."member_id") AS "member_count"
3525 FROM "unit" LEFT JOIN "unit_member"
3526 ON "unit"."id" = "unit_member"."unit_id"
3527 GROUP BY "unit"."id";
3529 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
3532 CREATE VIEW "opening_draft" AS
3533 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3534 ORDER BY "initiative_id", "id";
3536 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
3539 CREATE VIEW "current_draft" AS
3540 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3541 ORDER BY "initiative_id", "id" DESC;
3543 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
3546 CREATE VIEW "critical_opinion" AS
3547 SELECT * FROM "opinion"
3548 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
3549 OR ("degree" = -2 AND "fulfilled" = TRUE);
3551 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
3554 CREATE VIEW "issue_supporter_in_admission_state" AS
3555 SELECT
3556 "area"."unit_id",
3557 "issue"."area_id",
3558 "issue"."id" AS "issue_id",
3559 "supporter"."member_id",
3560 "direct_interest_snapshot"."weight"
3561 FROM "issue"
3562 JOIN "area" ON "area"."id" = "issue"."area_id"
3563 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
3564 JOIN "direct_interest_snapshot"
3565 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3566 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3567 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
3568 WHERE "issue"."state" = 'admission'::"issue_state";
3570 COMMENT ON VIEW "issue_supporter_in_admission_state" IS 'Helper view for "lf_update_issue_order" to allow a (proportional) ordering of issues within an area';
3573 CREATE VIEW "initiative_suggestion_order_calculation" AS
3574 SELECT
3575 "initiative"."id" AS "initiative_id",
3576 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
3577 FROM "initiative" JOIN "issue"
3578 ON "initiative"."issue_id" = "issue"."id"
3579 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
3580 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
3582 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
3584 COMMENT ON COLUMN "initiative_suggestion_order_calculation"."final" IS 'Set to TRUE, if the issue is fully frozen or closed, and the calculation has to be done only once for one last time';
3587 CREATE VIEW "individual_suggestion_ranking" AS
3588 SELECT
3589 "opinion"."initiative_id",
3590 "opinion"."member_id",
3591 "direct_interest_snapshot"."weight",
3592 CASE WHEN
3593 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
3594 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
3595 THEN 1 ELSE
3596 CASE WHEN
3597 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
3598 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
3599 THEN 2 ELSE
3600 CASE WHEN
3601 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
3602 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
3603 THEN 3 ELSE 4 END
3604 END
3605 END AS "preference",
3606 "opinion"."suggestion_id"
3607 FROM "opinion"
3608 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
3609 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3610 JOIN "direct_interest_snapshot"
3611 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3612 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3613 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
3615 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
3618 CREATE VIEW "battle_participant" AS
3619 SELECT "initiative"."id", "initiative"."issue_id"
3620 FROM "issue" JOIN "initiative"
3621 ON "issue"."id" = "initiative"."issue_id"
3622 WHERE "initiative"."admitted"
3623 UNION ALL
3624 SELECT NULL, "id" AS "issue_id"
3625 FROM "issue";
3627 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
3630 CREATE VIEW "battle_view" AS
3631 SELECT
3632 "issue"."id" AS "issue_id",
3633 "winning_initiative"."id" AS "winning_initiative_id",
3634 "losing_initiative"."id" AS "losing_initiative_id",
3635 sum(
3636 CASE WHEN
3637 coalesce("better_vote"."grade", 0) >
3638 coalesce("worse_vote"."grade", 0)
3639 THEN "direct_voter"."weight" ELSE 0 END
3640 ) AS "count"
3641 FROM "issue"
3642 LEFT JOIN "direct_voter"
3643 ON "issue"."id" = "direct_voter"."issue_id"
3644 JOIN "battle_participant" AS "winning_initiative"
3645 ON "issue"."id" = "winning_initiative"."issue_id"
3646 JOIN "battle_participant" AS "losing_initiative"
3647 ON "issue"."id" = "losing_initiative"."issue_id"
3648 LEFT JOIN "vote" AS "better_vote"
3649 ON "direct_voter"."member_id" = "better_vote"."member_id"
3650 AND "winning_initiative"."id" = "better_vote"."initiative_id"
3651 LEFT JOIN "vote" AS "worse_vote"
3652 ON "direct_voter"."member_id" = "worse_vote"."member_id"
3653 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
3654 WHERE "issue"."state" = 'voting'
3655 AND "issue"."phase_finished" NOTNULL
3656 AND (
3657 "winning_initiative"."id" != "losing_initiative"."id" OR
3658 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
3659 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
3660 GROUP BY
3661 "issue"."id",
3662 "winning_initiative"."id",
3663 "losing_initiative"."id";
3665 COMMENT ON VIEW "battle_view" IS 'Number of members preferring one initiative (or status-quo) to another initiative (or status-quo); Used to fill "battle" table';
3668 CREATE VIEW "expired_session" AS
3669 SELECT * FROM "session" WHERE now() > "expiry";
3671 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
3672 DELETE FROM "session" WHERE "id" = OLD."id";
3674 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
3675 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
3678 CREATE VIEW "expired_token" AS
3679 SELECT * FROM "token" WHERE now() > "expiry" AND NOT (
3680 "token_type" = 'authorization' AND "used" AND EXISTS (
3681 SELECT NULL FROM "token" AS "other"
3682 WHERE "other"."authorization_token_id" = "token"."id" ) );
3684 CREATE RULE "delete" AS ON DELETE TO "expired_token" DO INSTEAD
3685 DELETE FROM "token" WHERE "id" = OLD."id";
3687 COMMENT ON VIEW "expired_token" IS 'View containing all expired tokens where DELETE is possible; Note that used authorization codes must not be deleted if still referred to by other tokens';
3690 CREATE VIEW "unused_snapshot" AS
3691 SELECT "snapshot".* FROM "snapshot"
3692 LEFT JOIN "issue"
3693 ON "snapshot"."id" = "issue"."latest_snapshot_id"
3694 OR "snapshot"."id" = "issue"."admission_snapshot_id"
3695 OR "snapshot"."id" = "issue"."half_freeze_snapshot_id"
3696 OR "snapshot"."id" = "issue"."full_freeze_snapshot_id"
3697 WHERE "issue"."id" ISNULL;
3699 CREATE RULE "delete" AS ON DELETE TO "unused_snapshot" DO INSTEAD
3700 DELETE FROM "snapshot" WHERE "id" = OLD."id";
3702 COMMENT ON VIEW "unused_snapshot" IS 'Snapshots that are not referenced by any issue (either as latest snapshot or as snapshot at phase/state change)';
3705 CREATE VIEW "expired_snapshot" AS
3706 SELECT "unused_snapshot".* FROM "unused_snapshot" CROSS JOIN "system_setting"
3707 WHERE "unused_snapshot"."calculated" <
3708 now() - "system_setting"."snapshot_retention";
3710 CREATE RULE "delete" AS ON DELETE TO "expired_snapshot" DO INSTEAD
3711 DELETE FROM "snapshot" WHERE "id" = OLD."id";
3713 COMMENT ON VIEW "expired_snapshot" IS 'Contains "unused_snapshot"s that are older than "system_setting"."snapshot_retention" (for deletion)';
3716 CREATE VIEW "open_issue" AS
3717 SELECT * FROM "issue" WHERE "closed" ISNULL;
3719 COMMENT ON VIEW "open_issue" IS 'All open issues';
3722 CREATE VIEW "member_contingent" AS
3723 SELECT
3724 "member"."id" AS "member_id",
3725 "contingent"."polling",
3726 "contingent"."time_frame",
3727 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
3729 SELECT count(1) FROM "draft"
3730 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3731 WHERE "draft"."author_id" = "member"."id"
3732 AND "initiative"."polling" = "contingent"."polling"
3733 AND "draft"."created" > now() - "contingent"."time_frame"
3734 ) + (
3735 SELECT count(1) FROM "suggestion"
3736 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
3737 WHERE "suggestion"."author_id" = "member"."id"
3738 AND "contingent"."polling" = FALSE
3739 AND "suggestion"."created" > now() - "contingent"."time_frame"
3741 ELSE NULL END AS "text_entry_count",
3742 "contingent"."text_entry_limit",
3743 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
3744 SELECT count(1) FROM "opening_draft" AS "draft"
3745 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3746 WHERE "draft"."author_id" = "member"."id"
3747 AND "initiative"."polling" = "contingent"."polling"
3748 AND "draft"."created" > now() - "contingent"."time_frame"
3749 ) ELSE NULL END AS "initiative_count",
3750 "contingent"."initiative_limit"
3751 FROM "member" CROSS JOIN "contingent";
3753 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
3755 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
3756 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
3759 CREATE VIEW "member_contingent_left" AS
3760 SELECT
3761 "member_id",
3762 "polling",
3763 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
3764 max("initiative_limit" - "initiative_count") AS "initiatives_left"
3765 FROM "member_contingent" GROUP BY "member_id", "polling";
3767 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.';
3770 CREATE VIEW "event_for_notification" AS
3771 SELECT
3772 "member"."id" AS "recipient_id",
3773 "event".*
3774 FROM "member" CROSS JOIN "event"
3775 JOIN "issue" ON "issue"."id" = "event"."issue_id"
3776 JOIN "area" ON "area"."id" = "issue"."area_id"
3777 LEFT JOIN "privilege" ON
3778 "privilege"."member_id" = "member"."id" AND
3779 "privilege"."unit_id" = "area"."unit_id" AND
3780 "privilege"."voting_right" = TRUE
3781 LEFT JOIN "subscription" ON
3782 "subscription"."member_id" = "member"."id" AND
3783 "subscription"."unit_id" = "area"."unit_id"
3784 LEFT JOIN "ignored_area" ON
3785 "ignored_area"."member_id" = "member"."id" AND
3786 "ignored_area"."area_id" = "issue"."area_id"
3787 LEFT JOIN "interest" ON
3788 "interest"."member_id" = "member"."id" AND
3789 "interest"."issue_id" = "event"."issue_id"
3790 LEFT JOIN "supporter" ON
3791 "supporter"."member_id" = "member"."id" AND
3792 "supporter"."initiative_id" = "event"."initiative_id"
3793 WHERE ("privilege"."member_id" NOTNULL OR "subscription"."member_id" NOTNULL)
3794 AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL)
3795 AND (
3796 "event"."event" = 'issue_state_changed'::"event_type" OR
3797 ( "event"."event" = 'initiative_revoked'::"event_type" AND
3798 "supporter"."member_id" NOTNULL ) );
3800 COMMENT ON VIEW "event_for_notification" IS 'Entries of the "event" table which are of interest for a particular notification mail recipient';
3802 COMMENT ON COLUMN "event_for_notification"."recipient_id" IS 'member_id of the recipient of a notification mail';
3805 CREATE VIEW "updated_initiative" AS
3806 SELECT
3807 "supporter"."member_id" AS "recipient_id",
3808 FALSE AS "featured",
3809 "supporter"."initiative_id"
3810 FROM "supporter"
3811 JOIN "initiative" ON "supporter"."initiative_id" = "initiative"."id"
3812 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3813 LEFT JOIN "notification_initiative_sent" AS "sent" ON
3814 "sent"."member_id" = "supporter"."member_id" AND
3815 "sent"."initiative_id" = "supporter"."initiative_id"
3816 LEFT JOIN "ignored_initiative" ON
3817 "ignored_initiative"."member_id" = "supporter"."member_id" AND
3818 "ignored_initiative"."initiative_id" = "supporter"."initiative_id"
3819 WHERE "issue"."state" IN ('admission', 'discussion')
3820 AND "initiative"."revoked" ISNULL
3821 AND "ignored_initiative"."member_id" ISNULL
3822 AND (
3823 EXISTS (
3824 SELECT NULL FROM "draft"
3825 LEFT JOIN "ignored_member" ON
3826 "ignored_member"."member_id" = "supporter"."member_id" AND
3827 "ignored_member"."other_member_id" = "draft"."author_id"
3828 WHERE "draft"."initiative_id" = "supporter"."initiative_id"
3829 AND "draft"."id" > "supporter"."draft_id"
3830 AND "ignored_member"."member_id" ISNULL
3831 ) OR EXISTS (
3832 SELECT NULL FROM "suggestion"
3833 LEFT JOIN "opinion" ON
3834 "opinion"."member_id" = "supporter"."member_id" AND
3835 "opinion"."suggestion_id" = "suggestion"."id"
3836 LEFT JOIN "ignored_member" ON
3837 "ignored_member"."member_id" = "supporter"."member_id" AND
3838 "ignored_member"."other_member_id" = "suggestion"."author_id"
3839 WHERE "suggestion"."initiative_id" = "supporter"."initiative_id"
3840 AND "opinion"."member_id" ISNULL
3841 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
3842 AND "ignored_member"."member_id" ISNULL
3844 );
3846 COMMENT ON VIEW "updated_initiative" IS 'Helper view for view "updated_or_featured_initiative"';
3849 CREATE FUNCTION "featured_initiative"
3850 ( "recipient_id_p" "member"."id"%TYPE,
3851 "area_id_p" "area"."id"%TYPE )
3852 RETURNS SETOF "initiative"."id"%TYPE
3853 LANGUAGE 'plpgsql' STABLE AS $$
3854 DECLARE
3855 "counter_v" "member"."notification_counter"%TYPE;
3856 "sample_size_v" "member"."notification_sample_size"%TYPE;
3857 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
3858 "match_v" BOOLEAN;
3859 "member_id_v" "member"."id"%TYPE;
3860 "seed_v" TEXT;
3861 "initiative_id_v" "initiative"."id"%TYPE;
3862 BEGIN
3863 SELECT "notification_counter", "notification_sample_size"
3864 INTO "counter_v", "sample_size_v"
3865 FROM "member" WHERE "id" = "recipient_id_p";
3866 IF COALESCE("sample_size_v" <= 0, TRUE) THEN
3867 RETURN;
3868 END IF;
3869 "initiative_id_ary" := '{}';
3870 LOOP
3871 "match_v" := FALSE;
3872 FOR "member_id_v", "seed_v" IN
3873 SELECT * FROM (
3874 SELECT DISTINCT
3875 "supporter"."member_id",
3876 md5(
3877 "recipient_id_p" || '-' ||
3878 "counter_v" || '-' ||
3879 "area_id_p" || '-' ||
3880 "supporter"."member_id"
3881 ) AS "seed"
3882 FROM "supporter"
3883 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
3884 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3885 WHERE "supporter"."member_id" != "recipient_id_p"
3886 AND "issue"."area_id" = "area_id_p"
3887 AND "issue"."state" IN ('admission', 'discussion', 'verification')
3888 ) AS "subquery"
3889 ORDER BY "seed"
3890 LOOP
3891 SELECT "initiative"."id" INTO "initiative_id_v"
3892 FROM "initiative"
3893 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3894 JOIN "area" ON "area"."id" = "issue"."area_id"
3895 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
3896 LEFT JOIN "supporter" AS "self_support" ON
3897 "self_support"."initiative_id" = "initiative"."id" AND
3898 "self_support"."member_id" = "recipient_id_p"
3899 LEFT JOIN "privilege" ON
3900 "privilege"."member_id" = "recipient_id_p" AND
3901 "privilege"."unit_id" = "area"."unit_id" AND
3902 "privilege"."voting_right" = TRUE
3903 LEFT JOIN "subscription" ON
3904 "subscription"."member_id" = "recipient_id_p" AND
3905 "subscription"."unit_id" = "area"."unit_id"
3906 LEFT JOIN "ignored_initiative" ON
3907 "ignored_initiative"."member_id" = "recipient_id_p" AND
3908 "ignored_initiative"."initiative_id" = "initiative"."id"
3909 WHERE "supporter"."member_id" = "member_id_v"
3910 AND "issue"."area_id" = "area_id_p"
3911 AND "issue"."state" IN ('admission', 'discussion', 'verification')
3912 AND "initiative"."revoked" ISNULL
3913 AND "self_support"."member_id" ISNULL
3914 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
3915 AND (
3916 "privilege"."member_id" NOTNULL OR
3917 "subscription"."member_id" NOTNULL )
3918 AND "ignored_initiative"."member_id" ISNULL
3919 AND NOT EXISTS (
3920 SELECT NULL FROM "draft"
3921 JOIN "ignored_member" ON
3922 "ignored_member"."member_id" = "recipient_id_p" AND
3923 "ignored_member"."other_member_id" = "draft"."author_id"
3924 WHERE "draft"."initiative_id" = "initiative"."id"
3926 ORDER BY md5("seed_v" || '-' || "initiative"."id")
3927 LIMIT 1;
3928 IF FOUND THEN
3929 "match_v" := TRUE;
3930 RETURN NEXT "initiative_id_v";
3931 IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
3932 RETURN;
3933 END IF;
3934 "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
3935 END IF;
3936 END LOOP;
3937 EXIT WHEN NOT "match_v";
3938 END LOOP;
3939 RETURN;
3940 END;
3941 $$;
3943 COMMENT ON FUNCTION "featured_initiative"
3944 ( "recipient_id_p" "member"."id"%TYPE,
3945 "area_id_p" "area"."id"%TYPE )
3946 IS 'Helper function for view "updated_or_featured_initiative"';
3949 CREATE VIEW "updated_or_featured_initiative" AS
3950 SELECT
3951 "subquery".*,
3952 NOT EXISTS (
3953 SELECT NULL FROM "initiative" AS "better_initiative"
3954 WHERE "better_initiative"."issue_id" = "initiative"."issue_id"
3955 AND
3956 ( COALESCE("better_initiative"."supporter_count", -1),
3957 -"better_initiative"."id" ) >
3958 ( COALESCE("initiative"."supporter_count", -1),
3959 -"initiative"."id" )
3960 ) AS "leading"
3961 FROM (
3962 SELECT * FROM "updated_initiative"
3963 UNION ALL
3964 SELECT
3965 "member"."id" AS "recipient_id",
3966 TRUE AS "featured",
3967 "featured_initiative_id" AS "initiative_id"
3968 FROM "member" CROSS JOIN "area"
3969 CROSS JOIN LATERAL
3970 "featured_initiative"("member"."id", "area"."id") AS "featured_initiative_id"
3971 JOIN "initiative" ON "initiative"."id" = "featured_initiative_id"
3972 ) AS "subquery"
3973 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id";
3975 COMMENT ON VIEW "updated_or_featured_initiative" IS 'Initiatives to be included in a scheduled notification mail because (a) they have been updated or (b) they are featured';
3977 COMMENT ON COLUMN "updated_or_featured_initiative"."recipient_id" IS '"id" of the member who receives the notification mail';
3978 COMMENT ON COLUMN "updated_or_featured_initiative"."featured" IS 'TRUE if the initiative has been included because it was selected by the "featured_initiative" algorithm (see source of function "featured_initiative")';
3979 COMMENT ON COLUMN "updated_or_featured_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
3980 COMMENT ON COLUMN "updated_or_featured_initiative"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
3983 CREATE VIEW "leading_complement_initiative" AS
3984 SELECT * FROM (
3985 SELECT DISTINCT ON ("uf_initiative"."recipient_id", "initiative"."issue_id")
3986 "uf_initiative"."recipient_id",
3987 FALSE AS "featured",
3988 "uf_initiative"."initiative_id",
3989 TRUE AS "leading"
3990 FROM "updated_or_featured_initiative" AS "uf_initiative"
3991 JOIN "initiative" AS "uf_initiative_full" ON
3992 "uf_initiative_full"."id" = "uf_initiative"."initiative_id"
3993 JOIN "initiative" ON
3994 "initiative"."issue_id" = "uf_initiative_full"."issue_id"
3995 WHERE "initiative"."revoked" ISNULL
3996 ORDER BY
3997 "uf_initiative"."recipient_id",
3998 "initiative"."issue_id",
3999 "initiative"."supporter_count" DESC,
4000 "initiative"."id"
4001 ) AS "subquery"
4002 WHERE NOT EXISTS (
4003 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
4004 WHERE "other"."recipient_id" = "subquery"."recipient_id"
4005 AND "other"."initiative_id" = "subquery"."initiative_id"
4006 );
4008 COMMENT ON VIEW "leading_complement_initiative" IS 'Helper view for view "unfiltered_initiative_for_notification" in order to always include the most supported initiative of an issue';
4009 COMMENT ON COLUMN "leading_complement_initiative"."featured" IS 'Always FALSE in this view';
4010 COMMENT ON COLUMN "leading_complement_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4011 COMMENT ON COLUMN "leading_complement_initiative"."leading" IS 'Always TRUE in this view';
4014 CREATE VIEW "unfiltered_initiative_for_notification" AS
4015 SELECT
4016 "subquery".*,
4017 "supporter"."member_id" NOTNULL AS "supported",
4018 CASE WHEN "supporter"."member_id" NOTNULL THEN
4019 EXISTS (
4020 SELECT NULL FROM "draft"
4021 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
4022 AND "draft"."id" > "supporter"."draft_id"
4024 ELSE
4025 EXISTS (
4026 SELECT NULL FROM "draft"
4027 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
4028 AND COALESCE("draft"."id" > "sent"."last_draft_id", TRUE)
4030 END AS "new_draft",
4031 CASE WHEN "supporter"."member_id" NOTNULL THEN
4032 ( SELECT count(1) FROM "suggestion"
4033 LEFT JOIN "opinion" ON
4034 "opinion"."member_id" = "supporter"."member_id" AND
4035 "opinion"."suggestion_id" = "suggestion"."id"
4036 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
4037 AND "opinion"."member_id" ISNULL
4038 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4040 ELSE
4041 ( SELECT count(1) FROM "suggestion"
4042 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
4043 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4045 END AS "new_suggestion_count"
4046 FROM (
4047 SELECT * FROM "updated_or_featured_initiative"
4048 UNION ALL
4049 SELECT * FROM "leading_complement_initiative"
4050 ) AS "subquery"
4051 LEFT JOIN "supporter" ON
4052 "supporter"."member_id" = "subquery"."recipient_id" AND
4053 "supporter"."initiative_id" = "subquery"."initiative_id"
4054 LEFT JOIN "notification_initiative_sent" AS "sent" ON
4055 "sent"."member_id" = "subquery"."recipient_id" AND
4056 "sent"."initiative_id" = "subquery"."initiative_id";
4058 COMMENT ON VIEW "unfiltered_initiative_for_notification" IS 'Helper view which simply combines the views "updated_or_featured_initiative" and "leading_complement_initiative" and adds columns "supported", "new_draft", and "new_suggestion_count';
4060 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4061 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."new_draft" IS 'TRUE if a new draft exists (using the "draft_id" column of the "supporter" table in case of "supported" initiatives and the "last_draft_id" column of the "notification_initiative_sent" table in all other cases)';
4062 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."new_suggestion_count" IS 'Number of new suggestions (using the "last_suggestion_id" column of the "notification_initiative_sent" table while ignoring suggestions with an "opinion")';
4065 CREATE VIEW "initiative_for_notification" AS
4066 SELECT "unfiltered1".*
4067 FROM "unfiltered_initiative_for_notification" "unfiltered1"
4068 JOIN "initiative" AS "initiative1" ON
4069 "initiative1"."id" = "unfiltered1"."initiative_id"
4070 JOIN "issue" AS "issue1" ON "issue1"."id" = "initiative1"."issue_id"
4071 WHERE EXISTS (
4072 SELECT NULL
4073 FROM "unfiltered_initiative_for_notification" "unfiltered2"
4074 JOIN "initiative" AS "initiative2" ON
4075 "initiative2"."id" = "unfiltered2"."initiative_id"
4076 JOIN "issue" AS "issue2" ON "issue2"."id" = "initiative2"."issue_id"
4077 WHERE "unfiltered1"."recipient_id" = "unfiltered2"."recipient_id"
4078 AND "issue1"."area_id" = "issue2"."area_id"
4079 AND ("unfiltered2"."new_draft" OR "unfiltered2"."new_suggestion_count" > 0 )
4080 );
4082 COMMENT ON VIEW "initiative_for_notification" IS 'Initiatives to be included in a scheduled notification mail';
4084 COMMENT ON COLUMN "initiative_for_notification"."recipient_id" IS '"id" of the member who receives the notification mail';
4085 COMMENT ON COLUMN "initiative_for_notification"."featured" IS 'TRUE if the initiative has been included because it was selected by the "featured_initiative" algorithm (see source of function "featured_initiative")';
4086 COMMENT ON COLUMN "initiative_for_notification"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4087 COMMENT ON COLUMN "initiative_for_notification"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
4088 COMMENT ON COLUMN "initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4089 COMMENT ON COLUMN "initiative_for_notification"."new_draft" IS 'TRUE if a new draft exists (using the "draft_id" column of the "supporter" table in case of "supported" initiatives and the "last_draft_id" column of the "notification_initiative_sent" table in all other cases)';
4090 COMMENT ON COLUMN "initiative_for_notification"."new_suggestion_count" IS 'Number of new suggestions (using the "last_suggestion_id" column of the "notification_initiative_sent" table while ignoring suggestions with an "opinion")';
4093 CREATE VIEW "scheduled_notification_to_send" AS
4094 SELECT * FROM (
4095 SELECT
4096 "id" AS "recipient_id",
4097 now() - CASE WHEN "notification_dow" ISNULL THEN
4098 ( "notification_sent"::DATE + CASE
4099 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4100 THEN 0 ELSE 1 END
4101 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4102 ELSE
4103 ( "notification_sent"::DATE +
4104 ( 7 + "notification_dow" -
4105 EXTRACT(DOW FROM
4106 ( "notification_sent"::DATE + CASE
4107 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4108 THEN 0 ELSE 1 END
4109 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4110 )::INTEGER
4111 ) % 7 +
4112 CASE
4113 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4114 THEN 0 ELSE 1
4115 END
4116 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4117 END AS "pending"
4118 FROM (
4119 SELECT
4120 "id",
4121 COALESCE("notification_sent", "activated") AS "notification_sent",
4122 "notification_dow",
4123 "notification_hour"
4124 FROM "member_to_notify"
4125 WHERE "notification_hour" NOTNULL
4126 ) AS "subquery1"
4127 ) AS "subquery2"
4128 WHERE "pending" > '0'::INTERVAL;
4130 COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending';
4132 COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail';
4133 COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending';
4136 CREATE VIEW "newsletter_to_send" AS
4137 SELECT
4138 "member"."id" AS "recipient_id",
4139 "newsletter"."id" AS "newsletter_id",
4140 "newsletter"."published"
4141 FROM "newsletter" CROSS JOIN "member_eligible_to_be_notified" AS "member"
4142 LEFT JOIN "privilege" ON
4143 "privilege"."member_id" = "member"."id" AND
4144 "privilege"."unit_id" = "newsletter"."unit_id" AND
4145 "privilege"."voting_right" = TRUE
4146 LEFT JOIN "subscription" ON
4147 "subscription"."member_id" = "member"."id" AND
4148 "subscription"."unit_id" = "newsletter"."unit_id"
4149 WHERE "newsletter"."published" <= now()
4150 AND "newsletter"."sent" ISNULL
4151 AND (
4152 "member"."disable_notifications" = FALSE OR
4153 "newsletter"."include_all_members" = TRUE )
4154 AND (
4155 "newsletter"."unit_id" ISNULL OR
4156 "privilege"."member_id" NOTNULL OR
4157 "subscription"."member_id" NOTNULL );
4159 COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out';
4161 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter was supposed to be sent out (can be used for ordering)';
4165 ------------------------------------------------------
4166 -- Row set returning function for delegation chains --
4167 ------------------------------------------------------
4170 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
4171 ('first', 'intermediate', 'last', 'repetition');
4173 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
4176 CREATE TYPE "delegation_chain_row" AS (
4177 "index" INT4,
4178 "member_id" INT4,
4179 "member_valid" BOOLEAN,
4180 "participation" BOOLEAN,
4181 "overridden" BOOLEAN,
4182 "scope_in" "delegation_scope",
4183 "scope_out" "delegation_scope",
4184 "disabled_out" BOOLEAN,
4185 "loop" "delegation_chain_loop_tag" );
4187 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
4189 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
4190 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest; for area and global delegation chains: always null';
4191 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
4192 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
4193 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
4194 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
4195 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
4198 CREATE FUNCTION "delegation_chain_for_closed_issue"
4199 ( "member_id_p" "member"."id"%TYPE,
4200 "issue_id_p" "issue"."id"%TYPE )
4201 RETURNS SETOF "delegation_chain_row"
4202 LANGUAGE 'plpgsql' STABLE AS $$
4203 DECLARE
4204 "output_row" "delegation_chain_row";
4205 "direct_voter_row" "direct_voter"%ROWTYPE;
4206 "delegating_voter_row" "delegating_voter"%ROWTYPE;
4207 BEGIN
4208 "output_row"."index" := 0;
4209 "output_row"."member_id" := "member_id_p";
4210 "output_row"."member_valid" := TRUE;
4211 "output_row"."participation" := FALSE;
4212 "output_row"."overridden" := FALSE;
4213 "output_row"."disabled_out" := FALSE;
4214 LOOP
4215 SELECT INTO "direct_voter_row" * FROM "direct_voter"
4216 WHERE "issue_id" = "issue_id_p"
4217 AND "member_id" = "output_row"."member_id";
4218 IF "direct_voter_row"."member_id" NOTNULL THEN
4219 "output_row"."participation" := TRUE;
4220 "output_row"."scope_out" := NULL;
4221 "output_row"."disabled_out" := NULL;
4222 RETURN NEXT "output_row";
4223 RETURN;
4224 END IF;
4225 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
4226 WHERE "issue_id" = "issue_id_p"
4227 AND "member_id" = "output_row"."member_id";
4228 IF "delegating_voter_row"."member_id" ISNULL THEN
4229 RETURN;
4230 END IF;
4231 "output_row"."scope_out" := "delegating_voter_row"."scope";
4232 RETURN NEXT "output_row";
4233 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
4234 "output_row"."scope_in" := "output_row"."scope_out";
4235 END LOOP;
4236 END;
4237 $$;
4239 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
4240 ( "member"."id"%TYPE,
4241 "member"."id"%TYPE )
4242 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
4245 CREATE FUNCTION "delegation_chain"
4246 ( "member_id_p" "member"."id"%TYPE,
4247 "unit_id_p" "unit"."id"%TYPE,
4248 "area_id_p" "area"."id"%TYPE,
4249 "issue_id_p" "issue"."id"%TYPE,
4250 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4251 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4252 RETURNS SETOF "delegation_chain_row"
4253 LANGUAGE 'plpgsql' STABLE AS $$
4254 DECLARE
4255 "scope_v" "delegation_scope";
4256 "unit_id_v" "unit"."id"%TYPE;
4257 "area_id_v" "area"."id"%TYPE;
4258 "issue_row" "issue"%ROWTYPE;
4259 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
4260 "loop_member_id_v" "member"."id"%TYPE;
4261 "output_row" "delegation_chain_row";
4262 "output_rows" "delegation_chain_row"[];
4263 "simulate_v" BOOLEAN;
4264 "simulate_here_v" BOOLEAN;
4265 "delegation_row" "delegation"%ROWTYPE;
4266 "row_count" INT4;
4267 "i" INT4;
4268 "loop_v" BOOLEAN;
4269 BEGIN
4270 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
4271 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
4272 END IF;
4273 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
4274 "simulate_v" := TRUE;
4275 ELSE
4276 "simulate_v" := FALSE;
4277 END IF;
4278 IF
4279 "unit_id_p" NOTNULL AND
4280 "area_id_p" ISNULL AND
4281 "issue_id_p" ISNULL
4282 THEN
4283 "scope_v" := 'unit';
4284 "unit_id_v" := "unit_id_p";
4285 ELSIF
4286 "unit_id_p" ISNULL AND
4287 "area_id_p" NOTNULL AND
4288 "issue_id_p" ISNULL
4289 THEN
4290 "scope_v" := 'area';
4291 "area_id_v" := "area_id_p";
4292 SELECT "unit_id" INTO "unit_id_v"
4293 FROM "area" WHERE "id" = "area_id_v";
4294 ELSIF
4295 "unit_id_p" ISNULL AND
4296 "area_id_p" ISNULL AND
4297 "issue_id_p" NOTNULL
4298 THEN
4299 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
4300 IF "issue_row"."id" ISNULL THEN
4301 RETURN;
4302 END IF;
4303 IF "issue_row"."closed" NOTNULL THEN
4304 IF "simulate_v" THEN
4305 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
4306 END IF;
4307 FOR "output_row" IN
4308 SELECT * FROM
4309 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
4310 LOOP
4311 RETURN NEXT "output_row";
4312 END LOOP;
4313 RETURN;
4314 END IF;
4315 "scope_v" := 'issue';
4316 SELECT "area_id" INTO "area_id_v"
4317 FROM "issue" WHERE "id" = "issue_id_p";
4318 SELECT "unit_id" INTO "unit_id_v"
4319 FROM "area" WHERE "id" = "area_id_v";
4320 ELSE
4321 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
4322 END IF;
4323 "visited_member_ids" := '{}';
4324 "loop_member_id_v" := NULL;
4325 "output_rows" := '{}';
4326 "output_row"."index" := 0;
4327 "output_row"."member_id" := "member_id_p";
4328 "output_row"."member_valid" := TRUE;
4329 "output_row"."participation" := FALSE;
4330 "output_row"."overridden" := FALSE;
4331 "output_row"."disabled_out" := FALSE;
4332 "output_row"."scope_out" := NULL;
4333 LOOP
4334 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
4335 "loop_member_id_v" := "output_row"."member_id";
4336 ELSE
4337 "visited_member_ids" :=
4338 "visited_member_ids" || "output_row"."member_id";
4339 END IF;
4340 IF "output_row"."participation" ISNULL THEN
4341 "output_row"."overridden" := NULL;
4342 ELSIF "output_row"."participation" THEN
4343 "output_row"."overridden" := TRUE;
4344 END IF;
4345 "output_row"."scope_in" := "output_row"."scope_out";
4346 "output_row"."member_valid" := EXISTS (
4347 SELECT NULL FROM "member" JOIN "privilege"
4348 ON "privilege"."member_id" = "member"."id"
4349 AND "privilege"."unit_id" = "unit_id_v"
4350 WHERE "id" = "output_row"."member_id"
4351 AND "member"."active" AND "privilege"."voting_right"
4352 );
4353 "simulate_here_v" := (
4354 "simulate_v" AND
4355 "output_row"."member_id" = "member_id_p"
4356 );
4357 "delegation_row" := ROW(NULL);
4358 IF "output_row"."member_valid" OR "simulate_here_v" THEN
4359 IF "scope_v" = 'unit' THEN
4360 IF NOT "simulate_here_v" THEN
4361 SELECT * INTO "delegation_row" FROM "delegation"
4362 WHERE "truster_id" = "output_row"."member_id"
4363 AND "unit_id" = "unit_id_v";
4364 END IF;
4365 ELSIF "scope_v" = 'area' THEN
4366 IF "simulate_here_v" THEN
4367 IF "simulate_trustee_id_p" ISNULL THEN
4368 SELECT * INTO "delegation_row" FROM "delegation"
4369 WHERE "truster_id" = "output_row"."member_id"
4370 AND "unit_id" = "unit_id_v";
4371 END IF;
4372 ELSE
4373 SELECT * INTO "delegation_row" FROM "delegation"
4374 WHERE "truster_id" = "output_row"."member_id"
4375 AND (
4376 "unit_id" = "unit_id_v" OR
4377 "area_id" = "area_id_v"
4379 ORDER BY "scope" DESC;
4380 END IF;
4381 ELSIF "scope_v" = 'issue' THEN
4382 IF "issue_row"."fully_frozen" ISNULL THEN
4383 "output_row"."participation" := EXISTS (
4384 SELECT NULL FROM "interest"
4385 WHERE "issue_id" = "issue_id_p"
4386 AND "member_id" = "output_row"."member_id"
4387 );
4388 ELSE
4389 IF "output_row"."member_id" = "member_id_p" THEN
4390 "output_row"."participation" := EXISTS (
4391 SELECT NULL FROM "direct_voter"
4392 WHERE "issue_id" = "issue_id_p"
4393 AND "member_id" = "output_row"."member_id"
4394 );
4395 ELSE
4396 "output_row"."participation" := NULL;
4397 END IF;
4398 END IF;
4399 IF "simulate_here_v" THEN
4400 IF "simulate_trustee_id_p" ISNULL THEN
4401 SELECT * INTO "delegation_row" FROM "delegation"
4402 WHERE "truster_id" = "output_row"."member_id"
4403 AND (
4404 "unit_id" = "unit_id_v" OR
4405 "area_id" = "area_id_v"
4407 ORDER BY "scope" DESC;
4408 END IF;
4409 ELSE
4410 SELECT * INTO "delegation_row" FROM "delegation"
4411 WHERE "truster_id" = "output_row"."member_id"
4412 AND (
4413 "unit_id" = "unit_id_v" OR
4414 "area_id" = "area_id_v" OR
4415 "issue_id" = "issue_id_p"
4417 ORDER BY "scope" DESC;
4418 END IF;
4419 END IF;
4420 ELSE
4421 "output_row"."participation" := FALSE;
4422 END IF;
4423 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
4424 "output_row"."scope_out" := "scope_v";
4425 "output_rows" := "output_rows" || "output_row";
4426 "output_row"."member_id" := "simulate_trustee_id_p";
4427 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
4428 "output_row"."scope_out" := "delegation_row"."scope";
4429 "output_rows" := "output_rows" || "output_row";
4430 "output_row"."member_id" := "delegation_row"."trustee_id";
4431 ELSIF "delegation_row"."scope" NOTNULL THEN
4432 "output_row"."scope_out" := "delegation_row"."scope";
4433 "output_row"."disabled_out" := TRUE;
4434 "output_rows" := "output_rows" || "output_row";
4435 EXIT;
4436 ELSE
4437 "output_row"."scope_out" := NULL;
4438 "output_rows" := "output_rows" || "output_row";
4439 EXIT;
4440 END IF;
4441 EXIT WHEN "loop_member_id_v" NOTNULL;
4442 "output_row"."index" := "output_row"."index" + 1;
4443 END LOOP;
4444 "row_count" := array_upper("output_rows", 1);
4445 "i" := 1;
4446 "loop_v" := FALSE;
4447 LOOP
4448 "output_row" := "output_rows"["i"];
4449 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
4450 IF "loop_v" THEN
4451 IF "i" + 1 = "row_count" THEN
4452 "output_row"."loop" := 'last';
4453 ELSIF "i" = "row_count" THEN
4454 "output_row"."loop" := 'repetition';
4455 ELSE
4456 "output_row"."loop" := 'intermediate';
4457 END IF;
4458 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
4459 "output_row"."loop" := 'first';
4460 "loop_v" := TRUE;
4461 END IF;
4462 IF "scope_v" = 'unit' THEN
4463 "output_row"."participation" := NULL;
4464 END IF;
4465 RETURN NEXT "output_row";
4466 "i" := "i" + 1;
4467 END LOOP;
4468 RETURN;
4469 END;
4470 $$;
4472 COMMENT ON FUNCTION "delegation_chain"
4473 ( "member"."id"%TYPE,
4474 "unit"."id"%TYPE,
4475 "area"."id"%TYPE,
4476 "issue"."id"%TYPE,
4477 "member"."id"%TYPE,
4478 BOOLEAN )
4479 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
4483 ---------------------------------------------------------
4484 -- Single row returning function for delegation chains --
4485 ---------------------------------------------------------
4488 CREATE TYPE "delegation_info_loop_type" AS ENUM
4489 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
4491 COMMENT ON TYPE "delegation_info_loop_type" IS 'Type of "delegation_loop" in "delegation_info_type"; ''own'' means loop to self, ''first'' means loop to first trustee, ''first_ellipsis'' means loop to ellipsis after first trustee, ''other'' means loop to other trustee, ''other_ellipsis'' means loop to ellipsis after other trustee''';
4494 CREATE TYPE "delegation_info_type" AS (
4495 "own_participation" BOOLEAN,
4496 "own_delegation_scope" "delegation_scope",
4497 "first_trustee_id" INT4,
4498 "first_trustee_participation" BOOLEAN,
4499 "first_trustee_ellipsis" BOOLEAN,
4500 "other_trustee_id" INT4,
4501 "other_trustee_participation" BOOLEAN,
4502 "other_trustee_ellipsis" BOOLEAN,
4503 "delegation_loop" "delegation_info_loop_type",
4504 "participating_member_id" INT4 );
4506 COMMENT ON TYPE "delegation_info_type" IS 'Type of result returned by "delegation_info" function; For meaning of "participation" check comment on "delegation_chain_row" type';
4508 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
4509 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
4510 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
4511 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
4512 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
4513 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
4514 COMMENT ON COLUMN "delegation_info_type"."other_trustee_participation" IS 'Another trustee is participating (redundant field: if "other_trustee_id" is set, then "other_trustee_participation" is always TRUE, else "other_trustee_participation" is NULL)';
4515 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
4516 COMMENT ON COLUMN "delegation_info_type"."delegation_loop" IS 'Non-NULL value, if delegation chain contains a circle; See comment on "delegation_info_loop_type" for details';
4517 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
4520 CREATE FUNCTION "delegation_info"
4521 ( "member_id_p" "member"."id"%TYPE,
4522 "unit_id_p" "unit"."id"%TYPE,
4523 "area_id_p" "area"."id"%TYPE,
4524 "issue_id_p" "issue"."id"%TYPE,
4525 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4526 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4527 RETURNS "delegation_info_type"
4528 LANGUAGE 'plpgsql' STABLE AS $$
4529 DECLARE
4530 "current_row" "delegation_chain_row";
4531 "result" "delegation_info_type";
4532 BEGIN
4533 "result"."own_participation" := FALSE;
4534 FOR "current_row" IN
4535 SELECT * FROM "delegation_chain"(
4536 "member_id_p",
4537 "unit_id_p", "area_id_p", "issue_id_p",
4538 "simulate_trustee_id_p", "simulate_default_p")
4539 LOOP
4540 IF
4541 "result"."participating_member_id" ISNULL AND
4542 "current_row"."participation"
4543 THEN
4544 "result"."participating_member_id" := "current_row"."member_id";
4545 END IF;
4546 IF "current_row"."member_id" = "member_id_p" THEN
4547 "result"."own_participation" := "current_row"."participation";
4548 "result"."own_delegation_scope" := "current_row"."scope_out";
4549 IF "current_row"."loop" = 'first' THEN
4550 "result"."delegation_loop" := 'own';
4551 END IF;
4552 ELSIF
4553 "current_row"."member_valid" AND
4554 ( "current_row"."loop" ISNULL OR
4555 "current_row"."loop" != 'repetition' )
4556 THEN
4557 IF "result"."first_trustee_id" ISNULL THEN
4558 "result"."first_trustee_id" := "current_row"."member_id";
4559 "result"."first_trustee_participation" := "current_row"."participation";
4560 "result"."first_trustee_ellipsis" := FALSE;
4561 IF "current_row"."loop" = 'first' THEN
4562 "result"."delegation_loop" := 'first';
4563 END IF;
4564 ELSIF "result"."other_trustee_id" ISNULL THEN
4565 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
4566 "result"."other_trustee_id" := "current_row"."member_id";
4567 "result"."other_trustee_participation" := TRUE;
4568 "result"."other_trustee_ellipsis" := FALSE;
4569 IF "current_row"."loop" = 'first' THEN
4570 "result"."delegation_loop" := 'other';
4571 END IF;
4572 ELSE
4573 "result"."first_trustee_ellipsis" := TRUE;
4574 IF "current_row"."loop" = 'first' THEN
4575 "result"."delegation_loop" := 'first_ellipsis';
4576 END IF;
4577 END IF;
4578 ELSE
4579 "result"."other_trustee_ellipsis" := TRUE;
4580 IF "current_row"."loop" = 'first' THEN
4581 "result"."delegation_loop" := 'other_ellipsis';
4582 END IF;
4583 END IF;
4584 END IF;
4585 END LOOP;
4586 RETURN "result";
4587 END;
4588 $$;
4590 COMMENT ON FUNCTION "delegation_info"
4591 ( "member"."id"%TYPE,
4592 "unit"."id"%TYPE,
4593 "area"."id"%TYPE,
4594 "issue"."id"%TYPE,
4595 "member"."id"%TYPE,
4596 BOOLEAN )
4597 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
4601 ------------------------
4602 -- Geospatial lookups --
4603 ------------------------
4605 /*
4606 CREATE FUNCTION "closed_initiatives_in_bounding_box"
4607 ( "bounding_box_p" EBOX,
4608 "limit_p" INT4 )
4609 RETURNS SETOF "initiative"
4610 LANGUAGE 'plpgsql' STABLE AS $$
4611 DECLARE
4612 "limit_v" INT4;
4613 "count_v" INT4;
4614 BEGIN
4615 "limit_v" := "limit_p" + 1;
4616 LOOP
4617 SELECT count(1) INTO "count_v"
4618 FROM "initiative"
4619 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4620 WHERE "issue"."closed" NOTNULL
4621 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4622 LIMIT "limit_v";
4623 IF "count_v" < "limit_v" THEN
4624 RETURN QUERY SELECT "initiative".*
4625 FROM (
4626 SELECT
4627 "initiative"."id" AS "initiative_id",
4628 "issue"."closed"
4629 FROM "initiative"
4630 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4631 WHERE "issue"."closed" NOTNULL
4632 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4633 ) AS "subquery"
4634 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4635 ORDER BY "subquery"."closed" DESC
4636 LIMIT "limit_p";
4637 RETURN;
4638 END IF;
4639 SELECT count(1) INTO "count_v"
4640 FROM (
4641 SELECT "initiative"."id" AS "initiative_id"
4642 FROM "initiative"
4643 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4644 WHERE "issue"."closed" NOTNULL
4645 ORDER BY "closed" DESC
4646 LIMIT "limit_v"
4647 ) AS "subquery"
4648 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4649 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4650 LIMIT "limit_p";
4651 IF "count_v" >= "limit_p" THEN
4652 RETURN QUERY SELECT "initiative".*
4653 FROM (
4654 SELECT
4655 "initiative"."id" AS "initiative_id",
4656 "issue"."closed"
4657 FROM "initiative"
4658 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4659 WHERE "issue"."closed" NOTNULL
4660 ORDER BY "closed" DESC
4661 LIMIT "limit_v"
4662 ) AS "subquery"
4663 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4664 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4665 ORDER BY "subquery"."closed" DESC
4666 LIMIT "limit_p";
4667 RETURN;
4668 END IF;
4669 "limit_v" := "limit_v" * 2;
4670 END LOOP;
4671 END;
4672 $$;
4674 COMMENT ON FUNCTION "closed_initiatives_in_bounding_box"
4675 ( EBOX, INT4 )
4676 IS 'TODO';
4677 */
4681 ---------------------------
4682 -- Transaction isolation --
4683 ---------------------------
4686 CREATE FUNCTION "require_transaction_isolation"()
4687 RETURNS VOID
4688 LANGUAGE 'plpgsql' VOLATILE AS $$
4689 BEGIN
4690 IF
4691 current_setting('transaction_isolation') NOT IN
4692 ('repeatable read', 'serializable')
4693 THEN
4694 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
4695 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
4696 END IF;
4697 RETURN;
4698 END;
4699 $$;
4701 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
4704 CREATE FUNCTION "dont_require_transaction_isolation"()
4705 RETURNS VOID
4706 LANGUAGE 'plpgsql' VOLATILE AS $$
4707 BEGIN
4708 IF
4709 current_setting('transaction_isolation') IN
4710 ('repeatable read', 'serializable')
4711 THEN
4712 RAISE WARNING 'Unneccessary transaction isolation level: %',
4713 current_setting('transaction_isolation');
4714 END IF;
4715 RETURN;
4716 END;
4717 $$;
4719 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
4723 -------------------------
4724 -- Notification system --
4725 -------------------------
4727 CREATE FUNCTION "get_initiatives_for_notification"
4728 ( "recipient_id_p" "member"."id"%TYPE )
4729 RETURNS SETOF "initiative_for_notification"
4730 LANGUAGE 'plpgsql' VOLATILE AS $$
4731 DECLARE
4732 "result_row" "initiative_for_notification"%ROWTYPE;
4733 "last_draft_id_v" "draft"."id"%TYPE;
4734 "last_suggestion_id_v" "suggestion"."id"%TYPE;
4735 BEGIN
4736 PERFORM "require_transaction_isolation"();
4737 PERFORM NULL FROM "member" WHERE "id" = "recipient_id_p" FOR UPDATE;
4738 FOR "result_row" IN
4739 SELECT * FROM "initiative_for_notification"
4740 WHERE "recipient_id" = "recipient_id_p"
4741 LOOP
4742 SELECT "id" INTO "last_draft_id_v" FROM "draft"
4743 WHERE "draft"."initiative_id" = "result_row"."initiative_id"
4744 ORDER BY "id" DESC LIMIT 1;
4745 SELECT "id" INTO "last_suggestion_id_v" FROM "suggestion"
4746 WHERE "suggestion"."initiative_id" = "result_row"."initiative_id"
4747 ORDER BY "id" DESC LIMIT 1;
4748 INSERT INTO "notification_initiative_sent"
4749 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
4750 VALUES (
4751 "recipient_id_p",
4752 "result_row"."initiative_id",
4753 "last_draft_id_v",
4754 "last_suggestion_id_v" )
4755 ON CONFLICT ("member_id", "initiative_id") DO UPDATE SET
4756 "last_draft_id" = "last_draft_id_v",
4757 "last_suggestion_id" = "last_suggestion_id_v";
4758 RETURN NEXT "result_row";
4759 END LOOP;
4760 DELETE FROM "notification_initiative_sent"
4761 USING "initiative", "issue"
4762 WHERE "notification_initiative_sent"."member_id" = "recipient_id_p"
4763 AND "initiative"."id" = "notification_initiative_sent"."initiative_id"
4764 AND "issue"."id" = "initiative"."issue_id"
4765 AND ( "issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL );
4766 UPDATE "member" SET
4767 "notification_counter" = "notification_counter" + 1,
4768 "notification_sent" = now()
4769 WHERE "id" = "recipient_id_p";
4770 RETURN;
4771 END;
4772 $$;
4774 COMMENT ON FUNCTION "get_initiatives_for_notification"
4775 ( "member"."id"%TYPE )
4776 IS 'Returns rows from view "initiative_for_notification" for a given recipient while updating table "notification_initiative_sent" and columns "notification_counter" and "notification_sent" of "member" table';
4780 ------------------------------------------------------------------------
4781 -- Regular tasks, except calculcation of snapshots and voting results --
4782 ------------------------------------------------------------------------
4785 CREATE FUNCTION "check_activity"()
4786 RETURNS VOID
4787 LANGUAGE 'plpgsql' VOLATILE AS $$
4788 DECLARE
4789 "system_setting_row" "system_setting"%ROWTYPE;
4790 BEGIN
4791 PERFORM "dont_require_transaction_isolation"();
4792 SELECT * INTO "system_setting_row" FROM "system_setting";
4793 IF "system_setting_row"."member_ttl" NOTNULL THEN
4794 UPDATE "member" SET "active" = FALSE
4795 WHERE "active" = TRUE
4796 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
4797 END IF;
4798 RETURN;
4799 END;
4800 $$;
4802 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
4805 CREATE FUNCTION "calculate_member_counts"()
4806 RETURNS VOID
4807 LANGUAGE 'plpgsql' VOLATILE AS $$
4808 BEGIN
4809 PERFORM "require_transaction_isolation"();
4810 DELETE FROM "member_count";
4811 INSERT INTO "member_count" ("total_count")
4812 SELECT "total_count" FROM "member_count_view";
4813 UPDATE "unit" SET "member_count" = "view"."member_count"
4814 FROM "unit_member_count" AS "view"
4815 WHERE "view"."unit_id" = "unit"."id";
4816 RETURN;
4817 END;
4818 $$;
4820 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 "unit_member_count"';
4824 ------------------------------------
4825 -- Calculation of harmonic weight --
4826 ------------------------------------
4829 CREATE VIEW "remaining_harmonic_supporter_weight" AS
4830 SELECT
4831 "direct_interest_snapshot"."snapshot_id",
4832 "direct_interest_snapshot"."issue_id",
4833 "direct_interest_snapshot"."member_id",
4834 "direct_interest_snapshot"."weight" AS "weight_num",
4835 count("initiative"."id") AS "weight_den"
4836 FROM "issue"
4837 JOIN "direct_interest_snapshot"
4838 ON "issue"."latest_snapshot_id" = "direct_interest_snapshot"."snapshot_id"
4839 AND "issue"."id" = "direct_interest_snapshot"."issue_id"
4840 JOIN "initiative"
4841 ON "issue"."id" = "initiative"."issue_id"
4842 AND "initiative"."harmonic_weight" ISNULL
4843 JOIN "direct_supporter_snapshot"
4844 ON "issue"."latest_snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
4845 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
4846 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
4847 AND (
4848 "direct_supporter_snapshot"."satisfied" = TRUE OR
4849 coalesce("initiative"."admitted", FALSE) = FALSE
4851 GROUP BY
4852 "direct_interest_snapshot"."snapshot_id",
4853 "direct_interest_snapshot"."issue_id",
4854 "direct_interest_snapshot"."member_id",
4855 "direct_interest_snapshot"."weight";
4857 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
4860 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
4861 SELECT
4862 "initiative"."issue_id",
4863 "initiative"."id" AS "initiative_id",
4864 "initiative"."admitted",
4865 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
4866 "remaining_harmonic_supporter_weight"."weight_den"
4867 FROM "remaining_harmonic_supporter_weight"
4868 JOIN "initiative"
4869 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
4870 AND "initiative"."harmonic_weight" ISNULL
4871 JOIN "direct_supporter_snapshot"
4872 ON "remaining_harmonic_supporter_weight"."snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
4873 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
4874 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
4875 AND (
4876 "direct_supporter_snapshot"."satisfied" = TRUE OR
4877 coalesce("initiative"."admitted", FALSE) = FALSE
4879 GROUP BY
4880 "initiative"."issue_id",
4881 "initiative"."id",
4882 "initiative"."admitted",
4883 "remaining_harmonic_supporter_weight"."weight_den";
4885 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
4888 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
4889 SELECT
4890 "issue_id",
4891 "id" AS "initiative_id",
4892 "admitted",
4893 0 AS "weight_num",
4894 1 AS "weight_den"
4895 FROM "initiative"
4896 WHERE "harmonic_weight" ISNULL;
4898 COMMENT ON VIEW "remaining_harmonic_initiative_weight_dummies" IS 'Helper view for function "set_harmonic_initiative_weights" providing dummy weights of zero value, which are needed for corner cases where there are no supporters for an initiative at all';
4901 CREATE FUNCTION "set_harmonic_initiative_weights"
4902 ( "issue_id_p" "issue"."id"%TYPE )
4903 RETURNS VOID
4904 LANGUAGE 'plpgsql' VOLATILE AS $$
4905 DECLARE
4906 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
4907 "i" INT4;
4908 "count_v" INT4;
4909 "summand_v" FLOAT;
4910 "id_ary" INT4[];
4911 "weight_ary" FLOAT[];
4912 "min_weight_v" FLOAT;
4913 BEGIN
4914 PERFORM "require_transaction_isolation"();
4915 UPDATE "initiative" SET "harmonic_weight" = NULL
4916 WHERE "issue_id" = "issue_id_p";
4917 LOOP
4918 "min_weight_v" := NULL;
4919 "i" := 0;
4920 "count_v" := 0;
4921 FOR "weight_row" IN
4922 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
4923 WHERE "issue_id" = "issue_id_p"
4924 AND (
4925 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
4926 SELECT NULL FROM "initiative"
4927 WHERE "issue_id" = "issue_id_p"
4928 AND "harmonic_weight" ISNULL
4929 AND coalesce("admitted", FALSE) = FALSE
4932 UNION ALL -- needed for corner cases
4933 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
4934 WHERE "issue_id" = "issue_id_p"
4935 AND (
4936 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
4937 SELECT NULL FROM "initiative"
4938 WHERE "issue_id" = "issue_id_p"
4939 AND "harmonic_weight" ISNULL
4940 AND coalesce("admitted", FALSE) = FALSE
4943 ORDER BY "initiative_id" DESC, "weight_den" DESC
4944 -- NOTE: non-admitted initiatives placed first (at last positions),
4945 -- latest initiatives treated worse in case of tie
4946 LOOP
4947 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
4948 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
4949 "i" := "i" + 1;
4950 "count_v" := "i";
4951 "id_ary"["i"] := "weight_row"."initiative_id";
4952 "weight_ary"["i"] := "summand_v";
4953 ELSE
4954 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
4955 END IF;
4956 END LOOP;
4957 EXIT WHEN "count_v" = 0;
4958 "i" := 1;
4959 LOOP
4960 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
4961 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
4962 "min_weight_v" := "weight_ary"["i"];
4963 END IF;
4964 "i" := "i" + 1;
4965 EXIT WHEN "i" > "count_v";
4966 END LOOP;
4967 "i" := 1;
4968 LOOP
4969 IF "weight_ary"["i"] = "min_weight_v" THEN
4970 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
4971 WHERE "id" = "id_ary"["i"];
4972 EXIT;
4973 END IF;
4974 "i" := "i" + 1;
4975 END LOOP;
4976 END LOOP;
4977 UPDATE "initiative" SET "harmonic_weight" = 0
4978 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
4979 END;
4980 $$;
4982 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
4983 ( "issue"."id"%TYPE )
4984 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
4988 ------------------------------
4989 -- Calculation of snapshots --
4990 ------------------------------
4993 CREATE FUNCTION "weight_of_added_delegations_for_snapshot"
4994 ( "snapshot_id_p" "snapshot"."id"%TYPE,
4995 "issue_id_p" "issue"."id"%TYPE,
4996 "member_id_p" "member"."id"%TYPE,
4997 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
4998 RETURNS "direct_interest_snapshot"."weight"%TYPE
4999 LANGUAGE 'plpgsql' VOLATILE AS $$
5000 DECLARE
5001 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5002 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
5003 "weight_v" INT4;
5004 "sub_weight_v" INT4;
5005 BEGIN
5006 PERFORM "require_transaction_isolation"();
5007 "weight_v" := 0;
5008 FOR "issue_delegation_row" IN
5009 SELECT * FROM "issue_delegation"
5010 WHERE "trustee_id" = "member_id_p"
5011 AND "issue_id" = "issue_id_p"
5012 LOOP
5013 IF NOT EXISTS (
5014 SELECT NULL FROM "direct_interest_snapshot"
5015 WHERE "snapshot_id" = "snapshot_id_p"
5016 AND "issue_id" = "issue_id_p"
5017 AND "member_id" = "issue_delegation_row"."truster_id"
5018 ) AND NOT EXISTS (
5019 SELECT NULL FROM "delegating_interest_snapshot"
5020 WHERE "snapshot_id" = "snapshot_id_p"
5021 AND "issue_id" = "issue_id_p"
5022 AND "member_id" = "issue_delegation_row"."truster_id"
5023 ) THEN
5024 "delegate_member_ids_v" :=
5025 "member_id_p" || "delegate_member_ids_p";
5026 INSERT INTO "delegating_interest_snapshot" (
5027 "snapshot_id",
5028 "issue_id",
5029 "member_id",
5030 "scope",
5031 "delegate_member_ids"
5032 ) VALUES (
5033 "snapshot_id_p",
5034 "issue_id_p",
5035 "issue_delegation_row"."truster_id",
5036 "issue_delegation_row"."scope",
5037 "delegate_member_ids_v"
5038 );
5039 "sub_weight_v" := 1 +
5040 "weight_of_added_delegations_for_snapshot"(
5041 "snapshot_id_p",
5042 "issue_id_p",
5043 "issue_delegation_row"."truster_id",
5044 "delegate_member_ids_v"
5045 );
5046 UPDATE "delegating_interest_snapshot"
5047 SET "weight" = "sub_weight_v"
5048 WHERE "snapshot_id" = "snapshot_id_p"
5049 AND "issue_id" = "issue_id_p"
5050 AND "member_id" = "issue_delegation_row"."truster_id";
5051 "weight_v" := "weight_v" + "sub_weight_v";
5052 END IF;
5053 END LOOP;
5054 RETURN "weight_v";
5055 END;
5056 $$;
5058 COMMENT ON FUNCTION "weight_of_added_delegations_for_snapshot"
5059 ( "snapshot"."id"%TYPE,
5060 "issue"."id"%TYPE,
5061 "member"."id"%TYPE,
5062 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
5063 IS 'Helper function for "fill_snapshot" function';
5066 CREATE FUNCTION "take_snapshot"
5067 ( "issue_id_p" "issue"."id"%TYPE,
5068 "area_id_p" "area"."id"%TYPE = NULL )
5069 RETURNS "snapshot"."id"%TYPE
5070 LANGUAGE 'plpgsql' VOLATILE AS $$
5071 DECLARE
5072 "area_id_v" "area"."id"%TYPE;
5073 "unit_id_v" "unit"."id"%TYPE;
5074 "snapshot_id_v" "snapshot"."id"%TYPE;
5075 "issue_id_v" "issue"."id"%TYPE;
5076 "member_id_v" "member"."id"%TYPE;
5077 BEGIN
5078 IF "issue_id_p" NOTNULL AND "area_id_p" NOTNULL THEN
5079 RAISE EXCEPTION 'One of "issue_id_p" and "area_id_p" must be NULL';
5080 END IF;
5081 PERFORM "require_transaction_isolation"();
5082 IF "issue_id_p" ISNULL THEN
5083 "area_id_v" := "area_id_p";
5084 ELSE
5085 SELECT "area_id" INTO "area_id_v"
5086 FROM "issue" WHERE "id" = "issue_id_p";
5087 END IF;
5088 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5089 INSERT INTO "snapshot" ("area_id", "issue_id")
5090 VALUES ("area_id_v", "issue_id_p")
5091 RETURNING "id" INTO "snapshot_id_v";
5092 INSERT INTO "snapshot_population" ("snapshot_id", "member_id")
5093 SELECT "snapshot_id_v", "member_id"
5094 FROM "unit_member" WHERE "unit_id" = "unit_id_v";
5095 UPDATE "snapshot" SET
5096 "population" = (
5097 SELECT count(1) FROM "snapshot_population"
5098 WHERE "snapshot_id" = "snapshot_id_v"
5099 ) WHERE "id" = "snapshot_id_v";
5100 FOR "issue_id_v" IN
5101 SELECT "id" FROM "issue"
5102 WHERE CASE WHEN "issue_id_p" ISNULL THEN
5103 "area_id" = "area_id_p" AND
5104 "state" = 'admission'
5105 ELSE
5106 "id" = "issue_id_p"
5107 END
5108 LOOP
5109 INSERT INTO "snapshot_issue" ("snapshot_id", "issue_id")
5110 VALUES ("snapshot_id_v", "issue_id_v");
5111 INSERT INTO "direct_interest_snapshot"
5112 ("snapshot_id", "issue_id", "member_id")
5113 SELECT
5114 "snapshot_id_v" AS "snapshot_id",
5115 "issue_id_v" AS "issue_id",
5116 "member"."id" AS "member_id"
5117 FROM "issue"
5118 JOIN "area" ON "issue"."area_id" = "area"."id"
5119 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
5120 JOIN "member" ON "interest"."member_id" = "member"."id"
5121 JOIN "privilege"
5122 ON "privilege"."unit_id" = "area"."unit_id"
5123 AND "privilege"."member_id" = "member"."id"
5124 WHERE "issue"."id" = "issue_id_v"
5125 AND "member"."active" AND "privilege"."voting_right";
5126 FOR "member_id_v" IN
5127 SELECT "member_id" FROM "direct_interest_snapshot"
5128 WHERE "snapshot_id" = "snapshot_id_v"
5129 AND "issue_id" = "issue_id_v"
5130 LOOP
5131 UPDATE "direct_interest_snapshot" SET
5132 "weight" = 1 +
5133 "weight_of_added_delegations_for_snapshot"(
5134 "snapshot_id_v",
5135 "issue_id_v",
5136 "member_id_v",
5137 '{}'
5139 WHERE "snapshot_id" = "snapshot_id_v"
5140 AND "issue_id" = "issue_id_v"
5141 AND "member_id" = "member_id_v";
5142 END LOOP;
5143 INSERT INTO "direct_supporter_snapshot"
5144 ( "snapshot_id", "issue_id", "initiative_id", "member_id",
5145 "draft_id", "informed", "satisfied" )
5146 SELECT
5147 "snapshot_id_v" AS "snapshot_id",
5148 "issue_id_v" AS "issue_id",
5149 "initiative"."id" AS "initiative_id",
5150 "supporter"."member_id" AS "member_id",
5151 "supporter"."draft_id" AS "draft_id",
5152 "supporter"."draft_id" = "current_draft"."id" AS "informed",
5153 NOT EXISTS (
5154 SELECT NULL FROM "critical_opinion"
5155 WHERE "initiative_id" = "initiative"."id"
5156 AND "member_id" = "supporter"."member_id"
5157 ) AS "satisfied"
5158 FROM "initiative"
5159 JOIN "supporter"
5160 ON "supporter"."initiative_id" = "initiative"."id"
5161 JOIN "current_draft"
5162 ON "initiative"."id" = "current_draft"."initiative_id"
5163 JOIN "direct_interest_snapshot"
5164 ON "snapshot_id_v" = "direct_interest_snapshot"."snapshot_id"
5165 AND "supporter"."member_id" = "direct_interest_snapshot"."member_id"
5166 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
5167 WHERE "initiative"."issue_id" = "issue_id_v";
5168 DELETE FROM "temporary_suggestion_counts";
5169 INSERT INTO "temporary_suggestion_counts"
5170 ( "id",
5171 "minus2_unfulfilled_count", "minus2_fulfilled_count",
5172 "minus1_unfulfilled_count", "minus1_fulfilled_count",
5173 "plus1_unfulfilled_count", "plus1_fulfilled_count",
5174 "plus2_unfulfilled_count", "plus2_fulfilled_count" )
5175 SELECT
5176 "suggestion"."id",
5177 ( SELECT coalesce(sum("di"."weight"), 0)
5178 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5179 ON "di"."snapshot_id" = "snapshot_id_v"
5180 AND "di"."issue_id" = "issue_id_v"
5181 AND "di"."member_id" = "opinion"."member_id"
5182 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5183 AND "opinion"."degree" = -2
5184 AND "opinion"."fulfilled" = FALSE
5185 ) AS "minus2_unfulfilled_count",
5186 ( SELECT coalesce(sum("di"."weight"), 0)
5187 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5188 ON "di"."snapshot_id" = "snapshot_id_v"
5189 AND "di"."issue_id" = "issue_id_v"
5190 AND "di"."member_id" = "opinion"."member_id"
5191 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5192 AND "opinion"."degree" = -2
5193 AND "opinion"."fulfilled" = TRUE
5194 ) AS "minus2_fulfilled_count",
5195 ( SELECT coalesce(sum("di"."weight"), 0)
5196 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5197 ON "di"."snapshot_id" = "snapshot_id_v"
5198 AND "di"."issue_id" = "issue_id_v"
5199 AND "di"."member_id" = "opinion"."member_id"
5200 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5201 AND "opinion"."degree" = -1
5202 AND "opinion"."fulfilled" = FALSE
5203 ) AS "minus1_unfulfilled_count",
5204 ( SELECT coalesce(sum("di"."weight"), 0)
5205 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5206 ON "di"."snapshot_id" = "snapshot_id_v"
5207 AND "di"."issue_id" = "issue_id_v"
5208 AND "di"."member_id" = "opinion"."member_id"
5209 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5210 AND "opinion"."degree" = -1
5211 AND "opinion"."fulfilled" = TRUE
5212 ) AS "minus1_fulfilled_count",
5213 ( SELECT coalesce(sum("di"."weight"), 0)
5214 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5215 ON "di"."snapshot_id" = "snapshot_id_v"
5216 AND "di"."issue_id" = "issue_id_v"
5217 AND "di"."member_id" = "opinion"."member_id"
5218 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5219 AND "opinion"."degree" = 1
5220 AND "opinion"."fulfilled" = FALSE
5221 ) AS "plus1_unfulfilled_count",
5222 ( SELECT coalesce(sum("di"."weight"), 0)
5223 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5224 ON "di"."snapshot_id" = "snapshot_id_v"
5225 AND "di"."issue_id" = "issue_id_v"
5226 AND "di"."member_id" = "opinion"."member_id"
5227 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5228 AND "opinion"."degree" = 1
5229 AND "opinion"."fulfilled" = TRUE
5230 ) AS "plus1_fulfilled_count",
5231 ( SELECT coalesce(sum("di"."weight"), 0)
5232 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5233 ON "di"."snapshot_id" = "snapshot_id_v"
5234 AND "di"."issue_id" = "issue_id_v"
5235 AND "di"."member_id" = "opinion"."member_id"
5236 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5237 AND "opinion"."degree" = 2
5238 AND "opinion"."fulfilled" = FALSE
5239 ) AS "plus2_unfulfilled_count",
5240 ( SELECT coalesce(sum("di"."weight"), 0)
5241 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5242 ON "di"."snapshot_id" = "snapshot_id_v"
5243 AND "di"."issue_id" = "issue_id_v"
5244 AND "di"."member_id" = "opinion"."member_id"
5245 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5246 AND "opinion"."degree" = 2
5247 AND "opinion"."fulfilled" = TRUE
5248 ) AS "plus2_fulfilled_count"
5249 FROM "suggestion" JOIN "initiative"
5250 ON "suggestion"."initiative_id" = "initiative"."id"
5251 WHERE "initiative"."issue_id" = "issue_id_v";
5252 END LOOP;
5253 RETURN "snapshot_id_v";
5254 END;
5255 $$;
5257 COMMENT ON FUNCTION "take_snapshot"
5258 ( "issue"."id"%TYPE,
5259 "area"."id"%TYPE )
5260 IS 'This function creates a new interest/supporter snapshot of a particular issue, or, if the first argument is NULL, for all issues in ''admission'' phase of the area given as second argument. It must be executed with TRANSACTION ISOLATION LEVEL REPEATABLE READ. The snapshot must later be finished by calling "finish_snapshot" for every issue.';
5263 CREATE FUNCTION "finish_snapshot"
5264 ( "issue_id_p" "issue"."id"%TYPE )
5265 RETURNS VOID
5266 LANGUAGE 'plpgsql' VOLATILE AS $$
5267 DECLARE
5268 "snapshot_id_v" "snapshot"."id"%TYPE;
5269 BEGIN
5270 -- NOTE: function does not require snapshot isolation but we don't call
5271 -- "dont_require_snapshot_isolation" here because this function is
5272 -- also invoked by "check_issue"
5273 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
5274 SELECT "id" INTO "snapshot_id_v" FROM "snapshot"
5275 ORDER BY "id" DESC LIMIT 1;
5276 UPDATE "issue" SET
5277 "calculated" = "snapshot"."calculated",
5278 "latest_snapshot_id" = "snapshot_id_v",
5279 "population" = "snapshot"."population",
5280 "initiative_quorum" = CASE WHEN
5281 "policy"."initiative_quorum" > ceil(
5282 ( "issue"."population"::INT8 *
5283 "policy"."initiative_quorum_num"::INT8 ) /
5284 "policy"."initiative_quorum_den"::FLOAT8
5285 )::INT4
5286 THEN
5287 "policy"."initiative_quorum"
5288 ELSE
5289 ceil(
5290 ( "issue"."population"::INT8 *
5291 "policy"."initiative_quorum_num"::INT8 ) /
5292 "policy"."initiative_quorum_den"::FLOAT8
5293 )::INT4
5294 END
5295 FROM "snapshot", "policy"
5296 WHERE "issue"."id" = "issue_id_p"
5297 AND "snapshot"."id" = "snapshot_id_v"
5298 AND "policy"."id" = "issue"."policy_id";
5299 UPDATE "initiative" SET
5300 "supporter_count" = (
5301 SELECT coalesce(sum("di"."weight"), 0)
5302 FROM "direct_interest_snapshot" AS "di"
5303 JOIN "direct_supporter_snapshot" AS "ds"
5304 ON "di"."member_id" = "ds"."member_id"
5305 WHERE "di"."snapshot_id" = "snapshot_id_v"
5306 AND "di"."issue_id" = "issue_id_p"
5307 AND "ds"."snapshot_id" = "snapshot_id_v"
5308 AND "ds"."initiative_id" = "initiative"."id"
5309 ),
5310 "informed_supporter_count" = (
5311 SELECT coalesce(sum("di"."weight"), 0)
5312 FROM "direct_interest_snapshot" AS "di"
5313 JOIN "direct_supporter_snapshot" AS "ds"
5314 ON "di"."member_id" = "ds"."member_id"
5315 WHERE "di"."snapshot_id" = "snapshot_id_v"
5316 AND "di"."issue_id" = "issue_id_p"
5317 AND "ds"."snapshot_id" = "snapshot_id_v"
5318 AND "ds"."initiative_id" = "initiative"."id"
5319 AND "ds"."informed"
5320 ),
5321 "satisfied_supporter_count" = (
5322 SELECT coalesce(sum("di"."weight"), 0)
5323 FROM "direct_interest_snapshot" AS "di"
5324 JOIN "direct_supporter_snapshot" AS "ds"
5325 ON "di"."member_id" = "ds"."member_id"
5326 WHERE "di"."snapshot_id" = "snapshot_id_v"
5327 AND "di"."issue_id" = "issue_id_p"
5328 AND "ds"."snapshot_id" = "snapshot_id_v"
5329 AND "ds"."initiative_id" = "initiative"."id"
5330 AND "ds"."satisfied"
5331 ),
5332 "satisfied_informed_supporter_count" = (
5333 SELECT coalesce(sum("di"."weight"), 0)
5334 FROM "direct_interest_snapshot" AS "di"
5335 JOIN "direct_supporter_snapshot" AS "ds"
5336 ON "di"."member_id" = "ds"."member_id"
5337 WHERE "di"."snapshot_id" = "snapshot_id_v"
5338 AND "di"."issue_id" = "issue_id_p"
5339 AND "ds"."snapshot_id" = "snapshot_id_v"
5340 AND "ds"."initiative_id" = "initiative"."id"
5341 AND "ds"."informed"
5342 AND "ds"."satisfied"
5344 WHERE "issue_id" = "issue_id_p";
5345 UPDATE "suggestion" SET
5346 "minus2_unfulfilled_count" = "temp"."minus2_unfulfilled_count",
5347 "minus2_fulfilled_count" = "temp"."minus2_fulfilled_count",
5348 "minus1_unfulfilled_count" = "temp"."minus1_unfulfilled_count",
5349 "minus1_fulfilled_count" = "temp"."minus1_fulfilled_count",
5350 "plus1_unfulfilled_count" = "temp"."plus1_unfulfilled_count",
5351 "plus1_fulfilled_count" = "temp"."plus1_fulfilled_count",
5352 "plus2_unfulfilled_count" = "temp"."plus2_unfulfilled_count",
5353 "plus2_fulfilled_count" = "temp"."plus2_fulfilled_count"
5354 FROM "temporary_suggestion_counts" AS "temp", "initiative"
5355 WHERE "temp"."id" = "suggestion"."id"
5356 AND "initiative"."issue_id" = "issue_id_p"
5357 AND "suggestion"."initiative_id" = "initiative"."id";
5358 DELETE FROM "temporary_suggestion_counts";
5359 RETURN;
5360 END;
5361 $$;
5363 COMMENT ON FUNCTION "finish_snapshot"
5364 ( "issue"."id"%TYPE )
5365 IS 'After calling "take_snapshot", this function "finish_snapshot" needs to be called for every issue in the snapshot (separate function calls keep locking time minimal)';
5369 -----------------------
5370 -- Counting of votes --
5371 -----------------------
5374 CREATE FUNCTION "weight_of_added_vote_delegations"
5375 ( "issue_id_p" "issue"."id"%TYPE,
5376 "member_id_p" "member"."id"%TYPE,
5377 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
5378 RETURNS "direct_voter"."weight"%TYPE
5379 LANGUAGE 'plpgsql' VOLATILE AS $$
5380 DECLARE
5381 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5382 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
5383 "weight_v" INT4;
5384 "sub_weight_v" INT4;
5385 BEGIN
5386 PERFORM "require_transaction_isolation"();
5387 "weight_v" := 0;
5388 FOR "issue_delegation_row" IN
5389 SELECT * FROM "issue_delegation"
5390 WHERE "trustee_id" = "member_id_p"
5391 AND "issue_id" = "issue_id_p"
5392 LOOP
5393 IF NOT EXISTS (
5394 SELECT NULL FROM "direct_voter"
5395 WHERE "member_id" = "issue_delegation_row"."truster_id"
5396 AND "issue_id" = "issue_id_p"
5397 ) AND NOT EXISTS (
5398 SELECT NULL FROM "delegating_voter"
5399 WHERE "member_id" = "issue_delegation_row"."truster_id"
5400 AND "issue_id" = "issue_id_p"
5401 ) THEN
5402 "delegate_member_ids_v" :=
5403 "member_id_p" || "delegate_member_ids_p";
5404 INSERT INTO "delegating_voter" (
5405 "issue_id",
5406 "member_id",
5407 "scope",
5408 "delegate_member_ids"
5409 ) VALUES (
5410 "issue_id_p",
5411 "issue_delegation_row"."truster_id",
5412 "issue_delegation_row"."scope",
5413 "delegate_member_ids_v"
5414 );
5415 "sub_weight_v" := 1 +
5416 "weight_of_added_vote_delegations"(
5417 "issue_id_p",
5418 "issue_delegation_row"."truster_id",
5419 "delegate_member_ids_v"
5420 );
5421 UPDATE "delegating_voter"
5422 SET "weight" = "sub_weight_v"
5423 WHERE "issue_id" = "issue_id_p"
5424 AND "member_id" = "issue_delegation_row"."truster_id";
5425 "weight_v" := "weight_v" + "sub_weight_v";
5426 END IF;
5427 END LOOP;
5428 RETURN "weight_v";
5429 END;
5430 $$;
5432 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
5433 ( "issue"."id"%TYPE,
5434 "member"."id"%TYPE,
5435 "delegating_voter"."delegate_member_ids"%TYPE )
5436 IS 'Helper function for "add_vote_delegations" function';
5439 CREATE FUNCTION "add_vote_delegations"
5440 ( "issue_id_p" "issue"."id"%TYPE )
5441 RETURNS VOID
5442 LANGUAGE 'plpgsql' VOLATILE AS $$
5443 DECLARE
5444 "member_id_v" "member"."id"%TYPE;
5445 BEGIN
5446 PERFORM "require_transaction_isolation"();
5447 FOR "member_id_v" IN
5448 SELECT "member_id" FROM "direct_voter"
5449 WHERE "issue_id" = "issue_id_p"
5450 LOOP
5451 UPDATE "direct_voter" SET
5452 "weight" = "weight" + "weight_of_added_vote_delegations"(
5453 "issue_id_p",
5454 "member_id_v",
5455 '{}'
5457 WHERE "member_id" = "member_id_v"
5458 AND "issue_id" = "issue_id_p";
5459 END LOOP;
5460 RETURN;
5461 END;
5462 $$;
5464 COMMENT ON FUNCTION "add_vote_delegations"
5465 ( "issue_id_p" "issue"."id"%TYPE )
5466 IS 'Helper function for "close_voting" function';
5469 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
5470 RETURNS VOID
5471 LANGUAGE 'plpgsql' VOLATILE AS $$
5472 DECLARE
5473 "area_id_v" "area"."id"%TYPE;
5474 "unit_id_v" "unit"."id"%TYPE;
5475 "member_id_v" "member"."id"%TYPE;
5476 BEGIN
5477 PERFORM "require_transaction_isolation"();
5478 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
5479 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5480 -- override protection triggers:
5481 INSERT INTO "temporary_transaction_data" ("key", "value")
5482 VALUES ('override_protection_triggers', TRUE::TEXT);
5483 -- delete timestamp of voting comment:
5484 UPDATE "direct_voter" SET "comment_changed" = NULL
5485 WHERE "issue_id" = "issue_id_p";
5486 -- delete delegating votes (in cases of manual reset of issue state):
5487 DELETE FROM "delegating_voter"
5488 WHERE "issue_id" = "issue_id_p";
5489 -- delete votes from non-privileged voters:
5490 DELETE FROM "direct_voter"
5491 USING (
5492 SELECT
5493 "direct_voter"."member_id"
5494 FROM "direct_voter"
5495 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
5496 LEFT JOIN "privilege"
5497 ON "privilege"."unit_id" = "unit_id_v"
5498 AND "privilege"."member_id" = "direct_voter"."member_id"
5499 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
5500 "member"."active" = FALSE OR
5501 "privilege"."voting_right" ISNULL OR
5502 "privilege"."voting_right" = FALSE
5504 ) AS "subquery"
5505 WHERE "direct_voter"."issue_id" = "issue_id_p"
5506 AND "direct_voter"."member_id" = "subquery"."member_id";
5507 -- consider delegations:
5508 UPDATE "direct_voter" SET "weight" = 1
5509 WHERE "issue_id" = "issue_id_p";
5510 PERFORM "add_vote_delegations"("issue_id_p");
5511 -- mark first preferences:
5512 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
5513 FROM (
5514 SELECT
5515 "vote"."initiative_id",
5516 "vote"."member_id",
5517 CASE WHEN "vote"."grade" > 0 THEN
5518 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
5519 ELSE NULL
5520 END AS "first_preference"
5521 FROM "vote"
5522 JOIN "initiative" -- NOTE: due to missing index on issue_id
5523 ON "vote"."issue_id" = "initiative"."issue_id"
5524 JOIN "vote" AS "agg"
5525 ON "initiative"."id" = "agg"."initiative_id"
5526 AND "vote"."member_id" = "agg"."member_id"
5527 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
5528 ) AS "subquery"
5529 WHERE "vote"."issue_id" = "issue_id_p"
5530 AND "vote"."initiative_id" = "subquery"."initiative_id"
5531 AND "vote"."member_id" = "subquery"."member_id";
5532 -- finish overriding protection triggers (avoids garbage):
5533 DELETE FROM "temporary_transaction_data"
5534 WHERE "key" = 'override_protection_triggers';
5535 -- materialize battle_view:
5536 -- NOTE: "closed" column of issue must be set at this point
5537 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
5538 INSERT INTO "battle" (
5539 "issue_id",
5540 "winning_initiative_id", "losing_initiative_id",
5541 "count"
5542 ) SELECT
5543 "issue_id",
5544 "winning_initiative_id", "losing_initiative_id",
5545 "count"
5546 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
5547 -- set voter count:
5548 UPDATE "issue" SET
5549 "voter_count" = (
5550 SELECT coalesce(sum("weight"), 0)
5551 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
5553 WHERE "id" = "issue_id_p";
5554 -- copy "positive_votes" and "negative_votes" from "battle" table:
5555 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
5556 UPDATE "initiative" SET
5557 "first_preference_votes" = 0,
5558 "positive_votes" = "battle_win"."count",
5559 "negative_votes" = "battle_lose"."count"
5560 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
5561 WHERE
5562 "battle_win"."issue_id" = "issue_id_p" AND
5563 "battle_win"."winning_initiative_id" = "initiative"."id" AND
5564 "battle_win"."losing_initiative_id" ISNULL AND
5565 "battle_lose"."issue_id" = "issue_id_p" AND
5566 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
5567 "battle_lose"."winning_initiative_id" ISNULL;
5568 -- calculate "first_preference_votes":
5569 -- NOTE: will only set values not equal to zero
5570 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
5571 FROM (
5572 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
5573 FROM "vote" JOIN "direct_voter"
5574 ON "vote"."issue_id" = "direct_voter"."issue_id"
5575 AND "vote"."member_id" = "direct_voter"."member_id"
5576 WHERE "vote"."first_preference"
5577 GROUP BY "vote"."initiative_id"
5578 ) AS "subquery"
5579 WHERE "initiative"."issue_id" = "issue_id_p"
5580 AND "initiative"."admitted"
5581 AND "initiative"."id" = "subquery"."initiative_id";
5582 END;
5583 $$;
5585 COMMENT ON FUNCTION "close_voting"
5586 ( "issue"."id"%TYPE )
5587 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.';
5590 CREATE FUNCTION "defeat_strength"
5591 ( "positive_votes_p" INT4,
5592 "negative_votes_p" INT4,
5593 "defeat_strength_p" "defeat_strength" )
5594 RETURNS INT8
5595 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5596 BEGIN
5597 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
5598 IF "positive_votes_p" > "negative_votes_p" THEN
5599 RETURN "positive_votes_p";
5600 ELSE
5601 RETURN 0;
5602 END IF;
5603 ELSE
5604 IF "positive_votes_p" > "negative_votes_p" THEN
5605 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
5606 ELSIF "positive_votes_p" = "negative_votes_p" THEN
5607 RETURN 0;
5608 ELSE
5609 RETURN -1;
5610 END IF;
5611 END IF;
5612 END;
5613 $$;
5615 COMMENT ON FUNCTION "defeat_strength"(INT4, INT4, "defeat_strength") IS 'Calculates defeat strength (INT8!) according to the "defeat_strength" option (see comment on type "defeat_strength")';
5618 CREATE FUNCTION "secondary_link_strength"
5619 ( "initiative1_ord_p" INT4,
5620 "initiative2_ord_p" INT4,
5621 "tie_breaking_p" "tie_breaking" )
5622 RETURNS INT8
5623 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5624 BEGIN
5625 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
5626 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
5627 END IF;
5628 RETURN (
5629 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
5631 ELSE
5632 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
5633 1::INT8 << 62
5634 ELSE 0 END
5636 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
5637 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
5638 ELSE
5639 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
5640 END
5641 END
5642 );
5643 END;
5644 $$;
5646 COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4, "tie_breaking") IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)';
5649 CREATE TYPE "link_strength" AS (
5650 "primary" INT8,
5651 "secondary" INT8 );
5653 COMMENT ON TYPE "link_strength" IS 'Type to store the defeat strength of a link between two candidates plus a secondary criterion to create unique link strengths between the candidates (needed for tie-breaking ''variant1'' and ''variant2'')';
5656 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
5657 RETURNS "link_strength"[][]
5658 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5659 DECLARE
5660 "dimension_v" INT4;
5661 "matrix_p" "link_strength"[][];
5662 "i" INT4;
5663 "j" INT4;
5664 "k" INT4;
5665 BEGIN
5666 "dimension_v" := array_upper("matrix_d", 1);
5667 "matrix_p" := "matrix_d";
5668 "i" := 1;
5669 LOOP
5670 "j" := 1;
5671 LOOP
5672 IF "i" != "j" THEN
5673 "k" := 1;
5674 LOOP
5675 IF "i" != "k" AND "j" != "k" THEN
5676 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
5677 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
5678 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
5679 END IF;
5680 ELSE
5681 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
5682 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
5683 END IF;
5684 END IF;
5685 END IF;
5686 EXIT WHEN "k" = "dimension_v";
5687 "k" := "k" + 1;
5688 END LOOP;
5689 END IF;
5690 EXIT WHEN "j" = "dimension_v";
5691 "j" := "j" + 1;
5692 END LOOP;
5693 EXIT WHEN "i" = "dimension_v";
5694 "i" := "i" + 1;
5695 END LOOP;
5696 RETURN "matrix_p";
5697 END;
5698 $$;
5700 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
5703 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
5704 RETURNS VOID
5705 LANGUAGE 'plpgsql' VOLATILE AS $$
5706 DECLARE
5707 "issue_row" "issue"%ROWTYPE;
5708 "policy_row" "policy"%ROWTYPE;
5709 "dimension_v" INT4;
5710 "matrix_a" INT4[][]; -- absolute votes
5711 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
5712 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
5713 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
5714 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
5715 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
5716 "i" INT4;
5717 "j" INT4;
5718 "m" INT4;
5719 "n" INT4;
5720 "battle_row" "battle"%ROWTYPE;
5721 "rank_ary" INT4[];
5722 "rank_v" INT4;
5723 "initiative_id_v" "initiative"."id"%TYPE;
5724 BEGIN
5725 PERFORM "require_transaction_isolation"();
5726 SELECT * INTO "issue_row"
5727 FROM "issue" WHERE "id" = "issue_id_p";
5728 SELECT * INTO "policy_row"
5729 FROM "policy" WHERE "id" = "issue_row"."policy_id";
5730 SELECT count(1) INTO "dimension_v"
5731 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
5732 -- create "matrix_a" with absolute number of votes in pairwise
5733 -- comparison:
5734 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
5735 "i" := 1;
5736 "j" := 2;
5737 FOR "battle_row" IN
5738 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
5739 ORDER BY
5740 "winning_initiative_id" NULLS FIRST,
5741 "losing_initiative_id" NULLS FIRST
5742 LOOP
5743 "matrix_a"["i"]["j"] := "battle_row"."count";
5744 IF "j" = "dimension_v" THEN
5745 "i" := "i" + 1;
5746 "j" := 1;
5747 ELSE
5748 "j" := "j" + 1;
5749 IF "j" = "i" THEN
5750 "j" := "j" + 1;
5751 END IF;
5752 END IF;
5753 END LOOP;
5754 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
5755 RAISE EXCEPTION 'Wrong battle count (should not happen)';
5756 END IF;
5757 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
5758 -- and "secondary_link_strength" functions:
5759 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
5760 "i" := 1;
5761 LOOP
5762 "j" := 1;
5763 LOOP
5764 IF "i" != "j" THEN
5765 "matrix_d"["i"]["j"] := (
5766 "defeat_strength"(
5767 "matrix_a"["i"]["j"],
5768 "matrix_a"["j"]["i"],
5769 "policy_row"."defeat_strength"
5770 ),
5771 "secondary_link_strength"(
5772 "i",
5773 "j",
5774 "policy_row"."tie_breaking"
5776 )::"link_strength";
5777 END IF;
5778 EXIT WHEN "j" = "dimension_v";
5779 "j" := "j" + 1;
5780 END LOOP;
5781 EXIT WHEN "i" = "dimension_v";
5782 "i" := "i" + 1;
5783 END LOOP;
5784 -- find best paths:
5785 "matrix_p" := "find_best_paths"("matrix_d");
5786 -- create partial order:
5787 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
5788 "i" := 1;
5789 LOOP
5790 "j" := "i" + 1;
5791 LOOP
5792 IF "i" != "j" THEN
5793 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
5794 "matrix_b"["i"]["j"] := TRUE;
5795 "matrix_b"["j"]["i"] := FALSE;
5796 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
5797 "matrix_b"["i"]["j"] := FALSE;
5798 "matrix_b"["j"]["i"] := TRUE;
5799 END IF;
5800 END IF;
5801 EXIT WHEN "j" = "dimension_v";
5802 "j" := "j" + 1;
5803 END LOOP;
5804 EXIT WHEN "i" = "dimension_v" - 1;
5805 "i" := "i" + 1;
5806 END LOOP;
5807 -- tie-breaking by forbidding shared weakest links in beat-paths
5808 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
5809 -- is performed later by initiative id):
5810 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
5811 "m" := 1;
5812 LOOP
5813 "n" := "m" + 1;
5814 LOOP
5815 -- only process those candidates m and n, which are tied:
5816 IF "matrix_b"["m"]["n"] ISNULL THEN
5817 -- start with beat-paths prior tie-breaking:
5818 "matrix_t" := "matrix_p";
5819 -- start with all links allowed:
5820 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
5821 LOOP
5822 -- determine (and forbid) that link that is the weakest link
5823 -- in both the best path from candidate m to candidate n and
5824 -- from candidate n to candidate m:
5825 "i" := 1;
5826 <<forbid_one_link>>
5827 LOOP
5828 "j" := 1;
5829 LOOP
5830 IF "i" != "j" THEN
5831 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
5832 "matrix_f"["i"]["j"] := TRUE;
5833 -- exit for performance reasons,
5834 -- as exactly one link will be found:
5835 EXIT forbid_one_link;
5836 END IF;
5837 END IF;
5838 EXIT WHEN "j" = "dimension_v";
5839 "j" := "j" + 1;
5840 END LOOP;
5841 IF "i" = "dimension_v" THEN
5842 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
5843 END IF;
5844 "i" := "i" + 1;
5845 END LOOP;
5846 -- calculate best beat-paths while ignoring forbidden links:
5847 "i" := 1;
5848 LOOP
5849 "j" := 1;
5850 LOOP
5851 IF "i" != "j" THEN
5852 "matrix_t"["i"]["j"] := CASE
5853 WHEN "matrix_f"["i"]["j"]
5854 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
5855 ELSE "matrix_d"["i"]["j"] END;
5856 END IF;
5857 EXIT WHEN "j" = "dimension_v";
5858 "j" := "j" + 1;
5859 END LOOP;
5860 EXIT WHEN "i" = "dimension_v";
5861 "i" := "i" + 1;
5862 END LOOP;
5863 "matrix_t" := "find_best_paths"("matrix_t");
5864 -- extend partial order, if tie-breaking was successful:
5865 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
5866 "matrix_b"["m"]["n"] := TRUE;
5867 "matrix_b"["n"]["m"] := FALSE;
5868 EXIT;
5869 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
5870 "matrix_b"["m"]["n"] := FALSE;
5871 "matrix_b"["n"]["m"] := TRUE;
5872 EXIT;
5873 END IF;
5874 END LOOP;
5875 END IF;
5876 EXIT WHEN "n" = "dimension_v";
5877 "n" := "n" + 1;
5878 END LOOP;
5879 EXIT WHEN "m" = "dimension_v" - 1;
5880 "m" := "m" + 1;
5881 END LOOP;
5882 END IF;
5883 -- store a unique ranking in "rank_ary":
5884 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
5885 "rank_v" := 1;
5886 LOOP
5887 "i" := 1;
5888 <<assign_next_rank>>
5889 LOOP
5890 IF "rank_ary"["i"] ISNULL THEN
5891 "j" := 1;
5892 LOOP
5893 IF
5894 "i" != "j" AND
5895 "rank_ary"["j"] ISNULL AND
5896 ( "matrix_b"["j"]["i"] OR
5897 -- tie-breaking by "id"
5898 ( "matrix_b"["j"]["i"] ISNULL AND
5899 "j" < "i" ) )
5900 THEN
5901 -- someone else is better
5902 EXIT;
5903 END IF;
5904 IF "j" = "dimension_v" THEN
5905 -- noone is better
5906 "rank_ary"["i"] := "rank_v";
5907 EXIT assign_next_rank;
5908 END IF;
5909 "j" := "j" + 1;
5910 END LOOP;
5911 END IF;
5912 "i" := "i" + 1;
5913 IF "i" > "dimension_v" THEN
5914 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
5915 END IF;
5916 END LOOP;
5917 EXIT WHEN "rank_v" = "dimension_v";
5918 "rank_v" := "rank_v" + 1;
5919 END LOOP;
5920 -- write preliminary results:
5921 "i" := 2; -- omit status quo with "i" = 1
5922 FOR "initiative_id_v" IN
5923 SELECT "id" FROM "initiative"
5924 WHERE "issue_id" = "issue_id_p" AND "admitted"
5925 ORDER BY "id"
5926 LOOP
5927 UPDATE "initiative" SET
5928 "direct_majority" =
5929 CASE WHEN "policy_row"."direct_majority_strict" THEN
5930 "positive_votes" * "policy_row"."direct_majority_den" >
5931 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
5932 ELSE
5933 "positive_votes" * "policy_row"."direct_majority_den" >=
5934 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
5935 END
5936 AND "positive_votes" >= "policy_row"."direct_majority_positive"
5937 AND "issue_row"."voter_count"-"negative_votes" >=
5938 "policy_row"."direct_majority_non_negative",
5939 "indirect_majority" =
5940 CASE WHEN "policy_row"."indirect_majority_strict" THEN
5941 "positive_votes" * "policy_row"."indirect_majority_den" >
5942 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
5943 ELSE
5944 "positive_votes" * "policy_row"."indirect_majority_den" >=
5945 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
5946 END
5947 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
5948 AND "issue_row"."voter_count"-"negative_votes" >=
5949 "policy_row"."indirect_majority_non_negative",
5950 "schulze_rank" = "rank_ary"["i"],
5951 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
5952 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
5953 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
5954 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
5955 THEN NULL
5956 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
5957 "eligible" = FALSE,
5958 "winner" = FALSE,
5959 "rank" = NULL -- NOTE: in cases of manual reset of issue state
5960 WHERE "id" = "initiative_id_v";
5961 "i" := "i" + 1;
5962 END LOOP;
5963 IF "i" != "dimension_v" + 1 THEN
5964 RAISE EXCEPTION 'Wrong winner count (should not happen)';
5965 END IF;
5966 -- take indirect majorities into account:
5967 LOOP
5968 UPDATE "initiative" SET "indirect_majority" = TRUE
5969 FROM (
5970 SELECT "new_initiative"."id" AS "initiative_id"
5971 FROM "initiative" "old_initiative"
5972 JOIN "initiative" "new_initiative"
5973 ON "new_initiative"."issue_id" = "issue_id_p"
5974 AND "new_initiative"."indirect_majority" = FALSE
5975 JOIN "battle" "battle_win"
5976 ON "battle_win"."issue_id" = "issue_id_p"
5977 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
5978 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
5979 JOIN "battle" "battle_lose"
5980 ON "battle_lose"."issue_id" = "issue_id_p"
5981 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
5982 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
5983 WHERE "old_initiative"."issue_id" = "issue_id_p"
5984 AND "old_initiative"."indirect_majority" = TRUE
5985 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
5986 "battle_win"."count" * "policy_row"."indirect_majority_den" >
5987 "policy_row"."indirect_majority_num" *
5988 ("battle_win"."count"+"battle_lose"."count")
5989 ELSE
5990 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
5991 "policy_row"."indirect_majority_num" *
5992 ("battle_win"."count"+"battle_lose"."count")
5993 END
5994 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
5995 AND "issue_row"."voter_count"-"battle_lose"."count" >=
5996 "policy_row"."indirect_majority_non_negative"
5997 ) AS "subquery"
5998 WHERE "id" = "subquery"."initiative_id";
5999 EXIT WHEN NOT FOUND;
6000 END LOOP;
6001 -- set "multistage_majority" for remaining matching initiatives:
6002 UPDATE "initiative" SET "multistage_majority" = TRUE
6003 FROM (
6004 SELECT "losing_initiative"."id" AS "initiative_id"
6005 FROM "initiative" "losing_initiative"
6006 JOIN "initiative" "winning_initiative"
6007 ON "winning_initiative"."issue_id" = "issue_id_p"
6008 AND "winning_initiative"."admitted"
6009 JOIN "battle" "battle_win"
6010 ON "battle_win"."issue_id" = "issue_id_p"
6011 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
6012 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
6013 JOIN "battle" "battle_lose"
6014 ON "battle_lose"."issue_id" = "issue_id_p"
6015 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
6016 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
6017 WHERE "losing_initiative"."issue_id" = "issue_id_p"
6018 AND "losing_initiative"."admitted"
6019 AND "winning_initiative"."schulze_rank" <
6020 "losing_initiative"."schulze_rank"
6021 AND "battle_win"."count" > "battle_lose"."count"
6022 AND (
6023 "battle_win"."count" > "winning_initiative"."positive_votes" OR
6024 "battle_lose"."count" < "losing_initiative"."negative_votes" )
6025 ) AS "subquery"
6026 WHERE "id" = "subquery"."initiative_id";
6027 -- mark eligible initiatives:
6028 UPDATE "initiative" SET "eligible" = TRUE
6029 WHERE "issue_id" = "issue_id_p"
6030 AND "initiative"."direct_majority"
6031 AND "initiative"."indirect_majority"
6032 AND "initiative"."better_than_status_quo"
6033 AND (
6034 "policy_row"."no_multistage_majority" = FALSE OR
6035 "initiative"."multistage_majority" = FALSE )
6036 AND (
6037 "policy_row"."no_reverse_beat_path" = FALSE OR
6038 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
6039 -- mark final winner:
6040 UPDATE "initiative" SET "winner" = TRUE
6041 FROM (
6042 SELECT "id" AS "initiative_id"
6043 FROM "initiative"
6044 WHERE "issue_id" = "issue_id_p" AND "eligible"
6045 ORDER BY
6046 "schulze_rank",
6047 "id"
6048 LIMIT 1
6049 ) AS "subquery"
6050 WHERE "id" = "subquery"."initiative_id";
6051 -- write (final) ranks:
6052 "rank_v" := 1;
6053 FOR "initiative_id_v" IN
6054 SELECT "id"
6055 FROM "initiative"
6056 WHERE "issue_id" = "issue_id_p" AND "admitted"
6057 ORDER BY
6058 "winner" DESC,
6059 "eligible" DESC,
6060 "schulze_rank",
6061 "id"
6062 LOOP
6063 UPDATE "initiative" SET "rank" = "rank_v"
6064 WHERE "id" = "initiative_id_v";
6065 "rank_v" := "rank_v" + 1;
6066 END LOOP;
6067 -- set schulze rank of status quo and mark issue as finished:
6068 UPDATE "issue" SET
6069 "status_quo_schulze_rank" = "rank_ary"[1],
6070 "state" =
6071 CASE WHEN EXISTS (
6072 SELECT NULL FROM "initiative"
6073 WHERE "issue_id" = "issue_id_p" AND "winner"
6074 ) THEN
6075 'finished_with_winner'::"issue_state"
6076 ELSE
6077 'finished_without_winner'::"issue_state"
6078 END,
6079 "closed" = "phase_finished",
6080 "phase_finished" = NULL
6081 WHERE "id" = "issue_id_p";
6082 RETURN;
6083 END;
6084 $$;
6086 COMMENT ON FUNCTION "calculate_ranks"
6087 ( "issue"."id"%TYPE )
6088 IS 'Determine ranking (Votes have to be counted first)';
6092 -----------------------------
6093 -- Automatic state changes --
6094 -----------------------------
6097 CREATE FUNCTION "issue_admission"
6098 ( "area_id_p" "area"."id"%TYPE )
6099 RETURNS BOOLEAN
6100 LANGUAGE 'plpgsql' VOLATILE AS $$
6101 DECLARE
6102 "issue_id_v" "issue"."id"%TYPE;
6103 BEGIN
6104 PERFORM "dont_require_transaction_isolation"();
6105 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
6106 UPDATE "area" SET "issue_quorum" = "view"."issue_quorum"
6107 FROM "area_quorum" AS "view"
6108 WHERE "area"."id" = "view"."area_id"
6109 AND "area"."id" = "area_id_p";
6110 SELECT "id" INTO "issue_id_v" FROM "issue_for_admission"
6111 WHERE "area_id" = "area_id_p";
6112 IF "issue_id_v" ISNULL THEN RETURN FALSE; END IF;
6113 UPDATE "issue" SET
6114 "admission_snapshot_id" = "latest_snapshot_id",
6115 "state" = 'discussion',
6116 "accepted" = now(),
6117 "phase_finished" = NULL,
6118 "issue_quorum" = "issue_quorum"."issue_quorum"
6119 FROM "issue_quorum"
6120 WHERE "id" = "issue_id_v"
6121 AND "issue_quorum"."issue_id" = "issue_id_v";
6122 RETURN TRUE;
6123 END;
6124 $$;
6126 COMMENT ON FUNCTION "issue_admission"
6127 ( "area"."id"%TYPE )
6128 IS 'Checks if an issue in the area can be admitted for further discussion; returns TRUE on success in which case the function must be called again until it returns FALSE';
6131 CREATE TYPE "check_issue_persistence" AS (
6132 "state" "issue_state",
6133 "phase_finished" BOOLEAN,
6134 "issue_revoked" BOOLEAN,
6135 "snapshot_created" BOOLEAN,
6136 "harmonic_weights_set" BOOLEAN,
6137 "closed_voting" BOOLEAN );
6139 COMMENT ON TYPE "check_issue_persistence" IS 'Type of data returned by "check_issue" function, to be passed to subsequent calls of the same function';
6142 CREATE FUNCTION "check_issue"
6143 ( "issue_id_p" "issue"."id"%TYPE,
6144 "persist" "check_issue_persistence" )
6145 RETURNS "check_issue_persistence"
6146 LANGUAGE 'plpgsql' VOLATILE AS $$
6147 DECLARE
6148 "issue_row" "issue"%ROWTYPE;
6149 "last_calculated_v" "snapshot"."calculated"%TYPE;
6150 "policy_row" "policy"%ROWTYPE;
6151 "initiative_row" "initiative"%ROWTYPE;
6152 "state_v" "issue_state";
6153 BEGIN
6154 PERFORM "require_transaction_isolation"();
6155 IF "persist" ISNULL THEN
6156 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6157 FOR UPDATE;
6158 SELECT "calculated" INTO "last_calculated_v"
6159 FROM "snapshot" JOIN "snapshot_issue"
6160 ON "snapshot"."id" = "snapshot_issue"."snapshot_id"
6161 WHERE "snapshot_issue"."issue_id" = "issue_id_p";
6162 IF "issue_row"."closed" NOTNULL THEN
6163 RETURN NULL;
6164 END IF;
6165 "persist"."state" := "issue_row"."state";
6166 IF
6167 ( "issue_row"."state" = 'admission' AND "last_calculated_v" >=
6168 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
6169 ( "issue_row"."state" = 'discussion' AND now() >=
6170 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
6171 ( "issue_row"."state" = 'verification' AND now() >=
6172 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
6173 ( "issue_row"."state" = 'voting' AND now() >=
6174 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
6175 THEN
6176 "persist"."phase_finished" := TRUE;
6177 ELSE
6178 "persist"."phase_finished" := FALSE;
6179 END IF;
6180 IF
6181 NOT EXISTS (
6182 -- all initiatives are revoked
6183 SELECT NULL FROM "initiative"
6184 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6185 ) AND (
6186 -- and issue has not been accepted yet
6187 "persist"."state" = 'admission' OR
6188 -- or verification time has elapsed
6189 ( "persist"."state" = 'verification' AND
6190 "persist"."phase_finished" ) OR
6191 -- or no initiatives have been revoked lately
6192 NOT EXISTS (
6193 SELECT NULL FROM "initiative"
6194 WHERE "issue_id" = "issue_id_p"
6195 AND now() < "revoked" + "issue_row"."verification_time"
6198 THEN
6199 "persist"."issue_revoked" := TRUE;
6200 ELSE
6201 "persist"."issue_revoked" := FALSE;
6202 END IF;
6203 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
6204 UPDATE "issue" SET "phase_finished" = now()
6205 WHERE "id" = "issue_row"."id";
6206 RETURN "persist";
6207 ELSIF
6208 "persist"."state" IN ('admission', 'discussion', 'verification')
6209 THEN
6210 RETURN "persist";
6211 ELSE
6212 RETURN NULL;
6213 END IF;
6214 END IF;
6215 IF
6216 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6217 coalesce("persist"."snapshot_created", FALSE) = FALSE
6218 THEN
6219 IF "persist"."state" != 'admission' THEN
6220 PERFORM "take_snapshot"("issue_id_p");
6221 PERFORM "finish_snapshot"("issue_id_p");
6222 ELSE
6223 UPDATE "issue" SET "issue_quorum" = "issue_quorum"."issue_quorum"
6224 FROM "issue_quorum"
6225 WHERE "id" = "issue_id_p"
6226 AND "issue_quorum"."issue_id" = "issue_id_p";
6227 END IF;
6228 "persist"."snapshot_created" = TRUE;
6229 IF "persist"."phase_finished" THEN
6230 IF "persist"."state" = 'admission' THEN
6231 UPDATE "issue" SET "admission_snapshot_id" = "latest_snapshot_id"
6232 WHERE "id" = "issue_id_p";
6233 ELSIF "persist"."state" = 'discussion' THEN
6234 UPDATE "issue" SET "half_freeze_snapshot_id" = "latest_snapshot_id"
6235 WHERE "id" = "issue_id_p";
6236 ELSIF "persist"."state" = 'verification' THEN
6237 UPDATE "issue" SET "full_freeze_snapshot_id" = "latest_snapshot_id"
6238 WHERE "id" = "issue_id_p";
6239 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
6240 FOR "initiative_row" IN
6241 SELECT * FROM "initiative"
6242 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6243 FOR UPDATE
6244 LOOP
6245 IF
6246 "initiative_row"."polling" OR
6247 "initiative_row"."satisfied_supporter_count" >=
6248 "issue_row"."initiative_quorum"
6249 THEN
6250 UPDATE "initiative" SET "admitted" = TRUE
6251 WHERE "id" = "initiative_row"."id";
6252 ELSE
6253 UPDATE "initiative" SET "admitted" = FALSE
6254 WHERE "id" = "initiative_row"."id";
6255 END IF;
6256 END LOOP;
6257 END IF;
6258 END IF;
6259 RETURN "persist";
6260 END IF;
6261 IF
6262 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6263 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
6264 THEN
6265 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
6266 "persist"."harmonic_weights_set" = TRUE;
6267 IF
6268 "persist"."phase_finished" OR
6269 "persist"."issue_revoked" OR
6270 "persist"."state" = 'admission'
6271 THEN
6272 RETURN "persist";
6273 ELSE
6274 RETURN NULL;
6275 END IF;
6276 END IF;
6277 IF "persist"."issue_revoked" THEN
6278 IF "persist"."state" = 'admission' THEN
6279 "state_v" := 'canceled_revoked_before_accepted';
6280 ELSIF "persist"."state" = 'discussion' THEN
6281 "state_v" := 'canceled_after_revocation_during_discussion';
6282 ELSIF "persist"."state" = 'verification' THEN
6283 "state_v" := 'canceled_after_revocation_during_verification';
6284 END IF;
6285 UPDATE "issue" SET
6286 "state" = "state_v",
6287 "closed" = "phase_finished",
6288 "phase_finished" = NULL
6289 WHERE "id" = "issue_id_p";
6290 RETURN NULL;
6291 END IF;
6292 IF "persist"."state" = 'admission' THEN
6293 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6294 FOR UPDATE;
6295 IF "issue_row"."phase_finished" NOTNULL THEN
6296 UPDATE "issue" SET
6297 "state" = 'canceled_issue_not_accepted',
6298 "closed" = "phase_finished",
6299 "phase_finished" = NULL
6300 WHERE "id" = "issue_id_p";
6301 END IF;
6302 RETURN NULL;
6303 END IF;
6304 IF "persist"."phase_finished" THEN
6305 IF "persist"."state" = 'discussion' THEN
6306 UPDATE "issue" SET
6307 "state" = 'verification',
6308 "half_frozen" = "phase_finished",
6309 "phase_finished" = NULL
6310 WHERE "id" = "issue_id_p";
6311 RETURN NULL;
6312 END IF;
6313 IF "persist"."state" = 'verification' THEN
6314 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6315 FOR UPDATE;
6316 SELECT * INTO "policy_row" FROM "policy"
6317 WHERE "id" = "issue_row"."policy_id";
6318 IF EXISTS (
6319 SELECT NULL FROM "initiative"
6320 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
6321 ) THEN
6322 UPDATE "issue" SET
6323 "state" = 'voting',
6324 "fully_frozen" = "phase_finished",
6325 "phase_finished" = NULL
6326 WHERE "id" = "issue_id_p";
6327 ELSE
6328 UPDATE "issue" SET
6329 "state" = 'canceled_no_initiative_admitted',
6330 "fully_frozen" = "phase_finished",
6331 "closed" = "phase_finished",
6332 "phase_finished" = NULL
6333 WHERE "id" = "issue_id_p";
6334 -- NOTE: The following DELETE statements have effect only when
6335 -- issue state has been manipulated
6336 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
6337 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
6338 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
6339 END IF;
6340 RETURN NULL;
6341 END IF;
6342 IF "persist"."state" = 'voting' THEN
6343 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
6344 PERFORM "close_voting"("issue_id_p");
6345 "persist"."closed_voting" = TRUE;
6346 RETURN "persist";
6347 END IF;
6348 PERFORM "calculate_ranks"("issue_id_p");
6349 RETURN NULL;
6350 END IF;
6351 END IF;
6352 RAISE WARNING 'should not happen';
6353 RETURN NULL;
6354 END;
6355 $$;
6357 COMMENT ON FUNCTION "check_issue"
6358 ( "issue"."id"%TYPE,
6359 "check_issue_persistence" )
6360 IS 'Precalculate supporter counts etc. for a given issue, and check, if status change is required, and perform the status change when necessary; Function must be called multiple times with the previous result as second parameter, until the result is NULL (see source code of function "check_everything")';
6363 CREATE FUNCTION "check_everything"()
6364 RETURNS VOID
6365 LANGUAGE 'plpgsql' VOLATILE AS $$
6366 DECLARE
6367 "area_id_v" "area"."id"%TYPE;
6368 "snapshot_id_v" "snapshot"."id"%TYPE;
6369 "issue_id_v" "issue"."id"%TYPE;
6370 "persist_v" "check_issue_persistence";
6371 BEGIN
6372 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
6373 DELETE FROM "expired_session";
6374 DELETE FROM "expired_token";
6375 DELETE FROM "expired_snapshot";
6376 PERFORM "check_activity"();
6377 PERFORM "calculate_member_counts"();
6378 FOR "area_id_v" IN SELECT "id" FROM "area_with_unaccepted_issues" LOOP
6379 SELECT "take_snapshot"(NULL, "area_id_v") INTO "snapshot_id_v";
6380 PERFORM "finish_snapshot"("issue_id") FROM "snapshot_issue"
6381 WHERE "snapshot_id" = "snapshot_id_v";
6382 LOOP
6383 EXIT WHEN "issue_admission"("area_id_v") = FALSE;
6384 END LOOP;
6385 END LOOP;
6386 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
6387 "persist_v" := NULL;
6388 LOOP
6389 "persist_v" := "check_issue"("issue_id_v", "persist_v");
6390 EXIT WHEN "persist_v" ISNULL;
6391 END LOOP;
6392 END LOOP;
6393 RETURN;
6394 END;
6395 $$;
6397 COMMENT ON FUNCTION "check_everything"() IS 'Amongst other regular tasks, this function performs "check_issue" for every open issue. Use this function only for development and debugging purposes, as you may run into locking and/or serialization problems in productive environments. For production, use lf_update binary instead';
6401 ----------------------
6402 -- Deletion of data --
6403 ----------------------
6406 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
6407 RETURNS VOID
6408 LANGUAGE 'plpgsql' VOLATILE AS $$
6409 BEGIN
6410 IF EXISTS (
6411 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
6412 ) THEN
6413 -- override protection triggers:
6414 INSERT INTO "temporary_transaction_data" ("key", "value")
6415 VALUES ('override_protection_triggers', TRUE::TEXT);
6416 -- clean data:
6417 DELETE FROM "delegating_voter"
6418 WHERE "issue_id" = "issue_id_p";
6419 DELETE FROM "direct_voter"
6420 WHERE "issue_id" = "issue_id_p";
6421 DELETE FROM "delegating_interest_snapshot"
6422 WHERE "issue_id" = "issue_id_p";
6423 DELETE FROM "direct_interest_snapshot"
6424 WHERE "issue_id" = "issue_id_p";
6425 DELETE FROM "non_voter"
6426 WHERE "issue_id" = "issue_id_p";
6427 DELETE FROM "delegation"
6428 WHERE "issue_id" = "issue_id_p";
6429 DELETE FROM "supporter"
6430 USING "initiative" -- NOTE: due to missing index on issue_id
6431 WHERE "initiative"."issue_id" = "issue_id_p"
6432 AND "supporter"."initiative_id" = "initiative_id";
6433 -- mark issue as cleaned:
6434 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
6435 -- finish overriding protection triggers (avoids garbage):
6436 DELETE FROM "temporary_transaction_data"
6437 WHERE "key" = 'override_protection_triggers';
6438 END IF;
6439 RETURN;
6440 END;
6441 $$;
6443 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
6446 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
6447 RETURNS VOID
6448 LANGUAGE 'plpgsql' VOLATILE AS $$
6449 BEGIN
6450 UPDATE "member" SET
6451 "last_login" = NULL,
6452 "last_delegation_check" = NULL,
6453 "login" = NULL,
6454 "password" = NULL,
6455 "authority" = NULL,
6456 "authority_uid" = NULL,
6457 "authority_login" = NULL,
6458 "deleted" = coalesce("deleted", now()),
6459 "locked" = TRUE,
6460 "active" = FALSE,
6461 "notify_email" = NULL,
6462 "notify_email_unconfirmed" = NULL,
6463 "notify_email_secret" = NULL,
6464 "notify_email_secret_expiry" = NULL,
6465 "notify_email_lock_expiry" = NULL,
6466 "disable_notifications" = TRUE,
6467 "notification_counter" = DEFAULT,
6468 "notification_sample_size" = 0,
6469 "notification_dow" = NULL,
6470 "notification_hour" = NULL,
6471 "notification_sent" = NULL,
6472 "login_recovery_expiry" = NULL,
6473 "password_reset_secret" = NULL,
6474 "password_reset_secret_expiry" = NULL,
6475 "location" = NULL
6476 WHERE "id" = "member_id_p";
6477 -- "text_search_data" is updated by triggers
6478 DELETE FROM "member_settings" WHERE "member_id" = "member_id_p";
6479 DELETE FROM "member_profile" WHERE "member_id" = "member_id_p";
6480 DELETE FROM "rendered_member_statement" WHERE "member_id" = "member_id_p";
6481 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
6482 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
6483 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
6484 DELETE FROM "session" WHERE "member_id" = "member_id_p";
6485 DELETE FROM "member_application" WHERE "member_id" = "member_id_p";
6486 DELETE FROM "token" WHERE "member_id" = "member_id_p";
6487 DELETE FROM "subscription" WHERE "member_id" = "member_id_p";
6488 DELETE FROM "ignored_area" WHERE "member_id" = "member_id_p";
6489 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
6490 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
6491 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
6492 DELETE FROM "direct_voter" USING "issue"
6493 WHERE "direct_voter"."issue_id" = "issue"."id"
6494 AND "issue"."closed" ISNULL
6495 AND "member_id" = "member_id_p";
6496 DELETE FROM "notification_initiative_sent" WHERE "member_id" = "member_id_p";
6497 RETURN;
6498 END;
6499 $$;
6501 COMMENT ON FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE) IS 'Deactivate member and clear certain settings and data of this member (data protection)';
6504 CREATE FUNCTION "delete_private_data"()
6505 RETURNS VOID
6506 LANGUAGE 'plpgsql' VOLATILE AS $$
6507 BEGIN
6508 DELETE FROM "temporary_transaction_data";
6509 DELETE FROM "temporary_suggestion_counts";
6510 DELETE FROM "member" WHERE "activated" ISNULL;
6511 UPDATE "member" SET
6512 "invite_code" = NULL,
6513 "invite_code_expiry" = NULL,
6514 "admin_comment" = NULL,
6515 "last_login" = NULL,
6516 "last_delegation_check" = NULL,
6517 "login" = NULL,
6518 "password" = NULL,
6519 "authority" = NULL,
6520 "authority_uid" = NULL,
6521 "authority_login" = NULL,
6522 "lang" = NULL,
6523 "notify_email" = NULL,
6524 "notify_email_unconfirmed" = NULL,
6525 "notify_email_secret" = NULL,
6526 "notify_email_secret_expiry" = NULL,
6527 "notify_email_lock_expiry" = NULL,
6528 "disable_notifications" = TRUE,
6529 "notification_counter" = DEFAULT,
6530 "notification_sample_size" = 0,
6531 "notification_dow" = NULL,
6532 "notification_hour" = NULL,
6533 "notification_sent" = NULL,
6534 "login_recovery_expiry" = NULL,
6535 "password_reset_secret" = NULL,
6536 "password_reset_secret_expiry" = NULL,
6537 "location" = NULL;
6538 -- "text_search_data" is updated by triggers
6539 DELETE FROM "verification";
6540 DELETE FROM "member_settings";
6541 DELETE FROM "member_useterms";
6542 DELETE FROM "member_profile";
6543 DELETE FROM "rendered_member_statement";
6544 DELETE FROM "member_image";
6545 DELETE FROM "contact";
6546 DELETE FROM "ignored_member";
6547 DELETE FROM "session";
6548 DELETE FROM "system_application";
6549 DELETE FROM "system_application_redirect_uri";
6550 DELETE FROM "dynamic_application_scope";
6551 DELETE FROM "member_application";
6552 DELETE FROM "token";
6553 DELETE FROM "subscription";
6554 DELETE FROM "ignored_area";
6555 DELETE FROM "ignored_initiative";
6556 DELETE FROM "non_voter";
6557 DELETE FROM "direct_voter" USING "issue"
6558 WHERE "direct_voter"."issue_id" = "issue"."id"
6559 AND "issue"."closed" ISNULL;
6560 DELETE FROM "event_processed";
6561 DELETE FROM "notification_initiative_sent";
6562 DELETE FROM "newsletter";
6563 RETURN;
6564 END;
6565 $$;
6567 COMMENT ON FUNCTION "delete_private_data"() IS 'Used by lf_export script. DO NOT USE on productive database, but only on a copy! This function deletes all data which should not be publicly available, and can be used to create a database dump for publication. See source code to see which data is deleted. If you need a different behaviour, copy this function and modify lf_export accordingly, to avoid data-leaks after updating.';
6571 COMMIT;

Impressum / About Us