liquid_feedback_core

view core.sql @ 595:87914d1b757f

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

Impressum / About Us