liquid_feedback_core

view core.sql @ 540:ec84707b459a

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

Impressum / About Us