liquid_feedback_core

view core.sql @ 590:c918d08f5a80

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

Impressum / About Us