liquid_feedback_core

view core.sql @ 621:9e4e39136136

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

Impressum / About Us