liquid_feedback_core

view core.sql @ 589:aa23fa17604d

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

Impressum / About Us