liquid_feedback_core

view core.sql @ 597:d34f8403d2c6

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

Impressum / About Us