liquid_feedback_core
view core.sql @ 608:fa3c406a6775
Support for own voting weight other than 1
| author | jbe |
|---|---|
| date | Fri May 15 17:43:06 2020 +0200 (2020-05-15) |
| parents | 617ac1725557 |
| children | 314626831c04 |
line source
2 -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index
4 BEGIN;
6 CREATE EXTENSION IF NOT EXISTS btree_gist;
7 CREATE EXTENSION IF NOT EXISTS latlon;
8 CREATE EXTENSION IF NOT EXISTS conflux;
10 CREATE VIEW "liquid_feedback_version" AS
11 SELECT * FROM (VALUES ('4.2.0', 4, 2, 0))
12 AS "subquery"("string", "major", "minor", "revision");
16 -------------------------
17 -- Tables and indicies --
18 -------------------------
21 CREATE TABLE "temporary_transaction_data" (
22 PRIMARY KEY ("txid", "key"),
23 "txid" INT8 DEFAULT txid_current(),
24 "key" TEXT,
25 "value" TEXT NOT NULL );
27 COMMENT ON TABLE "temporary_transaction_data" IS 'Table to store temporary transaction data; shall be emptied before a transaction is committed';
29 COMMENT ON COLUMN "temporary_transaction_data"."txid" IS 'Value returned by function txid_current(); should be added to WHERE clause, when doing SELECT on this table, but ignored when doing DELETE on this table';
32 CREATE TABLE "system_setting" (
33 "member_ttl" INTERVAL );
34 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1));
36 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.';
37 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.';
39 COMMENT ON COLUMN "system_setting"."member_ttl" IS 'Time after members get their "active" flag set to FALSE, if they do not show any activity.';
42 CREATE TABLE "contingent" (
43 PRIMARY KEY ("polling", "time_frame"),
44 "polling" BOOLEAN,
45 "time_frame" INTERVAL,
46 "text_entry_limit" INT4,
47 "initiative_limit" INT4 );
49 COMMENT ON TABLE "contingent" IS 'Amount of text entries or initiatives a user may create within a given time frame. Only one row needs to be fulfilled for a member to be allowed to post. This table must not be empty.';
51 COMMENT ON COLUMN "contingent"."polling" IS 'Determines if settings are for creating initiatives and new drafts of initiatives with "polling" flag set';
52 COMMENT ON COLUMN "contingent"."text_entry_limit" IS 'Number of new drafts or suggestions to be submitted by each member within the given time frame';
53 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame';
56 CREATE TABLE "file" (
57 "id" SERIAL8 PRIMARY KEY,
58 UNIQUE ("content_type", "hash"),
59 "content_type" TEXT NOT NULL,
60 "hash" TEXT NOT NULL,
61 "data" BYTEA NOT NULL,
62 "preview_content_type" TEXT,
63 "preview_data" BYTEA );
65 COMMENT ON TABLE "file" IS 'Table holding file contents for draft attachments';
67 COMMENT ON COLUMN "file"."content_type" IS 'Content type of "data"';
68 COMMENT ON COLUMN "file"."hash" IS 'Hash of "data" to avoid storing duplicates where content-type and data is identical';
69 COMMENT ON COLUMN "file"."data" IS 'Binary content';
70 COMMENT ON COLUMN "file"."preview_content_type" IS 'Content type of "preview_data"';
71 COMMENT ON COLUMN "file"."preview_data" IS 'Preview (e.g. preview image)';
74 CREATE TABLE "member" (
75 "id" SERIAL4 PRIMARY KEY,
76 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
77 "deleted" TIMESTAMPTZ,
78 "invite_code" TEXT UNIQUE,
79 "invite_code_expiry" TIMESTAMPTZ,
80 "admin_comment" TEXT,
81 "activated" TIMESTAMPTZ,
82 "last_activity" DATE,
83 "last_login" TIMESTAMPTZ,
84 "last_delegation_check" TIMESTAMPTZ,
85 "login" TEXT UNIQUE,
86 "password" TEXT,
87 "authority" TEXT,
88 "authority_uid" TEXT,
89 "authority_login" TEXT,
90 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
91 "active" BOOLEAN NOT NULL DEFAULT FALSE,
92 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
93 "lang" TEXT,
94 "notify_email" TEXT,
95 "notify_email_unconfirmed" TEXT,
96 "notify_email_secret" TEXT UNIQUE,
97 "notify_email_secret_expiry" TIMESTAMPTZ,
98 "notify_email_lock_expiry" TIMESTAMPTZ,
99 "unsubscribe_secret" TEXT,
100 "disable_notifications" BOOLEAN NOT NULL DEFAULT FALSE,
101 "notification_counter" INT4 NOT NULL DEFAULT 1,
102 "notification_sample_size" INT4 NOT NULL DEFAULT 3,
103 "notification_dow" INT4 CHECK ("notification_dow" BETWEEN 0 AND 6),
104 "notification_hour" INT4 DEFAULT floor(random() * 24) CHECK ("notification_hour" BETWEEN 0 AND 23),
105 "notification_sent" TIMESTAMP,
106 "login_recovery_expiry" TIMESTAMPTZ,
107 "password_reset_secret" TEXT UNIQUE,
108 "password_reset_secret_expiry" TIMESTAMPTZ,
109 "name" TEXT UNIQUE, -- full text search
110 "identification" TEXT UNIQUE, -- full text search
111 "authentication" TEXT,
112 "role" BOOLEAN NOT NULL DEFAULT FALSE,
113 "location" JSONB,
114 CONSTRAINT "deleted_requires_locked"
115 CHECK ("deleted" ISNULL OR "locked" = TRUE),
116 CONSTRAINT "active_requires_activated_and_last_activity"
117 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)),
118 CONSTRAINT "authority_requires_uid_and_vice_versa"
119 CHECK (("authority" NOTNULL) = ("authority_uid" NOTNULL)),
120 CONSTRAINT "authority_uid_unique_per_authority"
121 UNIQUE ("authority", "authority_uid"),
122 CONSTRAINT "authority_login_requires_authority"
123 CHECK ("authority" NOTNULL OR "authority_login" ISNULL),
124 CONSTRAINT "notification_dow_requires_notification_hour"
125 CHECK ("notification_dow" ISNULL OR "notification_hour" NOTNULL),
126 CONSTRAINT "name_not_null_if_activated"
127 CHECK ("activated" ISNULL OR "name" NOTNULL) );
128 CREATE INDEX "member_authority_login_idx" ON "member" ("authority_login");
129 CREATE INDEX "member_active_idx" ON "member" ("active");
130 CREATE INDEX "member_location_idx" ON "member" USING gist ((GeoJSON_to_ecluster("location")));
132 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
134 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
135 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
136 COMMENT ON COLUMN "member"."invite_code_expiry" IS 'Expiry data/time for "invite_code"';
137 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
138 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';
139 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
140 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
141 COMMENT ON COLUMN "member"."last_delegation_check" IS 'Timestamp of last delegation check (i.e. confirmation of all unit and area delegations)';
142 COMMENT ON COLUMN "member"."login" IS 'Login name';
143 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
144 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)';
145 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)';
146 COMMENT ON COLUMN "member"."authority_login" IS 'Login name for external accounts (field is not unique!)';
147 COMMENT ON COLUMN "member"."deleted" IS 'Timestamp of deletion (set by "delete_member" function)';
148 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
149 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".';
150 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
151 COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member';
152 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
153 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
154 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
155 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
156 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
157 COMMENT ON COLUMN "member"."unsubscribe_secret" IS 'Secret string to be used for a List-Unsubscribe mail header';
158 COMMENT ON COLUMN "member"."disable_notifications" IS 'TRUE if member does not want to receive notifications';
159 COMMENT ON COLUMN "member"."notification_counter" IS 'Sequential number of next scheduled notification message (used as a seed for pseudo-random initiative selection algorithm)';
160 COMMENT ON COLUMN "member"."notification_sample_size" IS 'Number of featured initiatives per issue in scheduled notification messages';
161 COMMENT ON COLUMN "member"."notification_dow" IS 'Day of week for scheduled notifications (NULL to receive a daily digest)';
162 COMMENT ON COLUMN "member"."notification_hour" IS 'Time of day when scheduled notifications are sent out';
163 COMMENT ON COLUMN "member"."notification_sent" IS 'Timestamp of last scheduled notification mail that has been sent out';
164 COMMENT ON COLUMN "member"."login_recovery_expiry" IS 'Date/time after which another login recovery attempt is allowed';
165 COMMENT ON COLUMN "member"."password_reset_secret" IS 'Secret string sent via e-mail for password recovery';
166 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';
167 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member, may be NULL if account has not been activated yet';
168 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
169 COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated';
170 COMMENT ON COLUMN "member"."location" IS 'Geographic location on earth as GeoJSON object';
173 CREATE TABLE "member_history" ( -- TODO: redundancy with new "event" table
174 "id" SERIAL8 PRIMARY KEY,
175 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
176 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
177 "active" BOOLEAN NOT NULL,
178 "name" TEXT NOT NULL );
179 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
181 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
183 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
184 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
187 CREATE TABLE "agent" (
188 PRIMARY KEY ("controlled_id", "controller_id"),
189 "controlled_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
190 "controller_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
191 "accepted" BOOLEAN,
192 CONSTRAINT "controlled_id_and_controller_id_differ" CHECK (
193 "controlled_id" != "controller_id" ) );
194 CREATE INDEX "agent_controller_id_idx" ON "agent" ("controller_id");
196 COMMENT ON TABLE "agent" IS 'Privileges for role accounts';
198 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.';
201 CREATE TABLE "verification" (
202 "id" SERIAL8 PRIMARY KEY,
203 "requested" TIMESTAMPTZ,
204 "request_origin" JSONB,
205 "request_data" JSONB,
206 "requesting_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
207 "verifying_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
208 "verified_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
209 "verified" TIMESTAMPTZ,
210 "verification_data" JSONB,
211 "denied" TIMESTAMPTZ,
212 "comment" TEXT,
213 CONSTRAINT "verified_and_denied_conflict" CHECK (
214 "verified" ISNULL OR "denied" ISNULL ) );
215 CREATE INDEX "verification_requested_idx" ON "verification" ("requested");
216 CREATE INDEX "verification_open_request_idx" ON "verification" ("requested") WHERE "verified" ISNULL AND "denied" ISNULL;
217 CREATE INDEX "verification_requesting_member_id_idx" ON "verification" ("requesting_member_id");
218 CREATE INDEX "verification_verified_member_id_idx" ON "verification" ("verified_member_id");
219 CREATE INDEX "verification_verified_idx" ON "verification" ("verified");
220 CREATE INDEX "verification_denied_idx" ON "verification" ("denied");
222 COMMENT ON TABLE "verification" IS 'Request to verify a participant';
224 COMMENT ON COLUMN "verification"."requested" IS 'Timestamp when request for verification has been submitted';
225 COMMENT ON COLUMN "verification"."request_origin" IS 'JSON data containing information about the origin of the request (e.g. IP address or hostname)';
226 COMMENT ON COLUMN "verification"."request_data" IS 'JSON data containing information about the entity to be verified (e.g. real name, address, etc.)';
227 COMMENT ON COLUMN "verification"."requesting_member_id" IS 'Member who requested verification';
228 COMMENT ON COLUMN "verification"."verifying_member_id" IS 'Member who processed the verification request (i.e. who accepted or denied the request)';
229 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)';
230 COMMENT ON COLUMN "verification"."verified" IS 'Timestamp when request for verification has been accepted by authority';
231 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';
232 COMMENT ON COLUMN "verification"."denied" IS 'Timestamp when request for verification has been denied by authority';
233 COMMENT ON COLUMN "verification"."comment" IS 'Administrative comment';
236 -- TODO: merge tables "verification" and "role_verification"
238 CREATE TABLE "role_verification" (
239 "id" SERIAL8 PRIMARY KEY,
240 "requested" TIMESTAMPTZ,
241 "request_origin" JSONB,
242 "request_data" JSONB,
243 "requesting_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
244 "requesting_real_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
245 "verifying_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
246 "verified_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
247 "verified" TIMESTAMPTZ,
248 "verification_data" JSONB,
249 "denied" TIMESTAMPTZ,
250 "comment" TEXT,
251 CONSTRAINT "verified_and_denied_conflict" CHECK (
252 "verified" ISNULL OR "denied" ISNULL ) );
253 CREATE INDEX "role_verification_requested_idx" ON "role_verification" ("requested");
254 CREATE INDEX "role_verification_open_request_idx" ON "role_verification" ("requested") WHERE "verified" ISNULL AND "denied" ISNULL;
255 CREATE INDEX "role_verification_requesting_member_id_idx" ON "role_verification" ("requesting_member_id");
256 CREATE INDEX "role_verification_verified_member_id_idx" ON "role_verification" ("verified_member_id");
257 CREATE INDEX "role_verification_verified_idx" ON "role_verification" ("verified");
258 CREATE INDEX "role_verification_denied_idx" ON "role_verification" ("denied");
260 COMMENT ON TABLE "role_verification" IS 'Request to verify a role account (see table "verification" for documentation of columns not documented for this table)';
262 COMMENT ON COLUMN "role_verification"."requesting_member_id" IS 'Member role account to verify';
263 COMMENT ON COLUMN "role_verification"."requesting_real_member_id" IS 'Member account of real person who requested verification';
266 CREATE TABLE "member_settings" (
267 "member_id" INT4 PRIMARY KEY REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
268 "settings" JSONB NOT NULL CHECK (jsonb_typeof("settings") = 'object') );
270 COMMENT ON TABLE "member_settings" IS 'Stores a JSON document for each member containing optional (additional) settings for the respective member';
273 CREATE TABLE "member_useterms" (
274 "id" SERIAL8 PRIMARY KEY,
275 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
276 "accepted" TIMESTAMPTZ NOT NULL DEFAULT now(),
277 "contract_identifier" TEXT NOT NULL );
278 CREATE INDEX "member_useterms_member_id_contract_identifier" ON "member_useterms" ("member_id", "contract_identifier");
280 COMMENT ON TABLE "member_useterms" IS 'Keeps record of accepted terms of use; may contain multiple rows per member';
282 COMMENT ON COLUMN "member_useterms"."accepted" IS 'Point in time when user accepted the terms of use';
283 COMMENT ON COLUMN "member_useterms"."contract_identifier" IS 'String identifier to denote the accepted terms of use, including their version or revision';
286 CREATE TABLE "member_profile" (
287 "member_id" INT4 PRIMARY KEY REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
288 "formatting_engine" TEXT,
289 "statement" TEXT, -- full text search
290 "profile" JSONB NOT NULL DEFAULT '{}' CHECK (jsonb_typeof("profile") = 'object'),
291 "profile_text_data" TEXT ); -- full text search
293 COMMENT ON COLUMN "member_profile"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member_profile"."statement"';
294 COMMENT ON COLUMN "member_profile"."statement" IS 'Freely chosen text of the member for his/her profile';
295 COMMENT ON COLUMN "member_profile"."profile" IS 'Additional profile data as JSON document';
296 COMMENT ON COLUMN "member_profile"."profile_text_data" IS 'Text data from "profile" field for full text search';
299 CREATE TABLE "rendered_member_statement" (
300 PRIMARY KEY ("member_id", "format"),
301 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
302 "format" TEXT,
303 "content" TEXT NOT NULL );
305 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)';
308 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
310 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
313 CREATE TABLE "member_image" (
314 PRIMARY KEY ("member_id", "image_type", "scaled"),
315 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
316 "image_type" "member_image_type",
317 "scaled" BOOLEAN,
318 "content_type" TEXT, -- TODO: NOT NULL?
319 "data" BYTEA NOT NULL );
321 COMMENT ON TABLE "member_image" IS 'Images of members';
323 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
326 CREATE TABLE "member_count" (
327 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
328 "total_count" INT4 NOT NULL );
330 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';
332 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
333 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
336 CREATE TABLE "contact" (
337 PRIMARY KEY ("member_id", "other_member_id"),
338 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
339 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
340 "public" BOOLEAN NOT NULL DEFAULT FALSE,
341 "following" BOOLEAN NOT NULL DEFAULT TRUE,
342 CONSTRAINT "cant_save_yourself_as_contact"
343 CHECK ("member_id" != "other_member_id") );
344 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
346 COMMENT ON TABLE "contact" IS 'Contact lists';
348 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
349 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
350 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
351 COMMENT ON COLUMN "contact"."following" IS 'TRUE = actions of contact are shown in personal timeline';
354 CREATE TABLE "ignored_member" (
355 PRIMARY KEY ("member_id", "other_member_id"),
356 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
357 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
358 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
360 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
362 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
363 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
366 CREATE TABLE "session" (
367 UNIQUE ("member_id", "id"), -- index needed for foreign-key on table "token"
368 "id" SERIAL8 PRIMARY KEY,
369 "ident" TEXT NOT NULL UNIQUE,
370 "additional_secret" TEXT,
371 "logout_token" TEXT,
372 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
373 "member_id" INT4 REFERENCES "member" ("id") ON DELETE SET NULL,
374 "real_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
375 "authority" TEXT,
376 "authority_uid" TEXT,
377 "authority_login" TEXT,
378 "needs_delegation_check" BOOLEAN NOT NULL DEFAULT FALSE,
379 "lang" TEXT );
380 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
382 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
384 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
385 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
386 COMMENT ON COLUMN "session"."logout_token" IS 'Optional token to authorize logout through external component';
387 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in, or role account in use';
388 COMMENT ON COLUMN "session"."real_member_id" IS 'Reference to member, who is really logged in (real person rather than role account)';
389 COMMENT ON COLUMN "session"."authority" IS 'Temporary store for "member"."authority" during member account creation';
390 COMMENT ON COLUMN "session"."authority_uid" IS 'Temporary store for "member"."authority_uid" during member account creation';
391 COMMENT ON COLUMN "session"."authority_login" IS 'Temporary store for "member"."authority_login" during member account creation';
392 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';
393 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
396 CREATE TYPE "authflow" AS ENUM ('code', 'token');
398 COMMENT ON TYPE "authflow" IS 'OAuth 2.0 flows: ''code'' = Authorization Code flow, ''token'' = Implicit flow';
401 CREATE TABLE "system_application" (
402 "id" SERIAL4 PRIMARY KEY,
403 "name" TEXT NOT NULL,
404 "base_url" TEXT,
405 "manifest_url" TEXT,
406 "client_id" TEXT NOT NULL UNIQUE,
407 "default_redirect_uri" TEXT NOT NULL,
408 "cert_common_name" TEXT,
409 "client_cred_scope" TEXT,
410 "flow" "authflow",
411 "automatic_scope" TEXT,
412 "permitted_scope" TEXT,
413 "forbidden_scope" TEXT );
415 COMMENT ON TABLE "system_application" IS 'OAuth 2.0 clients that are registered by the system administrator';
417 COMMENT ON COLUMN "system_application"."name" IS 'Human readable name of application';
418 COMMENT ON COLUMN "system_application"."base_url" IS 'Base URL for users';
419 COMMENT ON COLUMN "system_application"."manifest_url" IS 'URL referring to a manifest that can be used for application (type/version) discovery';
420 COMMENT ON COLUMN "system_application"."client_id" IS 'OAuth 2.0 "client_id"';
421 COMMENT ON COLUMN "system_application"."cert_common_name" IS 'Value for CN field of TLS client certificate';
422 COMMENT ON COLUMN "system_application"."client_cred_scope" IS 'Space-separated list of scopes; If set, Client Credentials Grant is allowed; value determines scope';
423 COMMENT ON COLUMN "system_application"."flow" IS 'If set to ''code'' or ''token'', then Authorization Code or Implicit flow is allowed respectively';
424 COMMENT ON COLUMN "system_application"."automatic_scope" IS 'Space-separated list of scopes; Automatically granted scope for Authorization Code or Implicit flow';
425 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';
426 COMMENT ON COLUMN "system_application"."forbidden_scope" IS 'Space-separated list of scopes that may not be granted to the application by a member';
429 CREATE TABLE "system_application_redirect_uri" (
430 PRIMARY KEY ("system_application_id", "redirect_uri"),
431 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
432 "redirect_uri" TEXT );
434 COMMENT ON TABLE "system_application_redirect_uri" IS 'Additional OAuth 2.0 redirection endpoints, which may be selected through the "redirect_uri" GET parameter';
437 CREATE TABLE "dynamic_application_scope" (
438 PRIMARY KEY ("redirect_uri", "flow", "scope"),
439 "redirect_uri" TEXT,
440 "flow" TEXT,
441 "scope" TEXT,
442 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours' );
443 CREATE INDEX "dynamic_application_scope_redirect_uri_scope_idx" ON "dynamic_application_scope" ("redirect_uri", "flow", "scope");
444 CREATE INDEX "dynamic_application_scope_expiry_idx" ON "dynamic_application_scope" ("expiry");
446 COMMENT ON TABLE "dynamic_application_scope" IS 'Dynamic OAuth 2.0 client registration data';
448 COMMENT ON COLUMN "dynamic_application_scope"."redirect_uri" IS 'Redirection endpoint for which the registration has been done';
449 COMMENT ON COLUMN "dynamic_application_scope"."flow" IS 'OAuth 2.0 flow for which the registration has been done (see also "system_application"."flow")';
450 COMMENT ON COLUMN "dynamic_application_scope"."scope" IS 'Single scope without space characters (use multiple rows for more scopes)';
451 COMMENT ON COLUMN "dynamic_application_scope"."expiry" IS 'Expiry unless renewed';
454 CREATE TABLE "member_application" (
455 "id" SERIAL4 PRIMARY KEY,
456 UNIQUE ("system_application_id", "member_id"),
457 UNIQUE ("domain", "member_id"),
458 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
459 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
460 "domain" TEXT,
461 "session_id" INT8,
462 FOREIGN KEY ("member_id", "session_id") REFERENCES "session" ("member_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
463 "scope" TEXT NOT NULL,
464 CONSTRAINT "system_application_or_domain_but_not_both" CHECK (
465 ("system_application_id" NOTNULL AND "domain" ISNULL) OR
466 ("system_application_id" ISNULL AND "domain" NOTNULL) ) );
467 CREATE INDEX "member_application_member_id_idx" ON "member_application" ("member_id");
469 COMMENT ON TABLE "member_application" IS 'Application authorized by a member';
471 COMMENT ON COLUMN "member_application"."system_application_id" IS 'If set, then application is a system application';
472 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';
473 COMMENT ON COLUMN "member_application"."session_id" IS 'If set, registration ends with session';
474 COMMENT ON COLUMN "member_application"."scope" IS 'Granted scope as space-separated list of strings';
477 CREATE TYPE "token_type" AS ENUM ('authorization', 'refresh', 'access');
479 COMMENT ON TYPE "token_type" IS 'Types for entries in "token" table';
482 CREATE TABLE "token" (
483 "id" SERIAL8 PRIMARY KEY,
484 "token" TEXT NOT NULL UNIQUE,
485 "token_type" "token_type" NOT NULL,
486 "authorization_token_id" INT8 REFERENCES "token" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
487 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
488 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
489 "domain" TEXT,
490 FOREIGN KEY ("member_id", "domain") REFERENCES "member_application" ("member_id", "domain") ON DELETE CASCADE ON UPDATE CASCADE,
491 "session_id" INT8,
492 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"
493 "redirect_uri" TEXT,
494 "redirect_uri_explicit" BOOLEAN,
495 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
496 "expiry" TIMESTAMPTZ DEFAULT now() + '1 hour',
497 "used" BOOLEAN NOT NULL DEFAULT FALSE,
498 "scope" TEXT NOT NULL,
499 CONSTRAINT "access_token_needs_expiry"
500 CHECK ("token_type" != 'access'::"token_type" OR "expiry" NOTNULL),
501 CONSTRAINT "authorization_token_needs_redirect_uri"
502 CHECK ("token_type" != 'authorization'::"token_type" OR ("redirect_uri" NOTNULL AND "redirect_uri_explicit" NOTNULL) ) );
503 CREATE INDEX "token_member_id_idx" ON "token" ("member_id");
504 CREATE INDEX "token_authorization_token_id_idx" ON "token" ("authorization_token_id");
505 CREATE INDEX "token_expiry_idx" ON "token" ("expiry");
507 COMMENT ON TABLE "token" IS 'Issued OAuth 2.0 authorization codes and access/refresh tokens';
509 COMMENT ON COLUMN "token"."token" IS 'String secret (the actual token)';
510 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)';
511 COMMENT ON COLUMN "token"."system_application_id" IS 'If set, then application is a system application';
512 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';
513 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''';
514 COMMENT ON COLUMN "token"."redirect_uri" IS 'Authorization codes must be bound to a specific redirect URI';
515 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)';
516 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';
517 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)';
518 COMMENT ON COLUMN "token"."scope" IS 'Scope as space-separated list of strings (detached scopes are marked with ''_detached'' suffix)';
521 CREATE TABLE "token_scope" (
522 PRIMARY KEY ("token_id", "index"),
523 "token_id" INT8 REFERENCES "token" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
524 "index" INT4,
525 "scope" TEXT NOT NULL );
527 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';
530 CREATE TYPE "defeat_strength" AS ENUM ('simple', 'tuple');
532 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';
535 CREATE TYPE "tie_breaking" AS ENUM ('simple', 'variant1', 'variant2');
537 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';
540 CREATE TABLE "policy" (
541 "id" SERIAL4 PRIMARY KEY,
542 "index" INT4 NOT NULL,
543 "active" BOOLEAN NOT NULL DEFAULT TRUE,
544 "name" TEXT NOT NULL UNIQUE,
545 "description" TEXT NOT NULL DEFAULT '',
546 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
547 "min_admission_time" INTERVAL,
548 "max_admission_time" INTERVAL,
549 "discussion_time" INTERVAL,
550 "verification_time" INTERVAL,
551 "voting_time" INTERVAL,
552 "issue_quorum" INT4 CHECK ("issue_quorum" >= 1),
553 "issue_quorum_num" INT4,
554 "issue_quorum_den" INT4,
555 "initiative_quorum" INT4 NOT NULL CHECK ("initiative_quorum" >= 1),
556 "initiative_quorum_num" INT4 NOT NULL,
557 "initiative_quorum_den" INT4 NOT NULL,
558 "defeat_strength" "defeat_strength" NOT NULL DEFAULT 'tuple',
559 "tie_breaking" "tie_breaking" NOT NULL DEFAULT 'variant1',
560 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
561 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
562 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
563 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
564 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
565 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
566 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
567 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
568 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
569 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
570 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT FALSE,
571 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
572 CONSTRAINT "issue_quorum_if_and_only_if_not_polling" CHECK (
573 "polling" = ("issue_quorum" ISNULL) AND
574 "polling" = ("issue_quorum_num" ISNULL) AND
575 "polling" = ("issue_quorum_den" ISNULL) ),
576 CONSTRAINT "min_admission_time_smaller_than_max_admission_time" CHECK (
577 "min_admission_time" < "max_admission_time" ),
578 CONSTRAINT "timing_null_or_not_null_constraints" CHECK (
579 ( "polling" = FALSE AND
580 "min_admission_time" NOTNULL AND "max_admission_time" NOTNULL AND
581 "discussion_time" NOTNULL AND
582 "verification_time" NOTNULL AND
583 "voting_time" NOTNULL ) OR
584 ( "polling" = TRUE AND
585 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
586 "discussion_time" NOTNULL AND
587 "verification_time" NOTNULL AND
588 "voting_time" NOTNULL ) OR
589 ( "polling" = TRUE AND
590 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
591 "discussion_time" ISNULL AND
592 "verification_time" ISNULL AND
593 "voting_time" ISNULL ) ),
594 CONSTRAINT "no_reverse_beat_path_requires_tuple_defeat_strength" CHECK (
595 "defeat_strength" = 'tuple'::"defeat_strength" OR
596 "no_reverse_beat_path" = FALSE ) );
597 CREATE INDEX "policy_active_idx" ON "policy" ("active");
599 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
601 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
602 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
603 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';
604 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"';
605 COMMENT ON COLUMN "policy"."max_admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
606 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
607 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"';
608 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'')';
609 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';
610 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)';
611 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)';
612 COMMENT ON COLUMN "policy"."initiative_quorum" IS 'Absolute number of satisfied supporters to be reached by an initiative to be "admitted" for voting';
613 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
614 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
615 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';
616 COMMENT ON COLUMN "policy"."tie_breaking" IS 'Tie-breaker for the Schulze method; see type "tie_breaking"; ''variant1'' or ''variant2'' are recommended';
617 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
618 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
619 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.';
620 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
621 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';
622 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';
623 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';
624 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.';
625 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';
626 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';
627 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.';
628 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").';
631 CREATE TABLE "unit" (
632 "id" SERIAL4 PRIMARY KEY,
633 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
634 "active" BOOLEAN NOT NULL DEFAULT TRUE,
635 "name" TEXT NOT NULL, -- full text search
636 "description" TEXT NOT NULL DEFAULT '', -- full text search
637 "external_reference" TEXT,
638 "member_count" INT4,
639 "member_weight" INT4,
640 "location" JSONB );
641 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
642 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
643 CREATE INDEX "unit_active_idx" ON "unit" ("active");
644 CREATE INDEX "unit_location_idx" ON "unit" USING gist ((GeoJSON_to_ecluster("location")));
646 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
648 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
649 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
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 member''s 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 "interest" (
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 RESTRICT ON UPDATE CASCADE );
1126 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
1128 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.';
1131 CREATE TABLE "initiator" (
1132 PRIMARY KEY ("initiative_id", "member_id"),
1133 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1134 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1135 "accepted" BOOLEAN );
1136 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
1138 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.';
1140 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.';
1143 CREATE TABLE "supporter" (
1144 "issue_id" INT4 NOT NULL,
1145 PRIMARY KEY ("initiative_id", "member_id"),
1146 "initiative_id" INT4,
1147 "member_id" INT4,
1148 "draft_id" INT8 NOT NULL,
1149 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1150 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
1151 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
1153 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.';
1155 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1156 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")';
1159 CREATE TABLE "opinion" (
1160 "initiative_id" INT4 NOT NULL,
1161 PRIMARY KEY ("suggestion_id", "member_id"),
1162 "suggestion_id" INT8,
1163 "member_id" INT4,
1164 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
1165 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
1166 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1167 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1168 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
1170 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.';
1172 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
1175 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
1177 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
1180 CREATE TABLE "delegation" (
1181 "id" SERIAL8 PRIMARY KEY,
1182 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1183 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1184 "scope" "delegation_scope" NOT NULL,
1185 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1186 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1187 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1188 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
1189 CONSTRAINT "no_unit_delegation_to_null"
1190 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
1191 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
1192 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
1193 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
1194 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
1195 UNIQUE ("unit_id", "truster_id"),
1196 UNIQUE ("area_id", "truster_id"),
1197 UNIQUE ("issue_id", "truster_id") );
1198 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
1199 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
1201 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
1203 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
1204 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
1205 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
1208 CREATE TABLE "snapshot_issue" (
1209 PRIMARY KEY ("snapshot_id", "issue_id"),
1210 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1211 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); -- NOTE: trigger "delete_snapshot_on_partial_delete" will delete whole "snapshot"
1212 CREATE INDEX "snapshot_issue_issue_id_idx" ON "snapshot_issue" ("issue_id");
1214 COMMENT ON TABLE "snapshot_issue" IS 'List of issues included in a snapshot';
1216 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.';
1219 CREATE TABLE "direct_interest_snapshot" (
1220 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
1221 "snapshot_id" INT8,
1222 "issue_id" INT4,
1223 FOREIGN KEY ("snapshot_id", "issue_id")
1224 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1225 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1226 "ownweight" INT4 NOT NULL,
1227 "weight" INT4 );
1228 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
1230 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';
1232 COMMENT ON COLUMN "direct_interest_snapshot"."ownweight" IS 'Own voting weight of member, disregading delegations';
1233 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Voting weight of member according to own weight and "delegating_interest_snapshot"';
1236 CREATE TABLE "delegating_interest_snapshot" (
1237 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
1238 "snapshot_id" INT8,
1239 "issue_id" INT4,
1240 FOREIGN KEY ("snapshot_id", "issue_id")
1241 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1242 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1243 "ownweight" INT4 NOT NULL,
1244 "weight" INT4,
1245 "scope" "delegation_scope" NOT NULL,
1246 "delegate_member_ids" INT4[] NOT NULL );
1247 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
1249 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';
1251 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
1252 COMMENT ON COLUMN "delegating_interest_snapshot"."ownweight" IS 'Own voting weight of member, disregading delegations';
1253 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate voting weight considering incoming delegations';
1254 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"';
1257 CREATE TABLE "direct_supporter_snapshot" (
1258 PRIMARY KEY ("snapshot_id", "initiative_id", "member_id"),
1259 "snapshot_id" INT8,
1260 "issue_id" INT4 NOT NULL,
1261 FOREIGN KEY ("snapshot_id", "issue_id")
1262 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1263 "initiative_id" INT4,
1264 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1265 "draft_id" INT8 NOT NULL,
1266 "informed" BOOLEAN NOT NULL,
1267 "satisfied" BOOLEAN NOT NULL,
1268 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1269 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1270 FOREIGN KEY ("snapshot_id", "issue_id", "member_id") REFERENCES "direct_interest_snapshot" ("snapshot_id", "issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1271 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1273 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';
1275 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';
1276 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1277 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1280 CREATE TABLE "non_voter" (
1281 PRIMARY KEY ("member_id", "issue_id"),
1282 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1283 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1284 CREATE INDEX "non_voter_issue_id_idx" ON "non_voter" ("issue_id");
1286 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1289 CREATE TABLE "direct_voter" (
1290 PRIMARY KEY ("issue_id", "member_id"),
1291 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1292 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1293 "ownweight" INT4,
1294 "weight" INT4,
1295 "comment_changed" TIMESTAMPTZ,
1296 "formatting_engine" TEXT,
1297 "comment" TEXT ); -- full text index
1298 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1300 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';
1302 COMMENT ON COLUMN "direct_voter"."ownweight" IS 'Own voting weight of member, disregarding delegations';
1303 COMMENT ON COLUMN "direct_voter"."weight" IS 'Voting weight of member according to own weight and "delegating_interest_snapshot"';
1304 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';
1305 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';
1306 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.';
1309 CREATE TABLE "rendered_voter_comment" (
1310 PRIMARY KEY ("issue_id", "member_id", "format"),
1311 FOREIGN KEY ("issue_id", "member_id")
1312 REFERENCES "direct_voter" ("issue_id", "member_id")
1313 ON DELETE CASCADE ON UPDATE CASCADE,
1314 "issue_id" INT4,
1315 "member_id" INT4,
1316 "format" TEXT,
1317 "content" TEXT NOT NULL );
1319 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)';
1322 CREATE TABLE "delegating_voter" (
1323 PRIMARY KEY ("issue_id", "member_id"),
1324 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1325 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1326 "ownweight" INT4 NOT NULL,
1327 "weight" INT4,
1328 "scope" "delegation_scope" NOT NULL,
1329 "delegate_member_ids" INT4[] NOT NULL );
1330 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1332 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';
1334 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1335 COMMENT ON COLUMN "delegating_voter"."ownweight" IS 'Own voting weight of member, disregarding delegations';
1336 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate voting weight considering incoming delegations';
1337 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"';
1340 CREATE TABLE "vote" (
1341 "issue_id" INT4 NOT NULL,
1342 PRIMARY KEY ("initiative_id", "member_id"),
1343 "initiative_id" INT4,
1344 "member_id" INT4,
1345 "grade" INT4 NOT NULL,
1346 "first_preference" BOOLEAN,
1347 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1348 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1349 CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
1350 CHECK ("grade" > 0 OR "first_preference" ISNULL) );
1351 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1353 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';
1355 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1356 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.';
1357 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.';
1360 CREATE TABLE "posting" (
1361 UNIQUE ("author_id", "id"), -- index needed for foreign-key on table "posting_lexeme"
1362 "id" SERIAL8 PRIMARY KEY,
1363 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1364 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
1365 "message" TEXT NOT NULL,
1366 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1367 "area_id" INT4,
1368 FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1369 "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1370 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1371 FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1372 FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1373 "initiative_id" INT4,
1374 "suggestion_id" INT8,
1375 -- NOTE: no referential integrity for suggestions because those are
1376 -- actually deleted
1377 -- FOREIGN KEY ("initiative_id", "suggestion_id")
1378 -- REFERENCES "suggestion" ("initiative_id", "id")
1379 -- ON DELETE CASCADE ON UPDATE CASCADE,
1380 CONSTRAINT "area_requires_unit" CHECK (
1381 "area_id" ISNULL OR "unit_id" NOTNULL ),
1382 CONSTRAINT "policy_set_when_issue_set" CHECK (
1383 ("policy_id" NOTNULL) = ("issue_id" NOTNULL) ),
1384 CONSTRAINT "issue_requires_area" CHECK (
1385 "issue_id" ISNULL OR "area_id" NOTNULL ),
1386 CONSTRAINT "initiative_requires_issue" CHECK (
1387 "initiative_id" ISNULL OR "issue_id" NOTNULL ),
1388 CONSTRAINT "suggestion_requires_initiative" CHECK (
1389 "suggestion_id" ISNULL OR "initiative_id" NOTNULL ) );
1390 CREATE INDEX "posting_global_idx" ON "posting" USING gist ((pstamp("author_id", "id")));
1391 CREATE INDEX "posting_unit_idx" ON "posting" USING gist ("unit_id", (pstamp("author_id", "id"))) WHERE "unit_id" NOTNULL;
1392 CREATE INDEX "posting_area_idx" ON "posting" USING gist ("area_id", (pstamp("author_id", "id"))) WHERE "area_id" NOTNULL;
1393 CREATE INDEX "posting_policy_idx" ON "posting" USING gist ("policy_id", (pstamp("author_id", "id"))) WHERE "policy_id" NOTNULL;
1394 CREATE INDEX "posting_issue_idx" ON "posting" USING gist ("issue_id", (pstamp("author_id", "id"))) WHERE "issue_id" NOTNULL;
1395 CREATE INDEX "posting_initiative_idx" ON "posting" USING gist ("initiative_id", (pstamp("author_id", "id"))) WHERE "initiative_id" NOTNULL;
1396 CREATE INDEX "posting_suggestion_idx" ON "posting" USING gist ("suggestion_id", (pstamp("author_id", "id"))) WHERE "suggestion_id" NOTNULL;
1398 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';
1401 CREATE TABLE "posting_lexeme" (
1402 PRIMARY KEY ("posting_id", "lexeme"),
1403 FOREIGN KEY ("posting_id", "author_id") REFERENCES "posting" ("id", "author_id") ON DELETE CASCADE ON UPDATE CASCADE,
1404 "posting_id" INT8,
1405 "lexeme" TEXT,
1406 "author_id" INT4 );
1407 CREATE INDEX "posting_lexeme_idx" ON "posting_lexeme" USING gist ("lexeme", (pstamp("author_id", "posting_id")));
1409 COMMENT ON TABLE "posting_lexeme" IS 'Helper table to allow searches for hashtags.';
1412 CREATE TYPE "event_type" AS ENUM (
1413 'unit_created',
1414 'unit_updated',
1415 'area_created',
1416 'area_updated',
1417 'policy_created',
1418 'policy_updated',
1419 'issue_state_changed',
1420 'initiative_created_in_new_issue',
1421 'initiative_created_in_existing_issue',
1422 'initiative_revoked',
1423 'new_draft_created',
1424 'suggestion_created',
1425 'suggestion_deleted',
1426 'member_activated',
1427 'member_deleted',
1428 'member_active',
1429 'member_name_updated',
1430 'member_profile_updated',
1431 'member_image_updated',
1432 'interest',
1433 'initiator',
1434 'support',
1435 'support_updated',
1436 'suggestion_rated',
1437 'delegation',
1438 'contact',
1439 'posting_created' );
1441 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1444 CREATE TABLE "event" (
1445 "id" SERIAL8 PRIMARY KEY,
1446 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1447 "event" "event_type" NOT NULL,
1448 "posting_id" INT8 REFERENCES "posting" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1449 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1450 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1451 "scope" "delegation_scope",
1452 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1453 "area_id" INT4,
1454 FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1455 "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1456 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1457 FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1458 FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1459 "state" "issue_state",
1460 "initiative_id" INT4,
1461 "draft_id" INT8,
1462 "suggestion_id" INT8,
1463 "boolean_value" BOOLEAN,
1464 "numeric_value" INT4,
1465 "text_value" TEXT,
1466 "old_text_value" TEXT,
1467 FOREIGN KEY ("issue_id", "initiative_id")
1468 REFERENCES "initiative" ("issue_id", "id")
1469 ON DELETE CASCADE ON UPDATE CASCADE,
1470 FOREIGN KEY ("initiative_id", "draft_id")
1471 REFERENCES "draft" ("initiative_id", "id")
1472 ON DELETE CASCADE ON UPDATE CASCADE,
1473 -- NOTE: no referential integrity for suggestions because those are
1474 -- actually deleted
1475 -- FOREIGN KEY ("initiative_id", "suggestion_id")
1476 -- REFERENCES "suggestion" ("initiative_id", "id")
1477 -- ON DELETE CASCADE ON UPDATE CASCADE,
1478 CONSTRAINT "constr_for_issue_state_changed" CHECK (
1479 "event" != 'issue_state_changed' OR (
1480 "posting_id" ISNULL AND
1481 "member_id" ISNULL AND
1482 "other_member_id" ISNULL AND
1483 "scope" ISNULL AND
1484 "unit_id" NOTNULL AND
1485 "area_id" NOTNULL AND
1486 "policy_id" NOTNULL AND
1487 "issue_id" NOTNULL AND
1488 "state" NOTNULL AND
1489 "initiative_id" ISNULL AND
1490 "draft_id" ISNULL AND
1491 "suggestion_id" ISNULL AND
1492 "boolean_value" ISNULL AND
1493 "numeric_value" ISNULL AND
1494 "text_value" ISNULL AND
1495 "old_text_value" ISNULL )),
1496 CONSTRAINT "constr_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1497 "event" NOT IN (
1498 'initiative_created_in_new_issue',
1499 'initiative_created_in_existing_issue',
1500 'initiative_revoked',
1501 'new_draft_created'
1502 ) OR (
1503 "posting_id" ISNULL AND
1504 "member_id" NOTNULL AND
1505 "other_member_id" ISNULL AND
1506 "scope" ISNULL AND
1507 "unit_id" NOTNULL AND
1508 "area_id" NOTNULL AND
1509 "policy_id" NOTNULL AND
1510 "issue_id" NOTNULL AND
1511 "state" NOTNULL AND
1512 "initiative_id" NOTNULL AND
1513 "draft_id" NOTNULL AND
1514 "suggestion_id" ISNULL AND
1515 "boolean_value" ISNULL AND
1516 "numeric_value" ISNULL AND
1517 "text_value" ISNULL AND
1518 "old_text_value" ISNULL )),
1519 CONSTRAINT "constr_for_suggestion_creation" CHECK (
1520 "event" != 'suggestion_created' OR (
1521 "posting_id" ISNULL AND
1522 "member_id" NOTNULL AND
1523 "other_member_id" ISNULL AND
1524 "scope" ISNULL AND
1525 "unit_id" NOTNULL AND
1526 "area_id" NOTNULL AND
1527 "policy_id" NOTNULL AND
1528 "issue_id" NOTNULL AND
1529 "state" NOTNULL AND
1530 "initiative_id" NOTNULL AND
1531 "draft_id" ISNULL AND
1532 "suggestion_id" NOTNULL AND
1533 "boolean_value" ISNULL AND
1534 "numeric_value" ISNULL AND
1535 "text_value" ISNULL AND
1536 "old_text_value" ISNULL )),
1537 CONSTRAINT "constr_for_suggestion_removal" CHECK (
1538 "event" != 'suggestion_deleted' OR (
1539 "posting_id" ISNULL AND
1540 "member_id" ISNULL AND
1541 "other_member_id" ISNULL AND
1542 "scope" ISNULL AND
1543 "unit_id" NOTNULL AND
1544 "area_id" NOTNULL AND
1545 "policy_id" NOTNULL AND
1546 "issue_id" NOTNULL AND
1547 "state" NOTNULL AND
1548 "initiative_id" NOTNULL AND
1549 "draft_id" ISNULL AND
1550 "suggestion_id" NOTNULL AND
1551 "boolean_value" ISNULL AND
1552 "numeric_value" ISNULL AND
1553 "text_value" ISNULL AND
1554 "old_text_value" ISNULL )),
1555 CONSTRAINT "constr_for_value_less_member_event" CHECK (
1556 "event" NOT IN (
1557 'member_activated',
1558 'member_deleted',
1559 'member_profile_updated',
1560 'member_image_updated'
1561 ) OR (
1562 "posting_id" ISNULL AND
1563 "member_id" NOTNULL AND
1564 "other_member_id" ISNULL AND
1565 "scope" ISNULL AND
1566 "unit_id" ISNULL AND
1567 "area_id" ISNULL AND
1568 "policy_id" ISNULL AND
1569 "issue_id" ISNULL AND
1570 "state" ISNULL AND
1571 "initiative_id" ISNULL AND
1572 "draft_id" ISNULL AND
1573 "suggestion_id" ISNULL AND
1574 "boolean_value" ISNULL AND
1575 "numeric_value" ISNULL AND
1576 "text_value" ISNULL AND
1577 "old_text_value" ISNULL )),
1578 CONSTRAINT "constr_for_member_active" CHECK (
1579 "event" != 'member_active' OR (
1580 "posting_id" ISNULL AND
1581 "member_id" NOTNULL AND
1582 "other_member_id" ISNULL AND
1583 "scope" ISNULL AND
1584 "unit_id" ISNULL AND
1585 "area_id" ISNULL AND
1586 "policy_id" ISNULL AND
1587 "issue_id" ISNULL AND
1588 "state" ISNULL AND
1589 "initiative_id" ISNULL AND
1590 "draft_id" ISNULL AND
1591 "suggestion_id" ISNULL AND
1592 "boolean_value" NOTNULL AND
1593 "numeric_value" ISNULL AND
1594 "text_value" ISNULL AND
1595 "old_text_value" ISNULL )),
1596 CONSTRAINT "constr_for_member_name_updated" CHECK (
1597 "event" != 'member_name_updated' OR (
1598 "posting_id" ISNULL AND
1599 "member_id" NOTNULL AND
1600 "other_member_id" ISNULL AND
1601 "scope" ISNULL AND
1602 "unit_id" ISNULL AND
1603 "area_id" ISNULL AND
1604 "policy_id" ISNULL AND
1605 "issue_id" ISNULL AND
1606 "state" ISNULL AND
1607 "initiative_id" ISNULL AND
1608 "draft_id" ISNULL AND
1609 "suggestion_id" ISNULL AND
1610 "boolean_value" ISNULL AND
1611 "numeric_value" ISNULL AND
1612 "text_value" NOTNULL AND
1613 "old_text_value" NOTNULL )),
1614 CONSTRAINT "constr_for_interest" CHECK (
1615 "event" != 'interest' OR (
1616 "posting_id" ISNULL AND
1617 "member_id" NOTNULL AND
1618 "other_member_id" ISNULL AND
1619 "scope" ISNULL AND
1620 "unit_id" NOTNULL AND
1621 "area_id" NOTNULL AND
1622 "policy_id" NOTNULL AND
1623 "issue_id" NOTNULL AND
1624 "state" NOTNULL AND
1625 "initiative_id" ISNULL AND
1626 "draft_id" ISNULL AND
1627 "suggestion_id" ISNULL AND
1628 "boolean_value" NOTNULL AND
1629 "numeric_value" ISNULL AND
1630 "text_value" ISNULL AND
1631 "old_text_value" ISNULL )),
1632 CONSTRAINT "constr_for_initiator" CHECK (
1633 "event" != 'initiator' OR (
1634 "posting_id" ISNULL AND
1635 "member_id" NOTNULL AND
1636 "other_member_id" ISNULL AND
1637 "scope" ISNULL AND
1638 "unit_id" NOTNULL AND
1639 "area_id" NOTNULL AND
1640 "policy_id" NOTNULL AND
1641 "issue_id" NOTNULL AND
1642 "state" NOTNULL AND
1643 "initiative_id" NOTNULL AND
1644 "draft_id" ISNULL AND
1645 "suggestion_id" ISNULL AND
1646 "boolean_value" NOTNULL AND
1647 "numeric_value" ISNULL AND
1648 "text_value" ISNULL AND
1649 "old_text_value" ISNULL )),
1650 CONSTRAINT "constr_for_support" CHECK (
1651 "event" != 'support' OR (
1652 "posting_id" ISNULL AND
1653 "member_id" NOTNULL AND
1654 "other_member_id" ISNULL AND
1655 "scope" ISNULL AND
1656 "unit_id" NOTNULL AND
1657 "area_id" NOTNULL AND
1658 "policy_id" NOTNULL AND
1659 "issue_id" NOTNULL AND
1660 "state" NOTNULL AND
1661 "initiative_id" NOTNULL AND
1662 ("draft_id" NOTNULL) = ("boolean_value" = TRUE) AND
1663 "suggestion_id" ISNULL AND
1664 "boolean_value" NOTNULL AND
1665 "numeric_value" ISNULL AND
1666 "text_value" ISNULL AND
1667 "old_text_value" ISNULL )),
1668 CONSTRAINT "constr_for_support_updated" CHECK (
1669 "event" != 'support_updated' OR (
1670 "posting_id" ISNULL AND
1671 "member_id" NOTNULL AND
1672 "other_member_id" ISNULL AND
1673 "scope" ISNULL AND
1674 "unit_id" NOTNULL AND
1675 "area_id" NOTNULL AND
1676 "policy_id" NOTNULL AND
1677 "issue_id" NOTNULL AND
1678 "state" NOTNULL AND
1679 "initiative_id" NOTNULL AND
1680 "draft_id" NOTNULL AND
1681 "suggestion_id" ISNULL AND
1682 "boolean_value" ISNULL AND
1683 "numeric_value" ISNULL AND
1684 "text_value" ISNULL AND
1685 "old_text_value" ISNULL )),
1686 CONSTRAINT "constr_for_suggestion_rated" CHECK (
1687 "event" != 'suggestion_rated' OR (
1688 "posting_id" ISNULL AND
1689 "member_id" NOTNULL AND
1690 "other_member_id" ISNULL AND
1691 "scope" ISNULL AND
1692 "unit_id" NOTNULL AND
1693 "area_id" NOTNULL AND
1694 "policy_id" NOTNULL AND
1695 "issue_id" NOTNULL AND
1696 "state" NOTNULL AND
1697 "initiative_id" NOTNULL AND
1698 "draft_id" ISNULL AND
1699 "suggestion_id" NOTNULL AND
1700 ("boolean_value" NOTNULL) = ("numeric_value" != 0) AND
1701 "numeric_value" NOTNULL AND
1702 "numeric_value" IN (-2, -1, 0, 1, 2) AND
1703 "text_value" ISNULL AND
1704 "old_text_value" ISNULL )),
1705 CONSTRAINT "constr_for_delegation" CHECK (
1706 "event" != 'delegation' OR (
1707 "posting_id" ISNULL AND
1708 "member_id" NOTNULL AND
1709 (("other_member_id" ISNULL) OR ("boolean_value" = TRUE)) AND
1710 "scope" NOTNULL AND
1711 "unit_id" NOTNULL AND
1712 ("area_id" NOTNULL) = ("scope" != 'unit'::"delegation_scope") AND
1713 "policy_id" ISNULL AND
1714 ("issue_id" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1715 ("state" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1716 "initiative_id" ISNULL AND
1717 "draft_id" ISNULL AND
1718 "suggestion_id" ISNULL AND
1719 "boolean_value" NOTNULL AND
1720 "numeric_value" ISNULL AND
1721 "text_value" ISNULL AND
1722 "old_text_value" ISNULL )),
1723 CONSTRAINT "constr_for_contact" CHECK (
1724 "event" != 'contact' OR (
1725 "posting_id" ISNULL AND
1726 "member_id" NOTNULL AND
1727 "other_member_id" NOTNULL AND
1728 "scope" ISNULL AND
1729 "unit_id" ISNULL AND
1730 "area_id" ISNULL AND
1731 "policy_id" ISNULL AND
1732 "issue_id" ISNULL AND
1733 "state" ISNULL AND
1734 "initiative_id" ISNULL AND
1735 "draft_id" ISNULL AND
1736 "suggestion_id" ISNULL AND
1737 "boolean_value" NOTNULL AND
1738 "numeric_value" ISNULL AND
1739 "text_value" ISNULL AND
1740 "old_text_value" ISNULL )),
1741 CONSTRAINT "constr_for_posting_created" CHECK (
1742 "event" != 'posting_created' OR (
1743 "posting_id" NOTNULL AND
1744 "member_id" NOTNULL AND
1745 "other_member_id" ISNULL AND
1746 "scope" ISNULL AND
1747 "state" ISNULL AND
1748 ("area_id" ISNULL OR "unit_id" NOTNULL) AND
1749 ("policy_id" NOTNULL) = ("issue_id" NOTNULL) AND
1750 ("issue_id" ISNULL OR "area_id" NOTNULL) AND
1751 ("state" NOTNULL) = ("issue_id" NOTNULL) AND
1752 ("initiative_id" ISNULL OR "issue_id" NOTNULL) AND
1753 "draft_id" ISNULL AND
1754 ("suggestion_id" ISNULL OR "initiative_id" NOTNULL) AND
1755 "boolean_value" ISNULL AND
1756 "numeric_value" ISNULL AND
1757 "text_value" ISNULL AND
1758 "old_text_value" ISNULL )) );
1759 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1760 CREATE INDEX "event_tl_global_idx" ON "event" USING gist ((pstamp("member_id", "id")));
1761 CREATE INDEX "event_tl_unit_idx" ON "event" USING gist ("unit_id", (pstamp("member_id", "id"))) WHERE "unit_id" NOTNULL;
1762 CREATE INDEX "event_tl_area_idx" ON "event" USING gist ("area_id", (pstamp("member_id", "id"))) WHERE "area_id" NOTNULL;
1763 CREATE INDEX "event_tl_policy_idx" ON "event" USING gist ("policy_id", (pstamp("member_id", "id"))) WHERE "policy_id" NOTNULL;
1764 CREATE INDEX "event_tl_issue_idx" ON "event" USING gist ("issue_id", (pstamp("member_id", "id"))) WHERE "issue_id" NOTNULL;
1765 CREATE INDEX "event_tl_initiative_idx" ON "event" USING gist ("initiative_id", (pstamp("member_id", "id"))) WHERE "initiative_id" NOTNULL;
1766 CREATE INDEX "event_tl_suggestion_idx" ON "event" USING gist ("suggestion_id", (pstamp("member_id", "id"))) WHERE "suggestion_id" NOTNULL;
1769 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1771 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1772 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1773 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1774 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1777 CREATE TABLE "event_processed" (
1778 "event_id" INT8 NOT NULL );
1779 CREATE UNIQUE INDEX "event_processed_singleton_idx" ON "event_processed" ((1));
1781 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)';
1782 COMMENT ON INDEX "event_processed_singleton_idx" IS 'This index ensures that "event_processed" only contains one row maximum.';
1785 CREATE TABLE "notification_initiative_sent" (
1786 PRIMARY KEY ("member_id", "initiative_id"),
1787 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1788 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1789 "last_draft_id" INT8 NOT NULL,
1790 "last_suggestion_id" INT8 );
1791 CREATE INDEX "notification_initiative_sent_initiative_idx" ON "notification_initiative_sent" ("initiative_id");
1793 COMMENT ON TABLE "notification_initiative_sent" IS 'Information which initiatives have been promoted to a member in a scheduled notification mail';
1795 COMMENT ON COLUMN "notification_initiative_sent"."last_draft_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1796 COMMENT ON COLUMN "notification_initiative_sent"."last_suggestion_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1799 CREATE TABLE "newsletter" (
1800 "id" SERIAL4 PRIMARY KEY,
1801 "published" TIMESTAMPTZ NOT NULL,
1802 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1803 "include_all_members" BOOLEAN NOT NULL,
1804 "sent" TIMESTAMPTZ,
1805 "subject" TEXT NOT NULL,
1806 "content" TEXT NOT NULL );
1807 CREATE INDEX "newsletter_unit_id_idx" ON "newsletter" ("unit_id", "published");
1808 CREATE INDEX "newsletter_all_units_published_idx" ON "newsletter" ("published") WHERE "unit_id" ISNULL;
1809 CREATE INDEX "newsletter_published_idx" ON "newsletter" ("published");
1811 COMMENT ON TABLE "newsletter" IS 'Contains newsletters created by administrators to be sent out and for further reference';
1813 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter is to be sent out (and made available in the frontend)';
1814 COMMENT ON COLUMN "newsletter"."unit_id" IS 'If set, only members with voting right in the given unit are considered to be recipients';
1815 COMMENT ON COLUMN "newsletter"."include_all_members" IS 'TRUE = include all members regardless of their ''disable_notifications'' setting';
1816 COMMENT ON COLUMN "newsletter"."sent" IS 'Timestamp when the newsletter has been mailed out';
1817 COMMENT ON COLUMN "newsletter"."subject" IS 'Subject line (e.g. to be used for the email)';
1818 COMMENT ON COLUMN "newsletter"."content" IS 'Plain text content of the newsletter';
1822 ----------------------
1823 -- Full text search --
1824 ----------------------
1827 CREATE FUNCTION "highlight"
1828 ( "body_p" TEXT,
1829 "query_text_p" TEXT )
1830 RETURNS TEXT
1831 LANGUAGE 'plpgsql' IMMUTABLE AS $$
1832 BEGIN
1833 RETURN ts_headline(
1834 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
1835 "plainto_tsquery"("query_text_p"),
1836 'StartSel=* StopSel=* HighlightAll=TRUE' );
1837 END;
1838 $$;
1840 COMMENT ON FUNCTION "highlight"
1841 ( "body_p" TEXT,
1842 "query_text_p" TEXT )
1843 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.';
1846 CREATE FUNCTION "to_tsvector"("member") RETURNS TSVECTOR
1847 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1848 $1."name",
1849 $1."identification"
1850 )) $$;
1851 CREATE INDEX "member_to_tsvector_idx" ON "member" USING gin
1852 (("to_tsvector"("member".*)));
1854 CREATE FUNCTION "to_tsvector"("member_profile") RETURNS TSVECTOR
1855 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1856 $1."statement",
1857 $1."profile_text_data"
1858 )) $$;
1859 CREATE INDEX "member_profile_to_tsvector_idx" ON "member_profile" USING gin
1860 (("to_tsvector"("member_profile".*)));
1862 CREATE FUNCTION "to_tsvector"("unit") RETURNS TSVECTOR
1863 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1864 $1."name",
1865 $1."description"
1866 )) $$;
1867 CREATE INDEX "unit_to_tsvector_idx" ON "unit" USING gin
1868 (("to_tsvector"("unit".*)));
1870 CREATE FUNCTION "to_tsvector"("area") RETURNS TSVECTOR
1871 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1872 $1."name",
1873 $1."description"
1874 )) $$;
1875 CREATE INDEX "area_to_tsvector_idx" ON "area" USING gin
1876 (("to_tsvector"("area".*)));
1878 CREATE FUNCTION "to_tsvector"("initiative") RETURNS TSVECTOR
1879 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1880 $1."name",
1881 $1."content"
1882 )) $$;
1883 CREATE INDEX "initiative_to_tsvector_idx" ON "initiative" USING gin
1884 (("to_tsvector"("initiative".*)));
1886 CREATE FUNCTION "to_tsvector"("draft") RETURNS TSVECTOR
1887 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1888 $1."content"
1889 )) $$;
1890 CREATE INDEX "draft_to_tsvector_idx" ON "draft" USING gin
1891 (("to_tsvector"("draft".*)));
1893 CREATE FUNCTION "to_tsvector"("suggestion") RETURNS TSVECTOR
1894 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1895 $1."name",
1896 $1."content"
1897 )) $$;
1898 CREATE INDEX "suggestion_to_tsvector_idx" ON "suggestion" USING gin
1899 (("to_tsvector"("suggestion".*)));
1901 CREATE FUNCTION "to_tsvector"("direct_voter") RETURNS TSVECTOR
1902 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1903 $1."comment"
1904 )) $$;
1905 CREATE INDEX "direct_voter_to_tsvector_idx" ON "direct_voter" USING gin
1906 (("to_tsvector"("direct_voter".*)));
1909 CREATE FUNCTION "update_posting_lexeme_trigger"()
1910 RETURNS TRIGGER
1911 LANGUAGE 'plpgsql' VOLATILE AS $$
1912 DECLARE
1913 "lexeme_v" TEXT;
1914 BEGIN
1915 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
1916 DELETE FROM "posting_lexeme" WHERE "posting_id" = OLD."id";
1917 END IF;
1918 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
1919 FOR "lexeme_v" IN
1920 SELECT regexp_matches[1]
1921 FROM regexp_matches(NEW."message", '#[^\s.,;:]+')
1922 LOOP
1923 INSERT INTO "posting_lexeme" ("posting_id", "author_id", "lexeme")
1924 VALUES (
1925 NEW."id",
1926 NEW."author_id",
1927 "lexeme_v" )
1928 ON CONFLICT ("posting_id", "lexeme") DO NOTHING;
1929 END LOOP;
1930 END IF;
1931 RETURN NULL;
1932 END;
1933 $$;
1935 CREATE TRIGGER "update_posting_lexeme"
1936 AFTER INSERT OR UPDATE OR DELETE ON "posting"
1937 FOR EACH ROW EXECUTE PROCEDURE "update_posting_lexeme_trigger"();
1939 COMMENT ON FUNCTION "update_posting_lexeme_trigger"() IS 'Implementation of trigger "update_posting_lexeme" on table "posting"';
1940 COMMENT ON TRIGGER "update_posting_lexeme" ON "posting" IS 'Keeps table "posting_lexeme" up to date';
1944 ----------------------------------------------
1945 -- Writing of history entries and event log --
1946 ----------------------------------------------
1949 CREATE FUNCTION "write_member_history_trigger"()
1950 RETURNS TRIGGER
1951 LANGUAGE 'plpgsql' VOLATILE AS $$
1952 BEGIN
1953 IF
1954 ( NEW."active" != OLD."active" OR
1955 NEW."name" != OLD."name" ) AND
1956 OLD."activated" NOTNULL
1957 THEN
1958 INSERT INTO "member_history"
1959 ("member_id", "active", "name")
1960 VALUES (NEW."id", OLD."active", OLD."name");
1961 END IF;
1962 RETURN NULL;
1963 END;
1964 $$;
1966 CREATE TRIGGER "write_member_history"
1967 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1968 "write_member_history_trigger"();
1970 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1971 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1974 CREATE FUNCTION "write_event_unit_trigger"()
1975 RETURNS TRIGGER
1976 LANGUAGE 'plpgsql' VOLATILE AS $$
1977 DECLARE
1978 "event_v" "event_type";
1979 BEGIN
1980 IF TG_OP = 'UPDATE' THEN
1981 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1982 RETURN NULL;
1983 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1984 -- "event_v" := 'unit_created';
1985 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1986 -- "event_v" := 'unit_deleted';
1987 ELSIF OLD != NEW THEN
1988 "event_v" := 'unit_updated';
1989 ELSE
1990 RETURN NULL;
1991 END IF;
1992 ELSE
1993 "event_v" := 'unit_created';
1994 END IF;
1995 INSERT INTO "event" ("event", "unit_id") VALUES ("event_v", NEW."id");
1996 RETURN NULL;
1997 END;
1998 $$;
2000 CREATE TRIGGER "write_event_unit" AFTER INSERT OR UPDATE ON "unit"
2001 FOR EACH ROW EXECUTE PROCEDURE "write_event_unit_trigger"();
2003 COMMENT ON FUNCTION "write_event_unit_trigger"() IS 'Implementation of trigger "write_event_unit" on table "unit"';
2004 COMMENT ON TRIGGER "write_event_unit" ON "unit" IS 'Create entry in "event" table on new or changed/disabled units';
2007 CREATE FUNCTION "write_event_area_trigger"()
2008 RETURNS TRIGGER
2009 LANGUAGE 'plpgsql' VOLATILE AS $$
2010 DECLARE
2011 "event_v" "event_type";
2012 BEGIN
2013 IF TG_OP = 'UPDATE' THEN
2014 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
2015 RETURN NULL;
2016 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
2017 -- "event_v" := 'area_created';
2018 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
2019 -- "event_v" := 'area_deleted';
2020 ELSIF OLD != NEW THEN
2021 "event_v" := 'area_updated';
2022 ELSE
2023 RETURN NULL;
2024 END IF;
2025 ELSE
2026 "event_v" := 'area_created';
2027 END IF;
2028 INSERT INTO "event" ("event", "area_id") VALUES ("event_v", NEW."id");
2029 RETURN NULL;
2030 END;
2031 $$;
2033 CREATE TRIGGER "write_event_area" AFTER INSERT OR UPDATE ON "area"
2034 FOR EACH ROW EXECUTE PROCEDURE "write_event_area_trigger"();
2036 COMMENT ON FUNCTION "write_event_area_trigger"() IS 'Implementation of trigger "write_event_area" on table "area"';
2037 COMMENT ON TRIGGER "write_event_area" ON "area" IS 'Create entry in "event" table on new or changed/disabled areas';
2040 CREATE FUNCTION "write_event_policy_trigger"()
2041 RETURNS TRIGGER
2042 LANGUAGE 'plpgsql' VOLATILE AS $$
2043 DECLARE
2044 "event_v" "event_type";
2045 BEGIN
2046 IF TG_OP = 'UPDATE' THEN
2047 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
2048 RETURN NULL;
2049 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
2050 -- "event_v" := 'policy_created';
2051 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
2052 -- "event_v" := 'policy_deleted';
2053 ELSIF OLD != NEW THEN
2054 "event_v" := 'policy_updated';
2055 ELSE
2056 RETURN NULL;
2057 END IF;
2058 ELSE
2059 "event_v" := 'policy_created';
2060 END IF;
2061 INSERT INTO "event" ("event", "policy_id") VALUES ("event_v", NEW."id");
2062 RETURN NULL;
2063 END;
2064 $$;
2066 CREATE TRIGGER "write_event_policy" AFTER INSERT OR UPDATE ON "policy"
2067 FOR EACH ROW EXECUTE PROCEDURE "write_event_policy_trigger"();
2069 COMMENT ON FUNCTION "write_event_policy_trigger"() IS 'Implementation of trigger "write_event_policy" on table "policy"';
2070 COMMENT ON TRIGGER "write_event_policy" ON "policy" IS 'Create entry in "event" table on new or changed/disabled policies';
2073 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
2074 RETURNS TRIGGER
2075 LANGUAGE 'plpgsql' VOLATILE AS $$
2076 DECLARE
2077 "area_row" "area"%ROWTYPE;
2078 BEGIN
2079 IF NEW."state" != OLD."state" THEN
2080 SELECT * INTO "area_row" FROM "area" WHERE "id" = NEW."area_id"
2081 FOR SHARE;
2082 INSERT INTO "event" (
2083 "event",
2084 "unit_id", "area_id", "policy_id", "issue_id", "state"
2085 ) VALUES (
2086 'issue_state_changed',
2087 "area_row"."unit_id", NEW."area_id", NEW."policy_id",
2088 NEW."id", NEW."state"
2089 );
2090 END IF;
2091 RETURN NULL;
2092 END;
2093 $$;
2095 CREATE TRIGGER "write_event_issue_state_changed"
2096 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
2097 "write_event_issue_state_changed_trigger"();
2099 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
2100 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
2103 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
2104 RETURNS TRIGGER
2105 LANGUAGE 'plpgsql' VOLATILE AS $$
2106 DECLARE
2107 "initiative_row" "initiative"%ROWTYPE;
2108 "issue_row" "issue"%ROWTYPE;
2109 "area_row" "area"%ROWTYPE;
2110 "event_v" "event_type";
2111 BEGIN
2112 SELECT * INTO "initiative_row" FROM "initiative"
2113 WHERE "id" = NEW."initiative_id" FOR SHARE;
2114 SELECT * INTO "issue_row" FROM "issue"
2115 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2116 SELECT * INTO "area_row" FROM "area"
2117 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2118 IF EXISTS (
2119 SELECT NULL FROM "draft"
2120 WHERE "initiative_id" = NEW."initiative_id" AND "id" != NEW."id"
2121 FOR SHARE
2122 ) THEN
2123 "event_v" := 'new_draft_created';
2124 ELSE
2125 IF EXISTS (
2126 SELECT NULL FROM "initiative"
2127 WHERE "issue_id" = "initiative_row"."issue_id"
2128 AND "id" != "initiative_row"."id"
2129 FOR SHARE
2130 ) THEN
2131 "event_v" := 'initiative_created_in_existing_issue';
2132 ELSE
2133 "event_v" := 'initiative_created_in_new_issue';
2134 END IF;
2135 END IF;
2136 INSERT INTO "event" (
2137 "event", "member_id",
2138 "unit_id", "area_id", "policy_id", "issue_id", "state",
2139 "initiative_id", "draft_id"
2140 ) VALUES (
2141 "event_v", NEW."author_id",
2142 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
2143 "initiative_row"."issue_id", "issue_row"."state",
2144 NEW."initiative_id", NEW."id"
2145 );
2146 RETURN NULL;
2147 END;
2148 $$;
2150 CREATE TRIGGER "write_event_initiative_or_draft_created"
2151 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
2152 "write_event_initiative_or_draft_created_trigger"();
2154 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
2155 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
2158 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
2159 RETURNS TRIGGER
2160 LANGUAGE 'plpgsql' VOLATILE AS $$
2161 DECLARE
2162 "issue_row" "issue"%ROWTYPE;
2163 "area_row" "area"%ROWTYPE;
2164 "draft_id_v" "draft"."id"%TYPE;
2165 BEGIN
2166 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
2167 -- NOTE: lock for primary key update to avoid new drafts
2168 PERFORM NULL FROM "initiative" WHERE "id" = NEW."id" FOR UPDATE;
2169 SELECT * INTO "issue_row" FROM "issue"
2170 WHERE "id" = NEW."issue_id" FOR SHARE;
2171 SELECT * INTO "area_row" FROM "area"
2172 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2173 -- NOTE: FOR SHARE cannot be used with DISTINCT in view "current_draft"
2174 PERFORM NULL FROM "draft" WHERE "initiative_id" = NEW."id" FOR SHARE;
2175 SELECT "id" INTO "draft_id_v" FROM "current_draft"
2176 WHERE "initiative_id" = NEW."id";
2177 INSERT INTO "event" (
2178 "event", "member_id",
2179 "unit_id", "area_id", "policy_id", "issue_id", "state",
2180 "initiative_id", "draft_id"
2181 ) VALUES (
2182 'initiative_revoked', NEW."revoked_by_member_id",
2183 "area_row"."unit_id", "issue_row"."area_id",
2184 "issue_row"."policy_id",
2185 NEW."issue_id", "issue_row"."state",
2186 NEW."id", "draft_id_v"
2187 );
2188 END IF;
2189 RETURN NULL;
2190 END;
2191 $$;
2193 CREATE TRIGGER "write_event_initiative_revoked"
2194 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
2195 "write_event_initiative_revoked_trigger"();
2197 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
2198 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
2201 CREATE FUNCTION "write_event_suggestion_created_trigger"()
2202 RETURNS TRIGGER
2203 LANGUAGE 'plpgsql' VOLATILE AS $$
2204 DECLARE
2205 "initiative_row" "initiative"%ROWTYPE;
2206 "issue_row" "issue"%ROWTYPE;
2207 "area_row" "area"%ROWTYPE;
2208 BEGIN
2209 SELECT * INTO "initiative_row" FROM "initiative"
2210 WHERE "id" = NEW."initiative_id" FOR SHARE;
2211 SELECT * INTO "issue_row" FROM "issue"
2212 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2213 SELECT * INTO "area_row" FROM "area"
2214 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2215 INSERT INTO "event" (
2216 "event", "member_id",
2217 "unit_id", "area_id", "policy_id", "issue_id", "state",
2218 "initiative_id", "suggestion_id"
2219 ) VALUES (
2220 'suggestion_created', NEW."author_id",
2221 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
2222 "initiative_row"."issue_id", "issue_row"."state",
2223 NEW."initiative_id", NEW."id"
2224 );
2225 RETURN NULL;
2226 END;
2227 $$;
2229 CREATE TRIGGER "write_event_suggestion_created"
2230 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2231 "write_event_suggestion_created_trigger"();
2233 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
2234 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2237 CREATE FUNCTION "write_event_suggestion_removed_trigger"()
2238 RETURNS TRIGGER
2239 LANGUAGE 'plpgsql' VOLATILE AS $$
2240 DECLARE
2241 "initiative_row" "initiative"%ROWTYPE;
2242 "issue_row" "issue"%ROWTYPE;
2243 "area_row" "area"%ROWTYPE;
2244 BEGIN
2245 SELECT * INTO "initiative_row" FROM "initiative"
2246 WHERE "id" = OLD."initiative_id" FOR SHARE;
2247 IF "initiative_row"."id" NOTNULL THEN
2248 SELECT * INTO "issue_row" FROM "issue"
2249 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2250 SELECT * INTO "area_row" FROM "area"
2251 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2252 INSERT INTO "event" (
2253 "event",
2254 "unit_id", "area_id", "policy_id", "issue_id", "state",
2255 "initiative_id", "suggestion_id"
2256 ) VALUES (
2257 'suggestion_deleted',
2258 "area_row"."unit_id", "issue_row"."area_id",
2259 "issue_row"."policy_id",
2260 "initiative_row"."issue_id", "issue_row"."state",
2261 OLD."initiative_id", OLD."id"
2262 );
2263 END IF;
2264 RETURN NULL;
2265 END;
2266 $$;
2268 CREATE TRIGGER "write_event_suggestion_removed"
2269 AFTER DELETE ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2270 "write_event_suggestion_removed_trigger"();
2272 COMMENT ON FUNCTION "write_event_suggestion_removed_trigger"() IS 'Implementation of trigger "write_event_suggestion_removed" on table "issue"';
2273 COMMENT ON TRIGGER "write_event_suggestion_removed" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2276 CREATE FUNCTION "write_event_member_trigger"()
2277 RETURNS TRIGGER
2278 LANGUAGE 'plpgsql' VOLATILE AS $$
2279 BEGIN
2280 IF TG_OP = 'INSERT' THEN
2281 IF NEW."activated" NOTNULL AND NEW."deleted" ISNULL THEN
2282 INSERT INTO "event" ("event", "member_id")
2283 VALUES ('member_activated', NEW."id");
2284 END IF;
2285 IF NEW."active" THEN
2286 INSERT INTO "event" ("event", "member_id", "boolean_value")
2287 VALUES ('member_active', NEW."id", TRUE);
2288 END IF;
2289 ELSIF TG_OP = 'UPDATE' THEN
2290 IF OLD."id" != NEW."id" THEN
2291 RAISE EXCEPTION 'Cannot change member ID';
2292 END IF;
2293 IF
2294 (OLD."activated" ISNULL OR OLD."deleted" NOTNULL) AND
2295 NEW."activated" NOTNULL AND NEW."deleted" ISNULL
2296 THEN
2297 INSERT INTO "event" ("event", "member_id")
2298 VALUES ('member_activated', NEW."id");
2299 END IF;
2300 IF OLD."active" != NEW."active" THEN
2301 INSERT INTO "event" ("event", "member_id", "boolean_value") VALUES (
2302 'member_active', NEW."id", NEW."active"
2303 );
2304 END IF;
2305 IF OLD."name" != NEW."name" THEN
2306 INSERT INTO "event" (
2307 "event", "member_id", "text_value", "old_text_value"
2308 ) VALUES (
2309 'member_name_updated', NEW."id", NEW."name", OLD."name"
2310 );
2311 END IF;
2312 IF
2313 OLD."activated" NOTNULL AND OLD."deleted" ISNULL AND
2314 (NEW."activated" ISNULL OR NEW."deleted" NOTNULL)
2315 THEN
2316 INSERT INTO "event" ("event", "member_id")
2317 VALUES ('member_deleted', NEW."id");
2318 END IF;
2319 END IF;
2320 RETURN NULL;
2321 END;
2322 $$;
2324 CREATE TRIGGER "write_event_member"
2325 AFTER INSERT OR UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
2326 "write_event_member_trigger"();
2328 COMMENT ON FUNCTION "write_event_member_trigger"() IS 'Implementation of trigger "write_event_member" on table "member"';
2329 COMMENT ON TRIGGER "write_event_member" ON "member" IS 'Create entries in "event" table on insertion to member table';
2332 CREATE FUNCTION "write_event_member_profile_updated_trigger"()
2333 RETURNS TRIGGER
2334 LANGUAGE 'plpgsql' VOLATILE AS $$
2335 BEGIN
2336 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2337 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2338 INSERT INTO "event" ("event", "member_id") VALUES (
2339 'member_profile_updated', OLD."member_id"
2340 );
2341 END IF;
2342 END IF;
2343 IF TG_OP = 'UPDATE' THEN
2344 IF OLD."member_id" = NEW."member_id" THEN
2345 RETURN NULL;
2346 END IF;
2347 END IF;
2348 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2349 INSERT INTO "event" ("event", "member_id") VALUES (
2350 'member_profile_updated', NEW."member_id"
2351 );
2352 END IF;
2353 RETURN NULL;
2354 END;
2355 $$;
2357 CREATE TRIGGER "write_event_member_profile_updated"
2358 AFTER INSERT OR UPDATE OR DELETE ON "member_profile"
2359 FOR EACH ROW EXECUTE PROCEDURE
2360 "write_event_member_profile_updated_trigger"();
2362 COMMENT ON FUNCTION "write_event_member_profile_updated_trigger"() IS 'Implementation of trigger "write_event_member_profile_updated" on table "member_profile"';
2363 COMMENT ON TRIGGER "write_event_member_profile_updated" ON "member_profile" IS 'Creates entries in "event" table on member profile update';
2366 CREATE FUNCTION "write_event_member_image_updated_trigger"()
2367 RETURNS TRIGGER
2368 LANGUAGE 'plpgsql' VOLATILE AS $$
2369 BEGIN
2370 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2371 IF NOT OLD."scaled" THEN
2372 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2373 INSERT INTO "event" ("event", "member_id") VALUES (
2374 'member_image_updated', OLD."member_id"
2375 );
2376 END IF;
2377 END IF;
2378 END IF;
2379 IF TG_OP = 'UPDATE' THEN
2380 IF
2381 OLD."member_id" = NEW."member_id" AND
2382 OLD."scaled" = NEW."scaled"
2383 THEN
2384 RETURN NULL;
2385 END IF;
2386 END IF;
2387 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2388 IF NOT NEW."scaled" THEN
2389 INSERT INTO "event" ("event", "member_id") VALUES (
2390 'member_image_updated', NEW."member_id"
2391 );
2392 END IF;
2393 END IF;
2394 RETURN NULL;
2395 END;
2396 $$;
2398 CREATE TRIGGER "write_event_member_image_updated"
2399 AFTER INSERT OR UPDATE OR DELETE ON "member_image"
2400 FOR EACH ROW EXECUTE PROCEDURE
2401 "write_event_member_image_updated_trigger"();
2403 COMMENT ON FUNCTION "write_event_member_image_updated_trigger"() IS 'Implementation of trigger "write_event_member_image_updated" on table "member_image"';
2404 COMMENT ON TRIGGER "write_event_member_image_updated" ON "member_image" IS 'Creates entries in "event" table on member image update';
2407 CREATE FUNCTION "write_event_interest_trigger"()
2408 RETURNS TRIGGER
2409 LANGUAGE 'plpgsql' VOLATILE AS $$
2410 DECLARE
2411 "issue_row" "issue"%ROWTYPE;
2412 "area_row" "area"%ROWTYPE;
2413 BEGIN
2414 IF TG_OP = 'UPDATE' THEN
2415 IF OLD = NEW THEN
2416 RETURN NULL;
2417 END IF;
2418 END IF;
2419 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2420 SELECT * INTO "issue_row" FROM "issue"
2421 WHERE "id" = OLD."issue_id" FOR SHARE;
2422 SELECT * INTO "area_row" FROM "area"
2423 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2424 IF "issue_row"."id" NOTNULL THEN
2425 INSERT INTO "event" (
2426 "event", "member_id",
2427 "unit_id", "area_id", "policy_id", "issue_id", "state",
2428 "boolean_value"
2429 ) VALUES (
2430 'interest', OLD."member_id",
2431 "area_row"."unit_id", "issue_row"."area_id",
2432 "issue_row"."policy_id",
2433 OLD."issue_id", "issue_row"."state",
2434 FALSE
2435 );
2436 END IF;
2437 END IF;
2438 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2439 SELECT * INTO "issue_row" FROM "issue"
2440 WHERE "id" = NEW."issue_id" FOR SHARE;
2441 SELECT * INTO "area_row" FROM "area"
2442 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2443 INSERT INTO "event" (
2444 "event", "member_id",
2445 "unit_id", "area_id", "policy_id", "issue_id", "state",
2446 "boolean_value"
2447 ) VALUES (
2448 'interest', NEW."member_id",
2449 "area_row"."unit_id", "issue_row"."area_id",
2450 "issue_row"."policy_id",
2451 NEW."issue_id", "issue_row"."state",
2452 TRUE
2453 );
2454 END IF;
2455 RETURN NULL;
2456 END;
2457 $$;
2459 CREATE TRIGGER "write_event_interest"
2460 AFTER INSERT OR UPDATE OR DELETE ON "interest" FOR EACH ROW EXECUTE PROCEDURE
2461 "write_event_interest_trigger"();
2463 COMMENT ON FUNCTION "write_event_interest_trigger"() IS 'Implementation of trigger "write_event_interest_inserted" on table "interest"';
2464 COMMENT ON TRIGGER "write_event_interest" ON "interest" IS 'Create entry in "event" table on adding or removing interest';
2467 CREATE FUNCTION "write_event_initiator_trigger"()
2468 RETURNS TRIGGER
2469 LANGUAGE 'plpgsql' VOLATILE AS $$
2470 DECLARE
2471 "initiative_row" "initiative"%ROWTYPE;
2472 "issue_row" "issue"%ROWTYPE;
2473 "area_row" "area"%ROWTYPE;
2474 "accepted_v" BOOLEAN = FALSE;
2475 "rejected_v" BOOLEAN = FALSE;
2476 BEGIN
2477 IF TG_OP = 'UPDATE' THEN
2478 IF
2479 OLD."initiative_id" = NEW."initiative_id" AND
2480 OLD."member_id" = NEW."member_id"
2481 THEN
2482 IF
2483 coalesce(OLD."accepted", FALSE) = coalesce(NEW."accepted", FALSE)
2484 THEN
2485 RETURN NULL;
2486 END IF;
2487 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2488 "accepted_v" := TRUE;
2489 ELSE
2490 "rejected_v" := TRUE;
2491 END IF;
2492 END IF;
2493 END IF;
2494 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "accepted_v" THEN
2495 IF coalesce(OLD."accepted", FALSE) = TRUE THEN
2496 SELECT * INTO "initiative_row" FROM "initiative"
2497 WHERE "id" = OLD."initiative_id" FOR SHARE;
2498 IF "initiative_row"."id" NOTNULL THEN
2499 SELECT * INTO "issue_row" FROM "issue"
2500 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2501 SELECT * INTO "area_row" FROM "area"
2502 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2503 INSERT INTO "event" (
2504 "event", "member_id",
2505 "unit_id", "area_id", "policy_id", "issue_id", "state",
2506 "initiative_id", "boolean_value"
2507 ) VALUES (
2508 'initiator', OLD."member_id",
2509 "area_row"."unit_id", "issue_row"."area_id",
2510 "issue_row"."policy_id",
2511 "issue_row"."id", "issue_row"."state",
2512 OLD."initiative_id", FALSE
2513 );
2514 END IF;
2515 END IF;
2516 END IF;
2517 IF TG_OP = 'UPDATE' AND NOT "rejected_v" THEN
2518 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2519 SELECT * INTO "initiative_row" FROM "initiative"
2520 WHERE "id" = NEW."initiative_id" FOR SHARE;
2521 SELECT * INTO "issue_row" FROM "issue"
2522 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2523 SELECT * INTO "area_row" FROM "area"
2524 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2525 INSERT INTO "event" (
2526 "event", "member_id",
2527 "unit_id", "area_id", "policy_id", "issue_id", "state",
2528 "initiative_id", "boolean_value"
2529 ) VALUES (
2530 'initiator', NEW."member_id",
2531 "area_row"."unit_id", "issue_row"."area_id",
2532 "issue_row"."policy_id",
2533 "issue_row"."id", "issue_row"."state",
2534 NEW."initiative_id", TRUE
2535 );
2536 END IF;
2537 END IF;
2538 RETURN NULL;
2539 END;
2540 $$;
2542 CREATE TRIGGER "write_event_initiator"
2543 AFTER UPDATE OR DELETE ON "initiator" FOR EACH ROW EXECUTE PROCEDURE
2544 "write_event_initiator_trigger"();
2546 COMMENT ON FUNCTION "write_event_initiator_trigger"() IS 'Implementation of trigger "write_event_initiator" on table "initiator"';
2547 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)';
2550 CREATE FUNCTION "write_event_support_trigger"()
2551 RETURNS TRIGGER
2552 LANGUAGE 'plpgsql' VOLATILE AS $$
2553 DECLARE
2554 "issue_row" "issue"%ROWTYPE;
2555 "area_row" "area"%ROWTYPE;
2556 BEGIN
2557 IF TG_OP = 'UPDATE' THEN
2558 IF
2559 OLD."initiative_id" = NEW."initiative_id" AND
2560 OLD."member_id" = NEW."member_id"
2561 THEN
2562 IF OLD."draft_id" != NEW."draft_id" THEN
2563 SELECT * INTO "issue_row" FROM "issue"
2564 WHERE "id" = NEW."issue_id" FOR SHARE;
2565 SELECT * INTO "area_row" FROM "area"
2566 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2567 INSERT INTO "event" (
2568 "event", "member_id",
2569 "unit_id", "area_id", "policy_id", "issue_id", "state",
2570 "initiative_id", "draft_id"
2571 ) VALUES (
2572 'support_updated', NEW."member_id",
2573 "area_row"."unit_id", "issue_row"."area_id",
2574 "issue_row"."policy_id",
2575 "issue_row"."id", "issue_row"."state",
2576 NEW."initiative_id", NEW."draft_id"
2577 );
2578 END IF;
2579 RETURN NULL;
2580 END IF;
2581 END IF;
2582 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2583 IF EXISTS (
2584 SELECT NULL FROM "initiative" WHERE "id" = OLD."initiative_id"
2585 FOR SHARE
2586 ) THEN
2587 SELECT * INTO "issue_row" FROM "issue"
2588 WHERE "id" = OLD."issue_id" FOR SHARE;
2589 SELECT * INTO "area_row" FROM "area"
2590 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2591 INSERT INTO "event" (
2592 "event", "member_id",
2593 "unit_id", "area_id", "policy_id", "issue_id", "state",
2594 "initiative_id", "boolean_value"
2595 ) VALUES (
2596 'support', OLD."member_id",
2597 "area_row"."unit_id", "issue_row"."area_id",
2598 "issue_row"."policy_id",
2599 "issue_row"."id", "issue_row"."state",
2600 OLD."initiative_id", FALSE
2601 );
2602 END IF;
2603 END IF;
2604 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2605 SELECT * INTO "issue_row" FROM "issue"
2606 WHERE "id" = NEW."issue_id" FOR SHARE;
2607 SELECT * INTO "area_row" FROM "area"
2608 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2609 INSERT INTO "event" (
2610 "event", "member_id",
2611 "unit_id", "area_id", "policy_id", "issue_id", "state",
2612 "initiative_id", "draft_id", "boolean_value"
2613 ) VALUES (
2614 'support', NEW."member_id",
2615 "area_row"."unit_id", "issue_row"."area_id",
2616 "issue_row"."policy_id",
2617 "issue_row"."id", "issue_row"."state",
2618 NEW."initiative_id", NEW."draft_id", TRUE
2619 );
2620 END IF;
2621 RETURN NULL;
2622 END;
2623 $$;
2625 CREATE TRIGGER "write_event_support"
2626 AFTER INSERT OR UPDATE OR DELETE ON "supporter" FOR EACH ROW EXECUTE PROCEDURE
2627 "write_event_support_trigger"();
2629 COMMENT ON FUNCTION "write_event_support_trigger"() IS 'Implementation of trigger "write_event_support" on table "supporter"';
2630 COMMENT ON TRIGGER "write_event_support" ON "supporter" IS 'Create entry in "event" table when adding, updating, or removing support';
2633 CREATE FUNCTION "write_event_suggestion_rated_trigger"()
2634 RETURNS TRIGGER
2635 LANGUAGE 'plpgsql' VOLATILE AS $$
2636 DECLARE
2637 "same_pkey_v" BOOLEAN = FALSE;
2638 "initiative_row" "initiative"%ROWTYPE;
2639 "issue_row" "issue"%ROWTYPE;
2640 "area_row" "area"%ROWTYPE;
2641 BEGIN
2642 IF TG_OP = 'UPDATE' THEN
2643 IF
2644 OLD."suggestion_id" = NEW."suggestion_id" AND
2645 OLD."member_id" = NEW."member_id"
2646 THEN
2647 IF
2648 OLD."degree" = NEW."degree" AND
2649 OLD."fulfilled" = NEW."fulfilled"
2650 THEN
2651 RETURN NULL;
2652 END IF;
2653 "same_pkey_v" := TRUE;
2654 END IF;
2655 END IF;
2656 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "same_pkey_v" THEN
2657 IF EXISTS (
2658 SELECT NULL FROM "suggestion" WHERE "id" = OLD."suggestion_id"
2659 FOR SHARE
2660 ) THEN
2661 SELECT * INTO "initiative_row" FROM "initiative"
2662 WHERE "id" = OLD."initiative_id" FOR SHARE;
2663 SELECT * INTO "issue_row" FROM "issue"
2664 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2665 SELECT * INTO "area_row" FROM "area"
2666 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2667 INSERT INTO "event" (
2668 "event", "member_id",
2669 "unit_id", "area_id", "policy_id", "issue_id", "state",
2670 "initiative_id", "suggestion_id",
2671 "boolean_value", "numeric_value"
2672 ) VALUES (
2673 'suggestion_rated', OLD."member_id",
2674 "area_row"."unit_id", "issue_row"."area_id",
2675 "issue_row"."policy_id",
2676 "initiative_row"."issue_id", "issue_row"."state",
2677 OLD."initiative_id", OLD."suggestion_id",
2678 NULL, 0
2679 );
2680 END IF;
2681 END IF;
2682 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2683 SELECT * INTO "initiative_row" FROM "initiative"
2684 WHERE "id" = NEW."initiative_id" FOR SHARE;
2685 SELECT * INTO "issue_row" FROM "issue"
2686 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2687 SELECT * INTO "area_row" FROM "area"
2688 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2689 INSERT INTO "event" (
2690 "event", "member_id",
2691 "unit_id", "area_id", "policy_id", "issue_id", "state",
2692 "initiative_id", "suggestion_id",
2693 "boolean_value", "numeric_value"
2694 ) VALUES (
2695 'suggestion_rated', NEW."member_id",
2696 "area_row"."unit_id", "issue_row"."area_id",
2697 "issue_row"."policy_id",
2698 "initiative_row"."issue_id", "issue_row"."state",
2699 NEW."initiative_id", NEW."suggestion_id",
2700 NEW."fulfilled", NEW."degree"
2701 );
2702 END IF;
2703 RETURN NULL;
2704 END;
2705 $$;
2707 CREATE TRIGGER "write_event_suggestion_rated"
2708 AFTER INSERT OR UPDATE OR DELETE ON "opinion" FOR EACH ROW EXECUTE PROCEDURE
2709 "write_event_suggestion_rated_trigger"();
2711 COMMENT ON FUNCTION "write_event_suggestion_rated_trigger"() IS 'Implementation of trigger "write_event_suggestion_rated" on table "opinion"';
2712 COMMENT ON TRIGGER "write_event_suggestion_rated" ON "opinion" IS 'Create entry in "event" table when adding, updating, or removing support';
2715 CREATE FUNCTION "write_event_delegation_trigger"()
2716 RETURNS TRIGGER
2717 LANGUAGE 'plpgsql' VOLATILE AS $$
2718 DECLARE
2719 "issue_row" "issue"%ROWTYPE;
2720 "area_row" "area"%ROWTYPE;
2721 BEGIN
2722 IF TG_OP = 'DELETE' THEN
2723 IF EXISTS (
2724 SELECT NULL FROM "member" WHERE "id" = OLD."truster_id"
2725 ) AND (CASE OLD."scope"
2726 WHEN 'unit'::"delegation_scope" THEN EXISTS (
2727 SELECT NULL FROM "unit" WHERE "id" = OLD."unit_id"
2728 )
2729 WHEN 'area'::"delegation_scope" THEN EXISTS (
2730 SELECT NULL FROM "area" WHERE "id" = OLD."area_id"
2731 )
2732 WHEN 'issue'::"delegation_scope" THEN EXISTS (
2733 SELECT NULL FROM "issue" WHERE "id" = OLD."issue_id"
2734 )
2735 END) THEN
2736 SELECT * INTO "issue_row" FROM "issue"
2737 WHERE "id" = OLD."issue_id" FOR SHARE;
2738 SELECT * INTO "area_row" FROM "area"
2739 WHERE "id" = COALESCE(OLD."area_id", "issue_row"."area_id")
2740 FOR SHARE;
2741 INSERT INTO "event" (
2742 "event", "member_id", "scope",
2743 "unit_id", "area_id", "issue_id", "state",
2744 "boolean_value"
2745 ) VALUES (
2746 'delegation', OLD."truster_id", OLD."scope",
2747 COALESCE(OLD."unit_id", "area_row"."unit_id"), "area_row"."id",
2748 OLD."issue_id", "issue_row"."state",
2749 FALSE
2750 );
2751 END IF;
2752 ELSE
2753 SELECT * INTO "issue_row" FROM "issue"
2754 WHERE "id" = NEW."issue_id" FOR SHARE;
2755 SELECT * INTO "area_row" FROM "area"
2756 WHERE "id" = COALESCE(NEW."area_id", "issue_row"."area_id")
2757 FOR SHARE;
2758 INSERT INTO "event" (
2759 "event", "member_id", "other_member_id", "scope",
2760 "unit_id", "area_id", "issue_id", "state",
2761 "boolean_value"
2762 ) VALUES (
2763 'delegation', NEW."truster_id", NEW."trustee_id", NEW."scope",
2764 COALESCE(NEW."unit_id", "area_row"."unit_id"), "area_row"."id",
2765 NEW."issue_id", "issue_row"."state",
2766 TRUE
2767 );
2768 END IF;
2769 RETURN NULL;
2770 END;
2771 $$;
2773 CREATE TRIGGER "write_event_delegation"
2774 AFTER INSERT OR UPDATE OR DELETE ON "delegation" FOR EACH ROW EXECUTE PROCEDURE
2775 "write_event_delegation_trigger"();
2777 COMMENT ON FUNCTION "write_event_delegation_trigger"() IS 'Implementation of trigger "write_event_delegation" on table "delegation"';
2778 COMMENT ON TRIGGER "write_event_delegation" ON "delegation" IS 'Create entry in "event" table when adding, updating, or removing a delegation';
2781 CREATE FUNCTION "write_event_contact_trigger"()
2782 RETURNS TRIGGER
2783 LANGUAGE 'plpgsql' VOLATILE AS $$
2784 BEGIN
2785 IF TG_OP = 'UPDATE' THEN
2786 IF
2787 OLD."member_id" = NEW."member_id" AND
2788 OLD."other_member_id" = NEW."other_member_id" AND
2789 OLD."public" = NEW."public"
2790 THEN
2791 RETURN NULL;
2792 END IF;
2793 END IF;
2794 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2795 IF OLD."public" THEN
2796 IF EXISTS (
2797 SELECT NULL FROM "member" WHERE "id" = OLD."member_id"
2798 FOR SHARE
2799 ) AND EXISTS (
2800 SELECT NULL FROM "member" WHERE "id" = OLD."other_member_id"
2801 FOR SHARE
2802 ) THEN
2803 INSERT INTO "event" (
2804 "event", "member_id", "other_member_id", "boolean_value"
2805 ) VALUES (
2806 'contact', OLD."member_id", OLD."other_member_id", FALSE
2807 );
2808 END IF;
2809 END IF;
2810 END IF;
2811 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2812 IF NEW."public" THEN
2813 INSERT INTO "event" (
2814 "event", "member_id", "other_member_id", "boolean_value"
2815 ) VALUES (
2816 'contact', NEW."member_id", NEW."other_member_id", TRUE
2817 );
2818 END IF;
2819 END IF;
2820 RETURN NULL;
2821 END;
2822 $$;
2824 CREATE TRIGGER "write_event_contact"
2825 AFTER INSERT OR UPDATE OR DELETE ON "contact" FOR EACH ROW EXECUTE PROCEDURE
2826 "write_event_contact_trigger"();
2828 COMMENT ON FUNCTION "write_event_contact_trigger"() IS 'Implementation of trigger "write_event_contact" on table "contact"';
2829 COMMENT ON TRIGGER "write_event_contact" ON "contact" IS 'Create entry in "event" table when adding or removing public contacts';
2832 CREATE FUNCTION "write_event_posting_trigger"()
2833 RETURNS TRIGGER
2834 LANGUAGE 'plpgsql' VOLATILE AS $$
2835 BEGIN
2836 INSERT INTO "event" (
2837 "event", "posting_id", "member_id",
2838 "unit_id", "area_id", "policy_id",
2839 "issue_id", "initiative_id", "suggestion_id"
2840 ) VALUES (
2841 'posting_created', NEW."id", NEW."author_id",
2842 NEW."unit_id", NEW."area_id", NEW."policy_id",
2843 NEW."issue_id", NEW."initiative_id", NEW."suggestion_id"
2844 );
2845 RETURN NULL;
2846 END;
2847 $$;
2849 CREATE TRIGGER "write_event_posting"
2850 AFTER INSERT ON "posting" FOR EACH ROW EXECUTE PROCEDURE
2851 "write_event_posting_trigger"();
2853 COMMENT ON FUNCTION "write_event_posting_trigger"() IS 'Implementation of trigger "write_event_posting" on table "posting"';
2854 COMMENT ON TRIGGER "write_event_posting" ON "posting" IS 'Create entry in "event" table when creating a new posting';
2857 CREATE FUNCTION "send_event_notify_trigger"()
2858 RETURNS TRIGGER
2859 LANGUAGE 'plpgsql' VOLATILE AS $$
2860 BEGIN
2861 EXECUTE 'NOTIFY "event", ''' || NEW."event" || '''';
2862 RETURN NULL;
2863 END;
2864 $$;
2866 CREATE TRIGGER "send_notify"
2867 AFTER INSERT OR UPDATE ON "event" FOR EACH ROW EXECUTE PROCEDURE
2868 "send_event_notify_trigger"();
2872 ----------------------------
2873 -- Additional constraints --
2874 ----------------------------
2877 CREATE FUNCTION "delete_extended_scope_tokens_trigger"()
2878 RETURNS TRIGGER
2879 LANGUAGE 'plpgsql' VOLATILE AS $$
2880 DECLARE
2881 "system_application_row" "system_application"%ROWTYPE;
2882 BEGIN
2883 IF OLD."system_application_id" NOTNULL THEN
2884 SELECT * FROM "system_application" INTO "system_application_row"
2885 WHERE "id" = OLD."system_application_id";
2886 DELETE FROM "token"
2887 WHERE "member_id" = OLD."member_id"
2888 AND "system_application_id" = OLD."system_application_id"
2889 AND NOT COALESCE(
2890 regexp_split_to_array("scope", E'\\s+') <@
2891 regexp_split_to_array(
2892 "system_application_row"."automatic_scope", E'\\s+'
2893 ),
2894 FALSE
2895 );
2896 END IF;
2897 RETURN OLD;
2898 END;
2899 $$;
2901 CREATE TRIGGER "delete_extended_scope_tokens"
2902 BEFORE DELETE ON "member_application" FOR EACH ROW EXECUTE PROCEDURE
2903 "delete_extended_scope_tokens_trigger"();
2906 CREATE FUNCTION "detach_token_from_session_trigger"()
2907 RETURNS TRIGGER
2908 LANGUAGE 'plpgsql' VOLATILE AS $$
2909 BEGIN
2910 UPDATE "token" SET "session_id" = NULL
2911 WHERE "session_id" = OLD."id";
2912 RETURN OLD;
2913 END;
2914 $$;
2916 CREATE TRIGGER "detach_token_from_session"
2917 BEFORE DELETE ON "session" FOR EACH ROW EXECUTE PROCEDURE
2918 "detach_token_from_session_trigger"();
2921 CREATE FUNCTION "delete_non_detached_scope_with_session_trigger"()
2922 RETURNS TRIGGER
2923 LANGUAGE 'plpgsql' VOLATILE AS $$
2924 BEGIN
2925 IF NEW."session_id" ISNULL THEN
2926 SELECT coalesce(string_agg("element", ' '), '') INTO NEW."scope"
2927 FROM unnest(regexp_split_to_array(NEW."scope", E'\\s+')) AS "element"
2928 WHERE "element" LIKE '%_detached';
2929 END IF;
2930 RETURN NEW;
2931 END;
2932 $$;
2934 CREATE TRIGGER "delete_non_detached_scope_with_session"
2935 BEFORE INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2936 "delete_non_detached_scope_with_session_trigger"();
2939 CREATE FUNCTION "delete_token_with_empty_scope_trigger"()
2940 RETURNS TRIGGER
2941 LANGUAGE 'plpgsql' VOLATILE AS $$
2942 BEGIN
2943 IF NEW."scope" = '' THEN
2944 DELETE FROM "token" WHERE "id" = NEW."id";
2945 END IF;
2946 RETURN NULL;
2947 END;
2948 $$;
2950 CREATE TRIGGER "delete_token_with_empty_scope"
2951 AFTER INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2952 "delete_token_with_empty_scope_trigger"();
2955 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
2956 RETURNS TRIGGER
2957 LANGUAGE 'plpgsql' VOLATILE AS $$
2958 BEGIN
2959 IF NOT EXISTS (
2960 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
2961 ) THEN
2962 RAISE EXCEPTION 'Cannot create issue without an initial initiative.' USING
2963 ERRCODE = 'integrity_constraint_violation',
2964 HINT = 'Create issue, initiative, and draft within the same transaction.';
2965 END IF;
2966 RETURN NULL;
2967 END;
2968 $$;
2970 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
2971 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
2972 FOR EACH ROW EXECUTE PROCEDURE
2973 "issue_requires_first_initiative_trigger"();
2975 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
2976 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
2979 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
2980 RETURNS TRIGGER
2981 LANGUAGE 'plpgsql' VOLATILE AS $$
2982 DECLARE
2983 "reference_lost" BOOLEAN;
2984 BEGIN
2985 IF TG_OP = 'DELETE' THEN
2986 "reference_lost" := TRUE;
2987 ELSE
2988 "reference_lost" := NEW."issue_id" != OLD."issue_id";
2989 END IF;
2990 IF
2991 "reference_lost" AND NOT EXISTS (
2992 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
2993 )
2994 THEN
2995 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
2996 END IF;
2997 RETURN NULL;
2998 END;
2999 $$;
3001 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
3002 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
3003 FOR EACH ROW EXECUTE PROCEDURE
3004 "last_initiative_deletes_issue_trigger"();
3006 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
3007 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
3010 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
3011 RETURNS TRIGGER
3012 LANGUAGE 'plpgsql' VOLATILE AS $$
3013 BEGIN
3014 IF NOT EXISTS (
3015 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
3016 ) THEN
3017 RAISE EXCEPTION 'Cannot create initiative without an initial draft.' USING
3018 ERRCODE = 'integrity_constraint_violation',
3019 HINT = 'Create issue, initiative and draft within the same transaction.';
3020 END IF;
3021 RETURN NULL;
3022 END;
3023 $$;
3025 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
3026 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
3027 FOR EACH ROW EXECUTE PROCEDURE
3028 "initiative_requires_first_draft_trigger"();
3030 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
3031 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
3034 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
3035 RETURNS TRIGGER
3036 LANGUAGE 'plpgsql' VOLATILE AS $$
3037 DECLARE
3038 "reference_lost" BOOLEAN;
3039 BEGIN
3040 IF TG_OP = 'DELETE' THEN
3041 "reference_lost" := TRUE;
3042 ELSE
3043 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
3044 END IF;
3045 IF
3046 "reference_lost" AND NOT EXISTS (
3047 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
3048 )
3049 THEN
3050 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
3051 END IF;
3052 RETURN NULL;
3053 END;
3054 $$;
3056 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
3057 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
3058 FOR EACH ROW EXECUTE PROCEDURE
3059 "last_draft_deletes_initiative_trigger"();
3061 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
3062 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
3065 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
3066 RETURNS TRIGGER
3067 LANGUAGE 'plpgsql' VOLATILE AS $$
3068 BEGIN
3069 IF NOT EXISTS (
3070 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
3071 ) THEN
3072 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.' USING
3073 ERRCODE = 'integrity_constraint_violation',
3074 HINT = 'Create suggestion and opinion within the same transaction.';
3075 END IF;
3076 RETURN NULL;
3077 END;
3078 $$;
3080 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
3081 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
3082 FOR EACH ROW EXECUTE PROCEDURE
3083 "suggestion_requires_first_opinion_trigger"();
3085 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
3086 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
3089 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
3090 RETURNS TRIGGER
3091 LANGUAGE 'plpgsql' VOLATILE AS $$
3092 DECLARE
3093 "reference_lost" BOOLEAN;
3094 BEGIN
3095 IF TG_OP = 'DELETE' THEN
3096 "reference_lost" := TRUE;
3097 ELSE
3098 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
3099 END IF;
3100 IF
3101 "reference_lost" AND NOT EXISTS (
3102 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
3103 )
3104 THEN
3105 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
3106 END IF;
3107 RETURN NULL;
3108 END;
3109 $$;
3111 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
3112 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
3113 FOR EACH ROW EXECUTE PROCEDURE
3114 "last_opinion_deletes_suggestion_trigger"();
3116 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
3117 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
3120 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
3121 RETURNS TRIGGER
3122 LANGUAGE 'plpgsql' VOLATILE AS $$
3123 BEGIN
3124 DELETE FROM "direct_voter"
3125 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
3126 RETURN NULL;
3127 END;
3128 $$;
3130 CREATE TRIGGER "non_voter_deletes_direct_voter"
3131 AFTER INSERT OR UPDATE ON "non_voter"
3132 FOR EACH ROW EXECUTE PROCEDURE
3133 "non_voter_deletes_direct_voter_trigger"();
3135 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
3136 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")';
3139 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
3140 RETURNS TRIGGER
3141 LANGUAGE 'plpgsql' VOLATILE AS $$
3142 BEGIN
3143 DELETE FROM "non_voter"
3144 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
3145 RETURN NULL;
3146 END;
3147 $$;
3149 CREATE TRIGGER "direct_voter_deletes_non_voter"
3150 AFTER INSERT OR UPDATE ON "direct_voter"
3151 FOR EACH ROW EXECUTE PROCEDURE
3152 "direct_voter_deletes_non_voter_trigger"();
3154 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
3155 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")';
3158 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
3159 RETURNS TRIGGER
3160 LANGUAGE 'plpgsql' VOLATILE AS $$
3161 BEGIN
3162 IF NEW."comment" ISNULL THEN
3163 NEW."comment_changed" := NULL;
3164 NEW."formatting_engine" := NULL;
3165 END IF;
3166 RETURN NEW;
3167 END;
3168 $$;
3170 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
3171 BEFORE INSERT OR UPDATE ON "direct_voter"
3172 FOR EACH ROW EXECUTE PROCEDURE
3173 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
3175 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"';
3176 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.';
3179 CREATE FUNCTION "file_requires_reference_trigger"()
3180 RETURNS TRIGGER
3181 LANGUAGE 'plpgsql' VOLATILE AS $$
3182 BEGIN
3183 IF NOT EXISTS (
3184 SELECT NULL FROM "draft_attachment" WHERE "file_id" = NEW."id"
3185 ) THEN
3186 RAISE EXCEPTION 'Cannot create an unreferenced file.' USING
3187 ERRCODE = 'integrity_constraint_violation',
3188 HINT = 'Create file and its reference in another table within the same transaction.';
3189 END IF;
3190 RETURN NULL;
3191 END;
3192 $$;
3194 CREATE CONSTRAINT TRIGGER "file_requires_reference"
3195 AFTER INSERT OR UPDATE ON "file" DEFERRABLE INITIALLY DEFERRED
3196 FOR EACH ROW EXECUTE PROCEDURE
3197 "file_requires_reference_trigger"();
3199 COMMENT ON FUNCTION "file_requires_reference_trigger"() IS 'Implementation of trigger "file_requires_reference" on table "file"';
3200 COMMENT ON TRIGGER "file_requires_reference" ON "file" IS 'Ensure that files are always referenced';
3203 CREATE FUNCTION "last_reference_deletes_file_trigger"()
3204 RETURNS TRIGGER
3205 LANGUAGE 'plpgsql' VOLATILE AS $$
3206 DECLARE
3207 "reference_lost" BOOLEAN;
3208 BEGIN
3209 IF TG_OP = 'DELETE' THEN
3210 "reference_lost" := TRUE;
3211 ELSE
3212 "reference_lost" := NEW."file_id" != OLD."file_id";
3213 END IF;
3214 IF
3215 "reference_lost" AND NOT EXISTS (
3216 SELECT NULL FROM "draft_attachment" WHERE "file_id" = OLD."file_id"
3217 )
3218 THEN
3219 DELETE FROM "file" WHERE "id" = OLD."file_id";
3220 END IF;
3221 RETURN NULL;
3222 END;
3223 $$;
3225 CREATE CONSTRAINT TRIGGER "last_reference_deletes_file"
3226 AFTER UPDATE OR DELETE ON "draft_attachment" DEFERRABLE INITIALLY DEFERRED
3227 FOR EACH ROW EXECUTE PROCEDURE
3228 "last_reference_deletes_file_trigger"();
3230 COMMENT ON FUNCTION "last_reference_deletes_file_trigger"() IS 'Implementation of trigger "last_reference_deletes_file" on table "draft_attachment"';
3231 COMMENT ON TRIGGER "last_reference_deletes_file" ON "draft_attachment" IS 'Removing the last reference to a file deletes the file';
3235 ---------------------------------
3236 -- Delete incomplete snapshots --
3237 ---------------------------------
3240 CREATE FUNCTION "delete_snapshot_on_partial_delete_trigger"()
3241 RETURNS TRIGGER
3242 LANGUAGE 'plpgsql' VOLATILE AS $$
3243 BEGIN
3244 IF TG_OP = 'UPDATE' THEN
3245 IF
3246 OLD."snapshot_id" = NEW."snapshot_id" AND
3247 OLD."issue_id" = NEW."issue_id"
3248 THEN
3249 RETURN NULL;
3250 END IF;
3251 END IF;
3252 DELETE FROM "snapshot" WHERE "id" = OLD."snapshot_id";
3253 RETURN NULL;
3254 END;
3255 $$;
3257 CREATE TRIGGER "delete_snapshot_on_partial_delete"
3258 AFTER UPDATE OR DELETE ON "snapshot_issue"
3259 FOR EACH ROW EXECUTE PROCEDURE
3260 "delete_snapshot_on_partial_delete_trigger"();
3262 COMMENT ON FUNCTION "delete_snapshot_on_partial_delete_trigger"() IS 'Implementation of trigger "delete_snapshot_on_partial_delete" on table "snapshot_issue"';
3263 COMMENT ON TRIGGER "delete_snapshot_on_partial_delete" ON "snapshot_issue" IS 'Deletes whole snapshot if one issue is deleted from the snapshot';
3267 ---------------------------------------------------------------
3268 -- Ensure that votes are not modified when issues are closed --
3269 ---------------------------------------------------------------
3271 -- NOTE: Frontends should ensure this anyway, but in case of programming
3272 -- errors the following triggers ensure data integrity.
3275 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
3276 RETURNS TRIGGER
3277 LANGUAGE 'plpgsql' VOLATILE AS $$
3278 DECLARE
3279 "issue_id_v" "issue"."id"%TYPE;
3280 "issue_row" "issue"%ROWTYPE;
3281 BEGIN
3282 IF EXISTS (
3283 SELECT NULL FROM "temporary_transaction_data"
3284 WHERE "txid" = txid_current()
3285 AND "key" = 'override_protection_triggers'
3286 AND "value" = TRUE::TEXT
3287 ) THEN
3288 RETURN NULL;
3289 END IF;
3290 IF TG_OP = 'DELETE' THEN
3291 "issue_id_v" := OLD."issue_id";
3292 ELSE
3293 "issue_id_v" := NEW."issue_id";
3294 END IF;
3295 SELECT INTO "issue_row" * FROM "issue"
3296 WHERE "id" = "issue_id_v" FOR SHARE;
3297 IF (
3298 "issue_row"."closed" NOTNULL OR (
3299 "issue_row"."state" = 'voting' AND
3300 "issue_row"."phase_finished" NOTNULL
3301 )
3302 ) THEN
3303 IF
3304 TG_RELID = 'direct_voter'::regclass AND
3305 TG_OP = 'UPDATE'
3306 THEN
3307 IF
3308 OLD."issue_id" = NEW."issue_id" AND
3309 OLD."member_id" = NEW."member_id" AND
3310 OLD."weight" = NEW."weight"
3311 THEN
3312 RETURN NULL; -- allows changing of voter comment
3313 END IF;
3314 END IF;
3315 RAISE EXCEPTION 'Tried to modify data after voting has been closed.' USING
3316 ERRCODE = 'integrity_constraint_violation';
3317 END IF;
3318 RETURN NULL;
3319 END;
3320 $$;
3322 CREATE TRIGGER "forbid_changes_on_closed_issue"
3323 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
3324 FOR EACH ROW EXECUTE PROCEDURE
3325 "forbid_changes_on_closed_issue_trigger"();
3327 CREATE TRIGGER "forbid_changes_on_closed_issue"
3328 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
3329 FOR EACH ROW EXECUTE PROCEDURE
3330 "forbid_changes_on_closed_issue_trigger"();
3332 CREATE TRIGGER "forbid_changes_on_closed_issue"
3333 AFTER INSERT OR UPDATE OR DELETE ON "vote"
3334 FOR EACH ROW EXECUTE PROCEDURE
3335 "forbid_changes_on_closed_issue_trigger"();
3337 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"';
3338 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';
3339 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';
3340 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';
3344 --------------------------------------------------------------------
3345 -- Auto-retrieval of fields only needed for referential integrity --
3346 --------------------------------------------------------------------
3349 CREATE FUNCTION "autofill_issue_id_trigger"()
3350 RETURNS TRIGGER
3351 LANGUAGE 'plpgsql' VOLATILE AS $$
3352 BEGIN
3353 IF NEW."issue_id" ISNULL THEN
3354 SELECT "issue_id" INTO NEW."issue_id"
3355 FROM "initiative" WHERE "id" = NEW."initiative_id";
3356 END IF;
3357 RETURN NEW;
3358 END;
3359 $$;
3361 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
3362 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3364 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
3365 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3367 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
3368 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
3369 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
3372 CREATE FUNCTION "autofill_initiative_id_trigger"()
3373 RETURNS TRIGGER
3374 LANGUAGE 'plpgsql' VOLATILE AS $$
3375 BEGIN
3376 IF NEW."initiative_id" ISNULL THEN
3377 SELECT "initiative_id" INTO NEW."initiative_id"
3378 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3379 END IF;
3380 RETURN NEW;
3381 END;
3382 $$;
3384 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
3385 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
3387 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
3388 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
3392 -------------------------------------------------------
3393 -- Automatic copying of values for indexing purposes --
3394 -------------------------------------------------------
3397 CREATE FUNCTION "copy_current_draft_data"
3398 ("initiative_id_p" "initiative"."id"%TYPE )
3399 RETURNS VOID
3400 LANGUAGE 'plpgsql' VOLATILE AS $$
3401 BEGIN
3402 PERFORM NULL FROM "initiative" WHERE "id" = "initiative_id_p"
3403 FOR UPDATE;
3404 UPDATE "initiative" SET
3405 "location" = "draft"."location",
3406 "content" = "draft"."content"
3407 FROM "current_draft" AS "draft"
3408 WHERE "initiative"."id" = "initiative_id_p"
3409 AND "draft"."initiative_id" = "initiative_id_p";
3410 END;
3411 $$;
3413 COMMENT ON FUNCTION "copy_current_draft_data"
3414 ( "initiative"."id"%TYPE )
3415 IS 'Helper function for function "copy_current_draft_data_trigger"';
3418 CREATE FUNCTION "copy_current_draft_data_trigger"()
3419 RETURNS TRIGGER
3420 LANGUAGE 'plpgsql' VOLATILE AS $$
3421 BEGIN
3422 IF TG_OP='DELETE' THEN
3423 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3424 ELSE
3425 IF TG_OP='UPDATE' THEN
3426 IF COALESCE(OLD."inititiave_id" != NEW."initiative_id", TRUE) THEN
3427 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3428 END IF;
3429 END IF;
3430 PERFORM "copy_current_draft_data"(NEW."initiative_id");
3431 END IF;
3432 RETURN NULL;
3433 END;
3434 $$;
3436 CREATE TRIGGER "copy_current_draft_data"
3437 AFTER INSERT OR UPDATE OR DELETE ON "draft"
3438 FOR EACH ROW EXECUTE PROCEDURE
3439 "copy_current_draft_data_trigger"();
3441 COMMENT ON FUNCTION "copy_current_draft_data_trigger"() IS 'Implementation of trigger "copy_current_draft_data" on table "draft"';
3442 COMMENT ON TRIGGER "copy_current_draft_data" ON "draft" IS 'Copy certain fields from most recent "draft" to "initiative"';
3446 -----------------------------------------------------
3447 -- Automatic calculation of certain default values --
3448 -----------------------------------------------------
3451 CREATE FUNCTION "copy_timings_trigger"()
3452 RETURNS TRIGGER
3453 LANGUAGE 'plpgsql' VOLATILE AS $$
3454 DECLARE
3455 "policy_row" "policy"%ROWTYPE;
3456 BEGIN
3457 SELECT * INTO "policy_row" FROM "policy"
3458 WHERE "id" = NEW."policy_id";
3459 IF NEW."min_admission_time" ISNULL THEN
3460 NEW."min_admission_time" := "policy_row"."min_admission_time";
3461 END IF;
3462 IF NEW."max_admission_time" ISNULL THEN
3463 NEW."max_admission_time" := "policy_row"."max_admission_time";
3464 END IF;
3465 IF NEW."discussion_time" ISNULL THEN
3466 NEW."discussion_time" := "policy_row"."discussion_time";
3467 END IF;
3468 IF NEW."verification_time" ISNULL THEN
3469 NEW."verification_time" := "policy_row"."verification_time";
3470 END IF;
3471 IF NEW."voting_time" ISNULL THEN
3472 NEW."voting_time" := "policy_row"."voting_time";
3473 END IF;
3474 RETURN NEW;
3475 END;
3476 $$;
3478 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
3479 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
3481 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
3482 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
3485 CREATE FUNCTION "default_for_draft_id_trigger"()
3486 RETURNS TRIGGER
3487 LANGUAGE 'plpgsql' VOLATILE AS $$
3488 BEGIN
3489 IF NEW."draft_id" ISNULL THEN
3490 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
3491 WHERE "initiative_id" = NEW."initiative_id";
3492 END IF;
3493 RETURN NEW;
3494 END;
3495 $$;
3497 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
3498 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3499 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
3500 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3502 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
3503 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';
3504 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';
3508 ----------------------------------------
3509 -- Automatic creation of dependencies --
3510 ----------------------------------------
3513 CREATE FUNCTION "autocreate_interest_trigger"()
3514 RETURNS TRIGGER
3515 LANGUAGE 'plpgsql' VOLATILE AS $$
3516 BEGIN
3517 IF NOT EXISTS (
3518 SELECT NULL FROM "initiative" JOIN "interest"
3519 ON "initiative"."issue_id" = "interest"."issue_id"
3520 WHERE "initiative"."id" = NEW."initiative_id"
3521 AND "interest"."member_id" = NEW."member_id"
3522 ) THEN
3523 BEGIN
3524 INSERT INTO "interest" ("issue_id", "member_id")
3525 SELECT "issue_id", NEW."member_id"
3526 FROM "initiative" WHERE "id" = NEW."initiative_id";
3527 EXCEPTION WHEN unique_violation THEN END;
3528 END IF;
3529 RETURN NEW;
3530 END;
3531 $$;
3533 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
3534 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
3536 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
3537 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';
3540 CREATE FUNCTION "autocreate_supporter_trigger"()
3541 RETURNS TRIGGER
3542 LANGUAGE 'plpgsql' VOLATILE AS $$
3543 BEGIN
3544 IF NOT EXISTS (
3545 SELECT NULL FROM "suggestion" JOIN "supporter"
3546 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
3547 WHERE "suggestion"."id" = NEW."suggestion_id"
3548 AND "supporter"."member_id" = NEW."member_id"
3549 ) THEN
3550 BEGIN
3551 INSERT INTO "supporter" ("initiative_id", "member_id")
3552 SELECT "initiative_id", NEW."member_id"
3553 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3554 EXCEPTION WHEN unique_violation THEN END;
3555 END IF;
3556 RETURN NEW;
3557 END;
3558 $$;
3560 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
3561 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
3563 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
3564 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.';
3568 ------------------------------------------
3569 -- Views and helper functions for views --
3570 ------------------------------------------
3573 CREATE VIEW "member_eligible_to_be_notified" AS
3574 SELECT * FROM "member"
3575 WHERE "activated" NOTNULL AND "locked" = FALSE;
3577 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")';
3580 CREATE VIEW "member_to_notify" AS
3581 SELECT * FROM "member_eligible_to_be_notified"
3582 WHERE "disable_notifications" = FALSE;
3584 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)';
3587 CREATE VIEW "follower" AS
3588 SELECT
3589 "id" AS "follower_id",
3590 ( SELECT ARRAY["member"."id"] || array_agg("contact"."other_member_id")
3591 FROM "contact"
3592 WHERE "contact"."member_id" = "member"."id" AND "contact"."following" )
3593 AS "following_ids"
3594 FROM "member";
3596 COMMENT ON VIEW "follower" IS 'Provides the contacts of each member that are being followed (including the member itself) as an array of IDs';
3599 CREATE VIEW "area_quorum" AS
3600 SELECT
3601 "area"."id" AS "area_id",
3602 ceil(
3603 "area"."quorum_standard"::FLOAT8 * "quorum_factor"::FLOAT8 ^ (
3604 coalesce(
3605 ( SELECT sum(
3606 ( extract(epoch from "area"."quorum_time")::FLOAT8 /
3607 extract(epoch from
3608 ("issue"."accepted"-"issue"."created") +
3609 "issue"."discussion_time" +
3610 "issue"."verification_time" +
3611 "issue"."voting_time"
3612 )::FLOAT8
3613 ) ^ "area"."quorum_exponent"::FLOAT8
3614 )
3615 FROM "issue" JOIN "policy"
3616 ON "issue"."policy_id" = "policy"."id"
3617 WHERE "issue"."area_id" = "area"."id"
3618 AND "issue"."accepted" NOTNULL
3619 AND "issue"."closed" ISNULL
3620 AND "policy"."polling" = FALSE
3621 )::FLOAT8, 0::FLOAT8
3622 ) / "area"."quorum_issues"::FLOAT8 - 1::FLOAT8
3623 ) * CASE WHEN "area"."quorum_den" ISNULL THEN 1 ELSE (
3624 SELECT "snapshot"."population"
3625 FROM "snapshot"
3626 WHERE "snapshot"."area_id" = "area"."id"
3627 AND "snapshot"."issue_id" ISNULL
3628 ORDER BY "snapshot"."id" DESC
3629 LIMIT 1
3630 ) END / coalesce("area"."quorum_den", 1)
3632 )::INT4 AS "issue_quorum"
3633 FROM "area";
3635 COMMENT ON VIEW "area_quorum" IS 'Area-based quorum considering number of open (accepted) issues';
3638 CREATE VIEW "issue_quorum" AS
3639 SELECT DISTINCT ON ("issue_id")
3640 "issue"."id" AS "issue_id",
3641 "subquery"."issue_quorum"
3642 FROM "issue"
3643 CROSS JOIN LATERAL (
3644 SELECT "area_quorum"."issue_quorum"
3645 FROM "area_quorum" WHERE "area_quorum"."area_id" = "issue"."area_id"
3646 UNION ALL
3647 SELECT "policy"."issue_quorum"
3648 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3649 UNION ALL
3650 SELECT
3651 ceil(
3652 ("issue"."population"::INT8 * "policy"."issue_quorum_num"::INT8) /
3653 "policy"."issue_quorum_den"::FLOAT8
3654 )::INT4
3655 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3656 ) AS "subquery"
3657 ORDER BY "issue_id", "issue_quorum" DESC;
3659 COMMENT ON VIEW "issue_quorum" IS 'Effective quorum for issue admission';
3662 CREATE VIEW "area_with_unaccepted_issues" AS
3663 SELECT DISTINCT ON ("area"."id") "area".*
3664 FROM "area" JOIN "issue" ON "area"."id" = "issue"."area_id"
3665 WHERE "issue"."state" = 'admission';
3667 COMMENT ON VIEW "area_with_unaccepted_issues" IS 'All areas with unaccepted open issues (needed for issue admission system)';
3670 CREATE VIEW "issue_for_admission" AS
3671 SELECT DISTINCT ON ("issue"."area_id")
3672 "issue".*,
3673 max("initiative"."supporter_count") AS "max_supporter_count"
3674 FROM "issue"
3675 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
3676 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
3677 JOIN "area" ON "issue"."area_id" = "area"."id"
3678 WHERE "issue"."state" = 'admission'::"issue_state"
3679 AND now() >= "issue"."created" + "issue"."min_admission_time"
3680 AND "initiative"."supporter_count" >= "policy"."issue_quorum"
3681 AND "initiative"."supporter_count" * "policy"."issue_quorum_den" >=
3682 "issue"."population" * "policy"."issue_quorum_num"
3683 AND "initiative"."supporter_count" >= "area"."issue_quorum"
3684 AND "initiative"."revoked" ISNULL
3685 GROUP BY "issue"."id"
3686 ORDER BY "issue"."area_id", "max_supporter_count" DESC, "issue"."id";
3688 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';
3691 CREATE VIEW "unit_delegation" AS
3692 SELECT
3693 "unit"."id" AS "unit_id",
3694 "delegation"."id",
3695 "delegation"."truster_id",
3696 "delegation"."trustee_id",
3697 "delegation"."scope"
3698 FROM "unit"
3699 JOIN "delegation"
3700 ON "delegation"."unit_id" = "unit"."id"
3701 JOIN "member"
3702 ON "delegation"."truster_id" = "member"."id"
3703 JOIN "privilege"
3704 ON "delegation"."unit_id" = "privilege"."unit_id"
3705 AND "delegation"."truster_id" = "privilege"."member_id"
3706 WHERE "member"."active" AND "privilege"."voting_right";
3708 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
3711 CREATE VIEW "area_delegation" AS
3712 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
3713 "area"."id" AS "area_id",
3714 "delegation"."id",
3715 "delegation"."truster_id",
3716 "delegation"."trustee_id",
3717 "delegation"."scope"
3718 FROM "area"
3719 JOIN "delegation"
3720 ON "delegation"."unit_id" = "area"."unit_id"
3721 OR "delegation"."area_id" = "area"."id"
3722 JOIN "member"
3723 ON "delegation"."truster_id" = "member"."id"
3724 JOIN "privilege"
3725 ON "area"."unit_id" = "privilege"."unit_id"
3726 AND "delegation"."truster_id" = "privilege"."member_id"
3727 WHERE "member"."active" AND "privilege"."voting_right"
3728 ORDER BY
3729 "area"."id",
3730 "delegation"."truster_id",
3731 "delegation"."scope" DESC;
3733 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
3736 CREATE VIEW "issue_delegation" AS
3737 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
3738 "issue"."id" AS "issue_id",
3739 "delegation"."id",
3740 "delegation"."truster_id",
3741 "delegation"."trustee_id",
3742 "privilege"."weight",
3743 "delegation"."scope"
3744 FROM "issue"
3745 JOIN "area"
3746 ON "area"."id" = "issue"."area_id"
3747 JOIN "delegation"
3748 ON "delegation"."unit_id" = "area"."unit_id"
3749 OR "delegation"."area_id" = "area"."id"
3750 OR "delegation"."issue_id" = "issue"."id"
3751 JOIN "member"
3752 ON "delegation"."truster_id" = "member"."id"
3753 JOIN "privilege"
3754 ON "area"."unit_id" = "privilege"."unit_id"
3755 AND "delegation"."truster_id" = "privilege"."member_id"
3756 WHERE "member"."active" AND "privilege"."voting_right"
3757 ORDER BY
3758 "issue"."id",
3759 "delegation"."truster_id",
3760 "delegation"."scope" DESC;
3762 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
3765 CREATE VIEW "member_count_view" AS
3766 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
3768 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
3771 CREATE VIEW "unit_member" AS
3772 SELECT
3773 "unit"."id" AS "unit_id",
3774 "member"."id" AS "member_id",
3775 "privilege"."weight"
3776 FROM "privilege"
3777 JOIN "unit" ON "unit"."id" = "privilege"."unit_id"
3778 JOIN "member" ON "member"."id" = "privilege"."member_id"
3779 WHERE "privilege"."voting_right" AND "member"."active";
3781 COMMENT ON VIEW "unit_member" IS 'Active members with voting right in a unit';
3784 CREATE VIEW "unit_member_count" AS
3785 SELECT
3786 "unit"."id" AS "unit_id",
3787 count("unit_member"."member_id") AS "member_count",
3788 sum("unit_member"."weight") AS "member_weight"
3789 FROM "unit" LEFT JOIN "unit_member"
3790 ON "unit"."id" = "unit_member"."unit_id"
3791 GROUP BY "unit"."id";
3793 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
3796 CREATE VIEW "opening_draft" AS
3797 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3798 ORDER BY "initiative_id", "id";
3800 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
3803 CREATE VIEW "current_draft" AS
3804 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3805 ORDER BY "initiative_id", "id" DESC;
3807 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
3810 CREATE VIEW "critical_opinion" AS
3811 SELECT * FROM "opinion"
3812 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
3813 OR ("degree" = -2 AND "fulfilled" = TRUE);
3815 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
3818 CREATE VIEW "issue_supporter_in_admission_state" AS
3819 SELECT
3820 "area"."unit_id",
3821 "issue"."area_id",
3822 "issue"."id" AS "issue_id",
3823 "supporter"."member_id",
3824 "direct_interest_snapshot"."weight"
3825 FROM "issue"
3826 JOIN "area" ON "area"."id" = "issue"."area_id"
3827 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
3828 JOIN "direct_interest_snapshot"
3829 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3830 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3831 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
3832 WHERE "issue"."state" = 'admission'::"issue_state";
3834 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';
3837 CREATE VIEW "initiative_suggestion_order_calculation" AS
3838 SELECT
3839 "initiative"."id" AS "initiative_id",
3840 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
3841 FROM "initiative" JOIN "issue"
3842 ON "initiative"."issue_id" = "issue"."id"
3843 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
3844 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
3846 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
3848 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';
3851 CREATE VIEW "individual_suggestion_ranking" AS
3852 SELECT
3853 "opinion"."initiative_id",
3854 "opinion"."member_id",
3855 "direct_interest_snapshot"."weight",
3856 CASE WHEN
3857 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
3858 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
3859 THEN 1 ELSE
3860 CASE WHEN
3861 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
3862 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
3863 THEN 2 ELSE
3864 CASE WHEN
3865 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
3866 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
3867 THEN 3 ELSE 4 END
3868 END
3869 END AS "preference",
3870 "opinion"."suggestion_id"
3871 FROM "opinion"
3872 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
3873 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3874 JOIN "direct_interest_snapshot"
3875 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3876 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3877 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
3879 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
3882 CREATE VIEW "battle_participant" AS
3883 SELECT "initiative"."id", "initiative"."issue_id"
3884 FROM "issue" JOIN "initiative"
3885 ON "issue"."id" = "initiative"."issue_id"
3886 WHERE "initiative"."admitted"
3887 UNION ALL
3888 SELECT NULL, "id" AS "issue_id"
3889 FROM "issue";
3891 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
3894 CREATE VIEW "battle_view" AS
3895 SELECT
3896 "issue"."id" AS "issue_id",
3897 "winning_initiative"."id" AS "winning_initiative_id",
3898 "losing_initiative"."id" AS "losing_initiative_id",
3899 sum(
3900 CASE WHEN
3901 coalesce("better_vote"."grade", 0) >
3902 coalesce("worse_vote"."grade", 0)
3903 THEN "direct_voter"."weight" ELSE 0 END
3904 ) AS "count"
3905 FROM "issue"
3906 LEFT JOIN "direct_voter"
3907 ON "issue"."id" = "direct_voter"."issue_id"
3908 JOIN "battle_participant" AS "winning_initiative"
3909 ON "issue"."id" = "winning_initiative"."issue_id"
3910 JOIN "battle_participant" AS "losing_initiative"
3911 ON "issue"."id" = "losing_initiative"."issue_id"
3912 LEFT JOIN "vote" AS "better_vote"
3913 ON "direct_voter"."member_id" = "better_vote"."member_id"
3914 AND "winning_initiative"."id" = "better_vote"."initiative_id"
3915 LEFT JOIN "vote" AS "worse_vote"
3916 ON "direct_voter"."member_id" = "worse_vote"."member_id"
3917 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
3918 WHERE "issue"."state" = 'voting'
3919 AND "issue"."phase_finished" NOTNULL
3920 AND (
3921 "winning_initiative"."id" != "losing_initiative"."id" OR
3922 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
3923 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
3924 GROUP BY
3925 "issue"."id",
3926 "winning_initiative"."id",
3927 "losing_initiative"."id";
3929 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';
3932 CREATE VIEW "expired_session" AS
3933 SELECT * FROM "session" WHERE now() > "expiry";
3935 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
3936 DELETE FROM "session" WHERE "id" = OLD."id";
3938 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
3939 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
3942 CREATE VIEW "expired_token" AS
3943 SELECT * FROM "token" WHERE now() > "expiry" AND NOT (
3944 "token_type" = 'authorization' AND "used" AND EXISTS (
3945 SELECT NULL FROM "token" AS "other"
3946 WHERE "other"."authorization_token_id" = "token"."id" ) );
3948 CREATE RULE "delete" AS ON DELETE TO "expired_token" DO INSTEAD
3949 DELETE FROM "token" WHERE "id" = OLD."id";
3951 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';
3954 CREATE VIEW "unused_snapshot" AS
3955 SELECT "snapshot".* FROM "snapshot"
3956 LEFT JOIN "issue"
3957 ON "snapshot"."id" = "issue"."latest_snapshot_id"
3958 OR "snapshot"."id" = "issue"."admission_snapshot_id"
3959 OR "snapshot"."id" = "issue"."half_freeze_snapshot_id"
3960 OR "snapshot"."id" = "issue"."full_freeze_snapshot_id"
3961 WHERE "issue"."id" ISNULL;
3963 CREATE RULE "delete" AS ON DELETE TO "unused_snapshot" DO INSTEAD
3964 DELETE FROM "snapshot" WHERE "id" = OLD."id";
3966 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)';
3969 CREATE VIEW "open_issue" AS
3970 SELECT * FROM "issue" WHERE "closed" ISNULL;
3972 COMMENT ON VIEW "open_issue" IS 'All open issues';
3975 CREATE VIEW "member_contingent" AS
3976 SELECT
3977 "member"."id" AS "member_id",
3978 "contingent"."polling",
3979 "contingent"."time_frame",
3980 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
3981 (
3982 SELECT count(1) FROM "draft"
3983 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3984 WHERE "draft"."author_id" = "member"."id"
3985 AND "initiative"."polling" = "contingent"."polling"
3986 AND "draft"."created" > now() - "contingent"."time_frame"
3987 ) + (
3988 SELECT count(1) FROM "suggestion"
3989 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
3990 WHERE "suggestion"."author_id" = "member"."id"
3991 AND "contingent"."polling" = FALSE
3992 AND "suggestion"."created" > now() - "contingent"."time_frame"
3993 )
3994 ELSE NULL END AS "text_entry_count",
3995 "contingent"."text_entry_limit",
3996 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
3997 SELECT count(1) FROM "opening_draft" AS "draft"
3998 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3999 WHERE "draft"."author_id" = "member"."id"
4000 AND "initiative"."polling" = "contingent"."polling"
4001 AND "draft"."created" > now() - "contingent"."time_frame"
4002 ) ELSE NULL END AS "initiative_count",
4003 "contingent"."initiative_limit"
4004 FROM "member" CROSS JOIN "contingent";
4006 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
4008 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
4009 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
4012 CREATE VIEW "member_contingent_left" AS
4013 SELECT
4014 "member_id",
4015 "polling",
4016 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
4017 max("initiative_limit" - "initiative_count") AS "initiatives_left"
4018 FROM "member_contingent" GROUP BY "member_id", "polling";
4020 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.';
4023 CREATE VIEW "event_for_notification" AS
4024 SELECT
4025 "member"."id" AS "recipient_id",
4026 "event".*
4027 FROM "member" CROSS JOIN "event"
4028 JOIN "issue" ON "issue"."id" = "event"."issue_id"
4029 JOIN "area" ON "area"."id" = "issue"."area_id"
4030 LEFT JOIN "privilege" ON
4031 "privilege"."member_id" = "member"."id" AND
4032 "privilege"."unit_id" = "area"."unit_id" AND
4033 "privilege"."voting_right" = TRUE
4034 LEFT JOIN "subscription" ON
4035 "subscription"."member_id" = "member"."id" AND
4036 "subscription"."unit_id" = "area"."unit_id"
4037 LEFT JOIN "ignored_area" ON
4038 "ignored_area"."member_id" = "member"."id" AND
4039 "ignored_area"."area_id" = "issue"."area_id"
4040 LEFT JOIN "interest" ON
4041 "interest"."member_id" = "member"."id" AND
4042 "interest"."issue_id" = "event"."issue_id"
4043 LEFT JOIN "supporter" ON
4044 "supporter"."member_id" = "member"."id" AND
4045 "supporter"."initiative_id" = "event"."initiative_id"
4046 WHERE ("privilege"."member_id" NOTNULL OR "subscription"."member_id" NOTNULL)
4047 AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL)
4048 AND (
4049 "event"."event" = 'issue_state_changed'::"event_type" OR
4050 ( "event"."event" = 'initiative_revoked'::"event_type" AND
4051 "supporter"."member_id" NOTNULL ) );
4053 COMMENT ON VIEW "event_for_notification" IS 'Entries of the "event" table which are of interest for a particular notification mail recipient';
4055 COMMENT ON COLUMN "event_for_notification"."recipient_id" IS 'member_id of the recipient of a notification mail';
4058 CREATE VIEW "updated_initiative" AS
4059 SELECT
4060 "supporter"."member_id" AS "recipient_id",
4061 FALSE AS "featured",
4062 "supporter"."initiative_id"
4063 FROM "supporter"
4064 JOIN "initiative" ON "supporter"."initiative_id" = "initiative"."id"
4065 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4066 LEFT JOIN "notification_initiative_sent" AS "sent" ON
4067 "sent"."member_id" = "supporter"."member_id" AND
4068 "sent"."initiative_id" = "supporter"."initiative_id"
4069 LEFT JOIN "ignored_initiative" ON
4070 "ignored_initiative"."member_id" = "supporter"."member_id" AND
4071 "ignored_initiative"."initiative_id" = "supporter"."initiative_id"
4072 WHERE "issue"."state" IN ('admission', 'discussion')
4073 AND "initiative"."revoked" ISNULL
4074 AND "ignored_initiative"."member_id" ISNULL
4075 AND (
4076 EXISTS (
4077 SELECT NULL FROM "draft"
4078 LEFT JOIN "ignored_member" ON
4079 "ignored_member"."member_id" = "supporter"."member_id" AND
4080 "ignored_member"."other_member_id" = "draft"."author_id"
4081 WHERE "draft"."initiative_id" = "supporter"."initiative_id"
4082 AND "draft"."id" > "supporter"."draft_id"
4083 AND "ignored_member"."member_id" ISNULL
4084 ) OR EXISTS (
4085 SELECT NULL FROM "suggestion"
4086 LEFT JOIN "opinion" ON
4087 "opinion"."member_id" = "supporter"."member_id" AND
4088 "opinion"."suggestion_id" = "suggestion"."id"
4089 LEFT JOIN "ignored_member" ON
4090 "ignored_member"."member_id" = "supporter"."member_id" AND
4091 "ignored_member"."other_member_id" = "suggestion"."author_id"
4092 WHERE "suggestion"."initiative_id" = "supporter"."initiative_id"
4093 AND "opinion"."member_id" ISNULL
4094 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4095 AND "ignored_member"."member_id" ISNULL
4096 )
4097 );
4099 COMMENT ON VIEW "updated_initiative" IS 'Helper view for view "updated_or_featured_initiative"';
4102 CREATE FUNCTION "featured_initiative"
4103 ( "recipient_id_p" "member"."id"%TYPE,
4104 "area_id_p" "area"."id"%TYPE )
4105 RETURNS SETOF "initiative"."id"%TYPE
4106 LANGUAGE 'plpgsql' STABLE AS $$
4107 DECLARE
4108 "counter_v" "member"."notification_counter"%TYPE;
4109 "sample_size_v" "member"."notification_sample_size"%TYPE;
4110 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
4111 "match_v" BOOLEAN;
4112 "member_id_v" "member"."id"%TYPE;
4113 "seed_v" TEXT;
4114 "initiative_id_v" "initiative"."id"%TYPE;
4115 BEGIN
4116 SELECT "notification_counter", "notification_sample_size"
4117 INTO "counter_v", "sample_size_v"
4118 FROM "member" WHERE "id" = "recipient_id_p";
4119 IF COALESCE("sample_size_v" <= 0, TRUE) THEN
4120 RETURN;
4121 END IF;
4122 "initiative_id_ary" := '{}';
4123 LOOP
4124 "match_v" := FALSE;
4125 FOR "member_id_v", "seed_v" IN
4126 SELECT * FROM (
4127 SELECT DISTINCT
4128 "supporter"."member_id",
4129 md5(
4130 "recipient_id_p" || '-' ||
4131 "counter_v" || '-' ||
4132 "area_id_p" || '-' ||
4133 "supporter"."member_id"
4134 ) AS "seed"
4135 FROM "supporter"
4136 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
4137 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4138 WHERE "supporter"."member_id" != "recipient_id_p"
4139 AND "issue"."area_id" = "area_id_p"
4140 AND "issue"."state" IN ('admission', 'discussion', 'verification')
4141 ) AS "subquery"
4142 ORDER BY "seed"
4143 LOOP
4144 SELECT "initiative"."id" INTO "initiative_id_v"
4145 FROM "initiative"
4146 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4147 JOIN "area" ON "area"."id" = "issue"."area_id"
4148 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
4149 LEFT JOIN "supporter" AS "self_support" ON
4150 "self_support"."initiative_id" = "initiative"."id" AND
4151 "self_support"."member_id" = "recipient_id_p"
4152 LEFT JOIN "privilege" ON
4153 "privilege"."member_id" = "recipient_id_p" AND
4154 "privilege"."unit_id" = "area"."unit_id" AND
4155 "privilege"."voting_right" = TRUE
4156 LEFT JOIN "subscription" ON
4157 "subscription"."member_id" = "recipient_id_p" AND
4158 "subscription"."unit_id" = "area"."unit_id"
4159 LEFT JOIN "ignored_initiative" ON
4160 "ignored_initiative"."member_id" = "recipient_id_p" AND
4161 "ignored_initiative"."initiative_id" = "initiative"."id"
4162 WHERE "supporter"."member_id" = "member_id_v"
4163 AND "issue"."area_id" = "area_id_p"
4164 AND "issue"."state" IN ('admission', 'discussion', 'verification')
4165 AND "initiative"."revoked" ISNULL
4166 AND "self_support"."member_id" ISNULL
4167 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
4168 AND (
4169 "privilege"."member_id" NOTNULL OR
4170 "subscription"."member_id" NOTNULL )
4171 AND "ignored_initiative"."member_id" ISNULL
4172 AND NOT EXISTS (
4173 SELECT NULL FROM "draft"
4174 JOIN "ignored_member" ON
4175 "ignored_member"."member_id" = "recipient_id_p" AND
4176 "ignored_member"."other_member_id" = "draft"."author_id"
4177 WHERE "draft"."initiative_id" = "initiative"."id"
4178 )
4179 ORDER BY md5("seed_v" || '-' || "initiative"."id")
4180 LIMIT 1;
4181 IF FOUND THEN
4182 "match_v" := TRUE;
4183 RETURN NEXT "initiative_id_v";
4184 IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
4185 RETURN;
4186 END IF;
4187 "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
4188 END IF;
4189 END LOOP;
4190 EXIT WHEN NOT "match_v";
4191 END LOOP;
4192 RETURN;
4193 END;
4194 $$;
4196 COMMENT ON FUNCTION "featured_initiative"
4197 ( "recipient_id_p" "member"."id"%TYPE,
4198 "area_id_p" "area"."id"%TYPE )
4199 IS 'Helper function for view "updated_or_featured_initiative"';
4202 CREATE VIEW "updated_or_featured_initiative" AS
4203 SELECT
4204 "subquery".*,
4205 NOT EXISTS (
4206 SELECT NULL FROM "initiative" AS "better_initiative"
4207 WHERE "better_initiative"."issue_id" = "initiative"."issue_id"
4208 AND
4209 ( COALESCE("better_initiative"."supporter_count", -1),
4210 -"better_initiative"."id" ) >
4211 ( COALESCE("initiative"."supporter_count", -1),
4212 -"initiative"."id" )
4213 ) AS "leading"
4214 FROM (
4215 SELECT * FROM "updated_initiative"
4216 UNION ALL
4217 SELECT
4218 "member"."id" AS "recipient_id",
4219 TRUE AS "featured",
4220 "featured_initiative_id" AS "initiative_id"
4221 FROM "member" CROSS JOIN "area"
4222 CROSS JOIN LATERAL
4223 "featured_initiative"("member"."id", "area"."id") AS "featured_initiative_id"
4224 JOIN "initiative" ON "initiative"."id" = "featured_initiative_id"
4225 ) AS "subquery"
4226 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id";
4228 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';
4230 COMMENT ON COLUMN "updated_or_featured_initiative"."recipient_id" IS '"id" of the member who receives the notification mail';
4231 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")';
4232 COMMENT ON COLUMN "updated_or_featured_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4233 COMMENT ON COLUMN "updated_or_featured_initiative"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
4236 CREATE VIEW "leading_complement_initiative" AS
4237 SELECT * FROM (
4238 SELECT DISTINCT ON ("uf_initiative"."recipient_id", "initiative"."issue_id")
4239 "uf_initiative"."recipient_id",
4240 FALSE AS "featured",
4241 "uf_initiative"."initiative_id",
4242 TRUE AS "leading"
4243 FROM "updated_or_featured_initiative" AS "uf_initiative"
4244 JOIN "initiative" AS "uf_initiative_full" ON
4245 "uf_initiative_full"."id" = "uf_initiative"."initiative_id"
4246 JOIN "initiative" ON
4247 "initiative"."issue_id" = "uf_initiative_full"."issue_id"
4248 WHERE "initiative"."revoked" ISNULL
4249 ORDER BY
4250 "uf_initiative"."recipient_id",
4251 "initiative"."issue_id",
4252 "initiative"."supporter_count" DESC,
4253 "initiative"."id"
4254 ) AS "subquery"
4255 WHERE NOT EXISTS (
4256 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
4257 WHERE "other"."recipient_id" = "subquery"."recipient_id"
4258 AND "other"."initiative_id" = "subquery"."initiative_id"
4259 );
4261 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';
4262 COMMENT ON COLUMN "leading_complement_initiative"."featured" IS 'Always FALSE in this view';
4263 COMMENT ON COLUMN "leading_complement_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4264 COMMENT ON COLUMN "leading_complement_initiative"."leading" IS 'Always TRUE in this view';
4267 CREATE VIEW "unfiltered_initiative_for_notification" AS
4268 SELECT
4269 "subquery".*,
4270 "supporter"."member_id" NOTNULL AS "supported",
4271 CASE WHEN "supporter"."member_id" NOTNULL THEN
4272 EXISTS (
4273 SELECT NULL FROM "draft"
4274 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
4275 AND "draft"."id" > "supporter"."draft_id"
4276 )
4277 ELSE
4278 EXISTS (
4279 SELECT NULL FROM "draft"
4280 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
4281 AND COALESCE("draft"."id" > "sent"."last_draft_id", TRUE)
4282 )
4283 END AS "new_draft",
4284 CASE WHEN "supporter"."member_id" NOTNULL THEN
4285 ( SELECT count(1) FROM "suggestion"
4286 LEFT JOIN "opinion" ON
4287 "opinion"."member_id" = "supporter"."member_id" AND
4288 "opinion"."suggestion_id" = "suggestion"."id"
4289 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
4290 AND "opinion"."member_id" ISNULL
4291 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4292 )
4293 ELSE
4294 ( SELECT count(1) FROM "suggestion"
4295 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
4296 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4297 )
4298 END AS "new_suggestion_count"
4299 FROM (
4300 SELECT * FROM "updated_or_featured_initiative"
4301 UNION ALL
4302 SELECT * FROM "leading_complement_initiative"
4303 ) AS "subquery"
4304 LEFT JOIN "supporter" ON
4305 "supporter"."member_id" = "subquery"."recipient_id" AND
4306 "supporter"."initiative_id" = "subquery"."initiative_id"
4307 LEFT JOIN "notification_initiative_sent" AS "sent" ON
4308 "sent"."member_id" = "subquery"."recipient_id" AND
4309 "sent"."initiative_id" = "subquery"."initiative_id";
4311 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';
4313 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4314 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)';
4315 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")';
4318 CREATE VIEW "initiative_for_notification" AS
4319 SELECT "unfiltered1".*
4320 FROM "unfiltered_initiative_for_notification" "unfiltered1"
4321 JOIN "initiative" AS "initiative1" ON
4322 "initiative1"."id" = "unfiltered1"."initiative_id"
4323 JOIN "issue" AS "issue1" ON "issue1"."id" = "initiative1"."issue_id"
4324 WHERE EXISTS (
4325 SELECT NULL
4326 FROM "unfiltered_initiative_for_notification" "unfiltered2"
4327 JOIN "initiative" AS "initiative2" ON
4328 "initiative2"."id" = "unfiltered2"."initiative_id"
4329 JOIN "issue" AS "issue2" ON "issue2"."id" = "initiative2"."issue_id"
4330 WHERE "unfiltered1"."recipient_id" = "unfiltered2"."recipient_id"
4331 AND "issue1"."area_id" = "issue2"."area_id"
4332 AND ("unfiltered2"."new_draft" OR "unfiltered2"."new_suggestion_count" > 0 )
4333 );
4335 COMMENT ON VIEW "initiative_for_notification" IS 'Initiatives to be included in a scheduled notification mail';
4337 COMMENT ON COLUMN "initiative_for_notification"."recipient_id" IS '"id" of the member who receives the notification mail';
4338 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")';
4339 COMMENT ON COLUMN "initiative_for_notification"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4340 COMMENT ON COLUMN "initiative_for_notification"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
4341 COMMENT ON COLUMN "initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4342 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)';
4343 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")';
4346 CREATE VIEW "scheduled_notification_to_send" AS
4347 SELECT * FROM (
4348 SELECT
4349 "id" AS "recipient_id",
4350 now() - CASE WHEN "notification_dow" ISNULL THEN
4351 ( "notification_sent"::DATE + CASE
4352 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4353 THEN 0 ELSE 1 END
4354 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4355 ELSE
4356 ( "notification_sent"::DATE +
4357 ( 7 + "notification_dow" -
4358 EXTRACT(DOW FROM
4359 ( "notification_sent"::DATE + CASE
4360 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4361 THEN 0 ELSE 1 END
4362 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4363 )::INTEGER
4364 ) % 7 +
4365 CASE
4366 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4367 THEN 0 ELSE 1
4368 END
4369 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4370 END AS "pending"
4371 FROM (
4372 SELECT
4373 "id",
4374 COALESCE("notification_sent", "activated") AS "notification_sent",
4375 "notification_dow",
4376 "notification_hour"
4377 FROM "member_to_notify"
4378 WHERE "notification_hour" NOTNULL
4379 ) AS "subquery1"
4380 ) AS "subquery2"
4381 WHERE "pending" > '0'::INTERVAL;
4383 COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending';
4385 COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail';
4386 COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending';
4389 CREATE VIEW "newsletter_to_send" AS
4390 SELECT
4391 "member"."id" AS "recipient_id",
4392 "newsletter"."id" AS "newsletter_id",
4393 "newsletter"."published"
4394 FROM "newsletter" CROSS JOIN "member_eligible_to_be_notified" AS "member"
4395 LEFT JOIN "privilege" ON
4396 "privilege"."member_id" = "member"."id" AND
4397 "privilege"."unit_id" = "newsletter"."unit_id" AND
4398 "privilege"."voting_right" = TRUE
4399 LEFT JOIN "subscription" ON
4400 "subscription"."member_id" = "member"."id" AND
4401 "subscription"."unit_id" = "newsletter"."unit_id"
4402 WHERE "newsletter"."published" <= now()
4403 AND "newsletter"."sent" ISNULL
4404 AND (
4405 "member"."disable_notifications" = FALSE OR
4406 "newsletter"."include_all_members" = TRUE )
4407 AND (
4408 "newsletter"."unit_id" ISNULL OR
4409 "privilege"."member_id" NOTNULL OR
4410 "subscription"."member_id" NOTNULL );
4412 COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out';
4414 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter was supposed to be sent out (can be used for ordering)';
4418 ------------------------------------------------------
4419 -- Row set returning function for delegation chains --
4420 ------------------------------------------------------
4423 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
4424 ('first', 'intermediate', 'last', 'repetition');
4426 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
4429 CREATE TYPE "delegation_chain_row" AS (
4430 "index" INT4,
4431 "member_id" INT4,
4432 "member_valid" BOOLEAN,
4433 "participation" BOOLEAN,
4434 "overridden" BOOLEAN,
4435 "scope_in" "delegation_scope",
4436 "scope_out" "delegation_scope",
4437 "disabled_out" BOOLEAN,
4438 "loop" "delegation_chain_loop_tag" );
4440 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
4442 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
4443 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest; for area and global delegation chains: always null';
4444 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
4445 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
4446 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
4447 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
4448 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
4451 CREATE FUNCTION "delegation_chain_for_closed_issue"
4452 ( "member_id_p" "member"."id"%TYPE,
4453 "issue_id_p" "issue"."id"%TYPE )
4454 RETURNS SETOF "delegation_chain_row"
4455 LANGUAGE 'plpgsql' STABLE AS $$
4456 DECLARE
4457 "output_row" "delegation_chain_row";
4458 "direct_voter_row" "direct_voter"%ROWTYPE;
4459 "delegating_voter_row" "delegating_voter"%ROWTYPE;
4460 BEGIN
4461 "output_row"."index" := 0;
4462 "output_row"."member_id" := "member_id_p";
4463 "output_row"."member_valid" := TRUE;
4464 "output_row"."participation" := FALSE;
4465 "output_row"."overridden" := FALSE;
4466 "output_row"."disabled_out" := FALSE;
4467 LOOP
4468 SELECT INTO "direct_voter_row" * FROM "direct_voter"
4469 WHERE "issue_id" = "issue_id_p"
4470 AND "member_id" = "output_row"."member_id";
4471 IF "direct_voter_row"."member_id" NOTNULL THEN
4472 "output_row"."participation" := TRUE;
4473 "output_row"."scope_out" := NULL;
4474 "output_row"."disabled_out" := NULL;
4475 RETURN NEXT "output_row";
4476 RETURN;
4477 END IF;
4478 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
4479 WHERE "issue_id" = "issue_id_p"
4480 AND "member_id" = "output_row"."member_id";
4481 IF "delegating_voter_row"."member_id" ISNULL THEN
4482 RETURN;
4483 END IF;
4484 "output_row"."scope_out" := "delegating_voter_row"."scope";
4485 RETURN NEXT "output_row";
4486 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
4487 "output_row"."scope_in" := "output_row"."scope_out";
4488 END LOOP;
4489 END;
4490 $$;
4492 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
4493 ( "member"."id"%TYPE,
4494 "member"."id"%TYPE )
4495 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
4498 CREATE FUNCTION "delegation_chain"
4499 ( "member_id_p" "member"."id"%TYPE,
4500 "unit_id_p" "unit"."id"%TYPE,
4501 "area_id_p" "area"."id"%TYPE,
4502 "issue_id_p" "issue"."id"%TYPE,
4503 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4504 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4505 RETURNS SETOF "delegation_chain_row"
4506 LANGUAGE 'plpgsql' STABLE AS $$
4507 DECLARE
4508 "scope_v" "delegation_scope";
4509 "unit_id_v" "unit"."id"%TYPE;
4510 "area_id_v" "area"."id"%TYPE;
4511 "issue_row" "issue"%ROWTYPE;
4512 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
4513 "loop_member_id_v" "member"."id"%TYPE;
4514 "output_row" "delegation_chain_row";
4515 "output_rows" "delegation_chain_row"[];
4516 "simulate_v" BOOLEAN;
4517 "simulate_here_v" BOOLEAN;
4518 "delegation_row" "delegation"%ROWTYPE;
4519 "row_count" INT4;
4520 "i" INT4;
4521 "loop_v" BOOLEAN;
4522 BEGIN
4523 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
4524 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
4525 END IF;
4526 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
4527 "simulate_v" := TRUE;
4528 ELSE
4529 "simulate_v" := FALSE;
4530 END IF;
4531 IF
4532 "unit_id_p" NOTNULL AND
4533 "area_id_p" ISNULL AND
4534 "issue_id_p" ISNULL
4535 THEN
4536 "scope_v" := 'unit';
4537 "unit_id_v" := "unit_id_p";
4538 ELSIF
4539 "unit_id_p" ISNULL AND
4540 "area_id_p" NOTNULL AND
4541 "issue_id_p" ISNULL
4542 THEN
4543 "scope_v" := 'area';
4544 "area_id_v" := "area_id_p";
4545 SELECT "unit_id" INTO "unit_id_v"
4546 FROM "area" WHERE "id" = "area_id_v";
4547 ELSIF
4548 "unit_id_p" ISNULL AND
4549 "area_id_p" ISNULL AND
4550 "issue_id_p" NOTNULL
4551 THEN
4552 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
4553 IF "issue_row"."id" ISNULL THEN
4554 RETURN;
4555 END IF;
4556 IF "issue_row"."closed" NOTNULL THEN
4557 IF "simulate_v" THEN
4558 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
4559 END IF;
4560 FOR "output_row" IN
4561 SELECT * FROM
4562 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
4563 LOOP
4564 RETURN NEXT "output_row";
4565 END LOOP;
4566 RETURN;
4567 END IF;
4568 "scope_v" := 'issue';
4569 SELECT "area_id" INTO "area_id_v"
4570 FROM "issue" WHERE "id" = "issue_id_p";
4571 SELECT "unit_id" INTO "unit_id_v"
4572 FROM "area" WHERE "id" = "area_id_v";
4573 ELSE
4574 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
4575 END IF;
4576 "visited_member_ids" := '{}';
4577 "loop_member_id_v" := NULL;
4578 "output_rows" := '{}';
4579 "output_row"."index" := 0;
4580 "output_row"."member_id" := "member_id_p";
4581 "output_row"."member_valid" := TRUE;
4582 "output_row"."participation" := FALSE;
4583 "output_row"."overridden" := FALSE;
4584 "output_row"."disabled_out" := FALSE;
4585 "output_row"."scope_out" := NULL;
4586 LOOP
4587 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
4588 "loop_member_id_v" := "output_row"."member_id";
4589 ELSE
4590 "visited_member_ids" :=
4591 "visited_member_ids" || "output_row"."member_id";
4592 END IF;
4593 IF "output_row"."participation" ISNULL THEN
4594 "output_row"."overridden" := NULL;
4595 ELSIF "output_row"."participation" THEN
4596 "output_row"."overridden" := TRUE;
4597 END IF;
4598 "output_row"."scope_in" := "output_row"."scope_out";
4599 "output_row"."member_valid" := EXISTS (
4600 SELECT NULL FROM "member" JOIN "privilege"
4601 ON "privilege"."member_id" = "member"."id"
4602 AND "privilege"."unit_id" = "unit_id_v"
4603 WHERE "id" = "output_row"."member_id"
4604 AND "member"."active" AND "privilege"."voting_right"
4605 );
4606 "simulate_here_v" := (
4607 "simulate_v" AND
4608 "output_row"."member_id" = "member_id_p"
4609 );
4610 "delegation_row" := ROW(NULL);
4611 IF "output_row"."member_valid" OR "simulate_here_v" THEN
4612 IF "scope_v" = 'unit' THEN
4613 IF NOT "simulate_here_v" THEN
4614 SELECT * INTO "delegation_row" FROM "delegation"
4615 WHERE "truster_id" = "output_row"."member_id"
4616 AND "unit_id" = "unit_id_v";
4617 END IF;
4618 ELSIF "scope_v" = 'area' THEN
4619 IF "simulate_here_v" THEN
4620 IF "simulate_trustee_id_p" ISNULL THEN
4621 SELECT * INTO "delegation_row" FROM "delegation"
4622 WHERE "truster_id" = "output_row"."member_id"
4623 AND "unit_id" = "unit_id_v";
4624 END IF;
4625 ELSE
4626 SELECT * INTO "delegation_row" FROM "delegation"
4627 WHERE "truster_id" = "output_row"."member_id"
4628 AND (
4629 "unit_id" = "unit_id_v" OR
4630 "area_id" = "area_id_v"
4631 )
4632 ORDER BY "scope" DESC;
4633 END IF;
4634 ELSIF "scope_v" = 'issue' THEN
4635 IF "issue_row"."fully_frozen" ISNULL THEN
4636 "output_row"."participation" := EXISTS (
4637 SELECT NULL FROM "interest"
4638 WHERE "issue_id" = "issue_id_p"
4639 AND "member_id" = "output_row"."member_id"
4640 );
4641 ELSE
4642 IF "output_row"."member_id" = "member_id_p" THEN
4643 "output_row"."participation" := EXISTS (
4644 SELECT NULL FROM "direct_voter"
4645 WHERE "issue_id" = "issue_id_p"
4646 AND "member_id" = "output_row"."member_id"
4647 );
4648 ELSE
4649 "output_row"."participation" := NULL;
4650 END IF;
4651 END IF;
4652 IF "simulate_here_v" THEN
4653 IF "simulate_trustee_id_p" ISNULL THEN
4654 SELECT * INTO "delegation_row" FROM "delegation"
4655 WHERE "truster_id" = "output_row"."member_id"
4656 AND (
4657 "unit_id" = "unit_id_v" OR
4658 "area_id" = "area_id_v"
4659 )
4660 ORDER BY "scope" DESC;
4661 END IF;
4662 ELSE
4663 SELECT * INTO "delegation_row" FROM "delegation"
4664 WHERE "truster_id" = "output_row"."member_id"
4665 AND (
4666 "unit_id" = "unit_id_v" OR
4667 "area_id" = "area_id_v" OR
4668 "issue_id" = "issue_id_p"
4669 )
4670 ORDER BY "scope" DESC;
4671 END IF;
4672 END IF;
4673 ELSE
4674 "output_row"."participation" := FALSE;
4675 END IF;
4676 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
4677 "output_row"."scope_out" := "scope_v";
4678 "output_rows" := "output_rows" || "output_row";
4679 "output_row"."member_id" := "simulate_trustee_id_p";
4680 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
4681 "output_row"."scope_out" := "delegation_row"."scope";
4682 "output_rows" := "output_rows" || "output_row";
4683 "output_row"."member_id" := "delegation_row"."trustee_id";
4684 ELSIF "delegation_row"."scope" NOTNULL THEN
4685 "output_row"."scope_out" := "delegation_row"."scope";
4686 "output_row"."disabled_out" := TRUE;
4687 "output_rows" := "output_rows" || "output_row";
4688 EXIT;
4689 ELSE
4690 "output_row"."scope_out" := NULL;
4691 "output_rows" := "output_rows" || "output_row";
4692 EXIT;
4693 END IF;
4694 EXIT WHEN "loop_member_id_v" NOTNULL;
4695 "output_row"."index" := "output_row"."index" + 1;
4696 END LOOP;
4697 "row_count" := array_upper("output_rows", 1);
4698 "i" := 1;
4699 "loop_v" := FALSE;
4700 LOOP
4701 "output_row" := "output_rows"["i"];
4702 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
4703 IF "loop_v" THEN
4704 IF "i" + 1 = "row_count" THEN
4705 "output_row"."loop" := 'last';
4706 ELSIF "i" = "row_count" THEN
4707 "output_row"."loop" := 'repetition';
4708 ELSE
4709 "output_row"."loop" := 'intermediate';
4710 END IF;
4711 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
4712 "output_row"."loop" := 'first';
4713 "loop_v" := TRUE;
4714 END IF;
4715 IF "scope_v" = 'unit' THEN
4716 "output_row"."participation" := NULL;
4717 END IF;
4718 RETURN NEXT "output_row";
4719 "i" := "i" + 1;
4720 END LOOP;
4721 RETURN;
4722 END;
4723 $$;
4725 COMMENT ON FUNCTION "delegation_chain"
4726 ( "member"."id"%TYPE,
4727 "unit"."id"%TYPE,
4728 "area"."id"%TYPE,
4729 "issue"."id"%TYPE,
4730 "member"."id"%TYPE,
4731 BOOLEAN )
4732 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
4736 ---------------------------------------------------------
4737 -- Single row returning function for delegation chains --
4738 ---------------------------------------------------------
4741 CREATE TYPE "delegation_info_loop_type" AS ENUM
4742 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
4744 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''';
4747 CREATE TYPE "delegation_info_type" AS (
4748 "own_participation" BOOLEAN,
4749 "own_delegation_scope" "delegation_scope",
4750 "first_trustee_id" INT4,
4751 "first_trustee_participation" BOOLEAN,
4752 "first_trustee_ellipsis" BOOLEAN,
4753 "other_trustee_id" INT4,
4754 "other_trustee_participation" BOOLEAN,
4755 "other_trustee_ellipsis" BOOLEAN,
4756 "delegation_loop" "delegation_info_loop_type",
4757 "participating_member_id" INT4 );
4759 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';
4761 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
4762 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
4763 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
4764 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
4765 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
4766 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
4767 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)';
4768 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
4769 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';
4770 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
4773 CREATE FUNCTION "delegation_info"
4774 ( "member_id_p" "member"."id"%TYPE,
4775 "unit_id_p" "unit"."id"%TYPE,
4776 "area_id_p" "area"."id"%TYPE,
4777 "issue_id_p" "issue"."id"%TYPE,
4778 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4779 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4780 RETURNS "delegation_info_type"
4781 LANGUAGE 'plpgsql' STABLE AS $$
4782 DECLARE
4783 "current_row" "delegation_chain_row";
4784 "result" "delegation_info_type";
4785 BEGIN
4786 "result"."own_participation" := FALSE;
4787 FOR "current_row" IN
4788 SELECT * FROM "delegation_chain"(
4789 "member_id_p",
4790 "unit_id_p", "area_id_p", "issue_id_p",
4791 "simulate_trustee_id_p", "simulate_default_p")
4792 LOOP
4793 IF
4794 "result"."participating_member_id" ISNULL AND
4795 "current_row"."participation"
4796 THEN
4797 "result"."participating_member_id" := "current_row"."member_id";
4798 END IF;
4799 IF "current_row"."member_id" = "member_id_p" THEN
4800 "result"."own_participation" := "current_row"."participation";
4801 "result"."own_delegation_scope" := "current_row"."scope_out";
4802 IF "current_row"."loop" = 'first' THEN
4803 "result"."delegation_loop" := 'own';
4804 END IF;
4805 ELSIF
4806 "current_row"."member_valid" AND
4807 ( "current_row"."loop" ISNULL OR
4808 "current_row"."loop" != 'repetition' )
4809 THEN
4810 IF "result"."first_trustee_id" ISNULL THEN
4811 "result"."first_trustee_id" := "current_row"."member_id";
4812 "result"."first_trustee_participation" := "current_row"."participation";
4813 "result"."first_trustee_ellipsis" := FALSE;
4814 IF "current_row"."loop" = 'first' THEN
4815 "result"."delegation_loop" := 'first';
4816 END IF;
4817 ELSIF "result"."other_trustee_id" ISNULL THEN
4818 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
4819 "result"."other_trustee_id" := "current_row"."member_id";
4820 "result"."other_trustee_participation" := TRUE;
4821 "result"."other_trustee_ellipsis" := FALSE;
4822 IF "current_row"."loop" = 'first' THEN
4823 "result"."delegation_loop" := 'other';
4824 END IF;
4825 ELSE
4826 "result"."first_trustee_ellipsis" := TRUE;
4827 IF "current_row"."loop" = 'first' THEN
4828 "result"."delegation_loop" := 'first_ellipsis';
4829 END IF;
4830 END IF;
4831 ELSE
4832 "result"."other_trustee_ellipsis" := TRUE;
4833 IF "current_row"."loop" = 'first' THEN
4834 "result"."delegation_loop" := 'other_ellipsis';
4835 END IF;
4836 END IF;
4837 END IF;
4838 END LOOP;
4839 RETURN "result";
4840 END;
4841 $$;
4843 COMMENT ON FUNCTION "delegation_info"
4844 ( "member"."id"%TYPE,
4845 "unit"."id"%TYPE,
4846 "area"."id"%TYPE,
4847 "issue"."id"%TYPE,
4848 "member"."id"%TYPE,
4849 BOOLEAN )
4850 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
4854 ------------------------
4855 -- Geospatial lookups --
4856 ------------------------
4858 /*
4859 CREATE FUNCTION "closed_initiatives_in_bounding_box"
4860 ( "bounding_box_p" EBOX,
4861 "limit_p" INT4 )
4862 RETURNS SETOF "initiative"
4863 LANGUAGE 'plpgsql' STABLE AS $$
4864 DECLARE
4865 "limit_v" INT4;
4866 "count_v" INT4;
4867 BEGIN
4868 "limit_v" := "limit_p" + 1;
4869 LOOP
4870 SELECT count(1) INTO "count_v"
4871 FROM "initiative"
4872 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4873 WHERE "issue"."closed" NOTNULL
4874 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4875 LIMIT "limit_v";
4876 IF "count_v" < "limit_v" THEN
4877 RETURN QUERY SELECT "initiative".*
4878 FROM (
4879 SELECT
4880 "initiative"."id" AS "initiative_id",
4881 "issue"."closed"
4882 FROM "initiative"
4883 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4884 WHERE "issue"."closed" NOTNULL
4885 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4886 ) AS "subquery"
4887 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4888 ORDER BY "subquery"."closed" DESC
4889 LIMIT "limit_p";
4890 RETURN;
4891 END IF;
4892 SELECT count(1) INTO "count_v"
4893 FROM (
4894 SELECT "initiative"."id" AS "initiative_id"
4895 FROM "initiative"
4896 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4897 WHERE "issue"."closed" NOTNULL
4898 ORDER BY "closed" DESC
4899 LIMIT "limit_v"
4900 ) AS "subquery"
4901 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4902 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4903 LIMIT "limit_p";
4904 IF "count_v" >= "limit_p" THEN
4905 RETURN QUERY SELECT "initiative".*
4906 FROM (
4907 SELECT
4908 "initiative"."id" AS "initiative_id",
4909 "issue"."closed"
4910 FROM "initiative"
4911 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4912 WHERE "issue"."closed" NOTNULL
4913 ORDER BY "closed" DESC
4914 LIMIT "limit_v"
4915 ) AS "subquery"
4916 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4917 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4918 ORDER BY "subquery"."closed" DESC
4919 LIMIT "limit_p";
4920 RETURN;
4921 END IF;
4922 "limit_v" := "limit_v" * 2;
4923 END LOOP;
4924 END;
4925 $$;
4927 COMMENT ON FUNCTION "closed_initiatives_in_bounding_box"
4928 ( EBOX, INT4 )
4929 IS 'TODO';
4930 */
4934 ---------------------------
4935 -- Transaction isolation --
4936 ---------------------------
4939 CREATE FUNCTION "require_transaction_isolation"()
4940 RETURNS VOID
4941 LANGUAGE 'plpgsql' VOLATILE AS $$
4942 BEGIN
4943 IF
4944 current_setting('transaction_isolation') NOT IN
4945 ('repeatable read', 'serializable')
4946 THEN
4947 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
4948 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
4949 END IF;
4950 RETURN;
4951 END;
4952 $$;
4954 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
4957 CREATE FUNCTION "dont_require_transaction_isolation"()
4958 RETURNS VOID
4959 LANGUAGE 'plpgsql' VOLATILE AS $$
4960 BEGIN
4961 IF
4962 current_setting('transaction_isolation') IN
4963 ('repeatable read', 'serializable')
4964 THEN
4965 RAISE WARNING 'Unneccessary transaction isolation level: %',
4966 current_setting('transaction_isolation');
4967 END IF;
4968 RETURN;
4969 END;
4970 $$;
4972 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
4976 -------------------------
4977 -- Notification system --
4978 -------------------------
4980 CREATE FUNCTION "get_initiatives_for_notification"
4981 ( "recipient_id_p" "member"."id"%TYPE )
4982 RETURNS SETOF "initiative_for_notification"
4983 LANGUAGE 'plpgsql' VOLATILE AS $$
4984 DECLARE
4985 "result_row" "initiative_for_notification"%ROWTYPE;
4986 "last_draft_id_v" "draft"."id"%TYPE;
4987 "last_suggestion_id_v" "suggestion"."id"%TYPE;
4988 BEGIN
4989 PERFORM "require_transaction_isolation"();
4990 PERFORM NULL FROM "member" WHERE "id" = "recipient_id_p" FOR UPDATE;
4991 FOR "result_row" IN
4992 SELECT * FROM "initiative_for_notification"
4993 WHERE "recipient_id" = "recipient_id_p"
4994 LOOP
4995 SELECT "id" INTO "last_draft_id_v" FROM "draft"
4996 WHERE "draft"."initiative_id" = "result_row"."initiative_id"
4997 ORDER BY "id" DESC LIMIT 1;
4998 SELECT "id" INTO "last_suggestion_id_v" FROM "suggestion"
4999 WHERE "suggestion"."initiative_id" = "result_row"."initiative_id"
5000 ORDER BY "id" DESC LIMIT 1;
5001 INSERT INTO "notification_initiative_sent"
5002 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
5003 VALUES (
5004 "recipient_id_p",
5005 "result_row"."initiative_id",
5006 "last_draft_id_v",
5007 "last_suggestion_id_v" )
5008 ON CONFLICT ("member_id", "initiative_id") DO UPDATE SET
5009 "last_draft_id" = "last_draft_id_v",
5010 "last_suggestion_id" = "last_suggestion_id_v";
5011 RETURN NEXT "result_row";
5012 END LOOP;
5013 DELETE FROM "notification_initiative_sent"
5014 USING "initiative", "issue"
5015 WHERE "notification_initiative_sent"."member_id" = "recipient_id_p"
5016 AND "initiative"."id" = "notification_initiative_sent"."initiative_id"
5017 AND "issue"."id" = "initiative"."issue_id"
5018 AND ( "issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL );
5019 UPDATE "member" SET
5020 "notification_counter" = "notification_counter" + 1,
5021 "notification_sent" = now()
5022 WHERE "id" = "recipient_id_p";
5023 RETURN;
5024 END;
5025 $$;
5027 COMMENT ON FUNCTION "get_initiatives_for_notification"
5028 ( "member"."id"%TYPE )
5029 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';
5033 ------------------------------------------------------------------------
5034 -- Regular tasks, except calculcation of snapshots and voting results --
5035 ------------------------------------------------------------------------
5038 CREATE FUNCTION "check_activity"()
5039 RETURNS VOID
5040 LANGUAGE 'plpgsql' VOLATILE AS $$
5041 DECLARE
5042 "system_setting_row" "system_setting"%ROWTYPE;
5043 BEGIN
5044 PERFORM "dont_require_transaction_isolation"();
5045 SELECT * INTO "system_setting_row" FROM "system_setting";
5046 IF "system_setting_row"."member_ttl" NOTNULL THEN
5047 UPDATE "member" SET "active" = FALSE
5048 WHERE "active" = TRUE
5049 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
5050 END IF;
5051 RETURN;
5052 END;
5053 $$;
5055 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
5058 CREATE FUNCTION "calculate_member_counts"()
5059 RETURNS VOID
5060 LANGUAGE 'plpgsql' VOLATILE AS $$
5061 BEGIN
5062 PERFORM "require_transaction_isolation"();
5063 DELETE FROM "member_count";
5064 INSERT INTO "member_count" ("total_count")
5065 SELECT "total_count" FROM "member_count_view";
5066 UPDATE "unit" SET
5067 "member_count" = "view"."member_count",
5068 "member_weight" = "view"."member_weight"
5069 FROM "unit_member_count" AS "view"
5070 WHERE "view"."unit_id" = "unit"."id";
5071 RETURN;
5072 END;
5073 $$;
5075 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"';
5079 ------------------------------------
5080 -- Calculation of harmonic weight --
5081 ------------------------------------
5084 CREATE VIEW "remaining_harmonic_supporter_weight" AS
5085 SELECT
5086 "direct_interest_snapshot"."snapshot_id",
5087 "direct_interest_snapshot"."issue_id",
5088 "direct_interest_snapshot"."member_id",
5089 "direct_interest_snapshot"."weight" AS "weight_num",
5090 count("initiative"."id") AS "weight_den"
5091 FROM "issue"
5092 JOIN "direct_interest_snapshot"
5093 ON "issue"."latest_snapshot_id" = "direct_interest_snapshot"."snapshot_id"
5094 AND "issue"."id" = "direct_interest_snapshot"."issue_id"
5095 JOIN "initiative"
5096 ON "issue"."id" = "initiative"."issue_id"
5097 AND "initiative"."harmonic_weight" ISNULL
5098 JOIN "direct_supporter_snapshot"
5099 ON "issue"."latest_snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
5100 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
5101 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
5102 AND (
5103 "direct_supporter_snapshot"."satisfied" = TRUE OR
5104 coalesce("initiative"."admitted", FALSE) = FALSE
5105 )
5106 GROUP BY
5107 "direct_interest_snapshot"."snapshot_id",
5108 "direct_interest_snapshot"."issue_id",
5109 "direct_interest_snapshot"."member_id",
5110 "direct_interest_snapshot"."weight";
5112 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
5115 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
5116 SELECT
5117 "initiative"."issue_id",
5118 "initiative"."id" AS "initiative_id",
5119 "initiative"."admitted",
5120 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
5121 "remaining_harmonic_supporter_weight"."weight_den"
5122 FROM "remaining_harmonic_supporter_weight"
5123 JOIN "initiative"
5124 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
5125 AND "initiative"."harmonic_weight" ISNULL
5126 JOIN "direct_supporter_snapshot"
5127 ON "remaining_harmonic_supporter_weight"."snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
5128 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
5129 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
5130 AND (
5131 "direct_supporter_snapshot"."satisfied" = TRUE OR
5132 coalesce("initiative"."admitted", FALSE) = FALSE
5133 )
5134 GROUP BY
5135 "initiative"."issue_id",
5136 "initiative"."id",
5137 "initiative"."admitted",
5138 "remaining_harmonic_supporter_weight"."weight_den";
5140 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
5143 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
5144 SELECT
5145 "issue_id",
5146 "id" AS "initiative_id",
5147 "admitted",
5148 0 AS "weight_num",
5149 1 AS "weight_den"
5150 FROM "initiative"
5151 WHERE "harmonic_weight" ISNULL;
5153 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';
5156 CREATE FUNCTION "set_harmonic_initiative_weights"
5157 ( "issue_id_p" "issue"."id"%TYPE )
5158 RETURNS VOID
5159 LANGUAGE 'plpgsql' VOLATILE AS $$
5160 DECLARE
5161 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
5162 "i" INT4;
5163 "count_v" INT4;
5164 "summand_v" FLOAT;
5165 "id_ary" INT4[];
5166 "weight_ary" FLOAT[];
5167 "min_weight_v" FLOAT;
5168 BEGIN
5169 PERFORM "require_transaction_isolation"();
5170 UPDATE "initiative" SET "harmonic_weight" = NULL
5171 WHERE "issue_id" = "issue_id_p";
5172 LOOP
5173 "min_weight_v" := NULL;
5174 "i" := 0;
5175 "count_v" := 0;
5176 FOR "weight_row" IN
5177 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
5178 WHERE "issue_id" = "issue_id_p"
5179 AND (
5180 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
5181 SELECT NULL FROM "initiative"
5182 WHERE "issue_id" = "issue_id_p"
5183 AND "harmonic_weight" ISNULL
5184 AND coalesce("admitted", FALSE) = FALSE
5185 )
5186 )
5187 UNION ALL -- needed for corner cases
5188 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
5189 WHERE "issue_id" = "issue_id_p"
5190 AND (
5191 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
5192 SELECT NULL FROM "initiative"
5193 WHERE "issue_id" = "issue_id_p"
5194 AND "harmonic_weight" ISNULL
5195 AND coalesce("admitted", FALSE) = FALSE
5196 )
5197 )
5198 ORDER BY "initiative_id" DESC, "weight_den" DESC
5199 -- NOTE: non-admitted initiatives placed first (at last positions),
5200 -- latest initiatives treated worse in case of tie
5201 LOOP
5202 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
5203 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
5204 "i" := "i" + 1;
5205 "count_v" := "i";
5206 "id_ary"["i"] := "weight_row"."initiative_id";
5207 "weight_ary"["i"] := "summand_v";
5208 ELSE
5209 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
5210 END IF;
5211 END LOOP;
5212 EXIT WHEN "count_v" = 0;
5213 "i" := 1;
5214 LOOP
5215 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
5216 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
5217 "min_weight_v" := "weight_ary"["i"];
5218 END IF;
5219 "i" := "i" + 1;
5220 EXIT WHEN "i" > "count_v";
5221 END LOOP;
5222 "i" := 1;
5223 LOOP
5224 IF "weight_ary"["i"] = "min_weight_v" THEN
5225 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
5226 WHERE "id" = "id_ary"["i"];
5227 EXIT;
5228 END IF;
5229 "i" := "i" + 1;
5230 END LOOP;
5231 END LOOP;
5232 UPDATE "initiative" SET "harmonic_weight" = 0
5233 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
5234 END;
5235 $$;
5237 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
5238 ( "issue"."id"%TYPE )
5239 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
5243 ------------------------------
5244 -- Calculation of snapshots --
5245 ------------------------------
5248 CREATE FUNCTION "weight_of_added_delegations_for_snapshot"
5249 ( "snapshot_id_p" "snapshot"."id"%TYPE,
5250 "issue_id_p" "issue"."id"%TYPE,
5251 "member_id_p" "member"."id"%TYPE,
5252 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
5253 RETURNS "direct_interest_snapshot"."weight"%TYPE
5254 LANGUAGE 'plpgsql' VOLATILE AS $$
5255 DECLARE
5256 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5257 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
5258 "weight_v" INT4;
5259 "sub_weight_v" INT4;
5260 BEGIN
5261 PERFORM "require_transaction_isolation"();
5262 "weight_v" := 0;
5263 FOR "issue_delegation_row" IN
5264 SELECT * FROM "issue_delegation"
5265 WHERE "trustee_id" = "member_id_p"
5266 AND "issue_id" = "issue_id_p"
5267 LOOP
5268 IF NOT EXISTS (
5269 SELECT NULL FROM "direct_interest_snapshot"
5270 WHERE "snapshot_id" = "snapshot_id_p"
5271 AND "issue_id" = "issue_id_p"
5272 AND "member_id" = "issue_delegation_row"."truster_id"
5273 ) AND NOT EXISTS (
5274 SELECT NULL FROM "delegating_interest_snapshot"
5275 WHERE "snapshot_id" = "snapshot_id_p"
5276 AND "issue_id" = "issue_id_p"
5277 AND "member_id" = "issue_delegation_row"."truster_id"
5278 ) THEN
5279 "delegate_member_ids_v" :=
5280 "member_id_p" || "delegate_member_ids_p";
5281 INSERT INTO "delegating_interest_snapshot" (
5282 "snapshot_id",
5283 "issue_id",
5284 "member_id",
5285 "ownweight",
5286 "scope",
5287 "delegate_member_ids"
5288 ) VALUES (
5289 "snapshot_id_p",
5290 "issue_id_p",
5291 "issue_delegation_row"."truster_id",
5292 "issue_delegation_row"."weight",
5293 "issue_delegation_row"."scope",
5294 "delegate_member_ids_v"
5295 );
5296 "sub_weight_v" := "issue_delegation_row"."weight" +
5297 "weight_of_added_delegations_for_snapshot"(
5298 "snapshot_id_p",
5299 "issue_id_p",
5300 "issue_delegation_row"."truster_id",
5301 "delegate_member_ids_v"
5302 );
5303 UPDATE "delegating_interest_snapshot"
5304 SET "weight" = "sub_weight_v"
5305 WHERE "snapshot_id" = "snapshot_id_p"
5306 AND "issue_id" = "issue_id_p"
5307 AND "member_id" = "issue_delegation_row"."truster_id";
5308 "weight_v" := "weight_v" + "sub_weight_v";
5309 END IF;
5310 END LOOP;
5311 RETURN "weight_v";
5312 END;
5313 $$;
5315 COMMENT ON FUNCTION "weight_of_added_delegations_for_snapshot"
5316 ( "snapshot"."id"%TYPE,
5317 "issue"."id"%TYPE,
5318 "member"."id"%TYPE,
5319 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
5320 IS 'Helper function for "fill_snapshot" function';
5323 CREATE FUNCTION "take_snapshot"
5324 ( "issue_id_p" "issue"."id"%TYPE,
5325 "area_id_p" "area"."id"%TYPE = NULL )
5326 RETURNS "snapshot"."id"%TYPE
5327 LANGUAGE 'plpgsql' VOLATILE AS $$
5328 DECLARE
5329 "area_id_v" "area"."id"%TYPE;
5330 "unit_id_v" "unit"."id"%TYPE;
5331 "snapshot_id_v" "snapshot"."id"%TYPE;
5332 "issue_id_v" "issue"."id"%TYPE;
5333 "member_id_v" "member"."id"%TYPE;
5334 BEGIN
5335 IF "issue_id_p" NOTNULL AND "area_id_p" NOTNULL THEN
5336 RAISE EXCEPTION 'One of "issue_id_p" and "area_id_p" must be NULL';
5337 END IF;
5338 PERFORM "require_transaction_isolation"();
5339 IF "issue_id_p" ISNULL THEN
5340 "area_id_v" := "area_id_p";
5341 ELSE
5342 SELECT "area_id" INTO "area_id_v"
5343 FROM "issue" WHERE "id" = "issue_id_p";
5344 END IF;
5345 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5346 INSERT INTO "snapshot" ("area_id", "issue_id")
5347 VALUES ("area_id_v", "issue_id_p")
5348 RETURNING "id" INTO "snapshot_id_v";
5349 INSERT INTO "snapshot_population" ("snapshot_id", "member_id", "weight")
5350 SELECT "snapshot_id_v", "member_id", "weight"
5351 FROM "unit_member" WHERE "unit_id" = "unit_id_v";
5352 UPDATE "snapshot" SET
5353 "population" = (
5354 SELECT sum("weight") FROM "snapshot_population"
5355 WHERE "snapshot_id" = "snapshot_id_v"
5356 ) WHERE "id" = "snapshot_id_v";
5357 FOR "issue_id_v" IN
5358 SELECT "id" FROM "issue"
5359 WHERE CASE WHEN "issue_id_p" ISNULL THEN
5360 "area_id" = "area_id_p" AND
5361 "state" = 'admission'
5362 ELSE
5363 "id" = "issue_id_p"
5364 END
5365 LOOP
5366 INSERT INTO "snapshot_issue" ("snapshot_id", "issue_id")
5367 VALUES ("snapshot_id_v", "issue_id_v");
5368 INSERT INTO "direct_interest_snapshot"
5369 ("snapshot_id", "issue_id", "member_id", "ownweight")
5370 SELECT
5371 "snapshot_id_v" AS "snapshot_id",
5372 "issue_id_v" AS "issue_id",
5373 "member"."id" AS "member_id",
5374 "privilege"."weight" AS "ownweight"
5375 FROM "issue"
5376 JOIN "area" ON "issue"."area_id" = "area"."id"
5377 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
5378 JOIN "member" ON "interest"."member_id" = "member"."id"
5379 JOIN "privilege"
5380 ON "privilege"."unit_id" = "area"."unit_id"
5381 AND "privilege"."member_id" = "member"."id"
5382 WHERE "issue"."id" = "issue_id_v"
5383 AND "member"."active" AND "privilege"."voting_right";
5384 FOR "member_id_v" IN
5385 SELECT "member_id" FROM "direct_interest_snapshot"
5386 WHERE "snapshot_id" = "snapshot_id_v"
5387 AND "issue_id" = "issue_id_v"
5388 LOOP
5389 UPDATE "direct_interest_snapshot" SET
5390 "weight" = "ownweight" +
5391 "weight_of_added_delegations_for_snapshot"(
5392 "snapshot_id_v",
5393 "issue_id_v",
5394 "member_id_v",
5395 '{}'
5396 )
5397 WHERE "snapshot_id" = "snapshot_id_v"
5398 AND "issue_id" = "issue_id_v"
5399 AND "member_id" = "member_id_v";
5400 END LOOP;
5401 INSERT INTO "direct_supporter_snapshot"
5402 ( "snapshot_id", "issue_id", "initiative_id", "member_id",
5403 "draft_id", "informed", "satisfied" )
5404 SELECT
5405 "snapshot_id_v" AS "snapshot_id",
5406 "issue_id_v" AS "issue_id",
5407 "initiative"."id" AS "initiative_id",
5408 "supporter"."member_id" AS "member_id",
5409 "supporter"."draft_id" AS "draft_id",
5410 "supporter"."draft_id" = "current_draft"."id" AS "informed",
5411 NOT EXISTS (
5412 SELECT NULL FROM "critical_opinion"
5413 WHERE "initiative_id" = "initiative"."id"
5414 AND "member_id" = "supporter"."member_id"
5415 ) AS "satisfied"
5416 FROM "initiative"
5417 JOIN "supporter"
5418 ON "supporter"."initiative_id" = "initiative"."id"
5419 JOIN "current_draft"
5420 ON "initiative"."id" = "current_draft"."initiative_id"
5421 JOIN "direct_interest_snapshot"
5422 ON "snapshot_id_v" = "direct_interest_snapshot"."snapshot_id"
5423 AND "supporter"."member_id" = "direct_interest_snapshot"."member_id"
5424 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
5425 WHERE "initiative"."issue_id" = "issue_id_v";
5426 DELETE FROM "temporary_suggestion_counts";
5427 INSERT INTO "temporary_suggestion_counts"
5428 ( "id",
5429 "minus2_unfulfilled_count", "minus2_fulfilled_count",
5430 "minus1_unfulfilled_count", "minus1_fulfilled_count",
5431 "plus1_unfulfilled_count", "plus1_fulfilled_count",
5432 "plus2_unfulfilled_count", "plus2_fulfilled_count" )
5433 SELECT
5434 "suggestion"."id",
5435 ( SELECT coalesce(sum("di"."weight"), 0)
5436 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5437 ON "di"."snapshot_id" = "snapshot_id_v"
5438 AND "di"."issue_id" = "issue_id_v"
5439 AND "di"."member_id" = "opinion"."member_id"
5440 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5441 AND "opinion"."degree" = -2
5442 AND "opinion"."fulfilled" = FALSE
5443 ) AS "minus2_unfulfilled_count",
5444 ( SELECT coalesce(sum("di"."weight"), 0)
5445 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5446 ON "di"."snapshot_id" = "snapshot_id_v"
5447 AND "di"."issue_id" = "issue_id_v"
5448 AND "di"."member_id" = "opinion"."member_id"
5449 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5450 AND "opinion"."degree" = -2
5451 AND "opinion"."fulfilled" = TRUE
5452 ) AS "minus2_fulfilled_count",
5453 ( SELECT coalesce(sum("di"."weight"), 0)
5454 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5455 ON "di"."snapshot_id" = "snapshot_id_v"
5456 AND "di"."issue_id" = "issue_id_v"
5457 AND "di"."member_id" = "opinion"."member_id"
5458 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5459 AND "opinion"."degree" = -1
5460 AND "opinion"."fulfilled" = FALSE
5461 ) AS "minus1_unfulfilled_count",
5462 ( SELECT coalesce(sum("di"."weight"), 0)
5463 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5464 ON "di"."snapshot_id" = "snapshot_id_v"
5465 AND "di"."issue_id" = "issue_id_v"
5466 AND "di"."member_id" = "opinion"."member_id"
5467 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5468 AND "opinion"."degree" = -1
5469 AND "opinion"."fulfilled" = TRUE
5470 ) AS "minus1_fulfilled_count",
5471 ( SELECT coalesce(sum("di"."weight"), 0)
5472 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5473 ON "di"."snapshot_id" = "snapshot_id_v"
5474 AND "di"."issue_id" = "issue_id_v"
5475 AND "di"."member_id" = "opinion"."member_id"
5476 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5477 AND "opinion"."degree" = 1
5478 AND "opinion"."fulfilled" = FALSE
5479 ) AS "plus1_unfulfilled_count",
5480 ( SELECT coalesce(sum("di"."weight"), 0)
5481 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5482 ON "di"."snapshot_id" = "snapshot_id_v"
5483 AND "di"."issue_id" = "issue_id_v"
5484 AND "di"."member_id" = "opinion"."member_id"
5485 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5486 AND "opinion"."degree" = 1
5487 AND "opinion"."fulfilled" = TRUE
5488 ) AS "plus1_fulfilled_count",
5489 ( SELECT coalesce(sum("di"."weight"), 0)
5490 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5491 ON "di"."snapshot_id" = "snapshot_id_v"
5492 AND "di"."issue_id" = "issue_id_v"
5493 AND "di"."member_id" = "opinion"."member_id"
5494 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5495 AND "opinion"."degree" = 2
5496 AND "opinion"."fulfilled" = FALSE
5497 ) AS "plus2_unfulfilled_count",
5498 ( SELECT coalesce(sum("di"."weight"), 0)
5499 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5500 ON "di"."snapshot_id" = "snapshot_id_v"
5501 AND "di"."issue_id" = "issue_id_v"
5502 AND "di"."member_id" = "opinion"."member_id"
5503 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5504 AND "opinion"."degree" = 2
5505 AND "opinion"."fulfilled" = TRUE
5506 ) AS "plus2_fulfilled_count"
5507 FROM "suggestion" JOIN "initiative"
5508 ON "suggestion"."initiative_id" = "initiative"."id"
5509 WHERE "initiative"."issue_id" = "issue_id_v";
5510 END LOOP;
5511 RETURN "snapshot_id_v";
5512 END;
5513 $$;
5515 COMMENT ON FUNCTION "take_snapshot"
5516 ( "issue"."id"%TYPE,
5517 "area"."id"%TYPE )
5518 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.';
5521 CREATE FUNCTION "finish_snapshot"
5522 ( "issue_id_p" "issue"."id"%TYPE )
5523 RETURNS VOID
5524 LANGUAGE 'plpgsql' VOLATILE AS $$
5525 DECLARE
5526 "snapshot_id_v" "snapshot"."id"%TYPE;
5527 BEGIN
5528 -- NOTE: function does not require snapshot isolation but we don't call
5529 -- "dont_require_snapshot_isolation" here because this function is
5530 -- also invoked by "check_issue"
5531 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
5532 SELECT "id" INTO "snapshot_id_v" FROM "snapshot"
5533 ORDER BY "id" DESC LIMIT 1;
5534 UPDATE "issue" SET
5535 "calculated" = "snapshot"."calculated",
5536 "latest_snapshot_id" = "snapshot_id_v",
5537 "population" = "snapshot"."population",
5538 "initiative_quorum" = CASE WHEN
5539 "policy"."initiative_quorum" > ceil(
5540 ( "issue"."population"::INT8 *
5541 "policy"."initiative_quorum_num"::INT8 ) /
5542 "policy"."initiative_quorum_den"::FLOAT8
5543 )::INT4
5544 THEN
5545 "policy"."initiative_quorum"
5546 ELSE
5547 ceil(
5548 ( "issue"."population"::INT8 *
5549 "policy"."initiative_quorum_num"::INT8 ) /
5550 "policy"."initiative_quorum_den"::FLOAT8
5551 )::INT4
5552 END
5553 FROM "snapshot", "policy"
5554 WHERE "issue"."id" = "issue_id_p"
5555 AND "snapshot"."id" = "snapshot_id_v"
5556 AND "policy"."id" = "issue"."policy_id";
5557 UPDATE "initiative" SET
5558 "supporter_count" = (
5559 SELECT coalesce(sum("di"."weight"), 0)
5560 FROM "direct_interest_snapshot" AS "di"
5561 JOIN "direct_supporter_snapshot" AS "ds"
5562 ON "di"."member_id" = "ds"."member_id"
5563 WHERE "di"."snapshot_id" = "snapshot_id_v"
5564 AND "di"."issue_id" = "issue_id_p"
5565 AND "ds"."snapshot_id" = "snapshot_id_v"
5566 AND "ds"."initiative_id" = "initiative"."id"
5567 ),
5568 "informed_supporter_count" = (
5569 SELECT coalesce(sum("di"."weight"), 0)
5570 FROM "direct_interest_snapshot" AS "di"
5571 JOIN "direct_supporter_snapshot" AS "ds"
5572 ON "di"."member_id" = "ds"."member_id"
5573 WHERE "di"."snapshot_id" = "snapshot_id_v"
5574 AND "di"."issue_id" = "issue_id_p"
5575 AND "ds"."snapshot_id" = "snapshot_id_v"
5576 AND "ds"."initiative_id" = "initiative"."id"
5577 AND "ds"."informed"
5578 ),
5579 "satisfied_supporter_count" = (
5580 SELECT coalesce(sum("di"."weight"), 0)
5581 FROM "direct_interest_snapshot" AS "di"
5582 JOIN "direct_supporter_snapshot" AS "ds"
5583 ON "di"."member_id" = "ds"."member_id"
5584 WHERE "di"."snapshot_id" = "snapshot_id_v"
5585 AND "di"."issue_id" = "issue_id_p"
5586 AND "ds"."snapshot_id" = "snapshot_id_v"
5587 AND "ds"."initiative_id" = "initiative"."id"
5588 AND "ds"."satisfied"
5589 ),
5590 "satisfied_informed_supporter_count" = (
5591 SELECT coalesce(sum("di"."weight"), 0)
5592 FROM "direct_interest_snapshot" AS "di"
5593 JOIN "direct_supporter_snapshot" AS "ds"
5594 ON "di"."member_id" = "ds"."member_id"
5595 WHERE "di"."snapshot_id" = "snapshot_id_v"
5596 AND "di"."issue_id" = "issue_id_p"
5597 AND "ds"."snapshot_id" = "snapshot_id_v"
5598 AND "ds"."initiative_id" = "initiative"."id"
5599 AND "ds"."informed"
5600 AND "ds"."satisfied"
5601 )
5602 WHERE "issue_id" = "issue_id_p";
5603 UPDATE "suggestion" SET
5604 "minus2_unfulfilled_count" = "temp"."minus2_unfulfilled_count",
5605 "minus2_fulfilled_count" = "temp"."minus2_fulfilled_count",
5606 "minus1_unfulfilled_count" = "temp"."minus1_unfulfilled_count",
5607 "minus1_fulfilled_count" = "temp"."minus1_fulfilled_count",
5608 "plus1_unfulfilled_count" = "temp"."plus1_unfulfilled_count",
5609 "plus1_fulfilled_count" = "temp"."plus1_fulfilled_count",
5610 "plus2_unfulfilled_count" = "temp"."plus2_unfulfilled_count",
5611 "plus2_fulfilled_count" = "temp"."plus2_fulfilled_count"
5612 FROM "temporary_suggestion_counts" AS "temp", "initiative"
5613 WHERE "temp"."id" = "suggestion"."id"
5614 AND "initiative"."issue_id" = "issue_id_p"
5615 AND "suggestion"."initiative_id" = "initiative"."id";
5616 DELETE FROM "temporary_suggestion_counts";
5617 RETURN;
5618 END;
5619 $$;
5621 COMMENT ON FUNCTION "finish_snapshot"
5622 ( "issue"."id"%TYPE )
5623 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)';
5627 -----------------------
5628 -- Counting of votes --
5629 -----------------------
5632 CREATE FUNCTION "weight_of_added_vote_delegations"
5633 ( "issue_id_p" "issue"."id"%TYPE,
5634 "member_id_p" "member"."id"%TYPE,
5635 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
5636 RETURNS "direct_voter"."weight"%TYPE
5637 LANGUAGE 'plpgsql' VOLATILE AS $$
5638 DECLARE
5639 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5640 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
5641 "weight_v" INT4;
5642 "sub_weight_v" INT4;
5643 BEGIN
5644 PERFORM "require_transaction_isolation"();
5645 "weight_v" := 0;
5646 FOR "issue_delegation_row" IN
5647 SELECT * FROM "issue_delegation"
5648 WHERE "trustee_id" = "member_id_p"
5649 AND "issue_id" = "issue_id_p"
5650 LOOP
5651 IF NOT EXISTS (
5652 SELECT NULL FROM "direct_voter"
5653 WHERE "member_id" = "issue_delegation_row"."truster_id"
5654 AND "issue_id" = "issue_id_p"
5655 ) AND NOT EXISTS (
5656 SELECT NULL FROM "delegating_voter"
5657 WHERE "member_id" = "issue_delegation_row"."truster_id"
5658 AND "issue_id" = "issue_id_p"
5659 ) THEN
5660 "delegate_member_ids_v" :=
5661 "member_id_p" || "delegate_member_ids_p";
5662 INSERT INTO "delegating_voter" (
5663 "issue_id",
5664 "member_id",
5665 "ownweight",
5666 "scope",
5667 "delegate_member_ids"
5668 ) VALUES (
5669 "issue_id_p",
5670 "issue_delegation_row"."truster_id",
5671 "issue_delegation_row"."weight",
5672 "issue_delegation_row"."scope",
5673 "delegate_member_ids_v"
5674 );
5675 "sub_weight_v" := "issue_delegation_row"."weight" +
5676 "weight_of_added_vote_delegations"(
5677 "issue_id_p",
5678 "issue_delegation_row"."truster_id",
5679 "delegate_member_ids_v"
5680 );
5681 UPDATE "delegating_voter"
5682 SET "weight" = "sub_weight_v"
5683 WHERE "issue_id" = "issue_id_p"
5684 AND "member_id" = "issue_delegation_row"."truster_id";
5685 "weight_v" := "weight_v" + "sub_weight_v";
5686 END IF;
5687 END LOOP;
5688 RETURN "weight_v";
5689 END;
5690 $$;
5692 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
5693 ( "issue"."id"%TYPE,
5694 "member"."id"%TYPE,
5695 "delegating_voter"."delegate_member_ids"%TYPE )
5696 IS 'Helper function for "add_vote_delegations" function';
5699 CREATE FUNCTION "add_vote_delegations"
5700 ( "issue_id_p" "issue"."id"%TYPE )
5701 RETURNS VOID
5702 LANGUAGE 'plpgsql' VOLATILE AS $$
5703 DECLARE
5704 "member_id_v" "member"."id"%TYPE;
5705 BEGIN
5706 PERFORM "require_transaction_isolation"();
5707 FOR "member_id_v" IN
5708 SELECT "member_id" FROM "direct_voter"
5709 WHERE "issue_id" = "issue_id_p"
5710 LOOP
5711 UPDATE "direct_voter" SET
5712 "weight" = "ownweight" + "weight_of_added_vote_delegations"(
5713 "issue_id_p",
5714 "member_id_v",
5715 '{}'
5716 )
5717 WHERE "member_id" = "member_id_v"
5718 AND "issue_id" = "issue_id_p";
5719 END LOOP;
5720 RETURN;
5721 END;
5722 $$;
5724 COMMENT ON FUNCTION "add_vote_delegations"
5725 ( "issue_id_p" "issue"."id"%TYPE )
5726 IS 'Helper function for "close_voting" function';
5729 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
5730 RETURNS VOID
5731 LANGUAGE 'plpgsql' VOLATILE AS $$
5732 DECLARE
5733 "area_id_v" "area"."id"%TYPE;
5734 "unit_id_v" "unit"."id"%TYPE;
5735 "member_id_v" "member"."id"%TYPE;
5736 BEGIN
5737 PERFORM "require_transaction_isolation"();
5738 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
5739 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5740 -- override protection triggers:
5741 INSERT INTO "temporary_transaction_data" ("key", "value")
5742 VALUES ('override_protection_triggers', TRUE::TEXT);
5743 -- delete timestamp of voting comment:
5744 UPDATE "direct_voter" SET "comment_changed" = NULL
5745 WHERE "issue_id" = "issue_id_p";
5746 -- delete delegating votes (in cases of manual reset of issue state):
5747 DELETE FROM "delegating_voter"
5748 WHERE "issue_id" = "issue_id_p";
5749 -- delete votes from non-privileged voters:
5750 DELETE FROM "direct_voter"
5751 USING (
5752 SELECT "direct_voter"."member_id"
5753 FROM "direct_voter"
5754 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
5755 LEFT JOIN "privilege"
5756 ON "privilege"."unit_id" = "unit_id_v"
5757 AND "privilege"."member_id" = "direct_voter"."member_id"
5758 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
5759 "member"."active" = FALSE OR
5760 "privilege"."voting_right" ISNULL OR
5761 "privilege"."voting_right" = FALSE
5762 )
5763 ) AS "subquery"
5764 WHERE "direct_voter"."issue_id" = "issue_id_p"
5765 AND "direct_voter"."member_id" = "subquery"."member_id";
5766 -- consider voting weight and delegations:
5767 UPDATE "direct_voter" SET "ownweight" = "privilege"."weight"
5768 FROM "privilege"
5769 WHERE "issue_id" = "issue_id_p"
5770 AND "privilege"."unit_id" = "unit_id_v"
5771 AND "privilege"."member_id" = "direct_voter"."member_id";
5772 PERFORM "add_vote_delegations"("issue_id_p");
5773 -- mark first preferences:
5774 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
5775 FROM (
5776 SELECT
5777 "vote"."initiative_id",
5778 "vote"."member_id",
5779 CASE WHEN "vote"."grade" > 0 THEN
5780 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
5781 ELSE NULL
5782 END AS "first_preference"
5783 FROM "vote"
5784 JOIN "initiative" -- NOTE: due to missing index on issue_id
5785 ON "vote"."issue_id" = "initiative"."issue_id"
5786 JOIN "vote" AS "agg"
5787 ON "initiative"."id" = "agg"."initiative_id"
5788 AND "vote"."member_id" = "agg"."member_id"
5789 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
5790 ) AS "subquery"
5791 WHERE "vote"."issue_id" = "issue_id_p"
5792 AND "vote"."initiative_id" = "subquery"."initiative_id"
5793 AND "vote"."member_id" = "subquery"."member_id";
5794 -- finish overriding protection triggers (avoids garbage):
5795 DELETE FROM "temporary_transaction_data"
5796 WHERE "key" = 'override_protection_triggers';
5797 -- materialize battle_view:
5798 -- NOTE: "closed" column of issue must be set at this point
5799 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
5800 INSERT INTO "battle" (
5801 "issue_id",
5802 "winning_initiative_id", "losing_initiative_id",
5803 "count"
5804 ) SELECT
5805 "issue_id",
5806 "winning_initiative_id", "losing_initiative_id",
5807 "count"
5808 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
5809 -- set voter count:
5810 UPDATE "issue" SET
5811 "voter_count" = (
5812 SELECT coalesce(sum("weight"), 0)
5813 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
5814 )
5815 WHERE "id" = "issue_id_p";
5816 -- copy "positive_votes" and "negative_votes" from "battle" table:
5817 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
5818 UPDATE "initiative" SET
5819 "first_preference_votes" = 0,
5820 "positive_votes" = "battle_win"."count",
5821 "negative_votes" = "battle_lose"."count"
5822 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
5823 WHERE
5824 "battle_win"."issue_id" = "issue_id_p" AND
5825 "battle_win"."winning_initiative_id" = "initiative"."id" AND
5826 "battle_win"."losing_initiative_id" ISNULL AND
5827 "battle_lose"."issue_id" = "issue_id_p" AND
5828 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
5829 "battle_lose"."winning_initiative_id" ISNULL;
5830 -- calculate "first_preference_votes":
5831 -- NOTE: will only set values not equal to zero
5832 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
5833 FROM (
5834 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
5835 FROM "vote" JOIN "direct_voter"
5836 ON "vote"."issue_id" = "direct_voter"."issue_id"
5837 AND "vote"."member_id" = "direct_voter"."member_id"
5838 WHERE "vote"."first_preference"
5839 GROUP BY "vote"."initiative_id"
5840 ) AS "subquery"
5841 WHERE "initiative"."issue_id" = "issue_id_p"
5842 AND "initiative"."admitted"
5843 AND "initiative"."id" = "subquery"."initiative_id";
5844 END;
5845 $$;
5847 COMMENT ON FUNCTION "close_voting"
5848 ( "issue"."id"%TYPE )
5849 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.';
5852 CREATE FUNCTION "defeat_strength"
5853 ( "positive_votes_p" INT4,
5854 "negative_votes_p" INT4,
5855 "defeat_strength_p" "defeat_strength" )
5856 RETURNS INT8
5857 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5858 BEGIN
5859 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
5860 IF "positive_votes_p" > "negative_votes_p" THEN
5861 RETURN "positive_votes_p";
5862 ELSE
5863 RETURN 0;
5864 END IF;
5865 ELSE
5866 IF "positive_votes_p" > "negative_votes_p" THEN
5867 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
5868 ELSIF "positive_votes_p" = "negative_votes_p" THEN
5869 RETURN 0;
5870 ELSE
5871 RETURN -1;
5872 END IF;
5873 END IF;
5874 END;
5875 $$;
5877 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")';
5880 CREATE FUNCTION "secondary_link_strength"
5881 ( "initiative1_ord_p" INT4,
5882 "initiative2_ord_p" INT4,
5883 "tie_breaking_p" "tie_breaking" )
5884 RETURNS INT8
5885 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5886 BEGIN
5887 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
5888 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
5889 END IF;
5890 RETURN (
5891 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
5892 0
5893 ELSE
5894 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
5895 1::INT8 << 62
5896 ELSE 0 END
5897 +
5898 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
5899 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
5900 ELSE
5901 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
5902 END
5903 END
5904 );
5905 END;
5906 $$;
5908 COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4, "tie_breaking") IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)';
5911 CREATE TYPE "link_strength" AS (
5912 "primary" INT8,
5913 "secondary" INT8 );
5915 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'')';
5918 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
5919 RETURNS "link_strength"[][]
5920 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5921 DECLARE
5922 "dimension_v" INT4;
5923 "matrix_p" "link_strength"[][];
5924 "i" INT4;
5925 "j" INT4;
5926 "k" INT4;
5927 BEGIN
5928 "dimension_v" := array_upper("matrix_d", 1);
5929 "matrix_p" := "matrix_d";
5930 "i" := 1;
5931 LOOP
5932 "j" := 1;
5933 LOOP
5934 IF "i" != "j" THEN
5935 "k" := 1;
5936 LOOP
5937 IF "i" != "k" AND "j" != "k" THEN
5938 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
5939 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
5940 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
5941 END IF;
5942 ELSE
5943 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
5944 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
5945 END IF;
5946 END IF;
5947 END IF;
5948 EXIT WHEN "k" = "dimension_v";
5949 "k" := "k" + 1;
5950 END LOOP;
5951 END IF;
5952 EXIT WHEN "j" = "dimension_v";
5953 "j" := "j" + 1;
5954 END LOOP;
5955 EXIT WHEN "i" = "dimension_v";
5956 "i" := "i" + 1;
5957 END LOOP;
5958 RETURN "matrix_p";
5959 END;
5960 $$;
5962 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
5965 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
5966 RETURNS VOID
5967 LANGUAGE 'plpgsql' VOLATILE AS $$
5968 DECLARE
5969 "issue_row" "issue"%ROWTYPE;
5970 "policy_row" "policy"%ROWTYPE;
5971 "dimension_v" INT4;
5972 "matrix_a" INT4[][]; -- absolute votes
5973 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
5974 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
5975 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
5976 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
5977 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
5978 "i" INT4;
5979 "j" INT4;
5980 "m" INT4;
5981 "n" INT4;
5982 "battle_row" "battle"%ROWTYPE;
5983 "rank_ary" INT4[];
5984 "rank_v" INT4;
5985 "initiative_id_v" "initiative"."id"%TYPE;
5986 BEGIN
5987 PERFORM "require_transaction_isolation"();
5988 SELECT * INTO "issue_row"
5989 FROM "issue" WHERE "id" = "issue_id_p";
5990 SELECT * INTO "policy_row"
5991 FROM "policy" WHERE "id" = "issue_row"."policy_id";
5992 SELECT count(1) INTO "dimension_v"
5993 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
5994 -- create "matrix_a" with absolute number of votes in pairwise
5995 -- comparison:
5996 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
5997 "i" := 1;
5998 "j" := 2;
5999 FOR "battle_row" IN
6000 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
6001 ORDER BY
6002 "winning_initiative_id" NULLS FIRST,
6003 "losing_initiative_id" NULLS FIRST
6004 LOOP
6005 "matrix_a"["i"]["j"] := "battle_row"."count";
6006 IF "j" = "dimension_v" THEN
6007 "i" := "i" + 1;
6008 "j" := 1;
6009 ELSE
6010 "j" := "j" + 1;
6011 IF "j" = "i" THEN
6012 "j" := "j" + 1;
6013 END IF;
6014 END IF;
6015 END LOOP;
6016 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
6017 RAISE EXCEPTION 'Wrong battle count (should not happen)';
6018 END IF;
6019 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
6020 -- and "secondary_link_strength" functions:
6021 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
6022 "i" := 1;
6023 LOOP
6024 "j" := 1;
6025 LOOP
6026 IF "i" != "j" THEN
6027 "matrix_d"["i"]["j"] := (
6028 "defeat_strength"(
6029 "matrix_a"["i"]["j"],
6030 "matrix_a"["j"]["i"],
6031 "policy_row"."defeat_strength"
6032 ),
6033 "secondary_link_strength"(
6034 "i",
6035 "j",
6036 "policy_row"."tie_breaking"
6037 )
6038 )::"link_strength";
6039 END IF;
6040 EXIT WHEN "j" = "dimension_v";
6041 "j" := "j" + 1;
6042 END LOOP;
6043 EXIT WHEN "i" = "dimension_v";
6044 "i" := "i" + 1;
6045 END LOOP;
6046 -- find best paths:
6047 "matrix_p" := "find_best_paths"("matrix_d");
6048 -- create partial order:
6049 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
6050 "i" := 1;
6051 LOOP
6052 "j" := "i" + 1;
6053 LOOP
6054 IF "i" != "j" THEN
6055 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
6056 "matrix_b"["i"]["j"] := TRUE;
6057 "matrix_b"["j"]["i"] := FALSE;
6058 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
6059 "matrix_b"["i"]["j"] := FALSE;
6060 "matrix_b"["j"]["i"] := TRUE;
6061 END IF;
6062 END IF;
6063 EXIT WHEN "j" = "dimension_v";
6064 "j" := "j" + 1;
6065 END LOOP;
6066 EXIT WHEN "i" = "dimension_v" - 1;
6067 "i" := "i" + 1;
6068 END LOOP;
6069 -- tie-breaking by forbidding shared weakest links in beat-paths
6070 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
6071 -- is performed later by initiative id):
6072 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
6073 "m" := 1;
6074 LOOP
6075 "n" := "m" + 1;
6076 LOOP
6077 -- only process those candidates m and n, which are tied:
6078 IF "matrix_b"["m"]["n"] ISNULL THEN
6079 -- start with beat-paths prior tie-breaking:
6080 "matrix_t" := "matrix_p";
6081 -- start with all links allowed:
6082 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
6083 LOOP
6084 -- determine (and forbid) that link that is the weakest link
6085 -- in both the best path from candidate m to candidate n and
6086 -- from candidate n to candidate m:
6087 "i" := 1;
6088 <<forbid_one_link>>
6089 LOOP
6090 "j" := 1;
6091 LOOP
6092 IF "i" != "j" THEN
6093 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
6094 "matrix_f"["i"]["j"] := TRUE;
6095 -- exit for performance reasons,
6096 -- as exactly one link will be found:
6097 EXIT forbid_one_link;
6098 END IF;
6099 END IF;
6100 EXIT WHEN "j" = "dimension_v";
6101 "j" := "j" + 1;
6102 END LOOP;
6103 IF "i" = "dimension_v" THEN
6104 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
6105 END IF;
6106 "i" := "i" + 1;
6107 END LOOP;
6108 -- calculate best beat-paths while ignoring forbidden links:
6109 "i" := 1;
6110 LOOP
6111 "j" := 1;
6112 LOOP
6113 IF "i" != "j" THEN
6114 "matrix_t"["i"]["j"] := CASE
6115 WHEN "matrix_f"["i"]["j"]
6116 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
6117 ELSE "matrix_d"["i"]["j"] END;
6118 END IF;
6119 EXIT WHEN "j" = "dimension_v";
6120 "j" := "j" + 1;
6121 END LOOP;
6122 EXIT WHEN "i" = "dimension_v";
6123 "i" := "i" + 1;
6124 END LOOP;
6125 "matrix_t" := "find_best_paths"("matrix_t");
6126 -- extend partial order, if tie-breaking was successful:
6127 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
6128 "matrix_b"["m"]["n"] := TRUE;
6129 "matrix_b"["n"]["m"] := FALSE;
6130 EXIT;
6131 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
6132 "matrix_b"["m"]["n"] := FALSE;
6133 "matrix_b"["n"]["m"] := TRUE;
6134 EXIT;
6135 END IF;
6136 END LOOP;
6137 END IF;
6138 EXIT WHEN "n" = "dimension_v";
6139 "n" := "n" + 1;
6140 END LOOP;
6141 EXIT WHEN "m" = "dimension_v" - 1;
6142 "m" := "m" + 1;
6143 END LOOP;
6144 END IF;
6145 -- store a unique ranking in "rank_ary":
6146 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
6147 "rank_v" := 1;
6148 LOOP
6149 "i" := 1;
6150 <<assign_next_rank>>
6151 LOOP
6152 IF "rank_ary"["i"] ISNULL THEN
6153 "j" := 1;
6154 LOOP
6155 IF
6156 "i" != "j" AND
6157 "rank_ary"["j"] ISNULL AND
6158 ( "matrix_b"["j"]["i"] OR
6159 -- tie-breaking by "id"
6160 ( "matrix_b"["j"]["i"] ISNULL AND
6161 "j" < "i" ) )
6162 THEN
6163 -- someone else is better
6164 EXIT;
6165 END IF;
6166 IF "j" = "dimension_v" THEN
6167 -- noone is better
6168 "rank_ary"["i"] := "rank_v";
6169 EXIT assign_next_rank;
6170 END IF;
6171 "j" := "j" + 1;
6172 END LOOP;
6173 END IF;
6174 "i" := "i" + 1;
6175 IF "i" > "dimension_v" THEN
6176 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
6177 END IF;
6178 END LOOP;
6179 EXIT WHEN "rank_v" = "dimension_v";
6180 "rank_v" := "rank_v" + 1;
6181 END LOOP;
6182 -- write preliminary results:
6183 "i" := 2; -- omit status quo with "i" = 1
6184 FOR "initiative_id_v" IN
6185 SELECT "id" FROM "initiative"
6186 WHERE "issue_id" = "issue_id_p" AND "admitted"
6187 ORDER BY "id"
6188 LOOP
6189 UPDATE "initiative" SET
6190 "direct_majority" =
6191 CASE WHEN "policy_row"."direct_majority_strict" THEN
6192 "positive_votes" * "policy_row"."direct_majority_den" >
6193 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
6194 ELSE
6195 "positive_votes" * "policy_row"."direct_majority_den" >=
6196 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
6197 END
6198 AND "positive_votes" >= "policy_row"."direct_majority_positive"
6199 AND "issue_row"."voter_count"-"negative_votes" >=
6200 "policy_row"."direct_majority_non_negative",
6201 "indirect_majority" =
6202 CASE WHEN "policy_row"."indirect_majority_strict" THEN
6203 "positive_votes" * "policy_row"."indirect_majority_den" >
6204 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
6205 ELSE
6206 "positive_votes" * "policy_row"."indirect_majority_den" >=
6207 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
6208 END
6209 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
6210 AND "issue_row"."voter_count"-"negative_votes" >=
6211 "policy_row"."indirect_majority_non_negative",
6212 "schulze_rank" = "rank_ary"["i"],
6213 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
6214 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
6215 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
6216 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
6217 THEN NULL
6218 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
6219 "eligible" = FALSE,
6220 "winner" = FALSE,
6221 "rank" = NULL -- NOTE: in cases of manual reset of issue state
6222 WHERE "id" = "initiative_id_v";
6223 "i" := "i" + 1;
6224 END LOOP;
6225 IF "i" != "dimension_v" + 1 THEN
6226 RAISE EXCEPTION 'Wrong winner count (should not happen)';
6227 END IF;
6228 -- take indirect majorities into account:
6229 LOOP
6230 UPDATE "initiative" SET "indirect_majority" = TRUE
6231 FROM (
6232 SELECT "new_initiative"."id" AS "initiative_id"
6233 FROM "initiative" "old_initiative"
6234 JOIN "initiative" "new_initiative"
6235 ON "new_initiative"."issue_id" = "issue_id_p"
6236 AND "new_initiative"."indirect_majority" = FALSE
6237 JOIN "battle" "battle_win"
6238 ON "battle_win"."issue_id" = "issue_id_p"
6239 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
6240 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
6241 JOIN "battle" "battle_lose"
6242 ON "battle_lose"."issue_id" = "issue_id_p"
6243 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
6244 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
6245 WHERE "old_initiative"."issue_id" = "issue_id_p"
6246 AND "old_initiative"."indirect_majority" = TRUE
6247 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
6248 "battle_win"."count" * "policy_row"."indirect_majority_den" >
6249 "policy_row"."indirect_majority_num" *
6250 ("battle_win"."count"+"battle_lose"."count")
6251 ELSE
6252 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
6253 "policy_row"."indirect_majority_num" *
6254 ("battle_win"."count"+"battle_lose"."count")
6255 END
6256 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
6257 AND "issue_row"."voter_count"-"battle_lose"."count" >=
6258 "policy_row"."indirect_majority_non_negative"
6259 ) AS "subquery"
6260 WHERE "id" = "subquery"."initiative_id";
6261 EXIT WHEN NOT FOUND;
6262 END LOOP;
6263 -- set "multistage_majority" for remaining matching initiatives:
6264 UPDATE "initiative" SET "multistage_majority" = TRUE
6265 FROM (
6266 SELECT "losing_initiative"."id" AS "initiative_id"
6267 FROM "initiative" "losing_initiative"
6268 JOIN "initiative" "winning_initiative"
6269 ON "winning_initiative"."issue_id" = "issue_id_p"
6270 AND "winning_initiative"."admitted"
6271 JOIN "battle" "battle_win"
6272 ON "battle_win"."issue_id" = "issue_id_p"
6273 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
6274 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
6275 JOIN "battle" "battle_lose"
6276 ON "battle_lose"."issue_id" = "issue_id_p"
6277 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
6278 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
6279 WHERE "losing_initiative"."issue_id" = "issue_id_p"
6280 AND "losing_initiative"."admitted"
6281 AND "winning_initiative"."schulze_rank" <
6282 "losing_initiative"."schulze_rank"
6283 AND "battle_win"."count" > "battle_lose"."count"
6284 AND (
6285 "battle_win"."count" > "winning_initiative"."positive_votes" OR
6286 "battle_lose"."count" < "losing_initiative"."negative_votes" )
6287 ) AS "subquery"
6288 WHERE "id" = "subquery"."initiative_id";
6289 -- mark eligible initiatives:
6290 UPDATE "initiative" SET "eligible" = TRUE
6291 WHERE "issue_id" = "issue_id_p"
6292 AND "initiative"."direct_majority"
6293 AND "initiative"."indirect_majority"
6294 AND "initiative"."better_than_status_quo"
6295 AND (
6296 "policy_row"."no_multistage_majority" = FALSE OR
6297 "initiative"."multistage_majority" = FALSE )
6298 AND (
6299 "policy_row"."no_reverse_beat_path" = FALSE OR
6300 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
6301 -- mark final winner:
6302 UPDATE "initiative" SET "winner" = TRUE
6303 FROM (
6304 SELECT "id" AS "initiative_id"
6305 FROM "initiative"
6306 WHERE "issue_id" = "issue_id_p" AND "eligible"
6307 ORDER BY
6308 "schulze_rank",
6309 "id"
6310 LIMIT 1
6311 ) AS "subquery"
6312 WHERE "id" = "subquery"."initiative_id";
6313 -- write (final) ranks:
6314 "rank_v" := 1;
6315 FOR "initiative_id_v" IN
6316 SELECT "id"
6317 FROM "initiative"
6318 WHERE "issue_id" = "issue_id_p" AND "admitted"
6319 ORDER BY
6320 "winner" DESC,
6321 "eligible" DESC,
6322 "schulze_rank",
6323 "id"
6324 LOOP
6325 UPDATE "initiative" SET "rank" = "rank_v"
6326 WHERE "id" = "initiative_id_v";
6327 "rank_v" := "rank_v" + 1;
6328 END LOOP;
6329 -- set schulze rank of status quo and mark issue as finished:
6330 UPDATE "issue" SET
6331 "status_quo_schulze_rank" = "rank_ary"[1],
6332 "state" =
6333 CASE WHEN EXISTS (
6334 SELECT NULL FROM "initiative"
6335 WHERE "issue_id" = "issue_id_p" AND "winner"
6336 ) THEN
6337 'finished_with_winner'::"issue_state"
6338 ELSE
6339 'finished_without_winner'::"issue_state"
6340 END,
6341 "closed" = "phase_finished",
6342 "phase_finished" = NULL
6343 WHERE "id" = "issue_id_p";
6344 RETURN;
6345 END;
6346 $$;
6348 COMMENT ON FUNCTION "calculate_ranks"
6349 ( "issue"."id"%TYPE )
6350 IS 'Determine ranking (Votes have to be counted first)';
6354 -----------------------------
6355 -- Automatic state changes --
6356 -----------------------------
6359 CREATE FUNCTION "issue_admission"
6360 ( "area_id_p" "area"."id"%TYPE )
6361 RETURNS BOOLEAN
6362 LANGUAGE 'plpgsql' VOLATILE AS $$
6363 DECLARE
6364 "issue_id_v" "issue"."id"%TYPE;
6365 BEGIN
6366 PERFORM "dont_require_transaction_isolation"();
6367 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
6368 UPDATE "area" SET "issue_quorum" = "view"."issue_quorum"
6369 FROM "area_quorum" AS "view"
6370 WHERE "area"."id" = "view"."area_id"
6371 AND "area"."id" = "area_id_p";
6372 SELECT "id" INTO "issue_id_v" FROM "issue_for_admission"
6373 WHERE "area_id" = "area_id_p";
6374 IF "issue_id_v" ISNULL THEN RETURN FALSE; END IF;
6375 UPDATE "issue" SET
6376 "admission_snapshot_id" = "latest_snapshot_id",
6377 "state" = 'discussion',
6378 "accepted" = now(),
6379 "phase_finished" = NULL,
6380 "issue_quorum" = "issue_quorum"."issue_quorum"
6381 FROM "issue_quorum"
6382 WHERE "id" = "issue_id_v"
6383 AND "issue_quorum"."issue_id" = "issue_id_v";
6384 RETURN TRUE;
6385 END;
6386 $$;
6388 COMMENT ON FUNCTION "issue_admission"
6389 ( "area"."id"%TYPE )
6390 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';
6393 CREATE TYPE "check_issue_persistence" AS (
6394 "state" "issue_state",
6395 "phase_finished" BOOLEAN,
6396 "issue_revoked" BOOLEAN,
6397 "snapshot_created" BOOLEAN,
6398 "harmonic_weights_set" BOOLEAN,
6399 "closed_voting" BOOLEAN );
6401 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';
6404 CREATE FUNCTION "check_issue"
6405 ( "issue_id_p" "issue"."id"%TYPE,
6406 "persist" "check_issue_persistence" )
6407 RETURNS "check_issue_persistence"
6408 LANGUAGE 'plpgsql' VOLATILE AS $$
6409 DECLARE
6410 "issue_row" "issue"%ROWTYPE;
6411 "last_calculated_v" "snapshot"."calculated"%TYPE;
6412 "policy_row" "policy"%ROWTYPE;
6413 "initiative_row" "initiative"%ROWTYPE;
6414 "state_v" "issue_state";
6415 BEGIN
6416 PERFORM "require_transaction_isolation"();
6417 IF "persist" ISNULL THEN
6418 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6419 FOR UPDATE;
6420 SELECT "calculated" INTO "last_calculated_v"
6421 FROM "snapshot" JOIN "snapshot_issue"
6422 ON "snapshot"."id" = "snapshot_issue"."snapshot_id"
6423 WHERE "snapshot_issue"."issue_id" = "issue_id_p"
6424 ORDER BY "snapshot"."id" DESC;
6425 IF "issue_row"."closed" NOTNULL THEN
6426 RETURN NULL;
6427 END IF;
6428 "persist"."state" := "issue_row"."state";
6429 IF
6430 ( "issue_row"."state" = 'admission' AND "last_calculated_v" >=
6431 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
6432 ( "issue_row"."state" = 'discussion' AND now() >=
6433 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
6434 ( "issue_row"."state" = 'verification' AND now() >=
6435 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
6436 ( "issue_row"."state" = 'voting' AND now() >=
6437 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
6438 THEN
6439 "persist"."phase_finished" := TRUE;
6440 ELSE
6441 "persist"."phase_finished" := FALSE;
6442 END IF;
6443 IF
6444 NOT EXISTS (
6445 -- all initiatives are revoked
6446 SELECT NULL FROM "initiative"
6447 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6448 ) AND (
6449 -- and issue has not been accepted yet
6450 "persist"."state" = 'admission' OR
6451 -- or verification time has elapsed
6452 ( "persist"."state" = 'verification' AND
6453 "persist"."phase_finished" ) OR
6454 -- or no initiatives have been revoked lately
6455 NOT EXISTS (
6456 SELECT NULL FROM "initiative"
6457 WHERE "issue_id" = "issue_id_p"
6458 AND now() < "revoked" + "issue_row"."verification_time"
6459 )
6460 )
6461 THEN
6462 "persist"."issue_revoked" := TRUE;
6463 ELSE
6464 "persist"."issue_revoked" := FALSE;
6465 END IF;
6466 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
6467 UPDATE "issue" SET "phase_finished" = now()
6468 WHERE "id" = "issue_row"."id";
6469 RETURN "persist";
6470 ELSIF
6471 "persist"."state" IN ('admission', 'discussion', 'verification')
6472 THEN
6473 RETURN "persist";
6474 ELSE
6475 RETURN NULL;
6476 END IF;
6477 END IF;
6478 IF
6479 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6480 coalesce("persist"."snapshot_created", FALSE) = FALSE
6481 THEN
6482 IF "persist"."state" != 'admission' THEN
6483 PERFORM "take_snapshot"("issue_id_p");
6484 PERFORM "finish_snapshot"("issue_id_p");
6485 ELSE
6486 UPDATE "issue" SET "issue_quorum" = "issue_quorum"."issue_quorum"
6487 FROM "issue_quorum"
6488 WHERE "id" = "issue_id_p"
6489 AND "issue_quorum"."issue_id" = "issue_id_p";
6490 END IF;
6491 "persist"."snapshot_created" = TRUE;
6492 IF "persist"."phase_finished" THEN
6493 IF "persist"."state" = 'admission' THEN
6494 UPDATE "issue" SET "admission_snapshot_id" = "latest_snapshot_id"
6495 WHERE "id" = "issue_id_p";
6496 ELSIF "persist"."state" = 'discussion' THEN
6497 UPDATE "issue" SET "half_freeze_snapshot_id" = "latest_snapshot_id"
6498 WHERE "id" = "issue_id_p";
6499 ELSIF "persist"."state" = 'verification' THEN
6500 UPDATE "issue" SET "full_freeze_snapshot_id" = "latest_snapshot_id"
6501 WHERE "id" = "issue_id_p";
6502 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
6503 FOR "initiative_row" IN
6504 SELECT * FROM "initiative"
6505 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6506 FOR UPDATE
6507 LOOP
6508 IF
6509 "initiative_row"."polling" OR
6510 "initiative_row"."satisfied_supporter_count" >=
6511 "issue_row"."initiative_quorum"
6512 THEN
6513 UPDATE "initiative" SET "admitted" = TRUE
6514 WHERE "id" = "initiative_row"."id";
6515 ELSE
6516 UPDATE "initiative" SET "admitted" = FALSE
6517 WHERE "id" = "initiative_row"."id";
6518 END IF;
6519 END LOOP;
6520 END IF;
6521 END IF;
6522 RETURN "persist";
6523 END IF;
6524 IF
6525 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6526 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
6527 THEN
6528 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
6529 "persist"."harmonic_weights_set" = TRUE;
6530 IF
6531 "persist"."phase_finished" OR
6532 "persist"."issue_revoked" OR
6533 "persist"."state" = 'admission'
6534 THEN
6535 RETURN "persist";
6536 ELSE
6537 RETURN NULL;
6538 END IF;
6539 END IF;
6540 IF "persist"."issue_revoked" THEN
6541 IF "persist"."state" = 'admission' THEN
6542 "state_v" := 'canceled_revoked_before_accepted';
6543 ELSIF "persist"."state" = 'discussion' THEN
6544 "state_v" := 'canceled_after_revocation_during_discussion';
6545 ELSIF "persist"."state" = 'verification' THEN
6546 "state_v" := 'canceled_after_revocation_during_verification';
6547 END IF;
6548 UPDATE "issue" SET
6549 "state" = "state_v",
6550 "closed" = "phase_finished",
6551 "phase_finished" = NULL
6552 WHERE "id" = "issue_id_p";
6553 RETURN NULL;
6554 END IF;
6555 IF "persist"."state" = 'admission' THEN
6556 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6557 FOR UPDATE;
6558 IF "issue_row"."phase_finished" NOTNULL THEN
6559 UPDATE "issue" SET
6560 "state" = 'canceled_issue_not_accepted',
6561 "closed" = "phase_finished",
6562 "phase_finished" = NULL
6563 WHERE "id" = "issue_id_p";
6564 END IF;
6565 RETURN NULL;
6566 END IF;
6567 IF "persist"."phase_finished" THEN
6568 IF "persist"."state" = 'discussion' THEN
6569 UPDATE "issue" SET
6570 "state" = 'verification',
6571 "half_frozen" = "phase_finished",
6572 "phase_finished" = NULL
6573 WHERE "id" = "issue_id_p";
6574 RETURN NULL;
6575 END IF;
6576 IF "persist"."state" = 'verification' THEN
6577 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6578 FOR UPDATE;
6579 SELECT * INTO "policy_row" FROM "policy"
6580 WHERE "id" = "issue_row"."policy_id";
6581 IF EXISTS (
6582 SELECT NULL FROM "initiative"
6583 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
6584 ) THEN
6585 UPDATE "issue" SET
6586 "state" = 'voting',
6587 "fully_frozen" = "phase_finished",
6588 "phase_finished" = NULL
6589 WHERE "id" = "issue_id_p";
6590 ELSE
6591 UPDATE "issue" SET
6592 "state" = 'canceled_no_initiative_admitted',
6593 "fully_frozen" = "phase_finished",
6594 "closed" = "phase_finished",
6595 "phase_finished" = NULL
6596 WHERE "id" = "issue_id_p";
6597 -- NOTE: The following DELETE statements have effect only when
6598 -- issue state has been manipulated
6599 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
6600 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
6601 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
6602 END IF;
6603 RETURN NULL;
6604 END IF;
6605 IF "persist"."state" = 'voting' THEN
6606 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
6607 PERFORM "close_voting"("issue_id_p");
6608 "persist"."closed_voting" = TRUE;
6609 RETURN "persist";
6610 END IF;
6611 PERFORM "calculate_ranks"("issue_id_p");
6612 RETURN NULL;
6613 END IF;
6614 END IF;
6615 RAISE WARNING 'should not happen';
6616 RETURN NULL;
6617 END;
6618 $$;
6620 COMMENT ON FUNCTION "check_issue"
6621 ( "issue"."id"%TYPE,
6622 "check_issue_persistence" )
6623 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")';
6626 CREATE FUNCTION "check_everything"()
6627 RETURNS VOID
6628 LANGUAGE 'plpgsql' VOLATILE AS $$
6629 DECLARE
6630 "area_id_v" "area"."id"%TYPE;
6631 "snapshot_id_v" "snapshot"."id"%TYPE;
6632 "issue_id_v" "issue"."id"%TYPE;
6633 "persist_v" "check_issue_persistence";
6634 BEGIN
6635 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
6636 DELETE FROM "expired_session";
6637 DELETE FROM "expired_token";
6638 DELETE FROM "unused_snapshot";
6639 PERFORM "check_activity"();
6640 PERFORM "calculate_member_counts"();
6641 FOR "area_id_v" IN SELECT "id" FROM "area_with_unaccepted_issues" LOOP
6642 SELECT "take_snapshot"(NULL, "area_id_v") INTO "snapshot_id_v";
6643 PERFORM "finish_snapshot"("issue_id") FROM "snapshot_issue"
6644 WHERE "snapshot_id" = "snapshot_id_v";
6645 LOOP
6646 EXIT WHEN "issue_admission"("area_id_v") = FALSE;
6647 END LOOP;
6648 END LOOP;
6649 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
6650 "persist_v" := NULL;
6651 LOOP
6652 "persist_v" := "check_issue"("issue_id_v", "persist_v");
6653 EXIT WHEN "persist_v" ISNULL;
6654 END LOOP;
6655 END LOOP;
6656 DELETE FROM "unused_snapshot";
6657 RETURN;
6658 END;
6659 $$;
6661 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';
6665 ----------------------
6666 -- Deletion of data --
6667 ----------------------
6670 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
6671 RETURNS VOID
6672 LANGUAGE 'plpgsql' VOLATILE AS $$
6673 BEGIN
6674 IF EXISTS (
6675 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
6676 ) THEN
6677 -- override protection triggers:
6678 INSERT INTO "temporary_transaction_data" ("key", "value")
6679 VALUES ('override_protection_triggers', TRUE::TEXT);
6680 -- clean data:
6681 DELETE FROM "delegating_voter"
6682 WHERE "issue_id" = "issue_id_p";
6683 DELETE FROM "direct_voter"
6684 WHERE "issue_id" = "issue_id_p";
6685 DELETE FROM "delegating_interest_snapshot"
6686 WHERE "issue_id" = "issue_id_p";
6687 DELETE FROM "direct_interest_snapshot"
6688 WHERE "issue_id" = "issue_id_p";
6689 DELETE FROM "non_voter"
6690 WHERE "issue_id" = "issue_id_p";
6691 DELETE FROM "delegation"
6692 WHERE "issue_id" = "issue_id_p";
6693 DELETE FROM "supporter"
6694 USING "initiative" -- NOTE: due to missing index on issue_id
6695 WHERE "initiative"."issue_id" = "issue_id_p"
6696 AND "supporter"."initiative_id" = "initiative_id";
6697 -- mark issue as cleaned:
6698 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
6699 -- finish overriding protection triggers (avoids garbage):
6700 DELETE FROM "temporary_transaction_data"
6701 WHERE "key" = 'override_protection_triggers';
6702 END IF;
6703 RETURN;
6704 END;
6705 $$;
6707 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
6710 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
6711 RETURNS VOID
6712 LANGUAGE 'plpgsql' VOLATILE AS $$
6713 BEGIN
6714 UPDATE "member" SET
6715 "last_login" = NULL,
6716 "last_delegation_check" = NULL,
6717 "login" = NULL,
6718 "password" = NULL,
6719 "authority" = NULL,
6720 "authority_uid" = NULL,
6721 "authority_login" = NULL,
6722 "deleted" = coalesce("deleted", now()),
6723 "locked" = TRUE,
6724 "active" = FALSE,
6725 "notify_email" = NULL,
6726 "notify_email_unconfirmed" = NULL,
6727 "notify_email_secret" = NULL,
6728 "notify_email_secret_expiry" = NULL,
6729 "notify_email_lock_expiry" = NULL,
6730 "disable_notifications" = TRUE,
6731 "notification_counter" = DEFAULT,
6732 "notification_sample_size" = 0,
6733 "notification_dow" = NULL,
6734 "notification_hour" = NULL,
6735 "notification_sent" = NULL,
6736 "login_recovery_expiry" = NULL,
6737 "password_reset_secret" = NULL,
6738 "password_reset_secret_expiry" = NULL,
6739 "location" = NULL
6740 WHERE "id" = "member_id_p";
6741 DELETE FROM "member_settings" WHERE "member_id" = "member_id_p";
6742 DELETE FROM "member_profile" WHERE "member_id" = "member_id_p";
6743 DELETE FROM "rendered_member_statement" WHERE "member_id" = "member_id_p";
6744 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
6745 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
6746 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
6747 DELETE FROM "session" WHERE "member_id" = "member_id_p";
6748 DELETE FROM "member_application" WHERE "member_id" = "member_id_p";
6749 DELETE FROM "token" WHERE "member_id" = "member_id_p";
6750 DELETE FROM "subscription" WHERE "member_id" = "member_id_p";
6751 DELETE FROM "ignored_area" WHERE "member_id" = "member_id_p";
6752 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
6753 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
6754 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
6755 DELETE FROM "direct_voter" USING "issue"
6756 WHERE "direct_voter"."issue_id" = "issue"."id"
6757 AND "issue"."closed" ISNULL
6758 AND "member_id" = "member_id_p";
6759 DELETE FROM "notification_initiative_sent" WHERE "member_id" = "member_id_p";
6760 RETURN;
6761 END;
6762 $$;
6764 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)';
6767 CREATE FUNCTION "delete_private_data"()
6768 RETURNS VOID
6769 LANGUAGE 'plpgsql' VOLATILE AS $$
6770 BEGIN
6771 DELETE FROM "temporary_transaction_data";
6772 DELETE FROM "temporary_suggestion_counts";
6773 DELETE FROM "member" WHERE "activated" ISNULL;
6774 UPDATE "member" SET
6775 "invite_code" = NULL,
6776 "invite_code_expiry" = NULL,
6777 "admin_comment" = NULL,
6778 "last_login" = NULL,
6779 "last_delegation_check" = NULL,
6780 "login" = NULL,
6781 "password" = NULL,
6782 "authority" = NULL,
6783 "authority_uid" = NULL,
6784 "authority_login" = NULL,
6785 "lang" = NULL,
6786 "notify_email" = NULL,
6787 "notify_email_unconfirmed" = NULL,
6788 "notify_email_secret" = NULL,
6789 "notify_email_secret_expiry" = NULL,
6790 "notify_email_lock_expiry" = NULL,
6791 "disable_notifications" = TRUE,
6792 "notification_counter" = DEFAULT,
6793 "notification_sample_size" = 0,
6794 "notification_dow" = NULL,
6795 "notification_hour" = NULL,
6796 "notification_sent" = NULL,
6797 "login_recovery_expiry" = NULL,
6798 "password_reset_secret" = NULL,
6799 "password_reset_secret_expiry" = NULL,
6800 "location" = NULL;
6801 DELETE FROM "verification";
6802 DELETE FROM "member_settings";
6803 DELETE FROM "member_useterms";
6804 DELETE FROM "member_profile";
6805 DELETE FROM "rendered_member_statement";
6806 DELETE FROM "member_image";
6807 DELETE FROM "contact";
6808 DELETE FROM "ignored_member";
6809 DELETE FROM "session";
6810 DELETE FROM "system_application";
6811 DELETE FROM "system_application_redirect_uri";
6812 DELETE FROM "dynamic_application_scope";
6813 DELETE FROM "member_application";
6814 DELETE FROM "token";
6815 DELETE FROM "subscription";
6816 DELETE FROM "ignored_area";
6817 DELETE FROM "ignored_initiative";
6818 DELETE FROM "non_voter";
6819 DELETE FROM "direct_voter" USING "issue"
6820 WHERE "direct_voter"."issue_id" = "issue"."id"
6821 AND "issue"."closed" ISNULL;
6822 DELETE FROM "event_processed";
6823 DELETE FROM "notification_initiative_sent";
6824 DELETE FROM "newsletter";
6825 RETURN;
6826 END;
6827 $$;
6829 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.';
6833 COMMIT;
