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