liquid_feedback_core

view core.sql @ 616:ae53fc96c953

Added JSONB column "attr" to table "unit" for extended attributes of any kind
author jbe
date Tue Jul 28 18:57:20 2020 +0200 (2020-07-28)
parents 7f564126cffb
children 8e9d0878b5dc
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 "suggestion_id" INT8,
1390 -- NOTE: no referential integrity for suggestions because those are
1391 -- actually deleted
1392 -- FOREIGN KEY ("initiative_id", "suggestion_id")
1393 -- REFERENCES "suggestion" ("initiative_id", "id")
1394 -- ON DELETE CASCADE ON UPDATE CASCADE,
1395 CONSTRAINT "area_requires_unit" CHECK (
1396 "area_id" ISNULL OR "unit_id" NOTNULL ),
1397 CONSTRAINT "policy_set_when_issue_set" CHECK (
1398 ("policy_id" NOTNULL) = ("issue_id" NOTNULL) ),
1399 CONSTRAINT "issue_requires_area" CHECK (
1400 "issue_id" ISNULL OR "area_id" NOTNULL ),
1401 CONSTRAINT "initiative_requires_issue" CHECK (
1402 "initiative_id" ISNULL OR "issue_id" NOTNULL ),
1403 CONSTRAINT "suggestion_requires_initiative" CHECK (
1404 "suggestion_id" ISNULL OR "initiative_id" NOTNULL ) );
1405 CREATE INDEX "posting_global_idx" ON "posting" USING gist ((pstamp("author_id", "id")));
1406 CREATE INDEX "posting_unit_idx" ON "posting" USING gist ("unit_id", (pstamp("author_id", "id"))) WHERE "unit_id" NOTNULL;
1407 CREATE INDEX "posting_area_idx" ON "posting" USING gist ("area_id", (pstamp("author_id", "id"))) WHERE "area_id" NOTNULL;
1408 CREATE INDEX "posting_policy_idx" ON "posting" USING gist ("policy_id", (pstamp("author_id", "id"))) WHERE "policy_id" NOTNULL;
1409 CREATE INDEX "posting_issue_idx" ON "posting" USING gist ("issue_id", (pstamp("author_id", "id"))) WHERE "issue_id" NOTNULL;
1410 CREATE INDEX "posting_initiative_idx" ON "posting" USING gist ("initiative_id", (pstamp("author_id", "id"))) WHERE "initiative_id" NOTNULL;
1411 CREATE INDEX "posting_suggestion_idx" ON "posting" USING gist ("suggestion_id", (pstamp("author_id", "id"))) WHERE "suggestion_id" NOTNULL;
1413 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';
1416 CREATE TABLE "posting_lexeme" (
1417 PRIMARY KEY ("posting_id", "lexeme"),
1418 FOREIGN KEY ("posting_id", "author_id") REFERENCES "posting" ("id", "author_id") ON DELETE CASCADE ON UPDATE CASCADE,
1419 "posting_id" INT8,
1420 "lexeme" TEXT,
1421 "author_id" INT4 );
1422 CREATE INDEX "posting_lexeme_idx" ON "posting_lexeme" USING gist ("lexeme", (pstamp("author_id", "posting_id")));
1424 COMMENT ON TABLE "posting_lexeme" IS 'Helper table to allow searches for hashtags.';
1427 CREATE TYPE "event_type" AS ENUM (
1428 'unit_created',
1429 'unit_updated',
1430 'area_created',
1431 'area_updated',
1432 'policy_created',
1433 'policy_updated',
1434 'issue_state_changed',
1435 'initiative_created_in_new_issue',
1436 'initiative_created_in_existing_issue',
1437 'initiative_revoked',
1438 'new_draft_created',
1439 'suggestion_created',
1440 'suggestion_deleted',
1441 'member_activated',
1442 'member_deleted',
1443 'member_active',
1444 'member_name_updated',
1445 'member_profile_updated',
1446 'member_image_updated',
1447 'interest',
1448 'initiator',
1449 'support',
1450 'support_updated',
1451 'suggestion_rated',
1452 'delegation',
1453 'contact',
1454 'posting_created' );
1456 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1459 CREATE TABLE "event" (
1460 "id" SERIAL8 PRIMARY KEY,
1461 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1462 "event" "event_type" NOT NULL,
1463 "posting_id" INT8 REFERENCES "posting" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1464 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1465 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1466 "scope" "delegation_scope",
1467 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1468 "area_id" INT4,
1469 FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1470 "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1471 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1472 FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1473 FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1474 "state" "issue_state",
1475 "initiative_id" INT4,
1476 "draft_id" INT8,
1477 "suggestion_id" INT8,
1478 "boolean_value" BOOLEAN,
1479 "numeric_value" INT4,
1480 "text_value" TEXT,
1481 "old_text_value" TEXT,
1482 FOREIGN KEY ("issue_id", "initiative_id")
1483 REFERENCES "initiative" ("issue_id", "id")
1484 ON DELETE CASCADE ON UPDATE CASCADE,
1485 FOREIGN KEY ("initiative_id", "draft_id")
1486 REFERENCES "draft" ("initiative_id", "id")
1487 ON DELETE CASCADE ON UPDATE CASCADE,
1488 -- NOTE: no referential integrity for suggestions because those are
1489 -- actually deleted
1490 -- FOREIGN KEY ("initiative_id", "suggestion_id")
1491 -- REFERENCES "suggestion" ("initiative_id", "id")
1492 -- ON DELETE CASCADE ON UPDATE CASCADE,
1493 CONSTRAINT "constr_for_issue_state_changed" CHECK (
1494 "event" != 'issue_state_changed' OR (
1495 "posting_id" ISNULL AND
1496 "member_id" ISNULL AND
1497 "other_member_id" ISNULL AND
1498 "scope" ISNULL AND
1499 "unit_id" NOTNULL AND
1500 "area_id" NOTNULL AND
1501 "policy_id" NOTNULL AND
1502 "issue_id" NOTNULL AND
1503 "state" NOTNULL AND
1504 "initiative_id" ISNULL AND
1505 "draft_id" ISNULL AND
1506 "suggestion_id" ISNULL AND
1507 "boolean_value" ISNULL AND
1508 "numeric_value" ISNULL AND
1509 "text_value" ISNULL AND
1510 "old_text_value" ISNULL )),
1511 CONSTRAINT "constr_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1512 "event" NOT IN (
1513 'initiative_created_in_new_issue',
1514 'initiative_created_in_existing_issue',
1515 'initiative_revoked',
1516 'new_draft_created'
1517 ) OR (
1518 "posting_id" ISNULL AND
1519 "member_id" NOTNULL AND
1520 "other_member_id" ISNULL AND
1521 "scope" ISNULL AND
1522 "unit_id" NOTNULL AND
1523 "area_id" NOTNULL AND
1524 "policy_id" NOTNULL AND
1525 "issue_id" NOTNULL AND
1526 "state" NOTNULL AND
1527 "initiative_id" NOTNULL AND
1528 "draft_id" NOTNULL AND
1529 "suggestion_id" ISNULL AND
1530 "boolean_value" ISNULL AND
1531 "numeric_value" ISNULL AND
1532 "text_value" ISNULL AND
1533 "old_text_value" ISNULL )),
1534 CONSTRAINT "constr_for_suggestion_creation" CHECK (
1535 "event" != 'suggestion_created' OR (
1536 "posting_id" ISNULL AND
1537 "member_id" NOTNULL AND
1538 "other_member_id" ISNULL AND
1539 "scope" ISNULL AND
1540 "unit_id" NOTNULL AND
1541 "area_id" NOTNULL AND
1542 "policy_id" NOTNULL AND
1543 "issue_id" NOTNULL AND
1544 "state" NOTNULL AND
1545 "initiative_id" NOTNULL AND
1546 "draft_id" ISNULL AND
1547 "suggestion_id" NOTNULL AND
1548 "boolean_value" ISNULL AND
1549 "numeric_value" ISNULL AND
1550 "text_value" ISNULL AND
1551 "old_text_value" ISNULL )),
1552 CONSTRAINT "constr_for_suggestion_removal" CHECK (
1553 "event" != 'suggestion_deleted' OR (
1554 "posting_id" ISNULL AND
1555 "member_id" ISNULL AND
1556 "other_member_id" ISNULL AND
1557 "scope" ISNULL AND
1558 "unit_id" NOTNULL AND
1559 "area_id" NOTNULL AND
1560 "policy_id" NOTNULL AND
1561 "issue_id" NOTNULL AND
1562 "state" NOTNULL AND
1563 "initiative_id" NOTNULL AND
1564 "draft_id" ISNULL AND
1565 "suggestion_id" NOTNULL AND
1566 "boolean_value" ISNULL AND
1567 "numeric_value" ISNULL AND
1568 "text_value" ISNULL AND
1569 "old_text_value" ISNULL )),
1570 CONSTRAINT "constr_for_value_less_member_event" CHECK (
1571 "event" NOT IN (
1572 'member_activated',
1573 'member_deleted',
1574 'member_profile_updated',
1575 'member_image_updated'
1576 ) OR (
1577 "posting_id" ISNULL AND
1578 "member_id" NOTNULL AND
1579 "other_member_id" ISNULL AND
1580 "scope" ISNULL AND
1581 "unit_id" ISNULL AND
1582 "area_id" ISNULL AND
1583 "policy_id" ISNULL AND
1584 "issue_id" ISNULL AND
1585 "state" ISNULL AND
1586 "initiative_id" ISNULL AND
1587 "draft_id" ISNULL AND
1588 "suggestion_id" ISNULL AND
1589 "boolean_value" ISNULL AND
1590 "numeric_value" ISNULL AND
1591 "text_value" ISNULL AND
1592 "old_text_value" ISNULL )),
1593 CONSTRAINT "constr_for_member_active" CHECK (
1594 "event" != 'member_active' OR (
1595 "posting_id" ISNULL AND
1596 "member_id" NOTNULL AND
1597 "other_member_id" ISNULL AND
1598 "scope" ISNULL AND
1599 "unit_id" ISNULL AND
1600 "area_id" ISNULL AND
1601 "policy_id" ISNULL AND
1602 "issue_id" ISNULL AND
1603 "state" ISNULL AND
1604 "initiative_id" ISNULL AND
1605 "draft_id" ISNULL AND
1606 "suggestion_id" ISNULL AND
1607 "boolean_value" NOTNULL AND
1608 "numeric_value" ISNULL AND
1609 "text_value" ISNULL AND
1610 "old_text_value" ISNULL )),
1611 CONSTRAINT "constr_for_member_name_updated" CHECK (
1612 "event" != 'member_name_updated' OR (
1613 "posting_id" ISNULL AND
1614 "member_id" NOTNULL AND
1615 "other_member_id" ISNULL AND
1616 "scope" ISNULL AND
1617 "unit_id" ISNULL AND
1618 "area_id" ISNULL AND
1619 "policy_id" ISNULL AND
1620 "issue_id" ISNULL AND
1621 "state" ISNULL AND
1622 "initiative_id" ISNULL AND
1623 "draft_id" ISNULL AND
1624 "suggestion_id" ISNULL AND
1625 "boolean_value" ISNULL AND
1626 "numeric_value" ISNULL AND
1627 "text_value" NOTNULL AND
1628 "old_text_value" NOTNULL )),
1629 CONSTRAINT "constr_for_interest" CHECK (
1630 "event" != 'interest' OR (
1631 "posting_id" ISNULL AND
1632 "member_id" NOTNULL AND
1633 "other_member_id" ISNULL AND
1634 "scope" ISNULL AND
1635 "unit_id" NOTNULL AND
1636 "area_id" NOTNULL AND
1637 "policy_id" NOTNULL AND
1638 "issue_id" NOTNULL AND
1639 "state" NOTNULL AND
1640 "initiative_id" ISNULL AND
1641 "draft_id" ISNULL AND
1642 "suggestion_id" ISNULL AND
1643 "boolean_value" NOTNULL AND
1644 "numeric_value" ISNULL AND
1645 "text_value" ISNULL AND
1646 "old_text_value" ISNULL )),
1647 CONSTRAINT "constr_for_initiator" CHECK (
1648 "event" != 'initiator' OR (
1649 "posting_id" ISNULL AND
1650 "member_id" NOTNULL AND
1651 "other_member_id" ISNULL AND
1652 "scope" ISNULL AND
1653 "unit_id" NOTNULL AND
1654 "area_id" NOTNULL AND
1655 "policy_id" NOTNULL AND
1656 "issue_id" NOTNULL AND
1657 "state" NOTNULL AND
1658 "initiative_id" NOTNULL AND
1659 "draft_id" ISNULL AND
1660 "suggestion_id" ISNULL AND
1661 "boolean_value" NOTNULL AND
1662 "numeric_value" ISNULL AND
1663 "text_value" ISNULL AND
1664 "old_text_value" ISNULL )),
1665 CONSTRAINT "constr_for_support" CHECK (
1666 "event" != 'support' OR (
1667 "posting_id" ISNULL AND
1668 "member_id" NOTNULL AND
1669 "other_member_id" ISNULL AND
1670 "scope" ISNULL AND
1671 "unit_id" NOTNULL AND
1672 "area_id" NOTNULL AND
1673 "policy_id" NOTNULL AND
1674 "issue_id" NOTNULL AND
1675 "state" NOTNULL AND
1676 "initiative_id" NOTNULL AND
1677 ("draft_id" NOTNULL) = ("boolean_value" = TRUE) AND
1678 "suggestion_id" ISNULL AND
1679 "boolean_value" NOTNULL AND
1680 "numeric_value" ISNULL AND
1681 "text_value" ISNULL AND
1682 "old_text_value" ISNULL )),
1683 CONSTRAINT "constr_for_support_updated" CHECK (
1684 "event" != 'support_updated' OR (
1685 "posting_id" ISNULL AND
1686 "member_id" NOTNULL AND
1687 "other_member_id" ISNULL AND
1688 "scope" ISNULL AND
1689 "unit_id" NOTNULL AND
1690 "area_id" NOTNULL AND
1691 "policy_id" NOTNULL AND
1692 "issue_id" NOTNULL AND
1693 "state" NOTNULL AND
1694 "initiative_id" NOTNULL AND
1695 "draft_id" NOTNULL AND
1696 "suggestion_id" ISNULL AND
1697 "boolean_value" ISNULL AND
1698 "numeric_value" ISNULL AND
1699 "text_value" ISNULL AND
1700 "old_text_value" ISNULL )),
1701 CONSTRAINT "constr_for_suggestion_rated" CHECK (
1702 "event" != 'suggestion_rated' OR (
1703 "posting_id" ISNULL AND
1704 "member_id" NOTNULL AND
1705 "other_member_id" ISNULL AND
1706 "scope" ISNULL AND
1707 "unit_id" NOTNULL AND
1708 "area_id" NOTNULL AND
1709 "policy_id" NOTNULL AND
1710 "issue_id" NOTNULL AND
1711 "state" NOTNULL AND
1712 "initiative_id" NOTNULL AND
1713 "draft_id" ISNULL AND
1714 "suggestion_id" NOTNULL AND
1715 ("boolean_value" NOTNULL) = ("numeric_value" != 0) AND
1716 "numeric_value" NOTNULL AND
1717 "numeric_value" IN (-2, -1, 0, 1, 2) AND
1718 "text_value" ISNULL AND
1719 "old_text_value" ISNULL )),
1720 CONSTRAINT "constr_for_delegation" CHECK (
1721 "event" != 'delegation' OR (
1722 "posting_id" ISNULL AND
1723 "member_id" NOTNULL AND
1724 (("other_member_id" ISNULL) OR ("boolean_value" = TRUE)) AND
1725 "scope" NOTNULL AND
1726 "unit_id" NOTNULL AND
1727 ("area_id" NOTNULL) = ("scope" != 'unit'::"delegation_scope") AND
1728 "policy_id" ISNULL AND
1729 ("issue_id" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1730 ("state" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1731 "initiative_id" ISNULL AND
1732 "draft_id" ISNULL AND
1733 "suggestion_id" ISNULL AND
1734 "boolean_value" NOTNULL AND
1735 "numeric_value" ISNULL AND
1736 "text_value" ISNULL AND
1737 "old_text_value" ISNULL )),
1738 CONSTRAINT "constr_for_contact" CHECK (
1739 "event" != 'contact' OR (
1740 "posting_id" ISNULL AND
1741 "member_id" NOTNULL AND
1742 "other_member_id" NOTNULL AND
1743 "scope" ISNULL AND
1744 "unit_id" ISNULL AND
1745 "area_id" ISNULL AND
1746 "policy_id" ISNULL AND
1747 "issue_id" ISNULL AND
1748 "state" ISNULL AND
1749 "initiative_id" ISNULL AND
1750 "draft_id" ISNULL AND
1751 "suggestion_id" ISNULL AND
1752 "boolean_value" NOTNULL AND
1753 "numeric_value" ISNULL AND
1754 "text_value" ISNULL AND
1755 "old_text_value" ISNULL )),
1756 CONSTRAINT "constr_for_posting_created" CHECK (
1757 "event" != 'posting_created' OR (
1758 "posting_id" NOTNULL AND
1759 "member_id" NOTNULL AND
1760 "other_member_id" ISNULL AND
1761 "scope" ISNULL AND
1762 "state" ISNULL AND
1763 ("area_id" ISNULL OR "unit_id" NOTNULL) AND
1764 ("policy_id" NOTNULL) = ("issue_id" NOTNULL) AND
1765 ("issue_id" ISNULL OR "area_id" NOTNULL) AND
1766 ("state" NOTNULL) = ("issue_id" NOTNULL) AND
1767 ("initiative_id" ISNULL OR "issue_id" NOTNULL) AND
1768 "draft_id" ISNULL AND
1769 ("suggestion_id" ISNULL OR "initiative_id" NOTNULL) AND
1770 "boolean_value" ISNULL AND
1771 "numeric_value" ISNULL AND
1772 "text_value" ISNULL AND
1773 "old_text_value" ISNULL )) );
1774 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1775 CREATE INDEX "event_tl_global_idx" ON "event" USING gist ((pstamp("member_id", "id")));
1776 CREATE INDEX "event_tl_unit_idx" ON "event" USING gist ("unit_id", (pstamp("member_id", "id"))) WHERE "unit_id" NOTNULL;
1777 CREATE INDEX "event_tl_area_idx" ON "event" USING gist ("area_id", (pstamp("member_id", "id"))) WHERE "area_id" NOTNULL;
1778 CREATE INDEX "event_tl_policy_idx" ON "event" USING gist ("policy_id", (pstamp("member_id", "id"))) WHERE "policy_id" NOTNULL;
1779 CREATE INDEX "event_tl_issue_idx" ON "event" USING gist ("issue_id", (pstamp("member_id", "id"))) WHERE "issue_id" NOTNULL;
1780 CREATE INDEX "event_tl_initiative_idx" ON "event" USING gist ("initiative_id", (pstamp("member_id", "id"))) WHERE "initiative_id" NOTNULL;
1781 CREATE INDEX "event_tl_suggestion_idx" ON "event" USING gist ("suggestion_id", (pstamp("member_id", "id"))) WHERE "suggestion_id" NOTNULL;
1784 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1786 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1787 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1788 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1789 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1792 CREATE TABLE "event_processed" (
1793 "event_id" INT8 NOT NULL );
1794 CREATE UNIQUE INDEX "event_processed_singleton_idx" ON "event_processed" ((1));
1796 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)';
1797 COMMENT ON INDEX "event_processed_singleton_idx" IS 'This index ensures that "event_processed" only contains one row maximum.';
1800 CREATE TABLE "notification_initiative_sent" (
1801 PRIMARY KEY ("member_id", "initiative_id"),
1802 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1803 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1804 "last_draft_id" INT8 NOT NULL,
1805 "last_suggestion_id" INT8 );
1806 CREATE INDEX "notification_initiative_sent_initiative_idx" ON "notification_initiative_sent" ("initiative_id");
1808 COMMENT ON TABLE "notification_initiative_sent" IS 'Information which initiatives have been promoted to a member in a scheduled notification mail';
1810 COMMENT ON COLUMN "notification_initiative_sent"."last_draft_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1811 COMMENT ON COLUMN "notification_initiative_sent"."last_suggestion_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1814 CREATE TABLE "newsletter" (
1815 "id" SERIAL4 PRIMARY KEY,
1816 "published" TIMESTAMPTZ NOT NULL,
1817 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1818 "include_all_members" BOOLEAN NOT NULL,
1819 "sent" TIMESTAMPTZ,
1820 "subject" TEXT NOT NULL,
1821 "content" TEXT NOT NULL );
1822 CREATE INDEX "newsletter_unit_id_idx" ON "newsletter" ("unit_id", "published");
1823 CREATE INDEX "newsletter_all_units_published_idx" ON "newsletter" ("published") WHERE "unit_id" ISNULL;
1824 CREATE INDEX "newsletter_published_idx" ON "newsletter" ("published");
1826 COMMENT ON TABLE "newsletter" IS 'Contains newsletters created by administrators to be sent out and for further reference';
1828 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter is to be sent out (and made available in the frontend)';
1829 COMMENT ON COLUMN "newsletter"."unit_id" IS 'If set, only members with voting right in the given unit are considered to be recipients';
1830 COMMENT ON COLUMN "newsletter"."include_all_members" IS 'TRUE = include all members regardless of their ''disable_notifications'' setting';
1831 COMMENT ON COLUMN "newsletter"."sent" IS 'Timestamp when the newsletter has been mailed out';
1832 COMMENT ON COLUMN "newsletter"."subject" IS 'Subject line (e.g. to be used for the email)';
1833 COMMENT ON COLUMN "newsletter"."content" IS 'Plain text content of the newsletter';
1837 ----------------------
1838 -- Full text search --
1839 ----------------------
1842 CREATE FUNCTION "highlight"
1843 ( "body_p" TEXT,
1844 "query_text_p" TEXT )
1845 RETURNS TEXT
1846 LANGUAGE 'plpgsql' IMMUTABLE AS $$
1847 BEGIN
1848 RETURN ts_headline(
1849 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
1850 "plainto_tsquery"("query_text_p"),
1851 'StartSel=* StopSel=* HighlightAll=TRUE' );
1852 END;
1853 $$;
1855 COMMENT ON FUNCTION "highlight"
1856 ( "body_p" TEXT,
1857 "query_text_p" TEXT )
1858 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.';
1861 CREATE FUNCTION "to_tsvector"("member") RETURNS TSVECTOR
1862 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1863 $1."name",
1864 $1."identification"
1865 )) $$;
1866 CREATE INDEX "member_to_tsvector_idx" ON "member" USING gin
1867 (("to_tsvector"("member".*)));
1869 CREATE FUNCTION "to_tsvector"("member_profile") RETURNS TSVECTOR
1870 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1871 $1."statement",
1872 $1."profile_text_data"
1873 )) $$;
1874 CREATE INDEX "member_profile_to_tsvector_idx" ON "member_profile" USING gin
1875 (("to_tsvector"("member_profile".*)));
1877 CREATE FUNCTION "to_tsvector"("unit") RETURNS TSVECTOR
1878 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1879 $1."name",
1880 $1."description"
1881 )) $$;
1882 CREATE INDEX "unit_to_tsvector_idx" ON "unit" USING gin
1883 (("to_tsvector"("unit".*)));
1885 CREATE FUNCTION "to_tsvector"("area") RETURNS TSVECTOR
1886 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1887 $1."name",
1888 $1."description"
1889 )) $$;
1890 CREATE INDEX "area_to_tsvector_idx" ON "area" USING gin
1891 (("to_tsvector"("area".*)));
1893 CREATE FUNCTION "to_tsvector"("initiative") RETURNS TSVECTOR
1894 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1895 $1."name",
1896 $1."content"
1897 )) $$;
1898 CREATE INDEX "initiative_to_tsvector_idx" ON "initiative" USING gin
1899 (("to_tsvector"("initiative".*)));
1901 CREATE FUNCTION "to_tsvector"("draft") RETURNS TSVECTOR
1902 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1903 $1."content"
1904 )) $$;
1905 CREATE INDEX "draft_to_tsvector_idx" ON "draft" USING gin
1906 (("to_tsvector"("draft".*)));
1908 CREATE FUNCTION "to_tsvector"("suggestion") RETURNS TSVECTOR
1909 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1910 $1."name",
1911 $1."content"
1912 )) $$;
1913 CREATE INDEX "suggestion_to_tsvector_idx" ON "suggestion" USING gin
1914 (("to_tsvector"("suggestion".*)));
1916 CREATE FUNCTION "to_tsvector"("direct_voter") RETURNS TSVECTOR
1917 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1918 $1."comment"
1919 )) $$;
1920 CREATE INDEX "direct_voter_to_tsvector_idx" ON "direct_voter" USING gin
1921 (("to_tsvector"("direct_voter".*)));
1924 CREATE FUNCTION "update_posting_lexeme_trigger"()
1925 RETURNS TRIGGER
1926 LANGUAGE 'plpgsql' VOLATILE AS $$
1927 DECLARE
1928 "lexeme_v" TEXT;
1929 BEGIN
1930 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
1931 DELETE FROM "posting_lexeme" WHERE "posting_id" = OLD."id";
1932 END IF;
1933 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
1934 FOR "lexeme_v" IN
1935 SELECT regexp_matches[1]
1936 FROM regexp_matches(NEW."message", '#[^\s.,;:]+')
1937 LOOP
1938 INSERT INTO "posting_lexeme" ("posting_id", "author_id", "lexeme")
1939 VALUES (
1940 NEW."id",
1941 NEW."author_id",
1942 "lexeme_v" )
1943 ON CONFLICT ("posting_id", "lexeme") DO NOTHING;
1944 END LOOP;
1945 END IF;
1946 RETURN NULL;
1947 END;
1948 $$;
1950 CREATE TRIGGER "update_posting_lexeme"
1951 AFTER INSERT OR UPDATE OR DELETE ON "posting"
1952 FOR EACH ROW EXECUTE PROCEDURE "update_posting_lexeme_trigger"();
1954 COMMENT ON FUNCTION "update_posting_lexeme_trigger"() IS 'Implementation of trigger "update_posting_lexeme" on table "posting"';
1955 COMMENT ON TRIGGER "update_posting_lexeme" ON "posting" IS 'Keeps table "posting_lexeme" up to date';
1959 ----------------------------------------------
1960 -- Writing of history entries and event log --
1961 ----------------------------------------------
1964 CREATE FUNCTION "write_member_history_trigger"()
1965 RETURNS TRIGGER
1966 LANGUAGE 'plpgsql' VOLATILE AS $$
1967 BEGIN
1968 IF
1969 ( NEW."active" != OLD."active" OR
1970 NEW."name" != OLD."name" ) AND
1971 OLD."activated" NOTNULL
1972 THEN
1973 INSERT INTO "member_history"
1974 ("member_id", "active", "name")
1975 VALUES (NEW."id", OLD."active", OLD."name");
1976 END IF;
1977 RETURN NULL;
1978 END;
1979 $$;
1981 CREATE TRIGGER "write_member_history"
1982 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1983 "write_member_history_trigger"();
1985 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1986 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1989 CREATE FUNCTION "write_event_unit_trigger"()
1990 RETURNS TRIGGER
1991 LANGUAGE 'plpgsql' VOLATILE AS $$
1992 DECLARE
1993 "event_v" "event_type";
1994 BEGIN
1995 IF TG_OP = 'UPDATE' THEN
1996 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1997 RETURN NULL;
1998 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1999 -- "event_v" := 'unit_created';
2000 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
2001 -- "event_v" := 'unit_deleted';
2002 ELSIF OLD != NEW THEN
2003 "event_v" := 'unit_updated';
2004 ELSE
2005 RETURN NULL;
2006 END IF;
2007 ELSE
2008 "event_v" := 'unit_created';
2009 END IF;
2010 INSERT INTO "event" ("event", "unit_id") VALUES ("event_v", NEW."id");
2011 RETURN NULL;
2012 END;
2013 $$;
2015 CREATE TRIGGER "write_event_unit" AFTER INSERT OR UPDATE ON "unit"
2016 FOR EACH ROW EXECUTE PROCEDURE "write_event_unit_trigger"();
2018 COMMENT ON FUNCTION "write_event_unit_trigger"() IS 'Implementation of trigger "write_event_unit" on table "unit"';
2019 COMMENT ON TRIGGER "write_event_unit" ON "unit" IS 'Create entry in "event" table on new or changed/disabled units';
2022 CREATE FUNCTION "write_event_area_trigger"()
2023 RETURNS TRIGGER
2024 LANGUAGE 'plpgsql' VOLATILE AS $$
2025 DECLARE
2026 "event_v" "event_type";
2027 BEGIN
2028 IF TG_OP = 'UPDATE' THEN
2029 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
2030 RETURN NULL;
2031 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
2032 -- "event_v" := 'area_created';
2033 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
2034 -- "event_v" := 'area_deleted';
2035 ELSIF OLD != NEW THEN
2036 "event_v" := 'area_updated';
2037 ELSE
2038 RETURN NULL;
2039 END IF;
2040 ELSE
2041 "event_v" := 'area_created';
2042 END IF;
2043 INSERT INTO "event" ("event", "area_id") VALUES ("event_v", NEW."id");
2044 RETURN NULL;
2045 END;
2046 $$;
2048 CREATE TRIGGER "write_event_area" AFTER INSERT OR UPDATE ON "area"
2049 FOR EACH ROW EXECUTE PROCEDURE "write_event_area_trigger"();
2051 COMMENT ON FUNCTION "write_event_area_trigger"() IS 'Implementation of trigger "write_event_area" on table "area"';
2052 COMMENT ON TRIGGER "write_event_area" ON "area" IS 'Create entry in "event" table on new or changed/disabled areas';
2055 CREATE FUNCTION "write_event_policy_trigger"()
2056 RETURNS TRIGGER
2057 LANGUAGE 'plpgsql' VOLATILE AS $$
2058 DECLARE
2059 "event_v" "event_type";
2060 BEGIN
2061 IF TG_OP = 'UPDATE' THEN
2062 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
2063 RETURN NULL;
2064 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
2065 -- "event_v" := 'policy_created';
2066 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
2067 -- "event_v" := 'policy_deleted';
2068 ELSIF OLD != NEW THEN
2069 "event_v" := 'policy_updated';
2070 ELSE
2071 RETURN NULL;
2072 END IF;
2073 ELSE
2074 "event_v" := 'policy_created';
2075 END IF;
2076 INSERT INTO "event" ("event", "policy_id") VALUES ("event_v", NEW."id");
2077 RETURN NULL;
2078 END;
2079 $$;
2081 CREATE TRIGGER "write_event_policy" AFTER INSERT OR UPDATE ON "policy"
2082 FOR EACH ROW EXECUTE PROCEDURE "write_event_policy_trigger"();
2084 COMMENT ON FUNCTION "write_event_policy_trigger"() IS 'Implementation of trigger "write_event_policy" on table "policy"';
2085 COMMENT ON TRIGGER "write_event_policy" ON "policy" IS 'Create entry in "event" table on new or changed/disabled policies';
2088 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
2089 RETURNS TRIGGER
2090 LANGUAGE 'plpgsql' VOLATILE AS $$
2091 DECLARE
2092 "area_row" "area"%ROWTYPE;
2093 BEGIN
2094 IF NEW."state" != OLD."state" THEN
2095 SELECT * INTO "area_row" FROM "area" WHERE "id" = NEW."area_id"
2096 FOR SHARE;
2097 INSERT INTO "event" (
2098 "event",
2099 "unit_id", "area_id", "policy_id", "issue_id", "state"
2100 ) VALUES (
2101 'issue_state_changed',
2102 "area_row"."unit_id", NEW."area_id", NEW."policy_id",
2103 NEW."id", NEW."state"
2104 );
2105 END IF;
2106 RETURN NULL;
2107 END;
2108 $$;
2110 CREATE TRIGGER "write_event_issue_state_changed"
2111 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
2112 "write_event_issue_state_changed_trigger"();
2114 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
2115 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
2118 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
2119 RETURNS TRIGGER
2120 LANGUAGE 'plpgsql' VOLATILE AS $$
2121 DECLARE
2122 "initiative_row" "initiative"%ROWTYPE;
2123 "issue_row" "issue"%ROWTYPE;
2124 "area_row" "area"%ROWTYPE;
2125 "event_v" "event_type";
2126 BEGIN
2127 SELECT * INTO "initiative_row" FROM "initiative"
2128 WHERE "id" = NEW."initiative_id" FOR SHARE;
2129 SELECT * INTO "issue_row" FROM "issue"
2130 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2131 SELECT * INTO "area_row" FROM "area"
2132 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2133 IF EXISTS (
2134 SELECT NULL FROM "draft"
2135 WHERE "initiative_id" = NEW."initiative_id" AND "id" != NEW."id"
2136 FOR SHARE
2137 ) THEN
2138 "event_v" := 'new_draft_created';
2139 ELSE
2140 IF EXISTS (
2141 SELECT NULL FROM "initiative"
2142 WHERE "issue_id" = "initiative_row"."issue_id"
2143 AND "id" != "initiative_row"."id"
2144 FOR SHARE
2145 ) THEN
2146 "event_v" := 'initiative_created_in_existing_issue';
2147 ELSE
2148 "event_v" := 'initiative_created_in_new_issue';
2149 END IF;
2150 END IF;
2151 INSERT INTO "event" (
2152 "event", "member_id",
2153 "unit_id", "area_id", "policy_id", "issue_id", "state",
2154 "initiative_id", "draft_id"
2155 ) VALUES (
2156 "event_v", NEW."author_id",
2157 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
2158 "initiative_row"."issue_id", "issue_row"."state",
2159 NEW."initiative_id", NEW."id"
2160 );
2161 RETURN NULL;
2162 END;
2163 $$;
2165 CREATE TRIGGER "write_event_initiative_or_draft_created"
2166 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
2167 "write_event_initiative_or_draft_created_trigger"();
2169 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
2170 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
2173 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
2174 RETURNS TRIGGER
2175 LANGUAGE 'plpgsql' VOLATILE AS $$
2176 DECLARE
2177 "issue_row" "issue"%ROWTYPE;
2178 "area_row" "area"%ROWTYPE;
2179 "draft_id_v" "draft"."id"%TYPE;
2180 BEGIN
2181 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
2182 -- NOTE: lock for primary key update to avoid new drafts
2183 PERFORM NULL FROM "initiative" WHERE "id" = NEW."id" FOR UPDATE;
2184 SELECT * INTO "issue_row" FROM "issue"
2185 WHERE "id" = NEW."issue_id" FOR SHARE;
2186 SELECT * INTO "area_row" FROM "area"
2187 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2188 -- NOTE: FOR SHARE cannot be used with DISTINCT in view "current_draft"
2189 PERFORM NULL FROM "draft" WHERE "initiative_id" = NEW."id" FOR SHARE;
2190 SELECT "id" INTO "draft_id_v" FROM "current_draft"
2191 WHERE "initiative_id" = NEW."id";
2192 INSERT INTO "event" (
2193 "event", "member_id",
2194 "unit_id", "area_id", "policy_id", "issue_id", "state",
2195 "initiative_id", "draft_id"
2196 ) VALUES (
2197 'initiative_revoked', NEW."revoked_by_member_id",
2198 "area_row"."unit_id", "issue_row"."area_id",
2199 "issue_row"."policy_id",
2200 NEW."issue_id", "issue_row"."state",
2201 NEW."id", "draft_id_v"
2202 );
2203 END IF;
2204 RETURN NULL;
2205 END;
2206 $$;
2208 CREATE TRIGGER "write_event_initiative_revoked"
2209 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
2210 "write_event_initiative_revoked_trigger"();
2212 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
2213 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
2216 CREATE FUNCTION "write_event_suggestion_created_trigger"()
2217 RETURNS TRIGGER
2218 LANGUAGE 'plpgsql' VOLATILE AS $$
2219 DECLARE
2220 "initiative_row" "initiative"%ROWTYPE;
2221 "issue_row" "issue"%ROWTYPE;
2222 "area_row" "area"%ROWTYPE;
2223 BEGIN
2224 SELECT * INTO "initiative_row" FROM "initiative"
2225 WHERE "id" = NEW."initiative_id" FOR SHARE;
2226 SELECT * INTO "issue_row" FROM "issue"
2227 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2228 SELECT * INTO "area_row" FROM "area"
2229 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2230 INSERT INTO "event" (
2231 "event", "member_id",
2232 "unit_id", "area_id", "policy_id", "issue_id", "state",
2233 "initiative_id", "suggestion_id"
2234 ) VALUES (
2235 'suggestion_created', NEW."author_id",
2236 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
2237 "initiative_row"."issue_id", "issue_row"."state",
2238 NEW."initiative_id", NEW."id"
2239 );
2240 RETURN NULL;
2241 END;
2242 $$;
2244 CREATE TRIGGER "write_event_suggestion_created"
2245 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2246 "write_event_suggestion_created_trigger"();
2248 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
2249 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2252 CREATE FUNCTION "write_event_suggestion_removed_trigger"()
2253 RETURNS TRIGGER
2254 LANGUAGE 'plpgsql' VOLATILE AS $$
2255 DECLARE
2256 "initiative_row" "initiative"%ROWTYPE;
2257 "issue_row" "issue"%ROWTYPE;
2258 "area_row" "area"%ROWTYPE;
2259 BEGIN
2260 SELECT * INTO "initiative_row" FROM "initiative"
2261 WHERE "id" = OLD."initiative_id" FOR SHARE;
2262 IF "initiative_row"."id" NOTNULL THEN
2263 SELECT * INTO "issue_row" FROM "issue"
2264 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2265 SELECT * INTO "area_row" FROM "area"
2266 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2267 INSERT INTO "event" (
2268 "event",
2269 "unit_id", "area_id", "policy_id", "issue_id", "state",
2270 "initiative_id", "suggestion_id"
2271 ) VALUES (
2272 'suggestion_deleted',
2273 "area_row"."unit_id", "issue_row"."area_id",
2274 "issue_row"."policy_id",
2275 "initiative_row"."issue_id", "issue_row"."state",
2276 OLD."initiative_id", OLD."id"
2277 );
2278 END IF;
2279 RETURN NULL;
2280 END;
2281 $$;
2283 CREATE TRIGGER "write_event_suggestion_removed"
2284 AFTER DELETE ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2285 "write_event_suggestion_removed_trigger"();
2287 COMMENT ON FUNCTION "write_event_suggestion_removed_trigger"() IS 'Implementation of trigger "write_event_suggestion_removed" on table "issue"';
2288 COMMENT ON TRIGGER "write_event_suggestion_removed" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2291 CREATE FUNCTION "write_event_member_trigger"()
2292 RETURNS TRIGGER
2293 LANGUAGE 'plpgsql' VOLATILE AS $$
2294 BEGIN
2295 IF TG_OP = 'INSERT' THEN
2296 IF NEW."activated" NOTNULL AND NEW."deleted" ISNULL THEN
2297 INSERT INTO "event" ("event", "member_id")
2298 VALUES ('member_activated', NEW."id");
2299 END IF;
2300 IF NEW."active" THEN
2301 INSERT INTO "event" ("event", "member_id", "boolean_value")
2302 VALUES ('member_active', NEW."id", TRUE);
2303 END IF;
2304 ELSIF TG_OP = 'UPDATE' THEN
2305 IF OLD."id" != NEW."id" THEN
2306 RAISE EXCEPTION 'Cannot change member ID';
2307 END IF;
2308 IF
2309 (OLD."activated" ISNULL OR OLD."deleted" NOTNULL) AND
2310 NEW."activated" NOTNULL AND NEW."deleted" ISNULL
2311 THEN
2312 INSERT INTO "event" ("event", "member_id")
2313 VALUES ('member_activated', NEW."id");
2314 END IF;
2315 IF OLD."active" != NEW."active" THEN
2316 INSERT INTO "event" ("event", "member_id", "boolean_value") VALUES (
2317 'member_active', NEW."id", NEW."active"
2318 );
2319 END IF;
2320 IF OLD."name" != NEW."name" THEN
2321 INSERT INTO "event" (
2322 "event", "member_id", "text_value", "old_text_value"
2323 ) VALUES (
2324 'member_name_updated', NEW."id", NEW."name", OLD."name"
2325 );
2326 END IF;
2327 IF
2328 OLD."activated" NOTNULL AND OLD."deleted" ISNULL AND
2329 (NEW."activated" ISNULL OR NEW."deleted" NOTNULL)
2330 THEN
2331 INSERT INTO "event" ("event", "member_id")
2332 VALUES ('member_deleted', NEW."id");
2333 END IF;
2334 END IF;
2335 RETURN NULL;
2336 END;
2337 $$;
2339 CREATE TRIGGER "write_event_member"
2340 AFTER INSERT OR UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
2341 "write_event_member_trigger"();
2343 COMMENT ON FUNCTION "write_event_member_trigger"() IS 'Implementation of trigger "write_event_member" on table "member"';
2344 COMMENT ON TRIGGER "write_event_member" ON "member" IS 'Create entries in "event" table on insertion to member table';
2347 CREATE FUNCTION "write_event_member_profile_updated_trigger"()
2348 RETURNS TRIGGER
2349 LANGUAGE 'plpgsql' VOLATILE AS $$
2350 BEGIN
2351 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2352 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2353 INSERT INTO "event" ("event", "member_id") VALUES (
2354 'member_profile_updated', OLD."member_id"
2355 );
2356 END IF;
2357 END IF;
2358 IF TG_OP = 'UPDATE' THEN
2359 IF OLD."member_id" = NEW."member_id" THEN
2360 RETURN NULL;
2361 END IF;
2362 END IF;
2363 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2364 INSERT INTO "event" ("event", "member_id") VALUES (
2365 'member_profile_updated', NEW."member_id"
2366 );
2367 END IF;
2368 RETURN NULL;
2369 END;
2370 $$;
2372 CREATE TRIGGER "write_event_member_profile_updated"
2373 AFTER INSERT OR UPDATE OR DELETE ON "member_profile"
2374 FOR EACH ROW EXECUTE PROCEDURE
2375 "write_event_member_profile_updated_trigger"();
2377 COMMENT ON FUNCTION "write_event_member_profile_updated_trigger"() IS 'Implementation of trigger "write_event_member_profile_updated" on table "member_profile"';
2378 COMMENT ON TRIGGER "write_event_member_profile_updated" ON "member_profile" IS 'Creates entries in "event" table on member profile update';
2381 CREATE FUNCTION "write_event_member_image_updated_trigger"()
2382 RETURNS TRIGGER
2383 LANGUAGE 'plpgsql' VOLATILE AS $$
2384 BEGIN
2385 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2386 IF NOT OLD."scaled" THEN
2387 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2388 INSERT INTO "event" ("event", "member_id") VALUES (
2389 'member_image_updated', OLD."member_id"
2390 );
2391 END IF;
2392 END IF;
2393 END IF;
2394 IF TG_OP = 'UPDATE' THEN
2395 IF
2396 OLD."member_id" = NEW."member_id" AND
2397 OLD."scaled" = NEW."scaled"
2398 THEN
2399 RETURN NULL;
2400 END IF;
2401 END IF;
2402 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2403 IF NOT NEW."scaled" THEN
2404 INSERT INTO "event" ("event", "member_id") VALUES (
2405 'member_image_updated', NEW."member_id"
2406 );
2407 END IF;
2408 END IF;
2409 RETURN NULL;
2410 END;
2411 $$;
2413 CREATE TRIGGER "write_event_member_image_updated"
2414 AFTER INSERT OR UPDATE OR DELETE ON "member_image"
2415 FOR EACH ROW EXECUTE PROCEDURE
2416 "write_event_member_image_updated_trigger"();
2418 COMMENT ON FUNCTION "write_event_member_image_updated_trigger"() IS 'Implementation of trigger "write_event_member_image_updated" on table "member_image"';
2419 COMMENT ON TRIGGER "write_event_member_image_updated" ON "member_image" IS 'Creates entries in "event" table on member image update';
2422 CREATE FUNCTION "write_event_interest_trigger"()
2423 RETURNS TRIGGER
2424 LANGUAGE 'plpgsql' VOLATILE AS $$
2425 DECLARE
2426 "issue_row" "issue"%ROWTYPE;
2427 "area_row" "area"%ROWTYPE;
2428 BEGIN
2429 IF TG_OP = 'UPDATE' THEN
2430 IF OLD = NEW THEN
2431 RETURN NULL;
2432 END IF;
2433 END IF;
2434 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2435 SELECT * INTO "issue_row" FROM "issue"
2436 WHERE "id" = OLD."issue_id" FOR SHARE;
2437 SELECT * INTO "area_row" FROM "area"
2438 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2439 IF "issue_row"."id" NOTNULL THEN
2440 INSERT INTO "event" (
2441 "event", "member_id",
2442 "unit_id", "area_id", "policy_id", "issue_id", "state",
2443 "boolean_value"
2444 ) VALUES (
2445 'interest', OLD."member_id",
2446 "area_row"."unit_id", "issue_row"."area_id",
2447 "issue_row"."policy_id",
2448 OLD."issue_id", "issue_row"."state",
2449 FALSE
2450 );
2451 END IF;
2452 END IF;
2453 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2454 SELECT * INTO "issue_row" FROM "issue"
2455 WHERE "id" = NEW."issue_id" FOR SHARE;
2456 SELECT * INTO "area_row" FROM "area"
2457 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2458 INSERT INTO "event" (
2459 "event", "member_id",
2460 "unit_id", "area_id", "policy_id", "issue_id", "state",
2461 "boolean_value"
2462 ) VALUES (
2463 'interest', NEW."member_id",
2464 "area_row"."unit_id", "issue_row"."area_id",
2465 "issue_row"."policy_id",
2466 NEW."issue_id", "issue_row"."state",
2467 TRUE
2468 );
2469 END IF;
2470 RETURN NULL;
2471 END;
2472 $$;
2474 CREATE TRIGGER "write_event_interest"
2475 AFTER INSERT OR UPDATE OR DELETE ON "interest" FOR EACH ROW EXECUTE PROCEDURE
2476 "write_event_interest_trigger"();
2478 COMMENT ON FUNCTION "write_event_interest_trigger"() IS 'Implementation of trigger "write_event_interest_inserted" on table "interest"';
2479 COMMENT ON TRIGGER "write_event_interest" ON "interest" IS 'Create entry in "event" table on adding or removing interest';
2482 CREATE FUNCTION "write_event_initiator_trigger"()
2483 RETURNS TRIGGER
2484 LANGUAGE 'plpgsql' VOLATILE AS $$
2485 DECLARE
2486 "initiative_row" "initiative"%ROWTYPE;
2487 "issue_row" "issue"%ROWTYPE;
2488 "area_row" "area"%ROWTYPE;
2489 "accepted_v" BOOLEAN = FALSE;
2490 "rejected_v" BOOLEAN = FALSE;
2491 BEGIN
2492 IF TG_OP = 'UPDATE' THEN
2493 IF
2494 OLD."initiative_id" = NEW."initiative_id" AND
2495 OLD."member_id" = NEW."member_id"
2496 THEN
2497 IF
2498 coalesce(OLD."accepted", FALSE) = coalesce(NEW."accepted", FALSE)
2499 THEN
2500 RETURN NULL;
2501 END IF;
2502 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2503 "accepted_v" := TRUE;
2504 ELSE
2505 "rejected_v" := TRUE;
2506 END IF;
2507 END IF;
2508 END IF;
2509 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "accepted_v" THEN
2510 IF coalesce(OLD."accepted", FALSE) = TRUE THEN
2511 SELECT * INTO "initiative_row" FROM "initiative"
2512 WHERE "id" = OLD."initiative_id" FOR SHARE;
2513 IF "initiative_row"."id" NOTNULL THEN
2514 SELECT * INTO "issue_row" FROM "issue"
2515 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2516 SELECT * INTO "area_row" FROM "area"
2517 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2518 INSERT INTO "event" (
2519 "event", "member_id",
2520 "unit_id", "area_id", "policy_id", "issue_id", "state",
2521 "initiative_id", "boolean_value"
2522 ) VALUES (
2523 'initiator', OLD."member_id",
2524 "area_row"."unit_id", "issue_row"."area_id",
2525 "issue_row"."policy_id",
2526 "issue_row"."id", "issue_row"."state",
2527 OLD."initiative_id", FALSE
2528 );
2529 END IF;
2530 END IF;
2531 END IF;
2532 IF TG_OP = 'UPDATE' AND NOT "rejected_v" THEN
2533 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2534 SELECT * INTO "initiative_row" FROM "initiative"
2535 WHERE "id" = NEW."initiative_id" FOR SHARE;
2536 SELECT * INTO "issue_row" FROM "issue"
2537 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2538 SELECT * INTO "area_row" FROM "area"
2539 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2540 INSERT INTO "event" (
2541 "event", "member_id",
2542 "unit_id", "area_id", "policy_id", "issue_id", "state",
2543 "initiative_id", "boolean_value"
2544 ) VALUES (
2545 'initiator', NEW."member_id",
2546 "area_row"."unit_id", "issue_row"."area_id",
2547 "issue_row"."policy_id",
2548 "issue_row"."id", "issue_row"."state",
2549 NEW."initiative_id", TRUE
2550 );
2551 END IF;
2552 END IF;
2553 RETURN NULL;
2554 END;
2555 $$;
2557 CREATE TRIGGER "write_event_initiator"
2558 AFTER UPDATE OR DELETE ON "initiator" FOR EACH ROW EXECUTE PROCEDURE
2559 "write_event_initiator_trigger"();
2561 COMMENT ON FUNCTION "write_event_initiator_trigger"() IS 'Implementation of trigger "write_event_initiator" on table "initiator"';
2562 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)';
2565 CREATE FUNCTION "write_event_support_trigger"()
2566 RETURNS TRIGGER
2567 LANGUAGE 'plpgsql' VOLATILE AS $$
2568 DECLARE
2569 "issue_row" "issue"%ROWTYPE;
2570 "area_row" "area"%ROWTYPE;
2571 BEGIN
2572 IF TG_OP = 'UPDATE' THEN
2573 IF
2574 OLD."initiative_id" = NEW."initiative_id" AND
2575 OLD."member_id" = NEW."member_id"
2576 THEN
2577 IF OLD."draft_id" != NEW."draft_id" THEN
2578 SELECT * INTO "issue_row" FROM "issue"
2579 WHERE "id" = NEW."issue_id" FOR SHARE;
2580 SELECT * INTO "area_row" FROM "area"
2581 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2582 INSERT INTO "event" (
2583 "event", "member_id",
2584 "unit_id", "area_id", "policy_id", "issue_id", "state",
2585 "initiative_id", "draft_id"
2586 ) VALUES (
2587 'support_updated', NEW."member_id",
2588 "area_row"."unit_id", "issue_row"."area_id",
2589 "issue_row"."policy_id",
2590 "issue_row"."id", "issue_row"."state",
2591 NEW."initiative_id", NEW."draft_id"
2592 );
2593 END IF;
2594 RETURN NULL;
2595 END IF;
2596 END IF;
2597 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2598 IF EXISTS (
2599 SELECT NULL FROM "initiative" WHERE "id" = OLD."initiative_id"
2600 FOR SHARE
2601 ) THEN
2602 SELECT * INTO "issue_row" FROM "issue"
2603 WHERE "id" = OLD."issue_id" FOR SHARE;
2604 SELECT * INTO "area_row" FROM "area"
2605 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2606 INSERT INTO "event" (
2607 "event", "member_id",
2608 "unit_id", "area_id", "policy_id", "issue_id", "state",
2609 "initiative_id", "boolean_value"
2610 ) VALUES (
2611 'support', OLD."member_id",
2612 "area_row"."unit_id", "issue_row"."area_id",
2613 "issue_row"."policy_id",
2614 "issue_row"."id", "issue_row"."state",
2615 OLD."initiative_id", FALSE
2616 );
2617 END IF;
2618 END IF;
2619 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2620 SELECT * INTO "issue_row" FROM "issue"
2621 WHERE "id" = NEW."issue_id" FOR SHARE;
2622 SELECT * INTO "area_row" FROM "area"
2623 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2624 INSERT INTO "event" (
2625 "event", "member_id",
2626 "unit_id", "area_id", "policy_id", "issue_id", "state",
2627 "initiative_id", "draft_id", "boolean_value"
2628 ) VALUES (
2629 'support', NEW."member_id",
2630 "area_row"."unit_id", "issue_row"."area_id",
2631 "issue_row"."policy_id",
2632 "issue_row"."id", "issue_row"."state",
2633 NEW."initiative_id", NEW."draft_id", TRUE
2634 );
2635 END IF;
2636 RETURN NULL;
2637 END;
2638 $$;
2640 CREATE TRIGGER "write_event_support"
2641 AFTER INSERT OR UPDATE OR DELETE ON "supporter" FOR EACH ROW EXECUTE PROCEDURE
2642 "write_event_support_trigger"();
2644 COMMENT ON FUNCTION "write_event_support_trigger"() IS 'Implementation of trigger "write_event_support" on table "supporter"';
2645 COMMENT ON TRIGGER "write_event_support" ON "supporter" IS 'Create entry in "event" table when adding, updating, or removing support';
2648 CREATE FUNCTION "write_event_suggestion_rated_trigger"()
2649 RETURNS TRIGGER
2650 LANGUAGE 'plpgsql' VOLATILE AS $$
2651 DECLARE
2652 "same_pkey_v" BOOLEAN = FALSE;
2653 "initiative_row" "initiative"%ROWTYPE;
2654 "issue_row" "issue"%ROWTYPE;
2655 "area_row" "area"%ROWTYPE;
2656 BEGIN
2657 IF TG_OP = 'UPDATE' THEN
2658 IF
2659 OLD."suggestion_id" = NEW."suggestion_id" AND
2660 OLD."member_id" = NEW."member_id"
2661 THEN
2662 IF
2663 OLD."degree" = NEW."degree" AND
2664 OLD."fulfilled" = NEW."fulfilled"
2665 THEN
2666 RETURN NULL;
2667 END IF;
2668 "same_pkey_v" := TRUE;
2669 END IF;
2670 END IF;
2671 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "same_pkey_v" THEN
2672 IF EXISTS (
2673 SELECT NULL FROM "suggestion" WHERE "id" = OLD."suggestion_id"
2674 FOR SHARE
2675 ) THEN
2676 SELECT * INTO "initiative_row" FROM "initiative"
2677 WHERE "id" = OLD."initiative_id" FOR SHARE;
2678 SELECT * INTO "issue_row" FROM "issue"
2679 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2680 SELECT * INTO "area_row" FROM "area"
2681 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2682 INSERT INTO "event" (
2683 "event", "member_id",
2684 "unit_id", "area_id", "policy_id", "issue_id", "state",
2685 "initiative_id", "suggestion_id",
2686 "boolean_value", "numeric_value"
2687 ) VALUES (
2688 'suggestion_rated', OLD."member_id",
2689 "area_row"."unit_id", "issue_row"."area_id",
2690 "issue_row"."policy_id",
2691 "initiative_row"."issue_id", "issue_row"."state",
2692 OLD."initiative_id", OLD."suggestion_id",
2693 NULL, 0
2694 );
2695 END IF;
2696 END IF;
2697 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2698 SELECT * INTO "initiative_row" FROM "initiative"
2699 WHERE "id" = NEW."initiative_id" FOR SHARE;
2700 SELECT * INTO "issue_row" FROM "issue"
2701 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2702 SELECT * INTO "area_row" FROM "area"
2703 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2704 INSERT INTO "event" (
2705 "event", "member_id",
2706 "unit_id", "area_id", "policy_id", "issue_id", "state",
2707 "initiative_id", "suggestion_id",
2708 "boolean_value", "numeric_value"
2709 ) VALUES (
2710 'suggestion_rated', NEW."member_id",
2711 "area_row"."unit_id", "issue_row"."area_id",
2712 "issue_row"."policy_id",
2713 "initiative_row"."issue_id", "issue_row"."state",
2714 NEW."initiative_id", NEW."suggestion_id",
2715 NEW."fulfilled", NEW."degree"
2716 );
2717 END IF;
2718 RETURN NULL;
2719 END;
2720 $$;
2722 CREATE TRIGGER "write_event_suggestion_rated"
2723 AFTER INSERT OR UPDATE OR DELETE ON "opinion" FOR EACH ROW EXECUTE PROCEDURE
2724 "write_event_suggestion_rated_trigger"();
2726 COMMENT ON FUNCTION "write_event_suggestion_rated_trigger"() IS 'Implementation of trigger "write_event_suggestion_rated" on table "opinion"';
2727 COMMENT ON TRIGGER "write_event_suggestion_rated" ON "opinion" IS 'Create entry in "event" table when adding, updating, or removing support';
2730 CREATE FUNCTION "write_event_delegation_trigger"()
2731 RETURNS TRIGGER
2732 LANGUAGE 'plpgsql' VOLATILE AS $$
2733 DECLARE
2734 "issue_row" "issue"%ROWTYPE;
2735 "area_row" "area"%ROWTYPE;
2736 BEGIN
2737 IF TG_OP = 'DELETE' THEN
2738 IF EXISTS (
2739 SELECT NULL FROM "member" WHERE "id" = OLD."truster_id"
2740 ) AND (CASE OLD."scope"
2741 WHEN 'unit'::"delegation_scope" THEN EXISTS (
2742 SELECT NULL FROM "unit" WHERE "id" = OLD."unit_id"
2744 WHEN 'area'::"delegation_scope" THEN EXISTS (
2745 SELECT NULL FROM "area" WHERE "id" = OLD."area_id"
2747 WHEN 'issue'::"delegation_scope" THEN EXISTS (
2748 SELECT NULL FROM "issue" WHERE "id" = OLD."issue_id"
2750 END) THEN
2751 SELECT * INTO "issue_row" FROM "issue"
2752 WHERE "id" = OLD."issue_id" FOR SHARE;
2753 SELECT * INTO "area_row" FROM "area"
2754 WHERE "id" = COALESCE(OLD."area_id", "issue_row"."area_id")
2755 FOR SHARE;
2756 INSERT INTO "event" (
2757 "event", "member_id", "scope",
2758 "unit_id", "area_id", "issue_id", "state",
2759 "boolean_value"
2760 ) VALUES (
2761 'delegation', OLD."truster_id", OLD."scope",
2762 COALESCE(OLD."unit_id", "area_row"."unit_id"), "area_row"."id",
2763 OLD."issue_id", "issue_row"."state",
2764 FALSE
2765 );
2766 END IF;
2767 ELSE
2768 SELECT * INTO "issue_row" FROM "issue"
2769 WHERE "id" = NEW."issue_id" FOR SHARE;
2770 SELECT * INTO "area_row" FROM "area"
2771 WHERE "id" = COALESCE(NEW."area_id", "issue_row"."area_id")
2772 FOR SHARE;
2773 INSERT INTO "event" (
2774 "event", "member_id", "other_member_id", "scope",
2775 "unit_id", "area_id", "issue_id", "state",
2776 "boolean_value"
2777 ) VALUES (
2778 'delegation', NEW."truster_id", NEW."trustee_id", NEW."scope",
2779 COALESCE(NEW."unit_id", "area_row"."unit_id"), "area_row"."id",
2780 NEW."issue_id", "issue_row"."state",
2781 TRUE
2782 );
2783 END IF;
2784 RETURN NULL;
2785 END;
2786 $$;
2788 CREATE TRIGGER "write_event_delegation"
2789 AFTER INSERT OR UPDATE OR DELETE ON "delegation" FOR EACH ROW EXECUTE PROCEDURE
2790 "write_event_delegation_trigger"();
2792 COMMENT ON FUNCTION "write_event_delegation_trigger"() IS 'Implementation of trigger "write_event_delegation" on table "delegation"';
2793 COMMENT ON TRIGGER "write_event_delegation" ON "delegation" IS 'Create entry in "event" table when adding, updating, or removing a delegation';
2796 CREATE FUNCTION "write_event_contact_trigger"()
2797 RETURNS TRIGGER
2798 LANGUAGE 'plpgsql' VOLATILE AS $$
2799 BEGIN
2800 IF TG_OP = 'UPDATE' THEN
2801 IF
2802 OLD."member_id" = NEW."member_id" AND
2803 OLD."other_member_id" = NEW."other_member_id" AND
2804 OLD."public" = NEW."public"
2805 THEN
2806 RETURN NULL;
2807 END IF;
2808 END IF;
2809 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2810 IF OLD."public" THEN
2811 IF EXISTS (
2812 SELECT NULL FROM "member" WHERE "id" = OLD."member_id"
2813 FOR SHARE
2814 ) AND EXISTS (
2815 SELECT NULL FROM "member" WHERE "id" = OLD."other_member_id"
2816 FOR SHARE
2817 ) THEN
2818 INSERT INTO "event" (
2819 "event", "member_id", "other_member_id", "boolean_value"
2820 ) VALUES (
2821 'contact', OLD."member_id", OLD."other_member_id", FALSE
2822 );
2823 END IF;
2824 END IF;
2825 END IF;
2826 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2827 IF NEW."public" THEN
2828 INSERT INTO "event" (
2829 "event", "member_id", "other_member_id", "boolean_value"
2830 ) VALUES (
2831 'contact', NEW."member_id", NEW."other_member_id", TRUE
2832 );
2833 END IF;
2834 END IF;
2835 RETURN NULL;
2836 END;
2837 $$;
2839 CREATE TRIGGER "write_event_contact"
2840 AFTER INSERT OR UPDATE OR DELETE ON "contact" FOR EACH ROW EXECUTE PROCEDURE
2841 "write_event_contact_trigger"();
2843 COMMENT ON FUNCTION "write_event_contact_trigger"() IS 'Implementation of trigger "write_event_contact" on table "contact"';
2844 COMMENT ON TRIGGER "write_event_contact" ON "contact" IS 'Create entry in "event" table when adding or removing public contacts';
2847 CREATE FUNCTION "write_event_posting_trigger"()
2848 RETURNS TRIGGER
2849 LANGUAGE 'plpgsql' VOLATILE AS $$
2850 BEGIN
2851 INSERT INTO "event" (
2852 "event", "posting_id", "member_id",
2853 "unit_id", "area_id", "policy_id",
2854 "issue_id", "initiative_id", "suggestion_id"
2855 ) VALUES (
2856 'posting_created', NEW."id", NEW."author_id",
2857 NEW."unit_id", NEW."area_id", NEW."policy_id",
2858 NEW."issue_id", NEW."initiative_id", NEW."suggestion_id"
2859 );
2860 RETURN NULL;
2861 END;
2862 $$;
2864 CREATE TRIGGER "write_event_posting"
2865 AFTER INSERT ON "posting" FOR EACH ROW EXECUTE PROCEDURE
2866 "write_event_posting_trigger"();
2868 COMMENT ON FUNCTION "write_event_posting_trigger"() IS 'Implementation of trigger "write_event_posting" on table "posting"';
2869 COMMENT ON TRIGGER "write_event_posting" ON "posting" IS 'Create entry in "event" table when creating a new posting';
2872 CREATE FUNCTION "send_event_notify_trigger"()
2873 RETURNS TRIGGER
2874 LANGUAGE 'plpgsql' VOLATILE AS $$
2875 BEGIN
2876 EXECUTE 'NOTIFY "event", ''' || NEW."event" || '''';
2877 RETURN NULL;
2878 END;
2879 $$;
2881 CREATE TRIGGER "send_notify"
2882 AFTER INSERT OR UPDATE ON "event" FOR EACH ROW EXECUTE PROCEDURE
2883 "send_event_notify_trigger"();
2887 ----------------------------
2888 -- Additional constraints --
2889 ----------------------------
2892 CREATE FUNCTION "delete_extended_scope_tokens_trigger"()
2893 RETURNS TRIGGER
2894 LANGUAGE 'plpgsql' VOLATILE AS $$
2895 DECLARE
2896 "system_application_row" "system_application"%ROWTYPE;
2897 BEGIN
2898 IF OLD."system_application_id" NOTNULL THEN
2899 SELECT * FROM "system_application" INTO "system_application_row"
2900 WHERE "id" = OLD."system_application_id";
2901 DELETE FROM "token"
2902 WHERE "member_id" = OLD."member_id"
2903 AND "system_application_id" = OLD."system_application_id"
2904 AND NOT COALESCE(
2905 regexp_split_to_array("scope", E'\\s+') <@
2906 regexp_split_to_array(
2907 "system_application_row"."automatic_scope", E'\\s+'
2908 ),
2909 FALSE
2910 );
2911 END IF;
2912 RETURN OLD;
2913 END;
2914 $$;
2916 CREATE TRIGGER "delete_extended_scope_tokens"
2917 BEFORE DELETE ON "member_application" FOR EACH ROW EXECUTE PROCEDURE
2918 "delete_extended_scope_tokens_trigger"();
2921 CREATE FUNCTION "detach_token_from_session_trigger"()
2922 RETURNS TRIGGER
2923 LANGUAGE 'plpgsql' VOLATILE AS $$
2924 BEGIN
2925 UPDATE "token" SET "session_id" = NULL
2926 WHERE "session_id" = OLD."id";
2927 RETURN OLD;
2928 END;
2929 $$;
2931 CREATE TRIGGER "detach_token_from_session"
2932 BEFORE DELETE ON "session" FOR EACH ROW EXECUTE PROCEDURE
2933 "detach_token_from_session_trigger"();
2936 CREATE FUNCTION "delete_non_detached_scope_with_session_trigger"()
2937 RETURNS TRIGGER
2938 LANGUAGE 'plpgsql' VOLATILE AS $$
2939 BEGIN
2940 IF NEW."session_id" ISNULL THEN
2941 SELECT coalesce(string_agg("element", ' '), '') INTO NEW."scope"
2942 FROM unnest(regexp_split_to_array(NEW."scope", E'\\s+')) AS "element"
2943 WHERE "element" LIKE '%_detached';
2944 END IF;
2945 RETURN NEW;
2946 END;
2947 $$;
2949 CREATE TRIGGER "delete_non_detached_scope_with_session"
2950 BEFORE INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2951 "delete_non_detached_scope_with_session_trigger"();
2954 CREATE FUNCTION "delete_token_with_empty_scope_trigger"()
2955 RETURNS TRIGGER
2956 LANGUAGE 'plpgsql' VOLATILE AS $$
2957 BEGIN
2958 IF NEW."scope" = '' THEN
2959 DELETE FROM "token" WHERE "id" = NEW."id";
2960 END IF;
2961 RETURN NULL;
2962 END;
2963 $$;
2965 CREATE TRIGGER "delete_token_with_empty_scope"
2966 AFTER INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2967 "delete_token_with_empty_scope_trigger"();
2970 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
2971 RETURNS TRIGGER
2972 LANGUAGE 'plpgsql' VOLATILE AS $$
2973 BEGIN
2974 IF NOT EXISTS (
2975 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
2976 ) THEN
2977 RAISE EXCEPTION 'Cannot create issue without an initial initiative.' USING
2978 ERRCODE = 'integrity_constraint_violation',
2979 HINT = 'Create issue, initiative, and draft within the same transaction.';
2980 END IF;
2981 RETURN NULL;
2982 END;
2983 $$;
2985 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
2986 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
2987 FOR EACH ROW EXECUTE PROCEDURE
2988 "issue_requires_first_initiative_trigger"();
2990 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
2991 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
2994 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
2995 RETURNS TRIGGER
2996 LANGUAGE 'plpgsql' VOLATILE AS $$
2997 DECLARE
2998 "reference_lost" BOOLEAN;
2999 BEGIN
3000 IF TG_OP = 'DELETE' THEN
3001 "reference_lost" := TRUE;
3002 ELSE
3003 "reference_lost" := NEW."issue_id" != OLD."issue_id";
3004 END IF;
3005 IF
3006 "reference_lost" AND NOT EXISTS (
3007 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
3009 THEN
3010 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
3011 END IF;
3012 RETURN NULL;
3013 END;
3014 $$;
3016 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
3017 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
3018 FOR EACH ROW EXECUTE PROCEDURE
3019 "last_initiative_deletes_issue_trigger"();
3021 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
3022 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
3025 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
3026 RETURNS TRIGGER
3027 LANGUAGE 'plpgsql' VOLATILE AS $$
3028 BEGIN
3029 IF NOT EXISTS (
3030 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
3031 ) THEN
3032 RAISE EXCEPTION 'Cannot create initiative without an initial draft.' USING
3033 ERRCODE = 'integrity_constraint_violation',
3034 HINT = 'Create issue, initiative and draft within the same transaction.';
3035 END IF;
3036 RETURN NULL;
3037 END;
3038 $$;
3040 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
3041 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
3042 FOR EACH ROW EXECUTE PROCEDURE
3043 "initiative_requires_first_draft_trigger"();
3045 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
3046 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
3049 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
3050 RETURNS TRIGGER
3051 LANGUAGE 'plpgsql' VOLATILE AS $$
3052 DECLARE
3053 "reference_lost" BOOLEAN;
3054 BEGIN
3055 IF TG_OP = 'DELETE' THEN
3056 "reference_lost" := TRUE;
3057 ELSE
3058 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
3059 END IF;
3060 IF
3061 "reference_lost" AND NOT EXISTS (
3062 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
3064 THEN
3065 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
3066 END IF;
3067 RETURN NULL;
3068 END;
3069 $$;
3071 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
3072 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
3073 FOR EACH ROW EXECUTE PROCEDURE
3074 "last_draft_deletes_initiative_trigger"();
3076 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
3077 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
3080 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
3081 RETURNS TRIGGER
3082 LANGUAGE 'plpgsql' VOLATILE AS $$
3083 BEGIN
3084 IF NOT EXISTS (
3085 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
3086 ) THEN
3087 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.' USING
3088 ERRCODE = 'integrity_constraint_violation',
3089 HINT = 'Create suggestion and opinion within the same transaction.';
3090 END IF;
3091 RETURN NULL;
3092 END;
3093 $$;
3095 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
3096 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
3097 FOR EACH ROW EXECUTE PROCEDURE
3098 "suggestion_requires_first_opinion_trigger"();
3100 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
3101 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
3104 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
3105 RETURNS TRIGGER
3106 LANGUAGE 'plpgsql' VOLATILE AS $$
3107 DECLARE
3108 "reference_lost" BOOLEAN;
3109 BEGIN
3110 IF TG_OP = 'DELETE' THEN
3111 "reference_lost" := TRUE;
3112 ELSE
3113 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
3114 END IF;
3115 IF
3116 "reference_lost" AND NOT EXISTS (
3117 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
3119 THEN
3120 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
3121 END IF;
3122 RETURN NULL;
3123 END;
3124 $$;
3126 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
3127 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
3128 FOR EACH ROW EXECUTE PROCEDURE
3129 "last_opinion_deletes_suggestion_trigger"();
3131 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
3132 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
3135 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
3136 RETURNS TRIGGER
3137 LANGUAGE 'plpgsql' VOLATILE AS $$
3138 BEGIN
3139 DELETE FROM "direct_voter"
3140 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
3141 RETURN NULL;
3142 END;
3143 $$;
3145 CREATE TRIGGER "non_voter_deletes_direct_voter"
3146 AFTER INSERT OR UPDATE ON "non_voter"
3147 FOR EACH ROW EXECUTE PROCEDURE
3148 "non_voter_deletes_direct_voter_trigger"();
3150 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
3151 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")';
3154 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
3155 RETURNS TRIGGER
3156 LANGUAGE 'plpgsql' VOLATILE AS $$
3157 BEGIN
3158 DELETE FROM "non_voter"
3159 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
3160 RETURN NULL;
3161 END;
3162 $$;
3164 CREATE TRIGGER "direct_voter_deletes_non_voter"
3165 AFTER INSERT OR UPDATE ON "direct_voter"
3166 FOR EACH ROW EXECUTE PROCEDURE
3167 "direct_voter_deletes_non_voter_trigger"();
3169 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
3170 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")';
3173 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
3174 RETURNS TRIGGER
3175 LANGUAGE 'plpgsql' VOLATILE AS $$
3176 BEGIN
3177 IF NEW."comment" ISNULL THEN
3178 NEW."comment_changed" := NULL;
3179 NEW."formatting_engine" := NULL;
3180 END IF;
3181 RETURN NEW;
3182 END;
3183 $$;
3185 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
3186 BEFORE INSERT OR UPDATE ON "direct_voter"
3187 FOR EACH ROW EXECUTE PROCEDURE
3188 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
3190 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"';
3191 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.';
3194 CREATE FUNCTION "file_requires_reference_trigger"()
3195 RETURNS TRIGGER
3196 LANGUAGE 'plpgsql' VOLATILE AS $$
3197 BEGIN
3198 IF NOT EXISTS (
3199 SELECT NULL FROM "draft_attachment" WHERE "file_id" = NEW."id"
3200 ) THEN
3201 RAISE EXCEPTION 'Cannot create an unreferenced file.' USING
3202 ERRCODE = 'integrity_constraint_violation',
3203 HINT = 'Create file and its reference in another table within the same transaction.';
3204 END IF;
3205 RETURN NULL;
3206 END;
3207 $$;
3209 CREATE CONSTRAINT TRIGGER "file_requires_reference"
3210 AFTER INSERT OR UPDATE ON "file" DEFERRABLE INITIALLY DEFERRED
3211 FOR EACH ROW EXECUTE PROCEDURE
3212 "file_requires_reference_trigger"();
3214 COMMENT ON FUNCTION "file_requires_reference_trigger"() IS 'Implementation of trigger "file_requires_reference" on table "file"';
3215 COMMENT ON TRIGGER "file_requires_reference" ON "file" IS 'Ensure that files are always referenced';
3218 CREATE FUNCTION "last_reference_deletes_file_trigger"()
3219 RETURNS TRIGGER
3220 LANGUAGE 'plpgsql' VOLATILE AS $$
3221 DECLARE
3222 "reference_lost" BOOLEAN;
3223 BEGIN
3224 IF TG_OP = 'DELETE' THEN
3225 "reference_lost" := TRUE;
3226 ELSE
3227 "reference_lost" := NEW."file_id" != OLD."file_id";
3228 END IF;
3229 IF
3230 "reference_lost" AND NOT EXISTS (
3231 SELECT NULL FROM "draft_attachment" WHERE "file_id" = OLD."file_id"
3233 THEN
3234 DELETE FROM "file" WHERE "id" = OLD."file_id";
3235 END IF;
3236 RETURN NULL;
3237 END;
3238 $$;
3240 CREATE CONSTRAINT TRIGGER "last_reference_deletes_file"
3241 AFTER UPDATE OR DELETE ON "draft_attachment" DEFERRABLE INITIALLY DEFERRED
3242 FOR EACH ROW EXECUTE PROCEDURE
3243 "last_reference_deletes_file_trigger"();
3245 COMMENT ON FUNCTION "last_reference_deletes_file_trigger"() IS 'Implementation of trigger "last_reference_deletes_file" on table "draft_attachment"';
3246 COMMENT ON TRIGGER "last_reference_deletes_file" ON "draft_attachment" IS 'Removing the last reference to a file deletes the file';
3250 ---------------------------------
3251 -- Delete incomplete snapshots --
3252 ---------------------------------
3255 CREATE FUNCTION "delete_snapshot_on_partial_delete_trigger"()
3256 RETURNS TRIGGER
3257 LANGUAGE 'plpgsql' VOLATILE AS $$
3258 BEGIN
3259 IF TG_OP = 'UPDATE' THEN
3260 IF
3261 OLD."snapshot_id" = NEW."snapshot_id" AND
3262 OLD."issue_id" = NEW."issue_id"
3263 THEN
3264 RETURN NULL;
3265 END IF;
3266 END IF;
3267 DELETE FROM "snapshot" WHERE "id" = OLD."snapshot_id";
3268 RETURN NULL;
3269 END;
3270 $$;
3272 CREATE TRIGGER "delete_snapshot_on_partial_delete"
3273 AFTER UPDATE OR DELETE ON "snapshot_issue"
3274 FOR EACH ROW EXECUTE PROCEDURE
3275 "delete_snapshot_on_partial_delete_trigger"();
3277 COMMENT ON FUNCTION "delete_snapshot_on_partial_delete_trigger"() IS 'Implementation of trigger "delete_snapshot_on_partial_delete" on table "snapshot_issue"';
3278 COMMENT ON TRIGGER "delete_snapshot_on_partial_delete" ON "snapshot_issue" IS 'Deletes whole snapshot if one issue is deleted from the snapshot';
3282 ---------------------------------------------------------------
3283 -- Ensure that votes are not modified when issues are closed --
3284 ---------------------------------------------------------------
3286 -- NOTE: Frontends should ensure this anyway, but in case of programming
3287 -- errors the following triggers ensure data integrity.
3290 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
3291 RETURNS TRIGGER
3292 LANGUAGE 'plpgsql' VOLATILE AS $$
3293 DECLARE
3294 "issue_id_v" "issue"."id"%TYPE;
3295 "issue_row" "issue"%ROWTYPE;
3296 BEGIN
3297 IF EXISTS (
3298 SELECT NULL FROM "temporary_transaction_data"
3299 WHERE "txid" = txid_current()
3300 AND "key" = 'override_protection_triggers'
3301 AND "value" = TRUE::TEXT
3302 ) THEN
3303 RETURN NULL;
3304 END IF;
3305 IF TG_OP = 'DELETE' THEN
3306 "issue_id_v" := OLD."issue_id";
3307 ELSE
3308 "issue_id_v" := NEW."issue_id";
3309 END IF;
3310 SELECT INTO "issue_row" * FROM "issue"
3311 WHERE "id" = "issue_id_v" FOR SHARE;
3312 IF (
3313 "issue_row"."closed" NOTNULL OR (
3314 "issue_row"."state" = 'voting' AND
3315 "issue_row"."phase_finished" NOTNULL
3317 ) THEN
3318 IF
3319 TG_RELID = 'direct_voter'::regclass AND
3320 TG_OP = 'UPDATE'
3321 THEN
3322 IF
3323 OLD."issue_id" = NEW."issue_id" AND
3324 OLD."member_id" = NEW."member_id" AND
3325 OLD."weight" = NEW."weight"
3326 THEN
3327 RETURN NULL; -- allows changing of voter comment
3328 END IF;
3329 END IF;
3330 RAISE EXCEPTION 'Tried to modify data after voting has been closed.' USING
3331 ERRCODE = 'integrity_constraint_violation';
3332 END IF;
3333 RETURN NULL;
3334 END;
3335 $$;
3337 CREATE TRIGGER "forbid_changes_on_closed_issue"
3338 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
3339 FOR EACH ROW EXECUTE PROCEDURE
3340 "forbid_changes_on_closed_issue_trigger"();
3342 CREATE TRIGGER "forbid_changes_on_closed_issue"
3343 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
3344 FOR EACH ROW EXECUTE PROCEDURE
3345 "forbid_changes_on_closed_issue_trigger"();
3347 CREATE TRIGGER "forbid_changes_on_closed_issue"
3348 AFTER INSERT OR UPDATE OR DELETE ON "vote"
3349 FOR EACH ROW EXECUTE PROCEDURE
3350 "forbid_changes_on_closed_issue_trigger"();
3352 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"';
3353 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';
3354 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';
3355 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';
3359 --------------------------------------------------------------------
3360 -- Auto-retrieval of fields only needed for referential integrity --
3361 --------------------------------------------------------------------
3364 CREATE FUNCTION "autofill_issue_id_trigger"()
3365 RETURNS TRIGGER
3366 LANGUAGE 'plpgsql' VOLATILE AS $$
3367 BEGIN
3368 IF NEW."issue_id" ISNULL THEN
3369 SELECT "issue_id" INTO NEW."issue_id"
3370 FROM "initiative" WHERE "id" = NEW."initiative_id";
3371 END IF;
3372 RETURN NEW;
3373 END;
3374 $$;
3376 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
3377 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3379 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
3380 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3382 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
3383 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
3384 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
3387 CREATE FUNCTION "autofill_initiative_id_trigger"()
3388 RETURNS TRIGGER
3389 LANGUAGE 'plpgsql' VOLATILE AS $$
3390 BEGIN
3391 IF NEW."initiative_id" ISNULL THEN
3392 SELECT "initiative_id" INTO NEW."initiative_id"
3393 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3394 END IF;
3395 RETURN NEW;
3396 END;
3397 $$;
3399 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
3400 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
3402 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
3403 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
3407 -------------------------------------------------------
3408 -- Automatic copying of values for indexing purposes --
3409 -------------------------------------------------------
3412 CREATE FUNCTION "copy_current_draft_data"
3413 ("initiative_id_p" "initiative"."id"%TYPE )
3414 RETURNS VOID
3415 LANGUAGE 'plpgsql' VOLATILE AS $$
3416 BEGIN
3417 PERFORM NULL FROM "initiative" WHERE "id" = "initiative_id_p"
3418 FOR UPDATE;
3419 UPDATE "initiative" SET
3420 "location" = "draft"."location",
3421 "content" = "draft"."content"
3422 FROM "current_draft" AS "draft"
3423 WHERE "initiative"."id" = "initiative_id_p"
3424 AND "draft"."initiative_id" = "initiative_id_p";
3425 END;
3426 $$;
3428 COMMENT ON FUNCTION "copy_current_draft_data"
3429 ( "initiative"."id"%TYPE )
3430 IS 'Helper function for function "copy_current_draft_data_trigger"';
3433 CREATE FUNCTION "copy_current_draft_data_trigger"()
3434 RETURNS TRIGGER
3435 LANGUAGE 'plpgsql' VOLATILE AS $$
3436 BEGIN
3437 IF TG_OP='DELETE' THEN
3438 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3439 ELSE
3440 IF TG_OP='UPDATE' THEN
3441 IF COALESCE(OLD."inititiave_id" != NEW."initiative_id", TRUE) THEN
3442 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3443 END IF;
3444 END IF;
3445 PERFORM "copy_current_draft_data"(NEW."initiative_id");
3446 END IF;
3447 RETURN NULL;
3448 END;
3449 $$;
3451 CREATE TRIGGER "copy_current_draft_data"
3452 AFTER INSERT OR UPDATE OR DELETE ON "draft"
3453 FOR EACH ROW EXECUTE PROCEDURE
3454 "copy_current_draft_data_trigger"();
3456 COMMENT ON FUNCTION "copy_current_draft_data_trigger"() IS 'Implementation of trigger "copy_current_draft_data" on table "draft"';
3457 COMMENT ON TRIGGER "copy_current_draft_data" ON "draft" IS 'Copy certain fields from most recent "draft" to "initiative"';
3461 -----------------------------------------------------
3462 -- Automatic calculation of certain default values --
3463 -----------------------------------------------------
3466 CREATE FUNCTION "copy_timings_trigger"()
3467 RETURNS TRIGGER
3468 LANGUAGE 'plpgsql' VOLATILE AS $$
3469 DECLARE
3470 "policy_row" "policy"%ROWTYPE;
3471 BEGIN
3472 SELECT * INTO "policy_row" FROM "policy"
3473 WHERE "id" = NEW."policy_id";
3474 IF NEW."min_admission_time" ISNULL THEN
3475 NEW."min_admission_time" := "policy_row"."min_admission_time";
3476 END IF;
3477 IF NEW."max_admission_time" ISNULL THEN
3478 NEW."max_admission_time" := "policy_row"."max_admission_time";
3479 END IF;
3480 IF NEW."discussion_time" ISNULL THEN
3481 NEW."discussion_time" := "policy_row"."discussion_time";
3482 END IF;
3483 IF NEW."verification_time" ISNULL THEN
3484 NEW."verification_time" := "policy_row"."verification_time";
3485 END IF;
3486 IF NEW."voting_time" ISNULL THEN
3487 NEW."voting_time" := "policy_row"."voting_time";
3488 END IF;
3489 RETURN NEW;
3490 END;
3491 $$;
3493 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
3494 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
3496 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
3497 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
3500 CREATE FUNCTION "default_for_draft_id_trigger"()
3501 RETURNS TRIGGER
3502 LANGUAGE 'plpgsql' VOLATILE AS $$
3503 BEGIN
3504 IF NEW."draft_id" ISNULL THEN
3505 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
3506 WHERE "initiative_id" = NEW."initiative_id";
3507 END IF;
3508 RETURN NEW;
3509 END;
3510 $$;
3512 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
3513 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3514 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
3515 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3517 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
3518 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';
3519 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';
3523 ----------------------------------------
3524 -- Automatic creation of dependencies --
3525 ----------------------------------------
3528 CREATE FUNCTION "autocreate_interest_trigger"()
3529 RETURNS TRIGGER
3530 LANGUAGE 'plpgsql' VOLATILE AS $$
3531 BEGIN
3532 IF NOT EXISTS (
3533 SELECT NULL FROM "initiative" JOIN "interest"
3534 ON "initiative"."issue_id" = "interest"."issue_id"
3535 WHERE "initiative"."id" = NEW."initiative_id"
3536 AND "interest"."member_id" = NEW."member_id"
3537 ) THEN
3538 BEGIN
3539 INSERT INTO "interest" ("issue_id", "member_id")
3540 SELECT "issue_id", NEW."member_id"
3541 FROM "initiative" WHERE "id" = NEW."initiative_id";
3542 EXCEPTION WHEN unique_violation THEN END;
3543 END IF;
3544 RETURN NEW;
3545 END;
3546 $$;
3548 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
3549 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
3551 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
3552 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';
3555 CREATE FUNCTION "autocreate_supporter_trigger"()
3556 RETURNS TRIGGER
3557 LANGUAGE 'plpgsql' VOLATILE AS $$
3558 BEGIN
3559 IF NOT EXISTS (
3560 SELECT NULL FROM "suggestion" JOIN "supporter"
3561 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
3562 WHERE "suggestion"."id" = NEW."suggestion_id"
3563 AND "supporter"."member_id" = NEW."member_id"
3564 ) THEN
3565 BEGIN
3566 INSERT INTO "supporter" ("initiative_id", "member_id")
3567 SELECT "initiative_id", NEW."member_id"
3568 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3569 EXCEPTION WHEN unique_violation THEN END;
3570 END IF;
3571 RETURN NEW;
3572 END;
3573 $$;
3575 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
3576 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
3578 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
3579 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.';
3583 ------------------------------------------
3584 -- Views and helper functions for views --
3585 ------------------------------------------
3588 CREATE VIEW "member_eligible_to_be_notified" AS
3589 SELECT * FROM "member"
3590 WHERE "activated" NOTNULL AND "locked" = FALSE;
3592 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")';
3595 CREATE VIEW "member_to_notify" AS
3596 SELECT * FROM "member_eligible_to_be_notified"
3597 WHERE "disable_notifications" = FALSE;
3599 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)';
3602 CREATE VIEW "follower" AS
3603 SELECT
3604 "id" AS "follower_id",
3605 ( SELECT ARRAY["member"."id"] || array_agg("contact"."other_member_id")
3606 FROM "contact"
3607 WHERE "contact"."member_id" = "member"."id" AND "contact"."following" )
3608 AS "following_ids"
3609 FROM "member";
3611 COMMENT ON VIEW "follower" IS 'Provides the contacts of each member that are being followed (including the member itself) as an array of IDs';
3614 CREATE VIEW "area_quorum" AS
3615 SELECT
3616 "area"."id" AS "area_id",
3617 ceil(
3618 "area"."quorum_standard"::FLOAT8 * "quorum_factor"::FLOAT8 ^ (
3619 coalesce(
3620 ( SELECT sum(
3621 ( extract(epoch from "area"."quorum_time")::FLOAT8 /
3622 extract(epoch from
3623 ("issue"."accepted"-"issue"."created") +
3624 "issue"."discussion_time" +
3625 "issue"."verification_time" +
3626 "issue"."voting_time"
3627 )::FLOAT8
3628 ) ^ "area"."quorum_exponent"::FLOAT8
3630 FROM "issue" JOIN "policy"
3631 ON "issue"."policy_id" = "policy"."id"
3632 WHERE "issue"."area_id" = "area"."id"
3633 AND "issue"."accepted" NOTNULL
3634 AND "issue"."closed" ISNULL
3635 AND "policy"."polling" = FALSE
3636 )::FLOAT8, 0::FLOAT8
3637 ) / "area"."quorum_issues"::FLOAT8 - 1::FLOAT8
3638 ) * CASE WHEN "area"."quorum_den" ISNULL THEN 1 ELSE (
3639 SELECT "snapshot"."population"
3640 FROM "snapshot"
3641 WHERE "snapshot"."area_id" = "area"."id"
3642 AND "snapshot"."issue_id" ISNULL
3643 ORDER BY "snapshot"."id" DESC
3644 LIMIT 1
3645 ) END / coalesce("area"."quorum_den", 1)
3647 )::INT4 AS "issue_quorum"
3648 FROM "area";
3650 COMMENT ON VIEW "area_quorum" IS 'Area-based quorum considering number of open (accepted) issues';
3653 CREATE VIEW "issue_quorum" AS
3654 SELECT DISTINCT ON ("issue_id")
3655 "issue"."id" AS "issue_id",
3656 "subquery"."issue_quorum"
3657 FROM "issue"
3658 CROSS JOIN LATERAL (
3659 SELECT "area_quorum"."issue_quorum"
3660 FROM "area_quorum" WHERE "area_quorum"."area_id" = "issue"."area_id"
3661 UNION ALL
3662 SELECT "policy"."issue_quorum"
3663 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3664 UNION ALL
3665 SELECT
3666 ceil(
3667 ("issue"."population"::INT8 * "policy"."issue_quorum_num"::INT8) /
3668 "policy"."issue_quorum_den"::FLOAT8
3669 )::INT4
3670 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3671 ) AS "subquery"
3672 ORDER BY "issue_id", "issue_quorum" DESC;
3674 COMMENT ON VIEW "issue_quorum" IS 'Effective quorum for issue admission';
3677 CREATE VIEW "area_with_unaccepted_issues" AS
3678 SELECT DISTINCT ON ("area"."id") "area".*
3679 FROM "area" JOIN "issue" ON "area"."id" = "issue"."area_id"
3680 WHERE "issue"."state" = 'admission';
3682 COMMENT ON VIEW "area_with_unaccepted_issues" IS 'All areas with unaccepted open issues (needed for issue admission system)';
3685 CREATE VIEW "issue_for_admission" AS
3686 SELECT DISTINCT ON ("issue"."area_id")
3687 "issue".*,
3688 max("initiative"."supporter_count") AS "max_supporter_count"
3689 FROM "issue"
3690 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
3691 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
3692 JOIN "area" ON "issue"."area_id" = "area"."id"
3693 WHERE "issue"."state" = 'admission'::"issue_state"
3694 AND now() >= "issue"."created" + "issue"."min_admission_time"
3695 AND "initiative"."supporter_count" >= "policy"."issue_quorum"
3696 AND "initiative"."supporter_count" * "policy"."issue_quorum_den" >=
3697 "issue"."population" * "policy"."issue_quorum_num"
3698 AND "initiative"."supporter_count" >= "area"."issue_quorum"
3699 AND "initiative"."revoked" ISNULL
3700 GROUP BY "issue"."id"
3701 ORDER BY "issue"."area_id", "max_supporter_count" DESC, "issue"."id";
3703 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';
3706 CREATE VIEW "unit_delegation" AS
3707 SELECT
3708 "unit"."id" AS "unit_id",
3709 "delegation"."id",
3710 "delegation"."truster_id",
3711 "delegation"."trustee_id",
3712 "delegation"."scope"
3713 FROM "unit"
3714 JOIN "delegation"
3715 ON "delegation"."unit_id" = "unit"."id"
3716 JOIN "member"
3717 ON "delegation"."truster_id" = "member"."id"
3718 JOIN "privilege"
3719 ON "delegation"."unit_id" = "privilege"."unit_id"
3720 AND "delegation"."truster_id" = "privilege"."member_id"
3721 WHERE "member"."active" AND "privilege"."voting_right";
3723 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
3726 CREATE VIEW "area_delegation" AS
3727 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
3728 "area"."id" AS "area_id",
3729 "delegation"."id",
3730 "delegation"."truster_id",
3731 "delegation"."trustee_id",
3732 "delegation"."scope"
3733 FROM "area"
3734 JOIN "delegation"
3735 ON "delegation"."unit_id" = "area"."unit_id"
3736 OR "delegation"."area_id" = "area"."id"
3737 JOIN "member"
3738 ON "delegation"."truster_id" = "member"."id"
3739 JOIN "privilege"
3740 ON "area"."unit_id" = "privilege"."unit_id"
3741 AND "delegation"."truster_id" = "privilege"."member_id"
3742 WHERE "member"."active" AND "privilege"."voting_right"
3743 ORDER BY
3744 "area"."id",
3745 "delegation"."truster_id",
3746 "delegation"."scope" DESC;
3748 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
3751 CREATE VIEW "issue_delegation" AS
3752 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
3753 "issue"."id" AS "issue_id",
3754 "delegation"."id",
3755 "delegation"."truster_id",
3756 "delegation"."trustee_id",
3757 COALESCE("issue_privilege"."weight", "privilege"."weight") AS "weight",
3758 "delegation"."scope"
3759 FROM "issue"
3760 JOIN "area"
3761 ON "area"."id" = "issue"."area_id"
3762 JOIN "delegation"
3763 ON "delegation"."unit_id" = "area"."unit_id"
3764 OR "delegation"."area_id" = "area"."id"
3765 OR "delegation"."issue_id" = "issue"."id"
3766 JOIN "member"
3767 ON "delegation"."truster_id" = "member"."id"
3768 LEFT JOIN "privilege"
3769 ON "area"."unit_id" = "privilege"."unit_id"
3770 AND "delegation"."truster_id" = "privilege"."member_id"
3771 LEFT JOIN "issue_privilege"
3772 ON "issue"."id" = "issue_privilege"."issue_id"
3773 AND "delegation"."truster_id" = "issue_privilege"."member_id"
3774 WHERE "member"."active"
3775 AND COALESCE("issue_privilege"."voting_right", "privilege"."voting_right")
3776 ORDER BY
3777 "issue"."id",
3778 "delegation"."truster_id",
3779 "delegation"."scope" DESC;
3781 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
3784 CREATE VIEW "member_count_view" AS
3785 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
3787 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
3790 CREATE VIEW "unit_member" AS
3791 SELECT
3792 "privilege"."unit_id" AS "unit_id",
3793 "member"."id" AS "member_id",
3794 "privilege"."weight"
3795 FROM "privilege" JOIN "member" ON "member"."id" = "privilege"."member_id"
3796 WHERE "privilege"."voting_right" AND "member"."active";
3798 COMMENT ON VIEW "unit_member" IS 'Active members with voting right in a unit';
3801 CREATE VIEW "unit_member_count" AS
3802 SELECT
3803 "unit"."id" AS "unit_id",
3804 count("unit_member"."member_id") AS "member_count",
3805 sum("unit_member"."weight") AS "member_weight"
3806 FROM "unit" LEFT JOIN "unit_member"
3807 ON "unit"."id" = "unit_member"."unit_id"
3808 GROUP BY "unit"."id";
3810 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
3813 CREATE VIEW "opening_draft" AS
3814 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3815 ORDER BY "initiative_id", "id";
3817 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
3820 CREATE VIEW "current_draft" AS
3821 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3822 ORDER BY "initiative_id", "id" DESC;
3824 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
3827 CREATE VIEW "critical_opinion" AS
3828 SELECT * FROM "opinion"
3829 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
3830 OR ("degree" = -2 AND "fulfilled" = TRUE);
3832 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
3835 CREATE VIEW "issue_supporter_in_admission_state" AS
3836 SELECT
3837 "area"."unit_id",
3838 "issue"."area_id",
3839 "issue"."id" AS "issue_id",
3840 "supporter"."member_id",
3841 "direct_interest_snapshot"."weight"
3842 FROM "issue"
3843 JOIN "area" ON "area"."id" = "issue"."area_id"
3844 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
3845 JOIN "direct_interest_snapshot"
3846 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3847 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3848 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
3849 WHERE "issue"."state" = 'admission'::"issue_state";
3851 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';
3854 CREATE VIEW "initiative_suggestion_order_calculation" AS
3855 SELECT
3856 "initiative"."id" AS "initiative_id",
3857 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
3858 FROM "initiative" JOIN "issue"
3859 ON "initiative"."issue_id" = "issue"."id"
3860 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
3861 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
3863 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
3865 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';
3868 CREATE VIEW "individual_suggestion_ranking" AS
3869 SELECT
3870 "opinion"."initiative_id",
3871 "opinion"."member_id",
3872 "direct_interest_snapshot"."weight",
3873 CASE WHEN
3874 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
3875 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
3876 THEN 1 ELSE
3877 CASE WHEN
3878 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
3879 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
3880 THEN 2 ELSE
3881 CASE WHEN
3882 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
3883 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
3884 THEN 3 ELSE 4 END
3885 END
3886 END AS "preference",
3887 "opinion"."suggestion_id"
3888 FROM "opinion"
3889 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
3890 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3891 JOIN "direct_interest_snapshot"
3892 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3893 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3894 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
3896 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
3899 CREATE VIEW "battle_participant" AS
3900 SELECT "initiative"."id", "initiative"."issue_id"
3901 FROM "issue" JOIN "initiative"
3902 ON "issue"."id" = "initiative"."issue_id"
3903 WHERE "initiative"."admitted"
3904 UNION ALL
3905 SELECT NULL, "id" AS "issue_id"
3906 FROM "issue";
3908 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
3911 CREATE VIEW "battle_view" AS
3912 SELECT
3913 "issue"."id" AS "issue_id",
3914 "winning_initiative"."id" AS "winning_initiative_id",
3915 "losing_initiative"."id" AS "losing_initiative_id",
3916 sum(
3917 CASE WHEN
3918 coalesce("better_vote"."grade", 0) >
3919 coalesce("worse_vote"."grade", 0)
3920 THEN "direct_voter"."weight" ELSE 0 END
3921 ) AS "count"
3922 FROM "issue"
3923 LEFT JOIN "direct_voter"
3924 ON "issue"."id" = "direct_voter"."issue_id"
3925 JOIN "battle_participant" AS "winning_initiative"
3926 ON "issue"."id" = "winning_initiative"."issue_id"
3927 JOIN "battle_participant" AS "losing_initiative"
3928 ON "issue"."id" = "losing_initiative"."issue_id"
3929 LEFT JOIN "vote" AS "better_vote"
3930 ON "direct_voter"."member_id" = "better_vote"."member_id"
3931 AND "winning_initiative"."id" = "better_vote"."initiative_id"
3932 LEFT JOIN "vote" AS "worse_vote"
3933 ON "direct_voter"."member_id" = "worse_vote"."member_id"
3934 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
3935 WHERE "issue"."state" = 'voting'
3936 AND "issue"."phase_finished" NOTNULL
3937 AND (
3938 "winning_initiative"."id" != "losing_initiative"."id" OR
3939 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
3940 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
3941 GROUP BY
3942 "issue"."id",
3943 "winning_initiative"."id",
3944 "losing_initiative"."id";
3946 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';
3949 CREATE VIEW "expired_session" AS
3950 SELECT * FROM "session" WHERE now() > "expiry";
3952 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
3953 DELETE FROM "session" WHERE "id" = OLD."id";
3955 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
3956 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
3959 CREATE VIEW "expired_token" AS
3960 SELECT * FROM "token" WHERE now() > "expiry" AND NOT (
3961 "token_type" = 'authorization' AND "used" AND EXISTS (
3962 SELECT NULL FROM "token" AS "other"
3963 WHERE "other"."authorization_token_id" = "token"."id" ) );
3965 CREATE RULE "delete" AS ON DELETE TO "expired_token" DO INSTEAD
3966 DELETE FROM "token" WHERE "id" = OLD."id";
3968 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';
3971 CREATE VIEW "unused_snapshot" AS
3972 SELECT "snapshot".* FROM "snapshot"
3973 LEFT JOIN "issue"
3974 ON "snapshot"."id" = "issue"."latest_snapshot_id"
3975 OR "snapshot"."id" = "issue"."admission_snapshot_id"
3976 OR "snapshot"."id" = "issue"."half_freeze_snapshot_id"
3977 OR "snapshot"."id" = "issue"."full_freeze_snapshot_id"
3978 WHERE "issue"."id" ISNULL;
3980 CREATE RULE "delete" AS ON DELETE TO "unused_snapshot" DO INSTEAD
3981 DELETE FROM "snapshot" WHERE "id" = OLD."id";
3983 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)';
3986 CREATE VIEW "open_issue" AS
3987 SELECT * FROM "issue" WHERE "closed" ISNULL;
3989 COMMENT ON VIEW "open_issue" IS 'All open issues';
3992 CREATE VIEW "member_contingent" AS
3993 SELECT
3994 "member"."id" AS "member_id",
3995 "contingent"."polling",
3996 "contingent"."time_frame",
3997 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
3999 SELECT count(1) FROM "draft"
4000 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
4001 WHERE "draft"."author_id" = "member"."id"
4002 AND "initiative"."polling" = "contingent"."polling"
4003 AND "draft"."created" > now() - "contingent"."time_frame"
4004 ) + (
4005 SELECT count(1) FROM "suggestion"
4006 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
4007 WHERE "suggestion"."author_id" = "member"."id"
4008 AND "contingent"."polling" = FALSE
4009 AND "suggestion"."created" > now() - "contingent"."time_frame"
4011 ELSE NULL END AS "text_entry_count",
4012 "contingent"."text_entry_limit",
4013 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
4014 SELECT count(1) FROM "opening_draft" AS "draft"
4015 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
4016 WHERE "draft"."author_id" = "member"."id"
4017 AND "initiative"."polling" = "contingent"."polling"
4018 AND "draft"."created" > now() - "contingent"."time_frame"
4019 ) ELSE NULL END AS "initiative_count",
4020 "contingent"."initiative_limit"
4021 FROM "member" CROSS JOIN "contingent";
4023 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
4025 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
4026 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
4029 CREATE VIEW "member_contingent_left" AS
4030 SELECT
4031 "member_id",
4032 "polling",
4033 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
4034 max("initiative_limit" - "initiative_count") AS "initiatives_left"
4035 FROM "member_contingent" GROUP BY "member_id", "polling";
4037 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.';
4040 CREATE VIEW "event_for_notification" AS
4041 SELECT
4042 "member"."id" AS "recipient_id",
4043 "event".*
4044 FROM "member" CROSS JOIN "event"
4045 JOIN "issue" ON "issue"."id" = "event"."issue_id"
4046 JOIN "area" ON "area"."id" = "issue"."area_id"
4047 LEFT JOIN "privilege" ON
4048 "privilege"."member_id" = "member"."id" AND
4049 "privilege"."unit_id" = "area"."unit_id"
4050 LEFT JOIN "issue_privilege" ON
4051 "issue_privilege"."member_id" = "member"."id" AND
4052 "issue_privilege"."issue_id" = "event"."issue_id"
4053 LEFT JOIN "subscription" ON
4054 "subscription"."member_id" = "member"."id" AND
4055 "subscription"."unit_id" = "area"."unit_id"
4056 LEFT JOIN "ignored_area" ON
4057 "ignored_area"."member_id" = "member"."id" AND
4058 "ignored_area"."area_id" = "issue"."area_id"
4059 LEFT JOIN "interest" ON
4060 "interest"."member_id" = "member"."id" AND
4061 "interest"."issue_id" = "event"."issue_id"
4062 LEFT JOIN "supporter" ON
4063 "supporter"."member_id" = "member"."id" AND
4064 "supporter"."initiative_id" = "event"."initiative_id"
4065 WHERE (
4066 COALESCE("issue_privilege"."voting_right", "privilege"."voting_right") OR
4067 "subscription"."member_id" NOTNULL
4068 ) AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL)
4069 AND (
4070 "event"."event" = 'issue_state_changed'::"event_type" OR
4071 ( "event"."event" = 'initiative_revoked'::"event_type" AND
4072 "supporter"."member_id" NOTNULL ) );
4074 COMMENT ON VIEW "event_for_notification" IS 'Entries of the "event" table which are of interest for a particular notification mail recipient';
4076 COMMENT ON COLUMN "event_for_notification"."recipient_id" IS 'member_id of the recipient of a notification mail';
4079 CREATE VIEW "updated_initiative" AS
4080 SELECT
4081 "supporter"."member_id" AS "recipient_id",
4082 FALSE AS "featured",
4083 "supporter"."initiative_id"
4084 FROM "supporter"
4085 JOIN "initiative" ON "supporter"."initiative_id" = "initiative"."id"
4086 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4087 LEFT JOIN "notification_initiative_sent" AS "sent" ON
4088 "sent"."member_id" = "supporter"."member_id" AND
4089 "sent"."initiative_id" = "supporter"."initiative_id"
4090 LEFT JOIN "ignored_initiative" ON
4091 "ignored_initiative"."member_id" = "supporter"."member_id" AND
4092 "ignored_initiative"."initiative_id" = "supporter"."initiative_id"
4093 WHERE "issue"."state" IN ('admission', 'discussion')
4094 AND "initiative"."revoked" ISNULL
4095 AND "ignored_initiative"."member_id" ISNULL
4096 AND (
4097 EXISTS (
4098 SELECT NULL FROM "draft"
4099 LEFT JOIN "ignored_member" ON
4100 "ignored_member"."member_id" = "supporter"."member_id" AND
4101 "ignored_member"."other_member_id" = "draft"."author_id"
4102 WHERE "draft"."initiative_id" = "supporter"."initiative_id"
4103 AND "draft"."id" > "supporter"."draft_id"
4104 AND "ignored_member"."member_id" ISNULL
4105 ) OR EXISTS (
4106 SELECT NULL FROM "suggestion"
4107 LEFT JOIN "opinion" ON
4108 "opinion"."member_id" = "supporter"."member_id" AND
4109 "opinion"."suggestion_id" = "suggestion"."id"
4110 LEFT JOIN "ignored_member" ON
4111 "ignored_member"."member_id" = "supporter"."member_id" AND
4112 "ignored_member"."other_member_id" = "suggestion"."author_id"
4113 WHERE "suggestion"."initiative_id" = "supporter"."initiative_id"
4114 AND "opinion"."member_id" ISNULL
4115 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4116 AND "ignored_member"."member_id" ISNULL
4118 );
4120 COMMENT ON VIEW "updated_initiative" IS 'Helper view for view "updated_or_featured_initiative"';
4123 CREATE FUNCTION "featured_initiative"
4124 ( "recipient_id_p" "member"."id"%TYPE,
4125 "area_id_p" "area"."id"%TYPE )
4126 RETURNS SETOF "initiative"."id"%TYPE
4127 LANGUAGE 'plpgsql' STABLE AS $$
4128 DECLARE
4129 "counter_v" "member"."notification_counter"%TYPE;
4130 "sample_size_v" "member"."notification_sample_size"%TYPE;
4131 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
4132 "match_v" BOOLEAN;
4133 "member_id_v" "member"."id"%TYPE;
4134 "seed_v" TEXT;
4135 "initiative_id_v" "initiative"."id"%TYPE;
4136 BEGIN
4137 SELECT "notification_counter", "notification_sample_size"
4138 INTO "counter_v", "sample_size_v"
4139 FROM "member" WHERE "id" = "recipient_id_p";
4140 IF COALESCE("sample_size_v" <= 0, TRUE) THEN
4141 RETURN;
4142 END IF;
4143 "initiative_id_ary" := '{}';
4144 LOOP
4145 "match_v" := FALSE;
4146 FOR "member_id_v", "seed_v" IN
4147 SELECT * FROM (
4148 SELECT DISTINCT
4149 "supporter"."member_id",
4150 md5(
4151 "recipient_id_p" || '-' ||
4152 "counter_v" || '-' ||
4153 "area_id_p" || '-' ||
4154 "supporter"."member_id"
4155 ) AS "seed"
4156 FROM "supporter"
4157 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
4158 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4159 WHERE "supporter"."member_id" != "recipient_id_p"
4160 AND "issue"."area_id" = "area_id_p"
4161 AND "issue"."state" IN ('admission', 'discussion', 'verification')
4162 ) AS "subquery"
4163 ORDER BY "seed"
4164 LOOP
4165 SELECT "initiative"."id" INTO "initiative_id_v"
4166 FROM "initiative"
4167 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4168 JOIN "area" ON "area"."id" = "issue"."area_id"
4169 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
4170 LEFT JOIN "supporter" AS "self_support" ON
4171 "self_support"."initiative_id" = "initiative"."id" AND
4172 "self_support"."member_id" = "recipient_id_p"
4173 LEFT JOIN "privilege" ON
4174 "privilege"."member_id" = "recipient_id_p" AND
4175 "privilege"."unit_id" = "area"."unit_id"
4176 LEFT JOIN "issue_privilege" ON
4177 "privilege"."member_id" = "recipient_id_p" AND
4178 "privilege"."issue_id" = "initiative"."issue_id"
4179 LEFT JOIN "subscription" ON
4180 "subscription"."member_id" = "recipient_id_p" AND
4181 "subscription"."unit_id" = "area"."unit_id"
4182 LEFT JOIN "ignored_initiative" ON
4183 "ignored_initiative"."member_id" = "recipient_id_p" AND
4184 "ignored_initiative"."initiative_id" = "initiative"."id"
4185 WHERE "supporter"."member_id" = "member_id_v"
4186 AND "issue"."area_id" = "area_id_p"
4187 AND "issue"."state" IN ('admission', 'discussion', 'verification')
4188 AND "initiative"."revoked" ISNULL
4189 AND "self_support"."member_id" ISNULL
4190 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
4191 AND (
4192 COALESCE(
4193 "issue_privilege"."voting_right", "privilege"."voting_right"
4194 ) OR "subscription"."member_id" NOTNULL )
4195 AND "ignored_initiative"."member_id" ISNULL
4196 AND NOT EXISTS (
4197 SELECT NULL FROM "draft"
4198 JOIN "ignored_member" ON
4199 "ignored_member"."member_id" = "recipient_id_p" AND
4200 "ignored_member"."other_member_id" = "draft"."author_id"
4201 WHERE "draft"."initiative_id" = "initiative"."id"
4203 ORDER BY md5("seed_v" || '-' || "initiative"."id")
4204 LIMIT 1;
4205 IF FOUND THEN
4206 "match_v" := TRUE;
4207 RETURN NEXT "initiative_id_v";
4208 IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
4209 RETURN;
4210 END IF;
4211 "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
4212 END IF;
4213 END LOOP;
4214 EXIT WHEN NOT "match_v";
4215 END LOOP;
4216 RETURN;
4217 END;
4218 $$;
4220 COMMENT ON FUNCTION "featured_initiative"
4221 ( "recipient_id_p" "member"."id"%TYPE,
4222 "area_id_p" "area"."id"%TYPE )
4223 IS 'Helper function for view "updated_or_featured_initiative"';
4226 CREATE VIEW "updated_or_featured_initiative" AS
4227 SELECT
4228 "subquery".*,
4229 NOT EXISTS (
4230 SELECT NULL FROM "initiative" AS "better_initiative"
4231 WHERE "better_initiative"."issue_id" = "initiative"."issue_id"
4232 AND
4233 ( COALESCE("better_initiative"."supporter_count", -1),
4234 -"better_initiative"."id" ) >
4235 ( COALESCE("initiative"."supporter_count", -1),
4236 -"initiative"."id" )
4237 ) AS "leading"
4238 FROM (
4239 SELECT * FROM "updated_initiative"
4240 UNION ALL
4241 SELECT
4242 "member"."id" AS "recipient_id",
4243 TRUE AS "featured",
4244 "featured_initiative_id" AS "initiative_id"
4245 FROM "member" CROSS JOIN "area"
4246 CROSS JOIN LATERAL
4247 "featured_initiative"("member"."id", "area"."id") AS "featured_initiative_id"
4248 JOIN "initiative" ON "initiative"."id" = "featured_initiative_id"
4249 ) AS "subquery"
4250 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id";
4252 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';
4254 COMMENT ON COLUMN "updated_or_featured_initiative"."recipient_id" IS '"id" of the member who receives the notification mail';
4255 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")';
4256 COMMENT ON COLUMN "updated_or_featured_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4257 COMMENT ON COLUMN "updated_or_featured_initiative"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
4260 CREATE VIEW "leading_complement_initiative" AS
4261 SELECT * FROM (
4262 SELECT DISTINCT ON ("uf_initiative"."recipient_id", "initiative"."issue_id")
4263 "uf_initiative"."recipient_id",
4264 FALSE AS "featured",
4265 "uf_initiative"."initiative_id",
4266 TRUE AS "leading"
4267 FROM "updated_or_featured_initiative" AS "uf_initiative"
4268 JOIN "initiative" AS "uf_initiative_full" ON
4269 "uf_initiative_full"."id" = "uf_initiative"."initiative_id"
4270 JOIN "initiative" ON
4271 "initiative"."issue_id" = "uf_initiative_full"."issue_id"
4272 WHERE "initiative"."revoked" ISNULL
4273 ORDER BY
4274 "uf_initiative"."recipient_id",
4275 "initiative"."issue_id",
4276 "initiative"."supporter_count" DESC,
4277 "initiative"."id"
4278 ) AS "subquery"
4279 WHERE NOT EXISTS (
4280 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
4281 WHERE "other"."recipient_id" = "subquery"."recipient_id"
4282 AND "other"."initiative_id" = "subquery"."initiative_id"
4283 );
4285 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';
4286 COMMENT ON COLUMN "leading_complement_initiative"."featured" IS 'Always FALSE in this view';
4287 COMMENT ON COLUMN "leading_complement_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4288 COMMENT ON COLUMN "leading_complement_initiative"."leading" IS 'Always TRUE in this view';
4291 CREATE VIEW "unfiltered_initiative_for_notification" AS
4292 SELECT
4293 "subquery".*,
4294 "supporter"."member_id" NOTNULL AS "supported",
4295 CASE WHEN "supporter"."member_id" NOTNULL THEN
4296 EXISTS (
4297 SELECT NULL FROM "draft"
4298 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
4299 AND "draft"."id" > "supporter"."draft_id"
4301 ELSE
4302 EXISTS (
4303 SELECT NULL FROM "draft"
4304 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
4305 AND COALESCE("draft"."id" > "sent"."last_draft_id", TRUE)
4307 END AS "new_draft",
4308 CASE WHEN "supporter"."member_id" NOTNULL THEN
4309 ( SELECT count(1) FROM "suggestion"
4310 LEFT JOIN "opinion" ON
4311 "opinion"."member_id" = "supporter"."member_id" AND
4312 "opinion"."suggestion_id" = "suggestion"."id"
4313 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
4314 AND "opinion"."member_id" ISNULL
4315 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4317 ELSE
4318 ( SELECT count(1) FROM "suggestion"
4319 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
4320 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4322 END AS "new_suggestion_count"
4323 FROM (
4324 SELECT * FROM "updated_or_featured_initiative"
4325 UNION ALL
4326 SELECT * FROM "leading_complement_initiative"
4327 ) AS "subquery"
4328 LEFT JOIN "supporter" ON
4329 "supporter"."member_id" = "subquery"."recipient_id" AND
4330 "supporter"."initiative_id" = "subquery"."initiative_id"
4331 LEFT JOIN "notification_initiative_sent" AS "sent" ON
4332 "sent"."member_id" = "subquery"."recipient_id" AND
4333 "sent"."initiative_id" = "subquery"."initiative_id";
4335 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';
4337 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4338 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)';
4339 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")';
4342 CREATE VIEW "initiative_for_notification" AS
4343 SELECT "unfiltered1".*
4344 FROM "unfiltered_initiative_for_notification" "unfiltered1"
4345 JOIN "initiative" AS "initiative1" ON
4346 "initiative1"."id" = "unfiltered1"."initiative_id"
4347 JOIN "issue" AS "issue1" ON "issue1"."id" = "initiative1"."issue_id"
4348 WHERE EXISTS (
4349 SELECT NULL
4350 FROM "unfiltered_initiative_for_notification" "unfiltered2"
4351 JOIN "initiative" AS "initiative2" ON
4352 "initiative2"."id" = "unfiltered2"."initiative_id"
4353 JOIN "issue" AS "issue2" ON "issue2"."id" = "initiative2"."issue_id"
4354 WHERE "unfiltered1"."recipient_id" = "unfiltered2"."recipient_id"
4355 AND "issue1"."area_id" = "issue2"."area_id"
4356 AND ("unfiltered2"."new_draft" OR "unfiltered2"."new_suggestion_count" > 0 )
4357 );
4359 COMMENT ON VIEW "initiative_for_notification" IS 'Initiatives to be included in a scheduled notification mail';
4361 COMMENT ON COLUMN "initiative_for_notification"."recipient_id" IS '"id" of the member who receives the notification mail';
4362 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")';
4363 COMMENT ON COLUMN "initiative_for_notification"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4364 COMMENT ON COLUMN "initiative_for_notification"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
4365 COMMENT ON COLUMN "initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4366 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)';
4367 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")';
4370 CREATE VIEW "scheduled_notification_to_send" AS
4371 SELECT * FROM (
4372 SELECT
4373 "id" AS "recipient_id",
4374 now() - CASE WHEN "notification_dow" ISNULL THEN
4375 ( "notification_sent"::DATE + CASE
4376 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4377 THEN 0 ELSE 1 END
4378 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4379 ELSE
4380 ( "notification_sent"::DATE +
4381 ( 7 + "notification_dow" -
4382 EXTRACT(DOW FROM
4383 ( "notification_sent"::DATE + CASE
4384 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4385 THEN 0 ELSE 1 END
4386 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4387 )::INTEGER
4388 ) % 7 +
4389 CASE
4390 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4391 THEN 0 ELSE 1
4392 END
4393 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4394 END AS "pending"
4395 FROM (
4396 SELECT
4397 "id",
4398 COALESCE("notification_sent", "activated") AS "notification_sent",
4399 "notification_dow",
4400 "notification_hour"
4401 FROM "member_to_notify"
4402 WHERE "notification_hour" NOTNULL
4403 ) AS "subquery1"
4404 ) AS "subquery2"
4405 WHERE "pending" > '0'::INTERVAL;
4407 COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending';
4409 COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail';
4410 COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending';
4413 CREATE VIEW "newsletter_to_send" AS
4414 SELECT
4415 "member"."id" AS "recipient_id",
4416 "newsletter"."id" AS "newsletter_id",
4417 "newsletter"."published"
4418 FROM "newsletter" CROSS JOIN "member_eligible_to_be_notified" AS "member"
4419 LEFT JOIN "privilege" ON
4420 "privilege"."member_id" = "member"."id" AND
4421 "privilege"."unit_id" = "newsletter"."unit_id" AND
4422 "privilege"."voting_right" = TRUE
4423 LEFT JOIN "subscription" ON
4424 "subscription"."member_id" = "member"."id" AND
4425 "subscription"."unit_id" = "newsletter"."unit_id"
4426 WHERE "newsletter"."published" <= now()
4427 AND "newsletter"."sent" ISNULL
4428 AND (
4429 "member"."disable_notifications" = FALSE OR
4430 "newsletter"."include_all_members" = TRUE )
4431 AND (
4432 "newsletter"."unit_id" ISNULL OR
4433 "privilege"."member_id" NOTNULL OR
4434 "subscription"."member_id" NOTNULL );
4436 COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out';
4438 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter was supposed to be sent out (can be used for ordering)';
4442 ------------------------------------------------------
4443 -- Row set returning function for delegation chains --
4444 ------------------------------------------------------
4447 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
4448 ('first', 'intermediate', 'last', 'repetition');
4450 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
4453 CREATE TYPE "delegation_chain_row" AS (
4454 "index" INT4,
4455 "member_id" INT4,
4456 "member_valid" BOOLEAN,
4457 "participation" BOOLEAN,
4458 "overridden" BOOLEAN,
4459 "scope_in" "delegation_scope",
4460 "scope_out" "delegation_scope",
4461 "disabled_out" BOOLEAN,
4462 "loop" "delegation_chain_loop_tag" );
4464 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
4466 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
4467 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest; for area and global delegation chains: always null';
4468 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
4469 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
4470 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
4471 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
4472 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
4475 CREATE FUNCTION "delegation_chain_for_closed_issue"
4476 ( "member_id_p" "member"."id"%TYPE,
4477 "issue_id_p" "issue"."id"%TYPE )
4478 RETURNS SETOF "delegation_chain_row"
4479 LANGUAGE 'plpgsql' STABLE AS $$
4480 DECLARE
4481 "output_row" "delegation_chain_row";
4482 "direct_voter_row" "direct_voter"%ROWTYPE;
4483 "delegating_voter_row" "delegating_voter"%ROWTYPE;
4484 BEGIN
4485 "output_row"."index" := 0;
4486 "output_row"."member_id" := "member_id_p";
4487 "output_row"."member_valid" := TRUE;
4488 "output_row"."participation" := FALSE;
4489 "output_row"."overridden" := FALSE;
4490 "output_row"."disabled_out" := FALSE;
4491 LOOP
4492 SELECT INTO "direct_voter_row" * FROM "direct_voter"
4493 WHERE "issue_id" = "issue_id_p"
4494 AND "member_id" = "output_row"."member_id";
4495 IF "direct_voter_row"."member_id" NOTNULL THEN
4496 "output_row"."participation" := TRUE;
4497 "output_row"."scope_out" := NULL;
4498 "output_row"."disabled_out" := NULL;
4499 RETURN NEXT "output_row";
4500 RETURN;
4501 END IF;
4502 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
4503 WHERE "issue_id" = "issue_id_p"
4504 AND "member_id" = "output_row"."member_id";
4505 IF "delegating_voter_row"."member_id" ISNULL THEN
4506 RETURN;
4507 END IF;
4508 "output_row"."scope_out" := "delegating_voter_row"."scope";
4509 RETURN NEXT "output_row";
4510 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
4511 "output_row"."scope_in" := "output_row"."scope_out";
4512 END LOOP;
4513 END;
4514 $$;
4516 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
4517 ( "member"."id"%TYPE,
4518 "member"."id"%TYPE )
4519 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
4522 CREATE FUNCTION "delegation_chain"
4523 ( "member_id_p" "member"."id"%TYPE,
4524 "unit_id_p" "unit"."id"%TYPE,
4525 "area_id_p" "area"."id"%TYPE,
4526 "issue_id_p" "issue"."id"%TYPE,
4527 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4528 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4529 RETURNS SETOF "delegation_chain_row"
4530 LANGUAGE 'plpgsql' STABLE AS $$
4531 DECLARE
4532 "scope_v" "delegation_scope";
4533 "unit_id_v" "unit"."id"%TYPE;
4534 "area_id_v" "area"."id"%TYPE;
4535 "issue_row" "issue"%ROWTYPE;
4536 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
4537 "loop_member_id_v" "member"."id"%TYPE;
4538 "output_row" "delegation_chain_row";
4539 "output_rows" "delegation_chain_row"[];
4540 "simulate_v" BOOLEAN;
4541 "simulate_here_v" BOOLEAN;
4542 "delegation_row" "delegation"%ROWTYPE;
4543 "row_count" INT4;
4544 "i" INT4;
4545 "loop_v" BOOLEAN;
4546 BEGIN
4547 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
4548 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
4549 END IF;
4550 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
4551 "simulate_v" := TRUE;
4552 ELSE
4553 "simulate_v" := FALSE;
4554 END IF;
4555 IF
4556 "unit_id_p" NOTNULL AND
4557 "area_id_p" ISNULL AND
4558 "issue_id_p" ISNULL
4559 THEN
4560 "scope_v" := 'unit';
4561 "unit_id_v" := "unit_id_p";
4562 ELSIF
4563 "unit_id_p" ISNULL AND
4564 "area_id_p" NOTNULL AND
4565 "issue_id_p" ISNULL
4566 THEN
4567 "scope_v" := 'area';
4568 "area_id_v" := "area_id_p";
4569 SELECT "unit_id" INTO "unit_id_v"
4570 FROM "area" WHERE "id" = "area_id_v";
4571 ELSIF
4572 "unit_id_p" ISNULL AND
4573 "area_id_p" ISNULL AND
4574 "issue_id_p" NOTNULL
4575 THEN
4576 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
4577 IF "issue_row"."id" ISNULL THEN
4578 RETURN;
4579 END IF;
4580 IF "issue_row"."closed" NOTNULL THEN
4581 IF "simulate_v" THEN
4582 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
4583 END IF;
4584 FOR "output_row" IN
4585 SELECT * FROM
4586 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
4587 LOOP
4588 RETURN NEXT "output_row";
4589 END LOOP;
4590 RETURN;
4591 END IF;
4592 "scope_v" := 'issue';
4593 SELECT "area_id" INTO "area_id_v"
4594 FROM "issue" WHERE "id" = "issue_id_p";
4595 SELECT "unit_id" INTO "unit_id_v"
4596 FROM "area" WHERE "id" = "area_id_v";
4597 ELSE
4598 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
4599 END IF;
4600 "visited_member_ids" := '{}';
4601 "loop_member_id_v" := NULL;
4602 "output_rows" := '{}';
4603 "output_row"."index" := 0;
4604 "output_row"."member_id" := "member_id_p";
4605 "output_row"."member_valid" := TRUE;
4606 "output_row"."participation" := FALSE;
4607 "output_row"."overridden" := FALSE;
4608 "output_row"."disabled_out" := FALSE;
4609 "output_row"."scope_out" := NULL;
4610 LOOP
4611 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
4612 "loop_member_id_v" := "output_row"."member_id";
4613 ELSE
4614 "visited_member_ids" :=
4615 "visited_member_ids" || "output_row"."member_id";
4616 END IF;
4617 IF "output_row"."participation" ISNULL THEN
4618 "output_row"."overridden" := NULL;
4619 ELSIF "output_row"."participation" THEN
4620 "output_row"."overridden" := TRUE;
4621 END IF;
4622 "output_row"."scope_in" := "output_row"."scope_out";
4623 "output_row"."member_valid" := EXISTS (
4624 SELECT NULL FROM "member"
4625 LEFT JOIN "privilege"
4626 ON "privilege"."member_id" = "member"."id"
4627 AND "privilege"."unit_id" = "unit_id_v"
4628 LEFT JOIN "issue_privilege"
4629 ON "issue_privilege"."member_id" = "member"."id"
4630 AND "issue_privilege"."issue_id" = "issue_id_p"
4631 WHERE "id" = "output_row"."member_id"
4632 AND "member"."active"
4633 AND COALESCE(
4634 "issue_privilege"."voting_right", "privilege"."voting_right")
4635 );
4636 "simulate_here_v" := (
4637 "simulate_v" AND
4638 "output_row"."member_id" = "member_id_p"
4639 );
4640 "delegation_row" := ROW(NULL);
4641 IF "output_row"."member_valid" OR "simulate_here_v" THEN
4642 IF "scope_v" = 'unit' THEN
4643 IF NOT "simulate_here_v" THEN
4644 SELECT * INTO "delegation_row" FROM "delegation"
4645 WHERE "truster_id" = "output_row"."member_id"
4646 AND "unit_id" = "unit_id_v";
4647 END IF;
4648 ELSIF "scope_v" = 'area' THEN
4649 IF "simulate_here_v" THEN
4650 IF "simulate_trustee_id_p" ISNULL THEN
4651 SELECT * INTO "delegation_row" FROM "delegation"
4652 WHERE "truster_id" = "output_row"."member_id"
4653 AND "unit_id" = "unit_id_v";
4654 END IF;
4655 ELSE
4656 SELECT * INTO "delegation_row" FROM "delegation"
4657 WHERE "truster_id" = "output_row"."member_id"
4658 AND (
4659 "unit_id" = "unit_id_v" OR
4660 "area_id" = "area_id_v"
4662 ORDER BY "scope" DESC;
4663 END IF;
4664 ELSIF "scope_v" = 'issue' THEN
4665 IF "issue_row"."fully_frozen" ISNULL THEN
4666 "output_row"."participation" := EXISTS (
4667 SELECT NULL FROM "interest"
4668 WHERE "issue_id" = "issue_id_p"
4669 AND "member_id" = "output_row"."member_id"
4670 );
4671 ELSE
4672 IF "output_row"."member_id" = "member_id_p" THEN
4673 "output_row"."participation" := EXISTS (
4674 SELECT NULL FROM "direct_voter"
4675 WHERE "issue_id" = "issue_id_p"
4676 AND "member_id" = "output_row"."member_id"
4677 );
4678 ELSE
4679 "output_row"."participation" := NULL;
4680 END IF;
4681 END IF;
4682 IF "simulate_here_v" THEN
4683 IF "simulate_trustee_id_p" ISNULL THEN
4684 SELECT * INTO "delegation_row" FROM "delegation"
4685 WHERE "truster_id" = "output_row"."member_id"
4686 AND (
4687 "unit_id" = "unit_id_v" OR
4688 "area_id" = "area_id_v"
4690 ORDER BY "scope" DESC;
4691 END IF;
4692 ELSE
4693 SELECT * INTO "delegation_row" FROM "delegation"
4694 WHERE "truster_id" = "output_row"."member_id"
4695 AND (
4696 "unit_id" = "unit_id_v" OR
4697 "area_id" = "area_id_v" OR
4698 "issue_id" = "issue_id_p"
4700 ORDER BY "scope" DESC;
4701 END IF;
4702 END IF;
4703 ELSE
4704 "output_row"."participation" := FALSE;
4705 END IF;
4706 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
4707 "output_row"."scope_out" := "scope_v";
4708 "output_rows" := "output_rows" || "output_row";
4709 "output_row"."member_id" := "simulate_trustee_id_p";
4710 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
4711 "output_row"."scope_out" := "delegation_row"."scope";
4712 "output_rows" := "output_rows" || "output_row";
4713 "output_row"."member_id" := "delegation_row"."trustee_id";
4714 ELSIF "delegation_row"."scope" NOTNULL THEN
4715 "output_row"."scope_out" := "delegation_row"."scope";
4716 "output_row"."disabled_out" := TRUE;
4717 "output_rows" := "output_rows" || "output_row";
4718 EXIT;
4719 ELSE
4720 "output_row"."scope_out" := NULL;
4721 "output_rows" := "output_rows" || "output_row";
4722 EXIT;
4723 END IF;
4724 EXIT WHEN "loop_member_id_v" NOTNULL;
4725 "output_row"."index" := "output_row"."index" + 1;
4726 END LOOP;
4727 "row_count" := array_upper("output_rows", 1);
4728 "i" := 1;
4729 "loop_v" := FALSE;
4730 LOOP
4731 "output_row" := "output_rows"["i"];
4732 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
4733 IF "loop_v" THEN
4734 IF "i" + 1 = "row_count" THEN
4735 "output_row"."loop" := 'last';
4736 ELSIF "i" = "row_count" THEN
4737 "output_row"."loop" := 'repetition';
4738 ELSE
4739 "output_row"."loop" := 'intermediate';
4740 END IF;
4741 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
4742 "output_row"."loop" := 'first';
4743 "loop_v" := TRUE;
4744 END IF;
4745 IF "scope_v" = 'unit' THEN
4746 "output_row"."participation" := NULL;
4747 END IF;
4748 RETURN NEXT "output_row";
4749 "i" := "i" + 1;
4750 END LOOP;
4751 RETURN;
4752 END;
4753 $$;
4755 COMMENT ON FUNCTION "delegation_chain"
4756 ( "member"."id"%TYPE,
4757 "unit"."id"%TYPE,
4758 "area"."id"%TYPE,
4759 "issue"."id"%TYPE,
4760 "member"."id"%TYPE,
4761 BOOLEAN )
4762 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
4766 ---------------------------------------------------------
4767 -- Single row returning function for delegation chains --
4768 ---------------------------------------------------------
4771 CREATE TYPE "delegation_info_loop_type" AS ENUM
4772 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
4774 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''';
4777 CREATE TYPE "delegation_info_type" AS (
4778 "own_participation" BOOLEAN,
4779 "own_delegation_scope" "delegation_scope",
4780 "first_trustee_id" INT4,
4781 "first_trustee_participation" BOOLEAN,
4782 "first_trustee_ellipsis" BOOLEAN,
4783 "other_trustee_id" INT4,
4784 "other_trustee_participation" BOOLEAN,
4785 "other_trustee_ellipsis" BOOLEAN,
4786 "delegation_loop" "delegation_info_loop_type",
4787 "participating_member_id" INT4 );
4789 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';
4791 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
4792 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
4793 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
4794 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
4795 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
4796 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
4797 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)';
4798 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
4799 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';
4800 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
4803 CREATE FUNCTION "delegation_info"
4804 ( "member_id_p" "member"."id"%TYPE,
4805 "unit_id_p" "unit"."id"%TYPE,
4806 "area_id_p" "area"."id"%TYPE,
4807 "issue_id_p" "issue"."id"%TYPE,
4808 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4809 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4810 RETURNS "delegation_info_type"
4811 LANGUAGE 'plpgsql' STABLE AS $$
4812 DECLARE
4813 "current_row" "delegation_chain_row";
4814 "result" "delegation_info_type";
4815 BEGIN
4816 "result"."own_participation" := FALSE;
4817 FOR "current_row" IN
4818 SELECT * FROM "delegation_chain"(
4819 "member_id_p",
4820 "unit_id_p", "area_id_p", "issue_id_p",
4821 "simulate_trustee_id_p", "simulate_default_p")
4822 LOOP
4823 IF
4824 "result"."participating_member_id" ISNULL AND
4825 "current_row"."participation"
4826 THEN
4827 "result"."participating_member_id" := "current_row"."member_id";
4828 END IF;
4829 IF "current_row"."member_id" = "member_id_p" THEN
4830 "result"."own_participation" := "current_row"."participation";
4831 "result"."own_delegation_scope" := "current_row"."scope_out";
4832 IF "current_row"."loop" = 'first' THEN
4833 "result"."delegation_loop" := 'own';
4834 END IF;
4835 ELSIF
4836 "current_row"."member_valid" AND
4837 ( "current_row"."loop" ISNULL OR
4838 "current_row"."loop" != 'repetition' )
4839 THEN
4840 IF "result"."first_trustee_id" ISNULL THEN
4841 "result"."first_trustee_id" := "current_row"."member_id";
4842 "result"."first_trustee_participation" := "current_row"."participation";
4843 "result"."first_trustee_ellipsis" := FALSE;
4844 IF "current_row"."loop" = 'first' THEN
4845 "result"."delegation_loop" := 'first';
4846 END IF;
4847 ELSIF "result"."other_trustee_id" ISNULL THEN
4848 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
4849 "result"."other_trustee_id" := "current_row"."member_id";
4850 "result"."other_trustee_participation" := TRUE;
4851 "result"."other_trustee_ellipsis" := FALSE;
4852 IF "current_row"."loop" = 'first' THEN
4853 "result"."delegation_loop" := 'other';
4854 END IF;
4855 ELSE
4856 "result"."first_trustee_ellipsis" := TRUE;
4857 IF "current_row"."loop" = 'first' THEN
4858 "result"."delegation_loop" := 'first_ellipsis';
4859 END IF;
4860 END IF;
4861 ELSE
4862 "result"."other_trustee_ellipsis" := TRUE;
4863 IF "current_row"."loop" = 'first' THEN
4864 "result"."delegation_loop" := 'other_ellipsis';
4865 END IF;
4866 END IF;
4867 END IF;
4868 END LOOP;
4869 RETURN "result";
4870 END;
4871 $$;
4873 COMMENT ON FUNCTION "delegation_info"
4874 ( "member"."id"%TYPE,
4875 "unit"."id"%TYPE,
4876 "area"."id"%TYPE,
4877 "issue"."id"%TYPE,
4878 "member"."id"%TYPE,
4879 BOOLEAN )
4880 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
4884 ------------------------
4885 -- Geospatial lookups --
4886 ------------------------
4888 /*
4889 CREATE FUNCTION "closed_initiatives_in_bounding_box"
4890 ( "bounding_box_p" EBOX,
4891 "limit_p" INT4 )
4892 RETURNS SETOF "initiative"
4893 LANGUAGE 'plpgsql' STABLE AS $$
4894 DECLARE
4895 "limit_v" INT4;
4896 "count_v" INT4;
4897 BEGIN
4898 "limit_v" := "limit_p" + 1;
4899 LOOP
4900 SELECT count(1) INTO "count_v"
4901 FROM "initiative"
4902 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4903 WHERE "issue"."closed" NOTNULL
4904 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4905 LIMIT "limit_v";
4906 IF "count_v" < "limit_v" THEN
4907 RETURN QUERY SELECT "initiative".*
4908 FROM (
4909 SELECT
4910 "initiative"."id" AS "initiative_id",
4911 "issue"."closed"
4912 FROM "initiative"
4913 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4914 WHERE "issue"."closed" NOTNULL
4915 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4916 ) AS "subquery"
4917 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4918 ORDER BY "subquery"."closed" DESC
4919 LIMIT "limit_p";
4920 RETURN;
4921 END IF;
4922 SELECT count(1) INTO "count_v"
4923 FROM (
4924 SELECT "initiative"."id" AS "initiative_id"
4925 FROM "initiative"
4926 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4927 WHERE "issue"."closed" NOTNULL
4928 ORDER BY "closed" DESC
4929 LIMIT "limit_v"
4930 ) AS "subquery"
4931 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4932 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4933 LIMIT "limit_p";
4934 IF "count_v" >= "limit_p" THEN
4935 RETURN QUERY SELECT "initiative".*
4936 FROM (
4937 SELECT
4938 "initiative"."id" AS "initiative_id",
4939 "issue"."closed"
4940 FROM "initiative"
4941 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4942 WHERE "issue"."closed" NOTNULL
4943 ORDER BY "closed" DESC
4944 LIMIT "limit_v"
4945 ) AS "subquery"
4946 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4947 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4948 ORDER BY "subquery"."closed" DESC
4949 LIMIT "limit_p";
4950 RETURN;
4951 END IF;
4952 "limit_v" := "limit_v" * 2;
4953 END LOOP;
4954 END;
4955 $$;
4957 COMMENT ON FUNCTION "closed_initiatives_in_bounding_box"
4958 ( EBOX, INT4 )
4959 IS 'TODO';
4960 */
4964 ---------------------------
4965 -- Transaction isolation --
4966 ---------------------------
4969 CREATE FUNCTION "require_transaction_isolation"()
4970 RETURNS VOID
4971 LANGUAGE 'plpgsql' VOLATILE AS $$
4972 BEGIN
4973 IF
4974 current_setting('transaction_isolation') NOT IN
4975 ('repeatable read', 'serializable')
4976 THEN
4977 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
4978 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
4979 END IF;
4980 RETURN;
4981 END;
4982 $$;
4984 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
4987 CREATE FUNCTION "dont_require_transaction_isolation"()
4988 RETURNS VOID
4989 LANGUAGE 'plpgsql' VOLATILE AS $$
4990 BEGIN
4991 IF
4992 current_setting('transaction_isolation') IN
4993 ('repeatable read', 'serializable')
4994 THEN
4995 RAISE WARNING 'Unneccessary transaction isolation level: %',
4996 current_setting('transaction_isolation');
4997 END IF;
4998 RETURN;
4999 END;
5000 $$;
5002 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
5006 -------------------------
5007 -- Notification system --
5008 -------------------------
5010 CREATE FUNCTION "get_initiatives_for_notification"
5011 ( "recipient_id_p" "member"."id"%TYPE )
5012 RETURNS SETOF "initiative_for_notification"
5013 LANGUAGE 'plpgsql' VOLATILE AS $$
5014 DECLARE
5015 "result_row" "initiative_for_notification"%ROWTYPE;
5016 "last_draft_id_v" "draft"."id"%TYPE;
5017 "last_suggestion_id_v" "suggestion"."id"%TYPE;
5018 BEGIN
5019 PERFORM "require_transaction_isolation"();
5020 PERFORM NULL FROM "member" WHERE "id" = "recipient_id_p" FOR UPDATE;
5021 FOR "result_row" IN
5022 SELECT * FROM "initiative_for_notification"
5023 WHERE "recipient_id" = "recipient_id_p"
5024 LOOP
5025 SELECT "id" INTO "last_draft_id_v" FROM "draft"
5026 WHERE "draft"."initiative_id" = "result_row"."initiative_id"
5027 ORDER BY "id" DESC LIMIT 1;
5028 SELECT "id" INTO "last_suggestion_id_v" FROM "suggestion"
5029 WHERE "suggestion"."initiative_id" = "result_row"."initiative_id"
5030 ORDER BY "id" DESC LIMIT 1;
5031 INSERT INTO "notification_initiative_sent"
5032 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
5033 VALUES (
5034 "recipient_id_p",
5035 "result_row"."initiative_id",
5036 "last_draft_id_v",
5037 "last_suggestion_id_v" )
5038 ON CONFLICT ("member_id", "initiative_id") DO UPDATE SET
5039 "last_draft_id" = "last_draft_id_v",
5040 "last_suggestion_id" = "last_suggestion_id_v";
5041 RETURN NEXT "result_row";
5042 END LOOP;
5043 DELETE FROM "notification_initiative_sent"
5044 USING "initiative", "issue"
5045 WHERE "notification_initiative_sent"."member_id" = "recipient_id_p"
5046 AND "initiative"."id" = "notification_initiative_sent"."initiative_id"
5047 AND "issue"."id" = "initiative"."issue_id"
5048 AND ( "issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL );
5049 UPDATE "member" SET
5050 "notification_counter" = "notification_counter" + 1,
5051 "notification_sent" = now()
5052 WHERE "id" = "recipient_id_p";
5053 RETURN;
5054 END;
5055 $$;
5057 COMMENT ON FUNCTION "get_initiatives_for_notification"
5058 ( "member"."id"%TYPE )
5059 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';
5063 ------------------------------------------------------------------------
5064 -- Regular tasks, except calculcation of snapshots and voting results --
5065 ------------------------------------------------------------------------
5068 CREATE FUNCTION "check_activity"()
5069 RETURNS VOID
5070 LANGUAGE 'plpgsql' VOLATILE AS $$
5071 DECLARE
5072 "system_setting_row" "system_setting"%ROWTYPE;
5073 BEGIN
5074 PERFORM "dont_require_transaction_isolation"();
5075 SELECT * INTO "system_setting_row" FROM "system_setting";
5076 IF "system_setting_row"."member_ttl" NOTNULL THEN
5077 UPDATE "member" SET "active" = FALSE
5078 WHERE "active" = TRUE
5079 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
5080 END IF;
5081 RETURN;
5082 END;
5083 $$;
5085 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
5088 CREATE FUNCTION "calculate_member_counts"()
5089 RETURNS VOID
5090 LANGUAGE 'plpgsql' VOLATILE AS $$
5091 BEGIN
5092 PERFORM "require_transaction_isolation"();
5093 DELETE FROM "member_count";
5094 INSERT INTO "member_count" ("total_count")
5095 SELECT "total_count" FROM "member_count_view";
5096 UPDATE "unit" SET
5097 "member_count" = "view"."member_count",
5098 "member_weight" = "view"."member_weight"
5099 FROM "unit_member_count" AS "view"
5100 WHERE "view"."unit_id" = "unit"."id";
5101 RETURN;
5102 END;
5103 $$;
5105 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"';
5109 ------------------------------------
5110 -- Calculation of harmonic weight --
5111 ------------------------------------
5114 CREATE VIEW "remaining_harmonic_supporter_weight" AS
5115 SELECT
5116 "direct_interest_snapshot"."snapshot_id",
5117 "direct_interest_snapshot"."issue_id",
5118 "direct_interest_snapshot"."member_id",
5119 "direct_interest_snapshot"."weight" AS "weight_num",
5120 count("initiative"."id") AS "weight_den"
5121 FROM "issue"
5122 JOIN "direct_interest_snapshot"
5123 ON "issue"."latest_snapshot_id" = "direct_interest_snapshot"."snapshot_id"
5124 AND "issue"."id" = "direct_interest_snapshot"."issue_id"
5125 JOIN "initiative"
5126 ON "issue"."id" = "initiative"."issue_id"
5127 AND "initiative"."harmonic_weight" ISNULL
5128 JOIN "direct_supporter_snapshot"
5129 ON "issue"."latest_snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
5130 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
5131 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
5132 AND (
5133 "direct_supporter_snapshot"."satisfied" = TRUE OR
5134 coalesce("initiative"."admitted", FALSE) = FALSE
5136 GROUP BY
5137 "direct_interest_snapshot"."snapshot_id",
5138 "direct_interest_snapshot"."issue_id",
5139 "direct_interest_snapshot"."member_id",
5140 "direct_interest_snapshot"."weight";
5142 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
5145 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
5146 SELECT
5147 "initiative"."issue_id",
5148 "initiative"."id" AS "initiative_id",
5149 "initiative"."admitted",
5150 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
5151 "remaining_harmonic_supporter_weight"."weight_den"
5152 FROM "remaining_harmonic_supporter_weight"
5153 JOIN "initiative"
5154 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
5155 AND "initiative"."harmonic_weight" ISNULL
5156 JOIN "direct_supporter_snapshot"
5157 ON "remaining_harmonic_supporter_weight"."snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
5158 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
5159 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
5160 AND (
5161 "direct_supporter_snapshot"."satisfied" = TRUE OR
5162 coalesce("initiative"."admitted", FALSE) = FALSE
5164 GROUP BY
5165 "initiative"."issue_id",
5166 "initiative"."id",
5167 "initiative"."admitted",
5168 "remaining_harmonic_supporter_weight"."weight_den";
5170 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
5173 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
5174 SELECT
5175 "issue_id",
5176 "id" AS "initiative_id",
5177 "admitted",
5178 0 AS "weight_num",
5179 1 AS "weight_den"
5180 FROM "initiative"
5181 WHERE "harmonic_weight" ISNULL;
5183 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';
5186 CREATE FUNCTION "set_harmonic_initiative_weights"
5187 ( "issue_id_p" "issue"."id"%TYPE )
5188 RETURNS VOID
5189 LANGUAGE 'plpgsql' VOLATILE AS $$
5190 DECLARE
5191 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
5192 "i" INT4;
5193 "count_v" INT4;
5194 "summand_v" FLOAT;
5195 "id_ary" INT4[];
5196 "weight_ary" FLOAT[];
5197 "min_weight_v" FLOAT;
5198 BEGIN
5199 PERFORM "require_transaction_isolation"();
5200 UPDATE "initiative" SET "harmonic_weight" = NULL
5201 WHERE "issue_id" = "issue_id_p";
5202 LOOP
5203 "min_weight_v" := NULL;
5204 "i" := 0;
5205 "count_v" := 0;
5206 FOR "weight_row" IN
5207 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
5208 WHERE "issue_id" = "issue_id_p"
5209 AND (
5210 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
5211 SELECT NULL FROM "initiative"
5212 WHERE "issue_id" = "issue_id_p"
5213 AND "harmonic_weight" ISNULL
5214 AND coalesce("admitted", FALSE) = FALSE
5217 UNION ALL -- needed for corner cases
5218 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
5219 WHERE "issue_id" = "issue_id_p"
5220 AND (
5221 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
5222 SELECT NULL FROM "initiative"
5223 WHERE "issue_id" = "issue_id_p"
5224 AND "harmonic_weight" ISNULL
5225 AND coalesce("admitted", FALSE) = FALSE
5228 ORDER BY "initiative_id" DESC, "weight_den" DESC
5229 -- NOTE: non-admitted initiatives placed first (at last positions),
5230 -- latest initiatives treated worse in case of tie
5231 LOOP
5232 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
5233 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
5234 "i" := "i" + 1;
5235 "count_v" := "i";
5236 "id_ary"["i"] := "weight_row"."initiative_id";
5237 "weight_ary"["i"] := "summand_v";
5238 ELSE
5239 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
5240 END IF;
5241 END LOOP;
5242 EXIT WHEN "count_v" = 0;
5243 "i" := 1;
5244 LOOP
5245 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
5246 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
5247 "min_weight_v" := "weight_ary"["i"];
5248 END IF;
5249 "i" := "i" + 1;
5250 EXIT WHEN "i" > "count_v";
5251 END LOOP;
5252 "i" := 1;
5253 LOOP
5254 IF "weight_ary"["i"] = "min_weight_v" THEN
5255 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
5256 WHERE "id" = "id_ary"["i"];
5257 EXIT;
5258 END IF;
5259 "i" := "i" + 1;
5260 END LOOP;
5261 END LOOP;
5262 UPDATE "initiative" SET "harmonic_weight" = 0
5263 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
5264 END;
5265 $$;
5267 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
5268 ( "issue"."id"%TYPE )
5269 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
5273 ------------------------------
5274 -- Calculation of snapshots --
5275 ------------------------------
5278 CREATE FUNCTION "weight_of_added_delegations_for_snapshot"
5279 ( "snapshot_id_p" "snapshot"."id"%TYPE,
5280 "issue_id_p" "issue"."id"%TYPE,
5281 "member_id_p" "member"."id"%TYPE,
5282 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
5283 RETURNS "direct_interest_snapshot"."weight"%TYPE
5284 LANGUAGE 'plpgsql' VOLATILE AS $$
5285 DECLARE
5286 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5287 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
5288 "weight_v" INT4;
5289 "sub_weight_v" INT4;
5290 BEGIN
5291 PERFORM "require_transaction_isolation"();
5292 "weight_v" := 0;
5293 FOR "issue_delegation_row" IN
5294 SELECT * FROM "issue_delegation"
5295 WHERE "trustee_id" = "member_id_p"
5296 AND "issue_id" = "issue_id_p"
5297 LOOP
5298 IF NOT EXISTS (
5299 SELECT NULL FROM "direct_interest_snapshot"
5300 WHERE "snapshot_id" = "snapshot_id_p"
5301 AND "issue_id" = "issue_id_p"
5302 AND "member_id" = "issue_delegation_row"."truster_id"
5303 ) AND NOT EXISTS (
5304 SELECT NULL FROM "delegating_interest_snapshot"
5305 WHERE "snapshot_id" = "snapshot_id_p"
5306 AND "issue_id" = "issue_id_p"
5307 AND "member_id" = "issue_delegation_row"."truster_id"
5308 ) THEN
5309 "delegate_member_ids_v" :=
5310 "member_id_p" || "delegate_member_ids_p";
5311 INSERT INTO "delegating_interest_snapshot" (
5312 "snapshot_id",
5313 "issue_id",
5314 "member_id",
5315 "ownweight",
5316 "scope",
5317 "delegate_member_ids"
5318 ) VALUES (
5319 "snapshot_id_p",
5320 "issue_id_p",
5321 "issue_delegation_row"."truster_id",
5322 "issue_delegation_row"."weight",
5323 "issue_delegation_row"."scope",
5324 "delegate_member_ids_v"
5325 );
5326 "sub_weight_v" := "issue_delegation_row"."weight" +
5327 "weight_of_added_delegations_for_snapshot"(
5328 "snapshot_id_p",
5329 "issue_id_p",
5330 "issue_delegation_row"."truster_id",
5331 "delegate_member_ids_v"
5332 );
5333 UPDATE "delegating_interest_snapshot"
5334 SET "weight" = "sub_weight_v"
5335 WHERE "snapshot_id" = "snapshot_id_p"
5336 AND "issue_id" = "issue_id_p"
5337 AND "member_id" = "issue_delegation_row"."truster_id";
5338 "weight_v" := "weight_v" + "sub_weight_v";
5339 END IF;
5340 END LOOP;
5341 RETURN "weight_v";
5342 END;
5343 $$;
5345 COMMENT ON FUNCTION "weight_of_added_delegations_for_snapshot"
5346 ( "snapshot"."id"%TYPE,
5347 "issue"."id"%TYPE,
5348 "member"."id"%TYPE,
5349 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
5350 IS 'Helper function for "fill_snapshot" function';
5353 CREATE FUNCTION "take_snapshot"
5354 ( "issue_id_p" "issue"."id"%TYPE,
5355 "area_id_p" "area"."id"%TYPE = NULL )
5356 RETURNS "snapshot"."id"%TYPE
5357 LANGUAGE 'plpgsql' VOLATILE AS $$
5358 DECLARE
5359 "area_id_v" "area"."id"%TYPE;
5360 "unit_id_v" "unit"."id"%TYPE;
5361 "snapshot_id_v" "snapshot"."id"%TYPE;
5362 "issue_id_v" "issue"."id"%TYPE;
5363 "member_id_v" "member"."id"%TYPE;
5364 BEGIN
5365 IF "issue_id_p" NOTNULL AND "area_id_p" NOTNULL THEN
5366 RAISE EXCEPTION 'One of "issue_id_p" and "area_id_p" must be NULL';
5367 END IF;
5368 PERFORM "require_transaction_isolation"();
5369 IF "issue_id_p" ISNULL THEN
5370 "area_id_v" := "area_id_p";
5371 ELSE
5372 SELECT "area_id" INTO "area_id_v"
5373 FROM "issue" WHERE "id" = "issue_id_p";
5374 END IF;
5375 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5376 INSERT INTO "snapshot" ("area_id", "issue_id")
5377 VALUES ("area_id_v", "issue_id_p")
5378 RETURNING "id" INTO "snapshot_id_v";
5379 INSERT INTO "snapshot_population" ("snapshot_id", "member_id", "weight")
5380 SELECT
5381 "snapshot_id_v",
5382 "member"."id",
5383 COALESCE("issue_privilege"."weight", "privilege"."weight")
5384 FROM "member"
5385 LEFT JOIN "privilege"
5386 ON "privilege"."unit_id" = "unit_id_v"
5387 AND "privilege"."member_id" = "member"."id"
5388 LEFT JOIN "issue_privilege"
5389 ON "issue_privilege"."issue_id" = "issue_id_p"
5390 AND "issue_privilege"."member_id" = "member"."id"
5391 WHERE "member"."active" AND COALESCE(
5392 "issue_privilege"."voting_right", "privilege"."voting_right");
5393 UPDATE "snapshot" SET
5394 "population" = (
5395 SELECT sum("weight") FROM "snapshot_population"
5396 WHERE "snapshot_id" = "snapshot_id_v"
5397 ) WHERE "id" = "snapshot_id_v";
5398 FOR "issue_id_v" IN
5399 SELECT "id" FROM "issue"
5400 WHERE CASE WHEN "issue_id_p" ISNULL THEN
5401 "area_id" = "area_id_p" AND
5402 "state" = 'admission'
5403 ELSE
5404 "id" = "issue_id_p"
5405 END
5406 LOOP
5407 INSERT INTO "snapshot_issue" ("snapshot_id", "issue_id")
5408 VALUES ("snapshot_id_v", "issue_id_v");
5409 INSERT INTO "direct_interest_snapshot"
5410 ("snapshot_id", "issue_id", "member_id", "ownweight")
5411 SELECT
5412 "snapshot_id_v" AS "snapshot_id",
5413 "issue_id_v" AS "issue_id",
5414 "member"."id" AS "member_id",
5415 COALESCE(
5416 "issue_privilege"."weight", "privilege"."weight"
5417 ) AS "ownweight"
5418 FROM "issue"
5419 JOIN "area" ON "issue"."area_id" = "area"."id"
5420 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
5421 JOIN "member" ON "interest"."member_id" = "member"."id"
5422 LEFT JOIN "privilege"
5423 ON "privilege"."unit_id" = "area"."unit_id"
5424 AND "privilege"."member_id" = "member"."id"
5425 LEFT JOIN "issue_privilege"
5426 ON "issue_privilege"."issue_id" = "issue_id_v"
5427 AND "issue_privilege"."member_id" = "member"."id"
5428 WHERE "issue"."id" = "issue_id_v"
5429 AND "member"."active" AND COALESCE(
5430 "issue_privilege"."voting_right", "privilege"."voting_right");
5431 FOR "member_id_v" IN
5432 SELECT "member_id" FROM "direct_interest_snapshot"
5433 WHERE "snapshot_id" = "snapshot_id_v"
5434 AND "issue_id" = "issue_id_v"
5435 LOOP
5436 UPDATE "direct_interest_snapshot" SET
5437 "weight" = "ownweight" +
5438 "weight_of_added_delegations_for_snapshot"(
5439 "snapshot_id_v",
5440 "issue_id_v",
5441 "member_id_v",
5442 '{}'
5444 WHERE "snapshot_id" = "snapshot_id_v"
5445 AND "issue_id" = "issue_id_v"
5446 AND "member_id" = "member_id_v";
5447 END LOOP;
5448 INSERT INTO "direct_supporter_snapshot"
5449 ( "snapshot_id", "issue_id", "initiative_id", "member_id",
5450 "draft_id", "informed", "satisfied" )
5451 SELECT
5452 "snapshot_id_v" AS "snapshot_id",
5453 "issue_id_v" AS "issue_id",
5454 "initiative"."id" AS "initiative_id",
5455 "supporter"."member_id" AS "member_id",
5456 "supporter"."draft_id" AS "draft_id",
5457 "supporter"."draft_id" = "current_draft"."id" AS "informed",
5458 NOT EXISTS (
5459 SELECT NULL FROM "critical_opinion"
5460 WHERE "initiative_id" = "initiative"."id"
5461 AND "member_id" = "supporter"."member_id"
5462 ) AS "satisfied"
5463 FROM "initiative"
5464 JOIN "supporter"
5465 ON "supporter"."initiative_id" = "initiative"."id"
5466 JOIN "current_draft"
5467 ON "initiative"."id" = "current_draft"."initiative_id"
5468 JOIN "direct_interest_snapshot"
5469 ON "snapshot_id_v" = "direct_interest_snapshot"."snapshot_id"
5470 AND "supporter"."member_id" = "direct_interest_snapshot"."member_id"
5471 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
5472 WHERE "initiative"."issue_id" = "issue_id_v";
5473 DELETE FROM "temporary_suggestion_counts";
5474 INSERT INTO "temporary_suggestion_counts"
5475 ( "id",
5476 "minus2_unfulfilled_count", "minus2_fulfilled_count",
5477 "minus1_unfulfilled_count", "minus1_fulfilled_count",
5478 "plus1_unfulfilled_count", "plus1_fulfilled_count",
5479 "plus2_unfulfilled_count", "plus2_fulfilled_count" )
5480 SELECT
5481 "suggestion"."id",
5482 ( SELECT coalesce(sum("di"."weight"), 0)
5483 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5484 ON "di"."snapshot_id" = "snapshot_id_v"
5485 AND "di"."issue_id" = "issue_id_v"
5486 AND "di"."member_id" = "opinion"."member_id"
5487 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5488 AND "opinion"."degree" = -2
5489 AND "opinion"."fulfilled" = FALSE
5490 ) AS "minus2_unfulfilled_count",
5491 ( SELECT coalesce(sum("di"."weight"), 0)
5492 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5493 ON "di"."snapshot_id" = "snapshot_id_v"
5494 AND "di"."issue_id" = "issue_id_v"
5495 AND "di"."member_id" = "opinion"."member_id"
5496 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5497 AND "opinion"."degree" = -2
5498 AND "opinion"."fulfilled" = TRUE
5499 ) AS "minus2_fulfilled_count",
5500 ( SELECT coalesce(sum("di"."weight"), 0)
5501 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5502 ON "di"."snapshot_id" = "snapshot_id_v"
5503 AND "di"."issue_id" = "issue_id_v"
5504 AND "di"."member_id" = "opinion"."member_id"
5505 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5506 AND "opinion"."degree" = -1
5507 AND "opinion"."fulfilled" = FALSE
5508 ) AS "minus1_unfulfilled_count",
5509 ( SELECT coalesce(sum("di"."weight"), 0)
5510 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5511 ON "di"."snapshot_id" = "snapshot_id_v"
5512 AND "di"."issue_id" = "issue_id_v"
5513 AND "di"."member_id" = "opinion"."member_id"
5514 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5515 AND "opinion"."degree" = -1
5516 AND "opinion"."fulfilled" = TRUE
5517 ) AS "minus1_fulfilled_count",
5518 ( SELECT coalesce(sum("di"."weight"), 0)
5519 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5520 ON "di"."snapshot_id" = "snapshot_id_v"
5521 AND "di"."issue_id" = "issue_id_v"
5522 AND "di"."member_id" = "opinion"."member_id"
5523 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5524 AND "opinion"."degree" = 1
5525 AND "opinion"."fulfilled" = FALSE
5526 ) AS "plus1_unfulfilled_count",
5527 ( SELECT coalesce(sum("di"."weight"), 0)
5528 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5529 ON "di"."snapshot_id" = "snapshot_id_v"
5530 AND "di"."issue_id" = "issue_id_v"
5531 AND "di"."member_id" = "opinion"."member_id"
5532 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5533 AND "opinion"."degree" = 1
5534 AND "opinion"."fulfilled" = TRUE
5535 ) AS "plus1_fulfilled_count",
5536 ( SELECT coalesce(sum("di"."weight"), 0)
5537 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5538 ON "di"."snapshot_id" = "snapshot_id_v"
5539 AND "di"."issue_id" = "issue_id_v"
5540 AND "di"."member_id" = "opinion"."member_id"
5541 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5542 AND "opinion"."degree" = 2
5543 AND "opinion"."fulfilled" = FALSE
5544 ) AS "plus2_unfulfilled_count",
5545 ( SELECT coalesce(sum("di"."weight"), 0)
5546 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5547 ON "di"."snapshot_id" = "snapshot_id_v"
5548 AND "di"."issue_id" = "issue_id_v"
5549 AND "di"."member_id" = "opinion"."member_id"
5550 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5551 AND "opinion"."degree" = 2
5552 AND "opinion"."fulfilled" = TRUE
5553 ) AS "plus2_fulfilled_count"
5554 FROM "suggestion" JOIN "initiative"
5555 ON "suggestion"."initiative_id" = "initiative"."id"
5556 WHERE "initiative"."issue_id" = "issue_id_v";
5557 END LOOP;
5558 RETURN "snapshot_id_v";
5559 END;
5560 $$;
5562 COMMENT ON FUNCTION "take_snapshot"
5563 ( "issue"."id"%TYPE,
5564 "area"."id"%TYPE )
5565 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.';
5568 CREATE FUNCTION "finish_snapshot"
5569 ( "issue_id_p" "issue"."id"%TYPE )
5570 RETURNS VOID
5571 LANGUAGE 'plpgsql' VOLATILE AS $$
5572 DECLARE
5573 "snapshot_id_v" "snapshot"."id"%TYPE;
5574 BEGIN
5575 -- NOTE: function does not require snapshot isolation but we don't call
5576 -- "dont_require_snapshot_isolation" here because this function is
5577 -- also invoked by "check_issue"
5578 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
5579 SELECT "id" INTO "snapshot_id_v" FROM "snapshot"
5580 ORDER BY "id" DESC LIMIT 1;
5581 UPDATE "issue" SET
5582 "calculated" = "snapshot"."calculated",
5583 "latest_snapshot_id" = "snapshot_id_v",
5584 "population" = "snapshot"."population",
5585 "initiative_quorum" = CASE WHEN
5586 "policy"."initiative_quorum" > ceil(
5587 ( "issue"."population"::INT8 *
5588 "policy"."initiative_quorum_num"::INT8 ) /
5589 "policy"."initiative_quorum_den"::FLOAT8
5590 )::INT4
5591 THEN
5592 "policy"."initiative_quorum"
5593 ELSE
5594 ceil(
5595 ( "issue"."population"::INT8 *
5596 "policy"."initiative_quorum_num"::INT8 ) /
5597 "policy"."initiative_quorum_den"::FLOAT8
5598 )::INT4
5599 END
5600 FROM "snapshot", "policy"
5601 WHERE "issue"."id" = "issue_id_p"
5602 AND "snapshot"."id" = "snapshot_id_v"
5603 AND "policy"."id" = "issue"."policy_id";
5604 UPDATE "initiative" SET
5605 "supporter_count" = (
5606 SELECT coalesce(sum("di"."weight"), 0)
5607 FROM "direct_interest_snapshot" AS "di"
5608 JOIN "direct_supporter_snapshot" AS "ds"
5609 ON "di"."member_id" = "ds"."member_id"
5610 WHERE "di"."snapshot_id" = "snapshot_id_v"
5611 AND "di"."issue_id" = "issue_id_p"
5612 AND "ds"."snapshot_id" = "snapshot_id_v"
5613 AND "ds"."initiative_id" = "initiative"."id"
5614 ),
5615 "informed_supporter_count" = (
5616 SELECT coalesce(sum("di"."weight"), 0)
5617 FROM "direct_interest_snapshot" AS "di"
5618 JOIN "direct_supporter_snapshot" AS "ds"
5619 ON "di"."member_id" = "ds"."member_id"
5620 WHERE "di"."snapshot_id" = "snapshot_id_v"
5621 AND "di"."issue_id" = "issue_id_p"
5622 AND "ds"."snapshot_id" = "snapshot_id_v"
5623 AND "ds"."initiative_id" = "initiative"."id"
5624 AND "ds"."informed"
5625 ),
5626 "satisfied_supporter_count" = (
5627 SELECT coalesce(sum("di"."weight"), 0)
5628 FROM "direct_interest_snapshot" AS "di"
5629 JOIN "direct_supporter_snapshot" AS "ds"
5630 ON "di"."member_id" = "ds"."member_id"
5631 WHERE "di"."snapshot_id" = "snapshot_id_v"
5632 AND "di"."issue_id" = "issue_id_p"
5633 AND "ds"."snapshot_id" = "snapshot_id_v"
5634 AND "ds"."initiative_id" = "initiative"."id"
5635 AND "ds"."satisfied"
5636 ),
5637 "satisfied_informed_supporter_count" = (
5638 SELECT coalesce(sum("di"."weight"), 0)
5639 FROM "direct_interest_snapshot" AS "di"
5640 JOIN "direct_supporter_snapshot" AS "ds"
5641 ON "di"."member_id" = "ds"."member_id"
5642 WHERE "di"."snapshot_id" = "snapshot_id_v"
5643 AND "di"."issue_id" = "issue_id_p"
5644 AND "ds"."snapshot_id" = "snapshot_id_v"
5645 AND "ds"."initiative_id" = "initiative"."id"
5646 AND "ds"."informed"
5647 AND "ds"."satisfied"
5649 WHERE "issue_id" = "issue_id_p";
5650 UPDATE "suggestion" SET
5651 "minus2_unfulfilled_count" = "temp"."minus2_unfulfilled_count",
5652 "minus2_fulfilled_count" = "temp"."minus2_fulfilled_count",
5653 "minus1_unfulfilled_count" = "temp"."minus1_unfulfilled_count",
5654 "minus1_fulfilled_count" = "temp"."minus1_fulfilled_count",
5655 "plus1_unfulfilled_count" = "temp"."plus1_unfulfilled_count",
5656 "plus1_fulfilled_count" = "temp"."plus1_fulfilled_count",
5657 "plus2_unfulfilled_count" = "temp"."plus2_unfulfilled_count",
5658 "plus2_fulfilled_count" = "temp"."plus2_fulfilled_count"
5659 FROM "temporary_suggestion_counts" AS "temp", "initiative"
5660 WHERE "temp"."id" = "suggestion"."id"
5661 AND "initiative"."issue_id" = "issue_id_p"
5662 AND "suggestion"."initiative_id" = "initiative"."id";
5663 DELETE FROM "temporary_suggestion_counts";
5664 RETURN;
5665 END;
5666 $$;
5668 COMMENT ON FUNCTION "finish_snapshot"
5669 ( "issue"."id"%TYPE )
5670 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)';
5674 -----------------------
5675 -- Counting of votes --
5676 -----------------------
5679 CREATE FUNCTION "weight_of_added_vote_delegations"
5680 ( "issue_id_p" "issue"."id"%TYPE,
5681 "member_id_p" "member"."id"%TYPE,
5682 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
5683 RETURNS "direct_voter"."weight"%TYPE
5684 LANGUAGE 'plpgsql' VOLATILE AS $$
5685 DECLARE
5686 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5687 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
5688 "weight_v" INT4;
5689 "sub_weight_v" INT4;
5690 BEGIN
5691 PERFORM "require_transaction_isolation"();
5692 "weight_v" := 0;
5693 FOR "issue_delegation_row" IN
5694 SELECT * FROM "issue_delegation"
5695 WHERE "trustee_id" = "member_id_p"
5696 AND "issue_id" = "issue_id_p"
5697 LOOP
5698 IF NOT EXISTS (
5699 SELECT NULL FROM "direct_voter"
5700 WHERE "member_id" = "issue_delegation_row"."truster_id"
5701 AND "issue_id" = "issue_id_p"
5702 ) AND NOT EXISTS (
5703 SELECT NULL FROM "delegating_voter"
5704 WHERE "member_id" = "issue_delegation_row"."truster_id"
5705 AND "issue_id" = "issue_id_p"
5706 ) THEN
5707 "delegate_member_ids_v" :=
5708 "member_id_p" || "delegate_member_ids_p";
5709 INSERT INTO "delegating_voter" (
5710 "issue_id",
5711 "member_id",
5712 "ownweight",
5713 "scope",
5714 "delegate_member_ids"
5715 ) VALUES (
5716 "issue_id_p",
5717 "issue_delegation_row"."truster_id",
5718 "issue_delegation_row"."weight",
5719 "issue_delegation_row"."scope",
5720 "delegate_member_ids_v"
5721 );
5722 "sub_weight_v" := "issue_delegation_row"."weight" +
5723 "weight_of_added_vote_delegations"(
5724 "issue_id_p",
5725 "issue_delegation_row"."truster_id",
5726 "delegate_member_ids_v"
5727 );
5728 UPDATE "delegating_voter"
5729 SET "weight" = "sub_weight_v"
5730 WHERE "issue_id" = "issue_id_p"
5731 AND "member_id" = "issue_delegation_row"."truster_id";
5732 "weight_v" := "weight_v" + "sub_weight_v";
5733 END IF;
5734 END LOOP;
5735 RETURN "weight_v";
5736 END;
5737 $$;
5739 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
5740 ( "issue"."id"%TYPE,
5741 "member"."id"%TYPE,
5742 "delegating_voter"."delegate_member_ids"%TYPE )
5743 IS 'Helper function for "add_vote_delegations" function';
5746 CREATE FUNCTION "add_vote_delegations"
5747 ( "issue_id_p" "issue"."id"%TYPE )
5748 RETURNS VOID
5749 LANGUAGE 'plpgsql' VOLATILE AS $$
5750 DECLARE
5751 "member_id_v" "member"."id"%TYPE;
5752 BEGIN
5753 PERFORM "require_transaction_isolation"();
5754 FOR "member_id_v" IN
5755 SELECT "member_id" FROM "direct_voter"
5756 WHERE "issue_id" = "issue_id_p"
5757 LOOP
5758 UPDATE "direct_voter" SET
5759 "weight" = "ownweight" + "weight_of_added_vote_delegations"(
5760 "issue_id_p",
5761 "member_id_v",
5762 '{}'
5764 WHERE "member_id" = "member_id_v"
5765 AND "issue_id" = "issue_id_p";
5766 END LOOP;
5767 RETURN;
5768 END;
5769 $$;
5771 COMMENT ON FUNCTION "add_vote_delegations"
5772 ( "issue_id_p" "issue"."id"%TYPE )
5773 IS 'Helper function for "close_voting" function';
5776 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
5777 RETURNS VOID
5778 LANGUAGE 'plpgsql' VOLATILE AS $$
5779 DECLARE
5780 "area_id_v" "area"."id"%TYPE;
5781 "unit_id_v" "unit"."id"%TYPE;
5782 "member_id_v" "member"."id"%TYPE;
5783 BEGIN
5784 PERFORM "require_transaction_isolation"();
5785 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
5786 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5787 -- override protection triggers:
5788 INSERT INTO "temporary_transaction_data" ("key", "value")
5789 VALUES ('override_protection_triggers', TRUE::TEXT);
5790 -- delete timestamp of voting comment:
5791 UPDATE "direct_voter" SET "comment_changed" = NULL
5792 WHERE "issue_id" = "issue_id_p";
5793 -- delete delegating votes (in cases of manual reset of issue state):
5794 DELETE FROM "delegating_voter"
5795 WHERE "issue_id" = "issue_id_p";
5796 -- delete votes from non-privileged voters:
5797 DELETE FROM "direct_voter"
5798 USING (
5799 SELECT "direct_voter"."member_id"
5800 FROM "direct_voter"
5801 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
5802 LEFT JOIN "privilege"
5803 ON "privilege"."unit_id" = "unit_id_v"
5804 AND "privilege"."member_id" = "direct_voter"."member_id"
5805 LEFT JOIN "issue_privilege"
5806 ON "issue_privilege"."issue_id" = "issue_id_p"
5807 AND "issue_privilege"."member_id" = "direct_voter"."member_id"
5808 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
5809 "member"."active" = FALSE OR
5810 COALESCE(
5811 "issue_privilege"."voting_right",
5812 "privilege"."voting_right",
5813 FALSE
5814 ) = FALSE
5816 ) AS "subquery"
5817 WHERE "direct_voter"."issue_id" = "issue_id_p"
5818 AND "direct_voter"."member_id" = "subquery"."member_id";
5819 -- consider voting weight and delegations:
5820 UPDATE "direct_voter" SET "ownweight" = "privilege"."weight"
5821 FROM "privilege"
5822 WHERE "issue_id" = "issue_id_p"
5823 AND "privilege"."unit_id" = "unit_id_v"
5824 AND "privilege"."member_id" = "direct_voter"."member_id";
5825 UPDATE "direct_voter" SET "ownweight" = "issue_privilege"."weight"
5826 FROM "issue_privilege"
5827 WHERE "direct_voter"."issue_id" = "issue_id_p"
5828 AND "issue_privilege"."issue_id" = "issue_id_p"
5829 AND "issue_privilege"."member_id" = "direct_voter"."member_id";
5830 PERFORM "add_vote_delegations"("issue_id_p");
5831 -- mark first preferences:
5832 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
5833 FROM (
5834 SELECT
5835 "vote"."initiative_id",
5836 "vote"."member_id",
5837 CASE WHEN "vote"."grade" > 0 THEN
5838 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
5839 ELSE NULL
5840 END AS "first_preference"
5841 FROM "vote"
5842 JOIN "initiative" -- NOTE: due to missing index on issue_id
5843 ON "vote"."issue_id" = "initiative"."issue_id"
5844 JOIN "vote" AS "agg"
5845 ON "initiative"."id" = "agg"."initiative_id"
5846 AND "vote"."member_id" = "agg"."member_id"
5847 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
5848 ) AS "subquery"
5849 WHERE "vote"."issue_id" = "issue_id_p"
5850 AND "vote"."initiative_id" = "subquery"."initiative_id"
5851 AND "vote"."member_id" = "subquery"."member_id";
5852 -- finish overriding protection triggers (avoids garbage):
5853 DELETE FROM "temporary_transaction_data"
5854 WHERE "key" = 'override_protection_triggers';
5855 -- materialize battle_view:
5856 -- NOTE: "closed" column of issue must be set at this point
5857 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
5858 INSERT INTO "battle" (
5859 "issue_id",
5860 "winning_initiative_id", "losing_initiative_id",
5861 "count"
5862 ) SELECT
5863 "issue_id",
5864 "winning_initiative_id", "losing_initiative_id",
5865 "count"
5866 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
5867 -- set voter count:
5868 UPDATE "issue" SET
5869 "voter_count" = (
5870 SELECT coalesce(sum("weight"), 0)
5871 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
5873 WHERE "id" = "issue_id_p";
5874 -- copy "positive_votes" and "negative_votes" from "battle" table:
5875 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
5876 UPDATE "initiative" SET
5877 "first_preference_votes" = 0,
5878 "positive_votes" = "battle_win"."count",
5879 "negative_votes" = "battle_lose"."count"
5880 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
5881 WHERE
5882 "battle_win"."issue_id" = "issue_id_p" AND
5883 "battle_win"."winning_initiative_id" = "initiative"."id" AND
5884 "battle_win"."losing_initiative_id" ISNULL AND
5885 "battle_lose"."issue_id" = "issue_id_p" AND
5886 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
5887 "battle_lose"."winning_initiative_id" ISNULL;
5888 -- calculate "first_preference_votes":
5889 -- NOTE: will only set values not equal to zero
5890 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
5891 FROM (
5892 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
5893 FROM "vote" JOIN "direct_voter"
5894 ON "vote"."issue_id" = "direct_voter"."issue_id"
5895 AND "vote"."member_id" = "direct_voter"."member_id"
5896 WHERE "vote"."first_preference"
5897 GROUP BY "vote"."initiative_id"
5898 ) AS "subquery"
5899 WHERE "initiative"."issue_id" = "issue_id_p"
5900 AND "initiative"."admitted"
5901 AND "initiative"."id" = "subquery"."initiative_id";
5902 END;
5903 $$;
5905 COMMENT ON FUNCTION "close_voting"
5906 ( "issue"."id"%TYPE )
5907 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.';
5910 CREATE FUNCTION "defeat_strength"
5911 ( "positive_votes_p" INT4,
5912 "negative_votes_p" INT4,
5913 "defeat_strength_p" "defeat_strength" )
5914 RETURNS INT8
5915 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5916 BEGIN
5917 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
5918 IF "positive_votes_p" > "negative_votes_p" THEN
5919 RETURN "positive_votes_p";
5920 ELSE
5921 RETURN 0;
5922 END IF;
5923 ELSE
5924 IF "positive_votes_p" > "negative_votes_p" THEN
5925 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
5926 ELSIF "positive_votes_p" = "negative_votes_p" THEN
5927 RETURN 0;
5928 ELSE
5929 RETURN -1;
5930 END IF;
5931 END IF;
5932 END;
5933 $$;
5935 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")';
5938 CREATE FUNCTION "secondary_link_strength"
5939 ( "initiative1_ord_p" INT4,
5940 "initiative2_ord_p" INT4,
5941 "tie_breaking_p" "tie_breaking" )
5942 RETURNS INT8
5943 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5944 BEGIN
5945 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
5946 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
5947 END IF;
5948 RETURN (
5949 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
5951 ELSE
5952 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
5953 1::INT8 << 62
5954 ELSE 0 END
5956 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
5957 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
5958 ELSE
5959 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
5960 END
5961 END
5962 );
5963 END;
5964 $$;
5966 COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4, "tie_breaking") IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)';
5969 CREATE TYPE "link_strength" AS (
5970 "primary" INT8,
5971 "secondary" INT8 );
5973 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'')';
5976 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
5977 RETURNS "link_strength"[][]
5978 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5979 DECLARE
5980 "dimension_v" INT4;
5981 "matrix_p" "link_strength"[][];
5982 "i" INT4;
5983 "j" INT4;
5984 "k" INT4;
5985 BEGIN
5986 "dimension_v" := array_upper("matrix_d", 1);
5987 "matrix_p" := "matrix_d";
5988 "i" := 1;
5989 LOOP
5990 "j" := 1;
5991 LOOP
5992 IF "i" != "j" THEN
5993 "k" := 1;
5994 LOOP
5995 IF "i" != "k" AND "j" != "k" THEN
5996 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
5997 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
5998 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
5999 END IF;
6000 ELSE
6001 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
6002 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
6003 END IF;
6004 END IF;
6005 END IF;
6006 EXIT WHEN "k" = "dimension_v";
6007 "k" := "k" + 1;
6008 END LOOP;
6009 END IF;
6010 EXIT WHEN "j" = "dimension_v";
6011 "j" := "j" + 1;
6012 END LOOP;
6013 EXIT WHEN "i" = "dimension_v";
6014 "i" := "i" + 1;
6015 END LOOP;
6016 RETURN "matrix_p";
6017 END;
6018 $$;
6020 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
6023 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
6024 RETURNS VOID
6025 LANGUAGE 'plpgsql' VOLATILE AS $$
6026 DECLARE
6027 "issue_row" "issue"%ROWTYPE;
6028 "policy_row" "policy"%ROWTYPE;
6029 "dimension_v" INT4;
6030 "matrix_a" INT4[][]; -- absolute votes
6031 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
6032 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
6033 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
6034 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
6035 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
6036 "i" INT4;
6037 "j" INT4;
6038 "m" INT4;
6039 "n" INT4;
6040 "battle_row" "battle"%ROWTYPE;
6041 "rank_ary" INT4[];
6042 "rank_v" INT4;
6043 "initiative_id_v" "initiative"."id"%TYPE;
6044 BEGIN
6045 PERFORM "require_transaction_isolation"();
6046 SELECT * INTO "issue_row"
6047 FROM "issue" WHERE "id" = "issue_id_p";
6048 SELECT * INTO "policy_row"
6049 FROM "policy" WHERE "id" = "issue_row"."policy_id";
6050 SELECT count(1) INTO "dimension_v"
6051 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
6052 -- create "matrix_a" with absolute number of votes in pairwise
6053 -- comparison:
6054 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
6055 "i" := 1;
6056 "j" := 2;
6057 FOR "battle_row" IN
6058 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
6059 ORDER BY
6060 "winning_initiative_id" NULLS FIRST,
6061 "losing_initiative_id" NULLS FIRST
6062 LOOP
6063 "matrix_a"["i"]["j"] := "battle_row"."count";
6064 IF "j" = "dimension_v" THEN
6065 "i" := "i" + 1;
6066 "j" := 1;
6067 ELSE
6068 "j" := "j" + 1;
6069 IF "j" = "i" THEN
6070 "j" := "j" + 1;
6071 END IF;
6072 END IF;
6073 END LOOP;
6074 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
6075 RAISE EXCEPTION 'Wrong battle count (should not happen)';
6076 END IF;
6077 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
6078 -- and "secondary_link_strength" functions:
6079 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
6080 "i" := 1;
6081 LOOP
6082 "j" := 1;
6083 LOOP
6084 IF "i" != "j" THEN
6085 "matrix_d"["i"]["j"] := (
6086 "defeat_strength"(
6087 "matrix_a"["i"]["j"],
6088 "matrix_a"["j"]["i"],
6089 "policy_row"."defeat_strength"
6090 ),
6091 "secondary_link_strength"(
6092 "i",
6093 "j",
6094 "policy_row"."tie_breaking"
6096 )::"link_strength";
6097 END IF;
6098 EXIT WHEN "j" = "dimension_v";
6099 "j" := "j" + 1;
6100 END LOOP;
6101 EXIT WHEN "i" = "dimension_v";
6102 "i" := "i" + 1;
6103 END LOOP;
6104 -- find best paths:
6105 "matrix_p" := "find_best_paths"("matrix_d");
6106 -- create partial order:
6107 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
6108 "i" := 1;
6109 LOOP
6110 "j" := "i" + 1;
6111 LOOP
6112 IF "i" != "j" THEN
6113 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
6114 "matrix_b"["i"]["j"] := TRUE;
6115 "matrix_b"["j"]["i"] := FALSE;
6116 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
6117 "matrix_b"["i"]["j"] := FALSE;
6118 "matrix_b"["j"]["i"] := TRUE;
6119 END IF;
6120 END IF;
6121 EXIT WHEN "j" = "dimension_v";
6122 "j" := "j" + 1;
6123 END LOOP;
6124 EXIT WHEN "i" = "dimension_v" - 1;
6125 "i" := "i" + 1;
6126 END LOOP;
6127 -- tie-breaking by forbidding shared weakest links in beat-paths
6128 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
6129 -- is performed later by initiative id):
6130 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
6131 "m" := 1;
6132 LOOP
6133 "n" := "m" + 1;
6134 LOOP
6135 -- only process those candidates m and n, which are tied:
6136 IF "matrix_b"["m"]["n"] ISNULL THEN
6137 -- start with beat-paths prior tie-breaking:
6138 "matrix_t" := "matrix_p";
6139 -- start with all links allowed:
6140 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
6141 LOOP
6142 -- determine (and forbid) that link that is the weakest link
6143 -- in both the best path from candidate m to candidate n and
6144 -- from candidate n to candidate m:
6145 "i" := 1;
6146 <<forbid_one_link>>
6147 LOOP
6148 "j" := 1;
6149 LOOP
6150 IF "i" != "j" THEN
6151 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
6152 "matrix_f"["i"]["j"] := TRUE;
6153 -- exit for performance reasons,
6154 -- as exactly one link will be found:
6155 EXIT forbid_one_link;
6156 END IF;
6157 END IF;
6158 EXIT WHEN "j" = "dimension_v";
6159 "j" := "j" + 1;
6160 END LOOP;
6161 IF "i" = "dimension_v" THEN
6162 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
6163 END IF;
6164 "i" := "i" + 1;
6165 END LOOP;
6166 -- calculate best beat-paths while ignoring forbidden links:
6167 "i" := 1;
6168 LOOP
6169 "j" := 1;
6170 LOOP
6171 IF "i" != "j" THEN
6172 "matrix_t"["i"]["j"] := CASE
6173 WHEN "matrix_f"["i"]["j"]
6174 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
6175 ELSE "matrix_d"["i"]["j"] END;
6176 END IF;
6177 EXIT WHEN "j" = "dimension_v";
6178 "j" := "j" + 1;
6179 END LOOP;
6180 EXIT WHEN "i" = "dimension_v";
6181 "i" := "i" + 1;
6182 END LOOP;
6183 "matrix_t" := "find_best_paths"("matrix_t");
6184 -- extend partial order, if tie-breaking was successful:
6185 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
6186 "matrix_b"["m"]["n"] := TRUE;
6187 "matrix_b"["n"]["m"] := FALSE;
6188 EXIT;
6189 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
6190 "matrix_b"["m"]["n"] := FALSE;
6191 "matrix_b"["n"]["m"] := TRUE;
6192 EXIT;
6193 END IF;
6194 END LOOP;
6195 END IF;
6196 EXIT WHEN "n" = "dimension_v";
6197 "n" := "n" + 1;
6198 END LOOP;
6199 EXIT WHEN "m" = "dimension_v" - 1;
6200 "m" := "m" + 1;
6201 END LOOP;
6202 END IF;
6203 -- store a unique ranking in "rank_ary":
6204 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
6205 "rank_v" := 1;
6206 LOOP
6207 "i" := 1;
6208 <<assign_next_rank>>
6209 LOOP
6210 IF "rank_ary"["i"] ISNULL THEN
6211 "j" := 1;
6212 LOOP
6213 IF
6214 "i" != "j" AND
6215 "rank_ary"["j"] ISNULL AND
6216 ( "matrix_b"["j"]["i"] OR
6217 -- tie-breaking by "id"
6218 ( "matrix_b"["j"]["i"] ISNULL AND
6219 "j" < "i" ) )
6220 THEN
6221 -- someone else is better
6222 EXIT;
6223 END IF;
6224 IF "j" = "dimension_v" THEN
6225 -- noone is better
6226 "rank_ary"["i"] := "rank_v";
6227 EXIT assign_next_rank;
6228 END IF;
6229 "j" := "j" + 1;
6230 END LOOP;
6231 END IF;
6232 "i" := "i" + 1;
6233 IF "i" > "dimension_v" THEN
6234 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
6235 END IF;
6236 END LOOP;
6237 EXIT WHEN "rank_v" = "dimension_v";
6238 "rank_v" := "rank_v" + 1;
6239 END LOOP;
6240 -- write preliminary results:
6241 "i" := 2; -- omit status quo with "i" = 1
6242 FOR "initiative_id_v" IN
6243 SELECT "id" FROM "initiative"
6244 WHERE "issue_id" = "issue_id_p" AND "admitted"
6245 ORDER BY "id"
6246 LOOP
6247 UPDATE "initiative" SET
6248 "direct_majority" =
6249 CASE WHEN "policy_row"."direct_majority_strict" THEN
6250 "positive_votes" * "policy_row"."direct_majority_den" >
6251 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
6252 ELSE
6253 "positive_votes" * "policy_row"."direct_majority_den" >=
6254 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
6255 END
6256 AND "positive_votes" >= "policy_row"."direct_majority_positive"
6257 AND "issue_row"."voter_count"-"negative_votes" >=
6258 "policy_row"."direct_majority_non_negative",
6259 "indirect_majority" =
6260 CASE WHEN "policy_row"."indirect_majority_strict" THEN
6261 "positive_votes" * "policy_row"."indirect_majority_den" >
6262 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
6263 ELSE
6264 "positive_votes" * "policy_row"."indirect_majority_den" >=
6265 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
6266 END
6267 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
6268 AND "issue_row"."voter_count"-"negative_votes" >=
6269 "policy_row"."indirect_majority_non_negative",
6270 "schulze_rank" = "rank_ary"["i"],
6271 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
6272 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
6273 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
6274 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
6275 THEN NULL
6276 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
6277 "eligible" = FALSE,
6278 "winner" = FALSE,
6279 "rank" = NULL -- NOTE: in cases of manual reset of issue state
6280 WHERE "id" = "initiative_id_v";
6281 "i" := "i" + 1;
6282 END LOOP;
6283 IF "i" != "dimension_v" + 1 THEN
6284 RAISE EXCEPTION 'Wrong winner count (should not happen)';
6285 END IF;
6286 -- take indirect majorities into account:
6287 LOOP
6288 UPDATE "initiative" SET "indirect_majority" = TRUE
6289 FROM (
6290 SELECT "new_initiative"."id" AS "initiative_id"
6291 FROM "initiative" "old_initiative"
6292 JOIN "initiative" "new_initiative"
6293 ON "new_initiative"."issue_id" = "issue_id_p"
6294 AND "new_initiative"."indirect_majority" = FALSE
6295 JOIN "battle" "battle_win"
6296 ON "battle_win"."issue_id" = "issue_id_p"
6297 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
6298 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
6299 JOIN "battle" "battle_lose"
6300 ON "battle_lose"."issue_id" = "issue_id_p"
6301 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
6302 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
6303 WHERE "old_initiative"."issue_id" = "issue_id_p"
6304 AND "old_initiative"."indirect_majority" = TRUE
6305 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
6306 "battle_win"."count" * "policy_row"."indirect_majority_den" >
6307 "policy_row"."indirect_majority_num" *
6308 ("battle_win"."count"+"battle_lose"."count")
6309 ELSE
6310 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
6311 "policy_row"."indirect_majority_num" *
6312 ("battle_win"."count"+"battle_lose"."count")
6313 END
6314 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
6315 AND "issue_row"."voter_count"-"battle_lose"."count" >=
6316 "policy_row"."indirect_majority_non_negative"
6317 ) AS "subquery"
6318 WHERE "id" = "subquery"."initiative_id";
6319 EXIT WHEN NOT FOUND;
6320 END LOOP;
6321 -- set "multistage_majority" for remaining matching initiatives:
6322 UPDATE "initiative" SET "multistage_majority" = TRUE
6323 FROM (
6324 SELECT "losing_initiative"."id" AS "initiative_id"
6325 FROM "initiative" "losing_initiative"
6326 JOIN "initiative" "winning_initiative"
6327 ON "winning_initiative"."issue_id" = "issue_id_p"
6328 AND "winning_initiative"."admitted"
6329 JOIN "battle" "battle_win"
6330 ON "battle_win"."issue_id" = "issue_id_p"
6331 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
6332 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
6333 JOIN "battle" "battle_lose"
6334 ON "battle_lose"."issue_id" = "issue_id_p"
6335 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
6336 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
6337 WHERE "losing_initiative"."issue_id" = "issue_id_p"
6338 AND "losing_initiative"."admitted"
6339 AND "winning_initiative"."schulze_rank" <
6340 "losing_initiative"."schulze_rank"
6341 AND "battle_win"."count" > "battle_lose"."count"
6342 AND (
6343 "battle_win"."count" > "winning_initiative"."positive_votes" OR
6344 "battle_lose"."count" < "losing_initiative"."negative_votes" )
6345 ) AS "subquery"
6346 WHERE "id" = "subquery"."initiative_id";
6347 -- mark eligible initiatives:
6348 UPDATE "initiative" SET "eligible" = TRUE
6349 WHERE "issue_id" = "issue_id_p"
6350 AND "initiative"."direct_majority"
6351 AND "initiative"."indirect_majority"
6352 AND "initiative"."better_than_status_quo"
6353 AND (
6354 "policy_row"."no_multistage_majority" = FALSE OR
6355 "initiative"."multistage_majority" = FALSE )
6356 AND (
6357 "policy_row"."no_reverse_beat_path" = FALSE OR
6358 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
6359 -- mark final winner:
6360 UPDATE "initiative" SET "winner" = TRUE
6361 FROM (
6362 SELECT "id" AS "initiative_id"
6363 FROM "initiative"
6364 WHERE "issue_id" = "issue_id_p" AND "eligible"
6365 ORDER BY
6366 "schulze_rank",
6367 "id"
6368 LIMIT 1
6369 ) AS "subquery"
6370 WHERE "id" = "subquery"."initiative_id";
6371 -- write (final) ranks:
6372 "rank_v" := 1;
6373 FOR "initiative_id_v" IN
6374 SELECT "id"
6375 FROM "initiative"
6376 WHERE "issue_id" = "issue_id_p" AND "admitted"
6377 ORDER BY
6378 "winner" DESC,
6379 "eligible" DESC,
6380 "schulze_rank",
6381 "id"
6382 LOOP
6383 UPDATE "initiative" SET "rank" = "rank_v"
6384 WHERE "id" = "initiative_id_v";
6385 "rank_v" := "rank_v" + 1;
6386 END LOOP;
6387 -- set schulze rank of status quo and mark issue as finished:
6388 UPDATE "issue" SET
6389 "status_quo_schulze_rank" = "rank_ary"[1],
6390 "state" =
6391 CASE WHEN EXISTS (
6392 SELECT NULL FROM "initiative"
6393 WHERE "issue_id" = "issue_id_p" AND "winner"
6394 ) THEN
6395 'finished_with_winner'::"issue_state"
6396 ELSE
6397 'finished_without_winner'::"issue_state"
6398 END,
6399 "closed" = "phase_finished",
6400 "phase_finished" = NULL
6401 WHERE "id" = "issue_id_p";
6402 RETURN;
6403 END;
6404 $$;
6406 COMMENT ON FUNCTION "calculate_ranks"
6407 ( "issue"."id"%TYPE )
6408 IS 'Determine ranking (Votes have to be counted first)';
6412 -----------------------------
6413 -- Automatic state changes --
6414 -----------------------------
6417 CREATE FUNCTION "issue_admission"
6418 ( "area_id_p" "area"."id"%TYPE )
6419 RETURNS BOOLEAN
6420 LANGUAGE 'plpgsql' VOLATILE AS $$
6421 DECLARE
6422 "issue_id_v" "issue"."id"%TYPE;
6423 BEGIN
6424 PERFORM "dont_require_transaction_isolation"();
6425 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
6426 UPDATE "area" SET "issue_quorum" = "view"."issue_quorum"
6427 FROM "area_quorum" AS "view"
6428 WHERE "area"."id" = "view"."area_id"
6429 AND "area"."id" = "area_id_p";
6430 SELECT "id" INTO "issue_id_v" FROM "issue_for_admission"
6431 WHERE "area_id" = "area_id_p";
6432 IF "issue_id_v" ISNULL THEN RETURN FALSE; END IF;
6433 UPDATE "issue" SET
6434 "admission_snapshot_id" = "latest_snapshot_id",
6435 "state" = 'discussion',
6436 "accepted" = now(),
6437 "phase_finished" = NULL,
6438 "issue_quorum" = "issue_quorum"."issue_quorum"
6439 FROM "issue_quorum"
6440 WHERE "id" = "issue_id_v"
6441 AND "issue_quorum"."issue_id" = "issue_id_v";
6442 RETURN TRUE;
6443 END;
6444 $$;
6446 COMMENT ON FUNCTION "issue_admission"
6447 ( "area"."id"%TYPE )
6448 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';
6451 CREATE TYPE "check_issue_persistence" AS (
6452 "state" "issue_state",
6453 "phase_finished" BOOLEAN,
6454 "issue_revoked" BOOLEAN,
6455 "snapshot_created" BOOLEAN,
6456 "harmonic_weights_set" BOOLEAN,
6457 "closed_voting" BOOLEAN );
6459 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';
6462 CREATE FUNCTION "check_issue"
6463 ( "issue_id_p" "issue"."id"%TYPE,
6464 "persist" "check_issue_persistence" )
6465 RETURNS "check_issue_persistence"
6466 LANGUAGE 'plpgsql' VOLATILE AS $$
6467 DECLARE
6468 "issue_row" "issue"%ROWTYPE;
6469 "last_calculated_v" "snapshot"."calculated"%TYPE;
6470 "policy_row" "policy"%ROWTYPE;
6471 "initiative_row" "initiative"%ROWTYPE;
6472 "state_v" "issue_state";
6473 BEGIN
6474 PERFORM "require_transaction_isolation"();
6475 IF "persist" ISNULL THEN
6476 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6477 FOR UPDATE;
6478 SELECT "calculated" INTO "last_calculated_v"
6479 FROM "snapshot" JOIN "snapshot_issue"
6480 ON "snapshot"."id" = "snapshot_issue"."snapshot_id"
6481 WHERE "snapshot_issue"."issue_id" = "issue_id_p"
6482 ORDER BY "snapshot"."id" DESC;
6483 IF "issue_row"."closed" NOTNULL THEN
6484 RETURN NULL;
6485 END IF;
6486 "persist"."state" := "issue_row"."state";
6487 IF
6488 ( "issue_row"."state" = 'admission' AND "last_calculated_v" >=
6489 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
6490 ( "issue_row"."state" = 'discussion' AND now() >=
6491 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
6492 ( "issue_row"."state" = 'verification' AND now() >=
6493 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
6494 ( "issue_row"."state" = 'voting' AND now() >=
6495 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
6496 THEN
6497 "persist"."phase_finished" := TRUE;
6498 ELSE
6499 "persist"."phase_finished" := FALSE;
6500 END IF;
6501 IF
6502 NOT EXISTS (
6503 -- all initiatives are revoked
6504 SELECT NULL FROM "initiative"
6505 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6506 ) AND (
6507 -- and issue has not been accepted yet
6508 "persist"."state" = 'admission' OR
6509 -- or verification time has elapsed
6510 ( "persist"."state" = 'verification' AND
6511 "persist"."phase_finished" ) OR
6512 -- or no initiatives have been revoked lately
6513 NOT EXISTS (
6514 SELECT NULL FROM "initiative"
6515 WHERE "issue_id" = "issue_id_p"
6516 AND now() < "revoked" + "issue_row"."verification_time"
6519 THEN
6520 "persist"."issue_revoked" := TRUE;
6521 ELSE
6522 "persist"."issue_revoked" := FALSE;
6523 END IF;
6524 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
6525 UPDATE "issue" SET "phase_finished" = now()
6526 WHERE "id" = "issue_row"."id";
6527 RETURN "persist";
6528 ELSIF
6529 "persist"."state" IN ('admission', 'discussion', 'verification')
6530 THEN
6531 RETURN "persist";
6532 ELSE
6533 RETURN NULL;
6534 END IF;
6535 END IF;
6536 IF
6537 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6538 coalesce("persist"."snapshot_created", FALSE) = FALSE
6539 THEN
6540 IF "persist"."state" != 'admission' THEN
6541 PERFORM "take_snapshot"("issue_id_p");
6542 PERFORM "finish_snapshot"("issue_id_p");
6543 ELSE
6544 UPDATE "issue" SET "issue_quorum" = "issue_quorum"."issue_quorum"
6545 FROM "issue_quorum"
6546 WHERE "id" = "issue_id_p"
6547 AND "issue_quorum"."issue_id" = "issue_id_p";
6548 END IF;
6549 "persist"."snapshot_created" = TRUE;
6550 IF "persist"."phase_finished" THEN
6551 IF "persist"."state" = 'admission' THEN
6552 UPDATE "issue" SET "admission_snapshot_id" = "latest_snapshot_id"
6553 WHERE "id" = "issue_id_p";
6554 ELSIF "persist"."state" = 'discussion' THEN
6555 UPDATE "issue" SET "half_freeze_snapshot_id" = "latest_snapshot_id"
6556 WHERE "id" = "issue_id_p";
6557 ELSIF "persist"."state" = 'verification' THEN
6558 UPDATE "issue" SET "full_freeze_snapshot_id" = "latest_snapshot_id"
6559 WHERE "id" = "issue_id_p";
6560 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
6561 FOR "initiative_row" IN
6562 SELECT * FROM "initiative"
6563 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6564 FOR UPDATE
6565 LOOP
6566 IF
6567 "initiative_row"."polling" OR
6568 "initiative_row"."satisfied_supporter_count" >=
6569 "issue_row"."initiative_quorum"
6570 THEN
6571 UPDATE "initiative" SET "admitted" = TRUE
6572 WHERE "id" = "initiative_row"."id";
6573 ELSE
6574 UPDATE "initiative" SET "admitted" = FALSE
6575 WHERE "id" = "initiative_row"."id";
6576 END IF;
6577 END LOOP;
6578 END IF;
6579 END IF;
6580 RETURN "persist";
6581 END IF;
6582 IF
6583 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6584 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
6585 THEN
6586 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
6587 "persist"."harmonic_weights_set" = TRUE;
6588 IF
6589 "persist"."phase_finished" OR
6590 "persist"."issue_revoked" OR
6591 "persist"."state" = 'admission'
6592 THEN
6593 RETURN "persist";
6594 ELSE
6595 RETURN NULL;
6596 END IF;
6597 END IF;
6598 IF "persist"."issue_revoked" THEN
6599 IF "persist"."state" = 'admission' THEN
6600 "state_v" := 'canceled_revoked_before_accepted';
6601 ELSIF "persist"."state" = 'discussion' THEN
6602 "state_v" := 'canceled_after_revocation_during_discussion';
6603 ELSIF "persist"."state" = 'verification' THEN
6604 "state_v" := 'canceled_after_revocation_during_verification';
6605 END IF;
6606 UPDATE "issue" SET
6607 "state" = "state_v",
6608 "closed" = "phase_finished",
6609 "phase_finished" = NULL
6610 WHERE "id" = "issue_id_p";
6611 RETURN NULL;
6612 END IF;
6613 IF "persist"."state" = 'admission' THEN
6614 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6615 FOR UPDATE;
6616 IF "issue_row"."phase_finished" NOTNULL THEN
6617 UPDATE "issue" SET
6618 "state" = 'canceled_issue_not_accepted',
6619 "closed" = "phase_finished",
6620 "phase_finished" = NULL
6621 WHERE "id" = "issue_id_p";
6622 END IF;
6623 RETURN NULL;
6624 END IF;
6625 IF "persist"."phase_finished" THEN
6626 IF "persist"."state" = 'discussion' THEN
6627 UPDATE "issue" SET
6628 "state" = 'verification',
6629 "half_frozen" = "phase_finished",
6630 "phase_finished" = NULL
6631 WHERE "id" = "issue_id_p";
6632 RETURN NULL;
6633 END IF;
6634 IF "persist"."state" = 'verification' THEN
6635 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6636 FOR UPDATE;
6637 SELECT * INTO "policy_row" FROM "policy"
6638 WHERE "id" = "issue_row"."policy_id";
6639 IF EXISTS (
6640 SELECT NULL FROM "initiative"
6641 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
6642 ) THEN
6643 UPDATE "issue" SET
6644 "state" = 'voting',
6645 "fully_frozen" = "phase_finished",
6646 "phase_finished" = NULL
6647 WHERE "id" = "issue_id_p";
6648 ELSE
6649 UPDATE "issue" SET
6650 "state" = 'canceled_no_initiative_admitted',
6651 "fully_frozen" = "phase_finished",
6652 "closed" = "phase_finished",
6653 "phase_finished" = NULL
6654 WHERE "id" = "issue_id_p";
6655 -- NOTE: The following DELETE statements have effect only when
6656 -- issue state has been manipulated
6657 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
6658 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
6659 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
6660 END IF;
6661 RETURN NULL;
6662 END IF;
6663 IF "persist"."state" = 'voting' THEN
6664 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
6665 PERFORM "close_voting"("issue_id_p");
6666 "persist"."closed_voting" = TRUE;
6667 RETURN "persist";
6668 END IF;
6669 PERFORM "calculate_ranks"("issue_id_p");
6670 RETURN NULL;
6671 END IF;
6672 END IF;
6673 RAISE WARNING 'should not happen';
6674 RETURN NULL;
6675 END;
6676 $$;
6678 COMMENT ON FUNCTION "check_issue"
6679 ( "issue"."id"%TYPE,
6680 "check_issue_persistence" )
6681 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")';
6684 CREATE FUNCTION "check_everything"()
6685 RETURNS VOID
6686 LANGUAGE 'plpgsql' VOLATILE AS $$
6687 DECLARE
6688 "area_id_v" "area"."id"%TYPE;
6689 "snapshot_id_v" "snapshot"."id"%TYPE;
6690 "issue_id_v" "issue"."id"%TYPE;
6691 "persist_v" "check_issue_persistence";
6692 BEGIN
6693 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
6694 DELETE FROM "expired_session";
6695 DELETE FROM "expired_token";
6696 DELETE FROM "unused_snapshot";
6697 PERFORM "check_activity"();
6698 PERFORM "calculate_member_counts"();
6699 FOR "area_id_v" IN SELECT "id" FROM "area_with_unaccepted_issues" LOOP
6700 SELECT "take_snapshot"(NULL, "area_id_v") INTO "snapshot_id_v";
6701 PERFORM "finish_snapshot"("issue_id") FROM "snapshot_issue"
6702 WHERE "snapshot_id" = "snapshot_id_v";
6703 LOOP
6704 EXIT WHEN "issue_admission"("area_id_v") = FALSE;
6705 END LOOP;
6706 END LOOP;
6707 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
6708 "persist_v" := NULL;
6709 LOOP
6710 "persist_v" := "check_issue"("issue_id_v", "persist_v");
6711 EXIT WHEN "persist_v" ISNULL;
6712 END LOOP;
6713 END LOOP;
6714 DELETE FROM "unused_snapshot";
6715 RETURN;
6716 END;
6717 $$;
6719 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';
6723 ----------------------
6724 -- Deletion of data --
6725 ----------------------
6728 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
6729 RETURNS VOID
6730 LANGUAGE 'plpgsql' VOLATILE AS $$
6731 BEGIN
6732 IF EXISTS (
6733 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
6734 ) THEN
6735 -- override protection triggers:
6736 INSERT INTO "temporary_transaction_data" ("key", "value")
6737 VALUES ('override_protection_triggers', TRUE::TEXT);
6738 -- clean data:
6739 DELETE FROM "delegating_voter"
6740 WHERE "issue_id" = "issue_id_p";
6741 DELETE FROM "direct_voter"
6742 WHERE "issue_id" = "issue_id_p";
6743 DELETE FROM "delegating_interest_snapshot"
6744 WHERE "issue_id" = "issue_id_p";
6745 DELETE FROM "direct_interest_snapshot"
6746 WHERE "issue_id" = "issue_id_p";
6747 DELETE FROM "non_voter"
6748 WHERE "issue_id" = "issue_id_p";
6749 DELETE FROM "delegation"
6750 WHERE "issue_id" = "issue_id_p";
6751 DELETE FROM "supporter"
6752 USING "initiative" -- NOTE: due to missing index on issue_id
6753 WHERE "initiative"."issue_id" = "issue_id_p"
6754 AND "supporter"."initiative_id" = "initiative_id";
6755 -- mark issue as cleaned:
6756 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
6757 -- finish overriding protection triggers (avoids garbage):
6758 DELETE FROM "temporary_transaction_data"
6759 WHERE "key" = 'override_protection_triggers';
6760 END IF;
6761 RETURN;
6762 END;
6763 $$;
6765 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
6768 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
6769 RETURNS VOID
6770 LANGUAGE 'plpgsql' VOLATILE AS $$
6771 BEGIN
6772 UPDATE "member" SET
6773 "last_login" = NULL,
6774 "last_delegation_check" = NULL,
6775 "login" = NULL,
6776 "password" = NULL,
6777 "authority" = NULL,
6778 "authority_uid" = NULL,
6779 "authority_login" = NULL,
6780 "deleted" = coalesce("deleted", now()),
6781 "locked" = TRUE,
6782 "active" = FALSE,
6783 "notify_email" = NULL,
6784 "notify_email_unconfirmed" = NULL,
6785 "notify_email_secret" = NULL,
6786 "notify_email_secret_expiry" = NULL,
6787 "notify_email_lock_expiry" = NULL,
6788 "disable_notifications" = TRUE,
6789 "notification_counter" = DEFAULT,
6790 "notification_sample_size" = 0,
6791 "notification_dow" = NULL,
6792 "notification_hour" = NULL,
6793 "notification_sent" = NULL,
6794 "login_recovery_expiry" = NULL,
6795 "password_reset_secret" = NULL,
6796 "password_reset_secret_expiry" = NULL,
6797 "location" = NULL
6798 WHERE "id" = "member_id_p";
6799 DELETE FROM "member_settings" WHERE "member_id" = "member_id_p";
6800 DELETE FROM "member_profile" WHERE "member_id" = "member_id_p";
6801 DELETE FROM "rendered_member_statement" WHERE "member_id" = "member_id_p";
6802 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
6803 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
6804 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
6805 DELETE FROM "session" WHERE "member_id" = "member_id_p";
6806 DELETE FROM "member_application" WHERE "member_id" = "member_id_p";
6807 DELETE FROM "token" WHERE "member_id" = "member_id_p";
6808 DELETE FROM "subscription" WHERE "member_id" = "member_id_p";
6809 DELETE FROM "ignored_area" WHERE "member_id" = "member_id_p";
6810 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
6811 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
6812 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
6813 DELETE FROM "direct_voter" USING "issue"
6814 WHERE "direct_voter"."issue_id" = "issue"."id"
6815 AND "issue"."closed" ISNULL
6816 AND "member_id" = "member_id_p";
6817 DELETE FROM "notification_initiative_sent" WHERE "member_id" = "member_id_p";
6818 RETURN;
6819 END;
6820 $$;
6822 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)';
6825 CREATE FUNCTION "delete_private_data"()
6826 RETURNS VOID
6827 LANGUAGE 'plpgsql' VOLATILE AS $$
6828 BEGIN
6829 DELETE FROM "temporary_transaction_data";
6830 DELETE FROM "temporary_suggestion_counts";
6831 DELETE FROM "member" WHERE "activated" ISNULL;
6832 UPDATE "member" SET
6833 "invite_code" = NULL,
6834 "invite_code_expiry" = NULL,
6835 "admin_comment" = NULL,
6836 "last_login" = NULL,
6837 "last_delegation_check" = NULL,
6838 "login" = NULL,
6839 "password" = NULL,
6840 "authority" = NULL,
6841 "authority_uid" = NULL,
6842 "authority_login" = NULL,
6843 "lang" = NULL,
6844 "notify_email" = NULL,
6845 "notify_email_unconfirmed" = NULL,
6846 "notify_email_secret" = NULL,
6847 "notify_email_secret_expiry" = NULL,
6848 "notify_email_lock_expiry" = NULL,
6849 "disable_notifications" = TRUE,
6850 "notification_counter" = DEFAULT,
6851 "notification_sample_size" = 0,
6852 "notification_dow" = NULL,
6853 "notification_hour" = NULL,
6854 "notification_sent" = NULL,
6855 "login_recovery_expiry" = NULL,
6856 "password_reset_secret" = NULL,
6857 "password_reset_secret_expiry" = NULL,
6858 "location" = NULL;
6859 DELETE FROM "verification";
6860 DELETE FROM "member_settings";
6861 DELETE FROM "member_useterms";
6862 DELETE FROM "member_profile";
6863 DELETE FROM "rendered_member_statement";
6864 DELETE FROM "member_image";
6865 DELETE FROM "contact";
6866 DELETE FROM "ignored_member";
6867 DELETE FROM "session";
6868 DELETE FROM "system_application";
6869 DELETE FROM "system_application_redirect_uri";
6870 DELETE FROM "dynamic_application_scope";
6871 DELETE FROM "member_application";
6872 DELETE FROM "token";
6873 DELETE FROM "subscription";
6874 DELETE FROM "ignored_area";
6875 DELETE FROM "ignored_initiative";
6876 DELETE FROM "non_voter";
6877 DELETE FROM "direct_voter" USING "issue"
6878 WHERE "direct_voter"."issue_id" = "issue"."id"
6879 AND "issue"."closed" ISNULL;
6880 DELETE FROM "event_processed";
6881 DELETE FROM "notification_initiative_sent";
6882 DELETE FROM "newsletter";
6883 RETURN;
6884 END;
6885 $$;
6887 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.';
6891 COMMIT;

Impressum / About Us