liquid_feedback_core

view core.sql @ 600:f61caa45de94

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

Impressum / About Us