liquid_feedback_core

view core.sql @ 605:f50171274974

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

Impressum / About Us