liquid_feedback_core

view core.sql @ 569:622c71ca6428

Bugfix in view "unit_member" (wrong ON clause for JOIN)
author jbe
date Fri Sep 29 19:37:49 2017 +0200 (2017-09-29)
parents b1326d149247
children ed3c3d8bd16b
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.0-dev', 4, 0, -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 "location" JSONB,
131 "text_search_data" TSVECTOR,
132 CONSTRAINT "deleted_requires_locked"
133 CHECK ("deleted" ISNULL OR "locked" = TRUE),
134 CONSTRAINT "active_requires_activated_and_last_activity"
135 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)),
136 CONSTRAINT "authority_requires_uid_and_vice_versa"
137 CHECK (("authority" NOTNULL) = ("authority_uid" NOTNULL)),
138 CONSTRAINT "authority_uid_unique_per_authority"
139 UNIQUE ("authority", "authority_uid"),
140 CONSTRAINT "authority_login_requires_authority"
141 CHECK ("authority" NOTNULL OR "authority_login" ISNULL),
142 CONSTRAINT "notification_dow_requires_notification_hour"
143 CHECK ("notification_dow" ISNULL OR "notification_hour" NOTNULL),
144 CONSTRAINT "name_not_null_if_activated"
145 CHECK ("activated" ISNULL OR "name" NOTNULL) );
146 CREATE INDEX "member_authority_login_idx" ON "member" ("authority_login");
147 CREATE INDEX "member_active_idx" ON "member" ("active");
148 CREATE INDEX "member_location_idx" ON "member" USING gist ((GeoJSON_to_ecluster("location")));
149 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
150 CREATE TRIGGER "update_text_search_data"
151 BEFORE INSERT OR UPDATE ON "member"
152 FOR EACH ROW EXECUTE PROCEDURE
153 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
154 "name", "identification");
156 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
158 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
159 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
160 COMMENT ON COLUMN "member"."invite_code_expiry" IS 'Expiry data/time for "invite_code"';
161 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
162 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';
163 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
164 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
165 COMMENT ON COLUMN "member"."last_delegation_check" IS 'Timestamp of last delegation check (i.e. confirmation of all unit and area delegations)';
166 COMMENT ON COLUMN "member"."login" IS 'Login name';
167 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
168 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)';
169 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)';
170 COMMENT ON COLUMN "member"."authority_login" IS 'Login name for external accounts (field is not unique!)';
171 COMMENT ON COLUMN "member"."deleted" IS 'Timestamp of deletion (set by "delete_member" function)';
172 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
173 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".';
174 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
175 COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member';
176 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
177 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
178 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
179 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
180 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
181 COMMENT ON COLUMN "member"."disable_notifications" IS 'TRUE if member does not want to receive notifications';
182 COMMENT ON COLUMN "member"."notification_counter" IS 'Sequential number of next scheduled notification message (used as a seed for pseudo-random initiative selection algorithm)';
183 COMMENT ON COLUMN "member"."notification_sample_size" IS 'Number of featured initiatives per issue in scheduled notification messages';
184 COMMENT ON COLUMN "member"."notification_dow" IS 'Day of week for scheduled notifications (NULL to receive a daily digest)';
185 COMMENT ON COLUMN "member"."notification_hour" IS 'Time of day when scheduled notifications are sent out';
186 COMMENT ON COLUMN "member"."notification_sent" IS 'Timestamp of last scheduled notification mail that has been sent out';
187 COMMENT ON COLUMN "member"."login_recovery_expiry" IS 'Date/time after which another login recovery attempt is allowed';
188 COMMENT ON COLUMN "member"."password_reset_secret" IS 'Secret string sent via e-mail for password recovery';
189 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';
190 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member, may be NULL if account has not been activated yet';
191 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
192 COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated';
193 COMMENT ON COLUMN "member"."location" IS 'Geographic location on earth as GeoJSON object';
196 CREATE TABLE "member_history" ( -- TODO: redundancy with new "event" table
197 "id" SERIAL8 PRIMARY KEY,
198 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
199 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
200 "active" BOOLEAN NOT NULL,
201 "name" TEXT NOT NULL );
202 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
204 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
206 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
207 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
210 CREATE TABLE "verification" (
211 "id" SERIAL8 PRIMARY KEY,
212 "requested" TIMESTAMPTZ,
213 "request_origin" JSONB,
214 "request_data" JSONB,
215 "requesting_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
216 "verifying_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
217 "verified_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
218 "verified" TIMESTAMPTZ,
219 "verification_data" JSONB,
220 "denied" TIMESTAMPTZ,
221 "comment" TEXT,
222 CONSTRAINT "verified_and_denied_conflict" CHECK (
223 "verified" ISNULL OR "denied" ISNULL ) );
224 CREATE INDEX "verification_requested_idx" ON "verification" ("requested");
225 CREATE INDEX "verification_open_request_idx" ON "verification" ("requested") WHERE "verified" ISNULL AND "denied" ISNULL;
226 CREATE INDEX "verification_requesting_member_id_idx" ON "verification" ("requesting_member_id");
227 CREATE INDEX "verification_verified_member_id_idx" ON "verification" ("verified_member_id");
228 CREATE INDEX "verification_verified_idx" ON "verification" ("verified");
229 CREATE INDEX "verification_denied_idx" ON "verification" ("denied");
231 COMMENT ON TABLE "verification" IS 'Request to verify a participant';
233 COMMENT ON COLUMN "verification"."requested" IS 'Timestamp when request for verification has been submitted';
234 COMMENT ON COLUMN "verification"."request_origin" IS 'JSON data containing information about the origin of the request (e.g. IP address or hostname)';
235 COMMENT ON COLUMN "verification"."request_data" IS 'JSON data containing information about the entity to be verified (e.g. real name, address, etc.)';
236 COMMENT ON COLUMN "verification"."requesting_member_id" IS 'Member who requested verification';
237 COMMENT ON COLUMN "verification"."verifying_member_id" IS 'Member who processed the verification request (i.e. who accepted or denied the request)';
238 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)';
239 COMMENT ON COLUMN "verification"."verified" IS 'Timestamp when request for verification has been accepted by authority';
240 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';
241 COMMENT ON COLUMN "verification"."denied" IS 'Timestamp when request for verification has been denied by authority';
242 COMMENT ON COLUMN "verification"."comment" IS 'Administrative comment';
245 CREATE TABLE "member_settings" (
246 "member_id" INT4 PRIMARY KEY REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
247 "settings" JSONB NOT NULL CHECK (jsonb_typeof("settings") = 'object') );
249 COMMENT ON TABLE "member_settings" IS 'Stores a JSON document for each member containing optional (additional) settings for the respective member';
252 CREATE TABLE "member_useterms" (
253 "id" SERIAL8 PRIMARY KEY,
254 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
255 "accepted" TIMESTAMPTZ NOT NULL DEFAULT now(),
256 "contract_identifier" TEXT NOT NULL );
258 COMMENT ON TABLE "member_useterms" IS 'Keeps record of accepted terms of use; may contain multiple rows per member';
260 COMMENT ON COLUMN "member_useterms"."accepted" IS 'Point in time when user accepted the terms of use';
261 COMMENT ON COLUMN "member_useterms"."contract_identifier" IS 'String identifier to denote the accepted terms of use, including their version or revision';
264 CREATE TABLE "member_profile" (
265 "member_id" INT4 PRIMARY KEY REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
266 "formatting_engine" TEXT,
267 "statement" TEXT,
268 "profile" JSONB NOT NULL DEFAULT '{}' CHECK (jsonb_typeof("profile") = 'object'),
269 "profile_text_data" TEXT,
270 "text_search_data" TSVECTOR );
271 CREATE INDEX "member_profile_text_search_data_idx" ON "member_profile" USING gin ("text_search_data");
272 CREATE TRIGGER "update_text_search_data"
273 BEFORE INSERT OR UPDATE ON "member_profile"
274 FOR EACH ROW EXECUTE PROCEDURE
275 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
276 'statement', 'profile_text_data');
278 COMMENT ON COLUMN "member_profile"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member_profile"."statement"';
279 COMMENT ON COLUMN "member_profile"."statement" IS 'Freely chosen text of the member for his/her profile';
280 COMMENT ON COLUMN "member_profile"."profile" IS 'Additional profile data as JSON document';
281 COMMENT ON COLUMN "member_profile"."profile_text_data" IS 'Text data from "profile" field for full text search';
284 CREATE TABLE "rendered_member_statement" (
285 PRIMARY KEY ("member_id", "format"),
286 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
287 "format" TEXT,
288 "content" TEXT NOT NULL );
290 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)';
293 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
295 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
298 CREATE TABLE "member_image" (
299 PRIMARY KEY ("member_id", "image_type", "scaled"),
300 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
301 "image_type" "member_image_type",
302 "scaled" BOOLEAN,
303 "content_type" TEXT,
304 "data" BYTEA NOT NULL );
306 COMMENT ON TABLE "member_image" IS 'Images of members';
308 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
311 CREATE TABLE "member_count" (
312 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
313 "total_count" INT4 NOT NULL );
315 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';
317 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
318 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
321 CREATE TABLE "contact" (
322 PRIMARY KEY ("member_id", "other_member_id"),
323 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
324 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
325 "public" BOOLEAN NOT NULL DEFAULT FALSE,
326 CONSTRAINT "cant_save_yourself_as_contact"
327 CHECK ("member_id" != "other_member_id") );
328 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
330 COMMENT ON TABLE "contact" IS 'Contact lists';
332 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
333 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
334 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
337 CREATE TABLE "ignored_member" (
338 PRIMARY KEY ("member_id", "other_member_id"),
339 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
340 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
341 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
343 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
345 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
346 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
349 CREATE TABLE "session" (
350 UNIQUE ("member_id", "id"), -- index needed for foreign-key on table "token"
351 "id" SERIAL8 PRIMARY KEY,
352 "ident" TEXT NOT NULL UNIQUE,
353 "additional_secret" TEXT,
354 "logout_token" TEXT,
355 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
356 "member_id" INT4 REFERENCES "member" ("id") ON DELETE SET NULL,
357 "authority" TEXT,
358 "authority_uid" TEXT,
359 "authority_login" TEXT,
360 "needs_delegation_check" BOOLEAN NOT NULL DEFAULT FALSE,
361 "lang" TEXT );
362 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
364 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
366 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
367 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
368 COMMENT ON COLUMN "session"."logout_token" IS 'Optional token to authorize logout through external component';
369 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
370 COMMENT ON COLUMN "session"."authority" IS 'Temporary store for "member"."authority" during member account creation';
371 COMMENT ON COLUMN "session"."authority_uid" IS 'Temporary store for "member"."authority_uid" during member account creation';
372 COMMENT ON COLUMN "session"."authority_login" IS 'Temporary store for "member"."authority_login" during member account creation';
373 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';
374 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
377 CREATE TYPE "authflow" AS ENUM ('code', 'token');
379 COMMENT ON TYPE "authflow" IS 'OAuth 2.0 flows: ''code'' = Authorization Code flow, ''token'' = Implicit flow';
382 CREATE TABLE "system_application" (
383 "id" SERIAL4 PRIMARY KEY,
384 "name" TEXT NOT NULL,
385 "discovery_baseurl" TEXT,
386 "client_id" TEXT NOT NULL UNIQUE,
387 "default_redirect_uri" TEXT NOT NULL,
388 "cert_common_name" TEXT,
389 "client_cred_scope" TEXT,
390 "flow" "authflow",
391 "automatic_scope" TEXT,
392 "permitted_scope" TEXT,
393 "forbidden_scope" TEXT );
395 COMMENT ON TABLE "system_application" IS 'OAuth 2.0 clients that are registered by the system administrator';
397 COMMENT ON COLUMN "system_application"."name" IS 'Human readable name of application';
398 COMMENT ON COLUMN "system_application"."discovery_baseurl" IS 'Base URL for application discovery; NULL for hidden application';
399 COMMENT ON COLUMN "system_application"."client_id" IS 'OAuth 2.0 "client_id"';
400 COMMENT ON COLUMN "system_application"."cert_common_name" IS 'Value for CN field of TLS client certificate';
401 COMMENT ON COLUMN "system_application"."client_cred_scope" IS 'Space-separated list of scopes; If set, Client Credentials Grant is allowed; value determines scope';
402 COMMENT ON COLUMN "system_application"."flow" IS 'If set to ''code'' or ''token'', then Authorization Code or Implicit flow is allowed respectively';
403 COMMENT ON COLUMN "system_application"."automatic_scope" IS 'Space-separated list of scopes; Automatically granted scope for Authorization Code or Implicit flow';
404 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';
405 COMMENT ON COLUMN "system_application"."forbidden_scope" IS 'Space-separated list of scopes that may not be granted to the application by a member';
408 CREATE TABLE "system_application_redirect_uri" (
409 PRIMARY KEY ("system_application_id", "redirect_uri"),
410 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
411 "redirect_uri" TEXT );
413 COMMENT ON TABLE "system_application_redirect_uri" IS 'Additional OAuth 2.0 redirection endpoints, which may be selected through the "redirect_uri" GET parameter';
416 CREATE TABLE "dynamic_application_scope" (
417 PRIMARY KEY ("redirect_uri", "flow", "scope"),
418 "redirect_uri" TEXT,
419 "flow" TEXT,
420 "scope" TEXT,
421 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours' );
422 CREATE INDEX "dynamic_application_scope_redirect_uri_scope_idx" ON "dynamic_application_scope" ("redirect_uri", "flow", "scope");
423 CREATE INDEX "dynamic_application_scope_expiry_idx" ON "dynamic_application_scope" ("expiry");
425 COMMENT ON TABLE "dynamic_application_scope" IS 'Dynamic OAuth 2.0 client registration data';
427 COMMENT ON COLUMN "dynamic_application_scope"."redirect_uri" IS 'Redirection endpoint for which the registration has been done';
428 COMMENT ON COLUMN "dynamic_application_scope"."flow" IS 'OAuth 2.0 flow for which the registration has been done (see also "system_application"."flow")';
429 COMMENT ON COLUMN "dynamic_application_scope"."scope" IS 'Single scope without space characters (use multiple rows for more scopes)';
430 COMMENT ON COLUMN "dynamic_application_scope"."expiry" IS 'Expiry unless renewed';
433 CREATE TABLE "member_application" (
434 "id" SERIAL4 PRIMARY KEY,
435 UNIQUE ("system_application_id", "member_id"),
436 UNIQUE ("domain", "member_id"),
437 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
438 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
439 "domain" TEXT,
440 "session_id" INT8,
441 FOREIGN KEY ("member_id", "session_id") REFERENCES "session" ("member_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
442 "scope" TEXT NOT NULL,
443 CONSTRAINT "system_application_or_domain_but_not_both" CHECK (
444 ("system_application_id" NOTNULL AND "domain" ISNULL) OR
445 ("system_application_id" ISNULL AND "domain" NOTNULL) ) );
446 CREATE INDEX "member_application_member_id_idx" ON "member_application" ("member_id");
448 COMMENT ON TABLE "member_application" IS 'Application authorized by a member';
450 COMMENT ON COLUMN "member_application"."system_application_id" IS 'If set, then application is a system application';
451 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';
452 COMMENT ON COLUMN "member_application"."session_id" IS 'If set, registration ends with session';
453 COMMENT ON COLUMN "member_application"."scope" IS 'Granted scope as space-separated list of strings';
456 CREATE TYPE "token_type" AS ENUM ('authorization', 'refresh', 'access');
458 COMMENT ON TYPE "token_type" IS 'Types for entries in "token" table';
461 CREATE TABLE "token" (
462 "id" SERIAL8 PRIMARY KEY,
463 "token" TEXT NOT NULL UNIQUE,
464 "token_type" "token_type" NOT NULL,
465 "authorization_token_id" INT8 REFERENCES "token" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
466 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
467 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
468 "domain" TEXT,
469 FOREIGN KEY ("member_id", "domain") REFERENCES "member_application" ("member_id", "domain") ON DELETE CASCADE ON UPDATE CASCADE,
470 "session_id" INT8,
471 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"
472 "redirect_uri" TEXT,
473 "redirect_uri_explicit" BOOLEAN,
474 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
475 "expiry" TIMESTAMPTZ DEFAULT now() + '1 hour',
476 "used" BOOLEAN NOT NULL DEFAULT FALSE,
477 "scope" TEXT NOT NULL,
478 CONSTRAINT "access_token_needs_expiry"
479 CHECK ("token_type" != 'access'::"token_type" OR "expiry" NOTNULL),
480 CONSTRAINT "authorization_token_needs_redirect_uri"
481 CHECK ("token_type" != 'authorization'::"token_type" OR ("redirect_uri" NOTNULL AND "redirect_uri_explicit" NOTNULL) ) );
482 CREATE INDEX "token_member_id_idx" ON "token" ("member_id");
483 CREATE INDEX "token_authorization_token_id_idx" ON "token" ("authorization_token_id");
484 CREATE INDEX "token_expiry_idx" ON "token" ("expiry");
486 COMMENT ON TABLE "token" IS 'Issued OAuth 2.0 authorization codes and access/refresh tokens';
488 COMMENT ON COLUMN "token"."token" IS 'String secret (the actual token)';
489 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)';
490 COMMENT ON COLUMN "token"."system_application_id" IS 'If set, then application is a system application';
491 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';
492 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''';
493 COMMENT ON COLUMN "token"."redirect_uri" IS 'Authorization codes must be bound to a specific redirect URI';
494 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)';
495 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';
496 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)';
497 COMMENT ON COLUMN "token"."scope" IS 'Scope as space-separated list of strings (detached scopes are marked with ''_detached'' suffix)';
500 CREATE TABLE "token_scope" (
501 PRIMARY KEY ("token_id", "index"),
502 "token_id" INT8 REFERENCES "token" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
503 "index" INT4,
504 "scope" TEXT NOT NULL );
506 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';
509 CREATE TYPE "defeat_strength" AS ENUM ('simple', 'tuple');
511 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';
514 CREATE TYPE "tie_breaking" AS ENUM ('simple', 'variant1', 'variant2');
516 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';
519 CREATE TABLE "policy" (
520 "id" SERIAL4 PRIMARY KEY,
521 "index" INT4 NOT NULL,
522 "active" BOOLEAN NOT NULL DEFAULT TRUE,
523 "name" TEXT NOT NULL UNIQUE,
524 "description" TEXT NOT NULL DEFAULT '',
525 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
526 "min_admission_time" INTERVAL,
527 "max_admission_time" INTERVAL,
528 "discussion_time" INTERVAL,
529 "verification_time" INTERVAL,
530 "voting_time" INTERVAL,
531 "issue_quorum" INT4 CHECK ("issue_quorum" >= 1),
532 "issue_quorum_num" INT4,
533 "issue_quorum_den" INT4,
534 "initiative_quorum" INT4 NOT NULL CHECK ("initiative_quorum" >= 1),
535 "initiative_quorum_num" INT4 NOT NULL,
536 "initiative_quorum_den" INT4 NOT NULL,
537 "defeat_strength" "defeat_strength" NOT NULL DEFAULT 'tuple',
538 "tie_breaking" "tie_breaking" NOT NULL DEFAULT 'variant1',
539 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
540 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
541 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
542 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
543 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
544 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
545 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
546 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
547 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
548 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
549 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT FALSE,
550 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
551 CONSTRAINT "issue_quorum_if_and_only_if_not_polling" CHECK (
552 "polling" = ("issue_quorum" ISNULL) AND
553 "polling" = ("issue_quorum_num" ISNULL) AND
554 "polling" = ("issue_quorum_den" ISNULL) ),
555 CONSTRAINT "min_admission_time_smaller_than_max_admission_time" CHECK (
556 "min_admission_time" < "max_admission_time" ),
557 CONSTRAINT "timing_null_or_not_null_constraints" CHECK (
558 ( "polling" = FALSE AND
559 "min_admission_time" NOTNULL AND "max_admission_time" NOTNULL AND
560 "discussion_time" NOTNULL AND
561 "verification_time" NOTNULL AND
562 "voting_time" NOTNULL ) OR
563 ( "polling" = TRUE AND
564 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
565 "discussion_time" NOTNULL AND
566 "verification_time" NOTNULL AND
567 "voting_time" NOTNULL ) OR
568 ( "polling" = TRUE AND
569 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
570 "discussion_time" ISNULL AND
571 "verification_time" ISNULL AND
572 "voting_time" ISNULL ) ),
573 CONSTRAINT "no_reverse_beat_path_requires_tuple_defeat_strength" CHECK (
574 "defeat_strength" = 'tuple'::"defeat_strength" OR
575 "no_reverse_beat_path" = FALSE ) );
576 CREATE INDEX "policy_active_idx" ON "policy" ("active");
578 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
580 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
581 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
582 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';
583 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"';
584 COMMENT ON COLUMN "policy"."max_admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
585 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
586 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"';
587 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'')';
588 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';
589 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)';
590 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)';
591 COMMENT ON COLUMN "policy"."initiative_quorum" IS 'Absolute number of satisfied supporters to be reached by an initiative to be "admitted" for voting';
592 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
593 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
594 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';
595 COMMENT ON COLUMN "policy"."tie_breaking" IS 'Tie-breaker for the Schulze method; see type "tie_breaking"; ''variant1'' or ''variant2'' are recommended';
596 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
597 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
598 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.';
599 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
600 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';
601 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';
602 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';
603 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.';
604 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';
605 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';
606 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.';
607 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").';
610 CREATE TABLE "unit" (
611 "id" SERIAL4 PRIMARY KEY,
612 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
613 "active" BOOLEAN NOT NULL DEFAULT TRUE,
614 "name" TEXT NOT NULL,
615 "description" TEXT NOT NULL DEFAULT '',
616 "external_reference" TEXT,
617 "member_count" INT4,
618 "location" JSONB,
619 "text_search_data" TSVECTOR );
620 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
621 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
622 CREATE INDEX "unit_active_idx" ON "unit" ("active");
623 CREATE INDEX "unit_location_idx" ON "unit" USING gist ((GeoJSON_to_ecluster("location")));
624 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
625 CREATE TRIGGER "update_text_search_data"
626 BEFORE INSERT OR UPDATE ON "unit"
627 FOR EACH ROW EXECUTE PROCEDURE
628 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
629 "name", "description" );
631 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
633 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
634 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
635 COMMENT ON COLUMN "unit"."external_reference" IS 'Opaque data field to store an external reference';
636 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege" (only active members counted)';
637 COMMENT ON COLUMN "unit"."location" IS 'Geographic location on earth as GeoJSON object indicating valid coordinates for initiatives of issues with this policy';
640 CREATE TABLE "subscription" (
641 PRIMARY KEY ("member_id", "unit_id"),
642 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
643 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
644 CREATE INDEX "subscription_unit_id_idx" ON "subscription" ("unit_id");
646 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';
649 CREATE TABLE "area" (
650 UNIQUE ("unit_id", "id"), -- index needed for foreign-key on table "event"
651 "id" SERIAL4 PRIMARY KEY,
652 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
653 "active" BOOLEAN NOT NULL DEFAULT TRUE,
654 "name" TEXT NOT NULL,
655 "description" TEXT NOT NULL DEFAULT '',
656 "quorum_standard" NUMERIC NOT NULL DEFAULT 2 CHECK ("quorum_standard" >= 0),
657 "quorum_issues" NUMERIC NOT NULL DEFAULT 1 CHECK ("quorum_issues" > 0),
658 "quorum_time" INTERVAL NOT NULL DEFAULT '1 day' CHECK ("quorum_time" > '0'::INTERVAL),
659 "quorum_exponent" NUMERIC NOT NULL DEFAULT 0.5 CHECK ("quorum_exponent" BETWEEN 0 AND 1),
660 "quorum_factor" NUMERIC NOT NULL DEFAULT 2 CHECK ("quorum_factor" >= 1),
661 "quorum_den" INT4 CHECK ("quorum_den" > 0),
662 "issue_quorum" INT4,
663 "external_reference" TEXT,
664 "location" JSONB,
665 "text_search_data" TSVECTOR );
666 CREATE INDEX "area_active_idx" ON "area" ("active");
667 CREATE INDEX "area_location_idx" ON "area" USING gist ((GeoJSON_to_ecluster("location")));
668 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
669 CREATE TRIGGER "update_text_search_data"
670 BEFORE INSERT OR UPDATE ON "area"
671 FOR EACH ROW EXECUTE PROCEDURE
672 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
673 "name", "description" );
675 COMMENT ON TABLE "area" IS 'Subject areas';
677 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
678 COMMENT ON COLUMN "area"."quorum_standard" IS 'Parameter for dynamic issue quorum: default quorum';
679 COMMENT ON COLUMN "area"."quorum_issues" IS 'Parameter for dynamic issue quorum: number of open issues for default quorum';
680 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)';
681 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';
682 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';
683 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)';
684 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"';
685 COMMENT ON COLUMN "area"."external_reference" IS 'Opaque data field to store an external reference';
686 COMMENT ON COLUMN "area"."location" IS 'Geographic location on earth as GeoJSON object indicating valid coordinates for initiatives of issues with this policy';
689 CREATE TABLE "ignored_area" (
690 PRIMARY KEY ("member_id", "area_id"),
691 "member_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
692 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
693 CREATE INDEX "ignored_area_area_id_idx" ON "ignored_area" ("area_id");
695 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';
698 CREATE TABLE "allowed_policy" (
699 PRIMARY KEY ("area_id", "policy_id"),
700 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
701 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
702 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
703 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
705 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
707 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
710 CREATE TABLE "snapshot" (
711 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "issue"
712 "id" SERIAL8 PRIMARY KEY,
713 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
714 "population" INT4,
715 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
716 "issue_id" INT4 ); -- NOTE: following (cyclic) reference is added later through ALTER command: REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE
718 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';
721 CREATE TABLE "snapshot_population" (
722 PRIMARY KEY ("snapshot_id", "member_id"),
723 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
724 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE );
726 COMMENT ON TABLE "snapshot_population" IS 'Members with voting right relevant for a snapshot';
729 CREATE TYPE "issue_state" AS ENUM (
730 'admission', 'discussion', 'verification', 'voting',
731 'canceled_by_admin',
732 'canceled_revoked_before_accepted',
733 'canceled_issue_not_accepted',
734 'canceled_after_revocation_during_discussion',
735 'canceled_after_revocation_during_verification',
736 'canceled_no_initiative_admitted',
737 'finished_without_winner', 'finished_with_winner');
739 COMMENT ON TYPE "issue_state" IS 'State of issues';
742 CREATE TABLE "issue" (
743 UNIQUE ("area_id", "id"), -- index needed for foreign-key on table "event"
744 UNIQUE ("policy_id", "id"), -- index needed for foreign-key on table "event"
745 "id" SERIAL4 PRIMARY KEY,
746 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
747 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
748 "admin_notice" TEXT,
749 "external_reference" TEXT,
750 "state" "issue_state" NOT NULL DEFAULT 'admission',
751 "phase_finished" TIMESTAMPTZ,
752 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
753 "accepted" TIMESTAMPTZ,
754 "half_frozen" TIMESTAMPTZ,
755 "fully_frozen" TIMESTAMPTZ,
756 "closed" TIMESTAMPTZ,
757 "cleaned" TIMESTAMPTZ,
758 "min_admission_time" INTERVAL,
759 "max_admission_time" INTERVAL,
760 "discussion_time" INTERVAL NOT NULL,
761 "verification_time" INTERVAL NOT NULL,
762 "voting_time" INTERVAL NOT NULL,
763 "calculated" TIMESTAMPTZ, -- NOTE: copy of "calculated" column of latest snapshot, but no referential integrity to avoid overhead
764 "latest_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
765 "admission_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
766 "half_freeze_snapshot_id" INT8,
767 FOREIGN KEY ("id", "half_freeze_snapshot_id")
768 REFERENCES "snapshot" ("issue_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE,
769 "full_freeze_snapshot_id" INT8,
770 FOREIGN KEY ("id", "full_freeze_snapshot_id")
771 REFERENCES "snapshot" ("issue_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE,
772 "issue_quorum" INT4,
773 "initiative_quorum" INT4,
774 "population" INT4,
775 "voter_count" INT4,
776 "status_quo_schulze_rank" INT4,
777 CONSTRAINT "admission_time_not_null_unless_instantly_accepted" CHECK (
778 ("min_admission_time" NOTNULL) = ("max_admission_time" NOTNULL) AND
779 ("min_admission_time" NOTNULL OR ("accepted" NOTNULL AND "accepted" = "created")) ),
780 CONSTRAINT "valid_state" CHECK (
781 (
782 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
783 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
784 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL ) OR
785 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL)
786 ) AND (
787 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
788 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
789 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
790 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
791 ("state" = 'canceled_by_admin' AND "closed" NOTNULL) OR
792 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
793 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
794 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
795 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
796 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" = "fully_frozen") OR
797 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen") OR
798 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen")
799 )),
800 CONSTRAINT "phase_finished_only_when_not_closed" CHECK (
801 "phase_finished" ISNULL OR "closed" ISNULL ),
802 CONSTRAINT "state_change_order" CHECK (
803 "created" <= "accepted" AND
804 "accepted" <= "half_frozen" AND
805 "half_frozen" <= "fully_frozen" AND
806 "fully_frozen" <= "closed" ),
807 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
808 "cleaned" ISNULL OR "closed" NOTNULL ),
809 CONSTRAINT "snapshot_required" CHECK (
810 --("accepted" ISNULL OR "admission_snapshot_id" NOTNULL) AND
811 ("half_frozen" ISNULL OR "half_freeze_snapshot_id" NOTNULL) AND
812 ("fully_frozen" ISNULL OR "full_freeze_snapshot_id" NOTNULL) ) );
813 CREATE INDEX "issue_state_idx" ON "issue" ("state");
814 CREATE INDEX "issue_created_idx" ON "issue" ("created");
815 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
816 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
817 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
818 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
819 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
820 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
821 CREATE INDEX "issue_latest_snapshot_id" ON "issue" ("latest_snapshot_id");
822 CREATE INDEX "issue_admission_snapshot_id" ON "issue" ("admission_snapshot_id");
823 CREATE INDEX "issue_half_freeze_snapshot_id" ON "issue" ("half_freeze_snapshot_id");
824 CREATE INDEX "issue_full_freeze_snapshot_id" ON "issue" ("full_freeze_snapshot_id");
826 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
828 COMMENT ON COLUMN "issue"."admin_notice" IS 'Public notice by admin to explain manual interventions, or to announce corrections';
829 COMMENT ON COLUMN "issue"."external_reference" IS 'Opaque data field to store an external reference';
830 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';
831 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")';
832 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.';
833 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.';
834 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.';
835 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
836 COMMENT ON COLUMN "issue"."min_admission_time" IS 'Copied from "policy" table at creation of issue';
837 COMMENT ON COLUMN "issue"."max_admission_time" IS 'Copied from "policy" table at creation of issue';
838 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
839 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
840 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
841 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")';
842 COMMENT ON COLUMN "issue"."latest_snapshot_id" IS 'Snapshot id of most recent snapshot';
843 COMMENT ON COLUMN "issue"."admission_snapshot_id" IS 'Snapshot id when issue as accepted or canceled in admission phase';
844 COMMENT ON COLUMN "issue"."half_freeze_snapshot_id" IS 'Snapshot id at end of discussion phase';
845 COMMENT ON COLUMN "issue"."full_freeze_snapshot_id" IS 'Snapshot id at end of verification phase';
846 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';
847 COMMENT ON COLUMN "issue"."initiative_quorum" IS 'Calculated number of satisfied supporters to be reached by an initiative to be "admitted" for voting';
848 COMMENT ON COLUMN "issue"."population" IS 'Count of members in "snapshot_population" table with "snapshot_id" equal to "issue"."latest_snapshot_id"';
849 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';
850 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
853 ALTER TABLE "snapshot" ADD FOREIGN KEY ("issue_id") REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE;
856 CREATE TABLE "issue_order_in_admission_state" (
857 "id" INT8 PRIMARY KEY, -- NOTE: no referential integrity due to performans/locking issues; REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
858 "order_in_area" INT4,
859 "order_in_unit" INT4 );
861 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"';
863 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';
864 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';
865 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';
868 CREATE TABLE "initiative" (
869 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
870 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
871 "id" SERIAL4 PRIMARY KEY,
872 "name" TEXT NOT NULL,
873 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
874 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
875 "revoked" TIMESTAMPTZ,
876 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
877 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
878 "location" JSONB,
879 "external_reference" TEXT,
880 "admitted" BOOLEAN,
881 "supporter_count" INT4,
882 "informed_supporter_count" INT4,
883 "satisfied_supporter_count" INT4,
884 "satisfied_informed_supporter_count" INT4,
885 "harmonic_weight" NUMERIC(12, 3),
886 "final_suggestion_order_calculated" BOOLEAN NOT NULL DEFAULT FALSE,
887 "first_preference_votes" INT4,
888 "positive_votes" INT4,
889 "negative_votes" INT4,
890 "direct_majority" BOOLEAN,
891 "indirect_majority" BOOLEAN,
892 "schulze_rank" INT4,
893 "better_than_status_quo" BOOLEAN,
894 "worse_than_status_quo" BOOLEAN,
895 "reverse_beat_path" BOOLEAN,
896 "multistage_majority" BOOLEAN,
897 "eligible" BOOLEAN,
898 "winner" BOOLEAN,
899 "rank" INT4,
900 "text_search_data" TSVECTOR,
901 "draft_text_search_data" TSVECTOR,
902 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
903 CHECK (("revoked" NOTNULL) = ("revoked_by_member_id" NOTNULL)),
904 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
905 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
906 CONSTRAINT "revoked_initiatives_cant_be_admitted"
907 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
908 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
909 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
910 ( "first_preference_votes" ISNULL AND
911 "positive_votes" ISNULL AND "negative_votes" ISNULL AND
912 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
913 "schulze_rank" ISNULL AND
914 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
915 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
916 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
917 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
918 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
919 "eligible" = FALSE OR
920 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
921 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
922 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
923 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
924 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
925 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
926 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
927 CREATE INDEX "initiative_location_idx" ON "initiative" USING gist ((GeoJSON_to_ecluster("location")));
928 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
929 CREATE INDEX "initiative_draft_text_search_data_idx" ON "initiative" USING gin ("draft_text_search_data");
930 CREATE TRIGGER "update_text_search_data"
931 BEFORE INSERT OR UPDATE ON "initiative"
932 FOR EACH ROW EXECUTE PROCEDURE
933 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "name");
935 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.';
937 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
938 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
939 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
940 COMMENT ON COLUMN "initiative"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied from most recent draft)';
941 COMMENT ON COLUMN "initiative"."external_reference" IS 'Opaque data field to store an external reference';
942 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
943 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
944 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
945 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
946 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
947 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';
948 COMMENT ON COLUMN "initiative"."final_suggestion_order_calculated" IS 'Set to TRUE, when "proportional_order" of suggestions has been calculated the last time';
949 COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice';
950 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo';
951 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo';
952 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"';
953 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
954 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking';
955 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo';
956 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)';
957 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''';
958 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';
959 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"';
960 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank"';
961 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';
964 CREATE TABLE "battle" (
965 "issue_id" INT4 NOT NULL,
966 "winning_initiative_id" INT4,
967 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
968 "losing_initiative_id" INT4,
969 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
970 "count" INT4 NOT NULL,
971 CONSTRAINT "initiative_ids_not_equal" CHECK (
972 "winning_initiative_id" != "losing_initiative_id" OR
973 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
974 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
975 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
976 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
977 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
979 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';
982 CREATE TABLE "ignored_initiative" (
983 PRIMARY KEY ("member_id", "initiative_id"),
984 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
985 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
986 CREATE INDEX "ignored_initiative_initiative_id_idx" ON "ignored_initiative" ("initiative_id");
988 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';
991 CREATE TABLE "draft" (
992 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
993 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
994 "id" SERIAL8 PRIMARY KEY,
995 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
996 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
997 "formatting_engine" TEXT,
998 "content" TEXT NOT NULL,
999 "location" JSONB,
1000 "external_reference" TEXT,
1001 "text_search_data" TSVECTOR );
1002 CREATE INDEX "draft_created_idx" ON "draft" ("created");
1003 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
1004 CREATE INDEX "draft_location_idx" ON "draft" USING gist ((GeoJSON_to_ecluster("location")));
1005 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
1006 CREATE TRIGGER "update_text_search_data"
1007 BEFORE INSERT OR UPDATE ON "draft"
1008 FOR EACH ROW EXECUTE PROCEDURE
1009 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1011 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.';
1013 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
1014 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
1015 COMMENT ON COLUMN "draft"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied to "initiative" table if draft is most recent)';
1016 COMMENT ON COLUMN "draft"."external_reference" IS 'Opaque data field to store an external reference';
1019 CREATE TABLE "rendered_draft" (
1020 PRIMARY KEY ("draft_id", "format"),
1021 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1022 "format" TEXT,
1023 "content" TEXT NOT NULL );
1025 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)';
1028 CREATE TABLE "suggestion" (
1029 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
1030 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1031 "id" SERIAL8 PRIMARY KEY,
1032 "draft_id" INT8 NOT NULL,
1033 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1034 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
1035 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1036 "name" TEXT NOT NULL,
1037 "formatting_engine" TEXT,
1038 "content" TEXT NOT NULL DEFAULT '',
1039 "location" JSONB,
1040 "external_reference" TEXT,
1041 "text_search_data" TSVECTOR,
1042 "minus2_unfulfilled_count" INT4,
1043 "minus2_fulfilled_count" INT4,
1044 "minus1_unfulfilled_count" INT4,
1045 "minus1_fulfilled_count" INT4,
1046 "plus1_unfulfilled_count" INT4,
1047 "plus1_fulfilled_count" INT4,
1048 "plus2_unfulfilled_count" INT4,
1049 "plus2_fulfilled_count" INT4,
1050 "proportional_order" INT4 );
1051 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
1052 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
1053 CREATE INDEX "suggestion_location_idx" ON "suggestion" USING gist ((GeoJSON_to_ecluster("location")));
1054 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
1055 CREATE TRIGGER "update_text_search_data"
1056 BEFORE INSERT OR UPDATE ON "suggestion"
1057 FOR EACH ROW EXECUTE PROCEDURE
1058 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
1059 "name", "content");
1061 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';
1063 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")';
1064 COMMENT ON COLUMN "suggestion"."location" IS 'Geographic location of suggestion as GeoJSON object';
1065 COMMENT ON COLUMN "suggestion"."external_reference" IS 'Opaque data field to store an external reference';
1066 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1067 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1068 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1069 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1070 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1071 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1072 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1073 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1074 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"';
1077 CREATE TABLE "rendered_suggestion" (
1078 PRIMARY KEY ("suggestion_id", "format"),
1079 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1080 "format" TEXT,
1081 "content" TEXT NOT NULL );
1083 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)';
1086 CREATE TABLE "temporary_suggestion_counts" (
1087 "id" INT8 PRIMARY KEY, -- NOTE: no referential integrity due to performance/locking issues; REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1088 "minus2_unfulfilled_count" INT4 NOT NULL,
1089 "minus2_fulfilled_count" INT4 NOT NULL,
1090 "minus1_unfulfilled_count" INT4 NOT NULL,
1091 "minus1_fulfilled_count" INT4 NOT NULL,
1092 "plus1_unfulfilled_count" INT4 NOT NULL,
1093 "plus1_fulfilled_count" INT4 NOT NULL,
1094 "plus2_unfulfilled_count" INT4 NOT NULL,
1095 "plus2_fulfilled_count" INT4 NOT NULL );
1097 COMMENT ON TABLE "temporary_suggestion_counts" IS 'Holds certain calculated values (suggestion counts) temporarily until they can be copied into table "suggestion"';
1099 COMMENT ON COLUMN "temporary_suggestion_counts"."id" IS 'References "suggestion" ("id") but has no referential integrity trigger associated, due to performance/locking issues';
1102 CREATE TABLE "privilege" (
1103 PRIMARY KEY ("unit_id", "member_id"),
1104 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1105 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1106 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1107 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1108 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1109 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1110 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
1111 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
1112 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
1114 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
1116 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
1117 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
1118 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
1119 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
1120 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
1121 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
1122 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';
1125 CREATE TABLE "interest" (
1126 PRIMARY KEY ("issue_id", "member_id"),
1127 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1128 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE );
1129 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
1131 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.';
1134 CREATE TABLE "initiator" (
1135 PRIMARY KEY ("initiative_id", "member_id"),
1136 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1137 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1138 "accepted" BOOLEAN );
1139 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
1141 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.';
1143 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.';
1146 CREATE TABLE "supporter" (
1147 "issue_id" INT4 NOT NULL,
1148 PRIMARY KEY ("initiative_id", "member_id"),
1149 "initiative_id" INT4,
1150 "member_id" INT4,
1151 "draft_id" INT8 NOT NULL,
1152 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1153 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
1154 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
1156 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.';
1158 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1159 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")';
1162 CREATE TABLE "opinion" (
1163 "initiative_id" INT4 NOT NULL,
1164 PRIMARY KEY ("suggestion_id", "member_id"),
1165 "suggestion_id" INT8,
1166 "member_id" INT4,
1167 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
1168 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
1169 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1170 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1171 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
1173 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.';
1175 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
1178 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
1180 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
1183 CREATE TABLE "delegation" (
1184 "id" SERIAL8 PRIMARY KEY,
1185 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1186 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1187 "scope" "delegation_scope" NOT NULL,
1188 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1189 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1190 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1191 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
1192 CONSTRAINT "no_unit_delegation_to_null"
1193 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
1194 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
1195 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
1196 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
1197 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
1198 UNIQUE ("unit_id", "truster_id"),
1199 UNIQUE ("area_id", "truster_id"),
1200 UNIQUE ("issue_id", "truster_id") );
1201 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
1202 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
1204 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
1206 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
1207 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
1208 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
1211 CREATE TABLE "snapshot_issue" (
1212 PRIMARY KEY ("snapshot_id", "issue_id"),
1213 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1214 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); -- NOTE: trigger "delete_snapshot_on_partial_delete" will delete whole "snapshot"
1215 CREATE INDEX "snapshot_issue_issue_id_idx" ON "snapshot_issue" ("issue_id");
1217 COMMENT ON TABLE "snapshot_issue" IS 'List of issues included in a snapshot';
1219 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.';
1222 CREATE TABLE "direct_interest_snapshot" (
1223 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
1224 "snapshot_id" INT8,
1225 "issue_id" INT4,
1226 FOREIGN KEY ("snapshot_id", "issue_id")
1227 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1228 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1229 "weight" INT4 );
1230 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
1232 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';
1234 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
1237 CREATE TABLE "delegating_interest_snapshot" (
1238 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
1239 "snapshot_id" INT8,
1240 "issue_id" INT4,
1241 FOREIGN KEY ("snapshot_id", "issue_id")
1242 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1243 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1244 "weight" INT4,
1245 "scope" "delegation_scope" NOT NULL,
1246 "delegate_member_ids" INT4[] NOT NULL );
1247 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
1249 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';
1251 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
1252 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
1253 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"';
1256 CREATE TABLE "direct_supporter_snapshot" (
1257 PRIMARY KEY ("snapshot_id", "initiative_id", "member_id"),
1258 "snapshot_id" INT8,
1259 "issue_id" INT4 NOT NULL,
1260 FOREIGN KEY ("snapshot_id", "issue_id")
1261 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1262 "initiative_id" INT4,
1263 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1264 "draft_id" INT8 NOT NULL,
1265 "informed" BOOLEAN NOT NULL,
1266 "satisfied" BOOLEAN NOT NULL,
1267 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1268 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1269 FOREIGN KEY ("snapshot_id", "issue_id", "member_id") REFERENCES "direct_interest_snapshot" ("snapshot_id", "issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1270 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1272 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';
1274 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';
1275 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1276 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1279 CREATE TABLE "non_voter" (
1280 PRIMARY KEY ("member_id", "issue_id"),
1281 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1282 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1283 CREATE INDEX "non_voter_issue_id_idx" ON "non_voter" ("issue_id");
1285 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1288 CREATE TABLE "direct_voter" (
1289 PRIMARY KEY ("issue_id", "member_id"),
1290 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1291 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1292 "weight" INT4,
1293 "comment_changed" TIMESTAMPTZ,
1294 "formatting_engine" TEXT,
1295 "comment" TEXT,
1296 "text_search_data" TSVECTOR );
1297 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1298 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
1299 CREATE TRIGGER "update_text_search_data"
1300 BEFORE INSERT OR UPDATE ON "direct_voter"
1301 FOR EACH ROW EXECUTE PROCEDURE
1302 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
1304 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';
1306 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1307 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';
1308 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';
1309 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.';
1312 CREATE TABLE "rendered_voter_comment" (
1313 PRIMARY KEY ("issue_id", "member_id", "format"),
1314 FOREIGN KEY ("issue_id", "member_id")
1315 REFERENCES "direct_voter" ("issue_id", "member_id")
1316 ON DELETE CASCADE ON UPDATE CASCADE,
1317 "issue_id" INT4,
1318 "member_id" INT4,
1319 "format" TEXT,
1320 "content" TEXT NOT NULL );
1322 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)';
1325 CREATE TABLE "delegating_voter" (
1326 PRIMARY KEY ("issue_id", "member_id"),
1327 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1328 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1329 "weight" INT4,
1330 "scope" "delegation_scope" NOT NULL,
1331 "delegate_member_ids" INT4[] NOT NULL );
1332 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1334 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';
1336 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1337 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1338 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"';
1341 CREATE TABLE "vote" (
1342 "issue_id" INT4 NOT NULL,
1343 PRIMARY KEY ("initiative_id", "member_id"),
1344 "initiative_id" INT4,
1345 "member_id" INT4,
1346 "grade" INT4 NOT NULL,
1347 "first_preference" BOOLEAN,
1348 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1349 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1350 CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
1351 CHECK ("grade" > 0 OR "first_preference" ISNULL) );
1352 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1354 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';
1356 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1357 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.';
1358 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.';
1361 CREATE TYPE "event_type" AS ENUM (
1362 'unit_created',
1363 'unit_updated',
1364 'area_created',
1365 'area_updated',
1366 'policy_created',
1367 'policy_updated',
1368 'issue_state_changed',
1369 'initiative_created_in_new_issue',
1370 'initiative_created_in_existing_issue',
1371 'initiative_revoked',
1372 'new_draft_created',
1373 'suggestion_created',
1374 'suggestion_deleted',
1375 'member_activated',
1376 'member_deleted',
1377 'member_active',
1378 'member_name_updated',
1379 'member_profile_updated',
1380 'member_image_updated',
1381 'interest',
1382 'initiator',
1383 'support',
1384 'support_updated',
1385 'suggestion_rated',
1386 'delegation',
1387 'contact' );
1389 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1392 CREATE TABLE "event" (
1393 "id" SERIAL8 PRIMARY KEY,
1394 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1395 "event" "event_type" NOT NULL,
1396 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1397 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1398 "scope" "delegation_scope",
1399 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1400 "area_id" INT4,
1401 FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1402 "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1403 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1404 FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1405 FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1406 "state" "issue_state",
1407 "initiative_id" INT4,
1408 "draft_id" INT8,
1409 "suggestion_id" INT8,
1410 "boolean_value" BOOLEAN,
1411 "numeric_value" INT4,
1412 "text_value" TEXT,
1413 "old_text_value" TEXT,
1414 FOREIGN KEY ("issue_id", "initiative_id")
1415 REFERENCES "initiative" ("issue_id", "id")
1416 ON DELETE CASCADE ON UPDATE CASCADE,
1417 FOREIGN KEY ("initiative_id", "draft_id")
1418 REFERENCES "draft" ("initiative_id", "id")
1419 ON DELETE CASCADE ON UPDATE CASCADE,
1420 -- NOTE: no referential integrity for suggestions because those are
1421 -- actually deleted
1422 -- FOREIGN KEY ("initiative_id", "suggestion_id")
1423 -- REFERENCES "suggestion" ("initiative_id", "id")
1424 -- ON DELETE CASCADE ON UPDATE CASCADE,
1425 CONSTRAINT "constr_for_issue_state_changed" CHECK (
1426 "event" != 'issue_state_changed' OR (
1427 "member_id" ISNULL AND
1428 "other_member_id" ISNULL AND
1429 "scope" ISNULL AND
1430 "unit_id" NOTNULL AND
1431 "area_id" NOTNULL AND
1432 "policy_id" NOTNULL AND
1433 "issue_id" NOTNULL AND
1434 "state" NOTNULL AND
1435 "initiative_id" ISNULL AND
1436 "draft_id" ISNULL AND
1437 "suggestion_id" ISNULL AND
1438 "boolean_value" ISNULL AND
1439 "numeric_value" ISNULL AND
1440 "text_value" ISNULL AND
1441 "old_text_value" ISNULL )),
1442 CONSTRAINT "constr_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1443 "event" NOT IN (
1444 'initiative_created_in_new_issue',
1445 'initiative_created_in_existing_issue',
1446 'initiative_revoked',
1447 'new_draft_created'
1448 ) OR (
1449 "member_id" NOTNULL AND
1450 "other_member_id" ISNULL AND
1451 "scope" ISNULL AND
1452 "unit_id" NOTNULL AND
1453 "area_id" NOTNULL AND
1454 "policy_id" NOTNULL AND
1455 "issue_id" NOTNULL AND
1456 "state" NOTNULL AND
1457 "initiative_id" NOTNULL AND
1458 "draft_id" NOTNULL AND
1459 "suggestion_id" ISNULL AND
1460 "boolean_value" ISNULL AND
1461 "numeric_value" ISNULL AND
1462 "text_value" ISNULL AND
1463 "old_text_value" ISNULL )),
1464 CONSTRAINT "constr_for_suggestion_creation" CHECK (
1465 "event" != 'suggestion_created' OR (
1466 "member_id" NOTNULL AND
1467 "other_member_id" ISNULL AND
1468 "scope" ISNULL AND
1469 "unit_id" NOTNULL AND
1470 "area_id" NOTNULL AND
1471 "policy_id" NOTNULL AND
1472 "issue_id" NOTNULL AND
1473 "state" NOTNULL AND
1474 "initiative_id" NOTNULL AND
1475 "draft_id" ISNULL AND
1476 "suggestion_id" NOTNULL AND
1477 "boolean_value" ISNULL AND
1478 "numeric_value" ISNULL AND
1479 "text_value" ISNULL AND
1480 "old_text_value" ISNULL )),
1481 CONSTRAINT "constr_for_suggestion_removal" CHECK (
1482 "event" != 'suggestion_deleted' OR (
1483 "member_id" ISNULL AND
1484 "other_member_id" ISNULL AND
1485 "scope" ISNULL AND
1486 "unit_id" NOTNULL AND
1487 "area_id" NOTNULL AND
1488 "policy_id" NOTNULL AND
1489 "issue_id" NOTNULL AND
1490 "state" NOTNULL AND
1491 "initiative_id" NOTNULL AND
1492 "draft_id" ISNULL AND
1493 "suggestion_id" NOTNULL AND
1494 "boolean_value" ISNULL AND
1495 "numeric_value" ISNULL AND
1496 "text_value" ISNULL AND
1497 "old_text_value" ISNULL )),
1498 CONSTRAINT "constr_for_value_less_member_event" CHECK (
1499 "event" NOT IN (
1500 'member_activated',
1501 'member_deleted',
1502 'member_profile_updated',
1503 'member_image_updated'
1504 ) OR (
1505 "member_id" NOTNULL AND
1506 "other_member_id" ISNULL AND
1507 "scope" ISNULL AND
1508 "unit_id" ISNULL AND
1509 "area_id" ISNULL AND
1510 "policy_id" ISNULL AND
1511 "issue_id" ISNULL AND
1512 "state" ISNULL AND
1513 "initiative_id" ISNULL AND
1514 "draft_id" ISNULL AND
1515 "suggestion_id" ISNULL AND
1516 "boolean_value" ISNULL AND
1517 "numeric_value" ISNULL AND
1518 "text_value" ISNULL AND
1519 "old_text_value" ISNULL )),
1520 CONSTRAINT "constr_for_member_active" CHECK (
1521 "event" != 'member_active' OR (
1522 "member_id" NOTNULL AND
1523 "other_member_id" ISNULL AND
1524 "scope" ISNULL AND
1525 "unit_id" ISNULL AND
1526 "area_id" ISNULL AND
1527 "policy_id" ISNULL AND
1528 "issue_id" ISNULL AND
1529 "state" ISNULL AND
1530 "initiative_id" ISNULL AND
1531 "draft_id" ISNULL AND
1532 "suggestion_id" ISNULL AND
1533 "boolean_value" NOTNULL AND
1534 "numeric_value" ISNULL AND
1535 "text_value" ISNULL AND
1536 "old_text_value" ISNULL )),
1537 CONSTRAINT "constr_for_member_name_updated" CHECK (
1538 "event" != 'member_name_updated' OR (
1539 "member_id" NOTNULL AND
1540 "other_member_id" ISNULL AND
1541 "scope" ISNULL AND
1542 "unit_id" ISNULL AND
1543 "area_id" ISNULL AND
1544 "policy_id" ISNULL AND
1545 "issue_id" ISNULL AND
1546 "state" ISNULL AND
1547 "initiative_id" ISNULL AND
1548 "draft_id" ISNULL AND
1549 "suggestion_id" ISNULL AND
1550 "boolean_value" ISNULL AND
1551 "numeric_value" ISNULL AND
1552 "text_value" NOTNULL AND
1553 "old_text_value" NOTNULL )),
1554 CONSTRAINT "constr_for_interest" CHECK (
1555 "event" != 'interest' OR (
1556 "member_id" NOTNULL AND
1557 "other_member_id" ISNULL AND
1558 "scope" ISNULL AND
1559 "unit_id" NOTNULL AND
1560 "area_id" NOTNULL AND
1561 "policy_id" NOTNULL AND
1562 "issue_id" NOTNULL AND
1563 "state" NOTNULL AND
1564 "initiative_id" ISNULL AND
1565 "draft_id" ISNULL AND
1566 "suggestion_id" ISNULL AND
1567 "boolean_value" NOTNULL AND
1568 "numeric_value" ISNULL AND
1569 "text_value" ISNULL AND
1570 "old_text_value" ISNULL )),
1571 CONSTRAINT "constr_for_initiator" CHECK (
1572 "event" != 'initiator' OR (
1573 "member_id" NOTNULL AND
1574 "other_member_id" ISNULL AND
1575 "scope" ISNULL AND
1576 "unit_id" NOTNULL AND
1577 "area_id" NOTNULL AND
1578 "policy_id" NOTNULL AND
1579 "issue_id" NOTNULL AND
1580 "state" NOTNULL AND
1581 "initiative_id" NOTNULL AND
1582 "draft_id" ISNULL AND
1583 "suggestion_id" ISNULL AND
1584 "boolean_value" NOTNULL AND
1585 "numeric_value" ISNULL AND
1586 "text_value" ISNULL AND
1587 "old_text_value" ISNULL )),
1588 CONSTRAINT "constr_for_support" CHECK (
1589 "event" != 'support' OR (
1590 "member_id" NOTNULL AND
1591 "other_member_id" ISNULL AND
1592 "scope" ISNULL AND
1593 "unit_id" NOTNULL AND
1594 "area_id" NOTNULL AND
1595 "policy_id" NOTNULL AND
1596 "issue_id" NOTNULL AND
1597 "state" NOTNULL AND
1598 "initiative_id" NOTNULL AND
1599 ("draft_id" NOTNULL) = ("boolean_value" = TRUE) AND
1600 "suggestion_id" ISNULL AND
1601 "boolean_value" NOTNULL AND
1602 "numeric_value" ISNULL AND
1603 "text_value" ISNULL AND
1604 "old_text_value" ISNULL )),
1605 CONSTRAINT "constr_for_support_updated" CHECK (
1606 "event" != 'support_updated' OR (
1607 "member_id" NOTNULL AND
1608 "other_member_id" ISNULL AND
1609 "scope" ISNULL AND
1610 "unit_id" NOTNULL AND
1611 "area_id" NOTNULL AND
1612 "policy_id" NOTNULL AND
1613 "issue_id" NOTNULL AND
1614 "state" NOTNULL AND
1615 "initiative_id" NOTNULL AND
1616 "draft_id" NOTNULL AND
1617 "suggestion_id" ISNULL AND
1618 "boolean_value" ISNULL AND
1619 "numeric_value" ISNULL AND
1620 "text_value" ISNULL AND
1621 "old_text_value" ISNULL )),
1622 CONSTRAINT "constr_for_suggestion_rated" CHECK (
1623 "event" != 'suggestion_rated' OR (
1624 "member_id" NOTNULL AND
1625 "other_member_id" ISNULL AND
1626 "scope" ISNULL AND
1627 "unit_id" NOTNULL AND
1628 "area_id" NOTNULL AND
1629 "policy_id" NOTNULL AND
1630 "issue_id" NOTNULL AND
1631 "state" NOTNULL AND
1632 "initiative_id" NOTNULL AND
1633 "draft_id" ISNULL AND
1634 "suggestion_id" NOTNULL AND
1635 ("boolean_value" NOTNULL) = ("numeric_value" != 0) AND
1636 "numeric_value" NOTNULL AND
1637 "numeric_value" IN (-2, -1, 0, 1, 2) AND
1638 "text_value" ISNULL AND
1639 "old_text_value" ISNULL )),
1640 CONSTRAINT "constr_for_delegation" CHECK (
1641 "event" != 'delegation' OR (
1642 "member_id" NOTNULL AND
1643 (("other_member_id" ISNULL) OR ("boolean_value" = TRUE)) AND
1644 "scope" NOTNULL AND
1645 "unit_id" NOTNULL AND
1646 ("area_id" NOTNULL) = ("scope" != 'unit'::"delegation_scope") AND
1647 "policy_id" ISNULL AND
1648 ("issue_id" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1649 ("state" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1650 "initiative_id" ISNULL AND
1651 "draft_id" ISNULL AND
1652 "suggestion_id" ISNULL AND
1653 "boolean_value" NOTNULL AND
1654 "numeric_value" ISNULL AND
1655 "text_value" ISNULL AND
1656 "old_text_value" ISNULL )),
1657 CONSTRAINT "constr_for_contact" CHECK (
1658 "event" != 'contact' OR (
1659 "member_id" NOTNULL AND
1660 "other_member_id" NOTNULL AND
1661 "scope" ISNULL AND
1662 "unit_id" ISNULL AND
1663 "area_id" ISNULL AND
1664 "policy_id" ISNULL AND
1665 "issue_id" ISNULL AND
1666 "state" ISNULL AND
1667 "initiative_id" ISNULL AND
1668 "draft_id" ISNULL AND
1669 "suggestion_id" ISNULL AND
1670 "boolean_value" NOTNULL AND
1671 "numeric_value" ISNULL AND
1672 "text_value" ISNULL AND
1673 "old_text_value" ISNULL )) );
1674 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1676 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1678 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1679 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1680 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1681 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1684 CREATE TABLE "event_processed" (
1685 "event_id" INT8 NOT NULL );
1686 CREATE UNIQUE INDEX "event_processed_singleton_idx" ON "event_processed" ((1));
1688 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)';
1689 COMMENT ON INDEX "event_processed_singleton_idx" IS 'This index ensures that "event_processed" only contains one row maximum.';
1692 CREATE TABLE "notification_initiative_sent" (
1693 PRIMARY KEY ("member_id", "initiative_id"),
1694 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1695 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1696 "last_draft_id" INT8 NOT NULL,
1697 "last_suggestion_id" INT8 );
1698 CREATE INDEX "notification_initiative_sent_initiative_idx" ON "notification_initiative_sent" ("initiative_id");
1700 COMMENT ON TABLE "notification_initiative_sent" IS 'Information which initiatives have been promoted to a member in a scheduled notification mail';
1702 COMMENT ON COLUMN "notification_initiative_sent"."last_draft_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1703 COMMENT ON COLUMN "notification_initiative_sent"."last_suggestion_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1706 CREATE TABLE "newsletter" (
1707 "id" SERIAL4 PRIMARY KEY,
1708 "published" TIMESTAMPTZ NOT NULL,
1709 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1710 "include_all_members" BOOLEAN NOT NULL,
1711 "sent" TIMESTAMPTZ,
1712 "subject" TEXT NOT NULL,
1713 "content" TEXT NOT NULL );
1714 CREATE INDEX "newsletter_unit_id_idx" ON "newsletter" ("unit_id", "published");
1715 CREATE INDEX "newsletter_all_units_published_idx" ON "newsletter" ("published") WHERE "unit_id" ISNULL;
1716 CREATE INDEX "newsletter_published_idx" ON "newsletter" ("published");
1718 COMMENT ON TABLE "newsletter" IS 'Contains newsletters created by administrators to be sent out and for further reference';
1720 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter is to be sent out (and made available in the frontend)';
1721 COMMENT ON COLUMN "newsletter"."unit_id" IS 'If set, only members with voting right in the given unit are considered to be recipients';
1722 COMMENT ON COLUMN "newsletter"."include_all_members" IS 'TRUE = include all members regardless of their ''disable_notifications'' setting';
1723 COMMENT ON COLUMN "newsletter"."sent" IS 'Timestamp when the newsletter has been mailed out';
1724 COMMENT ON COLUMN "newsletter"."subject" IS 'Subject line (e.g. to be used for the email)';
1725 COMMENT ON COLUMN "newsletter"."content" IS 'Plain text content of the newsletter';
1729 ----------------------------------------------
1730 -- Writing of history entries and event log --
1731 ----------------------------------------------
1734 CREATE FUNCTION "write_member_history_trigger"()
1735 RETURNS TRIGGER
1736 LANGUAGE 'plpgsql' VOLATILE AS $$
1737 BEGIN
1738 IF
1739 ( NEW."active" != OLD."active" OR
1740 NEW."name" != OLD."name" ) AND
1741 OLD."activated" NOTNULL
1742 THEN
1743 INSERT INTO "member_history"
1744 ("member_id", "active", "name")
1745 VALUES (NEW."id", OLD."active", OLD."name");
1746 END IF;
1747 RETURN NULL;
1748 END;
1749 $$;
1751 CREATE TRIGGER "write_member_history"
1752 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1753 "write_member_history_trigger"();
1755 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1756 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1759 CREATE FUNCTION "write_event_unit_trigger"()
1760 RETURNS TRIGGER
1761 LANGUAGE 'plpgsql' VOLATILE AS $$
1762 DECLARE
1763 "event_v" "event_type";
1764 BEGIN
1765 IF TG_OP = 'UPDATE' THEN
1766 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1767 RETURN NULL;
1768 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1769 -- "event_v" := 'unit_created';
1770 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1771 -- "event_v" := 'unit_deleted';
1772 ELSIF OLD != NEW THEN
1773 "event_v" := 'unit_updated';
1774 ELSE
1775 RETURN NULL;
1776 END IF;
1777 ELSE
1778 "event_v" := 'unit_created';
1779 END IF;
1780 INSERT INTO "event" ("event", "unit_id") VALUES ("event_v", NEW."id");
1781 RETURN NULL;
1782 END;
1783 $$;
1785 CREATE TRIGGER "write_event_unit" AFTER INSERT OR UPDATE ON "unit"
1786 FOR EACH ROW EXECUTE PROCEDURE "write_event_unit_trigger"();
1788 COMMENT ON FUNCTION "write_event_unit_trigger"() IS 'Implementation of trigger "write_event_unit" on table "unit"';
1789 COMMENT ON TRIGGER "write_event_unit" ON "unit" IS 'Create entry in "event" table on new or changed/disabled units';
1792 CREATE FUNCTION "write_event_area_trigger"()
1793 RETURNS TRIGGER
1794 LANGUAGE 'plpgsql' VOLATILE AS $$
1795 DECLARE
1796 "event_v" "event_type";
1797 BEGIN
1798 IF TG_OP = 'UPDATE' THEN
1799 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1800 RETURN NULL;
1801 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1802 -- "event_v" := 'area_created';
1803 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1804 -- "event_v" := 'area_deleted';
1805 ELSIF OLD != NEW THEN
1806 "event_v" := 'area_updated';
1807 ELSE
1808 RETURN NULL;
1809 END IF;
1810 ELSE
1811 "event_v" := 'area_created';
1812 END IF;
1813 INSERT INTO "event" ("event", "area_id") VALUES ("event_v", NEW."id");
1814 RETURN NULL;
1815 END;
1816 $$;
1818 CREATE TRIGGER "write_event_area" AFTER INSERT OR UPDATE ON "area"
1819 FOR EACH ROW EXECUTE PROCEDURE "write_event_area_trigger"();
1821 COMMENT ON FUNCTION "write_event_area_trigger"() IS 'Implementation of trigger "write_event_area" on table "area"';
1822 COMMENT ON TRIGGER "write_event_area" ON "area" IS 'Create entry in "event" table on new or changed/disabled areas';
1825 CREATE FUNCTION "write_event_policy_trigger"()
1826 RETURNS TRIGGER
1827 LANGUAGE 'plpgsql' VOLATILE AS $$
1828 DECLARE
1829 "event_v" "event_type";
1830 BEGIN
1831 IF TG_OP = 'UPDATE' THEN
1832 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1833 RETURN NULL;
1834 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1835 -- "event_v" := 'policy_created';
1836 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1837 -- "event_v" := 'policy_deleted';
1838 ELSIF OLD != NEW THEN
1839 "event_v" := 'policy_updated';
1840 ELSE
1841 RETURN NULL;
1842 END IF;
1843 ELSE
1844 "event_v" := 'policy_created';
1845 END IF;
1846 INSERT INTO "event" ("event", "policy_id") VALUES ("event_v", NEW."id");
1847 RETURN NULL;
1848 END;
1849 $$;
1851 CREATE TRIGGER "write_event_policy" AFTER INSERT OR UPDATE ON "policy"
1852 FOR EACH ROW EXECUTE PROCEDURE "write_event_policy_trigger"();
1854 COMMENT ON FUNCTION "write_event_policy_trigger"() IS 'Implementation of trigger "write_event_policy" on table "policy"';
1855 COMMENT ON TRIGGER "write_event_policy" ON "policy" IS 'Create entry in "event" table on new or changed/disabled policies';
1858 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1859 RETURNS TRIGGER
1860 LANGUAGE 'plpgsql' VOLATILE AS $$
1861 DECLARE
1862 "area_row" "area"%ROWTYPE;
1863 BEGIN
1864 IF NEW."state" != OLD."state" THEN
1865 SELECT * INTO "area_row" FROM "area" WHERE "id" = NEW."area_id"
1866 FOR SHARE;
1867 INSERT INTO "event" (
1868 "event",
1869 "unit_id", "area_id", "policy_id", "issue_id", "state"
1870 ) VALUES (
1871 'issue_state_changed',
1872 "area_row"."unit_id", NEW."area_id", NEW."policy_id",
1873 NEW."id", NEW."state"
1874 );
1875 END IF;
1876 RETURN NULL;
1877 END;
1878 $$;
1880 CREATE TRIGGER "write_event_issue_state_changed"
1881 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1882 "write_event_issue_state_changed_trigger"();
1884 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1885 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1888 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1889 RETURNS TRIGGER
1890 LANGUAGE 'plpgsql' VOLATILE AS $$
1891 DECLARE
1892 "initiative_row" "initiative"%ROWTYPE;
1893 "issue_row" "issue"%ROWTYPE;
1894 "area_row" "area"%ROWTYPE;
1895 "event_v" "event_type";
1896 BEGIN
1897 SELECT * INTO "initiative_row" FROM "initiative"
1898 WHERE "id" = NEW."initiative_id" FOR SHARE;
1899 SELECT * INTO "issue_row" FROM "issue"
1900 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
1901 SELECT * INTO "area_row" FROM "area"
1902 WHERE "id" = "issue_row"."area_id" FOR SHARE;
1903 IF EXISTS (
1904 SELECT NULL FROM "draft"
1905 WHERE "initiative_id" = NEW."initiative_id" AND "id" != NEW."id"
1906 FOR SHARE
1907 ) THEN
1908 "event_v" := 'new_draft_created';
1909 ELSE
1910 IF EXISTS (
1911 SELECT NULL FROM "initiative"
1912 WHERE "issue_id" = "initiative_row"."issue_id"
1913 AND "id" != "initiative_row"."id"
1914 FOR SHARE
1915 ) THEN
1916 "event_v" := 'initiative_created_in_existing_issue';
1917 ELSE
1918 "event_v" := 'initiative_created_in_new_issue';
1919 END IF;
1920 END IF;
1921 INSERT INTO "event" (
1922 "event", "member_id",
1923 "unit_id", "area_id", "policy_id", "issue_id", "state",
1924 "initiative_id", "draft_id"
1925 ) VALUES (
1926 "event_v", NEW."author_id",
1927 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
1928 "initiative_row"."issue_id", "issue_row"."state",
1929 NEW."initiative_id", NEW."id"
1930 );
1931 RETURN NULL;
1932 END;
1933 $$;
1935 CREATE TRIGGER "write_event_initiative_or_draft_created"
1936 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1937 "write_event_initiative_or_draft_created_trigger"();
1939 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1940 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1943 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1944 RETURNS TRIGGER
1945 LANGUAGE 'plpgsql' VOLATILE AS $$
1946 DECLARE
1947 "issue_row" "issue"%ROWTYPE;
1948 "area_row" "area"%ROWTYPE;
1949 "draft_id_v" "draft"."id"%TYPE;
1950 BEGIN
1951 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1952 -- NOTE: lock for primary key update to avoid new drafts
1953 SELECT NULL FROM "initiative" WHERE "id" = NEW."id" FOR UPDATE;
1954 SELECT * INTO "issue_row" FROM "issue"
1955 WHERE "id" = NEW."issue_id" FOR SHARE;
1956 SELECT * INTO "area_row" FROM "area"
1957 WHERE "id" = "issue_row"."area_id" FOR SHARE;
1958 -- NOTE: FOR SHARE cannot be used with DISTINCT in view "current_draft"
1959 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id" FOR SHARE;
1960 SELECT "id" INTO "draft_id_v" FROM "current_draft"
1961 WHERE "initiative_id" = NEW."id";
1962 INSERT INTO "event" (
1963 "event", "member_id",
1964 "unit_id", "area_id", "policy_id", "issue_id", "state",
1965 "initiative_id", "draft_id"
1966 ) VALUES (
1967 'initiative_revoked', NEW."revoked_by_member_id",
1968 "area_row"."unit_id", "issue_row"."area_id",
1969 "issue_row"."policy_id",
1970 NEW."issue_id", "issue_row"."state",
1971 NEW."id", "draft_id_v"
1972 );
1973 END IF;
1974 RETURN NULL;
1975 END;
1976 $$;
1978 CREATE TRIGGER "write_event_initiative_revoked"
1979 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1980 "write_event_initiative_revoked_trigger"();
1982 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1983 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1986 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1987 RETURNS TRIGGER
1988 LANGUAGE 'plpgsql' VOLATILE AS $$
1989 DECLARE
1990 "initiative_row" "initiative"%ROWTYPE;
1991 "issue_row" "issue"%ROWTYPE;
1992 "area_row" "area"%ROWTYPE;
1993 BEGIN
1994 SELECT * INTO "initiative_row" FROM "initiative"
1995 WHERE "id" = NEW."initiative_id" FOR SHARE;
1996 SELECT * INTO "issue_row" FROM "issue"
1997 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
1998 SELECT * INTO "area_row" FROM "area"
1999 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2000 INSERT INTO "event" (
2001 "event", "member_id",
2002 "unit_id", "area_id", "policy_id", "issue_id", "state",
2003 "initiative_id", "suggestion_id"
2004 ) VALUES (
2005 'suggestion_created', NEW."author_id",
2006 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
2007 "initiative_row"."issue_id", "issue_row"."state",
2008 NEW."initiative_id", NEW."id"
2009 );
2010 RETURN NULL;
2011 END;
2012 $$;
2014 CREATE TRIGGER "write_event_suggestion_created"
2015 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2016 "write_event_suggestion_created_trigger"();
2018 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
2019 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2022 CREATE FUNCTION "write_event_suggestion_removed_trigger"()
2023 RETURNS TRIGGER
2024 LANGUAGE 'plpgsql' VOLATILE AS $$
2025 DECLARE
2026 "initiative_row" "initiative"%ROWTYPE;
2027 "issue_row" "issue"%ROWTYPE;
2028 "area_row" "area"%ROWTYPE;
2029 BEGIN
2030 SELECT * INTO "initiative_row" FROM "initiative"
2031 WHERE "id" = OLD."initiative_id" FOR SHARE;
2032 IF "initiative_row"."id" NOTNULL THEN
2033 SELECT * INTO "issue_row" FROM "issue"
2034 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2035 SELECT * INTO "area_row" FROM "area"
2036 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2037 INSERT INTO "event" (
2038 "event",
2039 "unit_id", "area_id", "policy_id", "issue_id", "state",
2040 "initiative_id", "suggestion_id"
2041 ) VALUES (
2042 'suggestion_deleted',
2043 "area_row"."unit_id", "issue_row"."area_id",
2044 "issue_row"."policy_id",
2045 "initiative_row"."issue_id", "issue_row"."state",
2046 OLD."initiative_id", OLD."id"
2047 );
2048 END IF;
2049 RETURN NULL;
2050 END;
2051 $$;
2053 CREATE TRIGGER "write_event_suggestion_removed"
2054 AFTER DELETE ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2055 "write_event_suggestion_removed_trigger"();
2057 COMMENT ON FUNCTION "write_event_suggestion_removed_trigger"() IS 'Implementation of trigger "write_event_suggestion_removed" on table "issue"';
2058 COMMENT ON TRIGGER "write_event_suggestion_removed" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2061 CREATE FUNCTION "write_event_member_trigger"()
2062 RETURNS TRIGGER
2063 LANGUAGE 'plpgsql' VOLATILE AS $$
2064 BEGIN
2065 IF TG_OP = 'INSERT' THEN
2066 IF NEW."activated" NOTNULL AND NEW."deleted" ISNULL THEN
2067 INSERT INTO "event" ("event", "member_id")
2068 VALUES ('member_activated', NEW."id");
2069 END IF;
2070 IF NEW."active" THEN
2071 INSERT INTO "event" ("event", "member_id", "boolean_value")
2072 VALUES ('member_active', NEW."id", TRUE);
2073 END IF;
2074 ELSIF TG_OP = 'UPDATE' THEN
2075 IF OLD."id" != NEW."id" THEN
2076 RAISE EXCEPTION 'Cannot change member ID';
2077 END IF;
2078 IF
2079 (OLD."activated" ISNULL OR OLD."deleted" NOTNULL) AND
2080 NEW."activated" NOTNULL AND NEW."deleted" ISNULL
2081 THEN
2082 INSERT INTO "event" ("event", "member_id")
2083 VALUES ('member_activated', NEW."id");
2084 END IF;
2085 IF OLD."active" != NEW."active" THEN
2086 INSERT INTO "event" ("event", "member_id", "boolean_value") VALUES (
2087 'member_active', NEW."id", NEW."active"
2088 );
2089 END IF;
2090 IF OLD."name" != NEW."name" THEN
2091 INSERT INTO "event" (
2092 "event", "member_id", "text_value", "old_text_value"
2093 ) VALUES (
2094 'member_name_updated', NEW."id", NEW."name", OLD."name"
2095 );
2096 END IF;
2097 IF
2098 OLD."activated" NOTNULL AND OLD."deleted" ISNULL AND
2099 (NEW."activated" ISNULL OR NEW."deleted" NOTNULL)
2100 THEN
2101 INSERT INTO "event" ("event", "member_id")
2102 VALUES ('member_deleted', NEW."id");
2103 END IF;
2104 END IF;
2105 RETURN NULL;
2106 END;
2107 $$;
2109 CREATE TRIGGER "write_event_member"
2110 AFTER INSERT OR UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
2111 "write_event_member_trigger"();
2113 COMMENT ON FUNCTION "write_event_member_trigger"() IS 'Implementation of trigger "write_event_member" on table "member"';
2114 COMMENT ON TRIGGER "write_event_member" ON "member" IS 'Create entries in "event" table on insertion to member table';
2117 CREATE FUNCTION "write_event_member_profile_updated_trigger"()
2118 RETURNS TRIGGER
2119 LANGUAGE 'plpgsql' VOLATILE AS $$
2120 BEGIN
2121 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2122 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2123 INSERT INTO "event" ("event", "member_id") VALUES (
2124 'member_profile_updated', OLD."member_id"
2125 );
2126 END IF;
2127 END IF;
2128 IF TG_OP = 'UPDATE' THEN
2129 IF OLD."member_id" = NEW."member_id" THEN
2130 RETURN NULL;
2131 END IF;
2132 END IF;
2133 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2134 INSERT INTO "event" ("event", "member_id") VALUES (
2135 'member_profile_updated', NEW."member_id"
2136 );
2137 END IF;
2138 RETURN NULL;
2139 END;
2140 $$;
2142 CREATE TRIGGER "write_event_member_profile_updated"
2143 AFTER INSERT OR UPDATE OR DELETE ON "member_profile"
2144 FOR EACH ROW EXECUTE PROCEDURE
2145 "write_event_member_profile_updated_trigger"();
2147 COMMENT ON FUNCTION "write_event_member_profile_updated_trigger"() IS 'Implementation of trigger "write_event_member_profile_updated" on table "member_profile"';
2148 COMMENT ON TRIGGER "write_event_member_profile_updated" ON "member_profile" IS 'Creates entries in "event" table on member profile update';
2151 CREATE FUNCTION "write_event_member_image_updated_trigger"()
2152 RETURNS TRIGGER
2153 LANGUAGE 'plpgsql' VOLATILE AS $$
2154 BEGIN
2155 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2156 IF NOT OLD."scaled" THEN
2157 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2158 INSERT INTO "event" ("event", "member_id") VALUES (
2159 'member_image_updated', OLD."member_id"
2160 );
2161 END IF;
2162 END IF;
2163 END IF;
2164 IF TG_OP = 'UPDATE' THEN
2165 IF
2166 OLD."member_id" = NEW."member_id" AND
2167 OLD."scaled" = NEW."scaled"
2168 THEN
2169 RETURN NULL;
2170 END IF;
2171 END IF;
2172 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2173 IF NOT NEW."scaled" THEN
2174 INSERT INTO "event" ("event", "member_id") VALUES (
2175 'member_image_updated', NEW."member_id"
2176 );
2177 END IF;
2178 END IF;
2179 RETURN NULL;
2180 END;
2181 $$;
2183 CREATE TRIGGER "write_event_member_image_updated"
2184 AFTER INSERT OR UPDATE OR DELETE ON "member_image"
2185 FOR EACH ROW EXECUTE PROCEDURE
2186 "write_event_member_image_updated_trigger"();
2188 COMMENT ON FUNCTION "write_event_member_image_updated_trigger"() IS 'Implementation of trigger "write_event_member_image_updated" on table "member_image"';
2189 COMMENT ON TRIGGER "write_event_member_image_updated" ON "member_image" IS 'Creates entries in "event" table on member image update';
2192 CREATE FUNCTION "write_event_interest_trigger"()
2193 RETURNS TRIGGER
2194 LANGUAGE 'plpgsql' VOLATILE AS $$
2195 DECLARE
2196 "issue_row" "issue"%ROWTYPE;
2197 "area_row" "area"%ROWTYPE;
2198 BEGIN
2199 IF TG_OP = 'UPDATE' THEN
2200 IF OLD = NEW THEN
2201 RETURN NULL;
2202 END IF;
2203 END IF;
2204 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2205 SELECT * INTO "issue_row" FROM "issue"
2206 WHERE "id" = OLD."issue_id" FOR SHARE;
2207 SELECT * INTO "area_row" FROM "area"
2208 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2209 IF "issue_row"."id" NOTNULL THEN
2210 INSERT INTO "event" (
2211 "event", "member_id",
2212 "unit_id", "area_id", "policy_id", "issue_id", "state",
2213 "boolean_value"
2214 ) VALUES (
2215 'interest', OLD."member_id",
2216 "area_row"."unit_id", "issue_row"."area_id",
2217 "issue_row"."policy_id",
2218 OLD."issue_id", "issue_row"."state",
2219 FALSE
2220 );
2221 END IF;
2222 END IF;
2223 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2224 SELECT * INTO "issue_row" FROM "issue"
2225 WHERE "id" = NEW."issue_id" FOR SHARE;
2226 SELECT * INTO "area_row" FROM "area"
2227 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2228 INSERT INTO "event" (
2229 "event", "member_id",
2230 "unit_id", "area_id", "policy_id", "issue_id", "state",
2231 "boolean_value"
2232 ) VALUES (
2233 'interest', NEW."member_id",
2234 "area_row"."unit_id", "issue_row"."area_id",
2235 "issue_row"."policy_id",
2236 NEW."issue_id", "issue_row"."state",
2237 TRUE
2238 );
2239 END IF;
2240 RETURN NULL;
2241 END;
2242 $$;
2244 CREATE TRIGGER "write_event_interest"
2245 AFTER INSERT OR UPDATE OR DELETE ON "interest" FOR EACH ROW EXECUTE PROCEDURE
2246 "write_event_interest_trigger"();
2248 COMMENT ON FUNCTION "write_event_interest_trigger"() IS 'Implementation of trigger "write_event_interest_inserted" on table "interest"';
2249 COMMENT ON TRIGGER "write_event_interest" ON "interest" IS 'Create entry in "event" table on adding or removing interest';
2252 CREATE FUNCTION "write_event_initiator_trigger"()
2253 RETURNS TRIGGER
2254 LANGUAGE 'plpgsql' VOLATILE AS $$
2255 DECLARE
2256 "initiative_row" "initiative"%ROWTYPE;
2257 "issue_row" "issue"%ROWTYPE;
2258 "area_row" "area"%ROWTYPE;
2259 "accepted_v" BOOLEAN = FALSE;
2260 "rejected_v" BOOLEAN = FALSE;
2261 BEGIN
2262 IF TG_OP = 'UPDATE' THEN
2263 IF
2264 OLD."initiative_id" = NEW."initiative_id" AND
2265 OLD."member_id" = NEW."member_id"
2266 THEN
2267 IF
2268 coalesce(OLD."accepted", FALSE) = coalesce(NEW."accepted", FALSE)
2269 THEN
2270 RETURN NULL;
2271 END IF;
2272 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2273 "accepted_v" := TRUE;
2274 ELSE
2275 "rejected_v" := TRUE;
2276 END IF;
2277 END IF;
2278 END IF;
2279 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "accepted_v" THEN
2280 IF coalesce(OLD."accepted", FALSE) = TRUE THEN
2281 SELECT * INTO "initiative_row" FROM "initiative"
2282 WHERE "id" = OLD."initiative_id" FOR SHARE;
2283 IF "initiative_row"."id" NOTNULL THEN
2284 SELECT * INTO "issue_row" FROM "issue"
2285 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2286 SELECT * INTO "area_row" FROM "area"
2287 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2288 INSERT INTO "event" (
2289 "event", "member_id",
2290 "unit_id", "area_id", "policy_id", "issue_id", "state",
2291 "initiative_id", "boolean_value"
2292 ) VALUES (
2293 'initiator', OLD."member_id",
2294 "area_row"."unit_id", "issue_row"."area_id",
2295 "issue_row"."policy_id",
2296 "issue_row"."id", "issue_row"."state",
2297 OLD."initiative_id", FALSE
2298 );
2299 END IF;
2300 END IF;
2301 END IF;
2302 IF TG_OP = 'UPDATE' AND NOT "rejected_v" THEN
2303 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2304 SELECT * INTO "initiative_row" FROM "initiative"
2305 WHERE "id" = NEW."initiative_id" FOR SHARE;
2306 SELECT * INTO "issue_row" FROM "issue"
2307 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2308 SELECT * INTO "area_row" FROM "area"
2309 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2310 INSERT INTO "event" (
2311 "event", "member_id",
2312 "unit_id", "area_id", "policy_id", "issue_id", "state",
2313 "initiative_id", "boolean_value"
2314 ) VALUES (
2315 'initiator', NEW."member_id",
2316 "area_row"."unit_id", "issue_row"."area_id",
2317 "issue_row"."policy_id",
2318 "issue_row"."id", "issue_row"."state",
2319 NEW."initiative_id", TRUE
2320 );
2321 END IF;
2322 END IF;
2323 RETURN NULL;
2324 END;
2325 $$;
2327 CREATE TRIGGER "write_event_initiator"
2328 AFTER UPDATE OR DELETE ON "initiator" FOR EACH ROW EXECUTE PROCEDURE
2329 "write_event_initiator_trigger"();
2331 COMMENT ON FUNCTION "write_event_initiator_trigger"() IS 'Implementation of trigger "write_event_initiator" on table "initiator"';
2332 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)';
2335 CREATE FUNCTION "write_event_support_trigger"()
2336 RETURNS TRIGGER
2337 LANGUAGE 'plpgsql' VOLATILE AS $$
2338 DECLARE
2339 "issue_row" "issue"%ROWTYPE;
2340 "area_row" "area"%ROWTYPE;
2341 BEGIN
2342 IF TG_OP = 'UPDATE' THEN
2343 IF
2344 OLD."initiative_id" = NEW."initiative_id" AND
2345 OLD."member_id" = NEW."member_id"
2346 THEN
2347 IF OLD."draft_id" != NEW."draft_id" THEN
2348 SELECT * INTO "issue_row" FROM "issue"
2349 WHERE "id" = NEW."issue_id" FOR SHARE;
2350 SELECT * INTO "area_row" FROM "area"
2351 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2352 INSERT INTO "event" (
2353 "event", "member_id",
2354 "unit_id", "area_id", "policy_id", "issue_id", "state",
2355 "initiative_id", "draft_id"
2356 ) VALUES (
2357 'support_updated', NEW."member_id",
2358 "area_row"."unit_id", "issue_row"."area_id",
2359 "issue_row"."policy_id",
2360 "issue_row"."id", "issue_row"."state",
2361 NEW."initiative_id", NEW."draft_id"
2362 );
2363 END IF;
2364 RETURN NULL;
2365 END IF;
2366 END IF;
2367 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2368 IF EXISTS (
2369 SELECT NULL FROM "initiative" WHERE "id" = OLD."initiative_id"
2370 FOR SHARE
2371 ) THEN
2372 SELECT * INTO "issue_row" FROM "issue"
2373 WHERE "id" = OLD."issue_id" FOR SHARE;
2374 SELECT * INTO "area_row" FROM "area"
2375 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2376 INSERT INTO "event" (
2377 "event", "member_id",
2378 "unit_id", "area_id", "policy_id", "issue_id", "state",
2379 "initiative_id", "boolean_value"
2380 ) VALUES (
2381 'support', OLD."member_id",
2382 "area_row"."unit_id", "issue_row"."area_id",
2383 "issue_row"."policy_id",
2384 "issue_row"."id", "issue_row"."state",
2385 OLD."initiative_id", FALSE
2386 );
2387 END IF;
2388 END IF;
2389 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2390 SELECT * INTO "issue_row" FROM "issue"
2391 WHERE "id" = NEW."issue_id" FOR SHARE;
2392 SELECT * INTO "area_row" FROM "area"
2393 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2394 INSERT INTO "event" (
2395 "event", "member_id",
2396 "unit_id", "area_id", "policy_id", "issue_id", "state",
2397 "initiative_id", "draft_id", "boolean_value"
2398 ) VALUES (
2399 'support', NEW."member_id",
2400 "area_row"."unit_id", "issue_row"."area_id",
2401 "issue_row"."policy_id",
2402 "issue_row"."id", "issue_row"."state",
2403 NEW."initiative_id", NEW."draft_id", TRUE
2404 );
2405 END IF;
2406 RETURN NULL;
2407 END;
2408 $$;
2410 CREATE TRIGGER "write_event_support"
2411 AFTER INSERT OR UPDATE OR DELETE ON "supporter" FOR EACH ROW EXECUTE PROCEDURE
2412 "write_event_support_trigger"();
2414 COMMENT ON FUNCTION "write_event_support_trigger"() IS 'Implementation of trigger "write_event_support" on table "supporter"';
2415 COMMENT ON TRIGGER "write_event_support" ON "supporter" IS 'Create entry in "event" table when adding, updating, or removing support';
2418 CREATE FUNCTION "write_event_suggestion_rated_trigger"()
2419 RETURNS TRIGGER
2420 LANGUAGE 'plpgsql' VOLATILE AS $$
2421 DECLARE
2422 "same_pkey_v" BOOLEAN = FALSE;
2423 "initiative_row" "initiative"%ROWTYPE;
2424 "issue_row" "issue"%ROWTYPE;
2425 "area_row" "area"%ROWTYPE;
2426 BEGIN
2427 IF TG_OP = 'UPDATE' THEN
2428 IF
2429 OLD."suggestion_id" = NEW."suggestion_id" AND
2430 OLD."member_id" = NEW."member_id"
2431 THEN
2432 IF
2433 OLD."degree" = NEW."degree" AND
2434 OLD."fulfilled" = NEW."fulfilled"
2435 THEN
2436 RETURN NULL;
2437 END IF;
2438 "same_pkey_v" := TRUE;
2439 END IF;
2440 END IF;
2441 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "same_pkey_v" THEN
2442 IF EXISTS (
2443 SELECT NULL FROM "suggestion" WHERE "id" = OLD."suggestion_id"
2444 FOR SHARE
2445 ) THEN
2446 SELECT * INTO "initiative_row" FROM "initiative"
2447 WHERE "id" = OLD."initiative_id" FOR SHARE;
2448 SELECT * INTO "issue_row" FROM "issue"
2449 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2450 SELECT * INTO "area_row" FROM "area"
2451 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2452 INSERT INTO "event" (
2453 "event", "member_id",
2454 "unit_id", "area_id", "policy_id", "issue_id", "state",
2455 "initiative_id", "suggestion_id",
2456 "boolean_value", "numeric_value"
2457 ) VALUES (
2458 'suggestion_rated', OLD."member_id",
2459 "area_row"."unit_id", "issue_row"."area_id",
2460 "issue_row"."policy_id",
2461 "initiative_row"."issue_id", "issue_row"."state",
2462 OLD."initiative_id", OLD."suggestion_id",
2463 NULL, 0
2464 );
2465 END IF;
2466 END IF;
2467 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2468 SELECT * INTO "initiative_row" FROM "initiative"
2469 WHERE "id" = NEW."initiative_id" FOR SHARE;
2470 SELECT * INTO "issue_row" FROM "issue"
2471 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2472 SELECT * INTO "area_row" FROM "area"
2473 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2474 INSERT INTO "event" (
2475 "event", "member_id",
2476 "unit_id", "area_id", "policy_id", "issue_id", "state",
2477 "initiative_id", "suggestion_id",
2478 "boolean_value", "numeric_value"
2479 ) VALUES (
2480 'suggestion_rated', NEW."member_id",
2481 "area_row"."unit_id", "issue_row"."area_id",
2482 "issue_row"."policy_id",
2483 "initiative_row"."issue_id", "issue_row"."state",
2484 NEW."initiative_id", NEW."suggestion_id",
2485 NEW."fulfilled", NEW."degree"
2486 );
2487 END IF;
2488 RETURN NULL;
2489 END;
2490 $$;
2492 CREATE TRIGGER "write_event_suggestion_rated"
2493 AFTER INSERT OR UPDATE OR DELETE ON "opinion" FOR EACH ROW EXECUTE PROCEDURE
2494 "write_event_suggestion_rated_trigger"();
2496 COMMENT ON FUNCTION "write_event_suggestion_rated_trigger"() IS 'Implementation of trigger "write_event_suggestion_rated" on table "opinion"';
2497 COMMENT ON TRIGGER "write_event_suggestion_rated" ON "opinion" IS 'Create entry in "event" table when adding, updating, or removing support';
2500 CREATE FUNCTION "write_event_delegation_trigger"()
2501 RETURNS TRIGGER
2502 LANGUAGE 'plpgsql' VOLATILE AS $$
2503 DECLARE
2504 "issue_row" "issue"%ROWTYPE;
2505 "area_row" "area"%ROWTYPE;
2506 BEGIN
2507 IF TG_OP = 'DELETE' THEN
2508 IF EXISTS (
2509 SELECT NULL FROM "member" WHERE "id" = OLD."truster_id"
2510 ) AND (CASE OLD."scope"
2511 WHEN 'unit'::"delegation_scope" THEN EXISTS (
2512 SELECT NULL FROM "unit" WHERE "id" = OLD."unit_id"
2514 WHEN 'area'::"delegation_scope" THEN EXISTS (
2515 SELECT NULL FROM "area" WHERE "id" = OLD."area_id"
2517 WHEN 'issue'::"delegation_scope" THEN EXISTS (
2518 SELECT NULL FROM "issue" WHERE "id" = OLD."issue_id"
2520 END) THEN
2521 SELECT * INTO "issue_row" FROM "issue"
2522 WHERE "id" = OLD."issue_id" FOR SHARE;
2523 SELECT * INTO "area_row" FROM "area"
2524 WHERE "id" = COALESCE(OLD."area_id", "issue_row"."area_id")
2525 FOR SHARE;
2526 INSERT INTO "event" (
2527 "event", "member_id", "scope",
2528 "unit_id", "area_id", "issue_id", "state",
2529 "boolean_value"
2530 ) VALUES (
2531 'delegation', OLD."truster_id", OLD."scope",
2532 COALESCE(OLD."unit_id", "area_row"."unit_id"), "area_row"."id",
2533 OLD."issue_id", "issue_row"."state",
2534 FALSE
2535 );
2536 END IF;
2537 ELSE
2538 SELECT * INTO "issue_row" FROM "issue"
2539 WHERE "id" = NEW."issue_id" FOR SHARE;
2540 SELECT * INTO "area_row" FROM "area"
2541 WHERE "id" = COALESCE(NEW."area_id", "issue_row"."area_id")
2542 FOR SHARE;
2543 INSERT INTO "event" (
2544 "event", "member_id", "other_member_id", "scope",
2545 "unit_id", "area_id", "issue_id", "state",
2546 "boolean_value"
2547 ) VALUES (
2548 'delegation', NEW."truster_id", NEW."trustee_id", NEW."scope",
2549 COALESCE(NEW."unit_id", "area_row"."unit_id"), "area_row"."id",
2550 NEW."issue_id", "issue_row"."state",
2551 TRUE
2552 );
2553 END IF;
2554 RETURN NULL;
2555 END;
2556 $$;
2558 CREATE TRIGGER "write_event_delegation"
2559 AFTER INSERT OR UPDATE OR DELETE ON "delegation" FOR EACH ROW EXECUTE PROCEDURE
2560 "write_event_delegation_trigger"();
2562 COMMENT ON FUNCTION "write_event_delegation_trigger"() IS 'Implementation of trigger "write_event_delegation" on table "delegation"';
2563 COMMENT ON TRIGGER "write_event_delegation" ON "delegation" IS 'Create entry in "event" table when adding, updating, or removing a delegation';
2566 CREATE FUNCTION "write_event_contact_trigger"()
2567 RETURNS TRIGGER
2568 LANGUAGE 'plpgsql' VOLATILE AS $$
2569 BEGIN
2570 IF TG_OP = 'UPDATE' THEN
2571 IF
2572 OLD."member_id" = NEW."member_id" AND
2573 OLD."other_member_id" = NEW."other_member_id" AND
2574 OLD."public" = NEW."public"
2575 THEN
2576 RETURN NULL;
2577 END IF;
2578 END IF;
2579 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2580 IF OLD."public" THEN
2581 IF EXISTS (
2582 SELECT NULL FROM "member" WHERE "id" = OLD."member_id"
2583 FOR SHARE
2584 ) AND EXISTS (
2585 SELECT NULL FROM "member" WHERE "id" = OLD."other_member_id"
2586 FOR SHARE
2587 ) THEN
2588 INSERT INTO "event" (
2589 "event", "member_id", "other_member_id", "boolean_value"
2590 ) VALUES (
2591 'contact', OLD."member_id", OLD."other_member_id", FALSE
2592 );
2593 END IF;
2594 END IF;
2595 END IF;
2596 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2597 IF NEW."public" THEN
2598 INSERT INTO "event" (
2599 "event", "member_id", "other_member_id", "boolean_value"
2600 ) VALUES (
2601 'contact', NEW."member_id", NEW."other_member_id", TRUE
2602 );
2603 END IF;
2604 END IF;
2605 RETURN NULL;
2606 END;
2607 $$;
2609 CREATE TRIGGER "write_event_contact"
2610 AFTER INSERT OR UPDATE OR DELETE ON "contact" FOR EACH ROW EXECUTE PROCEDURE
2611 "write_event_contact_trigger"();
2613 COMMENT ON FUNCTION "write_event_contact_trigger"() IS 'Implementation of trigger "write_event_contact" on table "contact"';
2614 COMMENT ON TRIGGER "write_event_contact" ON "contact" IS 'Create entry in "event" table when adding or removing public contacts';
2617 CREATE FUNCTION "send_event_notify_trigger"()
2618 RETURNS TRIGGER
2619 LANGUAGE 'plpgsql' VOLATILE AS $$
2620 BEGIN
2621 EXECUTE 'NOTIFY "event", ''' || NEW."event" || '''';
2622 RETURN NULL;
2623 END;
2624 $$;
2626 CREATE TRIGGER "send_notify"
2627 AFTER INSERT OR UPDATE ON "event" FOR EACH ROW EXECUTE PROCEDURE
2628 "send_event_notify_trigger"();
2632 ----------------------------
2633 -- Additional constraints --
2634 ----------------------------
2637 CREATE FUNCTION "delete_extended_scope_tokens_trigger"()
2638 RETURNS TRIGGER
2639 LANGUAGE 'plpgsql' VOLATILE AS $$
2640 DECLARE
2641 "system_application_row" "system_application"%ROWTYPE;
2642 BEGIN
2643 IF OLD."system_application_id" NOTNULL THEN
2644 SELECT * FROM "system_application" INTO "system_application_row"
2645 WHERE "id" = OLD."system_application_id";
2646 DELETE FROM "token"
2647 WHERE "member_id" = OLD."member_id"
2648 AND "system_application_id" = OLD."system_application_id"
2649 AND NOT COALESCE(
2650 regexp_split_to_array("scope", E'\\s+') <@
2651 regexp_split_to_array(
2652 "system_application_row"."automatic_scope", E'\\s+'
2653 ),
2654 FALSE
2655 );
2656 END IF;
2657 RETURN OLD;
2658 END;
2659 $$;
2661 CREATE TRIGGER "delete_extended_scope_tokens"
2662 BEFORE DELETE ON "member_application" FOR EACH ROW EXECUTE PROCEDURE
2663 "delete_extended_scope_tokens_trigger"();
2666 CREATE FUNCTION "detach_token_from_session_trigger"()
2667 RETURNS TRIGGER
2668 LANGUAGE 'plpgsql' VOLATILE AS $$
2669 BEGIN
2670 UPDATE "token" SET "session_id" = NULL
2671 WHERE "session_id" = OLD."id";
2672 RETURN OLD;
2673 END;
2674 $$;
2676 CREATE TRIGGER "detach_token_from_session"
2677 BEFORE DELETE ON "session" FOR EACH ROW EXECUTE PROCEDURE
2678 "detach_token_from_session_trigger"();
2681 CREATE FUNCTION "delete_non_detached_scope_with_session_trigger"()
2682 RETURNS TRIGGER
2683 LANGUAGE 'plpgsql' VOLATILE AS $$
2684 BEGIN
2685 IF NEW."session_id" ISNULL THEN
2686 SELECT coalesce(string_agg("element", ' '), '') INTO NEW."scope"
2687 FROM unnest(regexp_split_to_array(NEW."scope", E'\\s+')) AS "element"
2688 WHERE "element" LIKE '%_detached';
2689 END IF;
2690 RETURN NEW;
2691 END;
2692 $$;
2694 CREATE TRIGGER "delete_non_detached_scope_with_session"
2695 BEFORE INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2696 "delete_non_detached_scope_with_session_trigger"();
2699 CREATE FUNCTION "delete_token_with_empty_scope_trigger"()
2700 RETURNS TRIGGER
2701 LANGUAGE 'plpgsql' VOLATILE AS $$
2702 BEGIN
2703 IF NEW."scope" = '' THEN
2704 DELETE FROM "token" WHERE "id" = NEW."id";
2705 END IF;
2706 RETURN NULL;
2707 END;
2708 $$;
2710 CREATE TRIGGER "delete_token_with_empty_scope"
2711 AFTER INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2712 "delete_token_with_empty_scope_trigger"();
2715 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
2716 RETURNS TRIGGER
2717 LANGUAGE 'plpgsql' VOLATILE AS $$
2718 BEGIN
2719 IF NOT EXISTS (
2720 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
2721 ) THEN
2722 RAISE EXCEPTION 'Cannot create issue without an initial initiative.' USING
2723 ERRCODE = 'integrity_constraint_violation',
2724 HINT = 'Create issue, initiative, and draft within the same transaction.';
2725 END IF;
2726 RETURN NULL;
2727 END;
2728 $$;
2730 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
2731 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
2732 FOR EACH ROW EXECUTE PROCEDURE
2733 "issue_requires_first_initiative_trigger"();
2735 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
2736 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
2739 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
2740 RETURNS TRIGGER
2741 LANGUAGE 'plpgsql' VOLATILE AS $$
2742 DECLARE
2743 "reference_lost" BOOLEAN;
2744 BEGIN
2745 IF TG_OP = 'DELETE' THEN
2746 "reference_lost" := TRUE;
2747 ELSE
2748 "reference_lost" := NEW."issue_id" != OLD."issue_id";
2749 END IF;
2750 IF
2751 "reference_lost" AND NOT EXISTS (
2752 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
2754 THEN
2755 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
2756 END IF;
2757 RETURN NULL;
2758 END;
2759 $$;
2761 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
2762 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
2763 FOR EACH ROW EXECUTE PROCEDURE
2764 "last_initiative_deletes_issue_trigger"();
2766 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
2767 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
2770 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
2771 RETURNS TRIGGER
2772 LANGUAGE 'plpgsql' VOLATILE AS $$
2773 BEGIN
2774 IF NOT EXISTS (
2775 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
2776 ) THEN
2777 RAISE EXCEPTION 'Cannot create initiative without an initial draft.' USING
2778 ERRCODE = 'integrity_constraint_violation',
2779 HINT = 'Create issue, initiative and draft within the same transaction.';
2780 END IF;
2781 RETURN NULL;
2782 END;
2783 $$;
2785 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
2786 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
2787 FOR EACH ROW EXECUTE PROCEDURE
2788 "initiative_requires_first_draft_trigger"();
2790 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
2791 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
2794 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
2795 RETURNS TRIGGER
2796 LANGUAGE 'plpgsql' VOLATILE AS $$
2797 DECLARE
2798 "reference_lost" BOOLEAN;
2799 BEGIN
2800 IF TG_OP = 'DELETE' THEN
2801 "reference_lost" := TRUE;
2802 ELSE
2803 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
2804 END IF;
2805 IF
2806 "reference_lost" AND NOT EXISTS (
2807 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
2809 THEN
2810 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
2811 END IF;
2812 RETURN NULL;
2813 END;
2814 $$;
2816 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
2817 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
2818 FOR EACH ROW EXECUTE PROCEDURE
2819 "last_draft_deletes_initiative_trigger"();
2821 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
2822 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
2825 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
2826 RETURNS TRIGGER
2827 LANGUAGE 'plpgsql' VOLATILE AS $$
2828 BEGIN
2829 IF NOT EXISTS (
2830 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
2831 ) THEN
2832 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.' USING
2833 ERRCODE = 'integrity_constraint_violation',
2834 HINT = 'Create suggestion and opinion within the same transaction.';
2835 END IF;
2836 RETURN NULL;
2837 END;
2838 $$;
2840 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
2841 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
2842 FOR EACH ROW EXECUTE PROCEDURE
2843 "suggestion_requires_first_opinion_trigger"();
2845 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
2846 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
2849 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
2850 RETURNS TRIGGER
2851 LANGUAGE 'plpgsql' VOLATILE AS $$
2852 DECLARE
2853 "reference_lost" BOOLEAN;
2854 BEGIN
2855 IF TG_OP = 'DELETE' THEN
2856 "reference_lost" := TRUE;
2857 ELSE
2858 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
2859 END IF;
2860 IF
2861 "reference_lost" AND NOT EXISTS (
2862 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
2864 THEN
2865 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
2866 END IF;
2867 RETURN NULL;
2868 END;
2869 $$;
2871 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
2872 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
2873 FOR EACH ROW EXECUTE PROCEDURE
2874 "last_opinion_deletes_suggestion_trigger"();
2876 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
2877 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
2880 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
2881 RETURNS TRIGGER
2882 LANGUAGE 'plpgsql' VOLATILE AS $$
2883 BEGIN
2884 DELETE FROM "direct_voter"
2885 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
2886 RETURN NULL;
2887 END;
2888 $$;
2890 CREATE TRIGGER "non_voter_deletes_direct_voter"
2891 AFTER INSERT OR UPDATE ON "non_voter"
2892 FOR EACH ROW EXECUTE PROCEDURE
2893 "non_voter_deletes_direct_voter_trigger"();
2895 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
2896 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")';
2899 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
2900 RETURNS TRIGGER
2901 LANGUAGE 'plpgsql' VOLATILE AS $$
2902 BEGIN
2903 DELETE FROM "non_voter"
2904 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
2905 RETURN NULL;
2906 END;
2907 $$;
2909 CREATE TRIGGER "direct_voter_deletes_non_voter"
2910 AFTER INSERT OR UPDATE ON "direct_voter"
2911 FOR EACH ROW EXECUTE PROCEDURE
2912 "direct_voter_deletes_non_voter_trigger"();
2914 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
2915 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")';
2918 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
2919 RETURNS TRIGGER
2920 LANGUAGE 'plpgsql' VOLATILE AS $$
2921 BEGIN
2922 IF NEW."comment" ISNULL THEN
2923 NEW."comment_changed" := NULL;
2924 NEW."formatting_engine" := NULL;
2925 END IF;
2926 RETURN NEW;
2927 END;
2928 $$;
2930 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
2931 BEFORE INSERT OR UPDATE ON "direct_voter"
2932 FOR EACH ROW EXECUTE PROCEDURE
2933 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
2935 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"';
2936 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.';
2940 ---------------------------------
2941 -- Delete incomplete snapshots --
2942 ---------------------------------
2945 CREATE FUNCTION "delete_snapshot_on_partial_delete_trigger"()
2946 RETURNS TRIGGER
2947 LANGUAGE 'plpgsql' VOLATILE AS $$
2948 BEGIN
2949 IF TG_OP = 'UPDATE' THEN
2950 IF
2951 OLD."snapshot_id" = NEW."snapshot_id" AND
2952 OLD."issue_id" = NEW."issue_id"
2953 THEN
2954 RETURN NULL;
2955 END IF;
2956 END IF;
2957 DELETE FROM "snapshot" WHERE "id" = OLD."snapshot_id";
2958 RETURN NULL;
2959 END;
2960 $$;
2962 CREATE TRIGGER "delete_snapshot_on_partial_delete"
2963 AFTER UPDATE OR DELETE ON "snapshot_issue"
2964 FOR EACH ROW EXECUTE PROCEDURE
2965 "delete_snapshot_on_partial_delete_trigger"();
2967 COMMENT ON FUNCTION "delete_snapshot_on_partial_delete_trigger"() IS 'Implementation of trigger "delete_snapshot_on_partial_delete" on table "snapshot_issue"';
2968 COMMENT ON TRIGGER "delete_snapshot_on_partial_delete" ON "snapshot_issue" IS 'Deletes whole snapshot if one issue is deleted from the snapshot';
2972 ---------------------------------------------------------------
2973 -- Ensure that votes are not modified when issues are closed --
2974 ---------------------------------------------------------------
2976 -- NOTE: Frontends should ensure this anyway, but in case of programming
2977 -- errors the following triggers ensure data integrity.
2980 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
2981 RETURNS TRIGGER
2982 LANGUAGE 'plpgsql' VOLATILE AS $$
2983 DECLARE
2984 "issue_id_v" "issue"."id"%TYPE;
2985 "issue_row" "issue"%ROWTYPE;
2986 BEGIN
2987 IF EXISTS (
2988 SELECT NULL FROM "temporary_transaction_data"
2989 WHERE "txid" = txid_current()
2990 AND "key" = 'override_protection_triggers'
2991 AND "value" = TRUE::TEXT
2992 ) THEN
2993 RETURN NULL;
2994 END IF;
2995 IF TG_OP = 'DELETE' THEN
2996 "issue_id_v" := OLD."issue_id";
2997 ELSE
2998 "issue_id_v" := NEW."issue_id";
2999 END IF;
3000 SELECT INTO "issue_row" * FROM "issue"
3001 WHERE "id" = "issue_id_v" FOR SHARE;
3002 IF (
3003 "issue_row"."closed" NOTNULL OR (
3004 "issue_row"."state" = 'voting' AND
3005 "issue_row"."phase_finished" NOTNULL
3007 ) THEN
3008 IF
3009 TG_RELID = 'direct_voter'::regclass AND
3010 TG_OP = 'UPDATE'
3011 THEN
3012 IF
3013 OLD."issue_id" = NEW."issue_id" AND
3014 OLD."member_id" = NEW."member_id" AND
3015 OLD."weight" = NEW."weight"
3016 THEN
3017 RETURN NULL; -- allows changing of voter comment
3018 END IF;
3019 END IF;
3020 RAISE EXCEPTION 'Tried to modify data after voting has been closed.' USING
3021 ERRCODE = 'integrity_constraint_violation';
3022 END IF;
3023 RETURN NULL;
3024 END;
3025 $$;
3027 CREATE TRIGGER "forbid_changes_on_closed_issue"
3028 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
3029 FOR EACH ROW EXECUTE PROCEDURE
3030 "forbid_changes_on_closed_issue_trigger"();
3032 CREATE TRIGGER "forbid_changes_on_closed_issue"
3033 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
3034 FOR EACH ROW EXECUTE PROCEDURE
3035 "forbid_changes_on_closed_issue_trigger"();
3037 CREATE TRIGGER "forbid_changes_on_closed_issue"
3038 AFTER INSERT OR UPDATE OR DELETE ON "vote"
3039 FOR EACH ROW EXECUTE PROCEDURE
3040 "forbid_changes_on_closed_issue_trigger"();
3042 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"';
3043 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';
3044 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';
3045 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';
3049 --------------------------------------------------------------------
3050 -- Auto-retrieval of fields only needed for referential integrity --
3051 --------------------------------------------------------------------
3054 CREATE FUNCTION "autofill_issue_id_trigger"()
3055 RETURNS TRIGGER
3056 LANGUAGE 'plpgsql' VOLATILE AS $$
3057 BEGIN
3058 IF NEW."issue_id" ISNULL THEN
3059 SELECT "issue_id" INTO NEW."issue_id"
3060 FROM "initiative" WHERE "id" = NEW."initiative_id";
3061 END IF;
3062 RETURN NEW;
3063 END;
3064 $$;
3066 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
3067 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3069 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
3070 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3072 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
3073 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
3074 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
3077 CREATE FUNCTION "autofill_initiative_id_trigger"()
3078 RETURNS TRIGGER
3079 LANGUAGE 'plpgsql' VOLATILE AS $$
3080 BEGIN
3081 IF NEW."initiative_id" ISNULL THEN
3082 SELECT "initiative_id" INTO NEW."initiative_id"
3083 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3084 END IF;
3085 RETURN NEW;
3086 END;
3087 $$;
3089 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
3090 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
3092 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
3093 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
3097 -------------------------------------------------------
3098 -- Automatic copying of values for indexing purposes --
3099 -------------------------------------------------------
3102 CREATE FUNCTION "copy_current_draft_data"
3103 ("initiative_id_p" "initiative"."id"%TYPE )
3104 RETURNS VOID
3105 LANGUAGE 'plpgsql' VOLATILE AS $$
3106 BEGIN
3107 PERFORM NULL FROM "initiative" WHERE "id" = "initiative_id_p"
3108 FOR UPDATE;
3109 UPDATE "initiative" SET
3110 "location" = "draft"."location",
3111 "draft_text_search_data" = "draft"."text_search_data"
3112 FROM "current_draft" AS "draft"
3113 WHERE "initiative"."id" = "initiative_id_p"
3114 AND "draft"."initiative_id" = "initiative_id_p";
3115 END;
3116 $$;
3118 COMMENT ON FUNCTION "copy_current_draft_data"
3119 ( "initiative"."id"%TYPE )
3120 IS 'Helper function for function "copy_current_draft_data_trigger"';
3123 CREATE FUNCTION "copy_current_draft_data_trigger"()
3124 RETURNS TRIGGER
3125 LANGUAGE 'plpgsql' VOLATILE AS $$
3126 BEGIN
3127 IF TG_OP='DELETE' THEN
3128 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3129 ELSE
3130 IF TG_OP='UPDATE' THEN
3131 IF COALESCE(OLD."inititiave_id" != NEW."initiative_id", TRUE) THEN
3132 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3133 END IF;
3134 END IF;
3135 PERFORM "copy_current_draft_data"(NEW."initiative_id");
3136 END IF;
3137 RETURN NULL;
3138 END;
3139 $$;
3141 CREATE TRIGGER "copy_current_draft_data"
3142 AFTER INSERT OR UPDATE OR DELETE ON "draft"
3143 FOR EACH ROW EXECUTE PROCEDURE
3144 "copy_current_draft_data_trigger"();
3146 COMMENT ON FUNCTION "copy_current_draft_data_trigger"() IS 'Implementation of trigger "copy_current_draft_data" on table "draft"';
3147 COMMENT ON TRIGGER "copy_current_draft_data" ON "draft" IS 'Copy certain fields from most recent "draft" to "initiative"';
3151 -----------------------------------------------------
3152 -- Automatic calculation of certain default values --
3153 -----------------------------------------------------
3156 CREATE FUNCTION "copy_timings_trigger"()
3157 RETURNS TRIGGER
3158 LANGUAGE 'plpgsql' VOLATILE AS $$
3159 DECLARE
3160 "policy_row" "policy"%ROWTYPE;
3161 BEGIN
3162 SELECT * INTO "policy_row" FROM "policy"
3163 WHERE "id" = NEW."policy_id";
3164 IF NEW."min_admission_time" ISNULL THEN
3165 NEW."min_admission_time" := "policy_row"."min_admission_time";
3166 END IF;
3167 IF NEW."max_admission_time" ISNULL THEN
3168 NEW."max_admission_time" := "policy_row"."max_admission_time";
3169 END IF;
3170 IF NEW."discussion_time" ISNULL THEN
3171 NEW."discussion_time" := "policy_row"."discussion_time";
3172 END IF;
3173 IF NEW."verification_time" ISNULL THEN
3174 NEW."verification_time" := "policy_row"."verification_time";
3175 END IF;
3176 IF NEW."voting_time" ISNULL THEN
3177 NEW."voting_time" := "policy_row"."voting_time";
3178 END IF;
3179 RETURN NEW;
3180 END;
3181 $$;
3183 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
3184 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
3186 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
3187 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
3190 CREATE FUNCTION "default_for_draft_id_trigger"()
3191 RETURNS TRIGGER
3192 LANGUAGE 'plpgsql' VOLATILE AS $$
3193 BEGIN
3194 IF NEW."draft_id" ISNULL THEN
3195 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
3196 WHERE "initiative_id" = NEW."initiative_id";
3197 END IF;
3198 RETURN NEW;
3199 END;
3200 $$;
3202 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
3203 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3204 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
3205 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3207 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
3208 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';
3209 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';
3213 ----------------------------------------
3214 -- Automatic creation of dependencies --
3215 ----------------------------------------
3218 CREATE FUNCTION "autocreate_interest_trigger"()
3219 RETURNS TRIGGER
3220 LANGUAGE 'plpgsql' VOLATILE AS $$
3221 BEGIN
3222 IF NOT EXISTS (
3223 SELECT NULL FROM "initiative" JOIN "interest"
3224 ON "initiative"."issue_id" = "interest"."issue_id"
3225 WHERE "initiative"."id" = NEW."initiative_id"
3226 AND "interest"."member_id" = NEW."member_id"
3227 ) THEN
3228 BEGIN
3229 INSERT INTO "interest" ("issue_id", "member_id")
3230 SELECT "issue_id", NEW."member_id"
3231 FROM "initiative" WHERE "id" = NEW."initiative_id";
3232 EXCEPTION WHEN unique_violation THEN END;
3233 END IF;
3234 RETURN NEW;
3235 END;
3236 $$;
3238 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
3239 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
3241 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
3242 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';
3245 CREATE FUNCTION "autocreate_supporter_trigger"()
3246 RETURNS TRIGGER
3247 LANGUAGE 'plpgsql' VOLATILE AS $$
3248 BEGIN
3249 IF NOT EXISTS (
3250 SELECT NULL FROM "suggestion" JOIN "supporter"
3251 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
3252 WHERE "suggestion"."id" = NEW."suggestion_id"
3253 AND "supporter"."member_id" = NEW."member_id"
3254 ) THEN
3255 BEGIN
3256 INSERT INTO "supporter" ("initiative_id", "member_id")
3257 SELECT "initiative_id", NEW."member_id"
3258 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3259 EXCEPTION WHEN unique_violation THEN END;
3260 END IF;
3261 RETURN NEW;
3262 END;
3263 $$;
3265 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
3266 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
3268 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
3269 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.';
3273 ------------------------------------------
3274 -- Views and helper functions for views --
3275 ------------------------------------------
3278 CREATE VIEW "member_eligible_to_be_notified" AS
3279 SELECT * FROM "member"
3280 WHERE "activated" NOTNULL AND "locked" = FALSE;
3282 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")';
3285 CREATE VIEW "member_to_notify" AS
3286 SELECT * FROM "member_eligible_to_be_notified"
3287 WHERE "disable_notifications" = FALSE;
3289 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)';
3292 CREATE VIEW "area_quorum" AS
3293 SELECT
3294 "area"."id" AS "area_id",
3295 ceil(
3296 "area"."quorum_standard"::FLOAT8 * "quorum_factor"::FLOAT8 ^ (
3297 coalesce(
3298 ( SELECT sum(
3299 ( extract(epoch from "area"."quorum_time")::FLOAT8 /
3300 extract(epoch from
3301 ("issue"."accepted"-"issue"."created") +
3302 "issue"."discussion_time" +
3303 "issue"."verification_time" +
3304 "issue"."voting_time"
3305 )::FLOAT8
3306 ) ^ "area"."quorum_exponent"::FLOAT8
3308 FROM "issue" JOIN "policy"
3309 ON "issue"."policy_id" = "policy"."id"
3310 WHERE "issue"."area_id" = "area"."id"
3311 AND "issue"."accepted" NOTNULL
3312 AND "issue"."closed" ISNULL
3313 AND "policy"."polling" = FALSE
3314 )::FLOAT8, 0::FLOAT8
3315 ) / "area"."quorum_issues"::FLOAT8 - 1::FLOAT8
3316 ) * CASE WHEN "area"."quorum_den" ISNULL THEN 1 ELSE (
3317 SELECT "snapshot"."population"
3318 FROM "snapshot"
3319 WHERE "snapshot"."area_id" = "area"."id"
3320 AND "snapshot"."issue_id" ISNULL
3321 ORDER BY "snapshot"."id" DESC
3322 LIMIT 1
3323 ) END / coalesce("area"."quorum_den", 1)
3325 )::INT4 AS "issue_quorum"
3326 FROM "area";
3328 COMMENT ON VIEW "area_quorum" IS 'Area-based quorum considering number of open (accepted) issues';
3331 CREATE VIEW "issue_quorum" AS
3332 SELECT DISTINCT ON ("issue_id")
3333 "issue"."id" AS "issue_id",
3334 "subquery"."issue_quorum"
3335 FROM "issue"
3336 CROSS JOIN LATERAL (
3337 SELECT "area_quorum"."issue_quorum"
3338 FROM "area_quorum" WHERE "area_quorum"."area_id" = "issue"."area_id"
3339 UNION ALL
3340 SELECT "policy"."issue_quorum"
3341 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3342 UNION ALL
3343 SELECT
3344 ceil(
3345 ("issue"."population"::INT8 * "policy"."issue_quorum_num"::INT8) /
3346 "policy"."issue_quorum_den"::FLOAT8
3347 )::INT4
3348 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3349 ) AS "subquery"
3350 ORDER BY "issue_id", "issue_quorum" DESC;
3352 COMMENT ON VIEW "issue_quorum" IS 'Effective quorum for issue admission';
3355 CREATE VIEW "area_with_unaccepted_issues" AS
3356 SELECT DISTINCT ON ("area"."id") "area".*
3357 FROM "area" JOIN "issue" ON "area"."id" = "issue"."area_id"
3358 WHERE "issue"."state" = 'admission';
3360 COMMENT ON VIEW "area_with_unaccepted_issues" IS 'All areas with unaccepted open issues (needed for issue admission system)';
3363 CREATE VIEW "issue_for_admission" AS
3364 SELECT DISTINCT ON ("issue"."area_id")
3365 "issue".*,
3366 max("initiative"."supporter_count") AS "max_supporter_count"
3367 FROM "issue"
3368 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
3369 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
3370 JOIN "area" ON "issue"."area_id" = "area"."id"
3371 WHERE "issue"."state" = 'admission'::"issue_state"
3372 AND now() >= "issue"."created" + "issue"."min_admission_time"
3373 AND "initiative"."supporter_count" >= "policy"."issue_quorum"
3374 AND "initiative"."supporter_count" * "policy"."issue_quorum_den" >=
3375 "issue"."population" * "policy"."issue_quorum_num"
3376 AND "initiative"."supporter_count" >= "area"."issue_quorum"
3377 AND "initiative"."revoked" ISNULL
3378 GROUP BY "issue"."id"
3379 ORDER BY "issue"."area_id", "max_supporter_count" DESC, "issue"."id";
3381 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';
3384 CREATE VIEW "unit_delegation" AS
3385 SELECT
3386 "unit"."id" AS "unit_id",
3387 "delegation"."id",
3388 "delegation"."truster_id",
3389 "delegation"."trustee_id",
3390 "delegation"."scope"
3391 FROM "unit"
3392 JOIN "delegation"
3393 ON "delegation"."unit_id" = "unit"."id"
3394 JOIN "member"
3395 ON "delegation"."truster_id" = "member"."id"
3396 JOIN "privilege"
3397 ON "delegation"."unit_id" = "privilege"."unit_id"
3398 AND "delegation"."truster_id" = "privilege"."member_id"
3399 WHERE "member"."active" AND "privilege"."voting_right";
3401 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
3404 CREATE VIEW "area_delegation" AS
3405 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
3406 "area"."id" AS "area_id",
3407 "delegation"."id",
3408 "delegation"."truster_id",
3409 "delegation"."trustee_id",
3410 "delegation"."scope"
3411 FROM "area"
3412 JOIN "delegation"
3413 ON "delegation"."unit_id" = "area"."unit_id"
3414 OR "delegation"."area_id" = "area"."id"
3415 JOIN "member"
3416 ON "delegation"."truster_id" = "member"."id"
3417 JOIN "privilege"
3418 ON "area"."unit_id" = "privilege"."unit_id"
3419 AND "delegation"."truster_id" = "privilege"."member_id"
3420 WHERE "member"."active" AND "privilege"."voting_right"
3421 ORDER BY
3422 "area"."id",
3423 "delegation"."truster_id",
3424 "delegation"."scope" DESC;
3426 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
3429 CREATE VIEW "issue_delegation" AS
3430 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
3431 "issue"."id" AS "issue_id",
3432 "delegation"."id",
3433 "delegation"."truster_id",
3434 "delegation"."trustee_id",
3435 "delegation"."scope"
3436 FROM "issue"
3437 JOIN "area"
3438 ON "area"."id" = "issue"."area_id"
3439 JOIN "delegation"
3440 ON "delegation"."unit_id" = "area"."unit_id"
3441 OR "delegation"."area_id" = "area"."id"
3442 OR "delegation"."issue_id" = "issue"."id"
3443 JOIN "member"
3444 ON "delegation"."truster_id" = "member"."id"
3445 JOIN "privilege"
3446 ON "area"."unit_id" = "privilege"."unit_id"
3447 AND "delegation"."truster_id" = "privilege"."member_id"
3448 WHERE "member"."active" AND "privilege"."voting_right"
3449 ORDER BY
3450 "issue"."id",
3451 "delegation"."truster_id",
3452 "delegation"."scope" DESC;
3454 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
3457 CREATE VIEW "member_count_view" AS
3458 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
3460 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
3463 CREATE VIEW "unit_member" AS
3464 SELECT
3465 "unit"."id" AS "unit_id",
3466 "member"."id" AS "member_id"
3467 FROM "privilege"
3468 JOIN "unit" ON "unit"."id" = "privilege"."unit_id"
3469 JOIN "member" ON "member"."id" = "privilege"."member_id"
3470 WHERE "privilege"."voting_right" AND "member"."active";
3472 COMMENT ON VIEW "unit_member" IS 'Active members with voting right in a unit';
3475 CREATE VIEW "unit_member_count" AS
3476 SELECT
3477 "unit"."id" AS "unit_id",
3478 count("unit_member"."member_id") AS "member_count"
3479 FROM "unit" LEFT JOIN "unit_member"
3480 ON "unit"."id" = "unit_member"."unit_id"
3481 GROUP BY "unit"."id";
3483 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
3486 CREATE VIEW "opening_draft" AS
3487 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3488 ORDER BY "initiative_id", "id";
3490 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
3493 CREATE VIEW "current_draft" AS
3494 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3495 ORDER BY "initiative_id", "id" DESC;
3497 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
3500 CREATE VIEW "critical_opinion" AS
3501 SELECT * FROM "opinion"
3502 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
3503 OR ("degree" = -2 AND "fulfilled" = TRUE);
3505 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
3508 CREATE VIEW "issue_supporter_in_admission_state" AS
3509 SELECT
3510 "area"."unit_id",
3511 "issue"."area_id",
3512 "issue"."id" AS "issue_id",
3513 "supporter"."member_id",
3514 "direct_interest_snapshot"."weight"
3515 FROM "issue"
3516 JOIN "area" ON "area"."id" = "issue"."area_id"
3517 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
3518 JOIN "direct_interest_snapshot"
3519 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3520 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3521 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
3522 WHERE "issue"."state" = 'admission'::"issue_state";
3524 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';
3527 CREATE VIEW "initiative_suggestion_order_calculation" AS
3528 SELECT
3529 "initiative"."id" AS "initiative_id",
3530 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
3531 FROM "initiative" JOIN "issue"
3532 ON "initiative"."issue_id" = "issue"."id"
3533 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
3534 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
3536 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
3538 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';
3541 CREATE VIEW "individual_suggestion_ranking" AS
3542 SELECT
3543 "opinion"."initiative_id",
3544 "opinion"."member_id",
3545 "direct_interest_snapshot"."weight",
3546 CASE WHEN
3547 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
3548 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
3549 THEN 1 ELSE
3550 CASE WHEN
3551 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
3552 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
3553 THEN 2 ELSE
3554 CASE WHEN
3555 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
3556 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
3557 THEN 3 ELSE 4 END
3558 END
3559 END AS "preference",
3560 "opinion"."suggestion_id"
3561 FROM "opinion"
3562 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
3563 JOIN "issue" ON "issue"."id" = "initiative"."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" = "opinion"."member_id";
3569 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
3572 CREATE VIEW "battle_participant" AS
3573 SELECT "initiative"."id", "initiative"."issue_id"
3574 FROM "issue" JOIN "initiative"
3575 ON "issue"."id" = "initiative"."issue_id"
3576 WHERE "initiative"."admitted"
3577 UNION ALL
3578 SELECT NULL, "id" AS "issue_id"
3579 FROM "issue";
3581 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
3584 CREATE VIEW "battle_view" AS
3585 SELECT
3586 "issue"."id" AS "issue_id",
3587 "winning_initiative"."id" AS "winning_initiative_id",
3588 "losing_initiative"."id" AS "losing_initiative_id",
3589 sum(
3590 CASE WHEN
3591 coalesce("better_vote"."grade", 0) >
3592 coalesce("worse_vote"."grade", 0)
3593 THEN "direct_voter"."weight" ELSE 0 END
3594 ) AS "count"
3595 FROM "issue"
3596 LEFT JOIN "direct_voter"
3597 ON "issue"."id" = "direct_voter"."issue_id"
3598 JOIN "battle_participant" AS "winning_initiative"
3599 ON "issue"."id" = "winning_initiative"."issue_id"
3600 JOIN "battle_participant" AS "losing_initiative"
3601 ON "issue"."id" = "losing_initiative"."issue_id"
3602 LEFT JOIN "vote" AS "better_vote"
3603 ON "direct_voter"."member_id" = "better_vote"."member_id"
3604 AND "winning_initiative"."id" = "better_vote"."initiative_id"
3605 LEFT JOIN "vote" AS "worse_vote"
3606 ON "direct_voter"."member_id" = "worse_vote"."member_id"
3607 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
3608 WHERE "issue"."state" = 'voting'
3609 AND "issue"."phase_finished" NOTNULL
3610 AND (
3611 "winning_initiative"."id" != "losing_initiative"."id" OR
3612 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
3613 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
3614 GROUP BY
3615 "issue"."id",
3616 "winning_initiative"."id",
3617 "losing_initiative"."id";
3619 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';
3622 CREATE VIEW "expired_session" AS
3623 SELECT * FROM "session" WHERE now() > "expiry";
3625 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
3626 DELETE FROM "session" WHERE "id" = OLD."id";
3628 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
3629 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
3632 CREATE VIEW "expired_token" AS
3633 SELECT * FROM "token" WHERE now() > "expiry" AND NOT (
3634 "token_type" = 'authorization' AND "used" AND EXISTS (
3635 SELECT NULL FROM "token" AS "other"
3636 WHERE "other"."authorization_token_id" = "id" ) );
3638 CREATE RULE "delete" AS ON DELETE TO "expired_token" DO INSTEAD
3639 DELETE FROM "token" WHERE "id" = OLD."id";
3641 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';
3644 CREATE VIEW "unused_snapshot" AS
3645 SELECT "snapshot".* FROM "snapshot"
3646 LEFT JOIN "issue"
3647 ON "snapshot"."id" = "issue"."latest_snapshot_id"
3648 OR "snapshot"."id" = "issue"."admission_snapshot_id"
3649 OR "snapshot"."id" = "issue"."half_freeze_snapshot_id"
3650 OR "snapshot"."id" = "issue"."full_freeze_snapshot_id"
3651 WHERE "issue"."id" ISNULL;
3653 CREATE RULE "delete" AS ON DELETE TO "unused_snapshot" DO INSTEAD
3654 DELETE FROM "snapshot" WHERE "id" = OLD."id";
3656 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)';
3659 CREATE VIEW "expired_snapshot" AS
3660 SELECT "unused_snapshot".* FROM "unused_snapshot" CROSS JOIN "system_setting"
3661 WHERE "unused_snapshot"."calculated" <
3662 now() - "system_setting"."snapshot_retention";
3664 CREATE RULE "delete" AS ON DELETE TO "expired_snapshot" DO INSTEAD
3665 DELETE FROM "snapshot" WHERE "id" = OLD."id";
3667 COMMENT ON VIEW "expired_snapshot" IS 'Contains "unused_snapshot"s that are older than "system_setting"."snapshot_retention" (for deletion)';
3670 CREATE VIEW "open_issue" AS
3671 SELECT * FROM "issue" WHERE "closed" ISNULL;
3673 COMMENT ON VIEW "open_issue" IS 'All open issues';
3676 CREATE VIEW "member_contingent" AS
3677 SELECT
3678 "member"."id" AS "member_id",
3679 "contingent"."polling",
3680 "contingent"."time_frame",
3681 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
3683 SELECT count(1) FROM "draft"
3684 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3685 WHERE "draft"."author_id" = "member"."id"
3686 AND "initiative"."polling" = "contingent"."polling"
3687 AND "draft"."created" > now() - "contingent"."time_frame"
3688 ) + (
3689 SELECT count(1) FROM "suggestion"
3690 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
3691 WHERE "suggestion"."author_id" = "member"."id"
3692 AND "contingent"."polling" = FALSE
3693 AND "suggestion"."created" > now() - "contingent"."time_frame"
3695 ELSE NULL END AS "text_entry_count",
3696 "contingent"."text_entry_limit",
3697 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
3698 SELECT count(1) FROM "opening_draft" AS "draft"
3699 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3700 WHERE "draft"."author_id" = "member"."id"
3701 AND "initiative"."polling" = "contingent"."polling"
3702 AND "draft"."created" > now() - "contingent"."time_frame"
3703 ) ELSE NULL END AS "initiative_count",
3704 "contingent"."initiative_limit"
3705 FROM "member" CROSS JOIN "contingent";
3707 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
3709 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
3710 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
3713 CREATE VIEW "member_contingent_left" AS
3714 SELECT
3715 "member_id",
3716 "polling",
3717 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
3718 max("initiative_limit" - "initiative_count") AS "initiatives_left"
3719 FROM "member_contingent" GROUP BY "member_id", "polling";
3721 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.';
3724 CREATE VIEW "event_for_notification" AS
3725 SELECT
3726 "member"."id" AS "recipient_id",
3727 "event".*
3728 FROM "member" CROSS JOIN "event"
3729 JOIN "issue" ON "issue"."id" = "event"."issue_id"
3730 JOIN "area" ON "area"."id" = "issue"."area_id"
3731 LEFT JOIN "privilege" ON
3732 "privilege"."member_id" = "member"."id" AND
3733 "privilege"."unit_id" = "area"."unit_id" AND
3734 "privilege"."voting_right" = TRUE
3735 LEFT JOIN "subscription" ON
3736 "subscription"."member_id" = "member"."id" AND
3737 "subscription"."unit_id" = "area"."unit_id"
3738 LEFT JOIN "ignored_area" ON
3739 "ignored_area"."member_id" = "member"."id" AND
3740 "ignored_area"."area_id" = "issue"."area_id"
3741 LEFT JOIN "interest" ON
3742 "interest"."member_id" = "member"."id" AND
3743 "interest"."issue_id" = "event"."issue_id"
3744 LEFT JOIN "supporter" ON
3745 "supporter"."member_id" = "member"."id" AND
3746 "supporter"."initiative_id" = "event"."initiative_id"
3747 WHERE ("privilege"."member_id" NOTNULL OR "subscription"."member_id" NOTNULL)
3748 AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL)
3749 AND (
3750 "event"."event" = 'issue_state_changed'::"event_type" OR
3751 ( "event"."event" = 'initiative_revoked'::"event_type" AND
3752 "supporter"."member_id" NOTNULL ) );
3754 COMMENT ON VIEW "event_for_notification" IS 'Entries of the "event" table which are of interest for a particular notification mail recipient';
3756 COMMENT ON COLUMN "event_for_notification"."recipient_id" IS 'member_id of the recipient of a notification mail';
3759 CREATE VIEW "updated_initiative" AS
3760 SELECT
3761 "supporter"."member_id" AS "recipient_id",
3762 FALSE AS "featured",
3763 "supporter"."initiative_id"
3764 FROM "supporter"
3765 JOIN "initiative" ON "supporter"."initiative_id" = "initiative"."id"
3766 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3767 LEFT JOIN "notification_initiative_sent" AS "sent" ON
3768 "sent"."member_id" = "supporter"."member_id" AND
3769 "sent"."initiative_id" = "supporter"."initiative_id"
3770 LEFT JOIN "ignored_initiative" ON
3771 "ignored_initiative"."member_id" = "supporter"."member_id" AND
3772 "ignored_initiative"."initiative_id" = "supporter"."initiative_id"
3773 WHERE "issue"."state" IN ('admission', 'discussion')
3774 AND "initiative"."revoked" ISNULL
3775 AND "ignored_initiative"."member_id" ISNULL
3776 AND (
3777 EXISTS (
3778 SELECT NULL FROM "draft"
3779 LEFT JOIN "ignored_member" ON
3780 "ignored_member"."member_id" = "supporter"."member_id" AND
3781 "ignored_member"."other_member_id" = "draft"."author_id"
3782 WHERE "draft"."initiative_id" = "supporter"."initiative_id"
3783 AND "draft"."id" > "supporter"."draft_id"
3784 AND "ignored_member"."member_id" ISNULL
3785 ) OR EXISTS (
3786 SELECT NULL FROM "suggestion"
3787 LEFT JOIN "opinion" ON
3788 "opinion"."member_id" = "supporter"."member_id" AND
3789 "opinion"."suggestion_id" = "suggestion"."id"
3790 LEFT JOIN "ignored_member" ON
3791 "ignored_member"."member_id" = "supporter"."member_id" AND
3792 "ignored_member"."other_member_id" = "suggestion"."author_id"
3793 WHERE "suggestion"."initiative_id" = "supporter"."initiative_id"
3794 AND "opinion"."member_id" ISNULL
3795 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
3796 AND "ignored_member"."member_id" ISNULL
3798 );
3800 COMMENT ON VIEW "updated_initiative" IS 'Helper view for view "updated_or_featured_initiative"';
3803 CREATE FUNCTION "featured_initiative"
3804 ( "recipient_id_p" "member"."id"%TYPE,
3805 "area_id_p" "area"."id"%TYPE )
3806 RETURNS SETOF "initiative"."id"%TYPE
3807 LANGUAGE 'plpgsql' STABLE AS $$
3808 DECLARE
3809 "counter_v" "member"."notification_counter"%TYPE;
3810 "sample_size_v" "member"."notification_sample_size"%TYPE;
3811 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
3812 "match_v" BOOLEAN;
3813 "member_id_v" "member"."id"%TYPE;
3814 "seed_v" TEXT;
3815 "initiative_id_v" "initiative"."id"%TYPE;
3816 BEGIN
3817 SELECT "notification_counter", "notification_sample_size"
3818 INTO "counter_v", "sample_size_v"
3819 FROM "member" WHERE "id" = "recipient_id_p";
3820 IF COALESCE("sample_size_v" <= 0, TRUE) THEN
3821 RETURN;
3822 END IF;
3823 "initiative_id_ary" := '{}';
3824 LOOP
3825 "match_v" := FALSE;
3826 FOR "member_id_v", "seed_v" IN
3827 SELECT * FROM (
3828 SELECT DISTINCT
3829 "supporter"."member_id",
3830 md5(
3831 "recipient_id_p" || '-' ||
3832 "counter_v" || '-' ||
3833 "area_id_p" || '-' ||
3834 "supporter"."member_id"
3835 ) AS "seed"
3836 FROM "supporter"
3837 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
3838 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3839 WHERE "supporter"."member_id" != "recipient_id_p"
3840 AND "issue"."area_id" = "area_id_p"
3841 AND "issue"."state" IN ('admission', 'discussion', 'verification')
3842 ) AS "subquery"
3843 ORDER BY "seed"
3844 LOOP
3845 SELECT "initiative"."id" INTO "initiative_id_v"
3846 FROM "initiative"
3847 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3848 JOIN "area" ON "area"."id" = "issue"."area_id"
3849 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
3850 LEFT JOIN "supporter" AS "self_support" ON
3851 "self_support"."initiative_id" = "initiative"."id" AND
3852 "self_support"."member_id" = "recipient_id_p"
3853 LEFT JOIN "privilege" ON
3854 "privilege"."member_id" = "recipient_id_p" AND
3855 "privilege"."unit_id" = "area"."unit_id" AND
3856 "privilege"."voting_right" = TRUE
3857 LEFT JOIN "subscription" ON
3858 "subscription"."member_id" = "recipient_id_p" AND
3859 "subscription"."unit_id" = "area"."unit_id"
3860 LEFT JOIN "ignored_initiative" ON
3861 "ignored_initiative"."member_id" = "recipient_id_p" AND
3862 "ignored_initiative"."initiative_id" = "initiative"."id"
3863 WHERE "supporter"."member_id" = "member_id_v"
3864 AND "issue"."area_id" = "area_id_p"
3865 AND "issue"."state" IN ('admission', 'discussion', 'verification')
3866 AND "initiative"."revoked" ISNULL
3867 AND "self_support"."member_id" ISNULL
3868 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
3869 AND (
3870 "privilege"."member_id" NOTNULL OR
3871 "subscription"."member_id" NOTNULL )
3872 AND "ignored_initiative"."member_id" ISNULL
3873 AND NOT EXISTS (
3874 SELECT NULL FROM "draft"
3875 JOIN "ignored_member" ON
3876 "ignored_member"."member_id" = "recipient_id_p" AND
3877 "ignored_member"."other_member_id" = "draft"."author_id"
3878 WHERE "draft"."initiative_id" = "initiative"."id"
3880 ORDER BY md5("seed_v" || '-' || "initiative"."id")
3881 LIMIT 1;
3882 IF FOUND THEN
3883 "match_v" := TRUE;
3884 RETURN NEXT "initiative_id_v";
3885 IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
3886 RETURN;
3887 END IF;
3888 "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
3889 END IF;
3890 END LOOP;
3891 EXIT WHEN NOT "match_v";
3892 END LOOP;
3893 RETURN;
3894 END;
3895 $$;
3897 COMMENT ON FUNCTION "featured_initiative"
3898 ( "recipient_id_p" "member"."id"%TYPE,
3899 "area_id_p" "area"."id"%TYPE )
3900 IS 'Helper function for view "updated_or_featured_initiative"';
3903 CREATE VIEW "updated_or_featured_initiative" AS
3904 SELECT
3905 "subquery".*,
3906 NOT EXISTS (
3907 SELECT NULL FROM "initiative" AS "better_initiative"
3908 WHERE "better_initiative"."issue_id" = "initiative"."issue_id"
3909 AND
3910 ( COALESCE("better_initiative"."supporter_count", -1),
3911 -"better_initiative"."id" ) >
3912 ( COALESCE("initiative"."supporter_count", -1),
3913 -"initiative"."id" )
3914 ) AS "leading"
3915 FROM (
3916 SELECT * FROM "updated_initiative"
3917 UNION ALL
3918 SELECT
3919 "member"."id" AS "recipient_id",
3920 TRUE AS "featured",
3921 "featured_initiative_id" AS "initiative_id"
3922 FROM "member" CROSS JOIN "area"
3923 CROSS JOIN LATERAL
3924 "featured_initiative"("member"."id", "area"."id") AS "featured_initiative_id"
3925 JOIN "initiative" ON "initiative"."id" = "featured_initiative_id"
3926 ) AS "subquery"
3927 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id";
3929 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';
3931 COMMENT ON COLUMN "updated_or_featured_initiative"."recipient_id" IS '"id" of the member who receives the notification mail';
3932 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")';
3933 COMMENT ON COLUMN "updated_or_featured_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
3934 COMMENT ON COLUMN "updated_or_featured_initiative"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
3937 CREATE VIEW "leading_complement_initiative" AS
3938 SELECT * FROM (
3939 SELECT DISTINCT ON ("uf_initiative"."recipient_id", "initiative"."issue_id")
3940 "uf_initiative"."recipient_id",
3941 FALSE AS "featured",
3942 "uf_initiative"."initiative_id",
3943 TRUE AS "leading"
3944 FROM "updated_or_featured_initiative" AS "uf_initiative"
3945 JOIN "initiative" AS "uf_initiative_full" ON
3946 "uf_initiative_full"."id" = "uf_initiative"."initiative_id"
3947 JOIN "initiative" ON
3948 "initiative"."issue_id" = "uf_initiative_full"."issue_id"
3949 WHERE "initiative"."revoked" ISNULL
3950 ORDER BY
3951 "uf_initiative"."recipient_id",
3952 "initiative"."issue_id",
3953 "initiative"."supporter_count" DESC,
3954 "initiative"."id"
3955 ) AS "subquery"
3956 WHERE NOT EXISTS (
3957 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
3958 WHERE "other"."recipient_id" = "subquery"."recipient_id"
3959 AND "other"."initiative_id" = "subquery"."initiative_id"
3960 );
3962 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';
3963 COMMENT ON COLUMN "leading_complement_initiative"."featured" IS 'Always FALSE in this view';
3964 COMMENT ON COLUMN "leading_complement_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
3965 COMMENT ON COLUMN "leading_complement_initiative"."leading" IS 'Always TRUE in this view';
3968 CREATE VIEW "unfiltered_initiative_for_notification" AS
3969 SELECT
3970 "subquery".*,
3971 "supporter"."member_id" NOTNULL AS "supported",
3972 CASE WHEN "supporter"."member_id" NOTNULL THEN
3973 EXISTS (
3974 SELECT NULL FROM "draft"
3975 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
3976 AND "draft"."id" > "supporter"."draft_id"
3978 ELSE
3979 EXISTS (
3980 SELECT NULL FROM "draft"
3981 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
3982 AND COALESCE("draft"."id" > "sent"."last_draft_id", TRUE)
3984 END AS "new_draft",
3985 CASE WHEN "supporter"."member_id" NOTNULL THEN
3986 ( SELECT count(1) FROM "suggestion"
3987 LEFT JOIN "opinion" ON
3988 "opinion"."member_id" = "supporter"."member_id" AND
3989 "opinion"."suggestion_id" = "suggestion"."id"
3990 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
3991 AND "opinion"."member_id" ISNULL
3992 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
3994 ELSE
3995 ( SELECT count(1) FROM "suggestion"
3996 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
3997 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
3999 END AS "new_suggestion_count"
4000 FROM (
4001 SELECT * FROM "updated_or_featured_initiative"
4002 UNION ALL
4003 SELECT * FROM "leading_complement_initiative"
4004 ) AS "subquery"
4005 LEFT JOIN "supporter" ON
4006 "supporter"."member_id" = "subquery"."recipient_id" AND
4007 "supporter"."initiative_id" = "subquery"."initiative_id"
4008 LEFT JOIN "notification_initiative_sent" AS "sent" ON
4009 "sent"."member_id" = "subquery"."recipient_id" AND
4010 "sent"."initiative_id" = "subquery"."initiative_id";
4012 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';
4014 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4015 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)';
4016 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")';
4019 CREATE VIEW "initiative_for_notification" AS
4020 SELECT "unfiltered1".*
4021 FROM "unfiltered_initiative_for_notification" "unfiltered1"
4022 JOIN "initiative" AS "initiative1" ON
4023 "initiative1"."id" = "unfiltered1"."initiative_id"
4024 JOIN "issue" AS "issue1" ON "issue1"."id" = "initiative1"."issue_id"
4025 WHERE EXISTS (
4026 SELECT NULL
4027 FROM "unfiltered_initiative_for_notification" "unfiltered2"
4028 JOIN "initiative" AS "initiative2" ON
4029 "initiative2"."id" = "unfiltered2"."initiative_id"
4030 JOIN "issue" AS "issue2" ON "issue2"."id" = "initiative2"."issue_id"
4031 WHERE "unfiltered1"."recipient_id" = "unfiltered2"."recipient_id"
4032 AND "issue1"."area_id" = "issue2"."area_id"
4033 AND ("unfiltered2"."new_draft" OR "unfiltered2"."new_suggestion_count" > 0 )
4034 );
4036 COMMENT ON VIEW "initiative_for_notification" IS 'Initiatives to be included in a scheduled notification mail';
4038 COMMENT ON COLUMN "initiative_for_notification"."recipient_id" IS '"id" of the member who receives the notification mail';
4039 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")';
4040 COMMENT ON COLUMN "initiative_for_notification"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4041 COMMENT ON COLUMN "initiative_for_notification"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
4042 COMMENT ON COLUMN "initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4043 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)';
4044 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")';
4047 CREATE VIEW "scheduled_notification_to_send" AS
4048 SELECT * FROM (
4049 SELECT
4050 "id" AS "recipient_id",
4051 now() - CASE WHEN "notification_dow" ISNULL THEN
4052 ( "notification_sent"::DATE + CASE
4053 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4054 THEN 0 ELSE 1 END
4055 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4056 ELSE
4057 ( "notification_sent"::DATE +
4058 ( 7 + "notification_dow" -
4059 EXTRACT(DOW FROM
4060 ( "notification_sent"::DATE + CASE
4061 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4062 THEN 0 ELSE 1 END
4063 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4064 )::INTEGER
4065 ) % 7 +
4066 CASE
4067 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4068 THEN 0 ELSE 1
4069 END
4070 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4071 END AS "pending"
4072 FROM (
4073 SELECT
4074 "id",
4075 COALESCE("notification_sent", "activated") AS "notification_sent",
4076 "notification_dow",
4077 "notification_hour"
4078 FROM "member_to_notify"
4079 WHERE "notification_hour" NOTNULL
4080 ) AS "subquery1"
4081 ) AS "subquery2"
4082 WHERE "pending" > '0'::INTERVAL;
4084 COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending';
4086 COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail';
4087 COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending';
4090 CREATE VIEW "newsletter_to_send" AS
4091 SELECT
4092 "member"."id" AS "recipient_id",
4093 "newsletter"."id" AS "newsletter_id",
4094 "newsletter"."published"
4095 FROM "newsletter" CROSS JOIN "member_eligible_to_be_notified" AS "member"
4096 LEFT JOIN "privilege" ON
4097 "privilege"."member_id" = "member"."id" AND
4098 "privilege"."unit_id" = "newsletter"."unit_id" AND
4099 "privilege"."voting_right" = TRUE
4100 LEFT JOIN "subscription" ON
4101 "subscription"."member_id" = "member"."id" AND
4102 "subscription"."unit_id" = "newsletter"."unit_id"
4103 WHERE "newsletter"."published" <= now()
4104 AND "newsletter"."sent" ISNULL
4105 AND (
4106 "member"."disable_notifications" = FALSE OR
4107 "newsletter"."include_all_members" = TRUE )
4108 AND (
4109 "newsletter"."unit_id" ISNULL OR
4110 "privilege"."member_id" NOTNULL OR
4111 "subscription"."member_id" NOTNULL );
4113 COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out';
4115 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter was supposed to be sent out (can be used for ordering)';
4119 ------------------------------------------------------
4120 -- Row set returning function for delegation chains --
4121 ------------------------------------------------------
4124 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
4125 ('first', 'intermediate', 'last', 'repetition');
4127 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
4130 CREATE TYPE "delegation_chain_row" AS (
4131 "index" INT4,
4132 "member_id" INT4,
4133 "member_valid" BOOLEAN,
4134 "participation" BOOLEAN,
4135 "overridden" BOOLEAN,
4136 "scope_in" "delegation_scope",
4137 "scope_out" "delegation_scope",
4138 "disabled_out" BOOLEAN,
4139 "loop" "delegation_chain_loop_tag" );
4141 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
4143 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
4144 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest; for area and global delegation chains: always null';
4145 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
4146 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
4147 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
4148 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
4149 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
4152 CREATE FUNCTION "delegation_chain_for_closed_issue"
4153 ( "member_id_p" "member"."id"%TYPE,
4154 "issue_id_p" "issue"."id"%TYPE )
4155 RETURNS SETOF "delegation_chain_row"
4156 LANGUAGE 'plpgsql' STABLE AS $$
4157 DECLARE
4158 "output_row" "delegation_chain_row";
4159 "direct_voter_row" "direct_voter"%ROWTYPE;
4160 "delegating_voter_row" "delegating_voter"%ROWTYPE;
4161 BEGIN
4162 "output_row"."index" := 0;
4163 "output_row"."member_id" := "member_id_p";
4164 "output_row"."member_valid" := TRUE;
4165 "output_row"."participation" := FALSE;
4166 "output_row"."overridden" := FALSE;
4167 "output_row"."disabled_out" := FALSE;
4168 LOOP
4169 SELECT INTO "direct_voter_row" * FROM "direct_voter"
4170 WHERE "issue_id" = "issue_id_p"
4171 AND "member_id" = "output_row"."member_id";
4172 IF "direct_voter_row"."member_id" NOTNULL THEN
4173 "output_row"."participation" := TRUE;
4174 "output_row"."scope_out" := NULL;
4175 "output_row"."disabled_out" := NULL;
4176 RETURN NEXT "output_row";
4177 RETURN;
4178 END IF;
4179 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
4180 WHERE "issue_id" = "issue_id_p"
4181 AND "member_id" = "output_row"."member_id";
4182 IF "delegating_voter_row"."member_id" ISNULL THEN
4183 RETURN;
4184 END IF;
4185 "output_row"."scope_out" := "delegating_voter_row"."scope";
4186 RETURN NEXT "output_row";
4187 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
4188 "output_row"."scope_in" := "output_row"."scope_out";
4189 END LOOP;
4190 END;
4191 $$;
4193 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
4194 ( "member"."id"%TYPE,
4195 "member"."id"%TYPE )
4196 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
4199 CREATE FUNCTION "delegation_chain"
4200 ( "member_id_p" "member"."id"%TYPE,
4201 "unit_id_p" "unit"."id"%TYPE,
4202 "area_id_p" "area"."id"%TYPE,
4203 "issue_id_p" "issue"."id"%TYPE,
4204 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4205 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4206 RETURNS SETOF "delegation_chain_row"
4207 LANGUAGE 'plpgsql' STABLE AS $$
4208 DECLARE
4209 "scope_v" "delegation_scope";
4210 "unit_id_v" "unit"."id"%TYPE;
4211 "area_id_v" "area"."id"%TYPE;
4212 "issue_row" "issue"%ROWTYPE;
4213 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
4214 "loop_member_id_v" "member"."id"%TYPE;
4215 "output_row" "delegation_chain_row";
4216 "output_rows" "delegation_chain_row"[];
4217 "simulate_v" BOOLEAN;
4218 "simulate_here_v" BOOLEAN;
4219 "delegation_row" "delegation"%ROWTYPE;
4220 "row_count" INT4;
4221 "i" INT4;
4222 "loop_v" BOOLEAN;
4223 BEGIN
4224 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
4225 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
4226 END IF;
4227 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
4228 "simulate_v" := TRUE;
4229 ELSE
4230 "simulate_v" := FALSE;
4231 END IF;
4232 IF
4233 "unit_id_p" NOTNULL AND
4234 "area_id_p" ISNULL AND
4235 "issue_id_p" ISNULL
4236 THEN
4237 "scope_v" := 'unit';
4238 "unit_id_v" := "unit_id_p";
4239 ELSIF
4240 "unit_id_p" ISNULL AND
4241 "area_id_p" NOTNULL AND
4242 "issue_id_p" ISNULL
4243 THEN
4244 "scope_v" := 'area';
4245 "area_id_v" := "area_id_p";
4246 SELECT "unit_id" INTO "unit_id_v"
4247 FROM "area" WHERE "id" = "area_id_v";
4248 ELSIF
4249 "unit_id_p" ISNULL AND
4250 "area_id_p" ISNULL AND
4251 "issue_id_p" NOTNULL
4252 THEN
4253 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
4254 IF "issue_row"."id" ISNULL THEN
4255 RETURN;
4256 END IF;
4257 IF "issue_row"."closed" NOTNULL THEN
4258 IF "simulate_v" THEN
4259 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
4260 END IF;
4261 FOR "output_row" IN
4262 SELECT * FROM
4263 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
4264 LOOP
4265 RETURN NEXT "output_row";
4266 END LOOP;
4267 RETURN;
4268 END IF;
4269 "scope_v" := 'issue';
4270 SELECT "area_id" INTO "area_id_v"
4271 FROM "issue" WHERE "id" = "issue_id_p";
4272 SELECT "unit_id" INTO "unit_id_v"
4273 FROM "area" WHERE "id" = "area_id_v";
4274 ELSE
4275 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
4276 END IF;
4277 "visited_member_ids" := '{}';
4278 "loop_member_id_v" := NULL;
4279 "output_rows" := '{}';
4280 "output_row"."index" := 0;
4281 "output_row"."member_id" := "member_id_p";
4282 "output_row"."member_valid" := TRUE;
4283 "output_row"."participation" := FALSE;
4284 "output_row"."overridden" := FALSE;
4285 "output_row"."disabled_out" := FALSE;
4286 "output_row"."scope_out" := NULL;
4287 LOOP
4288 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
4289 "loop_member_id_v" := "output_row"."member_id";
4290 ELSE
4291 "visited_member_ids" :=
4292 "visited_member_ids" || "output_row"."member_id";
4293 END IF;
4294 IF "output_row"."participation" ISNULL THEN
4295 "output_row"."overridden" := NULL;
4296 ELSIF "output_row"."participation" THEN
4297 "output_row"."overridden" := TRUE;
4298 END IF;
4299 "output_row"."scope_in" := "output_row"."scope_out";
4300 "output_row"."member_valid" := EXISTS (
4301 SELECT NULL FROM "member" JOIN "privilege"
4302 ON "privilege"."member_id" = "member"."id"
4303 AND "privilege"."unit_id" = "unit_id_v"
4304 WHERE "id" = "output_row"."member_id"
4305 AND "member"."active" AND "privilege"."voting_right"
4306 );
4307 "simulate_here_v" := (
4308 "simulate_v" AND
4309 "output_row"."member_id" = "member_id_p"
4310 );
4311 "delegation_row" := ROW(NULL);
4312 IF "output_row"."member_valid" OR "simulate_here_v" THEN
4313 IF "scope_v" = 'unit' THEN
4314 IF NOT "simulate_here_v" THEN
4315 SELECT * INTO "delegation_row" FROM "delegation"
4316 WHERE "truster_id" = "output_row"."member_id"
4317 AND "unit_id" = "unit_id_v";
4318 END IF;
4319 ELSIF "scope_v" = 'area' THEN
4320 IF "simulate_here_v" THEN
4321 IF "simulate_trustee_id_p" ISNULL THEN
4322 SELECT * INTO "delegation_row" FROM "delegation"
4323 WHERE "truster_id" = "output_row"."member_id"
4324 AND "unit_id" = "unit_id_v";
4325 END IF;
4326 ELSE
4327 SELECT * INTO "delegation_row" FROM "delegation"
4328 WHERE "truster_id" = "output_row"."member_id"
4329 AND (
4330 "unit_id" = "unit_id_v" OR
4331 "area_id" = "area_id_v"
4333 ORDER BY "scope" DESC;
4334 END IF;
4335 ELSIF "scope_v" = 'issue' THEN
4336 IF "issue_row"."fully_frozen" ISNULL THEN
4337 "output_row"."participation" := EXISTS (
4338 SELECT NULL FROM "interest"
4339 WHERE "issue_id" = "issue_id_p"
4340 AND "member_id" = "output_row"."member_id"
4341 );
4342 ELSE
4343 IF "output_row"."member_id" = "member_id_p" THEN
4344 "output_row"."participation" := EXISTS (
4345 SELECT NULL FROM "direct_voter"
4346 WHERE "issue_id" = "issue_id_p"
4347 AND "member_id" = "output_row"."member_id"
4348 );
4349 ELSE
4350 "output_row"."participation" := NULL;
4351 END IF;
4352 END IF;
4353 IF "simulate_here_v" THEN
4354 IF "simulate_trustee_id_p" ISNULL THEN
4355 SELECT * INTO "delegation_row" FROM "delegation"
4356 WHERE "truster_id" = "output_row"."member_id"
4357 AND (
4358 "unit_id" = "unit_id_v" OR
4359 "area_id" = "area_id_v"
4361 ORDER BY "scope" DESC;
4362 END IF;
4363 ELSE
4364 SELECT * INTO "delegation_row" FROM "delegation"
4365 WHERE "truster_id" = "output_row"."member_id"
4366 AND (
4367 "unit_id" = "unit_id_v" OR
4368 "area_id" = "area_id_v" OR
4369 "issue_id" = "issue_id_p"
4371 ORDER BY "scope" DESC;
4372 END IF;
4373 END IF;
4374 ELSE
4375 "output_row"."participation" := FALSE;
4376 END IF;
4377 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
4378 "output_row"."scope_out" := "scope_v";
4379 "output_rows" := "output_rows" || "output_row";
4380 "output_row"."member_id" := "simulate_trustee_id_p";
4381 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
4382 "output_row"."scope_out" := "delegation_row"."scope";
4383 "output_rows" := "output_rows" || "output_row";
4384 "output_row"."member_id" := "delegation_row"."trustee_id";
4385 ELSIF "delegation_row"."scope" NOTNULL THEN
4386 "output_row"."scope_out" := "delegation_row"."scope";
4387 "output_row"."disabled_out" := TRUE;
4388 "output_rows" := "output_rows" || "output_row";
4389 EXIT;
4390 ELSE
4391 "output_row"."scope_out" := NULL;
4392 "output_rows" := "output_rows" || "output_row";
4393 EXIT;
4394 END IF;
4395 EXIT WHEN "loop_member_id_v" NOTNULL;
4396 "output_row"."index" := "output_row"."index" + 1;
4397 END LOOP;
4398 "row_count" := array_upper("output_rows", 1);
4399 "i" := 1;
4400 "loop_v" := FALSE;
4401 LOOP
4402 "output_row" := "output_rows"["i"];
4403 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
4404 IF "loop_v" THEN
4405 IF "i" + 1 = "row_count" THEN
4406 "output_row"."loop" := 'last';
4407 ELSIF "i" = "row_count" THEN
4408 "output_row"."loop" := 'repetition';
4409 ELSE
4410 "output_row"."loop" := 'intermediate';
4411 END IF;
4412 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
4413 "output_row"."loop" := 'first';
4414 "loop_v" := TRUE;
4415 END IF;
4416 IF "scope_v" = 'unit' THEN
4417 "output_row"."participation" := NULL;
4418 END IF;
4419 RETURN NEXT "output_row";
4420 "i" := "i" + 1;
4421 END LOOP;
4422 RETURN;
4423 END;
4424 $$;
4426 COMMENT ON FUNCTION "delegation_chain"
4427 ( "member"."id"%TYPE,
4428 "unit"."id"%TYPE,
4429 "area"."id"%TYPE,
4430 "issue"."id"%TYPE,
4431 "member"."id"%TYPE,
4432 BOOLEAN )
4433 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
4437 ---------------------------------------------------------
4438 -- Single row returning function for delegation chains --
4439 ---------------------------------------------------------
4442 CREATE TYPE "delegation_info_loop_type" AS ENUM
4443 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
4445 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''';
4448 CREATE TYPE "delegation_info_type" AS (
4449 "own_participation" BOOLEAN,
4450 "own_delegation_scope" "delegation_scope",
4451 "first_trustee_id" INT4,
4452 "first_trustee_participation" BOOLEAN,
4453 "first_trustee_ellipsis" BOOLEAN,
4454 "other_trustee_id" INT4,
4455 "other_trustee_participation" BOOLEAN,
4456 "other_trustee_ellipsis" BOOLEAN,
4457 "delegation_loop" "delegation_info_loop_type",
4458 "participating_member_id" INT4 );
4460 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';
4462 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
4463 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
4464 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
4465 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
4466 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
4467 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
4468 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)';
4469 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
4470 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';
4471 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
4474 CREATE FUNCTION "delegation_info"
4475 ( "member_id_p" "member"."id"%TYPE,
4476 "unit_id_p" "unit"."id"%TYPE,
4477 "area_id_p" "area"."id"%TYPE,
4478 "issue_id_p" "issue"."id"%TYPE,
4479 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4480 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4481 RETURNS "delegation_info_type"
4482 LANGUAGE 'plpgsql' STABLE AS $$
4483 DECLARE
4484 "current_row" "delegation_chain_row";
4485 "result" "delegation_info_type";
4486 BEGIN
4487 "result"."own_participation" := FALSE;
4488 FOR "current_row" IN
4489 SELECT * FROM "delegation_chain"(
4490 "member_id_p",
4491 "unit_id_p", "area_id_p", "issue_id_p",
4492 "simulate_trustee_id_p", "simulate_default_p")
4493 LOOP
4494 IF
4495 "result"."participating_member_id" ISNULL AND
4496 "current_row"."participation"
4497 THEN
4498 "result"."participating_member_id" := "current_row"."member_id";
4499 END IF;
4500 IF "current_row"."member_id" = "member_id_p" THEN
4501 "result"."own_participation" := "current_row"."participation";
4502 "result"."own_delegation_scope" := "current_row"."scope_out";
4503 IF "current_row"."loop" = 'first' THEN
4504 "result"."delegation_loop" := 'own';
4505 END IF;
4506 ELSIF
4507 "current_row"."member_valid" AND
4508 ( "current_row"."loop" ISNULL OR
4509 "current_row"."loop" != 'repetition' )
4510 THEN
4511 IF "result"."first_trustee_id" ISNULL THEN
4512 "result"."first_trustee_id" := "current_row"."member_id";
4513 "result"."first_trustee_participation" := "current_row"."participation";
4514 "result"."first_trustee_ellipsis" := FALSE;
4515 IF "current_row"."loop" = 'first' THEN
4516 "result"."delegation_loop" := 'first';
4517 END IF;
4518 ELSIF "result"."other_trustee_id" ISNULL THEN
4519 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
4520 "result"."other_trustee_id" := "current_row"."member_id";
4521 "result"."other_trustee_participation" := TRUE;
4522 "result"."other_trustee_ellipsis" := FALSE;
4523 IF "current_row"."loop" = 'first' THEN
4524 "result"."delegation_loop" := 'other';
4525 END IF;
4526 ELSE
4527 "result"."first_trustee_ellipsis" := TRUE;
4528 IF "current_row"."loop" = 'first' THEN
4529 "result"."delegation_loop" := 'first_ellipsis';
4530 END IF;
4531 END IF;
4532 ELSE
4533 "result"."other_trustee_ellipsis" := TRUE;
4534 IF "current_row"."loop" = 'first' THEN
4535 "result"."delegation_loop" := 'other_ellipsis';
4536 END IF;
4537 END IF;
4538 END IF;
4539 END LOOP;
4540 RETURN "result";
4541 END;
4542 $$;
4544 COMMENT ON FUNCTION "delegation_info"
4545 ( "member"."id"%TYPE,
4546 "unit"."id"%TYPE,
4547 "area"."id"%TYPE,
4548 "issue"."id"%TYPE,
4549 "member"."id"%TYPE,
4550 BOOLEAN )
4551 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
4555 ---------------------------
4556 -- Transaction isolation --
4557 ---------------------------
4560 CREATE FUNCTION "require_transaction_isolation"()
4561 RETURNS VOID
4562 LANGUAGE 'plpgsql' VOLATILE AS $$
4563 BEGIN
4564 IF
4565 current_setting('transaction_isolation') NOT IN
4566 ('repeatable read', 'serializable')
4567 THEN
4568 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
4569 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
4570 END IF;
4571 RETURN;
4572 END;
4573 $$;
4575 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
4578 CREATE FUNCTION "dont_require_transaction_isolation"()
4579 RETURNS VOID
4580 LANGUAGE 'plpgsql' VOLATILE AS $$
4581 BEGIN
4582 IF
4583 current_setting('transaction_isolation') IN
4584 ('repeatable read', 'serializable')
4585 THEN
4586 RAISE WARNING 'Unneccessary transaction isolation level: %',
4587 current_setting('transaction_isolation');
4588 END IF;
4589 RETURN;
4590 END;
4591 $$;
4593 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
4597 -------------------------
4598 -- Notification system --
4599 -------------------------
4601 CREATE FUNCTION "get_initiatives_for_notification"
4602 ( "recipient_id_p" "member"."id"%TYPE )
4603 RETURNS SETOF "initiative_for_notification"
4604 LANGUAGE 'plpgsql' VOLATILE AS $$
4605 DECLARE
4606 "result_row" "initiative_for_notification"%ROWTYPE;
4607 "last_draft_id_v" "draft"."id"%TYPE;
4608 "last_suggestion_id_v" "suggestion"."id"%TYPE;
4609 BEGIN
4610 PERFORM "require_transaction_isolation"();
4611 PERFORM NULL FROM "member" WHERE "id" = "recipient_id_p" FOR UPDATE;
4612 FOR "result_row" IN
4613 SELECT * FROM "initiative_for_notification"
4614 WHERE "recipient_id" = "recipient_id_p"
4615 LOOP
4616 SELECT "id" INTO "last_draft_id_v" FROM "draft"
4617 WHERE "draft"."initiative_id" = "result_row"."initiative_id"
4618 ORDER BY "id" DESC LIMIT 1;
4619 SELECT "id" INTO "last_suggestion_id_v" FROM "suggestion"
4620 WHERE "suggestion"."initiative_id" = "result_row"."initiative_id"
4621 ORDER BY "id" DESC LIMIT 1;
4622 INSERT INTO "notification_initiative_sent"
4623 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
4624 VALUES (
4625 "recipient_id_p",
4626 "result_row"."initiative_id",
4627 "last_draft_id_v",
4628 "last_suggestion_id_v" )
4629 ON CONFLICT ("member_id", "initiative_id") DO UPDATE SET
4630 "last_draft_id" = "last_draft_id_v",
4631 "last_suggestion_id" = "last_suggestion_id_v";
4632 RETURN NEXT "result_row";
4633 END LOOP;
4634 DELETE FROM "notification_initiative_sent"
4635 USING "initiative", "issue"
4636 WHERE "notification_initiative_sent"."member_id" = "recipient_id_p"
4637 AND "initiative"."id" = "notification_initiative_sent"."initiative_id"
4638 AND "issue"."id" = "initiative"."issue_id"
4639 AND ( "issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL );
4640 UPDATE "member" SET
4641 "notification_counter" = "notification_counter" + 1,
4642 "notification_sent" = now()
4643 WHERE "id" = "recipient_id_p";
4644 RETURN;
4645 END;
4646 $$;
4648 COMMENT ON FUNCTION "get_initiatives_for_notification"
4649 ( "member"."id"%TYPE )
4650 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';
4654 ------------------------------------------------------------------------
4655 -- Regular tasks, except calculcation of snapshots and voting results --
4656 ------------------------------------------------------------------------
4659 CREATE FUNCTION "check_activity"()
4660 RETURNS VOID
4661 LANGUAGE 'plpgsql' VOLATILE AS $$
4662 DECLARE
4663 "system_setting_row" "system_setting"%ROWTYPE;
4664 BEGIN
4665 PERFORM "dont_require_transaction_isolation"();
4666 SELECT * INTO "system_setting_row" FROM "system_setting";
4667 IF "system_setting_row"."member_ttl" NOTNULL THEN
4668 UPDATE "member" SET "active" = FALSE
4669 WHERE "active" = TRUE
4670 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
4671 END IF;
4672 RETURN;
4673 END;
4674 $$;
4676 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
4679 CREATE FUNCTION "calculate_member_counts"()
4680 RETURNS VOID
4681 LANGUAGE 'plpgsql' VOLATILE AS $$
4682 BEGIN
4683 PERFORM "require_transaction_isolation"();
4684 DELETE FROM "member_count";
4685 INSERT INTO "member_count" ("total_count")
4686 SELECT "total_count" FROM "member_count_view";
4687 UPDATE "unit" SET "member_count" = "view"."member_count"
4688 FROM "unit_member_count" AS "view"
4689 WHERE "view"."unit_id" = "unit"."id";
4690 RETURN;
4691 END;
4692 $$;
4694 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"';
4698 ------------------------------------
4699 -- Calculation of harmonic weight --
4700 ------------------------------------
4703 CREATE VIEW "remaining_harmonic_supporter_weight" AS
4704 SELECT
4705 "direct_interest_snapshot"."snapshot_id",
4706 "direct_interest_snapshot"."issue_id",
4707 "direct_interest_snapshot"."member_id",
4708 "direct_interest_snapshot"."weight" AS "weight_num",
4709 count("initiative"."id") AS "weight_den"
4710 FROM "issue"
4711 JOIN "direct_interest_snapshot"
4712 ON "issue"."latest_snapshot_id" = "direct_interest_snapshot"."snapshot_id"
4713 AND "issue"."id" = "direct_interest_snapshot"."issue_id"
4714 JOIN "initiative"
4715 ON "issue"."id" = "initiative"."issue_id"
4716 AND "initiative"."harmonic_weight" ISNULL
4717 JOIN "direct_supporter_snapshot"
4718 ON "issue"."latest_snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
4719 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
4720 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
4721 AND (
4722 "direct_supporter_snapshot"."satisfied" = TRUE OR
4723 coalesce("initiative"."admitted", FALSE) = FALSE
4725 GROUP BY
4726 "direct_interest_snapshot"."snapshot_id",
4727 "direct_interest_snapshot"."issue_id",
4728 "direct_interest_snapshot"."member_id",
4729 "direct_interest_snapshot"."weight";
4731 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
4734 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
4735 SELECT
4736 "initiative"."issue_id",
4737 "initiative"."id" AS "initiative_id",
4738 "initiative"."admitted",
4739 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
4740 "remaining_harmonic_supporter_weight"."weight_den"
4741 FROM "remaining_harmonic_supporter_weight"
4742 JOIN "initiative"
4743 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
4744 AND "initiative"."harmonic_weight" ISNULL
4745 JOIN "direct_supporter_snapshot"
4746 ON "remaining_harmonic_supporter_weight"."snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
4747 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
4748 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
4749 AND (
4750 "direct_supporter_snapshot"."satisfied" = TRUE OR
4751 coalesce("initiative"."admitted", FALSE) = FALSE
4753 GROUP BY
4754 "initiative"."issue_id",
4755 "initiative"."id",
4756 "initiative"."admitted",
4757 "remaining_harmonic_supporter_weight"."weight_den";
4759 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
4762 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
4763 SELECT
4764 "issue_id",
4765 "id" AS "initiative_id",
4766 "admitted",
4767 0 AS "weight_num",
4768 1 AS "weight_den"
4769 FROM "initiative"
4770 WHERE "harmonic_weight" ISNULL;
4772 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';
4775 CREATE FUNCTION "set_harmonic_initiative_weights"
4776 ( "issue_id_p" "issue"."id"%TYPE )
4777 RETURNS VOID
4778 LANGUAGE 'plpgsql' VOLATILE AS $$
4779 DECLARE
4780 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
4781 "i" INT4;
4782 "count_v" INT4;
4783 "summand_v" FLOAT;
4784 "id_ary" INT4[];
4785 "weight_ary" FLOAT[];
4786 "min_weight_v" FLOAT;
4787 BEGIN
4788 PERFORM "require_transaction_isolation"();
4789 UPDATE "initiative" SET "harmonic_weight" = NULL
4790 WHERE "issue_id" = "issue_id_p";
4791 LOOP
4792 "min_weight_v" := NULL;
4793 "i" := 0;
4794 "count_v" := 0;
4795 FOR "weight_row" IN
4796 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
4797 WHERE "issue_id" = "issue_id_p"
4798 AND (
4799 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
4800 SELECT NULL FROM "initiative"
4801 WHERE "issue_id" = "issue_id_p"
4802 AND "harmonic_weight" ISNULL
4803 AND coalesce("admitted", FALSE) = FALSE
4806 UNION ALL -- needed for corner cases
4807 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
4808 WHERE "issue_id" = "issue_id_p"
4809 AND (
4810 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
4811 SELECT NULL FROM "initiative"
4812 WHERE "issue_id" = "issue_id_p"
4813 AND "harmonic_weight" ISNULL
4814 AND coalesce("admitted", FALSE) = FALSE
4817 ORDER BY "initiative_id" DESC, "weight_den" DESC
4818 -- NOTE: non-admitted initiatives placed first (at last positions),
4819 -- latest initiatives treated worse in case of tie
4820 LOOP
4821 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
4822 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
4823 "i" := "i" + 1;
4824 "count_v" := "i";
4825 "id_ary"["i"] := "weight_row"."initiative_id";
4826 "weight_ary"["i"] := "summand_v";
4827 ELSE
4828 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
4829 END IF;
4830 END LOOP;
4831 EXIT WHEN "count_v" = 0;
4832 "i" := 1;
4833 LOOP
4834 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
4835 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
4836 "min_weight_v" := "weight_ary"["i"];
4837 END IF;
4838 "i" := "i" + 1;
4839 EXIT WHEN "i" > "count_v";
4840 END LOOP;
4841 "i" := 1;
4842 LOOP
4843 IF "weight_ary"["i"] = "min_weight_v" THEN
4844 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
4845 WHERE "id" = "id_ary"["i"];
4846 EXIT;
4847 END IF;
4848 "i" := "i" + 1;
4849 END LOOP;
4850 END LOOP;
4851 UPDATE "initiative" SET "harmonic_weight" = 0
4852 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
4853 END;
4854 $$;
4856 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
4857 ( "issue"."id"%TYPE )
4858 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
4862 ------------------------------
4863 -- Calculation of snapshots --
4864 ------------------------------
4867 CREATE FUNCTION "weight_of_added_delegations_for_snapshot"
4868 ( "snapshot_id_p" "snapshot"."id"%TYPE,
4869 "issue_id_p" "issue"."id"%TYPE,
4870 "member_id_p" "member"."id"%TYPE,
4871 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
4872 RETURNS "direct_interest_snapshot"."weight"%TYPE
4873 LANGUAGE 'plpgsql' VOLATILE AS $$
4874 DECLARE
4875 "issue_delegation_row" "issue_delegation"%ROWTYPE;
4876 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
4877 "weight_v" INT4;
4878 "sub_weight_v" INT4;
4879 BEGIN
4880 PERFORM "require_transaction_isolation"();
4881 "weight_v" := 0;
4882 FOR "issue_delegation_row" IN
4883 SELECT * FROM "issue_delegation"
4884 WHERE "trustee_id" = "member_id_p"
4885 AND "issue_id" = "issue_id_p"
4886 LOOP
4887 IF NOT EXISTS (
4888 SELECT NULL FROM "direct_interest_snapshot"
4889 WHERE "snapshot_id" = "snapshot_id_p"
4890 AND "issue_id" = "issue_id_p"
4891 AND "member_id" = "issue_delegation_row"."truster_id"
4892 ) AND NOT EXISTS (
4893 SELECT NULL FROM "delegating_interest_snapshot"
4894 WHERE "snapshot_id" = "snapshot_id_p"
4895 AND "issue_id" = "issue_id_p"
4896 AND "member_id" = "issue_delegation_row"."truster_id"
4897 ) THEN
4898 "delegate_member_ids_v" :=
4899 "member_id_p" || "delegate_member_ids_p";
4900 INSERT INTO "delegating_interest_snapshot" (
4901 "snapshot_id",
4902 "issue_id",
4903 "member_id",
4904 "scope",
4905 "delegate_member_ids"
4906 ) VALUES (
4907 "snapshot_id_p",
4908 "issue_id_p",
4909 "issue_delegation_row"."truster_id",
4910 "issue_delegation_row"."scope",
4911 "delegate_member_ids_v"
4912 );
4913 "sub_weight_v" := 1 +
4914 "weight_of_added_delegations_for_snapshot"(
4915 "snapshot_id_p",
4916 "issue_id_p",
4917 "issue_delegation_row"."truster_id",
4918 "delegate_member_ids_v"
4919 );
4920 UPDATE "delegating_interest_snapshot"
4921 SET "weight" = "sub_weight_v"
4922 WHERE "snapshot_id" = "snapshot_id_p"
4923 AND "issue_id" = "issue_id_p"
4924 AND "member_id" = "issue_delegation_row"."truster_id";
4925 "weight_v" := "weight_v" + "sub_weight_v";
4926 END IF;
4927 END LOOP;
4928 RETURN "weight_v";
4929 END;
4930 $$;
4932 COMMENT ON FUNCTION "weight_of_added_delegations_for_snapshot"
4933 ( "snapshot"."id"%TYPE,
4934 "issue"."id"%TYPE,
4935 "member"."id"%TYPE,
4936 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
4937 IS 'Helper function for "fill_snapshot" function';
4940 CREATE FUNCTION "take_snapshot"
4941 ( "issue_id_p" "issue"."id"%TYPE,
4942 "area_id_p" "area"."id"%TYPE = NULL )
4943 RETURNS "snapshot"."id"%TYPE
4944 LANGUAGE 'plpgsql' VOLATILE AS $$
4945 DECLARE
4946 "area_id_v" "area"."id"%TYPE;
4947 "unit_id_v" "unit"."id"%TYPE;
4948 "snapshot_id_v" "snapshot"."id"%TYPE;
4949 "issue_id_v" "issue"."id"%TYPE;
4950 "member_id_v" "member"."id"%TYPE;
4951 BEGIN
4952 IF "issue_id_p" NOTNULL AND "area_id_p" NOTNULL THEN
4953 RAISE EXCEPTION 'One of "issue_id_p" and "area_id_p" must be NULL';
4954 END IF;
4955 PERFORM "require_transaction_isolation"();
4956 IF "issue_id_p" ISNULL THEN
4957 "area_id_v" := "area_id_p";
4958 ELSE
4959 SELECT "area_id" INTO "area_id_v"
4960 FROM "issue" WHERE "id" = "issue_id_p";
4961 END IF;
4962 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
4963 INSERT INTO "snapshot" ("area_id", "issue_id")
4964 VALUES ("area_id_v", "issue_id_p")
4965 RETURNING "id" INTO "snapshot_id_v";
4966 INSERT INTO "snapshot_population" ("snapshot_id", "member_id")
4967 SELECT "snapshot_id_v", "member_id"
4968 FROM "unit_member" WHERE "unit_id" = "unit_id_v";
4969 UPDATE "snapshot" SET
4970 "population" = (
4971 SELECT count(1) FROM "snapshot_population"
4972 WHERE "snapshot_id" = "snapshot_id_v"
4973 ) WHERE "id" = "snapshot_id_v";
4974 FOR "issue_id_v" IN
4975 SELECT "id" FROM "issue"
4976 WHERE CASE WHEN "issue_id_p" ISNULL THEN
4977 "area_id" = "area_id_p" AND
4978 "state" = 'admission'
4979 ELSE
4980 "id" = "issue_id_p"
4981 END
4982 LOOP
4983 INSERT INTO "snapshot_issue" ("snapshot_id", "issue_id")
4984 VALUES ("snapshot_id_v", "issue_id_v");
4985 INSERT INTO "direct_interest_snapshot"
4986 ("snapshot_id", "issue_id", "member_id")
4987 SELECT
4988 "snapshot_id_v" AS "snapshot_id",
4989 "issue_id_v" AS "issue_id",
4990 "member"."id" AS "member_id"
4991 FROM "issue"
4992 JOIN "area" ON "issue"."area_id" = "area"."id"
4993 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
4994 JOIN "member" ON "interest"."member_id" = "member"."id"
4995 JOIN "privilege"
4996 ON "privilege"."unit_id" = "area"."unit_id"
4997 AND "privilege"."member_id" = "member"."id"
4998 WHERE "issue"."id" = "issue_id_v"
4999 AND "member"."active" AND "privilege"."voting_right";
5000 FOR "member_id_v" IN
5001 SELECT "member_id" FROM "direct_interest_snapshot"
5002 WHERE "snapshot_id" = "snapshot_id_v"
5003 AND "issue_id" = "issue_id_v"
5004 LOOP
5005 UPDATE "direct_interest_snapshot" SET
5006 "weight" = 1 +
5007 "weight_of_added_delegations_for_snapshot"(
5008 "snapshot_id_v",
5009 "issue_id_v",
5010 "member_id_v",
5011 '{}'
5013 WHERE "snapshot_id" = "snapshot_id_v"
5014 AND "issue_id" = "issue_id_v"
5015 AND "member_id" = "member_id_v";
5016 END LOOP;
5017 INSERT INTO "direct_supporter_snapshot"
5018 ( "snapshot_id", "issue_id", "initiative_id", "member_id",
5019 "draft_id", "informed", "satisfied" )
5020 SELECT
5021 "snapshot_id_v" AS "snapshot_id",
5022 "issue_id_v" AS "issue_id",
5023 "initiative"."id" AS "initiative_id",
5024 "supporter"."member_id" AS "member_id",
5025 "supporter"."draft_id" AS "draft_id",
5026 "supporter"."draft_id" = "current_draft"."id" AS "informed",
5027 NOT EXISTS (
5028 SELECT NULL FROM "critical_opinion"
5029 WHERE "initiative_id" = "initiative"."id"
5030 AND "member_id" = "supporter"."member_id"
5031 ) AS "satisfied"
5032 FROM "initiative"
5033 JOIN "supporter"
5034 ON "supporter"."initiative_id" = "initiative"."id"
5035 JOIN "current_draft"
5036 ON "initiative"."id" = "current_draft"."initiative_id"
5037 JOIN "direct_interest_snapshot"
5038 ON "snapshot_id_v" = "direct_interest_snapshot"."snapshot_id"
5039 AND "supporter"."member_id" = "direct_interest_snapshot"."member_id"
5040 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
5041 WHERE "initiative"."issue_id" = "issue_id_v";
5042 DELETE FROM "temporary_suggestion_counts";
5043 INSERT INTO "temporary_suggestion_counts"
5044 ( "id",
5045 "minus2_unfulfilled_count", "minus2_fulfilled_count",
5046 "minus1_unfulfilled_count", "minus1_fulfilled_count",
5047 "plus1_unfulfilled_count", "plus1_fulfilled_count",
5048 "plus2_unfulfilled_count", "plus2_fulfilled_count" )
5049 SELECT
5050 "suggestion"."id",
5051 ( SELECT coalesce(sum("di"."weight"), 0)
5052 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5053 ON "di"."snapshot_id" = "snapshot_id_v"
5054 AND "di"."issue_id" = "issue_id_v"
5055 AND "di"."member_id" = "opinion"."member_id"
5056 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5057 AND "opinion"."degree" = -2
5058 AND "opinion"."fulfilled" = FALSE
5059 ) AS "minus2_unfulfilled_count",
5060 ( SELECT coalesce(sum("di"."weight"), 0)
5061 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5062 ON "di"."snapshot_id" = "snapshot_id_v"
5063 AND "di"."issue_id" = "issue_id_v"
5064 AND "di"."member_id" = "opinion"."member_id"
5065 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5066 AND "opinion"."degree" = -2
5067 AND "opinion"."fulfilled" = TRUE
5068 ) AS "minus2_fulfilled_count",
5069 ( SELECT coalesce(sum("di"."weight"), 0)
5070 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5071 ON "di"."snapshot_id" = "snapshot_id_v"
5072 AND "di"."issue_id" = "issue_id_v"
5073 AND "di"."member_id" = "opinion"."member_id"
5074 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5075 AND "opinion"."degree" = -1
5076 AND "opinion"."fulfilled" = FALSE
5077 ) AS "minus1_unfulfilled_count",
5078 ( SELECT coalesce(sum("di"."weight"), 0)
5079 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5080 ON "di"."snapshot_id" = "snapshot_id_v"
5081 AND "di"."issue_id" = "issue_id_v"
5082 AND "di"."member_id" = "opinion"."member_id"
5083 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5084 AND "opinion"."degree" = -1
5085 AND "opinion"."fulfilled" = TRUE
5086 ) AS "minus1_fulfilled_count",
5087 ( SELECT coalesce(sum("di"."weight"), 0)
5088 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5089 ON "di"."snapshot_id" = "snapshot_id_v"
5090 AND "di"."issue_id" = "issue_id_v"
5091 AND "di"."member_id" = "opinion"."member_id"
5092 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5093 AND "opinion"."degree" = 1
5094 AND "opinion"."fulfilled" = FALSE
5095 ) AS "plus1_unfulfilled_count",
5096 ( SELECT coalesce(sum("di"."weight"), 0)
5097 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5098 ON "di"."snapshot_id" = "snapshot_id_v"
5099 AND "di"."issue_id" = "issue_id_v"
5100 AND "di"."member_id" = "opinion"."member_id"
5101 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5102 AND "opinion"."degree" = 1
5103 AND "opinion"."fulfilled" = TRUE
5104 ) AS "plus1_fulfilled_count",
5105 ( SELECT coalesce(sum("di"."weight"), 0)
5106 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5107 ON "di"."snapshot_id" = "snapshot_id_v"
5108 AND "di"."issue_id" = "issue_id_v"
5109 AND "di"."member_id" = "opinion"."member_id"
5110 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5111 AND "opinion"."degree" = 2
5112 AND "opinion"."fulfilled" = FALSE
5113 ) AS "plus2_unfulfilled_count",
5114 ( SELECT coalesce(sum("di"."weight"), 0)
5115 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5116 ON "di"."snapshot_id" = "snapshot_id_v"
5117 AND "di"."issue_id" = "issue_id_v"
5118 AND "di"."member_id" = "opinion"."member_id"
5119 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5120 AND "opinion"."degree" = 2
5121 AND "opinion"."fulfilled" = TRUE
5122 ) AS "plus2_fulfilled_count"
5123 FROM "suggestion" JOIN "initiative"
5124 ON "suggestion"."initiative_id" = "initiative"."id"
5125 WHERE "initiative"."issue_id" = "issue_id_v";
5126 END LOOP;
5127 RETURN "snapshot_id_v";
5128 END;
5129 $$;
5131 COMMENT ON FUNCTION "take_snapshot"
5132 ( "issue"."id"%TYPE,
5133 "area"."id"%TYPE )
5134 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.';
5137 CREATE FUNCTION "finish_snapshot"
5138 ( "issue_id_p" "issue"."id"%TYPE )
5139 RETURNS VOID
5140 LANGUAGE 'plpgsql' VOLATILE AS $$
5141 DECLARE
5142 "snapshot_id_v" "snapshot"."id"%TYPE;
5143 BEGIN
5144 -- NOTE: function does not require snapshot isolation but we don't call
5145 -- "dont_require_snapshot_isolation" here because this function is
5146 -- also invoked by "check_issue"
5147 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
5148 SELECT "id" INTO "snapshot_id_v" FROM "snapshot"
5149 ORDER BY "id" DESC LIMIT 1;
5150 UPDATE "issue" SET
5151 "calculated" = "snapshot"."calculated",
5152 "latest_snapshot_id" = "snapshot_id_v",
5153 "population" = "snapshot"."population",
5154 "initiative_quorum" = CASE WHEN
5155 "policy"."initiative_quorum" > ceil(
5156 ( "issue"."population"::INT8 *
5157 "policy"."initiative_quorum_num"::INT8 ) /
5158 "policy"."initiative_quorum_den"::FLOAT8
5159 )::INT4
5160 THEN
5161 "policy"."initiative_quorum"
5162 ELSE
5163 ceil(
5164 ( "issue"."population"::INT8 *
5165 "policy"."initiative_quorum_num"::INT8 ) /
5166 "policy"."initiative_quorum_den"::FLOAT8
5167 )::INT4
5168 END
5169 FROM "snapshot", "policy"
5170 WHERE "issue"."id" = "issue_id_p"
5171 AND "snapshot"."id" = "snapshot_id_v"
5172 AND "policy"."id" = "issue"."policy_id";
5173 UPDATE "initiative" SET
5174 "supporter_count" = (
5175 SELECT coalesce(sum("di"."weight"), 0)
5176 FROM "direct_interest_snapshot" AS "di"
5177 JOIN "direct_supporter_snapshot" AS "ds"
5178 ON "di"."member_id" = "ds"."member_id"
5179 WHERE "di"."snapshot_id" = "snapshot_id_v"
5180 AND "di"."issue_id" = "issue_id_p"
5181 AND "ds"."snapshot_id" = "snapshot_id_v"
5182 AND "ds"."initiative_id" = "initiative"."id"
5183 ),
5184 "informed_supporter_count" = (
5185 SELECT coalesce(sum("di"."weight"), 0)
5186 FROM "direct_interest_snapshot" AS "di"
5187 JOIN "direct_supporter_snapshot" AS "ds"
5188 ON "di"."member_id" = "ds"."member_id"
5189 WHERE "di"."snapshot_id" = "snapshot_id_v"
5190 AND "di"."issue_id" = "issue_id_p"
5191 AND "ds"."snapshot_id" = "snapshot_id_v"
5192 AND "ds"."initiative_id" = "initiative"."id"
5193 AND "ds"."informed"
5194 ),
5195 "satisfied_supporter_count" = (
5196 SELECT coalesce(sum("di"."weight"), 0)
5197 FROM "direct_interest_snapshot" AS "di"
5198 JOIN "direct_supporter_snapshot" AS "ds"
5199 ON "di"."member_id" = "ds"."member_id"
5200 WHERE "di"."snapshot_id" = "snapshot_id_v"
5201 AND "di"."issue_id" = "issue_id_p"
5202 AND "ds"."snapshot_id" = "snapshot_id_v"
5203 AND "ds"."initiative_id" = "initiative"."id"
5204 AND "ds"."satisfied"
5205 ),
5206 "satisfied_informed_supporter_count" = (
5207 SELECT coalesce(sum("di"."weight"), 0)
5208 FROM "direct_interest_snapshot" AS "di"
5209 JOIN "direct_supporter_snapshot" AS "ds"
5210 ON "di"."member_id" = "ds"."member_id"
5211 WHERE "di"."snapshot_id" = "snapshot_id_v"
5212 AND "di"."issue_id" = "issue_id_p"
5213 AND "ds"."snapshot_id" = "snapshot_id_v"
5214 AND "ds"."initiative_id" = "initiative"."id"
5215 AND "ds"."informed"
5216 AND "ds"."satisfied"
5218 WHERE "issue_id" = "issue_id_p";
5219 UPDATE "suggestion" SET
5220 "minus2_unfulfilled_count" = "temp"."minus2_unfulfilled_count",
5221 "minus2_fulfilled_count" = "temp"."minus2_fulfilled_count",
5222 "minus1_unfulfilled_count" = "temp"."minus1_unfulfilled_count",
5223 "minus1_fulfilled_count" = "temp"."minus1_fulfilled_count",
5224 "plus1_unfulfilled_count" = "temp"."plus1_unfulfilled_count",
5225 "plus1_fulfilled_count" = "temp"."plus1_fulfilled_count",
5226 "plus2_unfulfilled_count" = "temp"."plus2_unfulfilled_count",
5227 "plus2_fulfilled_count" = "temp"."plus2_fulfilled_count"
5228 FROM "temporary_suggestion_counts" AS "temp", "initiative"
5229 WHERE "temp"."id" = "suggestion"."id"
5230 AND "initiative"."issue_id" = "issue_id_p"
5231 AND "suggestion"."initiative_id" = "initiative"."id";
5232 DELETE FROM "temporary_suggestion_counts";
5233 RETURN;
5234 END;
5235 $$;
5237 COMMENT ON FUNCTION "finish_snapshot"
5238 ( "issue"."id"%TYPE )
5239 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)';
5243 -----------------------
5244 -- Counting of votes --
5245 -----------------------
5248 CREATE FUNCTION "weight_of_added_vote_delegations"
5249 ( "issue_id_p" "issue"."id"%TYPE,
5250 "member_id_p" "member"."id"%TYPE,
5251 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
5252 RETURNS "direct_voter"."weight"%TYPE
5253 LANGUAGE 'plpgsql' VOLATILE AS $$
5254 DECLARE
5255 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5256 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
5257 "weight_v" INT4;
5258 "sub_weight_v" INT4;
5259 BEGIN
5260 PERFORM "require_transaction_isolation"();
5261 "weight_v" := 0;
5262 FOR "issue_delegation_row" IN
5263 SELECT * FROM "issue_delegation"
5264 WHERE "trustee_id" = "member_id_p"
5265 AND "issue_id" = "issue_id_p"
5266 LOOP
5267 IF NOT EXISTS (
5268 SELECT NULL FROM "direct_voter"
5269 WHERE "member_id" = "issue_delegation_row"."truster_id"
5270 AND "issue_id" = "issue_id_p"
5271 ) AND NOT EXISTS (
5272 SELECT NULL FROM "delegating_voter"
5273 WHERE "member_id" = "issue_delegation_row"."truster_id"
5274 AND "issue_id" = "issue_id_p"
5275 ) THEN
5276 "delegate_member_ids_v" :=
5277 "member_id_p" || "delegate_member_ids_p";
5278 INSERT INTO "delegating_voter" (
5279 "issue_id",
5280 "member_id",
5281 "scope",
5282 "delegate_member_ids"
5283 ) VALUES (
5284 "issue_id_p",
5285 "issue_delegation_row"."truster_id",
5286 "issue_delegation_row"."scope",
5287 "delegate_member_ids_v"
5288 );
5289 "sub_weight_v" := 1 +
5290 "weight_of_added_vote_delegations"(
5291 "issue_id_p",
5292 "issue_delegation_row"."truster_id",
5293 "delegate_member_ids_v"
5294 );
5295 UPDATE "delegating_voter"
5296 SET "weight" = "sub_weight_v"
5297 WHERE "issue_id" = "issue_id_p"
5298 AND "member_id" = "issue_delegation_row"."truster_id";
5299 "weight_v" := "weight_v" + "sub_weight_v";
5300 END IF;
5301 END LOOP;
5302 RETURN "weight_v";
5303 END;
5304 $$;
5306 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
5307 ( "issue"."id"%TYPE,
5308 "member"."id"%TYPE,
5309 "delegating_voter"."delegate_member_ids"%TYPE )
5310 IS 'Helper function for "add_vote_delegations" function';
5313 CREATE FUNCTION "add_vote_delegations"
5314 ( "issue_id_p" "issue"."id"%TYPE )
5315 RETURNS VOID
5316 LANGUAGE 'plpgsql' VOLATILE AS $$
5317 DECLARE
5318 "member_id_v" "member"."id"%TYPE;
5319 BEGIN
5320 PERFORM "require_transaction_isolation"();
5321 FOR "member_id_v" IN
5322 SELECT "member_id" FROM "direct_voter"
5323 WHERE "issue_id" = "issue_id_p"
5324 LOOP
5325 UPDATE "direct_voter" SET
5326 "weight" = "weight" + "weight_of_added_vote_delegations"(
5327 "issue_id_p",
5328 "member_id_v",
5329 '{}'
5331 WHERE "member_id" = "member_id_v"
5332 AND "issue_id" = "issue_id_p";
5333 END LOOP;
5334 RETURN;
5335 END;
5336 $$;
5338 COMMENT ON FUNCTION "add_vote_delegations"
5339 ( "issue_id_p" "issue"."id"%TYPE )
5340 IS 'Helper function for "close_voting" function';
5343 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
5344 RETURNS VOID
5345 LANGUAGE 'plpgsql' VOLATILE AS $$
5346 DECLARE
5347 "area_id_v" "area"."id"%TYPE;
5348 "unit_id_v" "unit"."id"%TYPE;
5349 "member_id_v" "member"."id"%TYPE;
5350 BEGIN
5351 PERFORM "require_transaction_isolation"();
5352 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
5353 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5354 -- override protection triggers:
5355 INSERT INTO "temporary_transaction_data" ("key", "value")
5356 VALUES ('override_protection_triggers', TRUE::TEXT);
5357 -- delete timestamp of voting comment:
5358 UPDATE "direct_voter" SET "comment_changed" = NULL
5359 WHERE "issue_id" = "issue_id_p";
5360 -- delete delegating votes (in cases of manual reset of issue state):
5361 DELETE FROM "delegating_voter"
5362 WHERE "issue_id" = "issue_id_p";
5363 -- delete votes from non-privileged voters:
5364 DELETE FROM "direct_voter"
5365 USING (
5366 SELECT
5367 "direct_voter"."member_id"
5368 FROM "direct_voter"
5369 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
5370 LEFT JOIN "privilege"
5371 ON "privilege"."unit_id" = "unit_id_v"
5372 AND "privilege"."member_id" = "direct_voter"."member_id"
5373 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
5374 "member"."active" = FALSE OR
5375 "privilege"."voting_right" ISNULL OR
5376 "privilege"."voting_right" = FALSE
5378 ) AS "subquery"
5379 WHERE "direct_voter"."issue_id" = "issue_id_p"
5380 AND "direct_voter"."member_id" = "subquery"."member_id";
5381 -- consider delegations:
5382 UPDATE "direct_voter" SET "weight" = 1
5383 WHERE "issue_id" = "issue_id_p";
5384 PERFORM "add_vote_delegations"("issue_id_p");
5385 -- mark first preferences:
5386 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
5387 FROM (
5388 SELECT
5389 "vote"."initiative_id",
5390 "vote"."member_id",
5391 CASE WHEN "vote"."grade" > 0 THEN
5392 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
5393 ELSE NULL
5394 END AS "first_preference"
5395 FROM "vote"
5396 JOIN "initiative" -- NOTE: due to missing index on issue_id
5397 ON "vote"."issue_id" = "initiative"."issue_id"
5398 JOIN "vote" AS "agg"
5399 ON "initiative"."id" = "agg"."initiative_id"
5400 AND "vote"."member_id" = "agg"."member_id"
5401 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
5402 ) AS "subquery"
5403 WHERE "vote"."issue_id" = "issue_id_p"
5404 AND "vote"."initiative_id" = "subquery"."initiative_id"
5405 AND "vote"."member_id" = "subquery"."member_id";
5406 -- finish overriding protection triggers (avoids garbage):
5407 DELETE FROM "temporary_transaction_data"
5408 WHERE "key" = 'override_protection_triggers';
5409 -- materialize battle_view:
5410 -- NOTE: "closed" column of issue must be set at this point
5411 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
5412 INSERT INTO "battle" (
5413 "issue_id",
5414 "winning_initiative_id", "losing_initiative_id",
5415 "count"
5416 ) SELECT
5417 "issue_id",
5418 "winning_initiative_id", "losing_initiative_id",
5419 "count"
5420 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
5421 -- set voter count:
5422 UPDATE "issue" SET
5423 "voter_count" = (
5424 SELECT coalesce(sum("weight"), 0)
5425 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
5427 WHERE "id" = "issue_id_p";
5428 -- copy "positive_votes" and "negative_votes" from "battle" table:
5429 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
5430 UPDATE "initiative" SET
5431 "first_preference_votes" = 0,
5432 "positive_votes" = "battle_win"."count",
5433 "negative_votes" = "battle_lose"."count"
5434 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
5435 WHERE
5436 "battle_win"."issue_id" = "issue_id_p" AND
5437 "battle_win"."winning_initiative_id" = "initiative"."id" AND
5438 "battle_win"."losing_initiative_id" ISNULL AND
5439 "battle_lose"."issue_id" = "issue_id_p" AND
5440 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
5441 "battle_lose"."winning_initiative_id" ISNULL;
5442 -- calculate "first_preference_votes":
5443 -- NOTE: will only set values not equal to zero
5444 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
5445 FROM (
5446 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
5447 FROM "vote" JOIN "direct_voter"
5448 ON "vote"."issue_id" = "direct_voter"."issue_id"
5449 AND "vote"."member_id" = "direct_voter"."member_id"
5450 WHERE "vote"."first_preference"
5451 GROUP BY "vote"."initiative_id"
5452 ) AS "subquery"
5453 WHERE "initiative"."issue_id" = "issue_id_p"
5454 AND "initiative"."admitted"
5455 AND "initiative"."id" = "subquery"."initiative_id";
5456 END;
5457 $$;
5459 COMMENT ON FUNCTION "close_voting"
5460 ( "issue"."id"%TYPE )
5461 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.';
5464 CREATE FUNCTION "defeat_strength"
5465 ( "positive_votes_p" INT4,
5466 "negative_votes_p" INT4,
5467 "defeat_strength_p" "defeat_strength" )
5468 RETURNS INT8
5469 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5470 BEGIN
5471 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
5472 IF "positive_votes_p" > "negative_votes_p" THEN
5473 RETURN "positive_votes_p";
5474 ELSE
5475 RETURN 0;
5476 END IF;
5477 ELSE
5478 IF "positive_votes_p" > "negative_votes_p" THEN
5479 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
5480 ELSIF "positive_votes_p" = "negative_votes_p" THEN
5481 RETURN 0;
5482 ELSE
5483 RETURN -1;
5484 END IF;
5485 END IF;
5486 END;
5487 $$;
5489 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")';
5492 CREATE FUNCTION "secondary_link_strength"
5493 ( "initiative1_ord_p" INT4,
5494 "initiative2_ord_p" INT4,
5495 "tie_breaking_p" "tie_breaking" )
5496 RETURNS INT8
5497 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5498 BEGIN
5499 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
5500 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
5501 END IF;
5502 RETURN (
5503 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
5505 ELSE
5506 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
5507 1::INT8 << 62
5508 ELSE 0 END
5510 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
5511 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
5512 ELSE
5513 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
5514 END
5515 END
5516 );
5517 END;
5518 $$;
5520 COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4, "tie_breaking") IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)';
5523 CREATE TYPE "link_strength" AS (
5524 "primary" INT8,
5525 "secondary" INT8 );
5527 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'')';
5530 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
5531 RETURNS "link_strength"[][]
5532 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5533 DECLARE
5534 "dimension_v" INT4;
5535 "matrix_p" "link_strength"[][];
5536 "i" INT4;
5537 "j" INT4;
5538 "k" INT4;
5539 BEGIN
5540 "dimension_v" := array_upper("matrix_d", 1);
5541 "matrix_p" := "matrix_d";
5542 "i" := 1;
5543 LOOP
5544 "j" := 1;
5545 LOOP
5546 IF "i" != "j" THEN
5547 "k" := 1;
5548 LOOP
5549 IF "i" != "k" AND "j" != "k" THEN
5550 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
5551 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
5552 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
5553 END IF;
5554 ELSE
5555 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
5556 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
5557 END IF;
5558 END IF;
5559 END IF;
5560 EXIT WHEN "k" = "dimension_v";
5561 "k" := "k" + 1;
5562 END LOOP;
5563 END IF;
5564 EXIT WHEN "j" = "dimension_v";
5565 "j" := "j" + 1;
5566 END LOOP;
5567 EXIT WHEN "i" = "dimension_v";
5568 "i" := "i" + 1;
5569 END LOOP;
5570 RETURN "matrix_p";
5571 END;
5572 $$;
5574 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
5577 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
5578 RETURNS VOID
5579 LANGUAGE 'plpgsql' VOLATILE AS $$
5580 DECLARE
5581 "issue_row" "issue"%ROWTYPE;
5582 "policy_row" "policy"%ROWTYPE;
5583 "dimension_v" INT4;
5584 "matrix_a" INT4[][]; -- absolute votes
5585 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
5586 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
5587 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
5588 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
5589 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
5590 "i" INT4;
5591 "j" INT4;
5592 "m" INT4;
5593 "n" INT4;
5594 "battle_row" "battle"%ROWTYPE;
5595 "rank_ary" INT4[];
5596 "rank_v" INT4;
5597 "initiative_id_v" "initiative"."id"%TYPE;
5598 BEGIN
5599 PERFORM "require_transaction_isolation"();
5600 SELECT * INTO "issue_row"
5601 FROM "issue" WHERE "id" = "issue_id_p";
5602 SELECT * INTO "policy_row"
5603 FROM "policy" WHERE "id" = "issue_row"."policy_id";
5604 SELECT count(1) INTO "dimension_v"
5605 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
5606 -- create "matrix_a" with absolute number of votes in pairwise
5607 -- comparison:
5608 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
5609 "i" := 1;
5610 "j" := 2;
5611 FOR "battle_row" IN
5612 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
5613 ORDER BY
5614 "winning_initiative_id" NULLS FIRST,
5615 "losing_initiative_id" NULLS FIRST
5616 LOOP
5617 "matrix_a"["i"]["j"] := "battle_row"."count";
5618 IF "j" = "dimension_v" THEN
5619 "i" := "i" + 1;
5620 "j" := 1;
5621 ELSE
5622 "j" := "j" + 1;
5623 IF "j" = "i" THEN
5624 "j" := "j" + 1;
5625 END IF;
5626 END IF;
5627 END LOOP;
5628 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
5629 RAISE EXCEPTION 'Wrong battle count (should not happen)';
5630 END IF;
5631 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
5632 -- and "secondary_link_strength" functions:
5633 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
5634 "i" := 1;
5635 LOOP
5636 "j" := 1;
5637 LOOP
5638 IF "i" != "j" THEN
5639 "matrix_d"["i"]["j"] := (
5640 "defeat_strength"(
5641 "matrix_a"["i"]["j"],
5642 "matrix_a"["j"]["i"],
5643 "policy_row"."defeat_strength"
5644 ),
5645 "secondary_link_strength"(
5646 "i",
5647 "j",
5648 "policy_row"."tie_breaking"
5650 )::"link_strength";
5651 END IF;
5652 EXIT WHEN "j" = "dimension_v";
5653 "j" := "j" + 1;
5654 END LOOP;
5655 EXIT WHEN "i" = "dimension_v";
5656 "i" := "i" + 1;
5657 END LOOP;
5658 -- find best paths:
5659 "matrix_p" := "find_best_paths"("matrix_d");
5660 -- create partial order:
5661 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
5662 "i" := 1;
5663 LOOP
5664 "j" := "i" + 1;
5665 LOOP
5666 IF "i" != "j" THEN
5667 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
5668 "matrix_b"["i"]["j"] := TRUE;
5669 "matrix_b"["j"]["i"] := FALSE;
5670 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
5671 "matrix_b"["i"]["j"] := FALSE;
5672 "matrix_b"["j"]["i"] := TRUE;
5673 END IF;
5674 END IF;
5675 EXIT WHEN "j" = "dimension_v";
5676 "j" := "j" + 1;
5677 END LOOP;
5678 EXIT WHEN "i" = "dimension_v" - 1;
5679 "i" := "i" + 1;
5680 END LOOP;
5681 -- tie-breaking by forbidding shared weakest links in beat-paths
5682 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
5683 -- is performed later by initiative id):
5684 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
5685 "m" := 1;
5686 LOOP
5687 "n" := "m" + 1;
5688 LOOP
5689 -- only process those candidates m and n, which are tied:
5690 IF "matrix_b"["m"]["n"] ISNULL THEN
5691 -- start with beat-paths prior tie-breaking:
5692 "matrix_t" := "matrix_p";
5693 -- start with all links allowed:
5694 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
5695 LOOP
5696 -- determine (and forbid) that link that is the weakest link
5697 -- in both the best path from candidate m to candidate n and
5698 -- from candidate n to candidate m:
5699 "i" := 1;
5700 <<forbid_one_link>>
5701 LOOP
5702 "j" := 1;
5703 LOOP
5704 IF "i" != "j" THEN
5705 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
5706 "matrix_f"["i"]["j"] := TRUE;
5707 -- exit for performance reasons,
5708 -- as exactly one link will be found:
5709 EXIT forbid_one_link;
5710 END IF;
5711 END IF;
5712 EXIT WHEN "j" = "dimension_v";
5713 "j" := "j" + 1;
5714 END LOOP;
5715 IF "i" = "dimension_v" THEN
5716 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
5717 END IF;
5718 "i" := "i" + 1;
5719 END LOOP;
5720 -- calculate best beat-paths while ignoring forbidden links:
5721 "i" := 1;
5722 LOOP
5723 "j" := 1;
5724 LOOP
5725 IF "i" != "j" THEN
5726 "matrix_t"["i"]["j"] := CASE
5727 WHEN "matrix_f"["i"]["j"]
5728 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
5729 ELSE "matrix_d"["i"]["j"] END;
5730 END IF;
5731 EXIT WHEN "j" = "dimension_v";
5732 "j" := "j" + 1;
5733 END LOOP;
5734 EXIT WHEN "i" = "dimension_v";
5735 "i" := "i" + 1;
5736 END LOOP;
5737 "matrix_t" := "find_best_paths"("matrix_t");
5738 -- extend partial order, if tie-breaking was successful:
5739 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
5740 "matrix_b"["m"]["n"] := TRUE;
5741 "matrix_b"["n"]["m"] := FALSE;
5742 EXIT;
5743 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
5744 "matrix_b"["m"]["n"] := FALSE;
5745 "matrix_b"["n"]["m"] := TRUE;
5746 EXIT;
5747 END IF;
5748 END LOOP;
5749 END IF;
5750 EXIT WHEN "n" = "dimension_v";
5751 "n" := "n" + 1;
5752 END LOOP;
5753 EXIT WHEN "m" = "dimension_v" - 1;
5754 "m" := "m" + 1;
5755 END LOOP;
5756 END IF;
5757 -- store a unique ranking in "rank_ary":
5758 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
5759 "rank_v" := 1;
5760 LOOP
5761 "i" := 1;
5762 <<assign_next_rank>>
5763 LOOP
5764 IF "rank_ary"["i"] ISNULL THEN
5765 "j" := 1;
5766 LOOP
5767 IF
5768 "i" != "j" AND
5769 "rank_ary"["j"] ISNULL AND
5770 ( "matrix_b"["j"]["i"] OR
5771 -- tie-breaking by "id"
5772 ( "matrix_b"["j"]["i"] ISNULL AND
5773 "j" < "i" ) )
5774 THEN
5775 -- someone else is better
5776 EXIT;
5777 END IF;
5778 IF "j" = "dimension_v" THEN
5779 -- noone is better
5780 "rank_ary"["i"] := "rank_v";
5781 EXIT assign_next_rank;
5782 END IF;
5783 "j" := "j" + 1;
5784 END LOOP;
5785 END IF;
5786 "i" := "i" + 1;
5787 IF "i" > "dimension_v" THEN
5788 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
5789 END IF;
5790 END LOOP;
5791 EXIT WHEN "rank_v" = "dimension_v";
5792 "rank_v" := "rank_v" + 1;
5793 END LOOP;
5794 -- write preliminary results:
5795 "i" := 2; -- omit status quo with "i" = 1
5796 FOR "initiative_id_v" IN
5797 SELECT "id" FROM "initiative"
5798 WHERE "issue_id" = "issue_id_p" AND "admitted"
5799 ORDER BY "id"
5800 LOOP
5801 UPDATE "initiative" SET
5802 "direct_majority" =
5803 CASE WHEN "policy_row"."direct_majority_strict" THEN
5804 "positive_votes" * "policy_row"."direct_majority_den" >
5805 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
5806 ELSE
5807 "positive_votes" * "policy_row"."direct_majority_den" >=
5808 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
5809 END
5810 AND "positive_votes" >= "policy_row"."direct_majority_positive"
5811 AND "issue_row"."voter_count"-"negative_votes" >=
5812 "policy_row"."direct_majority_non_negative",
5813 "indirect_majority" =
5814 CASE WHEN "policy_row"."indirect_majority_strict" THEN
5815 "positive_votes" * "policy_row"."indirect_majority_den" >
5816 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
5817 ELSE
5818 "positive_votes" * "policy_row"."indirect_majority_den" >=
5819 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
5820 END
5821 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
5822 AND "issue_row"."voter_count"-"negative_votes" >=
5823 "policy_row"."indirect_majority_non_negative",
5824 "schulze_rank" = "rank_ary"["i"],
5825 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
5826 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
5827 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
5828 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
5829 THEN NULL
5830 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
5831 "eligible" = FALSE,
5832 "winner" = FALSE,
5833 "rank" = NULL -- NOTE: in cases of manual reset of issue state
5834 WHERE "id" = "initiative_id_v";
5835 "i" := "i" + 1;
5836 END LOOP;
5837 IF "i" != "dimension_v" + 1 THEN
5838 RAISE EXCEPTION 'Wrong winner count (should not happen)';
5839 END IF;
5840 -- take indirect majorities into account:
5841 LOOP
5842 UPDATE "initiative" SET "indirect_majority" = TRUE
5843 FROM (
5844 SELECT "new_initiative"."id" AS "initiative_id"
5845 FROM "initiative" "old_initiative"
5846 JOIN "initiative" "new_initiative"
5847 ON "new_initiative"."issue_id" = "issue_id_p"
5848 AND "new_initiative"."indirect_majority" = FALSE
5849 JOIN "battle" "battle_win"
5850 ON "battle_win"."issue_id" = "issue_id_p"
5851 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
5852 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
5853 JOIN "battle" "battle_lose"
5854 ON "battle_lose"."issue_id" = "issue_id_p"
5855 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
5856 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
5857 WHERE "old_initiative"."issue_id" = "issue_id_p"
5858 AND "old_initiative"."indirect_majority" = TRUE
5859 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
5860 "battle_win"."count" * "policy_row"."indirect_majority_den" >
5861 "policy_row"."indirect_majority_num" *
5862 ("battle_win"."count"+"battle_lose"."count")
5863 ELSE
5864 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
5865 "policy_row"."indirect_majority_num" *
5866 ("battle_win"."count"+"battle_lose"."count")
5867 END
5868 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
5869 AND "issue_row"."voter_count"-"battle_lose"."count" >=
5870 "policy_row"."indirect_majority_non_negative"
5871 ) AS "subquery"
5872 WHERE "id" = "subquery"."initiative_id";
5873 EXIT WHEN NOT FOUND;
5874 END LOOP;
5875 -- set "multistage_majority" for remaining matching initiatives:
5876 UPDATE "initiative" SET "multistage_majority" = TRUE
5877 FROM (
5878 SELECT "losing_initiative"."id" AS "initiative_id"
5879 FROM "initiative" "losing_initiative"
5880 JOIN "initiative" "winning_initiative"
5881 ON "winning_initiative"."issue_id" = "issue_id_p"
5882 AND "winning_initiative"."admitted"
5883 JOIN "battle" "battle_win"
5884 ON "battle_win"."issue_id" = "issue_id_p"
5885 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
5886 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
5887 JOIN "battle" "battle_lose"
5888 ON "battle_lose"."issue_id" = "issue_id_p"
5889 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
5890 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
5891 WHERE "losing_initiative"."issue_id" = "issue_id_p"
5892 AND "losing_initiative"."admitted"
5893 AND "winning_initiative"."schulze_rank" <
5894 "losing_initiative"."schulze_rank"
5895 AND "battle_win"."count" > "battle_lose"."count"
5896 AND (
5897 "battle_win"."count" > "winning_initiative"."positive_votes" OR
5898 "battle_lose"."count" < "losing_initiative"."negative_votes" )
5899 ) AS "subquery"
5900 WHERE "id" = "subquery"."initiative_id";
5901 -- mark eligible initiatives:
5902 UPDATE "initiative" SET "eligible" = TRUE
5903 WHERE "issue_id" = "issue_id_p"
5904 AND "initiative"."direct_majority"
5905 AND "initiative"."indirect_majority"
5906 AND "initiative"."better_than_status_quo"
5907 AND (
5908 "policy_row"."no_multistage_majority" = FALSE OR
5909 "initiative"."multistage_majority" = FALSE )
5910 AND (
5911 "policy_row"."no_reverse_beat_path" = FALSE OR
5912 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
5913 -- mark final winner:
5914 UPDATE "initiative" SET "winner" = TRUE
5915 FROM (
5916 SELECT "id" AS "initiative_id"
5917 FROM "initiative"
5918 WHERE "issue_id" = "issue_id_p" AND "eligible"
5919 ORDER BY
5920 "schulze_rank",
5921 "id"
5922 LIMIT 1
5923 ) AS "subquery"
5924 WHERE "id" = "subquery"."initiative_id";
5925 -- write (final) ranks:
5926 "rank_v" := 1;
5927 FOR "initiative_id_v" IN
5928 SELECT "id"
5929 FROM "initiative"
5930 WHERE "issue_id" = "issue_id_p" AND "admitted"
5931 ORDER BY
5932 "winner" DESC,
5933 "eligible" DESC,
5934 "schulze_rank",
5935 "id"
5936 LOOP
5937 UPDATE "initiative" SET "rank" = "rank_v"
5938 WHERE "id" = "initiative_id_v";
5939 "rank_v" := "rank_v" + 1;
5940 END LOOP;
5941 -- set schulze rank of status quo and mark issue as finished:
5942 UPDATE "issue" SET
5943 "status_quo_schulze_rank" = "rank_ary"[1],
5944 "state" =
5945 CASE WHEN EXISTS (
5946 SELECT NULL FROM "initiative"
5947 WHERE "issue_id" = "issue_id_p" AND "winner"
5948 ) THEN
5949 'finished_with_winner'::"issue_state"
5950 ELSE
5951 'finished_without_winner'::"issue_state"
5952 END,
5953 "closed" = "phase_finished",
5954 "phase_finished" = NULL
5955 WHERE "id" = "issue_id_p";
5956 RETURN;
5957 END;
5958 $$;
5960 COMMENT ON FUNCTION "calculate_ranks"
5961 ( "issue"."id"%TYPE )
5962 IS 'Determine ranking (Votes have to be counted first)';
5966 -----------------------------
5967 -- Automatic state changes --
5968 -----------------------------
5971 CREATE FUNCTION "issue_admission"
5972 ( "area_id_p" "area"."id"%TYPE )
5973 RETURNS BOOLEAN
5974 LANGUAGE 'plpgsql' VOLATILE AS $$
5975 DECLARE
5976 "issue_id_v" "issue"."id"%TYPE;
5977 BEGIN
5978 PERFORM "dont_require_transaction_isolation"();
5979 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
5980 UPDATE "area" SET "issue_quorum" = "view"."issue_quorum"
5981 FROM "area_quorum" AS "view"
5982 WHERE "area"."id" = "view"."area_id"
5983 AND "area"."id" = "area_id_p";
5984 SELECT "id" INTO "issue_id_v" FROM "issue_for_admission"
5985 WHERE "area_id" = "area_id_p";
5986 IF "issue_id_v" ISNULL THEN RETURN FALSE; END IF;
5987 UPDATE "issue" SET
5988 "admission_snapshot_id" = "latest_snapshot_id",
5989 "state" = 'discussion',
5990 "accepted" = now(),
5991 "phase_finished" = NULL,
5992 "issue_quorum" = "issue_quorum"."issue_quorum"
5993 FROM "issue_quorum"
5994 WHERE "id" = "issue_id_v"
5995 AND "issue_quorum"."issue_id" = "issue_id_v";
5996 RETURN TRUE;
5997 END;
5998 $$;
6000 COMMENT ON FUNCTION "issue_admission"
6001 ( "area"."id"%TYPE )
6002 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';
6005 CREATE TYPE "check_issue_persistence" AS (
6006 "state" "issue_state",
6007 "phase_finished" BOOLEAN,
6008 "issue_revoked" BOOLEAN,
6009 "snapshot_created" BOOLEAN,
6010 "harmonic_weights_set" BOOLEAN,
6011 "closed_voting" BOOLEAN );
6013 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';
6016 CREATE FUNCTION "check_issue"
6017 ( "issue_id_p" "issue"."id"%TYPE,
6018 "persist" "check_issue_persistence" )
6019 RETURNS "check_issue_persistence"
6020 LANGUAGE 'plpgsql' VOLATILE AS $$
6021 DECLARE
6022 "issue_row" "issue"%ROWTYPE;
6023 "last_calculated_v" "snapshot"."calculated"%TYPE;
6024 "policy_row" "policy"%ROWTYPE;
6025 "initiative_row" "initiative"%ROWTYPE;
6026 "state_v" "issue_state";
6027 BEGIN
6028 PERFORM "require_transaction_isolation"();
6029 IF "persist" ISNULL THEN
6030 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6031 FOR UPDATE;
6032 SELECT "calculated" INTO "last_calculated_v"
6033 FROM "snapshot" JOIN "snapshot_issue"
6034 ON "snapshot"."id" = "snapshot_issue"."snapshot_id"
6035 WHERE "snapshot_issue"."issue_id" = "issue_id_p";
6036 IF "issue_row"."closed" NOTNULL THEN
6037 RETURN NULL;
6038 END IF;
6039 "persist"."state" := "issue_row"."state";
6040 IF
6041 ( "issue_row"."state" = 'admission' AND "last_calculated_v" >=
6042 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
6043 ( "issue_row"."state" = 'discussion' AND now() >=
6044 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
6045 ( "issue_row"."state" = 'verification' AND now() >=
6046 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
6047 ( "issue_row"."state" = 'voting' AND now() >=
6048 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
6049 THEN
6050 "persist"."phase_finished" := TRUE;
6051 ELSE
6052 "persist"."phase_finished" := FALSE;
6053 END IF;
6054 IF
6055 NOT EXISTS (
6056 -- all initiatives are revoked
6057 SELECT NULL FROM "initiative"
6058 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6059 ) AND (
6060 -- and issue has not been accepted yet
6061 "persist"."state" = 'admission' OR
6062 -- or verification time has elapsed
6063 ( "persist"."state" = 'verification' AND
6064 "persist"."phase_finished" ) OR
6065 -- or no initiatives have been revoked lately
6066 NOT EXISTS (
6067 SELECT NULL FROM "initiative"
6068 WHERE "issue_id" = "issue_id_p"
6069 AND now() < "revoked" + "issue_row"."verification_time"
6072 THEN
6073 "persist"."issue_revoked" := TRUE;
6074 ELSE
6075 "persist"."issue_revoked" := FALSE;
6076 END IF;
6077 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
6078 UPDATE "issue" SET "phase_finished" = now()
6079 WHERE "id" = "issue_row"."id";
6080 RETURN "persist";
6081 ELSIF
6082 "persist"."state" IN ('admission', 'discussion', 'verification')
6083 THEN
6084 RETURN "persist";
6085 ELSE
6086 RETURN NULL;
6087 END IF;
6088 END IF;
6089 IF
6090 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6091 coalesce("persist"."snapshot_created", FALSE) = FALSE
6092 THEN
6093 IF "persist"."state" != 'admission' THEN
6094 PERFORM "take_snapshot"("issue_id_p");
6095 PERFORM "finish_snapshot"("issue_id_p");
6096 ELSE
6097 UPDATE "issue" SET "issue_quorum" = "issue_quorum"."issue_quorum"
6098 FROM "issue_quorum"
6099 WHERE "id" = "issue_id_p"
6100 AND "issue_quorum"."issue_id" = "issue_id_p";
6101 END IF;
6102 "persist"."snapshot_created" = TRUE;
6103 IF "persist"."phase_finished" THEN
6104 IF "persist"."state" = 'admission' THEN
6105 UPDATE "issue" SET "admission_snapshot_id" = "latest_snapshot_id"
6106 WHERE "id" = "issue_id_p";
6107 ELSIF "persist"."state" = 'discussion' THEN
6108 UPDATE "issue" SET "half_freeze_snapshot_id" = "latest_snapshot_id"
6109 WHERE "id" = "issue_id_p";
6110 ELSIF "persist"."state" = 'verification' THEN
6111 UPDATE "issue" SET "full_freeze_snapshot_id" = "latest_snapshot_id"
6112 WHERE "id" = "issue_id_p";
6113 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
6114 FOR "initiative_row" IN
6115 SELECT * FROM "initiative"
6116 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6117 FOR UPDATE
6118 LOOP
6119 IF
6120 "initiative_row"."polling" OR
6121 "initiative_row"."satisfied_supporter_count" >=
6122 "issue_row"."initiative_quorum"
6123 THEN
6124 UPDATE "initiative" SET "admitted" = TRUE
6125 WHERE "id" = "initiative_row"."id";
6126 ELSE
6127 UPDATE "initiative" SET "admitted" = FALSE
6128 WHERE "id" = "initiative_row"."id";
6129 END IF;
6130 END LOOP;
6131 END IF;
6132 END IF;
6133 RETURN "persist";
6134 END IF;
6135 IF
6136 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6137 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
6138 THEN
6139 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
6140 "persist"."harmonic_weights_set" = TRUE;
6141 IF
6142 "persist"."phase_finished" OR
6143 "persist"."issue_revoked" OR
6144 "persist"."state" = 'admission'
6145 THEN
6146 RETURN "persist";
6147 ELSE
6148 RETURN NULL;
6149 END IF;
6150 END IF;
6151 IF "persist"."issue_revoked" THEN
6152 IF "persist"."state" = 'admission' THEN
6153 "state_v" := 'canceled_revoked_before_accepted';
6154 ELSIF "persist"."state" = 'discussion' THEN
6155 "state_v" := 'canceled_after_revocation_during_discussion';
6156 ELSIF "persist"."state" = 'verification' THEN
6157 "state_v" := 'canceled_after_revocation_during_verification';
6158 END IF;
6159 UPDATE "issue" SET
6160 "state" = "state_v",
6161 "closed" = "phase_finished",
6162 "phase_finished" = NULL
6163 WHERE "id" = "issue_id_p";
6164 RETURN NULL;
6165 END IF;
6166 IF "persist"."state" = 'admission' THEN
6167 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6168 FOR UPDATE;
6169 IF "issue_row"."phase_finished" NOTNULL THEN
6170 UPDATE "issue" SET
6171 "state" = 'canceled_issue_not_accepted',
6172 "closed" = "phase_finished",
6173 "phase_finished" = NULL
6174 WHERE "id" = "issue_id_p";
6175 END IF;
6176 RETURN NULL;
6177 END IF;
6178 IF "persist"."phase_finished" THEN
6179 IF "persist"."state" = 'discussion' THEN
6180 UPDATE "issue" SET
6181 "state" = 'verification',
6182 "half_frozen" = "phase_finished",
6183 "phase_finished" = NULL
6184 WHERE "id" = "issue_id_p";
6185 RETURN NULL;
6186 END IF;
6187 IF "persist"."state" = 'verification' THEN
6188 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6189 FOR UPDATE;
6190 SELECT * INTO "policy_row" FROM "policy"
6191 WHERE "id" = "issue_row"."policy_id";
6192 IF EXISTS (
6193 SELECT NULL FROM "initiative"
6194 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
6195 ) THEN
6196 UPDATE "issue" SET
6197 "state" = 'voting',
6198 "fully_frozen" = "phase_finished",
6199 "phase_finished" = NULL
6200 WHERE "id" = "issue_id_p";
6201 ELSE
6202 UPDATE "issue" SET
6203 "state" = 'canceled_no_initiative_admitted',
6204 "fully_frozen" = "phase_finished",
6205 "closed" = "phase_finished",
6206 "phase_finished" = NULL
6207 WHERE "id" = "issue_id_p";
6208 -- NOTE: The following DELETE statements have effect only when
6209 -- issue state has been manipulated
6210 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
6211 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
6212 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
6213 END IF;
6214 RETURN NULL;
6215 END IF;
6216 IF "persist"."state" = 'voting' THEN
6217 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
6218 PERFORM "close_voting"("issue_id_p");
6219 "persist"."closed_voting" = TRUE;
6220 RETURN "persist";
6221 END IF;
6222 PERFORM "calculate_ranks"("issue_id_p");
6223 RETURN NULL;
6224 END IF;
6225 END IF;
6226 RAISE WARNING 'should not happen';
6227 RETURN NULL;
6228 END;
6229 $$;
6231 COMMENT ON FUNCTION "check_issue"
6232 ( "issue"."id"%TYPE,
6233 "check_issue_persistence" )
6234 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")';
6237 CREATE FUNCTION "check_everything"()
6238 RETURNS VOID
6239 LANGUAGE 'plpgsql' VOLATILE AS $$
6240 DECLARE
6241 "area_id_v" "area"."id"%TYPE;
6242 "snapshot_id_v" "snapshot"."id"%TYPE;
6243 "issue_id_v" "issue"."id"%TYPE;
6244 "persist_v" "check_issue_persistence";
6245 BEGIN
6246 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
6247 DELETE FROM "expired_session";
6248 DELETE FROM "expired_token";
6249 DELETE FROM "expired_snapshot";
6250 PERFORM "check_activity"();
6251 PERFORM "calculate_member_counts"();
6252 FOR "area_id_v" IN SELECT "id" FROM "area_with_unaccepted_issues" LOOP
6253 SELECT "take_snapshot"(NULL, "area_id_v") INTO "snapshot_id_v";
6254 PERFORM "finish_snapshot"("issue_id") FROM "snapshot_issue"
6255 WHERE "snapshot_id" = "snapshot_id_v";
6256 LOOP
6257 EXIT WHEN "issue_admission"("area_id_v") = FALSE;
6258 END LOOP;
6259 END LOOP;
6260 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
6261 "persist_v" := NULL;
6262 LOOP
6263 "persist_v" := "check_issue"("issue_id_v", "persist_v");
6264 EXIT WHEN "persist_v" ISNULL;
6265 END LOOP;
6266 END LOOP;
6267 RETURN;
6268 END;
6269 $$;
6271 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';
6275 ----------------------
6276 -- Deletion of data --
6277 ----------------------
6280 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
6281 RETURNS VOID
6282 LANGUAGE 'plpgsql' VOLATILE AS $$
6283 BEGIN
6284 IF EXISTS (
6285 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
6286 ) THEN
6287 -- override protection triggers:
6288 INSERT INTO "temporary_transaction_data" ("key", "value")
6289 VALUES ('override_protection_triggers', TRUE::TEXT);
6290 -- clean data:
6291 DELETE FROM "delegating_voter"
6292 WHERE "issue_id" = "issue_id_p";
6293 DELETE FROM "direct_voter"
6294 WHERE "issue_id" = "issue_id_p";
6295 DELETE FROM "delegating_interest_snapshot"
6296 WHERE "issue_id" = "issue_id_p";
6297 DELETE FROM "direct_interest_snapshot"
6298 WHERE "issue_id" = "issue_id_p";
6299 DELETE FROM "non_voter"
6300 WHERE "issue_id" = "issue_id_p";
6301 DELETE FROM "delegation"
6302 WHERE "issue_id" = "issue_id_p";
6303 DELETE FROM "supporter"
6304 USING "initiative" -- NOTE: due to missing index on issue_id
6305 WHERE "initiative"."issue_id" = "issue_id_p"
6306 AND "supporter"."initiative_id" = "initiative_id";
6307 -- mark issue as cleaned:
6308 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
6309 -- finish overriding protection triggers (avoids garbage):
6310 DELETE FROM "temporary_transaction_data"
6311 WHERE "key" = 'override_protection_triggers';
6312 END IF;
6313 RETURN;
6314 END;
6315 $$;
6317 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
6320 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
6321 RETURNS VOID
6322 LANGUAGE 'plpgsql' VOLATILE AS $$
6323 BEGIN
6324 UPDATE "member" SET
6325 "last_login" = NULL,
6326 "last_delegation_check" = NULL,
6327 "login" = NULL,
6328 "password" = NULL,
6329 "authority" = NULL,
6330 "authority_uid" = NULL,
6331 "authority_login" = NULL,
6332 "deleted" = coalesce("deleted", now()),
6333 "locked" = TRUE,
6334 "active" = FALSE,
6335 "notify_email" = NULL,
6336 "notify_email_unconfirmed" = NULL,
6337 "notify_email_secret" = NULL,
6338 "notify_email_secret_expiry" = NULL,
6339 "notify_email_lock_expiry" = NULL,
6340 "disable_notifications" = TRUE,
6341 "notification_counter" = DEFAULT,
6342 "notification_sample_size" = 0,
6343 "notification_dow" = NULL,
6344 "notification_hour" = NULL,
6345 "notification_sent" = NULL,
6346 "login_recovery_expiry" = NULL,
6347 "password_reset_secret" = NULL,
6348 "password_reset_secret_expiry" = NULL,
6349 "location" = NULL
6350 WHERE "id" = "member_id_p";
6351 -- "text_search_data" is updated by triggers
6352 DELETE FROM "member_settings" WHERE "member_id" = "member_id_p";
6353 DELETE FROM "member_profile" WHERE "member_id" = "member_id_p";
6354 DELETE FROM "rendered_member_statement" WHERE "member_id" = "member_id_p";
6355 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
6356 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
6357 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
6358 DELETE FROM "session" WHERE "member_id" = "member_id_p";
6359 DELETE FROM "member_application" WHERE "member_id" = "member_id_p";
6360 DELETE FROM "token" WHERE "member_id" = "member_id_p";
6361 DELETE FROM "subscription" WHERE "member_id" = "member_id_p";
6362 DELETE FROM "ignored_area" WHERE "member_id" = "member_id_p";
6363 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
6364 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
6365 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
6366 DELETE FROM "direct_voter" USING "issue"
6367 WHERE "direct_voter"."issue_id" = "issue"."id"
6368 AND "issue"."closed" ISNULL
6369 AND "member_id" = "member_id_p";
6370 DELETE FROM "notification_initiative_sent" WHERE "member_id" = "member_id_p";
6371 RETURN;
6372 END;
6373 $$;
6375 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)';
6378 CREATE FUNCTION "delete_private_data"()
6379 RETURNS VOID
6380 LANGUAGE 'plpgsql' VOLATILE AS $$
6381 BEGIN
6382 DELETE FROM "temporary_transaction_data";
6383 DELETE FROM "temporary_suggestion_counts";
6384 DELETE FROM "member" WHERE "activated" ISNULL;
6385 UPDATE "member" SET
6386 "invite_code" = NULL,
6387 "invite_code_expiry" = NULL,
6388 "admin_comment" = NULL,
6389 "last_login" = NULL,
6390 "last_delegation_check" = NULL,
6391 "login" = NULL,
6392 "password" = NULL,
6393 "authority" = NULL,
6394 "authority_uid" = NULL,
6395 "authority_login" = NULL,
6396 "lang" = NULL,
6397 "notify_email" = NULL,
6398 "notify_email_unconfirmed" = NULL,
6399 "notify_email_secret" = NULL,
6400 "notify_email_secret_expiry" = NULL,
6401 "notify_email_lock_expiry" = NULL,
6402 "disable_notifications" = TRUE,
6403 "notification_counter" = DEFAULT,
6404 "notification_sample_size" = 0,
6405 "notification_dow" = NULL,
6406 "notification_hour" = NULL,
6407 "notification_sent" = NULL,
6408 "login_recovery_expiry" = NULL,
6409 "password_reset_secret" = NULL,
6410 "password_reset_secret_expiry" = NULL,
6411 "location" = NULL;
6412 -- "text_search_data" is updated by triggers
6413 DELETE FROM "verification";
6414 DELETE FROM "member_settings";
6415 DELETE FROM "member_useterms";
6416 DELETE FROM "member_profile";
6417 DELETE FROM "rendered_member_statement";
6418 DELETE FROM "member_image";
6419 DELETE FROM "contact";
6420 DELETE FROM "ignored_member";
6421 DELETE FROM "session";
6422 DELETE FROM "system_application";
6423 DELETE FROM "system_application_redirect_uri";
6424 DELETE FROM "dynamic_application_scope";
6425 DELETE FROM "member_application";
6426 DELETE FROM "token";
6427 DELETE FROM "subscription";
6428 DELETE FROM "ignored_area";
6429 DELETE FROM "ignored_initiative";
6430 DELETE FROM "non_voter";
6431 DELETE FROM "direct_voter" USING "issue"
6432 WHERE "direct_voter"."issue_id" = "issue"."id"
6433 AND "issue"."closed" ISNULL;
6434 DELETE FROM "event_processed";
6435 DELETE FROM "notification_initiative_sent";
6436 DELETE FROM "newsletter";
6437 RETURN;
6438 END;
6439 $$;
6441 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.';
6445 COMMIT;

Impressum / About Us