liquid_feedback_core

view core.sql @ 624:82387194519b

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

Impressum / About Us