liquid_feedback_core

view core.sql @ 619:63092784fe9d

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

Impressum / About Us