liquid_feedback_core

view core.sql @ 599:81cd9463878f

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

Impressum / About Us