liquid_feedback_core

view core.sql @ 598:f02b7ea48971

Added tables "file" and "draft_attachment"
author jbe
date Thu Feb 06 18:40:46 2020 +0100 (2020-02-06)
parents d34f8403d2c6
children 81cd9463878f
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.';
3166 ---------------------------------
3167 -- Delete incomplete snapshots --
3168 ---------------------------------
3171 CREATE FUNCTION "delete_snapshot_on_partial_delete_trigger"()
3172 RETURNS TRIGGER
3173 LANGUAGE 'plpgsql' VOLATILE AS $$
3174 BEGIN
3175 IF TG_OP = 'UPDATE' THEN
3176 IF
3177 OLD."snapshot_id" = NEW."snapshot_id" AND
3178 OLD."issue_id" = NEW."issue_id"
3179 THEN
3180 RETURN NULL;
3181 END IF;
3182 END IF;
3183 DELETE FROM "snapshot" WHERE "id" = OLD."snapshot_id";
3184 RETURN NULL;
3185 END;
3186 $$;
3188 CREATE TRIGGER "delete_snapshot_on_partial_delete"
3189 AFTER UPDATE OR DELETE ON "snapshot_issue"
3190 FOR EACH ROW EXECUTE PROCEDURE
3191 "delete_snapshot_on_partial_delete_trigger"();
3193 COMMENT ON FUNCTION "delete_snapshot_on_partial_delete_trigger"() IS 'Implementation of trigger "delete_snapshot_on_partial_delete" on table "snapshot_issue"';
3194 COMMENT ON TRIGGER "delete_snapshot_on_partial_delete" ON "snapshot_issue" IS 'Deletes whole snapshot if one issue is deleted from the snapshot';
3198 ---------------------------------------------------------------
3199 -- Ensure that votes are not modified when issues are closed --
3200 ---------------------------------------------------------------
3202 -- NOTE: Frontends should ensure this anyway, but in case of programming
3203 -- errors the following triggers ensure data integrity.
3206 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
3207 RETURNS TRIGGER
3208 LANGUAGE 'plpgsql' VOLATILE AS $$
3209 DECLARE
3210 "issue_id_v" "issue"."id"%TYPE;
3211 "issue_row" "issue"%ROWTYPE;
3212 BEGIN
3213 IF EXISTS (
3214 SELECT NULL FROM "temporary_transaction_data"
3215 WHERE "txid" = txid_current()
3216 AND "key" = 'override_protection_triggers'
3217 AND "value" = TRUE::TEXT
3218 ) THEN
3219 RETURN NULL;
3220 END IF;
3221 IF TG_OP = 'DELETE' THEN
3222 "issue_id_v" := OLD."issue_id";
3223 ELSE
3224 "issue_id_v" := NEW."issue_id";
3225 END IF;
3226 SELECT INTO "issue_row" * FROM "issue"
3227 WHERE "id" = "issue_id_v" FOR SHARE;
3228 IF (
3229 "issue_row"."closed" NOTNULL OR (
3230 "issue_row"."state" = 'voting' AND
3231 "issue_row"."phase_finished" NOTNULL
3233 ) THEN
3234 IF
3235 TG_RELID = 'direct_voter'::regclass AND
3236 TG_OP = 'UPDATE'
3237 THEN
3238 IF
3239 OLD."issue_id" = NEW."issue_id" AND
3240 OLD."member_id" = NEW."member_id" AND
3241 OLD."weight" = NEW."weight"
3242 THEN
3243 RETURN NULL; -- allows changing of voter comment
3244 END IF;
3245 END IF;
3246 RAISE EXCEPTION 'Tried to modify data after voting has been closed.' USING
3247 ERRCODE = 'integrity_constraint_violation';
3248 END IF;
3249 RETURN NULL;
3250 END;
3251 $$;
3253 CREATE TRIGGER "forbid_changes_on_closed_issue"
3254 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
3255 FOR EACH ROW EXECUTE PROCEDURE
3256 "forbid_changes_on_closed_issue_trigger"();
3258 CREATE TRIGGER "forbid_changes_on_closed_issue"
3259 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
3260 FOR EACH ROW EXECUTE PROCEDURE
3261 "forbid_changes_on_closed_issue_trigger"();
3263 CREATE TRIGGER "forbid_changes_on_closed_issue"
3264 AFTER INSERT OR UPDATE OR DELETE ON "vote"
3265 FOR EACH ROW EXECUTE PROCEDURE
3266 "forbid_changes_on_closed_issue_trigger"();
3268 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"';
3269 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';
3270 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';
3271 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';
3275 --------------------------------------------------------------------
3276 -- Auto-retrieval of fields only needed for referential integrity --
3277 --------------------------------------------------------------------
3280 CREATE FUNCTION "autofill_issue_id_trigger"()
3281 RETURNS TRIGGER
3282 LANGUAGE 'plpgsql' VOLATILE AS $$
3283 BEGIN
3284 IF NEW."issue_id" ISNULL THEN
3285 SELECT "issue_id" INTO NEW."issue_id"
3286 FROM "initiative" WHERE "id" = NEW."initiative_id";
3287 END IF;
3288 RETURN NEW;
3289 END;
3290 $$;
3292 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
3293 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3295 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
3296 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3298 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
3299 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
3300 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
3303 CREATE FUNCTION "autofill_initiative_id_trigger"()
3304 RETURNS TRIGGER
3305 LANGUAGE 'plpgsql' VOLATILE AS $$
3306 BEGIN
3307 IF NEW."initiative_id" ISNULL THEN
3308 SELECT "initiative_id" INTO NEW."initiative_id"
3309 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3310 END IF;
3311 RETURN NEW;
3312 END;
3313 $$;
3315 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
3316 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
3318 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
3319 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
3323 -------------------------------------------------------
3324 -- Automatic copying of values for indexing purposes --
3325 -------------------------------------------------------
3328 CREATE FUNCTION "copy_current_draft_data"
3329 ("initiative_id_p" "initiative"."id"%TYPE )
3330 RETURNS VOID
3331 LANGUAGE 'plpgsql' VOLATILE AS $$
3332 BEGIN
3333 PERFORM NULL FROM "initiative" WHERE "id" = "initiative_id_p"
3334 FOR UPDATE;
3335 UPDATE "initiative" SET
3336 "location" = "draft"."location",
3337 "content" = "draft"."content"
3338 FROM "current_draft" AS "draft"
3339 WHERE "initiative"."id" = "initiative_id_p"
3340 AND "draft"."initiative_id" = "initiative_id_p";
3341 END;
3342 $$;
3344 COMMENT ON FUNCTION "copy_current_draft_data"
3345 ( "initiative"."id"%TYPE )
3346 IS 'Helper function for function "copy_current_draft_data_trigger"';
3349 CREATE FUNCTION "copy_current_draft_data_trigger"()
3350 RETURNS TRIGGER
3351 LANGUAGE 'plpgsql' VOLATILE AS $$
3352 BEGIN
3353 IF TG_OP='DELETE' THEN
3354 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3355 ELSE
3356 IF TG_OP='UPDATE' THEN
3357 IF COALESCE(OLD."inititiave_id" != NEW."initiative_id", TRUE) THEN
3358 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3359 END IF;
3360 END IF;
3361 PERFORM "copy_current_draft_data"(NEW."initiative_id");
3362 END IF;
3363 RETURN NULL;
3364 END;
3365 $$;
3367 CREATE TRIGGER "copy_current_draft_data"
3368 AFTER INSERT OR UPDATE OR DELETE ON "draft"
3369 FOR EACH ROW EXECUTE PROCEDURE
3370 "copy_current_draft_data_trigger"();
3372 COMMENT ON FUNCTION "copy_current_draft_data_trigger"() IS 'Implementation of trigger "copy_current_draft_data" on table "draft"';
3373 COMMENT ON TRIGGER "copy_current_draft_data" ON "draft" IS 'Copy certain fields from most recent "draft" to "initiative"';
3377 -----------------------------------------------------
3378 -- Automatic calculation of certain default values --
3379 -----------------------------------------------------
3382 CREATE FUNCTION "copy_timings_trigger"()
3383 RETURNS TRIGGER
3384 LANGUAGE 'plpgsql' VOLATILE AS $$
3385 DECLARE
3386 "policy_row" "policy"%ROWTYPE;
3387 BEGIN
3388 SELECT * INTO "policy_row" FROM "policy"
3389 WHERE "id" = NEW."policy_id";
3390 IF NEW."min_admission_time" ISNULL THEN
3391 NEW."min_admission_time" := "policy_row"."min_admission_time";
3392 END IF;
3393 IF NEW."max_admission_time" ISNULL THEN
3394 NEW."max_admission_time" := "policy_row"."max_admission_time";
3395 END IF;
3396 IF NEW."discussion_time" ISNULL THEN
3397 NEW."discussion_time" := "policy_row"."discussion_time";
3398 END IF;
3399 IF NEW."verification_time" ISNULL THEN
3400 NEW."verification_time" := "policy_row"."verification_time";
3401 END IF;
3402 IF NEW."voting_time" ISNULL THEN
3403 NEW."voting_time" := "policy_row"."voting_time";
3404 END IF;
3405 RETURN NEW;
3406 END;
3407 $$;
3409 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
3410 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
3412 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
3413 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
3416 CREATE FUNCTION "default_for_draft_id_trigger"()
3417 RETURNS TRIGGER
3418 LANGUAGE 'plpgsql' VOLATILE AS $$
3419 BEGIN
3420 IF NEW."draft_id" ISNULL THEN
3421 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
3422 WHERE "initiative_id" = NEW."initiative_id";
3423 END IF;
3424 RETURN NEW;
3425 END;
3426 $$;
3428 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
3429 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3430 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
3431 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3433 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
3434 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';
3435 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';
3439 ----------------------------------------
3440 -- Automatic creation of dependencies --
3441 ----------------------------------------
3444 CREATE FUNCTION "autocreate_interest_trigger"()
3445 RETURNS TRIGGER
3446 LANGUAGE 'plpgsql' VOLATILE AS $$
3447 BEGIN
3448 IF NOT EXISTS (
3449 SELECT NULL FROM "initiative" JOIN "interest"
3450 ON "initiative"."issue_id" = "interest"."issue_id"
3451 WHERE "initiative"."id" = NEW."initiative_id"
3452 AND "interest"."member_id" = NEW."member_id"
3453 ) THEN
3454 BEGIN
3455 INSERT INTO "interest" ("issue_id", "member_id")
3456 SELECT "issue_id", NEW."member_id"
3457 FROM "initiative" WHERE "id" = NEW."initiative_id";
3458 EXCEPTION WHEN unique_violation THEN END;
3459 END IF;
3460 RETURN NEW;
3461 END;
3462 $$;
3464 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
3465 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
3467 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
3468 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';
3471 CREATE FUNCTION "autocreate_supporter_trigger"()
3472 RETURNS TRIGGER
3473 LANGUAGE 'plpgsql' VOLATILE AS $$
3474 BEGIN
3475 IF NOT EXISTS (
3476 SELECT NULL FROM "suggestion" JOIN "supporter"
3477 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
3478 WHERE "suggestion"."id" = NEW."suggestion_id"
3479 AND "supporter"."member_id" = NEW."member_id"
3480 ) THEN
3481 BEGIN
3482 INSERT INTO "supporter" ("initiative_id", "member_id")
3483 SELECT "initiative_id", NEW."member_id"
3484 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3485 EXCEPTION WHEN unique_violation THEN END;
3486 END IF;
3487 RETURN NEW;
3488 END;
3489 $$;
3491 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
3492 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
3494 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
3495 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.';
3499 ------------------------------------------
3500 -- Views and helper functions for views --
3501 ------------------------------------------
3504 CREATE VIEW "member_eligible_to_be_notified" AS
3505 SELECT * FROM "member"
3506 WHERE "activated" NOTNULL AND "locked" = FALSE;
3508 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")';
3511 CREATE VIEW "member_to_notify" AS
3512 SELECT * FROM "member_eligible_to_be_notified"
3513 WHERE "disable_notifications" = FALSE;
3515 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)';
3518 CREATE VIEW "follower" AS
3519 SELECT
3520 "id" AS "follower_id",
3521 ( SELECT ARRAY["member"."id"] || array_agg("contact"."other_member_id")
3522 FROM "contact"
3523 WHERE "contact"."member_id" = "member"."id" AND "contact"."following" )
3524 AS "following_ids"
3525 FROM "member";
3527 COMMENT ON VIEW "follower" IS 'Provides the contacts of each member that are being followed (including the member itself) as an array of IDs';
3530 CREATE VIEW "area_quorum" AS
3531 SELECT
3532 "area"."id" AS "area_id",
3533 ceil(
3534 "area"."quorum_standard"::FLOAT8 * "quorum_factor"::FLOAT8 ^ (
3535 coalesce(
3536 ( SELECT sum(
3537 ( extract(epoch from "area"."quorum_time")::FLOAT8 /
3538 extract(epoch from
3539 ("issue"."accepted"-"issue"."created") +
3540 "issue"."discussion_time" +
3541 "issue"."verification_time" +
3542 "issue"."voting_time"
3543 )::FLOAT8
3544 ) ^ "area"."quorum_exponent"::FLOAT8
3546 FROM "issue" JOIN "policy"
3547 ON "issue"."policy_id" = "policy"."id"
3548 WHERE "issue"."area_id" = "area"."id"
3549 AND "issue"."accepted" NOTNULL
3550 AND "issue"."closed" ISNULL
3551 AND "policy"."polling" = FALSE
3552 )::FLOAT8, 0::FLOAT8
3553 ) / "area"."quorum_issues"::FLOAT8 - 1::FLOAT8
3554 ) * CASE WHEN "area"."quorum_den" ISNULL THEN 1 ELSE (
3555 SELECT "snapshot"."population"
3556 FROM "snapshot"
3557 WHERE "snapshot"."area_id" = "area"."id"
3558 AND "snapshot"."issue_id" ISNULL
3559 ORDER BY "snapshot"."id" DESC
3560 LIMIT 1
3561 ) END / coalesce("area"."quorum_den", 1)
3563 )::INT4 AS "issue_quorum"
3564 FROM "area";
3566 COMMENT ON VIEW "area_quorum" IS 'Area-based quorum considering number of open (accepted) issues';
3569 CREATE VIEW "issue_quorum" AS
3570 SELECT DISTINCT ON ("issue_id")
3571 "issue"."id" AS "issue_id",
3572 "subquery"."issue_quorum"
3573 FROM "issue"
3574 CROSS JOIN LATERAL (
3575 SELECT "area_quorum"."issue_quorum"
3576 FROM "area_quorum" WHERE "area_quorum"."area_id" = "issue"."area_id"
3577 UNION ALL
3578 SELECT "policy"."issue_quorum"
3579 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3580 UNION ALL
3581 SELECT
3582 ceil(
3583 ("issue"."population"::INT8 * "policy"."issue_quorum_num"::INT8) /
3584 "policy"."issue_quorum_den"::FLOAT8
3585 )::INT4
3586 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3587 ) AS "subquery"
3588 ORDER BY "issue_id", "issue_quorum" DESC;
3590 COMMENT ON VIEW "issue_quorum" IS 'Effective quorum for issue admission';
3593 CREATE VIEW "area_with_unaccepted_issues" AS
3594 SELECT DISTINCT ON ("area"."id") "area".*
3595 FROM "area" JOIN "issue" ON "area"."id" = "issue"."area_id"
3596 WHERE "issue"."state" = 'admission';
3598 COMMENT ON VIEW "area_with_unaccepted_issues" IS 'All areas with unaccepted open issues (needed for issue admission system)';
3601 CREATE VIEW "issue_for_admission" AS
3602 SELECT DISTINCT ON ("issue"."area_id")
3603 "issue".*,
3604 max("initiative"."supporter_count") AS "max_supporter_count"
3605 FROM "issue"
3606 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
3607 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
3608 JOIN "area" ON "issue"."area_id" = "area"."id"
3609 WHERE "issue"."state" = 'admission'::"issue_state"
3610 AND now() >= "issue"."created" + "issue"."min_admission_time"
3611 AND "initiative"."supporter_count" >= "policy"."issue_quorum"
3612 AND "initiative"."supporter_count" * "policy"."issue_quorum_den" >=
3613 "issue"."population" * "policy"."issue_quorum_num"
3614 AND "initiative"."supporter_count" >= "area"."issue_quorum"
3615 AND "initiative"."revoked" ISNULL
3616 GROUP BY "issue"."id"
3617 ORDER BY "issue"."area_id", "max_supporter_count" DESC, "issue"."id";
3619 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';
3622 CREATE VIEW "unit_delegation" AS
3623 SELECT
3624 "unit"."id" AS "unit_id",
3625 "delegation"."id",
3626 "delegation"."truster_id",
3627 "delegation"."trustee_id",
3628 "delegation"."scope"
3629 FROM "unit"
3630 JOIN "delegation"
3631 ON "delegation"."unit_id" = "unit"."id"
3632 JOIN "member"
3633 ON "delegation"."truster_id" = "member"."id"
3634 JOIN "privilege"
3635 ON "delegation"."unit_id" = "privilege"."unit_id"
3636 AND "delegation"."truster_id" = "privilege"."member_id"
3637 WHERE "member"."active" AND "privilege"."voting_right";
3639 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
3642 CREATE VIEW "area_delegation" AS
3643 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
3644 "area"."id" AS "area_id",
3645 "delegation"."id",
3646 "delegation"."truster_id",
3647 "delegation"."trustee_id",
3648 "delegation"."scope"
3649 FROM "area"
3650 JOIN "delegation"
3651 ON "delegation"."unit_id" = "area"."unit_id"
3652 OR "delegation"."area_id" = "area"."id"
3653 JOIN "member"
3654 ON "delegation"."truster_id" = "member"."id"
3655 JOIN "privilege"
3656 ON "area"."unit_id" = "privilege"."unit_id"
3657 AND "delegation"."truster_id" = "privilege"."member_id"
3658 WHERE "member"."active" AND "privilege"."voting_right"
3659 ORDER BY
3660 "area"."id",
3661 "delegation"."truster_id",
3662 "delegation"."scope" DESC;
3664 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
3667 CREATE VIEW "issue_delegation" AS
3668 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
3669 "issue"."id" AS "issue_id",
3670 "delegation"."id",
3671 "delegation"."truster_id",
3672 "delegation"."trustee_id",
3673 "delegation"."scope"
3674 FROM "issue"
3675 JOIN "area"
3676 ON "area"."id" = "issue"."area_id"
3677 JOIN "delegation"
3678 ON "delegation"."unit_id" = "area"."unit_id"
3679 OR "delegation"."area_id" = "area"."id"
3680 OR "delegation"."issue_id" = "issue"."id"
3681 JOIN "member"
3682 ON "delegation"."truster_id" = "member"."id"
3683 JOIN "privilege"
3684 ON "area"."unit_id" = "privilege"."unit_id"
3685 AND "delegation"."truster_id" = "privilege"."member_id"
3686 WHERE "member"."active" AND "privilege"."voting_right"
3687 ORDER BY
3688 "issue"."id",
3689 "delegation"."truster_id",
3690 "delegation"."scope" DESC;
3692 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
3695 CREATE VIEW "member_count_view" AS
3696 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
3698 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
3701 CREATE VIEW "unit_member" AS
3702 SELECT
3703 "unit"."id" AS "unit_id",
3704 "member"."id" AS "member_id"
3705 FROM "privilege"
3706 JOIN "unit" ON "unit"."id" = "privilege"."unit_id"
3707 JOIN "member" ON "member"."id" = "privilege"."member_id"
3708 WHERE "privilege"."voting_right" AND "member"."active";
3710 COMMENT ON VIEW "unit_member" IS 'Active members with voting right in a unit';
3713 CREATE VIEW "unit_member_count" AS
3714 SELECT
3715 "unit"."id" AS "unit_id",
3716 count("unit_member"."member_id") AS "member_count"
3717 FROM "unit" LEFT JOIN "unit_member"
3718 ON "unit"."id" = "unit_member"."unit_id"
3719 GROUP BY "unit"."id";
3721 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
3724 CREATE VIEW "opening_draft" AS
3725 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3726 ORDER BY "initiative_id", "id";
3728 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
3731 CREATE VIEW "current_draft" AS
3732 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3733 ORDER BY "initiative_id", "id" DESC;
3735 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
3738 CREATE VIEW "critical_opinion" AS
3739 SELECT * FROM "opinion"
3740 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
3741 OR ("degree" = -2 AND "fulfilled" = TRUE);
3743 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
3746 CREATE VIEW "issue_supporter_in_admission_state" AS
3747 SELECT
3748 "area"."unit_id",
3749 "issue"."area_id",
3750 "issue"."id" AS "issue_id",
3751 "supporter"."member_id",
3752 "direct_interest_snapshot"."weight"
3753 FROM "issue"
3754 JOIN "area" ON "area"."id" = "issue"."area_id"
3755 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
3756 JOIN "direct_interest_snapshot"
3757 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3758 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3759 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
3760 WHERE "issue"."state" = 'admission'::"issue_state";
3762 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';
3765 CREATE VIEW "initiative_suggestion_order_calculation" AS
3766 SELECT
3767 "initiative"."id" AS "initiative_id",
3768 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
3769 FROM "initiative" JOIN "issue"
3770 ON "initiative"."issue_id" = "issue"."id"
3771 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
3772 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
3774 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
3776 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';
3779 CREATE VIEW "individual_suggestion_ranking" AS
3780 SELECT
3781 "opinion"."initiative_id",
3782 "opinion"."member_id",
3783 "direct_interest_snapshot"."weight",
3784 CASE WHEN
3785 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
3786 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
3787 THEN 1 ELSE
3788 CASE WHEN
3789 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
3790 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
3791 THEN 2 ELSE
3792 CASE WHEN
3793 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
3794 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
3795 THEN 3 ELSE 4 END
3796 END
3797 END AS "preference",
3798 "opinion"."suggestion_id"
3799 FROM "opinion"
3800 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
3801 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3802 JOIN "direct_interest_snapshot"
3803 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3804 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3805 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
3807 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
3810 CREATE VIEW "battle_participant" AS
3811 SELECT "initiative"."id", "initiative"."issue_id"
3812 FROM "issue" JOIN "initiative"
3813 ON "issue"."id" = "initiative"."issue_id"
3814 WHERE "initiative"."admitted"
3815 UNION ALL
3816 SELECT NULL, "id" AS "issue_id"
3817 FROM "issue";
3819 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
3822 CREATE VIEW "battle_view" AS
3823 SELECT
3824 "issue"."id" AS "issue_id",
3825 "winning_initiative"."id" AS "winning_initiative_id",
3826 "losing_initiative"."id" AS "losing_initiative_id",
3827 sum(
3828 CASE WHEN
3829 coalesce("better_vote"."grade", 0) >
3830 coalesce("worse_vote"."grade", 0)
3831 THEN "direct_voter"."weight" ELSE 0 END
3832 ) AS "count"
3833 FROM "issue"
3834 LEFT JOIN "direct_voter"
3835 ON "issue"."id" = "direct_voter"."issue_id"
3836 JOIN "battle_participant" AS "winning_initiative"
3837 ON "issue"."id" = "winning_initiative"."issue_id"
3838 JOIN "battle_participant" AS "losing_initiative"
3839 ON "issue"."id" = "losing_initiative"."issue_id"
3840 LEFT JOIN "vote" AS "better_vote"
3841 ON "direct_voter"."member_id" = "better_vote"."member_id"
3842 AND "winning_initiative"."id" = "better_vote"."initiative_id"
3843 LEFT JOIN "vote" AS "worse_vote"
3844 ON "direct_voter"."member_id" = "worse_vote"."member_id"
3845 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
3846 WHERE "issue"."state" = 'voting'
3847 AND "issue"."phase_finished" NOTNULL
3848 AND (
3849 "winning_initiative"."id" != "losing_initiative"."id" OR
3850 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
3851 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
3852 GROUP BY
3853 "issue"."id",
3854 "winning_initiative"."id",
3855 "losing_initiative"."id";
3857 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';
3860 CREATE VIEW "expired_session" AS
3861 SELECT * FROM "session" WHERE now() > "expiry";
3863 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
3864 DELETE FROM "session" WHERE "id" = OLD."id";
3866 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
3867 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
3870 CREATE VIEW "expired_token" AS
3871 SELECT * FROM "token" WHERE now() > "expiry" AND NOT (
3872 "token_type" = 'authorization' AND "used" AND EXISTS (
3873 SELECT NULL FROM "token" AS "other"
3874 WHERE "other"."authorization_token_id" = "token"."id" ) );
3876 CREATE RULE "delete" AS ON DELETE TO "expired_token" DO INSTEAD
3877 DELETE FROM "token" WHERE "id" = OLD."id";
3879 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';
3882 CREATE VIEW "unused_snapshot" AS
3883 SELECT "snapshot".* FROM "snapshot"
3884 LEFT JOIN "issue"
3885 ON "snapshot"."id" = "issue"."latest_snapshot_id"
3886 OR "snapshot"."id" = "issue"."admission_snapshot_id"
3887 OR "snapshot"."id" = "issue"."half_freeze_snapshot_id"
3888 OR "snapshot"."id" = "issue"."full_freeze_snapshot_id"
3889 WHERE "issue"."id" ISNULL;
3891 CREATE RULE "delete" AS ON DELETE TO "unused_snapshot" DO INSTEAD
3892 DELETE FROM "snapshot" WHERE "id" = OLD."id";
3894 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)';
3897 CREATE VIEW "open_issue" AS
3898 SELECT * FROM "issue" WHERE "closed" ISNULL;
3900 COMMENT ON VIEW "open_issue" IS 'All open issues';
3903 CREATE VIEW "member_contingent" AS
3904 SELECT
3905 "member"."id" AS "member_id",
3906 "contingent"."polling",
3907 "contingent"."time_frame",
3908 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
3910 SELECT count(1) FROM "draft"
3911 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3912 WHERE "draft"."author_id" = "member"."id"
3913 AND "initiative"."polling" = "contingent"."polling"
3914 AND "draft"."created" > now() - "contingent"."time_frame"
3915 ) + (
3916 SELECT count(1) FROM "suggestion"
3917 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
3918 WHERE "suggestion"."author_id" = "member"."id"
3919 AND "contingent"."polling" = FALSE
3920 AND "suggestion"."created" > now() - "contingent"."time_frame"
3922 ELSE NULL END AS "text_entry_count",
3923 "contingent"."text_entry_limit",
3924 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
3925 SELECT count(1) FROM "opening_draft" AS "draft"
3926 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3927 WHERE "draft"."author_id" = "member"."id"
3928 AND "initiative"."polling" = "contingent"."polling"
3929 AND "draft"."created" > now() - "contingent"."time_frame"
3930 ) ELSE NULL END AS "initiative_count",
3931 "contingent"."initiative_limit"
3932 FROM "member" CROSS JOIN "contingent";
3934 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
3936 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
3937 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
3940 CREATE VIEW "member_contingent_left" AS
3941 SELECT
3942 "member_id",
3943 "polling",
3944 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
3945 max("initiative_limit" - "initiative_count") AS "initiatives_left"
3946 FROM "member_contingent" GROUP BY "member_id", "polling";
3948 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.';
3951 CREATE VIEW "event_for_notification" AS
3952 SELECT
3953 "member"."id" AS "recipient_id",
3954 "event".*
3955 FROM "member" CROSS JOIN "event"
3956 JOIN "issue" ON "issue"."id" = "event"."issue_id"
3957 JOIN "area" ON "area"."id" = "issue"."area_id"
3958 LEFT JOIN "privilege" ON
3959 "privilege"."member_id" = "member"."id" AND
3960 "privilege"."unit_id" = "area"."unit_id" AND
3961 "privilege"."voting_right" = TRUE
3962 LEFT JOIN "subscription" ON
3963 "subscription"."member_id" = "member"."id" AND
3964 "subscription"."unit_id" = "area"."unit_id"
3965 LEFT JOIN "ignored_area" ON
3966 "ignored_area"."member_id" = "member"."id" AND
3967 "ignored_area"."area_id" = "issue"."area_id"
3968 LEFT JOIN "interest" ON
3969 "interest"."member_id" = "member"."id" AND
3970 "interest"."issue_id" = "event"."issue_id"
3971 LEFT JOIN "supporter" ON
3972 "supporter"."member_id" = "member"."id" AND
3973 "supporter"."initiative_id" = "event"."initiative_id"
3974 WHERE ("privilege"."member_id" NOTNULL OR "subscription"."member_id" NOTNULL)
3975 AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL)
3976 AND (
3977 "event"."event" = 'issue_state_changed'::"event_type" OR
3978 ( "event"."event" = 'initiative_revoked'::"event_type" AND
3979 "supporter"."member_id" NOTNULL ) );
3981 COMMENT ON VIEW "event_for_notification" IS 'Entries of the "event" table which are of interest for a particular notification mail recipient';
3983 COMMENT ON COLUMN "event_for_notification"."recipient_id" IS 'member_id of the recipient of a notification mail';
3986 CREATE VIEW "updated_initiative" AS
3987 SELECT
3988 "supporter"."member_id" AS "recipient_id",
3989 FALSE AS "featured",
3990 "supporter"."initiative_id"
3991 FROM "supporter"
3992 JOIN "initiative" ON "supporter"."initiative_id" = "initiative"."id"
3993 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3994 LEFT JOIN "notification_initiative_sent" AS "sent" ON
3995 "sent"."member_id" = "supporter"."member_id" AND
3996 "sent"."initiative_id" = "supporter"."initiative_id"
3997 LEFT JOIN "ignored_initiative" ON
3998 "ignored_initiative"."member_id" = "supporter"."member_id" AND
3999 "ignored_initiative"."initiative_id" = "supporter"."initiative_id"
4000 WHERE "issue"."state" IN ('admission', 'discussion')
4001 AND "initiative"."revoked" ISNULL
4002 AND "ignored_initiative"."member_id" ISNULL
4003 AND (
4004 EXISTS (
4005 SELECT NULL FROM "draft"
4006 LEFT JOIN "ignored_member" ON
4007 "ignored_member"."member_id" = "supporter"."member_id" AND
4008 "ignored_member"."other_member_id" = "draft"."author_id"
4009 WHERE "draft"."initiative_id" = "supporter"."initiative_id"
4010 AND "draft"."id" > "supporter"."draft_id"
4011 AND "ignored_member"."member_id" ISNULL
4012 ) OR EXISTS (
4013 SELECT NULL FROM "suggestion"
4014 LEFT JOIN "opinion" ON
4015 "opinion"."member_id" = "supporter"."member_id" AND
4016 "opinion"."suggestion_id" = "suggestion"."id"
4017 LEFT JOIN "ignored_member" ON
4018 "ignored_member"."member_id" = "supporter"."member_id" AND
4019 "ignored_member"."other_member_id" = "suggestion"."author_id"
4020 WHERE "suggestion"."initiative_id" = "supporter"."initiative_id"
4021 AND "opinion"."member_id" ISNULL
4022 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4023 AND "ignored_member"."member_id" ISNULL
4025 );
4027 COMMENT ON VIEW "updated_initiative" IS 'Helper view for view "updated_or_featured_initiative"';
4030 CREATE FUNCTION "featured_initiative"
4031 ( "recipient_id_p" "member"."id"%TYPE,
4032 "area_id_p" "area"."id"%TYPE )
4033 RETURNS SETOF "initiative"."id"%TYPE
4034 LANGUAGE 'plpgsql' STABLE AS $$
4035 DECLARE
4036 "counter_v" "member"."notification_counter"%TYPE;
4037 "sample_size_v" "member"."notification_sample_size"%TYPE;
4038 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
4039 "match_v" BOOLEAN;
4040 "member_id_v" "member"."id"%TYPE;
4041 "seed_v" TEXT;
4042 "initiative_id_v" "initiative"."id"%TYPE;
4043 BEGIN
4044 SELECT "notification_counter", "notification_sample_size"
4045 INTO "counter_v", "sample_size_v"
4046 FROM "member" WHERE "id" = "recipient_id_p";
4047 IF COALESCE("sample_size_v" <= 0, TRUE) THEN
4048 RETURN;
4049 END IF;
4050 "initiative_id_ary" := '{}';
4051 LOOP
4052 "match_v" := FALSE;
4053 FOR "member_id_v", "seed_v" IN
4054 SELECT * FROM (
4055 SELECT DISTINCT
4056 "supporter"."member_id",
4057 md5(
4058 "recipient_id_p" || '-' ||
4059 "counter_v" || '-' ||
4060 "area_id_p" || '-' ||
4061 "supporter"."member_id"
4062 ) AS "seed"
4063 FROM "supporter"
4064 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
4065 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4066 WHERE "supporter"."member_id" != "recipient_id_p"
4067 AND "issue"."area_id" = "area_id_p"
4068 AND "issue"."state" IN ('admission', 'discussion', 'verification')
4069 ) AS "subquery"
4070 ORDER BY "seed"
4071 LOOP
4072 SELECT "initiative"."id" INTO "initiative_id_v"
4073 FROM "initiative"
4074 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4075 JOIN "area" ON "area"."id" = "issue"."area_id"
4076 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
4077 LEFT JOIN "supporter" AS "self_support" ON
4078 "self_support"."initiative_id" = "initiative"."id" AND
4079 "self_support"."member_id" = "recipient_id_p"
4080 LEFT JOIN "privilege" ON
4081 "privilege"."member_id" = "recipient_id_p" AND
4082 "privilege"."unit_id" = "area"."unit_id" AND
4083 "privilege"."voting_right" = TRUE
4084 LEFT JOIN "subscription" ON
4085 "subscription"."member_id" = "recipient_id_p" AND
4086 "subscription"."unit_id" = "area"."unit_id"
4087 LEFT JOIN "ignored_initiative" ON
4088 "ignored_initiative"."member_id" = "recipient_id_p" AND
4089 "ignored_initiative"."initiative_id" = "initiative"."id"
4090 WHERE "supporter"."member_id" = "member_id_v"
4091 AND "issue"."area_id" = "area_id_p"
4092 AND "issue"."state" IN ('admission', 'discussion', 'verification')
4093 AND "initiative"."revoked" ISNULL
4094 AND "self_support"."member_id" ISNULL
4095 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
4096 AND (
4097 "privilege"."member_id" NOTNULL OR
4098 "subscription"."member_id" NOTNULL )
4099 AND "ignored_initiative"."member_id" ISNULL
4100 AND NOT EXISTS (
4101 SELECT NULL FROM "draft"
4102 JOIN "ignored_member" ON
4103 "ignored_member"."member_id" = "recipient_id_p" AND
4104 "ignored_member"."other_member_id" = "draft"."author_id"
4105 WHERE "draft"."initiative_id" = "initiative"."id"
4107 ORDER BY md5("seed_v" || '-' || "initiative"."id")
4108 LIMIT 1;
4109 IF FOUND THEN
4110 "match_v" := TRUE;
4111 RETURN NEXT "initiative_id_v";
4112 IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
4113 RETURN;
4114 END IF;
4115 "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
4116 END IF;
4117 END LOOP;
4118 EXIT WHEN NOT "match_v";
4119 END LOOP;
4120 RETURN;
4121 END;
4122 $$;
4124 COMMENT ON FUNCTION "featured_initiative"
4125 ( "recipient_id_p" "member"."id"%TYPE,
4126 "area_id_p" "area"."id"%TYPE )
4127 IS 'Helper function for view "updated_or_featured_initiative"';
4130 CREATE VIEW "updated_or_featured_initiative" AS
4131 SELECT
4132 "subquery".*,
4133 NOT EXISTS (
4134 SELECT NULL FROM "initiative" AS "better_initiative"
4135 WHERE "better_initiative"."issue_id" = "initiative"."issue_id"
4136 AND
4137 ( COALESCE("better_initiative"."supporter_count", -1),
4138 -"better_initiative"."id" ) >
4139 ( COALESCE("initiative"."supporter_count", -1),
4140 -"initiative"."id" )
4141 ) AS "leading"
4142 FROM (
4143 SELECT * FROM "updated_initiative"
4144 UNION ALL
4145 SELECT
4146 "member"."id" AS "recipient_id",
4147 TRUE AS "featured",
4148 "featured_initiative_id" AS "initiative_id"
4149 FROM "member" CROSS JOIN "area"
4150 CROSS JOIN LATERAL
4151 "featured_initiative"("member"."id", "area"."id") AS "featured_initiative_id"
4152 JOIN "initiative" ON "initiative"."id" = "featured_initiative_id"
4153 ) AS "subquery"
4154 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id";
4156 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';
4158 COMMENT ON COLUMN "updated_or_featured_initiative"."recipient_id" IS '"id" of the member who receives the notification mail';
4159 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")';
4160 COMMENT ON COLUMN "updated_or_featured_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4161 COMMENT ON COLUMN "updated_or_featured_initiative"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
4164 CREATE VIEW "leading_complement_initiative" AS
4165 SELECT * FROM (
4166 SELECT DISTINCT ON ("uf_initiative"."recipient_id", "initiative"."issue_id")
4167 "uf_initiative"."recipient_id",
4168 FALSE AS "featured",
4169 "uf_initiative"."initiative_id",
4170 TRUE AS "leading"
4171 FROM "updated_or_featured_initiative" AS "uf_initiative"
4172 JOIN "initiative" AS "uf_initiative_full" ON
4173 "uf_initiative_full"."id" = "uf_initiative"."initiative_id"
4174 JOIN "initiative" ON
4175 "initiative"."issue_id" = "uf_initiative_full"."issue_id"
4176 WHERE "initiative"."revoked" ISNULL
4177 ORDER BY
4178 "uf_initiative"."recipient_id",
4179 "initiative"."issue_id",
4180 "initiative"."supporter_count" DESC,
4181 "initiative"."id"
4182 ) AS "subquery"
4183 WHERE NOT EXISTS (
4184 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
4185 WHERE "other"."recipient_id" = "subquery"."recipient_id"
4186 AND "other"."initiative_id" = "subquery"."initiative_id"
4187 );
4189 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';
4190 COMMENT ON COLUMN "leading_complement_initiative"."featured" IS 'Always FALSE in this view';
4191 COMMENT ON COLUMN "leading_complement_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4192 COMMENT ON COLUMN "leading_complement_initiative"."leading" IS 'Always TRUE in this view';
4195 CREATE VIEW "unfiltered_initiative_for_notification" AS
4196 SELECT
4197 "subquery".*,
4198 "supporter"."member_id" NOTNULL AS "supported",
4199 CASE WHEN "supporter"."member_id" NOTNULL THEN
4200 EXISTS (
4201 SELECT NULL FROM "draft"
4202 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
4203 AND "draft"."id" > "supporter"."draft_id"
4205 ELSE
4206 EXISTS (
4207 SELECT NULL FROM "draft"
4208 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
4209 AND COALESCE("draft"."id" > "sent"."last_draft_id", TRUE)
4211 END AS "new_draft",
4212 CASE WHEN "supporter"."member_id" NOTNULL THEN
4213 ( SELECT count(1) FROM "suggestion"
4214 LEFT JOIN "opinion" ON
4215 "opinion"."member_id" = "supporter"."member_id" AND
4216 "opinion"."suggestion_id" = "suggestion"."id"
4217 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
4218 AND "opinion"."member_id" ISNULL
4219 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4221 ELSE
4222 ( SELECT count(1) FROM "suggestion"
4223 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
4224 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4226 END AS "new_suggestion_count"
4227 FROM (
4228 SELECT * FROM "updated_or_featured_initiative"
4229 UNION ALL
4230 SELECT * FROM "leading_complement_initiative"
4231 ) AS "subquery"
4232 LEFT JOIN "supporter" ON
4233 "supporter"."member_id" = "subquery"."recipient_id" AND
4234 "supporter"."initiative_id" = "subquery"."initiative_id"
4235 LEFT JOIN "notification_initiative_sent" AS "sent" ON
4236 "sent"."member_id" = "subquery"."recipient_id" AND
4237 "sent"."initiative_id" = "subquery"."initiative_id";
4239 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';
4241 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4242 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)';
4243 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")';
4246 CREATE VIEW "initiative_for_notification" AS
4247 SELECT "unfiltered1".*
4248 FROM "unfiltered_initiative_for_notification" "unfiltered1"
4249 JOIN "initiative" AS "initiative1" ON
4250 "initiative1"."id" = "unfiltered1"."initiative_id"
4251 JOIN "issue" AS "issue1" ON "issue1"."id" = "initiative1"."issue_id"
4252 WHERE EXISTS (
4253 SELECT NULL
4254 FROM "unfiltered_initiative_for_notification" "unfiltered2"
4255 JOIN "initiative" AS "initiative2" ON
4256 "initiative2"."id" = "unfiltered2"."initiative_id"
4257 JOIN "issue" AS "issue2" ON "issue2"."id" = "initiative2"."issue_id"
4258 WHERE "unfiltered1"."recipient_id" = "unfiltered2"."recipient_id"
4259 AND "issue1"."area_id" = "issue2"."area_id"
4260 AND ("unfiltered2"."new_draft" OR "unfiltered2"."new_suggestion_count" > 0 )
4261 );
4263 COMMENT ON VIEW "initiative_for_notification" IS 'Initiatives to be included in a scheduled notification mail';
4265 COMMENT ON COLUMN "initiative_for_notification"."recipient_id" IS '"id" of the member who receives the notification mail';
4266 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")';
4267 COMMENT ON COLUMN "initiative_for_notification"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4268 COMMENT ON COLUMN "initiative_for_notification"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
4269 COMMENT ON COLUMN "initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4270 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)';
4271 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")';
4274 CREATE VIEW "scheduled_notification_to_send" AS
4275 SELECT * FROM (
4276 SELECT
4277 "id" AS "recipient_id",
4278 now() - CASE WHEN "notification_dow" ISNULL THEN
4279 ( "notification_sent"::DATE + CASE
4280 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4281 THEN 0 ELSE 1 END
4282 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4283 ELSE
4284 ( "notification_sent"::DATE +
4285 ( 7 + "notification_dow" -
4286 EXTRACT(DOW FROM
4287 ( "notification_sent"::DATE + CASE
4288 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4289 THEN 0 ELSE 1 END
4290 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4291 )::INTEGER
4292 ) % 7 +
4293 CASE
4294 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4295 THEN 0 ELSE 1
4296 END
4297 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4298 END AS "pending"
4299 FROM (
4300 SELECT
4301 "id",
4302 COALESCE("notification_sent", "activated") AS "notification_sent",
4303 "notification_dow",
4304 "notification_hour"
4305 FROM "member_to_notify"
4306 WHERE "notification_hour" NOTNULL
4307 ) AS "subquery1"
4308 ) AS "subquery2"
4309 WHERE "pending" > '0'::INTERVAL;
4311 COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending';
4313 COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail';
4314 COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending';
4317 CREATE VIEW "newsletter_to_send" AS
4318 SELECT
4319 "member"."id" AS "recipient_id",
4320 "newsletter"."id" AS "newsletter_id",
4321 "newsletter"."published"
4322 FROM "newsletter" CROSS JOIN "member_eligible_to_be_notified" AS "member"
4323 LEFT JOIN "privilege" ON
4324 "privilege"."member_id" = "member"."id" AND
4325 "privilege"."unit_id" = "newsletter"."unit_id" AND
4326 "privilege"."voting_right" = TRUE
4327 LEFT JOIN "subscription" ON
4328 "subscription"."member_id" = "member"."id" AND
4329 "subscription"."unit_id" = "newsletter"."unit_id"
4330 WHERE "newsletter"."published" <= now()
4331 AND "newsletter"."sent" ISNULL
4332 AND (
4333 "member"."disable_notifications" = FALSE OR
4334 "newsletter"."include_all_members" = TRUE )
4335 AND (
4336 "newsletter"."unit_id" ISNULL OR
4337 "privilege"."member_id" NOTNULL OR
4338 "subscription"."member_id" NOTNULL );
4340 COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out';
4342 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter was supposed to be sent out (can be used for ordering)';
4346 ------------------------------------------------------
4347 -- Row set returning function for delegation chains --
4348 ------------------------------------------------------
4351 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
4352 ('first', 'intermediate', 'last', 'repetition');
4354 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
4357 CREATE TYPE "delegation_chain_row" AS (
4358 "index" INT4,
4359 "member_id" INT4,
4360 "member_valid" BOOLEAN,
4361 "participation" BOOLEAN,
4362 "overridden" BOOLEAN,
4363 "scope_in" "delegation_scope",
4364 "scope_out" "delegation_scope",
4365 "disabled_out" BOOLEAN,
4366 "loop" "delegation_chain_loop_tag" );
4368 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
4370 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
4371 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest; for area and global delegation chains: always null';
4372 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
4373 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
4374 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
4375 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
4376 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
4379 CREATE FUNCTION "delegation_chain_for_closed_issue"
4380 ( "member_id_p" "member"."id"%TYPE,
4381 "issue_id_p" "issue"."id"%TYPE )
4382 RETURNS SETOF "delegation_chain_row"
4383 LANGUAGE 'plpgsql' STABLE AS $$
4384 DECLARE
4385 "output_row" "delegation_chain_row";
4386 "direct_voter_row" "direct_voter"%ROWTYPE;
4387 "delegating_voter_row" "delegating_voter"%ROWTYPE;
4388 BEGIN
4389 "output_row"."index" := 0;
4390 "output_row"."member_id" := "member_id_p";
4391 "output_row"."member_valid" := TRUE;
4392 "output_row"."participation" := FALSE;
4393 "output_row"."overridden" := FALSE;
4394 "output_row"."disabled_out" := FALSE;
4395 LOOP
4396 SELECT INTO "direct_voter_row" * FROM "direct_voter"
4397 WHERE "issue_id" = "issue_id_p"
4398 AND "member_id" = "output_row"."member_id";
4399 IF "direct_voter_row"."member_id" NOTNULL THEN
4400 "output_row"."participation" := TRUE;
4401 "output_row"."scope_out" := NULL;
4402 "output_row"."disabled_out" := NULL;
4403 RETURN NEXT "output_row";
4404 RETURN;
4405 END IF;
4406 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
4407 WHERE "issue_id" = "issue_id_p"
4408 AND "member_id" = "output_row"."member_id";
4409 IF "delegating_voter_row"."member_id" ISNULL THEN
4410 RETURN;
4411 END IF;
4412 "output_row"."scope_out" := "delegating_voter_row"."scope";
4413 RETURN NEXT "output_row";
4414 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
4415 "output_row"."scope_in" := "output_row"."scope_out";
4416 END LOOP;
4417 END;
4418 $$;
4420 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
4421 ( "member"."id"%TYPE,
4422 "member"."id"%TYPE )
4423 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
4426 CREATE FUNCTION "delegation_chain"
4427 ( "member_id_p" "member"."id"%TYPE,
4428 "unit_id_p" "unit"."id"%TYPE,
4429 "area_id_p" "area"."id"%TYPE,
4430 "issue_id_p" "issue"."id"%TYPE,
4431 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4432 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4433 RETURNS SETOF "delegation_chain_row"
4434 LANGUAGE 'plpgsql' STABLE AS $$
4435 DECLARE
4436 "scope_v" "delegation_scope";
4437 "unit_id_v" "unit"."id"%TYPE;
4438 "area_id_v" "area"."id"%TYPE;
4439 "issue_row" "issue"%ROWTYPE;
4440 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
4441 "loop_member_id_v" "member"."id"%TYPE;
4442 "output_row" "delegation_chain_row";
4443 "output_rows" "delegation_chain_row"[];
4444 "simulate_v" BOOLEAN;
4445 "simulate_here_v" BOOLEAN;
4446 "delegation_row" "delegation"%ROWTYPE;
4447 "row_count" INT4;
4448 "i" INT4;
4449 "loop_v" BOOLEAN;
4450 BEGIN
4451 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
4452 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
4453 END IF;
4454 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
4455 "simulate_v" := TRUE;
4456 ELSE
4457 "simulate_v" := FALSE;
4458 END IF;
4459 IF
4460 "unit_id_p" NOTNULL AND
4461 "area_id_p" ISNULL AND
4462 "issue_id_p" ISNULL
4463 THEN
4464 "scope_v" := 'unit';
4465 "unit_id_v" := "unit_id_p";
4466 ELSIF
4467 "unit_id_p" ISNULL AND
4468 "area_id_p" NOTNULL AND
4469 "issue_id_p" ISNULL
4470 THEN
4471 "scope_v" := 'area';
4472 "area_id_v" := "area_id_p";
4473 SELECT "unit_id" INTO "unit_id_v"
4474 FROM "area" WHERE "id" = "area_id_v";
4475 ELSIF
4476 "unit_id_p" ISNULL AND
4477 "area_id_p" ISNULL AND
4478 "issue_id_p" NOTNULL
4479 THEN
4480 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
4481 IF "issue_row"."id" ISNULL THEN
4482 RETURN;
4483 END IF;
4484 IF "issue_row"."closed" NOTNULL THEN
4485 IF "simulate_v" THEN
4486 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
4487 END IF;
4488 FOR "output_row" IN
4489 SELECT * FROM
4490 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
4491 LOOP
4492 RETURN NEXT "output_row";
4493 END LOOP;
4494 RETURN;
4495 END IF;
4496 "scope_v" := 'issue';
4497 SELECT "area_id" INTO "area_id_v"
4498 FROM "issue" WHERE "id" = "issue_id_p";
4499 SELECT "unit_id" INTO "unit_id_v"
4500 FROM "area" WHERE "id" = "area_id_v";
4501 ELSE
4502 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
4503 END IF;
4504 "visited_member_ids" := '{}';
4505 "loop_member_id_v" := NULL;
4506 "output_rows" := '{}';
4507 "output_row"."index" := 0;
4508 "output_row"."member_id" := "member_id_p";
4509 "output_row"."member_valid" := TRUE;
4510 "output_row"."participation" := FALSE;
4511 "output_row"."overridden" := FALSE;
4512 "output_row"."disabled_out" := FALSE;
4513 "output_row"."scope_out" := NULL;
4514 LOOP
4515 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
4516 "loop_member_id_v" := "output_row"."member_id";
4517 ELSE
4518 "visited_member_ids" :=
4519 "visited_member_ids" || "output_row"."member_id";
4520 END IF;
4521 IF "output_row"."participation" ISNULL THEN
4522 "output_row"."overridden" := NULL;
4523 ELSIF "output_row"."participation" THEN
4524 "output_row"."overridden" := TRUE;
4525 END IF;
4526 "output_row"."scope_in" := "output_row"."scope_out";
4527 "output_row"."member_valid" := EXISTS (
4528 SELECT NULL FROM "member" JOIN "privilege"
4529 ON "privilege"."member_id" = "member"."id"
4530 AND "privilege"."unit_id" = "unit_id_v"
4531 WHERE "id" = "output_row"."member_id"
4532 AND "member"."active" AND "privilege"."voting_right"
4533 );
4534 "simulate_here_v" := (
4535 "simulate_v" AND
4536 "output_row"."member_id" = "member_id_p"
4537 );
4538 "delegation_row" := ROW(NULL);
4539 IF "output_row"."member_valid" OR "simulate_here_v" THEN
4540 IF "scope_v" = 'unit' THEN
4541 IF NOT "simulate_here_v" THEN
4542 SELECT * INTO "delegation_row" FROM "delegation"
4543 WHERE "truster_id" = "output_row"."member_id"
4544 AND "unit_id" = "unit_id_v";
4545 END IF;
4546 ELSIF "scope_v" = 'area' THEN
4547 IF "simulate_here_v" THEN
4548 IF "simulate_trustee_id_p" ISNULL THEN
4549 SELECT * INTO "delegation_row" FROM "delegation"
4550 WHERE "truster_id" = "output_row"."member_id"
4551 AND "unit_id" = "unit_id_v";
4552 END IF;
4553 ELSE
4554 SELECT * INTO "delegation_row" FROM "delegation"
4555 WHERE "truster_id" = "output_row"."member_id"
4556 AND (
4557 "unit_id" = "unit_id_v" OR
4558 "area_id" = "area_id_v"
4560 ORDER BY "scope" DESC;
4561 END IF;
4562 ELSIF "scope_v" = 'issue' THEN
4563 IF "issue_row"."fully_frozen" ISNULL THEN
4564 "output_row"."participation" := EXISTS (
4565 SELECT NULL FROM "interest"
4566 WHERE "issue_id" = "issue_id_p"
4567 AND "member_id" = "output_row"."member_id"
4568 );
4569 ELSE
4570 IF "output_row"."member_id" = "member_id_p" THEN
4571 "output_row"."participation" := EXISTS (
4572 SELECT NULL FROM "direct_voter"
4573 WHERE "issue_id" = "issue_id_p"
4574 AND "member_id" = "output_row"."member_id"
4575 );
4576 ELSE
4577 "output_row"."participation" := NULL;
4578 END IF;
4579 END IF;
4580 IF "simulate_here_v" THEN
4581 IF "simulate_trustee_id_p" ISNULL THEN
4582 SELECT * INTO "delegation_row" FROM "delegation"
4583 WHERE "truster_id" = "output_row"."member_id"
4584 AND (
4585 "unit_id" = "unit_id_v" OR
4586 "area_id" = "area_id_v"
4588 ORDER BY "scope" DESC;
4589 END IF;
4590 ELSE
4591 SELECT * INTO "delegation_row" FROM "delegation"
4592 WHERE "truster_id" = "output_row"."member_id"
4593 AND (
4594 "unit_id" = "unit_id_v" OR
4595 "area_id" = "area_id_v" OR
4596 "issue_id" = "issue_id_p"
4598 ORDER BY "scope" DESC;
4599 END IF;
4600 END IF;
4601 ELSE
4602 "output_row"."participation" := FALSE;
4603 END IF;
4604 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
4605 "output_row"."scope_out" := "scope_v";
4606 "output_rows" := "output_rows" || "output_row";
4607 "output_row"."member_id" := "simulate_trustee_id_p";
4608 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
4609 "output_row"."scope_out" := "delegation_row"."scope";
4610 "output_rows" := "output_rows" || "output_row";
4611 "output_row"."member_id" := "delegation_row"."trustee_id";
4612 ELSIF "delegation_row"."scope" NOTNULL THEN
4613 "output_row"."scope_out" := "delegation_row"."scope";
4614 "output_row"."disabled_out" := TRUE;
4615 "output_rows" := "output_rows" || "output_row";
4616 EXIT;
4617 ELSE
4618 "output_row"."scope_out" := NULL;
4619 "output_rows" := "output_rows" || "output_row";
4620 EXIT;
4621 END IF;
4622 EXIT WHEN "loop_member_id_v" NOTNULL;
4623 "output_row"."index" := "output_row"."index" + 1;
4624 END LOOP;
4625 "row_count" := array_upper("output_rows", 1);
4626 "i" := 1;
4627 "loop_v" := FALSE;
4628 LOOP
4629 "output_row" := "output_rows"["i"];
4630 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
4631 IF "loop_v" THEN
4632 IF "i" + 1 = "row_count" THEN
4633 "output_row"."loop" := 'last';
4634 ELSIF "i" = "row_count" THEN
4635 "output_row"."loop" := 'repetition';
4636 ELSE
4637 "output_row"."loop" := 'intermediate';
4638 END IF;
4639 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
4640 "output_row"."loop" := 'first';
4641 "loop_v" := TRUE;
4642 END IF;
4643 IF "scope_v" = 'unit' THEN
4644 "output_row"."participation" := NULL;
4645 END IF;
4646 RETURN NEXT "output_row";
4647 "i" := "i" + 1;
4648 END LOOP;
4649 RETURN;
4650 END;
4651 $$;
4653 COMMENT ON FUNCTION "delegation_chain"
4654 ( "member"."id"%TYPE,
4655 "unit"."id"%TYPE,
4656 "area"."id"%TYPE,
4657 "issue"."id"%TYPE,
4658 "member"."id"%TYPE,
4659 BOOLEAN )
4660 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
4664 ---------------------------------------------------------
4665 -- Single row returning function for delegation chains --
4666 ---------------------------------------------------------
4669 CREATE TYPE "delegation_info_loop_type" AS ENUM
4670 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
4672 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''';
4675 CREATE TYPE "delegation_info_type" AS (
4676 "own_participation" BOOLEAN,
4677 "own_delegation_scope" "delegation_scope",
4678 "first_trustee_id" INT4,
4679 "first_trustee_participation" BOOLEAN,
4680 "first_trustee_ellipsis" BOOLEAN,
4681 "other_trustee_id" INT4,
4682 "other_trustee_participation" BOOLEAN,
4683 "other_trustee_ellipsis" BOOLEAN,
4684 "delegation_loop" "delegation_info_loop_type",
4685 "participating_member_id" INT4 );
4687 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';
4689 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
4690 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
4691 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
4692 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
4693 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
4694 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
4695 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)';
4696 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
4697 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';
4698 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
4701 CREATE FUNCTION "delegation_info"
4702 ( "member_id_p" "member"."id"%TYPE,
4703 "unit_id_p" "unit"."id"%TYPE,
4704 "area_id_p" "area"."id"%TYPE,
4705 "issue_id_p" "issue"."id"%TYPE,
4706 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4707 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4708 RETURNS "delegation_info_type"
4709 LANGUAGE 'plpgsql' STABLE AS $$
4710 DECLARE
4711 "current_row" "delegation_chain_row";
4712 "result" "delegation_info_type";
4713 BEGIN
4714 "result"."own_participation" := FALSE;
4715 FOR "current_row" IN
4716 SELECT * FROM "delegation_chain"(
4717 "member_id_p",
4718 "unit_id_p", "area_id_p", "issue_id_p",
4719 "simulate_trustee_id_p", "simulate_default_p")
4720 LOOP
4721 IF
4722 "result"."participating_member_id" ISNULL AND
4723 "current_row"."participation"
4724 THEN
4725 "result"."participating_member_id" := "current_row"."member_id";
4726 END IF;
4727 IF "current_row"."member_id" = "member_id_p" THEN
4728 "result"."own_participation" := "current_row"."participation";
4729 "result"."own_delegation_scope" := "current_row"."scope_out";
4730 IF "current_row"."loop" = 'first' THEN
4731 "result"."delegation_loop" := 'own';
4732 END IF;
4733 ELSIF
4734 "current_row"."member_valid" AND
4735 ( "current_row"."loop" ISNULL OR
4736 "current_row"."loop" != 'repetition' )
4737 THEN
4738 IF "result"."first_trustee_id" ISNULL THEN
4739 "result"."first_trustee_id" := "current_row"."member_id";
4740 "result"."first_trustee_participation" := "current_row"."participation";
4741 "result"."first_trustee_ellipsis" := FALSE;
4742 IF "current_row"."loop" = 'first' THEN
4743 "result"."delegation_loop" := 'first';
4744 END IF;
4745 ELSIF "result"."other_trustee_id" ISNULL THEN
4746 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
4747 "result"."other_trustee_id" := "current_row"."member_id";
4748 "result"."other_trustee_participation" := TRUE;
4749 "result"."other_trustee_ellipsis" := FALSE;
4750 IF "current_row"."loop" = 'first' THEN
4751 "result"."delegation_loop" := 'other';
4752 END IF;
4753 ELSE
4754 "result"."first_trustee_ellipsis" := TRUE;
4755 IF "current_row"."loop" = 'first' THEN
4756 "result"."delegation_loop" := 'first_ellipsis';
4757 END IF;
4758 END IF;
4759 ELSE
4760 "result"."other_trustee_ellipsis" := TRUE;
4761 IF "current_row"."loop" = 'first' THEN
4762 "result"."delegation_loop" := 'other_ellipsis';
4763 END IF;
4764 END IF;
4765 END IF;
4766 END LOOP;
4767 RETURN "result";
4768 END;
4769 $$;
4771 COMMENT ON FUNCTION "delegation_info"
4772 ( "member"."id"%TYPE,
4773 "unit"."id"%TYPE,
4774 "area"."id"%TYPE,
4775 "issue"."id"%TYPE,
4776 "member"."id"%TYPE,
4777 BOOLEAN )
4778 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
4782 ------------------------
4783 -- Geospatial lookups --
4784 ------------------------
4786 /*
4787 CREATE FUNCTION "closed_initiatives_in_bounding_box"
4788 ( "bounding_box_p" EBOX,
4789 "limit_p" INT4 )
4790 RETURNS SETOF "initiative"
4791 LANGUAGE 'plpgsql' STABLE AS $$
4792 DECLARE
4793 "limit_v" INT4;
4794 "count_v" INT4;
4795 BEGIN
4796 "limit_v" := "limit_p" + 1;
4797 LOOP
4798 SELECT count(1) INTO "count_v"
4799 FROM "initiative"
4800 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4801 WHERE "issue"."closed" NOTNULL
4802 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4803 LIMIT "limit_v";
4804 IF "count_v" < "limit_v" THEN
4805 RETURN QUERY SELECT "initiative".*
4806 FROM (
4807 SELECT
4808 "initiative"."id" AS "initiative_id",
4809 "issue"."closed"
4810 FROM "initiative"
4811 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4812 WHERE "issue"."closed" NOTNULL
4813 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4814 ) AS "subquery"
4815 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4816 ORDER BY "subquery"."closed" DESC
4817 LIMIT "limit_p";
4818 RETURN;
4819 END IF;
4820 SELECT count(1) INTO "count_v"
4821 FROM (
4822 SELECT "initiative"."id" AS "initiative_id"
4823 FROM "initiative"
4824 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4825 WHERE "issue"."closed" NOTNULL
4826 ORDER BY "closed" DESC
4827 LIMIT "limit_v"
4828 ) AS "subquery"
4829 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4830 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4831 LIMIT "limit_p";
4832 IF "count_v" >= "limit_p" THEN
4833 RETURN QUERY SELECT "initiative".*
4834 FROM (
4835 SELECT
4836 "initiative"."id" AS "initiative_id",
4837 "issue"."closed"
4838 FROM "initiative"
4839 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4840 WHERE "issue"."closed" NOTNULL
4841 ORDER BY "closed" DESC
4842 LIMIT "limit_v"
4843 ) AS "subquery"
4844 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4845 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4846 ORDER BY "subquery"."closed" DESC
4847 LIMIT "limit_p";
4848 RETURN;
4849 END IF;
4850 "limit_v" := "limit_v" * 2;
4851 END LOOP;
4852 END;
4853 $$;
4855 COMMENT ON FUNCTION "closed_initiatives_in_bounding_box"
4856 ( EBOX, INT4 )
4857 IS 'TODO';
4858 */
4862 ---------------------------
4863 -- Transaction isolation --
4864 ---------------------------
4867 CREATE FUNCTION "require_transaction_isolation"()
4868 RETURNS VOID
4869 LANGUAGE 'plpgsql' VOLATILE AS $$
4870 BEGIN
4871 IF
4872 current_setting('transaction_isolation') NOT IN
4873 ('repeatable read', 'serializable')
4874 THEN
4875 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
4876 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
4877 END IF;
4878 RETURN;
4879 END;
4880 $$;
4882 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
4885 CREATE FUNCTION "dont_require_transaction_isolation"()
4886 RETURNS VOID
4887 LANGUAGE 'plpgsql' VOLATILE AS $$
4888 BEGIN
4889 IF
4890 current_setting('transaction_isolation') IN
4891 ('repeatable read', 'serializable')
4892 THEN
4893 RAISE WARNING 'Unneccessary transaction isolation level: %',
4894 current_setting('transaction_isolation');
4895 END IF;
4896 RETURN;
4897 END;
4898 $$;
4900 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
4904 -------------------------
4905 -- Notification system --
4906 -------------------------
4908 CREATE FUNCTION "get_initiatives_for_notification"
4909 ( "recipient_id_p" "member"."id"%TYPE )
4910 RETURNS SETOF "initiative_for_notification"
4911 LANGUAGE 'plpgsql' VOLATILE AS $$
4912 DECLARE
4913 "result_row" "initiative_for_notification"%ROWTYPE;
4914 "last_draft_id_v" "draft"."id"%TYPE;
4915 "last_suggestion_id_v" "suggestion"."id"%TYPE;
4916 BEGIN
4917 PERFORM "require_transaction_isolation"();
4918 PERFORM NULL FROM "member" WHERE "id" = "recipient_id_p" FOR UPDATE;
4919 FOR "result_row" IN
4920 SELECT * FROM "initiative_for_notification"
4921 WHERE "recipient_id" = "recipient_id_p"
4922 LOOP
4923 SELECT "id" INTO "last_draft_id_v" FROM "draft"
4924 WHERE "draft"."initiative_id" = "result_row"."initiative_id"
4925 ORDER BY "id" DESC LIMIT 1;
4926 SELECT "id" INTO "last_suggestion_id_v" FROM "suggestion"
4927 WHERE "suggestion"."initiative_id" = "result_row"."initiative_id"
4928 ORDER BY "id" DESC LIMIT 1;
4929 INSERT INTO "notification_initiative_sent"
4930 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
4931 VALUES (
4932 "recipient_id_p",
4933 "result_row"."initiative_id",
4934 "last_draft_id_v",
4935 "last_suggestion_id_v" )
4936 ON CONFLICT ("member_id", "initiative_id") DO UPDATE SET
4937 "last_draft_id" = "last_draft_id_v",
4938 "last_suggestion_id" = "last_suggestion_id_v";
4939 RETURN NEXT "result_row";
4940 END LOOP;
4941 DELETE FROM "notification_initiative_sent"
4942 USING "initiative", "issue"
4943 WHERE "notification_initiative_sent"."member_id" = "recipient_id_p"
4944 AND "initiative"."id" = "notification_initiative_sent"."initiative_id"
4945 AND "issue"."id" = "initiative"."issue_id"
4946 AND ( "issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL );
4947 UPDATE "member" SET
4948 "notification_counter" = "notification_counter" + 1,
4949 "notification_sent" = now()
4950 WHERE "id" = "recipient_id_p";
4951 RETURN;
4952 END;
4953 $$;
4955 COMMENT ON FUNCTION "get_initiatives_for_notification"
4956 ( "member"."id"%TYPE )
4957 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';
4961 ------------------------------------------------------------------------
4962 -- Regular tasks, except calculcation of snapshots and voting results --
4963 ------------------------------------------------------------------------
4966 CREATE FUNCTION "check_activity"()
4967 RETURNS VOID
4968 LANGUAGE 'plpgsql' VOLATILE AS $$
4969 DECLARE
4970 "system_setting_row" "system_setting"%ROWTYPE;
4971 BEGIN
4972 PERFORM "dont_require_transaction_isolation"();
4973 SELECT * INTO "system_setting_row" FROM "system_setting";
4974 IF "system_setting_row"."member_ttl" NOTNULL THEN
4975 UPDATE "member" SET "active" = FALSE
4976 WHERE "active" = TRUE
4977 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
4978 END IF;
4979 RETURN;
4980 END;
4981 $$;
4983 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
4986 CREATE FUNCTION "calculate_member_counts"()
4987 RETURNS VOID
4988 LANGUAGE 'plpgsql' VOLATILE AS $$
4989 BEGIN
4990 PERFORM "require_transaction_isolation"();
4991 DELETE FROM "member_count";
4992 INSERT INTO "member_count" ("total_count")
4993 SELECT "total_count" FROM "member_count_view";
4994 UPDATE "unit" SET "member_count" = "view"."member_count"
4995 FROM "unit_member_count" AS "view"
4996 WHERE "view"."unit_id" = "unit"."id";
4997 RETURN;
4998 END;
4999 $$;
5001 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"';
5005 ------------------------------------
5006 -- Calculation of harmonic weight --
5007 ------------------------------------
5010 CREATE VIEW "remaining_harmonic_supporter_weight" AS
5011 SELECT
5012 "direct_interest_snapshot"."snapshot_id",
5013 "direct_interest_snapshot"."issue_id",
5014 "direct_interest_snapshot"."member_id",
5015 "direct_interest_snapshot"."weight" AS "weight_num",
5016 count("initiative"."id") AS "weight_den"
5017 FROM "issue"
5018 JOIN "direct_interest_snapshot"
5019 ON "issue"."latest_snapshot_id" = "direct_interest_snapshot"."snapshot_id"
5020 AND "issue"."id" = "direct_interest_snapshot"."issue_id"
5021 JOIN "initiative"
5022 ON "issue"."id" = "initiative"."issue_id"
5023 AND "initiative"."harmonic_weight" ISNULL
5024 JOIN "direct_supporter_snapshot"
5025 ON "issue"."latest_snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
5026 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
5027 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
5028 AND (
5029 "direct_supporter_snapshot"."satisfied" = TRUE OR
5030 coalesce("initiative"."admitted", FALSE) = FALSE
5032 GROUP BY
5033 "direct_interest_snapshot"."snapshot_id",
5034 "direct_interest_snapshot"."issue_id",
5035 "direct_interest_snapshot"."member_id",
5036 "direct_interest_snapshot"."weight";
5038 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
5041 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
5042 SELECT
5043 "initiative"."issue_id",
5044 "initiative"."id" AS "initiative_id",
5045 "initiative"."admitted",
5046 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
5047 "remaining_harmonic_supporter_weight"."weight_den"
5048 FROM "remaining_harmonic_supporter_weight"
5049 JOIN "initiative"
5050 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
5051 AND "initiative"."harmonic_weight" ISNULL
5052 JOIN "direct_supporter_snapshot"
5053 ON "remaining_harmonic_supporter_weight"."snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
5054 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
5055 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
5056 AND (
5057 "direct_supporter_snapshot"."satisfied" = TRUE OR
5058 coalesce("initiative"."admitted", FALSE) = FALSE
5060 GROUP BY
5061 "initiative"."issue_id",
5062 "initiative"."id",
5063 "initiative"."admitted",
5064 "remaining_harmonic_supporter_weight"."weight_den";
5066 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
5069 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
5070 SELECT
5071 "issue_id",
5072 "id" AS "initiative_id",
5073 "admitted",
5074 0 AS "weight_num",
5075 1 AS "weight_den"
5076 FROM "initiative"
5077 WHERE "harmonic_weight" ISNULL;
5079 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';
5082 CREATE FUNCTION "set_harmonic_initiative_weights"
5083 ( "issue_id_p" "issue"."id"%TYPE )
5084 RETURNS VOID
5085 LANGUAGE 'plpgsql' VOLATILE AS $$
5086 DECLARE
5087 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
5088 "i" INT4;
5089 "count_v" INT4;
5090 "summand_v" FLOAT;
5091 "id_ary" INT4[];
5092 "weight_ary" FLOAT[];
5093 "min_weight_v" FLOAT;
5094 BEGIN
5095 PERFORM "require_transaction_isolation"();
5096 UPDATE "initiative" SET "harmonic_weight" = NULL
5097 WHERE "issue_id" = "issue_id_p";
5098 LOOP
5099 "min_weight_v" := NULL;
5100 "i" := 0;
5101 "count_v" := 0;
5102 FOR "weight_row" IN
5103 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
5104 WHERE "issue_id" = "issue_id_p"
5105 AND (
5106 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
5107 SELECT NULL FROM "initiative"
5108 WHERE "issue_id" = "issue_id_p"
5109 AND "harmonic_weight" ISNULL
5110 AND coalesce("admitted", FALSE) = FALSE
5113 UNION ALL -- needed for corner cases
5114 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
5115 WHERE "issue_id" = "issue_id_p"
5116 AND (
5117 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
5118 SELECT NULL FROM "initiative"
5119 WHERE "issue_id" = "issue_id_p"
5120 AND "harmonic_weight" ISNULL
5121 AND coalesce("admitted", FALSE) = FALSE
5124 ORDER BY "initiative_id" DESC, "weight_den" DESC
5125 -- NOTE: non-admitted initiatives placed first (at last positions),
5126 -- latest initiatives treated worse in case of tie
5127 LOOP
5128 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
5129 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
5130 "i" := "i" + 1;
5131 "count_v" := "i";
5132 "id_ary"["i"] := "weight_row"."initiative_id";
5133 "weight_ary"["i"] := "summand_v";
5134 ELSE
5135 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
5136 END IF;
5137 END LOOP;
5138 EXIT WHEN "count_v" = 0;
5139 "i" := 1;
5140 LOOP
5141 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
5142 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
5143 "min_weight_v" := "weight_ary"["i"];
5144 END IF;
5145 "i" := "i" + 1;
5146 EXIT WHEN "i" > "count_v";
5147 END LOOP;
5148 "i" := 1;
5149 LOOP
5150 IF "weight_ary"["i"] = "min_weight_v" THEN
5151 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
5152 WHERE "id" = "id_ary"["i"];
5153 EXIT;
5154 END IF;
5155 "i" := "i" + 1;
5156 END LOOP;
5157 END LOOP;
5158 UPDATE "initiative" SET "harmonic_weight" = 0
5159 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
5160 END;
5161 $$;
5163 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
5164 ( "issue"."id"%TYPE )
5165 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
5169 ------------------------------
5170 -- Calculation of snapshots --
5171 ------------------------------
5174 CREATE FUNCTION "weight_of_added_delegations_for_snapshot"
5175 ( "snapshot_id_p" "snapshot"."id"%TYPE,
5176 "issue_id_p" "issue"."id"%TYPE,
5177 "member_id_p" "member"."id"%TYPE,
5178 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
5179 RETURNS "direct_interest_snapshot"."weight"%TYPE
5180 LANGUAGE 'plpgsql' VOLATILE AS $$
5181 DECLARE
5182 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5183 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
5184 "weight_v" INT4;
5185 "sub_weight_v" INT4;
5186 BEGIN
5187 PERFORM "require_transaction_isolation"();
5188 "weight_v" := 0;
5189 FOR "issue_delegation_row" IN
5190 SELECT * FROM "issue_delegation"
5191 WHERE "trustee_id" = "member_id_p"
5192 AND "issue_id" = "issue_id_p"
5193 LOOP
5194 IF NOT EXISTS (
5195 SELECT NULL FROM "direct_interest_snapshot"
5196 WHERE "snapshot_id" = "snapshot_id_p"
5197 AND "issue_id" = "issue_id_p"
5198 AND "member_id" = "issue_delegation_row"."truster_id"
5199 ) AND NOT EXISTS (
5200 SELECT NULL FROM "delegating_interest_snapshot"
5201 WHERE "snapshot_id" = "snapshot_id_p"
5202 AND "issue_id" = "issue_id_p"
5203 AND "member_id" = "issue_delegation_row"."truster_id"
5204 ) THEN
5205 "delegate_member_ids_v" :=
5206 "member_id_p" || "delegate_member_ids_p";
5207 INSERT INTO "delegating_interest_snapshot" (
5208 "snapshot_id",
5209 "issue_id",
5210 "member_id",
5211 "scope",
5212 "delegate_member_ids"
5213 ) VALUES (
5214 "snapshot_id_p",
5215 "issue_id_p",
5216 "issue_delegation_row"."truster_id",
5217 "issue_delegation_row"."scope",
5218 "delegate_member_ids_v"
5219 );
5220 "sub_weight_v" := 1 +
5221 "weight_of_added_delegations_for_snapshot"(
5222 "snapshot_id_p",
5223 "issue_id_p",
5224 "issue_delegation_row"."truster_id",
5225 "delegate_member_ids_v"
5226 );
5227 UPDATE "delegating_interest_snapshot"
5228 SET "weight" = "sub_weight_v"
5229 WHERE "snapshot_id" = "snapshot_id_p"
5230 AND "issue_id" = "issue_id_p"
5231 AND "member_id" = "issue_delegation_row"."truster_id";
5232 "weight_v" := "weight_v" + "sub_weight_v";
5233 END IF;
5234 END LOOP;
5235 RETURN "weight_v";
5236 END;
5237 $$;
5239 COMMENT ON FUNCTION "weight_of_added_delegations_for_snapshot"
5240 ( "snapshot"."id"%TYPE,
5241 "issue"."id"%TYPE,
5242 "member"."id"%TYPE,
5243 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
5244 IS 'Helper function for "fill_snapshot" function';
5247 CREATE FUNCTION "take_snapshot"
5248 ( "issue_id_p" "issue"."id"%TYPE,
5249 "area_id_p" "area"."id"%TYPE = NULL )
5250 RETURNS "snapshot"."id"%TYPE
5251 LANGUAGE 'plpgsql' VOLATILE AS $$
5252 DECLARE
5253 "area_id_v" "area"."id"%TYPE;
5254 "unit_id_v" "unit"."id"%TYPE;
5255 "snapshot_id_v" "snapshot"."id"%TYPE;
5256 "issue_id_v" "issue"."id"%TYPE;
5257 "member_id_v" "member"."id"%TYPE;
5258 BEGIN
5259 IF "issue_id_p" NOTNULL AND "area_id_p" NOTNULL THEN
5260 RAISE EXCEPTION 'One of "issue_id_p" and "area_id_p" must be NULL';
5261 END IF;
5262 PERFORM "require_transaction_isolation"();
5263 IF "issue_id_p" ISNULL THEN
5264 "area_id_v" := "area_id_p";
5265 ELSE
5266 SELECT "area_id" INTO "area_id_v"
5267 FROM "issue" WHERE "id" = "issue_id_p";
5268 END IF;
5269 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5270 INSERT INTO "snapshot" ("area_id", "issue_id")
5271 VALUES ("area_id_v", "issue_id_p")
5272 RETURNING "id" INTO "snapshot_id_v";
5273 INSERT INTO "snapshot_population" ("snapshot_id", "member_id")
5274 SELECT "snapshot_id_v", "member_id"
5275 FROM "unit_member" WHERE "unit_id" = "unit_id_v";
5276 UPDATE "snapshot" SET
5277 "population" = (
5278 SELECT count(1) FROM "snapshot_population"
5279 WHERE "snapshot_id" = "snapshot_id_v"
5280 ) WHERE "id" = "snapshot_id_v";
5281 FOR "issue_id_v" IN
5282 SELECT "id" FROM "issue"
5283 WHERE CASE WHEN "issue_id_p" ISNULL THEN
5284 "area_id" = "area_id_p" AND
5285 "state" = 'admission'
5286 ELSE
5287 "id" = "issue_id_p"
5288 END
5289 LOOP
5290 INSERT INTO "snapshot_issue" ("snapshot_id", "issue_id")
5291 VALUES ("snapshot_id_v", "issue_id_v");
5292 INSERT INTO "direct_interest_snapshot"
5293 ("snapshot_id", "issue_id", "member_id")
5294 SELECT
5295 "snapshot_id_v" AS "snapshot_id",
5296 "issue_id_v" AS "issue_id",
5297 "member"."id" AS "member_id"
5298 FROM "issue"
5299 JOIN "area" ON "issue"."area_id" = "area"."id"
5300 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
5301 JOIN "member" ON "interest"."member_id" = "member"."id"
5302 JOIN "privilege"
5303 ON "privilege"."unit_id" = "area"."unit_id"
5304 AND "privilege"."member_id" = "member"."id"
5305 WHERE "issue"."id" = "issue_id_v"
5306 AND "member"."active" AND "privilege"."voting_right";
5307 FOR "member_id_v" IN
5308 SELECT "member_id" FROM "direct_interest_snapshot"
5309 WHERE "snapshot_id" = "snapshot_id_v"
5310 AND "issue_id" = "issue_id_v"
5311 LOOP
5312 UPDATE "direct_interest_snapshot" SET
5313 "weight" = 1 +
5314 "weight_of_added_delegations_for_snapshot"(
5315 "snapshot_id_v",
5316 "issue_id_v",
5317 "member_id_v",
5318 '{}'
5320 WHERE "snapshot_id" = "snapshot_id_v"
5321 AND "issue_id" = "issue_id_v"
5322 AND "member_id" = "member_id_v";
5323 END LOOP;
5324 INSERT INTO "direct_supporter_snapshot"
5325 ( "snapshot_id", "issue_id", "initiative_id", "member_id",
5326 "draft_id", "informed", "satisfied" )
5327 SELECT
5328 "snapshot_id_v" AS "snapshot_id",
5329 "issue_id_v" AS "issue_id",
5330 "initiative"."id" AS "initiative_id",
5331 "supporter"."member_id" AS "member_id",
5332 "supporter"."draft_id" AS "draft_id",
5333 "supporter"."draft_id" = "current_draft"."id" AS "informed",
5334 NOT EXISTS (
5335 SELECT NULL FROM "critical_opinion"
5336 WHERE "initiative_id" = "initiative"."id"
5337 AND "member_id" = "supporter"."member_id"
5338 ) AS "satisfied"
5339 FROM "initiative"
5340 JOIN "supporter"
5341 ON "supporter"."initiative_id" = "initiative"."id"
5342 JOIN "current_draft"
5343 ON "initiative"."id" = "current_draft"."initiative_id"
5344 JOIN "direct_interest_snapshot"
5345 ON "snapshot_id_v" = "direct_interest_snapshot"."snapshot_id"
5346 AND "supporter"."member_id" = "direct_interest_snapshot"."member_id"
5347 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
5348 WHERE "initiative"."issue_id" = "issue_id_v";
5349 DELETE FROM "temporary_suggestion_counts";
5350 INSERT INTO "temporary_suggestion_counts"
5351 ( "id",
5352 "minus2_unfulfilled_count", "minus2_fulfilled_count",
5353 "minus1_unfulfilled_count", "minus1_fulfilled_count",
5354 "plus1_unfulfilled_count", "plus1_fulfilled_count",
5355 "plus2_unfulfilled_count", "plus2_fulfilled_count" )
5356 SELECT
5357 "suggestion"."id",
5358 ( SELECT coalesce(sum("di"."weight"), 0)
5359 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5360 ON "di"."snapshot_id" = "snapshot_id_v"
5361 AND "di"."issue_id" = "issue_id_v"
5362 AND "di"."member_id" = "opinion"."member_id"
5363 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5364 AND "opinion"."degree" = -2
5365 AND "opinion"."fulfilled" = FALSE
5366 ) AS "minus2_unfulfilled_count",
5367 ( SELECT coalesce(sum("di"."weight"), 0)
5368 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5369 ON "di"."snapshot_id" = "snapshot_id_v"
5370 AND "di"."issue_id" = "issue_id_v"
5371 AND "di"."member_id" = "opinion"."member_id"
5372 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5373 AND "opinion"."degree" = -2
5374 AND "opinion"."fulfilled" = TRUE
5375 ) AS "minus2_fulfilled_count",
5376 ( SELECT coalesce(sum("di"."weight"), 0)
5377 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5378 ON "di"."snapshot_id" = "snapshot_id_v"
5379 AND "di"."issue_id" = "issue_id_v"
5380 AND "di"."member_id" = "opinion"."member_id"
5381 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5382 AND "opinion"."degree" = -1
5383 AND "opinion"."fulfilled" = FALSE
5384 ) AS "minus1_unfulfilled_count",
5385 ( SELECT coalesce(sum("di"."weight"), 0)
5386 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5387 ON "di"."snapshot_id" = "snapshot_id_v"
5388 AND "di"."issue_id" = "issue_id_v"
5389 AND "di"."member_id" = "opinion"."member_id"
5390 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5391 AND "opinion"."degree" = -1
5392 AND "opinion"."fulfilled" = TRUE
5393 ) AS "minus1_fulfilled_count",
5394 ( SELECT coalesce(sum("di"."weight"), 0)
5395 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5396 ON "di"."snapshot_id" = "snapshot_id_v"
5397 AND "di"."issue_id" = "issue_id_v"
5398 AND "di"."member_id" = "opinion"."member_id"
5399 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5400 AND "opinion"."degree" = 1
5401 AND "opinion"."fulfilled" = FALSE
5402 ) AS "plus1_unfulfilled_count",
5403 ( SELECT coalesce(sum("di"."weight"), 0)
5404 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5405 ON "di"."snapshot_id" = "snapshot_id_v"
5406 AND "di"."issue_id" = "issue_id_v"
5407 AND "di"."member_id" = "opinion"."member_id"
5408 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5409 AND "opinion"."degree" = 1
5410 AND "opinion"."fulfilled" = TRUE
5411 ) AS "plus1_fulfilled_count",
5412 ( SELECT coalesce(sum("di"."weight"), 0)
5413 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5414 ON "di"."snapshot_id" = "snapshot_id_v"
5415 AND "di"."issue_id" = "issue_id_v"
5416 AND "di"."member_id" = "opinion"."member_id"
5417 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5418 AND "opinion"."degree" = 2
5419 AND "opinion"."fulfilled" = FALSE
5420 ) AS "plus2_unfulfilled_count",
5421 ( SELECT coalesce(sum("di"."weight"), 0)
5422 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5423 ON "di"."snapshot_id" = "snapshot_id_v"
5424 AND "di"."issue_id" = "issue_id_v"
5425 AND "di"."member_id" = "opinion"."member_id"
5426 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5427 AND "opinion"."degree" = 2
5428 AND "opinion"."fulfilled" = TRUE
5429 ) AS "plus2_fulfilled_count"
5430 FROM "suggestion" JOIN "initiative"
5431 ON "suggestion"."initiative_id" = "initiative"."id"
5432 WHERE "initiative"."issue_id" = "issue_id_v";
5433 END LOOP;
5434 RETURN "snapshot_id_v";
5435 END;
5436 $$;
5438 COMMENT ON FUNCTION "take_snapshot"
5439 ( "issue"."id"%TYPE,
5440 "area"."id"%TYPE )
5441 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.';
5444 CREATE FUNCTION "finish_snapshot"
5445 ( "issue_id_p" "issue"."id"%TYPE )
5446 RETURNS VOID
5447 LANGUAGE 'plpgsql' VOLATILE AS $$
5448 DECLARE
5449 "snapshot_id_v" "snapshot"."id"%TYPE;
5450 BEGIN
5451 -- NOTE: function does not require snapshot isolation but we don't call
5452 -- "dont_require_snapshot_isolation" here because this function is
5453 -- also invoked by "check_issue"
5454 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
5455 SELECT "id" INTO "snapshot_id_v" FROM "snapshot"
5456 ORDER BY "id" DESC LIMIT 1;
5457 UPDATE "issue" SET
5458 "calculated" = "snapshot"."calculated",
5459 "latest_snapshot_id" = "snapshot_id_v",
5460 "population" = "snapshot"."population",
5461 "initiative_quorum" = CASE WHEN
5462 "policy"."initiative_quorum" > ceil(
5463 ( "issue"."population"::INT8 *
5464 "policy"."initiative_quorum_num"::INT8 ) /
5465 "policy"."initiative_quorum_den"::FLOAT8
5466 )::INT4
5467 THEN
5468 "policy"."initiative_quorum"
5469 ELSE
5470 ceil(
5471 ( "issue"."population"::INT8 *
5472 "policy"."initiative_quorum_num"::INT8 ) /
5473 "policy"."initiative_quorum_den"::FLOAT8
5474 )::INT4
5475 END
5476 FROM "snapshot", "policy"
5477 WHERE "issue"."id" = "issue_id_p"
5478 AND "snapshot"."id" = "snapshot_id_v"
5479 AND "policy"."id" = "issue"."policy_id";
5480 UPDATE "initiative" SET
5481 "supporter_count" = (
5482 SELECT coalesce(sum("di"."weight"), 0)
5483 FROM "direct_interest_snapshot" AS "di"
5484 JOIN "direct_supporter_snapshot" AS "ds"
5485 ON "di"."member_id" = "ds"."member_id"
5486 WHERE "di"."snapshot_id" = "snapshot_id_v"
5487 AND "di"."issue_id" = "issue_id_p"
5488 AND "ds"."snapshot_id" = "snapshot_id_v"
5489 AND "ds"."initiative_id" = "initiative"."id"
5490 ),
5491 "informed_supporter_count" = (
5492 SELECT coalesce(sum("di"."weight"), 0)
5493 FROM "direct_interest_snapshot" AS "di"
5494 JOIN "direct_supporter_snapshot" AS "ds"
5495 ON "di"."member_id" = "ds"."member_id"
5496 WHERE "di"."snapshot_id" = "snapshot_id_v"
5497 AND "di"."issue_id" = "issue_id_p"
5498 AND "ds"."snapshot_id" = "snapshot_id_v"
5499 AND "ds"."initiative_id" = "initiative"."id"
5500 AND "ds"."informed"
5501 ),
5502 "satisfied_supporter_count" = (
5503 SELECT coalesce(sum("di"."weight"), 0)
5504 FROM "direct_interest_snapshot" AS "di"
5505 JOIN "direct_supporter_snapshot" AS "ds"
5506 ON "di"."member_id" = "ds"."member_id"
5507 WHERE "di"."snapshot_id" = "snapshot_id_v"
5508 AND "di"."issue_id" = "issue_id_p"
5509 AND "ds"."snapshot_id" = "snapshot_id_v"
5510 AND "ds"."initiative_id" = "initiative"."id"
5511 AND "ds"."satisfied"
5512 ),
5513 "satisfied_informed_supporter_count" = (
5514 SELECT coalesce(sum("di"."weight"), 0)
5515 FROM "direct_interest_snapshot" AS "di"
5516 JOIN "direct_supporter_snapshot" AS "ds"
5517 ON "di"."member_id" = "ds"."member_id"
5518 WHERE "di"."snapshot_id" = "snapshot_id_v"
5519 AND "di"."issue_id" = "issue_id_p"
5520 AND "ds"."snapshot_id" = "snapshot_id_v"
5521 AND "ds"."initiative_id" = "initiative"."id"
5522 AND "ds"."informed"
5523 AND "ds"."satisfied"
5525 WHERE "issue_id" = "issue_id_p";
5526 UPDATE "suggestion" SET
5527 "minus2_unfulfilled_count" = "temp"."minus2_unfulfilled_count",
5528 "minus2_fulfilled_count" = "temp"."minus2_fulfilled_count",
5529 "minus1_unfulfilled_count" = "temp"."minus1_unfulfilled_count",
5530 "minus1_fulfilled_count" = "temp"."minus1_fulfilled_count",
5531 "plus1_unfulfilled_count" = "temp"."plus1_unfulfilled_count",
5532 "plus1_fulfilled_count" = "temp"."plus1_fulfilled_count",
5533 "plus2_unfulfilled_count" = "temp"."plus2_unfulfilled_count",
5534 "plus2_fulfilled_count" = "temp"."plus2_fulfilled_count"
5535 FROM "temporary_suggestion_counts" AS "temp", "initiative"
5536 WHERE "temp"."id" = "suggestion"."id"
5537 AND "initiative"."issue_id" = "issue_id_p"
5538 AND "suggestion"."initiative_id" = "initiative"."id";
5539 DELETE FROM "temporary_suggestion_counts";
5540 RETURN;
5541 END;
5542 $$;
5544 COMMENT ON FUNCTION "finish_snapshot"
5545 ( "issue"."id"%TYPE )
5546 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)';
5550 -----------------------
5551 -- Counting of votes --
5552 -----------------------
5555 CREATE FUNCTION "weight_of_added_vote_delegations"
5556 ( "issue_id_p" "issue"."id"%TYPE,
5557 "member_id_p" "member"."id"%TYPE,
5558 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
5559 RETURNS "direct_voter"."weight"%TYPE
5560 LANGUAGE 'plpgsql' VOLATILE AS $$
5561 DECLARE
5562 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5563 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
5564 "weight_v" INT4;
5565 "sub_weight_v" INT4;
5566 BEGIN
5567 PERFORM "require_transaction_isolation"();
5568 "weight_v" := 0;
5569 FOR "issue_delegation_row" IN
5570 SELECT * FROM "issue_delegation"
5571 WHERE "trustee_id" = "member_id_p"
5572 AND "issue_id" = "issue_id_p"
5573 LOOP
5574 IF NOT EXISTS (
5575 SELECT NULL FROM "direct_voter"
5576 WHERE "member_id" = "issue_delegation_row"."truster_id"
5577 AND "issue_id" = "issue_id_p"
5578 ) AND NOT EXISTS (
5579 SELECT NULL FROM "delegating_voter"
5580 WHERE "member_id" = "issue_delegation_row"."truster_id"
5581 AND "issue_id" = "issue_id_p"
5582 ) THEN
5583 "delegate_member_ids_v" :=
5584 "member_id_p" || "delegate_member_ids_p";
5585 INSERT INTO "delegating_voter" (
5586 "issue_id",
5587 "member_id",
5588 "scope",
5589 "delegate_member_ids"
5590 ) VALUES (
5591 "issue_id_p",
5592 "issue_delegation_row"."truster_id",
5593 "issue_delegation_row"."scope",
5594 "delegate_member_ids_v"
5595 );
5596 "sub_weight_v" := 1 +
5597 "weight_of_added_vote_delegations"(
5598 "issue_id_p",
5599 "issue_delegation_row"."truster_id",
5600 "delegate_member_ids_v"
5601 );
5602 UPDATE "delegating_voter"
5603 SET "weight" = "sub_weight_v"
5604 WHERE "issue_id" = "issue_id_p"
5605 AND "member_id" = "issue_delegation_row"."truster_id";
5606 "weight_v" := "weight_v" + "sub_weight_v";
5607 END IF;
5608 END LOOP;
5609 RETURN "weight_v";
5610 END;
5611 $$;
5613 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
5614 ( "issue"."id"%TYPE,
5615 "member"."id"%TYPE,
5616 "delegating_voter"."delegate_member_ids"%TYPE )
5617 IS 'Helper function for "add_vote_delegations" function';
5620 CREATE FUNCTION "add_vote_delegations"
5621 ( "issue_id_p" "issue"."id"%TYPE )
5622 RETURNS VOID
5623 LANGUAGE 'plpgsql' VOLATILE AS $$
5624 DECLARE
5625 "member_id_v" "member"."id"%TYPE;
5626 BEGIN
5627 PERFORM "require_transaction_isolation"();
5628 FOR "member_id_v" IN
5629 SELECT "member_id" FROM "direct_voter"
5630 WHERE "issue_id" = "issue_id_p"
5631 LOOP
5632 UPDATE "direct_voter" SET
5633 "weight" = "weight" + "weight_of_added_vote_delegations"(
5634 "issue_id_p",
5635 "member_id_v",
5636 '{}'
5638 WHERE "member_id" = "member_id_v"
5639 AND "issue_id" = "issue_id_p";
5640 END LOOP;
5641 RETURN;
5642 END;
5643 $$;
5645 COMMENT ON FUNCTION "add_vote_delegations"
5646 ( "issue_id_p" "issue"."id"%TYPE )
5647 IS 'Helper function for "close_voting" function';
5650 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
5651 RETURNS VOID
5652 LANGUAGE 'plpgsql' VOLATILE AS $$
5653 DECLARE
5654 "area_id_v" "area"."id"%TYPE;
5655 "unit_id_v" "unit"."id"%TYPE;
5656 "member_id_v" "member"."id"%TYPE;
5657 BEGIN
5658 PERFORM "require_transaction_isolation"();
5659 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
5660 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5661 -- override protection triggers:
5662 INSERT INTO "temporary_transaction_data" ("key", "value")
5663 VALUES ('override_protection_triggers', TRUE::TEXT);
5664 -- delete timestamp of voting comment:
5665 UPDATE "direct_voter" SET "comment_changed" = NULL
5666 WHERE "issue_id" = "issue_id_p";
5667 -- delete delegating votes (in cases of manual reset of issue state):
5668 DELETE FROM "delegating_voter"
5669 WHERE "issue_id" = "issue_id_p";
5670 -- delete votes from non-privileged voters:
5671 DELETE FROM "direct_voter"
5672 USING (
5673 SELECT
5674 "direct_voter"."member_id"
5675 FROM "direct_voter"
5676 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
5677 LEFT JOIN "privilege"
5678 ON "privilege"."unit_id" = "unit_id_v"
5679 AND "privilege"."member_id" = "direct_voter"."member_id"
5680 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
5681 "member"."active" = FALSE OR
5682 "privilege"."voting_right" ISNULL OR
5683 "privilege"."voting_right" = FALSE
5685 ) AS "subquery"
5686 WHERE "direct_voter"."issue_id" = "issue_id_p"
5687 AND "direct_voter"."member_id" = "subquery"."member_id";
5688 -- consider delegations:
5689 UPDATE "direct_voter" SET "weight" = 1
5690 WHERE "issue_id" = "issue_id_p";
5691 PERFORM "add_vote_delegations"("issue_id_p");
5692 -- mark first preferences:
5693 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
5694 FROM (
5695 SELECT
5696 "vote"."initiative_id",
5697 "vote"."member_id",
5698 CASE WHEN "vote"."grade" > 0 THEN
5699 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
5700 ELSE NULL
5701 END AS "first_preference"
5702 FROM "vote"
5703 JOIN "initiative" -- NOTE: due to missing index on issue_id
5704 ON "vote"."issue_id" = "initiative"."issue_id"
5705 JOIN "vote" AS "agg"
5706 ON "initiative"."id" = "agg"."initiative_id"
5707 AND "vote"."member_id" = "agg"."member_id"
5708 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
5709 ) AS "subquery"
5710 WHERE "vote"."issue_id" = "issue_id_p"
5711 AND "vote"."initiative_id" = "subquery"."initiative_id"
5712 AND "vote"."member_id" = "subquery"."member_id";
5713 -- finish overriding protection triggers (avoids garbage):
5714 DELETE FROM "temporary_transaction_data"
5715 WHERE "key" = 'override_protection_triggers';
5716 -- materialize battle_view:
5717 -- NOTE: "closed" column of issue must be set at this point
5718 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
5719 INSERT INTO "battle" (
5720 "issue_id",
5721 "winning_initiative_id", "losing_initiative_id",
5722 "count"
5723 ) SELECT
5724 "issue_id",
5725 "winning_initiative_id", "losing_initiative_id",
5726 "count"
5727 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
5728 -- set voter count:
5729 UPDATE "issue" SET
5730 "voter_count" = (
5731 SELECT coalesce(sum("weight"), 0)
5732 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
5734 WHERE "id" = "issue_id_p";
5735 -- copy "positive_votes" and "negative_votes" from "battle" table:
5736 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
5737 UPDATE "initiative" SET
5738 "first_preference_votes" = 0,
5739 "positive_votes" = "battle_win"."count",
5740 "negative_votes" = "battle_lose"."count"
5741 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
5742 WHERE
5743 "battle_win"."issue_id" = "issue_id_p" AND
5744 "battle_win"."winning_initiative_id" = "initiative"."id" AND
5745 "battle_win"."losing_initiative_id" ISNULL AND
5746 "battle_lose"."issue_id" = "issue_id_p" AND
5747 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
5748 "battle_lose"."winning_initiative_id" ISNULL;
5749 -- calculate "first_preference_votes":
5750 -- NOTE: will only set values not equal to zero
5751 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
5752 FROM (
5753 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
5754 FROM "vote" JOIN "direct_voter"
5755 ON "vote"."issue_id" = "direct_voter"."issue_id"
5756 AND "vote"."member_id" = "direct_voter"."member_id"
5757 WHERE "vote"."first_preference"
5758 GROUP BY "vote"."initiative_id"
5759 ) AS "subquery"
5760 WHERE "initiative"."issue_id" = "issue_id_p"
5761 AND "initiative"."admitted"
5762 AND "initiative"."id" = "subquery"."initiative_id";
5763 END;
5764 $$;
5766 COMMENT ON FUNCTION "close_voting"
5767 ( "issue"."id"%TYPE )
5768 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.';
5771 CREATE FUNCTION "defeat_strength"
5772 ( "positive_votes_p" INT4,
5773 "negative_votes_p" INT4,
5774 "defeat_strength_p" "defeat_strength" )
5775 RETURNS INT8
5776 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5777 BEGIN
5778 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
5779 IF "positive_votes_p" > "negative_votes_p" THEN
5780 RETURN "positive_votes_p";
5781 ELSE
5782 RETURN 0;
5783 END IF;
5784 ELSE
5785 IF "positive_votes_p" > "negative_votes_p" THEN
5786 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
5787 ELSIF "positive_votes_p" = "negative_votes_p" THEN
5788 RETURN 0;
5789 ELSE
5790 RETURN -1;
5791 END IF;
5792 END IF;
5793 END;
5794 $$;
5796 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")';
5799 CREATE FUNCTION "secondary_link_strength"
5800 ( "initiative1_ord_p" INT4,
5801 "initiative2_ord_p" INT4,
5802 "tie_breaking_p" "tie_breaking" )
5803 RETURNS INT8
5804 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5805 BEGIN
5806 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
5807 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
5808 END IF;
5809 RETURN (
5810 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
5812 ELSE
5813 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
5814 1::INT8 << 62
5815 ELSE 0 END
5817 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
5818 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
5819 ELSE
5820 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
5821 END
5822 END
5823 );
5824 END;
5825 $$;
5827 COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4, "tie_breaking") IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)';
5830 CREATE TYPE "link_strength" AS (
5831 "primary" INT8,
5832 "secondary" INT8 );
5834 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'')';
5837 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
5838 RETURNS "link_strength"[][]
5839 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5840 DECLARE
5841 "dimension_v" INT4;
5842 "matrix_p" "link_strength"[][];
5843 "i" INT4;
5844 "j" INT4;
5845 "k" INT4;
5846 BEGIN
5847 "dimension_v" := array_upper("matrix_d", 1);
5848 "matrix_p" := "matrix_d";
5849 "i" := 1;
5850 LOOP
5851 "j" := 1;
5852 LOOP
5853 IF "i" != "j" THEN
5854 "k" := 1;
5855 LOOP
5856 IF "i" != "k" AND "j" != "k" THEN
5857 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
5858 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
5859 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
5860 END IF;
5861 ELSE
5862 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
5863 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
5864 END IF;
5865 END IF;
5866 END IF;
5867 EXIT WHEN "k" = "dimension_v";
5868 "k" := "k" + 1;
5869 END LOOP;
5870 END IF;
5871 EXIT WHEN "j" = "dimension_v";
5872 "j" := "j" + 1;
5873 END LOOP;
5874 EXIT WHEN "i" = "dimension_v";
5875 "i" := "i" + 1;
5876 END LOOP;
5877 RETURN "matrix_p";
5878 END;
5879 $$;
5881 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
5884 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
5885 RETURNS VOID
5886 LANGUAGE 'plpgsql' VOLATILE AS $$
5887 DECLARE
5888 "issue_row" "issue"%ROWTYPE;
5889 "policy_row" "policy"%ROWTYPE;
5890 "dimension_v" INT4;
5891 "matrix_a" INT4[][]; -- absolute votes
5892 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
5893 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
5894 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
5895 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
5896 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
5897 "i" INT4;
5898 "j" INT4;
5899 "m" INT4;
5900 "n" INT4;
5901 "battle_row" "battle"%ROWTYPE;
5902 "rank_ary" INT4[];
5903 "rank_v" INT4;
5904 "initiative_id_v" "initiative"."id"%TYPE;
5905 BEGIN
5906 PERFORM "require_transaction_isolation"();
5907 SELECT * INTO "issue_row"
5908 FROM "issue" WHERE "id" = "issue_id_p";
5909 SELECT * INTO "policy_row"
5910 FROM "policy" WHERE "id" = "issue_row"."policy_id";
5911 SELECT count(1) INTO "dimension_v"
5912 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
5913 -- create "matrix_a" with absolute number of votes in pairwise
5914 -- comparison:
5915 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
5916 "i" := 1;
5917 "j" := 2;
5918 FOR "battle_row" IN
5919 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
5920 ORDER BY
5921 "winning_initiative_id" NULLS FIRST,
5922 "losing_initiative_id" NULLS FIRST
5923 LOOP
5924 "matrix_a"["i"]["j"] := "battle_row"."count";
5925 IF "j" = "dimension_v" THEN
5926 "i" := "i" + 1;
5927 "j" := 1;
5928 ELSE
5929 "j" := "j" + 1;
5930 IF "j" = "i" THEN
5931 "j" := "j" + 1;
5932 END IF;
5933 END IF;
5934 END LOOP;
5935 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
5936 RAISE EXCEPTION 'Wrong battle count (should not happen)';
5937 END IF;
5938 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
5939 -- and "secondary_link_strength" functions:
5940 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
5941 "i" := 1;
5942 LOOP
5943 "j" := 1;
5944 LOOP
5945 IF "i" != "j" THEN
5946 "matrix_d"["i"]["j"] := (
5947 "defeat_strength"(
5948 "matrix_a"["i"]["j"],
5949 "matrix_a"["j"]["i"],
5950 "policy_row"."defeat_strength"
5951 ),
5952 "secondary_link_strength"(
5953 "i",
5954 "j",
5955 "policy_row"."tie_breaking"
5957 )::"link_strength";
5958 END IF;
5959 EXIT WHEN "j" = "dimension_v";
5960 "j" := "j" + 1;
5961 END LOOP;
5962 EXIT WHEN "i" = "dimension_v";
5963 "i" := "i" + 1;
5964 END LOOP;
5965 -- find best paths:
5966 "matrix_p" := "find_best_paths"("matrix_d");
5967 -- create partial order:
5968 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
5969 "i" := 1;
5970 LOOP
5971 "j" := "i" + 1;
5972 LOOP
5973 IF "i" != "j" THEN
5974 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
5975 "matrix_b"["i"]["j"] := TRUE;
5976 "matrix_b"["j"]["i"] := FALSE;
5977 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
5978 "matrix_b"["i"]["j"] := FALSE;
5979 "matrix_b"["j"]["i"] := TRUE;
5980 END IF;
5981 END IF;
5982 EXIT WHEN "j" = "dimension_v";
5983 "j" := "j" + 1;
5984 END LOOP;
5985 EXIT WHEN "i" = "dimension_v" - 1;
5986 "i" := "i" + 1;
5987 END LOOP;
5988 -- tie-breaking by forbidding shared weakest links in beat-paths
5989 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
5990 -- is performed later by initiative id):
5991 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
5992 "m" := 1;
5993 LOOP
5994 "n" := "m" + 1;
5995 LOOP
5996 -- only process those candidates m and n, which are tied:
5997 IF "matrix_b"["m"]["n"] ISNULL THEN
5998 -- start with beat-paths prior tie-breaking:
5999 "matrix_t" := "matrix_p";
6000 -- start with all links allowed:
6001 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
6002 LOOP
6003 -- determine (and forbid) that link that is the weakest link
6004 -- in both the best path from candidate m to candidate n and
6005 -- from candidate n to candidate m:
6006 "i" := 1;
6007 <<forbid_one_link>>
6008 LOOP
6009 "j" := 1;
6010 LOOP
6011 IF "i" != "j" THEN
6012 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
6013 "matrix_f"["i"]["j"] := TRUE;
6014 -- exit for performance reasons,
6015 -- as exactly one link will be found:
6016 EXIT forbid_one_link;
6017 END IF;
6018 END IF;
6019 EXIT WHEN "j" = "dimension_v";
6020 "j" := "j" + 1;
6021 END LOOP;
6022 IF "i" = "dimension_v" THEN
6023 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
6024 END IF;
6025 "i" := "i" + 1;
6026 END LOOP;
6027 -- calculate best beat-paths while ignoring forbidden links:
6028 "i" := 1;
6029 LOOP
6030 "j" := 1;
6031 LOOP
6032 IF "i" != "j" THEN
6033 "matrix_t"["i"]["j"] := CASE
6034 WHEN "matrix_f"["i"]["j"]
6035 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
6036 ELSE "matrix_d"["i"]["j"] END;
6037 END IF;
6038 EXIT WHEN "j" = "dimension_v";
6039 "j" := "j" + 1;
6040 END LOOP;
6041 EXIT WHEN "i" = "dimension_v";
6042 "i" := "i" + 1;
6043 END LOOP;
6044 "matrix_t" := "find_best_paths"("matrix_t");
6045 -- extend partial order, if tie-breaking was successful:
6046 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
6047 "matrix_b"["m"]["n"] := TRUE;
6048 "matrix_b"["n"]["m"] := FALSE;
6049 EXIT;
6050 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
6051 "matrix_b"["m"]["n"] := FALSE;
6052 "matrix_b"["n"]["m"] := TRUE;
6053 EXIT;
6054 END IF;
6055 END LOOP;
6056 END IF;
6057 EXIT WHEN "n" = "dimension_v";
6058 "n" := "n" + 1;
6059 END LOOP;
6060 EXIT WHEN "m" = "dimension_v" - 1;
6061 "m" := "m" + 1;
6062 END LOOP;
6063 END IF;
6064 -- store a unique ranking in "rank_ary":
6065 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
6066 "rank_v" := 1;
6067 LOOP
6068 "i" := 1;
6069 <<assign_next_rank>>
6070 LOOP
6071 IF "rank_ary"["i"] ISNULL THEN
6072 "j" := 1;
6073 LOOP
6074 IF
6075 "i" != "j" AND
6076 "rank_ary"["j"] ISNULL AND
6077 ( "matrix_b"["j"]["i"] OR
6078 -- tie-breaking by "id"
6079 ( "matrix_b"["j"]["i"] ISNULL AND
6080 "j" < "i" ) )
6081 THEN
6082 -- someone else is better
6083 EXIT;
6084 END IF;
6085 IF "j" = "dimension_v" THEN
6086 -- noone is better
6087 "rank_ary"["i"] := "rank_v";
6088 EXIT assign_next_rank;
6089 END IF;
6090 "j" := "j" + 1;
6091 END LOOP;
6092 END IF;
6093 "i" := "i" + 1;
6094 IF "i" > "dimension_v" THEN
6095 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
6096 END IF;
6097 END LOOP;
6098 EXIT WHEN "rank_v" = "dimension_v";
6099 "rank_v" := "rank_v" + 1;
6100 END LOOP;
6101 -- write preliminary results:
6102 "i" := 2; -- omit status quo with "i" = 1
6103 FOR "initiative_id_v" IN
6104 SELECT "id" FROM "initiative"
6105 WHERE "issue_id" = "issue_id_p" AND "admitted"
6106 ORDER BY "id"
6107 LOOP
6108 UPDATE "initiative" SET
6109 "direct_majority" =
6110 CASE WHEN "policy_row"."direct_majority_strict" THEN
6111 "positive_votes" * "policy_row"."direct_majority_den" >
6112 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
6113 ELSE
6114 "positive_votes" * "policy_row"."direct_majority_den" >=
6115 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
6116 END
6117 AND "positive_votes" >= "policy_row"."direct_majority_positive"
6118 AND "issue_row"."voter_count"-"negative_votes" >=
6119 "policy_row"."direct_majority_non_negative",
6120 "indirect_majority" =
6121 CASE WHEN "policy_row"."indirect_majority_strict" THEN
6122 "positive_votes" * "policy_row"."indirect_majority_den" >
6123 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
6124 ELSE
6125 "positive_votes" * "policy_row"."indirect_majority_den" >=
6126 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
6127 END
6128 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
6129 AND "issue_row"."voter_count"-"negative_votes" >=
6130 "policy_row"."indirect_majority_non_negative",
6131 "schulze_rank" = "rank_ary"["i"],
6132 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
6133 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
6134 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
6135 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
6136 THEN NULL
6137 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
6138 "eligible" = FALSE,
6139 "winner" = FALSE,
6140 "rank" = NULL -- NOTE: in cases of manual reset of issue state
6141 WHERE "id" = "initiative_id_v";
6142 "i" := "i" + 1;
6143 END LOOP;
6144 IF "i" != "dimension_v" + 1 THEN
6145 RAISE EXCEPTION 'Wrong winner count (should not happen)';
6146 END IF;
6147 -- take indirect majorities into account:
6148 LOOP
6149 UPDATE "initiative" SET "indirect_majority" = TRUE
6150 FROM (
6151 SELECT "new_initiative"."id" AS "initiative_id"
6152 FROM "initiative" "old_initiative"
6153 JOIN "initiative" "new_initiative"
6154 ON "new_initiative"."issue_id" = "issue_id_p"
6155 AND "new_initiative"."indirect_majority" = FALSE
6156 JOIN "battle" "battle_win"
6157 ON "battle_win"."issue_id" = "issue_id_p"
6158 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
6159 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
6160 JOIN "battle" "battle_lose"
6161 ON "battle_lose"."issue_id" = "issue_id_p"
6162 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
6163 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
6164 WHERE "old_initiative"."issue_id" = "issue_id_p"
6165 AND "old_initiative"."indirect_majority" = TRUE
6166 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
6167 "battle_win"."count" * "policy_row"."indirect_majority_den" >
6168 "policy_row"."indirect_majority_num" *
6169 ("battle_win"."count"+"battle_lose"."count")
6170 ELSE
6171 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
6172 "policy_row"."indirect_majority_num" *
6173 ("battle_win"."count"+"battle_lose"."count")
6174 END
6175 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
6176 AND "issue_row"."voter_count"-"battle_lose"."count" >=
6177 "policy_row"."indirect_majority_non_negative"
6178 ) AS "subquery"
6179 WHERE "id" = "subquery"."initiative_id";
6180 EXIT WHEN NOT FOUND;
6181 END LOOP;
6182 -- set "multistage_majority" for remaining matching initiatives:
6183 UPDATE "initiative" SET "multistage_majority" = TRUE
6184 FROM (
6185 SELECT "losing_initiative"."id" AS "initiative_id"
6186 FROM "initiative" "losing_initiative"
6187 JOIN "initiative" "winning_initiative"
6188 ON "winning_initiative"."issue_id" = "issue_id_p"
6189 AND "winning_initiative"."admitted"
6190 JOIN "battle" "battle_win"
6191 ON "battle_win"."issue_id" = "issue_id_p"
6192 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
6193 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
6194 JOIN "battle" "battle_lose"
6195 ON "battle_lose"."issue_id" = "issue_id_p"
6196 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
6197 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
6198 WHERE "losing_initiative"."issue_id" = "issue_id_p"
6199 AND "losing_initiative"."admitted"
6200 AND "winning_initiative"."schulze_rank" <
6201 "losing_initiative"."schulze_rank"
6202 AND "battle_win"."count" > "battle_lose"."count"
6203 AND (
6204 "battle_win"."count" > "winning_initiative"."positive_votes" OR
6205 "battle_lose"."count" < "losing_initiative"."negative_votes" )
6206 ) AS "subquery"
6207 WHERE "id" = "subquery"."initiative_id";
6208 -- mark eligible initiatives:
6209 UPDATE "initiative" SET "eligible" = TRUE
6210 WHERE "issue_id" = "issue_id_p"
6211 AND "initiative"."direct_majority"
6212 AND "initiative"."indirect_majority"
6213 AND "initiative"."better_than_status_quo"
6214 AND (
6215 "policy_row"."no_multistage_majority" = FALSE OR
6216 "initiative"."multistage_majority" = FALSE )
6217 AND (
6218 "policy_row"."no_reverse_beat_path" = FALSE OR
6219 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
6220 -- mark final winner:
6221 UPDATE "initiative" SET "winner" = TRUE
6222 FROM (
6223 SELECT "id" AS "initiative_id"
6224 FROM "initiative"
6225 WHERE "issue_id" = "issue_id_p" AND "eligible"
6226 ORDER BY
6227 "schulze_rank",
6228 "id"
6229 LIMIT 1
6230 ) AS "subquery"
6231 WHERE "id" = "subquery"."initiative_id";
6232 -- write (final) ranks:
6233 "rank_v" := 1;
6234 FOR "initiative_id_v" IN
6235 SELECT "id"
6236 FROM "initiative"
6237 WHERE "issue_id" = "issue_id_p" AND "admitted"
6238 ORDER BY
6239 "winner" DESC,
6240 "eligible" DESC,
6241 "schulze_rank",
6242 "id"
6243 LOOP
6244 UPDATE "initiative" SET "rank" = "rank_v"
6245 WHERE "id" = "initiative_id_v";
6246 "rank_v" := "rank_v" + 1;
6247 END LOOP;
6248 -- set schulze rank of status quo and mark issue as finished:
6249 UPDATE "issue" SET
6250 "status_quo_schulze_rank" = "rank_ary"[1],
6251 "state" =
6252 CASE WHEN EXISTS (
6253 SELECT NULL FROM "initiative"
6254 WHERE "issue_id" = "issue_id_p" AND "winner"
6255 ) THEN
6256 'finished_with_winner'::"issue_state"
6257 ELSE
6258 'finished_without_winner'::"issue_state"
6259 END,
6260 "closed" = "phase_finished",
6261 "phase_finished" = NULL
6262 WHERE "id" = "issue_id_p";
6263 RETURN;
6264 END;
6265 $$;
6267 COMMENT ON FUNCTION "calculate_ranks"
6268 ( "issue"."id"%TYPE )
6269 IS 'Determine ranking (Votes have to be counted first)';
6273 -----------------------------
6274 -- Automatic state changes --
6275 -----------------------------
6278 CREATE FUNCTION "issue_admission"
6279 ( "area_id_p" "area"."id"%TYPE )
6280 RETURNS BOOLEAN
6281 LANGUAGE 'plpgsql' VOLATILE AS $$
6282 DECLARE
6283 "issue_id_v" "issue"."id"%TYPE;
6284 BEGIN
6285 PERFORM "dont_require_transaction_isolation"();
6286 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
6287 UPDATE "area" SET "issue_quorum" = "view"."issue_quorum"
6288 FROM "area_quorum" AS "view"
6289 WHERE "area"."id" = "view"."area_id"
6290 AND "area"."id" = "area_id_p";
6291 SELECT "id" INTO "issue_id_v" FROM "issue_for_admission"
6292 WHERE "area_id" = "area_id_p";
6293 IF "issue_id_v" ISNULL THEN RETURN FALSE; END IF;
6294 UPDATE "issue" SET
6295 "admission_snapshot_id" = "latest_snapshot_id",
6296 "state" = 'discussion',
6297 "accepted" = now(),
6298 "phase_finished" = NULL,
6299 "issue_quorum" = "issue_quorum"."issue_quorum"
6300 FROM "issue_quorum"
6301 WHERE "id" = "issue_id_v"
6302 AND "issue_quorum"."issue_id" = "issue_id_v";
6303 RETURN TRUE;
6304 END;
6305 $$;
6307 COMMENT ON FUNCTION "issue_admission"
6308 ( "area"."id"%TYPE )
6309 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';
6312 CREATE TYPE "check_issue_persistence" AS (
6313 "state" "issue_state",
6314 "phase_finished" BOOLEAN,
6315 "issue_revoked" BOOLEAN,
6316 "snapshot_created" BOOLEAN,
6317 "harmonic_weights_set" BOOLEAN,
6318 "closed_voting" BOOLEAN );
6320 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';
6323 CREATE FUNCTION "check_issue"
6324 ( "issue_id_p" "issue"."id"%TYPE,
6325 "persist" "check_issue_persistence" )
6326 RETURNS "check_issue_persistence"
6327 LANGUAGE 'plpgsql' VOLATILE AS $$
6328 DECLARE
6329 "issue_row" "issue"%ROWTYPE;
6330 "last_calculated_v" "snapshot"."calculated"%TYPE;
6331 "policy_row" "policy"%ROWTYPE;
6332 "initiative_row" "initiative"%ROWTYPE;
6333 "state_v" "issue_state";
6334 BEGIN
6335 PERFORM "require_transaction_isolation"();
6336 IF "persist" ISNULL THEN
6337 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6338 FOR UPDATE;
6339 SELECT "calculated" INTO "last_calculated_v"
6340 FROM "snapshot" JOIN "snapshot_issue"
6341 ON "snapshot"."id" = "snapshot_issue"."snapshot_id"
6342 WHERE "snapshot_issue"."issue_id" = "issue_id_p"
6343 ORDER BY "snapshot"."id" DESC;
6344 IF "issue_row"."closed" NOTNULL THEN
6345 RETURN NULL;
6346 END IF;
6347 "persist"."state" := "issue_row"."state";
6348 IF
6349 ( "issue_row"."state" = 'admission' AND "last_calculated_v" >=
6350 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
6351 ( "issue_row"."state" = 'discussion' AND now() >=
6352 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
6353 ( "issue_row"."state" = 'verification' AND now() >=
6354 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
6355 ( "issue_row"."state" = 'voting' AND now() >=
6356 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
6357 THEN
6358 "persist"."phase_finished" := TRUE;
6359 ELSE
6360 "persist"."phase_finished" := FALSE;
6361 END IF;
6362 IF
6363 NOT EXISTS (
6364 -- all initiatives are revoked
6365 SELECT NULL FROM "initiative"
6366 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6367 ) AND (
6368 -- and issue has not been accepted yet
6369 "persist"."state" = 'admission' OR
6370 -- or verification time has elapsed
6371 ( "persist"."state" = 'verification' AND
6372 "persist"."phase_finished" ) OR
6373 -- or no initiatives have been revoked lately
6374 NOT EXISTS (
6375 SELECT NULL FROM "initiative"
6376 WHERE "issue_id" = "issue_id_p"
6377 AND now() < "revoked" + "issue_row"."verification_time"
6380 THEN
6381 "persist"."issue_revoked" := TRUE;
6382 ELSE
6383 "persist"."issue_revoked" := FALSE;
6384 END IF;
6385 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
6386 UPDATE "issue" SET "phase_finished" = now()
6387 WHERE "id" = "issue_row"."id";
6388 RETURN "persist";
6389 ELSIF
6390 "persist"."state" IN ('admission', 'discussion', 'verification')
6391 THEN
6392 RETURN "persist";
6393 ELSE
6394 RETURN NULL;
6395 END IF;
6396 END IF;
6397 IF
6398 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6399 coalesce("persist"."snapshot_created", FALSE) = FALSE
6400 THEN
6401 IF "persist"."state" != 'admission' THEN
6402 PERFORM "take_snapshot"("issue_id_p");
6403 PERFORM "finish_snapshot"("issue_id_p");
6404 ELSE
6405 UPDATE "issue" SET "issue_quorum" = "issue_quorum"."issue_quorum"
6406 FROM "issue_quorum"
6407 WHERE "id" = "issue_id_p"
6408 AND "issue_quorum"."issue_id" = "issue_id_p";
6409 END IF;
6410 "persist"."snapshot_created" = TRUE;
6411 IF "persist"."phase_finished" THEN
6412 IF "persist"."state" = 'admission' THEN
6413 UPDATE "issue" SET "admission_snapshot_id" = "latest_snapshot_id"
6414 WHERE "id" = "issue_id_p";
6415 ELSIF "persist"."state" = 'discussion' THEN
6416 UPDATE "issue" SET "half_freeze_snapshot_id" = "latest_snapshot_id"
6417 WHERE "id" = "issue_id_p";
6418 ELSIF "persist"."state" = 'verification' THEN
6419 UPDATE "issue" SET "full_freeze_snapshot_id" = "latest_snapshot_id"
6420 WHERE "id" = "issue_id_p";
6421 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
6422 FOR "initiative_row" IN
6423 SELECT * FROM "initiative"
6424 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6425 FOR UPDATE
6426 LOOP
6427 IF
6428 "initiative_row"."polling" OR
6429 "initiative_row"."satisfied_supporter_count" >=
6430 "issue_row"."initiative_quorum"
6431 THEN
6432 UPDATE "initiative" SET "admitted" = TRUE
6433 WHERE "id" = "initiative_row"."id";
6434 ELSE
6435 UPDATE "initiative" SET "admitted" = FALSE
6436 WHERE "id" = "initiative_row"."id";
6437 END IF;
6438 END LOOP;
6439 END IF;
6440 END IF;
6441 RETURN "persist";
6442 END IF;
6443 IF
6444 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6445 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
6446 THEN
6447 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
6448 "persist"."harmonic_weights_set" = TRUE;
6449 IF
6450 "persist"."phase_finished" OR
6451 "persist"."issue_revoked" OR
6452 "persist"."state" = 'admission'
6453 THEN
6454 RETURN "persist";
6455 ELSE
6456 RETURN NULL;
6457 END IF;
6458 END IF;
6459 IF "persist"."issue_revoked" THEN
6460 IF "persist"."state" = 'admission' THEN
6461 "state_v" := 'canceled_revoked_before_accepted';
6462 ELSIF "persist"."state" = 'discussion' THEN
6463 "state_v" := 'canceled_after_revocation_during_discussion';
6464 ELSIF "persist"."state" = 'verification' THEN
6465 "state_v" := 'canceled_after_revocation_during_verification';
6466 END IF;
6467 UPDATE "issue" SET
6468 "state" = "state_v",
6469 "closed" = "phase_finished",
6470 "phase_finished" = NULL
6471 WHERE "id" = "issue_id_p";
6472 RETURN NULL;
6473 END IF;
6474 IF "persist"."state" = 'admission' THEN
6475 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6476 FOR UPDATE;
6477 IF "issue_row"."phase_finished" NOTNULL THEN
6478 UPDATE "issue" SET
6479 "state" = 'canceled_issue_not_accepted',
6480 "closed" = "phase_finished",
6481 "phase_finished" = NULL
6482 WHERE "id" = "issue_id_p";
6483 END IF;
6484 RETURN NULL;
6485 END IF;
6486 IF "persist"."phase_finished" THEN
6487 IF "persist"."state" = 'discussion' THEN
6488 UPDATE "issue" SET
6489 "state" = 'verification',
6490 "half_frozen" = "phase_finished",
6491 "phase_finished" = NULL
6492 WHERE "id" = "issue_id_p";
6493 RETURN NULL;
6494 END IF;
6495 IF "persist"."state" = 'verification' THEN
6496 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6497 FOR UPDATE;
6498 SELECT * INTO "policy_row" FROM "policy"
6499 WHERE "id" = "issue_row"."policy_id";
6500 IF EXISTS (
6501 SELECT NULL FROM "initiative"
6502 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
6503 ) THEN
6504 UPDATE "issue" SET
6505 "state" = 'voting',
6506 "fully_frozen" = "phase_finished",
6507 "phase_finished" = NULL
6508 WHERE "id" = "issue_id_p";
6509 ELSE
6510 UPDATE "issue" SET
6511 "state" = 'canceled_no_initiative_admitted',
6512 "fully_frozen" = "phase_finished",
6513 "closed" = "phase_finished",
6514 "phase_finished" = NULL
6515 WHERE "id" = "issue_id_p";
6516 -- NOTE: The following DELETE statements have effect only when
6517 -- issue state has been manipulated
6518 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
6519 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
6520 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
6521 END IF;
6522 RETURN NULL;
6523 END IF;
6524 IF "persist"."state" = 'voting' THEN
6525 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
6526 PERFORM "close_voting"("issue_id_p");
6527 "persist"."closed_voting" = TRUE;
6528 RETURN "persist";
6529 END IF;
6530 PERFORM "calculate_ranks"("issue_id_p");
6531 RETURN NULL;
6532 END IF;
6533 END IF;
6534 RAISE WARNING 'should not happen';
6535 RETURN NULL;
6536 END;
6537 $$;
6539 COMMENT ON FUNCTION "check_issue"
6540 ( "issue"."id"%TYPE,
6541 "check_issue_persistence" )
6542 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")';
6545 CREATE FUNCTION "check_everything"()
6546 RETURNS VOID
6547 LANGUAGE 'plpgsql' VOLATILE AS $$
6548 DECLARE
6549 "area_id_v" "area"."id"%TYPE;
6550 "snapshot_id_v" "snapshot"."id"%TYPE;
6551 "issue_id_v" "issue"."id"%TYPE;
6552 "persist_v" "check_issue_persistence";
6553 BEGIN
6554 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
6555 DELETE FROM "expired_session";
6556 DELETE FROM "expired_token";
6557 DELETE FROM "unused_snapshot";
6558 PERFORM "check_activity"();
6559 PERFORM "calculate_member_counts"();
6560 FOR "area_id_v" IN SELECT "id" FROM "area_with_unaccepted_issues" LOOP
6561 SELECT "take_snapshot"(NULL, "area_id_v") INTO "snapshot_id_v";
6562 PERFORM "finish_snapshot"("issue_id") FROM "snapshot_issue"
6563 WHERE "snapshot_id" = "snapshot_id_v";
6564 LOOP
6565 EXIT WHEN "issue_admission"("area_id_v") = FALSE;
6566 END LOOP;
6567 END LOOP;
6568 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
6569 "persist_v" := NULL;
6570 LOOP
6571 "persist_v" := "check_issue"("issue_id_v", "persist_v");
6572 EXIT WHEN "persist_v" ISNULL;
6573 END LOOP;
6574 END LOOP;
6575 DELETE FROM "unused_snapshot";
6576 RETURN;
6577 END;
6578 $$;
6580 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';
6584 ----------------------
6585 -- Deletion of data --
6586 ----------------------
6589 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
6590 RETURNS VOID
6591 LANGUAGE 'plpgsql' VOLATILE AS $$
6592 BEGIN
6593 IF EXISTS (
6594 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
6595 ) THEN
6596 -- override protection triggers:
6597 INSERT INTO "temporary_transaction_data" ("key", "value")
6598 VALUES ('override_protection_triggers', TRUE::TEXT);
6599 -- clean data:
6600 DELETE FROM "delegating_voter"
6601 WHERE "issue_id" = "issue_id_p";
6602 DELETE FROM "direct_voter"
6603 WHERE "issue_id" = "issue_id_p";
6604 DELETE FROM "delegating_interest_snapshot"
6605 WHERE "issue_id" = "issue_id_p";
6606 DELETE FROM "direct_interest_snapshot"
6607 WHERE "issue_id" = "issue_id_p";
6608 DELETE FROM "non_voter"
6609 WHERE "issue_id" = "issue_id_p";
6610 DELETE FROM "delegation"
6611 WHERE "issue_id" = "issue_id_p";
6612 DELETE FROM "supporter"
6613 USING "initiative" -- NOTE: due to missing index on issue_id
6614 WHERE "initiative"."issue_id" = "issue_id_p"
6615 AND "supporter"."initiative_id" = "initiative_id";
6616 -- mark issue as cleaned:
6617 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
6618 -- finish overriding protection triggers (avoids garbage):
6619 DELETE FROM "temporary_transaction_data"
6620 WHERE "key" = 'override_protection_triggers';
6621 END IF;
6622 RETURN;
6623 END;
6624 $$;
6626 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
6629 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
6630 RETURNS VOID
6631 LANGUAGE 'plpgsql' VOLATILE AS $$
6632 BEGIN
6633 UPDATE "member" SET
6634 "last_login" = NULL,
6635 "last_delegation_check" = NULL,
6636 "login" = NULL,
6637 "password" = NULL,
6638 "authority" = NULL,
6639 "authority_uid" = NULL,
6640 "authority_login" = NULL,
6641 "deleted" = coalesce("deleted", now()),
6642 "locked" = TRUE,
6643 "active" = FALSE,
6644 "notify_email" = NULL,
6645 "notify_email_unconfirmed" = NULL,
6646 "notify_email_secret" = NULL,
6647 "notify_email_secret_expiry" = NULL,
6648 "notify_email_lock_expiry" = NULL,
6649 "disable_notifications" = TRUE,
6650 "notification_counter" = DEFAULT,
6651 "notification_sample_size" = 0,
6652 "notification_dow" = NULL,
6653 "notification_hour" = NULL,
6654 "notification_sent" = NULL,
6655 "login_recovery_expiry" = NULL,
6656 "password_reset_secret" = NULL,
6657 "password_reset_secret_expiry" = NULL,
6658 "location" = NULL
6659 WHERE "id" = "member_id_p";
6660 DELETE FROM "member_settings" WHERE "member_id" = "member_id_p";
6661 DELETE FROM "member_profile" WHERE "member_id" = "member_id_p";
6662 DELETE FROM "rendered_member_statement" WHERE "member_id" = "member_id_p";
6663 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
6664 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
6665 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
6666 DELETE FROM "session" WHERE "member_id" = "member_id_p";
6667 DELETE FROM "member_application" WHERE "member_id" = "member_id_p";
6668 DELETE FROM "token" WHERE "member_id" = "member_id_p";
6669 DELETE FROM "subscription" WHERE "member_id" = "member_id_p";
6670 DELETE FROM "ignored_area" WHERE "member_id" = "member_id_p";
6671 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
6672 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
6673 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
6674 DELETE FROM "direct_voter" USING "issue"
6675 WHERE "direct_voter"."issue_id" = "issue"."id"
6676 AND "issue"."closed" ISNULL
6677 AND "member_id" = "member_id_p";
6678 DELETE FROM "notification_initiative_sent" WHERE "member_id" = "member_id_p";
6679 RETURN;
6680 END;
6681 $$;
6683 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)';
6686 CREATE FUNCTION "delete_private_data"()
6687 RETURNS VOID
6688 LANGUAGE 'plpgsql' VOLATILE AS $$
6689 BEGIN
6690 DELETE FROM "temporary_transaction_data";
6691 DELETE FROM "temporary_suggestion_counts";
6692 DELETE FROM "member" WHERE "activated" ISNULL;
6693 UPDATE "member" SET
6694 "invite_code" = NULL,
6695 "invite_code_expiry" = NULL,
6696 "admin_comment" = NULL,
6697 "last_login" = NULL,
6698 "last_delegation_check" = NULL,
6699 "login" = NULL,
6700 "password" = NULL,
6701 "authority" = NULL,
6702 "authority_uid" = NULL,
6703 "authority_login" = NULL,
6704 "lang" = NULL,
6705 "notify_email" = NULL,
6706 "notify_email_unconfirmed" = NULL,
6707 "notify_email_secret" = NULL,
6708 "notify_email_secret_expiry" = NULL,
6709 "notify_email_lock_expiry" = NULL,
6710 "disable_notifications" = TRUE,
6711 "notification_counter" = DEFAULT,
6712 "notification_sample_size" = 0,
6713 "notification_dow" = NULL,
6714 "notification_hour" = NULL,
6715 "notification_sent" = NULL,
6716 "login_recovery_expiry" = NULL,
6717 "password_reset_secret" = NULL,
6718 "password_reset_secret_expiry" = NULL,
6719 "location" = NULL;
6720 DELETE FROM "verification";
6721 DELETE FROM "member_settings";
6722 DELETE FROM "member_useterms";
6723 DELETE FROM "member_profile";
6724 DELETE FROM "rendered_member_statement";
6725 DELETE FROM "member_image";
6726 DELETE FROM "contact";
6727 DELETE FROM "ignored_member";
6728 DELETE FROM "session";
6729 DELETE FROM "system_application";
6730 DELETE FROM "system_application_redirect_uri";
6731 DELETE FROM "dynamic_application_scope";
6732 DELETE FROM "member_application";
6733 DELETE FROM "token";
6734 DELETE FROM "subscription";
6735 DELETE FROM "ignored_area";
6736 DELETE FROM "ignored_initiative";
6737 DELETE FROM "non_voter";
6738 DELETE FROM "direct_voter" USING "issue"
6739 WHERE "direct_voter"."issue_id" = "issue"."id"
6740 AND "issue"."closed" ISNULL;
6741 DELETE FROM "event_processed";
6742 DELETE FROM "notification_initiative_sent";
6743 DELETE FROM "newsletter";
6744 RETURN;
6745 END;
6746 $$;
6748 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.';
6752 COMMIT;

Impressum / About Us