liquid_feedback_core

view core.sql @ 618:5b3b20f1278d

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

Impressum / About Us