liquid_feedback_core

view core.sql @ 581:1cb6710fc429

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

Impressum / About Us