liquid_feedback_core

view core.sql @ 593:e7f772ca0621

Removed an index on table "initiative"
author jbe
date Sat Dec 08 01:37:23 2018 +0100 (2018-12-08)
parents 332a2177e208
children a2c156197bc7
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_closed_idx" ON "issue" ("closed");
870 CREATE INDEX "issue_open_created_idx" ON "issue" ("created") WHERE "closed" ISNULL;
871 CREATE INDEX "issue_latest_snapshot_id_idx" ON "issue" ("latest_snapshot_id");
872 CREATE INDEX "issue_admission_snapshot_id_idx" ON "issue" ("admission_snapshot_id");
873 CREATE INDEX "issue_half_freeze_snapshot_id_idx" ON "issue" ("half_freeze_snapshot_id");
874 CREATE INDEX "issue_full_freeze_snapshot_id_idx" ON "issue" ("full_freeze_snapshot_id");
876 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
878 COMMENT ON COLUMN "issue"."admin_notice" IS 'Public notice by admin to explain manual interventions, or to announce corrections';
879 COMMENT ON COLUMN "issue"."external_reference" IS 'Opaque data field to store an external reference';
880 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';
881 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")';
882 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.';
883 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.';
884 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.';
885 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
886 COMMENT ON COLUMN "issue"."min_admission_time" IS 'Copied from "policy" table at creation of issue';
887 COMMENT ON COLUMN "issue"."max_admission_time" IS 'Copied from "policy" table at creation of issue';
888 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
889 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
890 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
891 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")';
892 COMMENT ON COLUMN "issue"."latest_snapshot_id" IS 'Snapshot id of most recent snapshot';
893 COMMENT ON COLUMN "issue"."admission_snapshot_id" IS 'Snapshot id when issue as accepted or canceled in admission phase';
894 COMMENT ON COLUMN "issue"."half_freeze_snapshot_id" IS 'Snapshot id at end of discussion phase';
895 COMMENT ON COLUMN "issue"."full_freeze_snapshot_id" IS 'Snapshot id at end of verification phase';
896 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';
897 COMMENT ON COLUMN "issue"."initiative_quorum" IS 'Calculated number of satisfied supporters to be reached by an initiative to be "admitted" for voting';
898 COMMENT ON COLUMN "issue"."population" IS 'Count of members in "snapshot_population" table with "snapshot_id" equal to "issue"."latest_snapshot_id"';
899 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';
900 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
903 ALTER TABLE "snapshot" ADD FOREIGN KEY ("issue_id") REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE;
906 CREATE TABLE "issue_order_in_admission_state" (
907 "id" INT8 PRIMARY KEY, -- NOTE: no referential integrity due to performans/locking issues; REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
908 "order_in_area" INT4,
909 "order_in_unit" INT4 );
911 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"';
913 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';
914 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';
915 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';
918 CREATE TABLE "initiative" (
919 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
920 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
921 "id" SERIAL4 PRIMARY KEY,
922 "name" TEXT NOT NULL,
923 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
924 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
925 "revoked" TIMESTAMPTZ,
926 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
927 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
928 "location" JSONB,
929 "external_reference" TEXT,
930 "admitted" BOOLEAN,
931 "supporter_count" INT4,
932 "informed_supporter_count" INT4,
933 "satisfied_supporter_count" INT4,
934 "satisfied_informed_supporter_count" INT4,
935 "harmonic_weight" NUMERIC(12, 3),
936 "final_suggestion_order_calculated" BOOLEAN NOT NULL DEFAULT FALSE,
937 "first_preference_votes" INT4,
938 "positive_votes" INT4,
939 "negative_votes" INT4,
940 "direct_majority" BOOLEAN,
941 "indirect_majority" BOOLEAN,
942 "schulze_rank" INT4,
943 "better_than_status_quo" BOOLEAN,
944 "worse_than_status_quo" BOOLEAN,
945 "reverse_beat_path" BOOLEAN,
946 "multistage_majority" BOOLEAN,
947 "eligible" BOOLEAN,
948 "winner" BOOLEAN,
949 "rank" INT4,
950 "text_search_data" TSVECTOR,
951 "draft_text_search_data" TSVECTOR,
952 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
953 CHECK (("revoked" NOTNULL) = ("revoked_by_member_id" NOTNULL)),
954 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
955 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
956 CONSTRAINT "revoked_initiatives_cant_be_admitted"
957 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
958 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
959 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
960 ( "first_preference_votes" ISNULL AND
961 "positive_votes" ISNULL AND "negative_votes" ISNULL AND
962 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
963 "schulze_rank" ISNULL AND
964 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
965 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
966 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
967 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
968 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
969 "eligible" = FALSE OR
970 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
971 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
972 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
973 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
974 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
975 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
976 CREATE INDEX "initiative_location_idx" ON "initiative" USING gist ((GeoJSON_to_ecluster("location")));
977 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
978 CREATE INDEX "initiative_draft_text_search_data_idx" ON "initiative" USING gin ("draft_text_search_data");
979 CREATE TRIGGER "update_text_search_data"
980 BEFORE INSERT OR UPDATE ON "initiative"
981 FOR EACH ROW EXECUTE PROCEDURE
982 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "name");
984 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.';
986 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
987 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
988 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
989 COMMENT ON COLUMN "initiative"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied from most recent draft)';
990 COMMENT ON COLUMN "initiative"."external_reference" IS 'Opaque data field to store an external reference';
991 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
992 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
993 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
994 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
995 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
996 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';
997 COMMENT ON COLUMN "initiative"."final_suggestion_order_calculated" IS 'Set to TRUE, when "proportional_order" of suggestions has been calculated the last time';
998 COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice';
999 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo';
1000 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo';
1001 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"';
1002 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
1003 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking';
1004 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo';
1005 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)';
1006 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''';
1007 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';
1008 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"';
1009 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank"';
1010 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';
1013 CREATE TABLE "battle" (
1014 "issue_id" INT4 NOT NULL,
1015 "winning_initiative_id" INT4,
1016 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1017 "losing_initiative_id" INT4,
1018 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1019 "count" INT4 NOT NULL,
1020 CONSTRAINT "initiative_ids_not_equal" CHECK (
1021 "winning_initiative_id" != "losing_initiative_id" OR
1022 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
1023 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
1024 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
1025 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
1026 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
1028 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';
1031 CREATE TABLE "ignored_initiative" (
1032 PRIMARY KEY ("member_id", "initiative_id"),
1033 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1034 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1035 CREATE INDEX "ignored_initiative_initiative_id_idx" ON "ignored_initiative" ("initiative_id");
1037 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';
1040 CREATE TABLE "draft" (
1041 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
1042 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1043 "id" SERIAL8 PRIMARY KEY,
1044 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
1045 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1046 "formatting_engine" TEXT,
1047 "content" TEXT NOT NULL,
1048 "location" JSONB,
1049 "external_reference" TEXT,
1050 "text_search_data" TSVECTOR );
1051 CREATE INDEX "draft_created_idx" ON "draft" ("created");
1052 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
1053 CREATE INDEX "draft_location_idx" ON "draft" USING gist ((GeoJSON_to_ecluster("location")));
1054 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
1055 CREATE TRIGGER "update_text_search_data"
1056 BEFORE INSERT OR UPDATE ON "draft"
1057 FOR EACH ROW EXECUTE PROCEDURE
1058 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1060 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.';
1062 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
1063 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
1064 COMMENT ON COLUMN "draft"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied to "initiative" table if draft is most recent)';
1065 COMMENT ON COLUMN "draft"."external_reference" IS 'Opaque data field to store an external reference';
1068 CREATE TABLE "rendered_draft" (
1069 PRIMARY KEY ("draft_id", "format"),
1070 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1071 "format" TEXT,
1072 "content" TEXT NOT NULL );
1074 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)';
1077 CREATE TABLE "suggestion" (
1078 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
1079 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1080 "id" SERIAL8 PRIMARY KEY,
1081 "draft_id" INT8 NOT NULL,
1082 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1083 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
1084 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1085 "name" TEXT NOT NULL,
1086 "formatting_engine" TEXT,
1087 "content" TEXT NOT NULL DEFAULT '',
1088 "location" JSONB,
1089 "external_reference" TEXT,
1090 "text_search_data" TSVECTOR,
1091 "minus2_unfulfilled_count" INT4,
1092 "minus2_fulfilled_count" INT4,
1093 "minus1_unfulfilled_count" INT4,
1094 "minus1_fulfilled_count" INT4,
1095 "plus1_unfulfilled_count" INT4,
1096 "plus1_fulfilled_count" INT4,
1097 "plus2_unfulfilled_count" INT4,
1098 "plus2_fulfilled_count" INT4,
1099 "proportional_order" INT4 );
1100 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
1101 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
1102 CREATE INDEX "suggestion_location_idx" ON "suggestion" USING gist ((GeoJSON_to_ecluster("location")));
1103 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
1104 CREATE TRIGGER "update_text_search_data"
1105 BEFORE INSERT OR UPDATE ON "suggestion"
1106 FOR EACH ROW EXECUTE PROCEDURE
1107 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
1108 "name", "content");
1110 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';
1112 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")';
1113 COMMENT ON COLUMN "suggestion"."location" IS 'Geographic location of suggestion as GeoJSON object';
1114 COMMENT ON COLUMN "suggestion"."external_reference" IS 'Opaque data field to store an external reference';
1115 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1116 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1117 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1118 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1119 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1120 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1121 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1122 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1123 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"';
1126 CREATE TABLE "rendered_suggestion" (
1127 PRIMARY KEY ("suggestion_id", "format"),
1128 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1129 "format" TEXT,
1130 "content" TEXT NOT NULL );
1132 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)';
1135 CREATE TABLE "temporary_suggestion_counts" (
1136 "id" INT8 PRIMARY KEY, -- NOTE: no referential integrity due to performance/locking issues; REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1137 "minus2_unfulfilled_count" INT4 NOT NULL,
1138 "minus2_fulfilled_count" INT4 NOT NULL,
1139 "minus1_unfulfilled_count" INT4 NOT NULL,
1140 "minus1_fulfilled_count" INT4 NOT NULL,
1141 "plus1_unfulfilled_count" INT4 NOT NULL,
1142 "plus1_fulfilled_count" INT4 NOT NULL,
1143 "plus2_unfulfilled_count" INT4 NOT NULL,
1144 "plus2_fulfilled_count" INT4 NOT NULL );
1146 COMMENT ON TABLE "temporary_suggestion_counts" IS 'Holds certain calculated values (suggestion counts) temporarily until they can be copied into table "suggestion"';
1148 COMMENT ON COLUMN "temporary_suggestion_counts"."id" IS 'References "suggestion" ("id") but has no referential integrity trigger associated, due to performance/locking issues';
1151 CREATE TABLE "privilege" (
1152 PRIMARY KEY ("unit_id", "member_id"),
1153 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1154 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1155 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1156 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1157 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1158 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1159 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
1160 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
1161 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
1163 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
1165 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
1166 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
1167 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
1168 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
1169 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
1170 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
1171 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';
1174 CREATE TABLE "interest" (
1175 PRIMARY KEY ("issue_id", "member_id"),
1176 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1177 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE );
1178 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
1180 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.';
1183 CREATE TABLE "initiator" (
1184 PRIMARY KEY ("initiative_id", "member_id"),
1185 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1186 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1187 "accepted" BOOLEAN );
1188 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
1190 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.';
1192 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.';
1195 CREATE TABLE "supporter" (
1196 "issue_id" INT4 NOT NULL,
1197 PRIMARY KEY ("initiative_id", "member_id"),
1198 "initiative_id" INT4,
1199 "member_id" INT4,
1200 "draft_id" INT8 NOT NULL,
1201 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1202 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
1203 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
1205 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.';
1207 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1208 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")';
1211 CREATE TABLE "opinion" (
1212 "initiative_id" INT4 NOT NULL,
1213 PRIMARY KEY ("suggestion_id", "member_id"),
1214 "suggestion_id" INT8,
1215 "member_id" INT4,
1216 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
1217 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
1218 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1219 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1220 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
1222 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.';
1224 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
1227 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
1229 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
1232 CREATE TABLE "delegation" (
1233 "id" SERIAL8 PRIMARY KEY,
1234 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1235 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1236 "scope" "delegation_scope" NOT NULL,
1237 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1238 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1239 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1240 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
1241 CONSTRAINT "no_unit_delegation_to_null"
1242 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
1243 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
1244 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
1245 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
1246 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
1247 UNIQUE ("unit_id", "truster_id"),
1248 UNIQUE ("area_id", "truster_id"),
1249 UNIQUE ("issue_id", "truster_id") );
1250 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
1251 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
1253 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
1255 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
1256 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
1257 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
1260 CREATE TABLE "snapshot_issue" (
1261 PRIMARY KEY ("snapshot_id", "issue_id"),
1262 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1263 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); -- NOTE: trigger "delete_snapshot_on_partial_delete" will delete whole "snapshot"
1264 CREATE INDEX "snapshot_issue_issue_id_idx" ON "snapshot_issue" ("issue_id");
1266 COMMENT ON TABLE "snapshot_issue" IS 'List of issues included in a snapshot';
1268 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.';
1271 CREATE TABLE "direct_interest_snapshot" (
1272 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
1273 "snapshot_id" INT8,
1274 "issue_id" INT4,
1275 FOREIGN KEY ("snapshot_id", "issue_id")
1276 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1277 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1278 "weight" INT4 );
1279 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
1281 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';
1283 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
1286 CREATE TABLE "delegating_interest_snapshot" (
1287 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
1288 "snapshot_id" INT8,
1289 "issue_id" INT4,
1290 FOREIGN KEY ("snapshot_id", "issue_id")
1291 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1292 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1293 "weight" INT4,
1294 "scope" "delegation_scope" NOT NULL,
1295 "delegate_member_ids" INT4[] NOT NULL );
1296 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
1298 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';
1300 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
1301 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
1302 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"';
1305 CREATE TABLE "direct_supporter_snapshot" (
1306 PRIMARY KEY ("snapshot_id", "initiative_id", "member_id"),
1307 "snapshot_id" INT8,
1308 "issue_id" INT4 NOT NULL,
1309 FOREIGN KEY ("snapshot_id", "issue_id")
1310 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1311 "initiative_id" INT4,
1312 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1313 "draft_id" INT8 NOT NULL,
1314 "informed" BOOLEAN NOT NULL,
1315 "satisfied" BOOLEAN NOT NULL,
1316 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1317 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1318 FOREIGN KEY ("snapshot_id", "issue_id", "member_id") REFERENCES "direct_interest_snapshot" ("snapshot_id", "issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1319 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1321 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';
1323 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';
1324 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1325 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1328 CREATE TABLE "non_voter" (
1329 PRIMARY KEY ("member_id", "issue_id"),
1330 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1331 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1332 CREATE INDEX "non_voter_issue_id_idx" ON "non_voter" ("issue_id");
1334 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1337 CREATE TABLE "direct_voter" (
1338 PRIMARY KEY ("issue_id", "member_id"),
1339 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1340 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1341 "weight" INT4,
1342 "comment_changed" TIMESTAMPTZ,
1343 "formatting_engine" TEXT,
1344 "comment" TEXT,
1345 "text_search_data" TSVECTOR );
1346 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1347 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
1348 CREATE TRIGGER "update_text_search_data"
1349 BEFORE INSERT OR UPDATE ON "direct_voter"
1350 FOR EACH ROW EXECUTE PROCEDURE
1351 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
1353 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';
1355 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1356 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';
1357 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';
1358 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.';
1361 CREATE TABLE "rendered_voter_comment" (
1362 PRIMARY KEY ("issue_id", "member_id", "format"),
1363 FOREIGN KEY ("issue_id", "member_id")
1364 REFERENCES "direct_voter" ("issue_id", "member_id")
1365 ON DELETE CASCADE ON UPDATE CASCADE,
1366 "issue_id" INT4,
1367 "member_id" INT4,
1368 "format" TEXT,
1369 "content" TEXT NOT NULL );
1371 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)';
1374 CREATE TABLE "delegating_voter" (
1375 PRIMARY KEY ("issue_id", "member_id"),
1376 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1377 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1378 "weight" INT4,
1379 "scope" "delegation_scope" NOT NULL,
1380 "delegate_member_ids" INT4[] NOT NULL );
1381 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1383 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';
1385 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1386 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1387 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"';
1390 CREATE TABLE "vote" (
1391 "issue_id" INT4 NOT NULL,
1392 PRIMARY KEY ("initiative_id", "member_id"),
1393 "initiative_id" INT4,
1394 "member_id" INT4,
1395 "grade" INT4 NOT NULL,
1396 "first_preference" BOOLEAN,
1397 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1398 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1399 CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
1400 CHECK ("grade" > 0 OR "first_preference" ISNULL) );
1401 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1403 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';
1405 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1406 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.';
1407 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.';
1410 CREATE TABLE "posting" (
1411 "id" SERIAL8 PRIMARY KEY,
1412 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1413 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
1414 "message" TEXT NOT NULL,
1415 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1416 "area_id" INT4,
1417 FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1418 "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1419 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1420 FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1421 FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1422 "initiative_id" INT4,
1423 "suggestion_id" INT8,
1424 -- NOTE: no referential integrity for suggestions because those are
1425 -- actually deleted
1426 -- FOREIGN KEY ("initiative_id", "suggestion_id")
1427 -- REFERENCES "suggestion" ("initiative_id", "id")
1428 -- ON DELETE CASCADE ON UPDATE CASCADE,
1429 CONSTRAINT "area_requires_unit" CHECK (
1430 "area_id" ISNULL OR "unit_id" NOTNULL ),
1431 CONSTRAINT "policy_set_when_issue_set" CHECK (
1432 ("policy_id" NOTNULL) = ("issue_id" NOTNULL) ),
1433 CONSTRAINT "issue_requires_area" CHECK (
1434 "issue_id" ISNULL OR "area_id" NOTNULL ),
1435 CONSTRAINT "initiative_requires_issue" CHECK (
1436 "initiative_id" ISNULL OR "issue_id" NOTNULL ),
1437 CONSTRAINT "suggestion_requires_initiative" CHECK (
1438 "suggestion_id" ISNULL OR "initiative_id" NOTNULL ) );
1439 CREATE INDEX "posting_global_idx" ON "posting" USING gist ((pstamp("author_id", "id")));
1440 CREATE INDEX "posting_unit_idx" ON "posting" USING gist ("unit_id", (pstamp("author_id", "id"))) WHERE "unit_id" NOTNULL;
1441 CREATE INDEX "posting_area_idx" ON "posting" USING gist ("area_id", (pstamp("author_id", "id"))) WHERE "area_id" NOTNULL;
1442 CREATE INDEX "posting_policy_idx" ON "posting" USING gist ("policy_id", (pstamp("author_id", "id"))) WHERE "policy_id" NOTNULL;
1443 CREATE INDEX "posting_issue_idx" ON "posting" USING gist ("issue_id", (pstamp("author_id", "id"))) WHERE "issue_id" NOTNULL;
1444 CREATE INDEX "posting_initiative_idx" ON "posting" USING gist ("initiative_id", (pstamp("author_id", "id"))) WHERE "initiative_id" NOTNULL;
1445 CREATE INDEX "posting_suggestion_idx" ON "posting" USING gist ("suggestion_id", (pstamp("author_id", "id"))) WHERE "suggestion_id" NOTNULL;
1447 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';
1450 CREATE TYPE "event_type" AS ENUM (
1451 'unit_created',
1452 'unit_updated',
1453 'area_created',
1454 'area_updated',
1455 'policy_created',
1456 'policy_updated',
1457 'issue_state_changed',
1458 'initiative_created_in_new_issue',
1459 'initiative_created_in_existing_issue',
1460 'initiative_revoked',
1461 'new_draft_created',
1462 'suggestion_created',
1463 'suggestion_deleted',
1464 'member_activated',
1465 'member_deleted',
1466 'member_active',
1467 'member_name_updated',
1468 'member_profile_updated',
1469 'member_image_updated',
1470 'interest',
1471 'initiator',
1472 'support',
1473 'support_updated',
1474 'suggestion_rated',
1475 'delegation',
1476 'contact',
1477 'posting_created' );
1479 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1482 CREATE TABLE "event" (
1483 "id" SERIAL8 PRIMARY KEY,
1484 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1485 "event" "event_type" NOT NULL,
1486 "posting_id" INT8 REFERENCES "posting" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1487 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1488 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1489 "scope" "delegation_scope",
1490 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1491 "area_id" INT4,
1492 FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1493 "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1494 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1495 FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1496 FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1497 "state" "issue_state",
1498 "initiative_id" INT4,
1499 "draft_id" INT8,
1500 "suggestion_id" INT8,
1501 "boolean_value" BOOLEAN,
1502 "numeric_value" INT4,
1503 "text_value" TEXT,
1504 "old_text_value" TEXT,
1505 FOREIGN KEY ("issue_id", "initiative_id")
1506 REFERENCES "initiative" ("issue_id", "id")
1507 ON DELETE CASCADE ON UPDATE CASCADE,
1508 FOREIGN KEY ("initiative_id", "draft_id")
1509 REFERENCES "draft" ("initiative_id", "id")
1510 ON DELETE CASCADE ON UPDATE CASCADE,
1511 -- NOTE: no referential integrity for suggestions because those are
1512 -- actually deleted
1513 -- FOREIGN KEY ("initiative_id", "suggestion_id")
1514 -- REFERENCES "suggestion" ("initiative_id", "id")
1515 -- ON DELETE CASCADE ON UPDATE CASCADE,
1516 CONSTRAINT "constr_for_issue_state_changed" CHECK (
1517 "event" != 'issue_state_changed' OR (
1518 "posting_id" ISNULL AND
1519 "member_id" ISNULL AND
1520 "other_member_id" ISNULL AND
1521 "scope" ISNULL AND
1522 "unit_id" NOTNULL AND
1523 "area_id" NOTNULL AND
1524 "policy_id" NOTNULL AND
1525 "issue_id" NOTNULL AND
1526 "state" NOTNULL AND
1527 "initiative_id" ISNULL AND
1528 "draft_id" ISNULL AND
1529 "suggestion_id" ISNULL AND
1530 "boolean_value" ISNULL AND
1531 "numeric_value" ISNULL AND
1532 "text_value" ISNULL AND
1533 "old_text_value" ISNULL )),
1534 CONSTRAINT "constr_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1535 "event" NOT IN (
1536 'initiative_created_in_new_issue',
1537 'initiative_created_in_existing_issue',
1538 'initiative_revoked',
1539 'new_draft_created'
1540 ) OR (
1541 "posting_id" ISNULL AND
1542 "member_id" NOTNULL AND
1543 "other_member_id" ISNULL AND
1544 "scope" ISNULL AND
1545 "unit_id" NOTNULL AND
1546 "area_id" NOTNULL AND
1547 "policy_id" NOTNULL AND
1548 "issue_id" NOTNULL AND
1549 "state" NOTNULL AND
1550 "initiative_id" NOTNULL AND
1551 "draft_id" NOTNULL AND
1552 "suggestion_id" ISNULL AND
1553 "boolean_value" ISNULL AND
1554 "numeric_value" ISNULL AND
1555 "text_value" ISNULL AND
1556 "old_text_value" ISNULL )),
1557 CONSTRAINT "constr_for_suggestion_creation" CHECK (
1558 "event" != 'suggestion_created' OR (
1559 "posting_id" ISNULL AND
1560 "member_id" NOTNULL AND
1561 "other_member_id" ISNULL AND
1562 "scope" ISNULL AND
1563 "unit_id" NOTNULL AND
1564 "area_id" NOTNULL AND
1565 "policy_id" NOTNULL AND
1566 "issue_id" NOTNULL AND
1567 "state" NOTNULL AND
1568 "initiative_id" NOTNULL AND
1569 "draft_id" ISNULL AND
1570 "suggestion_id" NOTNULL AND
1571 "boolean_value" ISNULL AND
1572 "numeric_value" ISNULL AND
1573 "text_value" ISNULL AND
1574 "old_text_value" ISNULL )),
1575 CONSTRAINT "constr_for_suggestion_removal" CHECK (
1576 "event" != 'suggestion_deleted' OR (
1577 "posting_id" ISNULL AND
1578 "member_id" ISNULL AND
1579 "other_member_id" ISNULL AND
1580 "scope" ISNULL AND
1581 "unit_id" NOTNULL AND
1582 "area_id" NOTNULL AND
1583 "policy_id" NOTNULL AND
1584 "issue_id" NOTNULL AND
1585 "state" NOTNULL AND
1586 "initiative_id" NOTNULL AND
1587 "draft_id" ISNULL AND
1588 "suggestion_id" NOTNULL AND
1589 "boolean_value" ISNULL AND
1590 "numeric_value" ISNULL AND
1591 "text_value" ISNULL AND
1592 "old_text_value" ISNULL )),
1593 CONSTRAINT "constr_for_value_less_member_event" CHECK (
1594 "event" NOT IN (
1595 'member_activated',
1596 'member_deleted',
1597 'member_profile_updated',
1598 'member_image_updated'
1599 ) OR (
1600 "posting_id" ISNULL AND
1601 "member_id" NOTNULL AND
1602 "other_member_id" ISNULL AND
1603 "scope" ISNULL AND
1604 "unit_id" ISNULL AND
1605 "area_id" ISNULL AND
1606 "policy_id" ISNULL AND
1607 "issue_id" ISNULL AND
1608 "state" ISNULL AND
1609 "initiative_id" ISNULL AND
1610 "draft_id" ISNULL AND
1611 "suggestion_id" ISNULL AND
1612 "boolean_value" ISNULL AND
1613 "numeric_value" ISNULL AND
1614 "text_value" ISNULL AND
1615 "old_text_value" ISNULL )),
1616 CONSTRAINT "constr_for_member_active" CHECK (
1617 "event" != 'member_active' OR (
1618 "posting_id" ISNULL AND
1619 "member_id" NOTNULL AND
1620 "other_member_id" ISNULL AND
1621 "scope" ISNULL AND
1622 "unit_id" ISNULL AND
1623 "area_id" ISNULL AND
1624 "policy_id" ISNULL AND
1625 "issue_id" ISNULL AND
1626 "state" ISNULL AND
1627 "initiative_id" ISNULL AND
1628 "draft_id" ISNULL AND
1629 "suggestion_id" ISNULL AND
1630 "boolean_value" NOTNULL AND
1631 "numeric_value" ISNULL AND
1632 "text_value" ISNULL AND
1633 "old_text_value" ISNULL )),
1634 CONSTRAINT "constr_for_member_name_updated" CHECK (
1635 "event" != 'member_name_updated' OR (
1636 "posting_id" ISNULL AND
1637 "member_id" NOTNULL AND
1638 "other_member_id" ISNULL AND
1639 "scope" ISNULL AND
1640 "unit_id" ISNULL AND
1641 "area_id" ISNULL AND
1642 "policy_id" ISNULL AND
1643 "issue_id" ISNULL AND
1644 "state" ISNULL AND
1645 "initiative_id" ISNULL AND
1646 "draft_id" ISNULL AND
1647 "suggestion_id" ISNULL AND
1648 "boolean_value" ISNULL AND
1649 "numeric_value" ISNULL AND
1650 "text_value" NOTNULL AND
1651 "old_text_value" NOTNULL )),
1652 CONSTRAINT "constr_for_interest" CHECK (
1653 "event" != 'interest' OR (
1654 "posting_id" ISNULL AND
1655 "member_id" NOTNULL AND
1656 "other_member_id" ISNULL AND
1657 "scope" ISNULL AND
1658 "unit_id" NOTNULL AND
1659 "area_id" NOTNULL AND
1660 "policy_id" NOTNULL AND
1661 "issue_id" NOTNULL AND
1662 "state" NOTNULL AND
1663 "initiative_id" ISNULL AND
1664 "draft_id" ISNULL AND
1665 "suggestion_id" ISNULL AND
1666 "boolean_value" NOTNULL AND
1667 "numeric_value" ISNULL AND
1668 "text_value" ISNULL AND
1669 "old_text_value" ISNULL )),
1670 CONSTRAINT "constr_for_initiator" CHECK (
1671 "event" != 'initiator' OR (
1672 "posting_id" ISNULL AND
1673 "member_id" NOTNULL AND
1674 "other_member_id" ISNULL AND
1675 "scope" ISNULL AND
1676 "unit_id" NOTNULL AND
1677 "area_id" NOTNULL AND
1678 "policy_id" NOTNULL AND
1679 "issue_id" NOTNULL AND
1680 "state" NOTNULL AND
1681 "initiative_id" NOTNULL AND
1682 "draft_id" ISNULL AND
1683 "suggestion_id" ISNULL AND
1684 "boolean_value" NOTNULL AND
1685 "numeric_value" ISNULL AND
1686 "text_value" ISNULL AND
1687 "old_text_value" ISNULL )),
1688 CONSTRAINT "constr_for_support" CHECK (
1689 "event" != 'support' OR (
1690 "posting_id" ISNULL AND
1691 "member_id" NOTNULL AND
1692 "other_member_id" ISNULL AND
1693 "scope" ISNULL AND
1694 "unit_id" NOTNULL AND
1695 "area_id" NOTNULL AND
1696 "policy_id" NOTNULL AND
1697 "issue_id" NOTNULL AND
1698 "state" NOTNULL AND
1699 "initiative_id" NOTNULL AND
1700 ("draft_id" NOTNULL) = ("boolean_value" = TRUE) AND
1701 "suggestion_id" ISNULL AND
1702 "boolean_value" NOTNULL AND
1703 "numeric_value" ISNULL AND
1704 "text_value" ISNULL AND
1705 "old_text_value" ISNULL )),
1706 CONSTRAINT "constr_for_support_updated" CHECK (
1707 "event" != 'support_updated' OR (
1708 "posting_id" ISNULL AND
1709 "member_id" NOTNULL AND
1710 "other_member_id" ISNULL AND
1711 "scope" ISNULL AND
1712 "unit_id" NOTNULL AND
1713 "area_id" NOTNULL AND
1714 "policy_id" NOTNULL AND
1715 "issue_id" NOTNULL AND
1716 "state" NOTNULL AND
1717 "initiative_id" NOTNULL AND
1718 "draft_id" NOTNULL AND
1719 "suggestion_id" ISNULL AND
1720 "boolean_value" ISNULL AND
1721 "numeric_value" ISNULL AND
1722 "text_value" ISNULL AND
1723 "old_text_value" ISNULL )),
1724 CONSTRAINT "constr_for_suggestion_rated" CHECK (
1725 "event" != 'suggestion_rated' OR (
1726 "posting_id" ISNULL AND
1727 "member_id" NOTNULL AND
1728 "other_member_id" ISNULL AND
1729 "scope" ISNULL AND
1730 "unit_id" NOTNULL AND
1731 "area_id" NOTNULL AND
1732 "policy_id" NOTNULL AND
1733 "issue_id" NOTNULL AND
1734 "state" NOTNULL AND
1735 "initiative_id" NOTNULL AND
1736 "draft_id" ISNULL AND
1737 "suggestion_id" NOTNULL AND
1738 ("boolean_value" NOTNULL) = ("numeric_value" != 0) AND
1739 "numeric_value" NOTNULL AND
1740 "numeric_value" IN (-2, -1, 0, 1, 2) AND
1741 "text_value" ISNULL AND
1742 "old_text_value" ISNULL )),
1743 CONSTRAINT "constr_for_delegation" CHECK (
1744 "event" != 'delegation' OR (
1745 "posting_id" ISNULL AND
1746 "member_id" NOTNULL AND
1747 (("other_member_id" ISNULL) OR ("boolean_value" = TRUE)) AND
1748 "scope" NOTNULL AND
1749 "unit_id" NOTNULL AND
1750 ("area_id" NOTNULL) = ("scope" != 'unit'::"delegation_scope") AND
1751 "policy_id" ISNULL AND
1752 ("issue_id" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1753 ("state" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1754 "initiative_id" ISNULL AND
1755 "draft_id" ISNULL AND
1756 "suggestion_id" ISNULL AND
1757 "boolean_value" NOTNULL AND
1758 "numeric_value" ISNULL AND
1759 "text_value" ISNULL AND
1760 "old_text_value" ISNULL )),
1761 CONSTRAINT "constr_for_contact" CHECK (
1762 "event" != 'contact' OR (
1763 "posting_id" ISNULL AND
1764 "member_id" NOTNULL AND
1765 "other_member_id" NOTNULL AND
1766 "scope" ISNULL AND
1767 "unit_id" ISNULL AND
1768 "area_id" ISNULL AND
1769 "policy_id" ISNULL AND
1770 "issue_id" ISNULL AND
1771 "state" ISNULL AND
1772 "initiative_id" ISNULL AND
1773 "draft_id" ISNULL AND
1774 "suggestion_id" ISNULL AND
1775 "boolean_value" NOTNULL AND
1776 "numeric_value" ISNULL AND
1777 "text_value" ISNULL AND
1778 "old_text_value" ISNULL )),
1779 CONSTRAINT "constr_for_posting_created" CHECK (
1780 "event" != 'posting_created' OR (
1781 "posting_id" NOTNULL AND
1782 "member_id" NOTNULL AND
1783 "other_member_id" ISNULL AND
1784 "scope" ISNULL AND
1785 "state" ISNULL AND
1786 ("area_id" ISNULL OR "unit_id" NOTNULL) AND
1787 ("policy_id" NOTNULL) = ("issue_id" NOTNULL) AND
1788 ("issue_id" ISNULL OR "area_id" NOTNULL) AND
1789 ("state" NOTNULL) = ("issue_id" NOTNULL) AND
1790 ("initiative_id" ISNULL OR "issue_id" NOTNULL) AND
1791 "draft_id" ISNULL AND
1792 ("suggestion_id" ISNULL OR "initiative_id" NOTNULL) AND
1793 "boolean_value" ISNULL AND
1794 "numeric_value" ISNULL AND
1795 "text_value" ISNULL AND
1796 "old_text_value" ISNULL )) );
1797 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1798 CREATE INDEX "event_tl_global_idx" ON "event" USING gist ((pstamp("member_id", "id")));
1799 CREATE INDEX "event_tl_unit_idx" ON "event" USING gist ("unit_id", (pstamp("member_id", "id"))) WHERE "unit_id" NOTNULL;
1800 CREATE INDEX "event_tl_area_idx" ON "event" USING gist ("area_id", (pstamp("member_id", "id"))) WHERE "area_id" NOTNULL;
1801 CREATE INDEX "event_tl_policy_idx" ON "event" USING gist ("policy_id", (pstamp("member_id", "id"))) WHERE "policy_id" NOTNULL;
1802 CREATE INDEX "event_tl_issue_idx" ON "event" USING gist ("issue_id", (pstamp("member_id", "id"))) WHERE "issue_id" NOTNULL;
1803 CREATE INDEX "event_tl_initiative_idx" ON "event" USING gist ("initiative_id", (pstamp("member_id", "id"))) WHERE "initiative_id" NOTNULL;
1804 CREATE INDEX "event_tl_suggestion_idx" ON "event" USING gist ("suggestion_id", (pstamp("member_id", "id"))) WHERE "suggestion_id" NOTNULL;
1807 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1809 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1810 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1811 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1812 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1815 CREATE TABLE "event_processed" (
1816 "event_id" INT8 NOT NULL );
1817 CREATE UNIQUE INDEX "event_processed_singleton_idx" ON "event_processed" ((1));
1819 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)';
1820 COMMENT ON INDEX "event_processed_singleton_idx" IS 'This index ensures that "event_processed" only contains one row maximum.';
1823 CREATE TABLE "notification_initiative_sent" (
1824 PRIMARY KEY ("member_id", "initiative_id"),
1825 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1826 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1827 "last_draft_id" INT8 NOT NULL,
1828 "last_suggestion_id" INT8 );
1829 CREATE INDEX "notification_initiative_sent_initiative_idx" ON "notification_initiative_sent" ("initiative_id");
1831 COMMENT ON TABLE "notification_initiative_sent" IS 'Information which initiatives have been promoted to a member in a scheduled notification mail';
1833 COMMENT ON COLUMN "notification_initiative_sent"."last_draft_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1834 COMMENT ON COLUMN "notification_initiative_sent"."last_suggestion_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1837 CREATE TABLE "newsletter" (
1838 "id" SERIAL4 PRIMARY KEY,
1839 "published" TIMESTAMPTZ NOT NULL,
1840 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1841 "include_all_members" BOOLEAN NOT NULL,
1842 "sent" TIMESTAMPTZ,
1843 "subject" TEXT NOT NULL,
1844 "content" TEXT NOT NULL );
1845 CREATE INDEX "newsletter_unit_id_idx" ON "newsletter" ("unit_id", "published");
1846 CREATE INDEX "newsletter_all_units_published_idx" ON "newsletter" ("published") WHERE "unit_id" ISNULL;
1847 CREATE INDEX "newsletter_published_idx" ON "newsletter" ("published");
1849 COMMENT ON TABLE "newsletter" IS 'Contains newsletters created by administrators to be sent out and for further reference';
1851 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter is to be sent out (and made available in the frontend)';
1852 COMMENT ON COLUMN "newsletter"."unit_id" IS 'If set, only members with voting right in the given unit are considered to be recipients';
1853 COMMENT ON COLUMN "newsletter"."include_all_members" IS 'TRUE = include all members regardless of their ''disable_notifications'' setting';
1854 COMMENT ON COLUMN "newsletter"."sent" IS 'Timestamp when the newsletter has been mailed out';
1855 COMMENT ON COLUMN "newsletter"."subject" IS 'Subject line (e.g. to be used for the email)';
1856 COMMENT ON COLUMN "newsletter"."content" IS 'Plain text content of the newsletter';
1860 ----------------------------------------------
1861 -- Writing of history entries and event log --
1862 ----------------------------------------------
1865 CREATE FUNCTION "write_member_history_trigger"()
1866 RETURNS TRIGGER
1867 LANGUAGE 'plpgsql' VOLATILE AS $$
1868 BEGIN
1869 IF
1870 ( NEW."active" != OLD."active" OR
1871 NEW."name" != OLD."name" ) AND
1872 OLD."activated" NOTNULL
1873 THEN
1874 INSERT INTO "member_history"
1875 ("member_id", "active", "name")
1876 VALUES (NEW."id", OLD."active", OLD."name");
1877 END IF;
1878 RETURN NULL;
1879 END;
1880 $$;
1882 CREATE TRIGGER "write_member_history"
1883 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1884 "write_member_history_trigger"();
1886 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1887 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1890 CREATE FUNCTION "write_event_unit_trigger"()
1891 RETURNS TRIGGER
1892 LANGUAGE 'plpgsql' VOLATILE AS $$
1893 DECLARE
1894 "event_v" "event_type";
1895 BEGIN
1896 IF TG_OP = 'UPDATE' THEN
1897 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1898 RETURN NULL;
1899 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1900 -- "event_v" := 'unit_created';
1901 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1902 -- "event_v" := 'unit_deleted';
1903 ELSIF OLD != NEW THEN
1904 "event_v" := 'unit_updated';
1905 ELSE
1906 RETURN NULL;
1907 END IF;
1908 ELSE
1909 "event_v" := 'unit_created';
1910 END IF;
1911 INSERT INTO "event" ("event", "unit_id") VALUES ("event_v", NEW."id");
1912 RETURN NULL;
1913 END;
1914 $$;
1916 CREATE TRIGGER "write_event_unit" AFTER INSERT OR UPDATE ON "unit"
1917 FOR EACH ROW EXECUTE PROCEDURE "write_event_unit_trigger"();
1919 COMMENT ON FUNCTION "write_event_unit_trigger"() IS 'Implementation of trigger "write_event_unit" on table "unit"';
1920 COMMENT ON TRIGGER "write_event_unit" ON "unit" IS 'Create entry in "event" table on new or changed/disabled units';
1923 CREATE FUNCTION "write_event_area_trigger"()
1924 RETURNS TRIGGER
1925 LANGUAGE 'plpgsql' VOLATILE AS $$
1926 DECLARE
1927 "event_v" "event_type";
1928 BEGIN
1929 IF TG_OP = 'UPDATE' THEN
1930 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1931 RETURN NULL;
1932 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1933 -- "event_v" := 'area_created';
1934 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1935 -- "event_v" := 'area_deleted';
1936 ELSIF OLD != NEW THEN
1937 "event_v" := 'area_updated';
1938 ELSE
1939 RETURN NULL;
1940 END IF;
1941 ELSE
1942 "event_v" := 'area_created';
1943 END IF;
1944 INSERT INTO "event" ("event", "area_id") VALUES ("event_v", NEW."id");
1945 RETURN NULL;
1946 END;
1947 $$;
1949 CREATE TRIGGER "write_event_area" AFTER INSERT OR UPDATE ON "area"
1950 FOR EACH ROW EXECUTE PROCEDURE "write_event_area_trigger"();
1952 COMMENT ON FUNCTION "write_event_area_trigger"() IS 'Implementation of trigger "write_event_area" on table "area"';
1953 COMMENT ON TRIGGER "write_event_area" ON "area" IS 'Create entry in "event" table on new or changed/disabled areas';
1956 CREATE FUNCTION "write_event_policy_trigger"()
1957 RETURNS TRIGGER
1958 LANGUAGE 'plpgsql' VOLATILE AS $$
1959 DECLARE
1960 "event_v" "event_type";
1961 BEGIN
1962 IF TG_OP = 'UPDATE' THEN
1963 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1964 RETURN NULL;
1965 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1966 -- "event_v" := 'policy_created';
1967 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1968 -- "event_v" := 'policy_deleted';
1969 ELSIF OLD != NEW THEN
1970 "event_v" := 'policy_updated';
1971 ELSE
1972 RETURN NULL;
1973 END IF;
1974 ELSE
1975 "event_v" := 'policy_created';
1976 END IF;
1977 INSERT INTO "event" ("event", "policy_id") VALUES ("event_v", NEW."id");
1978 RETURN NULL;
1979 END;
1980 $$;
1982 CREATE TRIGGER "write_event_policy" AFTER INSERT OR UPDATE ON "policy"
1983 FOR EACH ROW EXECUTE PROCEDURE "write_event_policy_trigger"();
1985 COMMENT ON FUNCTION "write_event_policy_trigger"() IS 'Implementation of trigger "write_event_policy" on table "policy"';
1986 COMMENT ON TRIGGER "write_event_policy" ON "policy" IS 'Create entry in "event" table on new or changed/disabled policies';
1989 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1990 RETURNS TRIGGER
1991 LANGUAGE 'plpgsql' VOLATILE AS $$
1992 DECLARE
1993 "area_row" "area"%ROWTYPE;
1994 BEGIN
1995 IF NEW."state" != OLD."state" THEN
1996 SELECT * INTO "area_row" FROM "area" WHERE "id" = NEW."area_id"
1997 FOR SHARE;
1998 INSERT INTO "event" (
1999 "event",
2000 "unit_id", "area_id", "policy_id", "issue_id", "state"
2001 ) VALUES (
2002 'issue_state_changed',
2003 "area_row"."unit_id", NEW."area_id", NEW."policy_id",
2004 NEW."id", NEW."state"
2005 );
2006 END IF;
2007 RETURN NULL;
2008 END;
2009 $$;
2011 CREATE TRIGGER "write_event_issue_state_changed"
2012 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
2013 "write_event_issue_state_changed_trigger"();
2015 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
2016 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
2019 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
2020 RETURNS TRIGGER
2021 LANGUAGE 'plpgsql' VOLATILE AS $$
2022 DECLARE
2023 "initiative_row" "initiative"%ROWTYPE;
2024 "issue_row" "issue"%ROWTYPE;
2025 "area_row" "area"%ROWTYPE;
2026 "event_v" "event_type";
2027 BEGIN
2028 SELECT * INTO "initiative_row" FROM "initiative"
2029 WHERE "id" = NEW."initiative_id" FOR SHARE;
2030 SELECT * INTO "issue_row" FROM "issue"
2031 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2032 SELECT * INTO "area_row" FROM "area"
2033 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2034 IF EXISTS (
2035 SELECT NULL FROM "draft"
2036 WHERE "initiative_id" = NEW."initiative_id" AND "id" != NEW."id"
2037 FOR SHARE
2038 ) THEN
2039 "event_v" := 'new_draft_created';
2040 ELSE
2041 IF EXISTS (
2042 SELECT NULL FROM "initiative"
2043 WHERE "issue_id" = "initiative_row"."issue_id"
2044 AND "id" != "initiative_row"."id"
2045 FOR SHARE
2046 ) THEN
2047 "event_v" := 'initiative_created_in_existing_issue';
2048 ELSE
2049 "event_v" := 'initiative_created_in_new_issue';
2050 END IF;
2051 END IF;
2052 INSERT INTO "event" (
2053 "event", "member_id",
2054 "unit_id", "area_id", "policy_id", "issue_id", "state",
2055 "initiative_id", "draft_id"
2056 ) VALUES (
2057 "event_v", NEW."author_id",
2058 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
2059 "initiative_row"."issue_id", "issue_row"."state",
2060 NEW."initiative_id", NEW."id"
2061 );
2062 RETURN NULL;
2063 END;
2064 $$;
2066 CREATE TRIGGER "write_event_initiative_or_draft_created"
2067 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
2068 "write_event_initiative_or_draft_created_trigger"();
2070 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
2071 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
2074 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
2075 RETURNS TRIGGER
2076 LANGUAGE 'plpgsql' VOLATILE AS $$
2077 DECLARE
2078 "issue_row" "issue"%ROWTYPE;
2079 "area_row" "area"%ROWTYPE;
2080 "draft_id_v" "draft"."id"%TYPE;
2081 BEGIN
2082 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
2083 -- NOTE: lock for primary key update to avoid new drafts
2084 PERFORM NULL FROM "initiative" WHERE "id" = NEW."id" FOR UPDATE;
2085 SELECT * INTO "issue_row" FROM "issue"
2086 WHERE "id" = NEW."issue_id" FOR SHARE;
2087 SELECT * INTO "area_row" FROM "area"
2088 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2089 -- NOTE: FOR SHARE cannot be used with DISTINCT in view "current_draft"
2090 PERFORM NULL FROM "draft" WHERE "initiative_id" = NEW."id" FOR SHARE;
2091 SELECT "id" INTO "draft_id_v" FROM "current_draft"
2092 WHERE "initiative_id" = NEW."id";
2093 INSERT INTO "event" (
2094 "event", "member_id",
2095 "unit_id", "area_id", "policy_id", "issue_id", "state",
2096 "initiative_id", "draft_id"
2097 ) VALUES (
2098 'initiative_revoked', NEW."revoked_by_member_id",
2099 "area_row"."unit_id", "issue_row"."area_id",
2100 "issue_row"."policy_id",
2101 NEW."issue_id", "issue_row"."state",
2102 NEW."id", "draft_id_v"
2103 );
2104 END IF;
2105 RETURN NULL;
2106 END;
2107 $$;
2109 CREATE TRIGGER "write_event_initiative_revoked"
2110 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
2111 "write_event_initiative_revoked_trigger"();
2113 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
2114 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
2117 CREATE FUNCTION "write_event_suggestion_created_trigger"()
2118 RETURNS TRIGGER
2119 LANGUAGE 'plpgsql' VOLATILE AS $$
2120 DECLARE
2121 "initiative_row" "initiative"%ROWTYPE;
2122 "issue_row" "issue"%ROWTYPE;
2123 "area_row" "area"%ROWTYPE;
2124 BEGIN
2125 SELECT * INTO "initiative_row" FROM "initiative"
2126 WHERE "id" = NEW."initiative_id" FOR SHARE;
2127 SELECT * INTO "issue_row" FROM "issue"
2128 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2129 SELECT * INTO "area_row" FROM "area"
2130 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2131 INSERT INTO "event" (
2132 "event", "member_id",
2133 "unit_id", "area_id", "policy_id", "issue_id", "state",
2134 "initiative_id", "suggestion_id"
2135 ) VALUES (
2136 'suggestion_created', NEW."author_id",
2137 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
2138 "initiative_row"."issue_id", "issue_row"."state",
2139 NEW."initiative_id", NEW."id"
2140 );
2141 RETURN NULL;
2142 END;
2143 $$;
2145 CREATE TRIGGER "write_event_suggestion_created"
2146 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2147 "write_event_suggestion_created_trigger"();
2149 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
2150 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2153 CREATE FUNCTION "write_event_suggestion_removed_trigger"()
2154 RETURNS TRIGGER
2155 LANGUAGE 'plpgsql' VOLATILE AS $$
2156 DECLARE
2157 "initiative_row" "initiative"%ROWTYPE;
2158 "issue_row" "issue"%ROWTYPE;
2159 "area_row" "area"%ROWTYPE;
2160 BEGIN
2161 SELECT * INTO "initiative_row" FROM "initiative"
2162 WHERE "id" = OLD."initiative_id" FOR SHARE;
2163 IF "initiative_row"."id" NOTNULL THEN
2164 SELECT * INTO "issue_row" FROM "issue"
2165 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2166 SELECT * INTO "area_row" FROM "area"
2167 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2168 INSERT INTO "event" (
2169 "event",
2170 "unit_id", "area_id", "policy_id", "issue_id", "state",
2171 "initiative_id", "suggestion_id"
2172 ) VALUES (
2173 'suggestion_deleted',
2174 "area_row"."unit_id", "issue_row"."area_id",
2175 "issue_row"."policy_id",
2176 "initiative_row"."issue_id", "issue_row"."state",
2177 OLD."initiative_id", OLD."id"
2178 );
2179 END IF;
2180 RETURN NULL;
2181 END;
2182 $$;
2184 CREATE TRIGGER "write_event_suggestion_removed"
2185 AFTER DELETE ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2186 "write_event_suggestion_removed_trigger"();
2188 COMMENT ON FUNCTION "write_event_suggestion_removed_trigger"() IS 'Implementation of trigger "write_event_suggestion_removed" on table "issue"';
2189 COMMENT ON TRIGGER "write_event_suggestion_removed" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2192 CREATE FUNCTION "write_event_member_trigger"()
2193 RETURNS TRIGGER
2194 LANGUAGE 'plpgsql' VOLATILE AS $$
2195 BEGIN
2196 IF TG_OP = 'INSERT' THEN
2197 IF NEW."activated" NOTNULL AND NEW."deleted" ISNULL THEN
2198 INSERT INTO "event" ("event", "member_id")
2199 VALUES ('member_activated', NEW."id");
2200 END IF;
2201 IF NEW."active" THEN
2202 INSERT INTO "event" ("event", "member_id", "boolean_value")
2203 VALUES ('member_active', NEW."id", TRUE);
2204 END IF;
2205 ELSIF TG_OP = 'UPDATE' THEN
2206 IF OLD."id" != NEW."id" THEN
2207 RAISE EXCEPTION 'Cannot change member ID';
2208 END IF;
2209 IF
2210 (OLD."activated" ISNULL OR OLD."deleted" NOTNULL) AND
2211 NEW."activated" NOTNULL AND NEW."deleted" ISNULL
2212 THEN
2213 INSERT INTO "event" ("event", "member_id")
2214 VALUES ('member_activated', NEW."id");
2215 END IF;
2216 IF OLD."active" != NEW."active" THEN
2217 INSERT INTO "event" ("event", "member_id", "boolean_value") VALUES (
2218 'member_active', NEW."id", NEW."active"
2219 );
2220 END IF;
2221 IF OLD."name" != NEW."name" THEN
2222 INSERT INTO "event" (
2223 "event", "member_id", "text_value", "old_text_value"
2224 ) VALUES (
2225 'member_name_updated', NEW."id", NEW."name", OLD."name"
2226 );
2227 END IF;
2228 IF
2229 OLD."activated" NOTNULL AND OLD."deleted" ISNULL AND
2230 (NEW."activated" ISNULL OR NEW."deleted" NOTNULL)
2231 THEN
2232 INSERT INTO "event" ("event", "member_id")
2233 VALUES ('member_deleted', NEW."id");
2234 END IF;
2235 END IF;
2236 RETURN NULL;
2237 END;
2238 $$;
2240 CREATE TRIGGER "write_event_member"
2241 AFTER INSERT OR UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
2242 "write_event_member_trigger"();
2244 COMMENT ON FUNCTION "write_event_member_trigger"() IS 'Implementation of trigger "write_event_member" on table "member"';
2245 COMMENT ON TRIGGER "write_event_member" ON "member" IS 'Create entries in "event" table on insertion to member table';
2248 CREATE FUNCTION "write_event_member_profile_updated_trigger"()
2249 RETURNS TRIGGER
2250 LANGUAGE 'plpgsql' VOLATILE AS $$
2251 BEGIN
2252 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2253 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2254 INSERT INTO "event" ("event", "member_id") VALUES (
2255 'member_profile_updated', OLD."member_id"
2256 );
2257 END IF;
2258 END IF;
2259 IF TG_OP = 'UPDATE' THEN
2260 IF OLD."member_id" = NEW."member_id" THEN
2261 RETURN NULL;
2262 END IF;
2263 END IF;
2264 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2265 INSERT INTO "event" ("event", "member_id") VALUES (
2266 'member_profile_updated', NEW."member_id"
2267 );
2268 END IF;
2269 RETURN NULL;
2270 END;
2271 $$;
2273 CREATE TRIGGER "write_event_member_profile_updated"
2274 AFTER INSERT OR UPDATE OR DELETE ON "member_profile"
2275 FOR EACH ROW EXECUTE PROCEDURE
2276 "write_event_member_profile_updated_trigger"();
2278 COMMENT ON FUNCTION "write_event_member_profile_updated_trigger"() IS 'Implementation of trigger "write_event_member_profile_updated" on table "member_profile"';
2279 COMMENT ON TRIGGER "write_event_member_profile_updated" ON "member_profile" IS 'Creates entries in "event" table on member profile update';
2282 CREATE FUNCTION "write_event_member_image_updated_trigger"()
2283 RETURNS TRIGGER
2284 LANGUAGE 'plpgsql' VOLATILE AS $$
2285 BEGIN
2286 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2287 IF NOT OLD."scaled" THEN
2288 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2289 INSERT INTO "event" ("event", "member_id") VALUES (
2290 'member_image_updated', OLD."member_id"
2291 );
2292 END IF;
2293 END IF;
2294 END IF;
2295 IF TG_OP = 'UPDATE' THEN
2296 IF
2297 OLD."member_id" = NEW."member_id" AND
2298 OLD."scaled" = NEW."scaled"
2299 THEN
2300 RETURN NULL;
2301 END IF;
2302 END IF;
2303 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2304 IF NOT NEW."scaled" THEN
2305 INSERT INTO "event" ("event", "member_id") VALUES (
2306 'member_image_updated', NEW."member_id"
2307 );
2308 END IF;
2309 END IF;
2310 RETURN NULL;
2311 END;
2312 $$;
2314 CREATE TRIGGER "write_event_member_image_updated"
2315 AFTER INSERT OR UPDATE OR DELETE ON "member_image"
2316 FOR EACH ROW EXECUTE PROCEDURE
2317 "write_event_member_image_updated_trigger"();
2319 COMMENT ON FUNCTION "write_event_member_image_updated_trigger"() IS 'Implementation of trigger "write_event_member_image_updated" on table "member_image"';
2320 COMMENT ON TRIGGER "write_event_member_image_updated" ON "member_image" IS 'Creates entries in "event" table on member image update';
2323 CREATE FUNCTION "write_event_interest_trigger"()
2324 RETURNS TRIGGER
2325 LANGUAGE 'plpgsql' VOLATILE AS $$
2326 DECLARE
2327 "issue_row" "issue"%ROWTYPE;
2328 "area_row" "area"%ROWTYPE;
2329 BEGIN
2330 IF TG_OP = 'UPDATE' THEN
2331 IF OLD = NEW THEN
2332 RETURN NULL;
2333 END IF;
2334 END IF;
2335 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2336 SELECT * INTO "issue_row" FROM "issue"
2337 WHERE "id" = OLD."issue_id" FOR SHARE;
2338 SELECT * INTO "area_row" FROM "area"
2339 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2340 IF "issue_row"."id" NOTNULL THEN
2341 INSERT INTO "event" (
2342 "event", "member_id",
2343 "unit_id", "area_id", "policy_id", "issue_id", "state",
2344 "boolean_value"
2345 ) VALUES (
2346 'interest', OLD."member_id",
2347 "area_row"."unit_id", "issue_row"."area_id",
2348 "issue_row"."policy_id",
2349 OLD."issue_id", "issue_row"."state",
2350 FALSE
2351 );
2352 END IF;
2353 END IF;
2354 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2355 SELECT * INTO "issue_row" FROM "issue"
2356 WHERE "id" = NEW."issue_id" FOR SHARE;
2357 SELECT * INTO "area_row" FROM "area"
2358 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2359 INSERT INTO "event" (
2360 "event", "member_id",
2361 "unit_id", "area_id", "policy_id", "issue_id", "state",
2362 "boolean_value"
2363 ) VALUES (
2364 'interest', NEW."member_id",
2365 "area_row"."unit_id", "issue_row"."area_id",
2366 "issue_row"."policy_id",
2367 NEW."issue_id", "issue_row"."state",
2368 TRUE
2369 );
2370 END IF;
2371 RETURN NULL;
2372 END;
2373 $$;
2375 CREATE TRIGGER "write_event_interest"
2376 AFTER INSERT OR UPDATE OR DELETE ON "interest" FOR EACH ROW EXECUTE PROCEDURE
2377 "write_event_interest_trigger"();
2379 COMMENT ON FUNCTION "write_event_interest_trigger"() IS 'Implementation of trigger "write_event_interest_inserted" on table "interest"';
2380 COMMENT ON TRIGGER "write_event_interest" ON "interest" IS 'Create entry in "event" table on adding or removing interest';
2383 CREATE FUNCTION "write_event_initiator_trigger"()
2384 RETURNS TRIGGER
2385 LANGUAGE 'plpgsql' VOLATILE AS $$
2386 DECLARE
2387 "initiative_row" "initiative"%ROWTYPE;
2388 "issue_row" "issue"%ROWTYPE;
2389 "area_row" "area"%ROWTYPE;
2390 "accepted_v" BOOLEAN = FALSE;
2391 "rejected_v" BOOLEAN = FALSE;
2392 BEGIN
2393 IF TG_OP = 'UPDATE' THEN
2394 IF
2395 OLD."initiative_id" = NEW."initiative_id" AND
2396 OLD."member_id" = NEW."member_id"
2397 THEN
2398 IF
2399 coalesce(OLD."accepted", FALSE) = coalesce(NEW."accepted", FALSE)
2400 THEN
2401 RETURN NULL;
2402 END IF;
2403 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2404 "accepted_v" := TRUE;
2405 ELSE
2406 "rejected_v" := TRUE;
2407 END IF;
2408 END IF;
2409 END IF;
2410 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "accepted_v" THEN
2411 IF coalesce(OLD."accepted", FALSE) = TRUE THEN
2412 SELECT * INTO "initiative_row" FROM "initiative"
2413 WHERE "id" = OLD."initiative_id" FOR SHARE;
2414 IF "initiative_row"."id" NOTNULL THEN
2415 SELECT * INTO "issue_row" FROM "issue"
2416 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2417 SELECT * INTO "area_row" FROM "area"
2418 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2419 INSERT INTO "event" (
2420 "event", "member_id",
2421 "unit_id", "area_id", "policy_id", "issue_id", "state",
2422 "initiative_id", "boolean_value"
2423 ) VALUES (
2424 'initiator', OLD."member_id",
2425 "area_row"."unit_id", "issue_row"."area_id",
2426 "issue_row"."policy_id",
2427 "issue_row"."id", "issue_row"."state",
2428 OLD."initiative_id", FALSE
2429 );
2430 END IF;
2431 END IF;
2432 END IF;
2433 IF TG_OP = 'UPDATE' AND NOT "rejected_v" THEN
2434 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2435 SELECT * INTO "initiative_row" FROM "initiative"
2436 WHERE "id" = NEW."initiative_id" FOR SHARE;
2437 SELECT * INTO "issue_row" FROM "issue"
2438 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2439 SELECT * INTO "area_row" FROM "area"
2440 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2441 INSERT INTO "event" (
2442 "event", "member_id",
2443 "unit_id", "area_id", "policy_id", "issue_id", "state",
2444 "initiative_id", "boolean_value"
2445 ) VALUES (
2446 'initiator', NEW."member_id",
2447 "area_row"."unit_id", "issue_row"."area_id",
2448 "issue_row"."policy_id",
2449 "issue_row"."id", "issue_row"."state",
2450 NEW."initiative_id", TRUE
2451 );
2452 END IF;
2453 END IF;
2454 RETURN NULL;
2455 END;
2456 $$;
2458 CREATE TRIGGER "write_event_initiator"
2459 AFTER UPDATE OR DELETE ON "initiator" FOR EACH ROW EXECUTE PROCEDURE
2460 "write_event_initiator_trigger"();
2462 COMMENT ON FUNCTION "write_event_initiator_trigger"() IS 'Implementation of trigger "write_event_initiator" on table "initiator"';
2463 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)';
2466 CREATE FUNCTION "write_event_support_trigger"()
2467 RETURNS TRIGGER
2468 LANGUAGE 'plpgsql' VOLATILE AS $$
2469 DECLARE
2470 "issue_row" "issue"%ROWTYPE;
2471 "area_row" "area"%ROWTYPE;
2472 BEGIN
2473 IF TG_OP = 'UPDATE' THEN
2474 IF
2475 OLD."initiative_id" = NEW."initiative_id" AND
2476 OLD."member_id" = NEW."member_id"
2477 THEN
2478 IF OLD."draft_id" != NEW."draft_id" THEN
2479 SELECT * INTO "issue_row" FROM "issue"
2480 WHERE "id" = NEW."issue_id" FOR SHARE;
2481 SELECT * INTO "area_row" FROM "area"
2482 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2483 INSERT INTO "event" (
2484 "event", "member_id",
2485 "unit_id", "area_id", "policy_id", "issue_id", "state",
2486 "initiative_id", "draft_id"
2487 ) VALUES (
2488 'support_updated', NEW."member_id",
2489 "area_row"."unit_id", "issue_row"."area_id",
2490 "issue_row"."policy_id",
2491 "issue_row"."id", "issue_row"."state",
2492 NEW."initiative_id", NEW."draft_id"
2493 );
2494 END IF;
2495 RETURN NULL;
2496 END IF;
2497 END IF;
2498 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2499 IF EXISTS (
2500 SELECT NULL FROM "initiative" WHERE "id" = OLD."initiative_id"
2501 FOR SHARE
2502 ) THEN
2503 SELECT * INTO "issue_row" FROM "issue"
2504 WHERE "id" = OLD."issue_id" FOR SHARE;
2505 SELECT * INTO "area_row" FROM "area"
2506 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2507 INSERT INTO "event" (
2508 "event", "member_id",
2509 "unit_id", "area_id", "policy_id", "issue_id", "state",
2510 "initiative_id", "boolean_value"
2511 ) VALUES (
2512 'support', OLD."member_id",
2513 "area_row"."unit_id", "issue_row"."area_id",
2514 "issue_row"."policy_id",
2515 "issue_row"."id", "issue_row"."state",
2516 OLD."initiative_id", FALSE
2517 );
2518 END IF;
2519 END IF;
2520 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2521 SELECT * INTO "issue_row" FROM "issue"
2522 WHERE "id" = NEW."issue_id" FOR SHARE;
2523 SELECT * INTO "area_row" FROM "area"
2524 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2525 INSERT INTO "event" (
2526 "event", "member_id",
2527 "unit_id", "area_id", "policy_id", "issue_id", "state",
2528 "initiative_id", "draft_id", "boolean_value"
2529 ) VALUES (
2530 'support', NEW."member_id",
2531 "area_row"."unit_id", "issue_row"."area_id",
2532 "issue_row"."policy_id",
2533 "issue_row"."id", "issue_row"."state",
2534 NEW."initiative_id", NEW."draft_id", TRUE
2535 );
2536 END IF;
2537 RETURN NULL;
2538 END;
2539 $$;
2541 CREATE TRIGGER "write_event_support"
2542 AFTER INSERT OR UPDATE OR DELETE ON "supporter" FOR EACH ROW EXECUTE PROCEDURE
2543 "write_event_support_trigger"();
2545 COMMENT ON FUNCTION "write_event_support_trigger"() IS 'Implementation of trigger "write_event_support" on table "supporter"';
2546 COMMENT ON TRIGGER "write_event_support" ON "supporter" IS 'Create entry in "event" table when adding, updating, or removing support';
2549 CREATE FUNCTION "write_event_suggestion_rated_trigger"()
2550 RETURNS TRIGGER
2551 LANGUAGE 'plpgsql' VOLATILE AS $$
2552 DECLARE
2553 "same_pkey_v" BOOLEAN = FALSE;
2554 "initiative_row" "initiative"%ROWTYPE;
2555 "issue_row" "issue"%ROWTYPE;
2556 "area_row" "area"%ROWTYPE;
2557 BEGIN
2558 IF TG_OP = 'UPDATE' THEN
2559 IF
2560 OLD."suggestion_id" = NEW."suggestion_id" AND
2561 OLD."member_id" = NEW."member_id"
2562 THEN
2563 IF
2564 OLD."degree" = NEW."degree" AND
2565 OLD."fulfilled" = NEW."fulfilled"
2566 THEN
2567 RETURN NULL;
2568 END IF;
2569 "same_pkey_v" := TRUE;
2570 END IF;
2571 END IF;
2572 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "same_pkey_v" THEN
2573 IF EXISTS (
2574 SELECT NULL FROM "suggestion" WHERE "id" = OLD."suggestion_id"
2575 FOR SHARE
2576 ) THEN
2577 SELECT * INTO "initiative_row" FROM "initiative"
2578 WHERE "id" = OLD."initiative_id" FOR SHARE;
2579 SELECT * INTO "issue_row" FROM "issue"
2580 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2581 SELECT * INTO "area_row" FROM "area"
2582 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2583 INSERT INTO "event" (
2584 "event", "member_id",
2585 "unit_id", "area_id", "policy_id", "issue_id", "state",
2586 "initiative_id", "suggestion_id",
2587 "boolean_value", "numeric_value"
2588 ) VALUES (
2589 'suggestion_rated', OLD."member_id",
2590 "area_row"."unit_id", "issue_row"."area_id",
2591 "issue_row"."policy_id",
2592 "initiative_row"."issue_id", "issue_row"."state",
2593 OLD."initiative_id", OLD."suggestion_id",
2594 NULL, 0
2595 );
2596 END IF;
2597 END IF;
2598 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2599 SELECT * INTO "initiative_row" FROM "initiative"
2600 WHERE "id" = NEW."initiative_id" FOR SHARE;
2601 SELECT * INTO "issue_row" FROM "issue"
2602 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2603 SELECT * INTO "area_row" FROM "area"
2604 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2605 INSERT INTO "event" (
2606 "event", "member_id",
2607 "unit_id", "area_id", "policy_id", "issue_id", "state",
2608 "initiative_id", "suggestion_id",
2609 "boolean_value", "numeric_value"
2610 ) VALUES (
2611 'suggestion_rated', NEW."member_id",
2612 "area_row"."unit_id", "issue_row"."area_id",
2613 "issue_row"."policy_id",
2614 "initiative_row"."issue_id", "issue_row"."state",
2615 NEW."initiative_id", NEW."suggestion_id",
2616 NEW."fulfilled", NEW."degree"
2617 );
2618 END IF;
2619 RETURN NULL;
2620 END;
2621 $$;
2623 CREATE TRIGGER "write_event_suggestion_rated"
2624 AFTER INSERT OR UPDATE OR DELETE ON "opinion" FOR EACH ROW EXECUTE PROCEDURE
2625 "write_event_suggestion_rated_trigger"();
2627 COMMENT ON FUNCTION "write_event_suggestion_rated_trigger"() IS 'Implementation of trigger "write_event_suggestion_rated" on table "opinion"';
2628 COMMENT ON TRIGGER "write_event_suggestion_rated" ON "opinion" IS 'Create entry in "event" table when adding, updating, or removing support';
2631 CREATE FUNCTION "write_event_delegation_trigger"()
2632 RETURNS TRIGGER
2633 LANGUAGE 'plpgsql' VOLATILE AS $$
2634 DECLARE
2635 "issue_row" "issue"%ROWTYPE;
2636 "area_row" "area"%ROWTYPE;
2637 BEGIN
2638 IF TG_OP = 'DELETE' THEN
2639 IF EXISTS (
2640 SELECT NULL FROM "member" WHERE "id" = OLD."truster_id"
2641 ) AND (CASE OLD."scope"
2642 WHEN 'unit'::"delegation_scope" THEN EXISTS (
2643 SELECT NULL FROM "unit" WHERE "id" = OLD."unit_id"
2645 WHEN 'area'::"delegation_scope" THEN EXISTS (
2646 SELECT NULL FROM "area" WHERE "id" = OLD."area_id"
2648 WHEN 'issue'::"delegation_scope" THEN EXISTS (
2649 SELECT NULL FROM "issue" WHERE "id" = OLD."issue_id"
2651 END) THEN
2652 SELECT * INTO "issue_row" FROM "issue"
2653 WHERE "id" = OLD."issue_id" FOR SHARE;
2654 SELECT * INTO "area_row" FROM "area"
2655 WHERE "id" = COALESCE(OLD."area_id", "issue_row"."area_id")
2656 FOR SHARE;
2657 INSERT INTO "event" (
2658 "event", "member_id", "scope",
2659 "unit_id", "area_id", "issue_id", "state",
2660 "boolean_value"
2661 ) VALUES (
2662 'delegation', OLD."truster_id", OLD."scope",
2663 COALESCE(OLD."unit_id", "area_row"."unit_id"), "area_row"."id",
2664 OLD."issue_id", "issue_row"."state",
2665 FALSE
2666 );
2667 END IF;
2668 ELSE
2669 SELECT * INTO "issue_row" FROM "issue"
2670 WHERE "id" = NEW."issue_id" FOR SHARE;
2671 SELECT * INTO "area_row" FROM "area"
2672 WHERE "id" = COALESCE(NEW."area_id", "issue_row"."area_id")
2673 FOR SHARE;
2674 INSERT INTO "event" (
2675 "event", "member_id", "other_member_id", "scope",
2676 "unit_id", "area_id", "issue_id", "state",
2677 "boolean_value"
2678 ) VALUES (
2679 'delegation', NEW."truster_id", NEW."trustee_id", NEW."scope",
2680 COALESCE(NEW."unit_id", "area_row"."unit_id"), "area_row"."id",
2681 NEW."issue_id", "issue_row"."state",
2682 TRUE
2683 );
2684 END IF;
2685 RETURN NULL;
2686 END;
2687 $$;
2689 CREATE TRIGGER "write_event_delegation"
2690 AFTER INSERT OR UPDATE OR DELETE ON "delegation" FOR EACH ROW EXECUTE PROCEDURE
2691 "write_event_delegation_trigger"();
2693 COMMENT ON FUNCTION "write_event_delegation_trigger"() IS 'Implementation of trigger "write_event_delegation" on table "delegation"';
2694 COMMENT ON TRIGGER "write_event_delegation" ON "delegation" IS 'Create entry in "event" table when adding, updating, or removing a delegation';
2697 CREATE FUNCTION "write_event_contact_trigger"()
2698 RETURNS TRIGGER
2699 LANGUAGE 'plpgsql' VOLATILE AS $$
2700 BEGIN
2701 IF TG_OP = 'UPDATE' THEN
2702 IF
2703 OLD."member_id" = NEW."member_id" AND
2704 OLD."other_member_id" = NEW."other_member_id" AND
2705 OLD."public" = NEW."public"
2706 THEN
2707 RETURN NULL;
2708 END IF;
2709 END IF;
2710 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2711 IF OLD."public" THEN
2712 IF EXISTS (
2713 SELECT NULL FROM "member" WHERE "id" = OLD."member_id"
2714 FOR SHARE
2715 ) AND EXISTS (
2716 SELECT NULL FROM "member" WHERE "id" = OLD."other_member_id"
2717 FOR SHARE
2718 ) THEN
2719 INSERT INTO "event" (
2720 "event", "member_id", "other_member_id", "boolean_value"
2721 ) VALUES (
2722 'contact', OLD."member_id", OLD."other_member_id", FALSE
2723 );
2724 END IF;
2725 END IF;
2726 END IF;
2727 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2728 IF NEW."public" THEN
2729 INSERT INTO "event" (
2730 "event", "member_id", "other_member_id", "boolean_value"
2731 ) VALUES (
2732 'contact', NEW."member_id", NEW."other_member_id", TRUE
2733 );
2734 END IF;
2735 END IF;
2736 RETURN NULL;
2737 END;
2738 $$;
2740 CREATE TRIGGER "write_event_contact"
2741 AFTER INSERT OR UPDATE OR DELETE ON "contact" FOR EACH ROW EXECUTE PROCEDURE
2742 "write_event_contact_trigger"();
2744 COMMENT ON FUNCTION "write_event_contact_trigger"() IS 'Implementation of trigger "write_event_contact" on table "contact"';
2745 COMMENT ON TRIGGER "write_event_contact" ON "contact" IS 'Create entry in "event" table when adding or removing public contacts';
2748 CREATE FUNCTION "write_event_posting_trigger"()
2749 RETURNS TRIGGER
2750 LANGUAGE 'plpgsql' VOLATILE AS $$
2751 BEGIN
2752 INSERT INTO "event" (
2753 "event", "posting_id", "member_id",
2754 "unit_id", "area_id", "policy_id",
2755 "issue_id", "initiative_id", "suggestion_id"
2756 ) VALUES (
2757 'posting_created', NEW."id", NEW."author_id",
2758 NEW."unit_id", NEW."area_id", NEW."policy_id",
2759 NEW."issue_id", NEW."initiative_id", NEW."suggestion_id"
2760 );
2761 RETURN NULL;
2762 END;
2763 $$;
2765 CREATE TRIGGER "write_event_posting"
2766 AFTER INSERT ON "posting" FOR EACH ROW EXECUTE PROCEDURE
2767 "write_event_posting_trigger"();
2769 COMMENT ON FUNCTION "write_event_posting_trigger"() IS 'Implementation of trigger "write_event_posting" on table "posting"';
2770 COMMENT ON TRIGGER "write_event_posting" ON "posting" IS 'Create entry in "event" table when creating a new posting';
2773 CREATE FUNCTION "send_event_notify_trigger"()
2774 RETURNS TRIGGER
2775 LANGUAGE 'plpgsql' VOLATILE AS $$
2776 BEGIN
2777 EXECUTE 'NOTIFY "event", ''' || NEW."event" || '''';
2778 RETURN NULL;
2779 END;
2780 $$;
2782 CREATE TRIGGER "send_notify"
2783 AFTER INSERT OR UPDATE ON "event" FOR EACH ROW EXECUTE PROCEDURE
2784 "send_event_notify_trigger"();
2788 ----------------------------
2789 -- Additional constraints --
2790 ----------------------------
2793 CREATE FUNCTION "delete_extended_scope_tokens_trigger"()
2794 RETURNS TRIGGER
2795 LANGUAGE 'plpgsql' VOLATILE AS $$
2796 DECLARE
2797 "system_application_row" "system_application"%ROWTYPE;
2798 BEGIN
2799 IF OLD."system_application_id" NOTNULL THEN
2800 SELECT * FROM "system_application" INTO "system_application_row"
2801 WHERE "id" = OLD."system_application_id";
2802 DELETE FROM "token"
2803 WHERE "member_id" = OLD."member_id"
2804 AND "system_application_id" = OLD."system_application_id"
2805 AND NOT COALESCE(
2806 regexp_split_to_array("scope", E'\\s+') <@
2807 regexp_split_to_array(
2808 "system_application_row"."automatic_scope", E'\\s+'
2809 ),
2810 FALSE
2811 );
2812 END IF;
2813 RETURN OLD;
2814 END;
2815 $$;
2817 CREATE TRIGGER "delete_extended_scope_tokens"
2818 BEFORE DELETE ON "member_application" FOR EACH ROW EXECUTE PROCEDURE
2819 "delete_extended_scope_tokens_trigger"();
2822 CREATE FUNCTION "detach_token_from_session_trigger"()
2823 RETURNS TRIGGER
2824 LANGUAGE 'plpgsql' VOLATILE AS $$
2825 BEGIN
2826 UPDATE "token" SET "session_id" = NULL
2827 WHERE "session_id" = OLD."id";
2828 RETURN OLD;
2829 END;
2830 $$;
2832 CREATE TRIGGER "detach_token_from_session"
2833 BEFORE DELETE ON "session" FOR EACH ROW EXECUTE PROCEDURE
2834 "detach_token_from_session_trigger"();
2837 CREATE FUNCTION "delete_non_detached_scope_with_session_trigger"()
2838 RETURNS TRIGGER
2839 LANGUAGE 'plpgsql' VOLATILE AS $$
2840 BEGIN
2841 IF NEW."session_id" ISNULL THEN
2842 SELECT coalesce(string_agg("element", ' '), '') INTO NEW."scope"
2843 FROM unnest(regexp_split_to_array(NEW."scope", E'\\s+')) AS "element"
2844 WHERE "element" LIKE '%_detached';
2845 END IF;
2846 RETURN NEW;
2847 END;
2848 $$;
2850 CREATE TRIGGER "delete_non_detached_scope_with_session"
2851 BEFORE INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2852 "delete_non_detached_scope_with_session_trigger"();
2855 CREATE FUNCTION "delete_token_with_empty_scope_trigger"()
2856 RETURNS TRIGGER
2857 LANGUAGE 'plpgsql' VOLATILE AS $$
2858 BEGIN
2859 IF NEW."scope" = '' THEN
2860 DELETE FROM "token" WHERE "id" = NEW."id";
2861 END IF;
2862 RETURN NULL;
2863 END;
2864 $$;
2866 CREATE TRIGGER "delete_token_with_empty_scope"
2867 AFTER INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2868 "delete_token_with_empty_scope_trigger"();
2871 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
2872 RETURNS TRIGGER
2873 LANGUAGE 'plpgsql' VOLATILE AS $$
2874 BEGIN
2875 IF NOT EXISTS (
2876 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
2877 ) THEN
2878 RAISE EXCEPTION 'Cannot create issue without an initial initiative.' USING
2879 ERRCODE = 'integrity_constraint_violation',
2880 HINT = 'Create issue, initiative, and draft within the same transaction.';
2881 END IF;
2882 RETURN NULL;
2883 END;
2884 $$;
2886 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
2887 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
2888 FOR EACH ROW EXECUTE PROCEDURE
2889 "issue_requires_first_initiative_trigger"();
2891 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
2892 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
2895 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
2896 RETURNS TRIGGER
2897 LANGUAGE 'plpgsql' VOLATILE AS $$
2898 DECLARE
2899 "reference_lost" BOOLEAN;
2900 BEGIN
2901 IF TG_OP = 'DELETE' THEN
2902 "reference_lost" := TRUE;
2903 ELSE
2904 "reference_lost" := NEW."issue_id" != OLD."issue_id";
2905 END IF;
2906 IF
2907 "reference_lost" AND NOT EXISTS (
2908 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
2910 THEN
2911 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
2912 END IF;
2913 RETURN NULL;
2914 END;
2915 $$;
2917 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
2918 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
2919 FOR EACH ROW EXECUTE PROCEDURE
2920 "last_initiative_deletes_issue_trigger"();
2922 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
2923 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
2926 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
2927 RETURNS TRIGGER
2928 LANGUAGE 'plpgsql' VOLATILE AS $$
2929 BEGIN
2930 IF NOT EXISTS (
2931 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
2932 ) THEN
2933 RAISE EXCEPTION 'Cannot create initiative without an initial draft.' USING
2934 ERRCODE = 'integrity_constraint_violation',
2935 HINT = 'Create issue, initiative and draft within the same transaction.';
2936 END IF;
2937 RETURN NULL;
2938 END;
2939 $$;
2941 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
2942 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
2943 FOR EACH ROW EXECUTE PROCEDURE
2944 "initiative_requires_first_draft_trigger"();
2946 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
2947 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
2950 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
2951 RETURNS TRIGGER
2952 LANGUAGE 'plpgsql' VOLATILE AS $$
2953 DECLARE
2954 "reference_lost" BOOLEAN;
2955 BEGIN
2956 IF TG_OP = 'DELETE' THEN
2957 "reference_lost" := TRUE;
2958 ELSE
2959 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
2960 END IF;
2961 IF
2962 "reference_lost" AND NOT EXISTS (
2963 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
2965 THEN
2966 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
2967 END IF;
2968 RETURN NULL;
2969 END;
2970 $$;
2972 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
2973 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
2974 FOR EACH ROW EXECUTE PROCEDURE
2975 "last_draft_deletes_initiative_trigger"();
2977 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
2978 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
2981 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
2982 RETURNS TRIGGER
2983 LANGUAGE 'plpgsql' VOLATILE AS $$
2984 BEGIN
2985 IF NOT EXISTS (
2986 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
2987 ) THEN
2988 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.' USING
2989 ERRCODE = 'integrity_constraint_violation',
2990 HINT = 'Create suggestion and opinion within the same transaction.';
2991 END IF;
2992 RETURN NULL;
2993 END;
2994 $$;
2996 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
2997 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
2998 FOR EACH ROW EXECUTE PROCEDURE
2999 "suggestion_requires_first_opinion_trigger"();
3001 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
3002 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
3005 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
3006 RETURNS TRIGGER
3007 LANGUAGE 'plpgsql' VOLATILE AS $$
3008 DECLARE
3009 "reference_lost" BOOLEAN;
3010 BEGIN
3011 IF TG_OP = 'DELETE' THEN
3012 "reference_lost" := TRUE;
3013 ELSE
3014 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
3015 END IF;
3016 IF
3017 "reference_lost" AND NOT EXISTS (
3018 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
3020 THEN
3021 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
3022 END IF;
3023 RETURN NULL;
3024 END;
3025 $$;
3027 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
3028 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
3029 FOR EACH ROW EXECUTE PROCEDURE
3030 "last_opinion_deletes_suggestion_trigger"();
3032 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
3033 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
3036 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
3037 RETURNS TRIGGER
3038 LANGUAGE 'plpgsql' VOLATILE AS $$
3039 BEGIN
3040 DELETE FROM "direct_voter"
3041 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
3042 RETURN NULL;
3043 END;
3044 $$;
3046 CREATE TRIGGER "non_voter_deletes_direct_voter"
3047 AFTER INSERT OR UPDATE ON "non_voter"
3048 FOR EACH ROW EXECUTE PROCEDURE
3049 "non_voter_deletes_direct_voter_trigger"();
3051 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
3052 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")';
3055 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
3056 RETURNS TRIGGER
3057 LANGUAGE 'plpgsql' VOLATILE AS $$
3058 BEGIN
3059 DELETE FROM "non_voter"
3060 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
3061 RETURN NULL;
3062 END;
3063 $$;
3065 CREATE TRIGGER "direct_voter_deletes_non_voter"
3066 AFTER INSERT OR UPDATE ON "direct_voter"
3067 FOR EACH ROW EXECUTE PROCEDURE
3068 "direct_voter_deletes_non_voter_trigger"();
3070 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
3071 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")';
3074 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
3075 RETURNS TRIGGER
3076 LANGUAGE 'plpgsql' VOLATILE AS $$
3077 BEGIN
3078 IF NEW."comment" ISNULL THEN
3079 NEW."comment_changed" := NULL;
3080 NEW."formatting_engine" := NULL;
3081 END IF;
3082 RETURN NEW;
3083 END;
3084 $$;
3086 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
3087 BEFORE INSERT OR UPDATE ON "direct_voter"
3088 FOR EACH ROW EXECUTE PROCEDURE
3089 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
3091 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"';
3092 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.';
3096 ---------------------------------
3097 -- Delete incomplete snapshots --
3098 ---------------------------------
3101 CREATE FUNCTION "delete_snapshot_on_partial_delete_trigger"()
3102 RETURNS TRIGGER
3103 LANGUAGE 'plpgsql' VOLATILE AS $$
3104 BEGIN
3105 IF TG_OP = 'UPDATE' THEN
3106 IF
3107 OLD."snapshot_id" = NEW."snapshot_id" AND
3108 OLD."issue_id" = NEW."issue_id"
3109 THEN
3110 RETURN NULL;
3111 END IF;
3112 END IF;
3113 DELETE FROM "snapshot" WHERE "id" = OLD."snapshot_id";
3114 RETURN NULL;
3115 END;
3116 $$;
3118 CREATE TRIGGER "delete_snapshot_on_partial_delete"
3119 AFTER UPDATE OR DELETE ON "snapshot_issue"
3120 FOR EACH ROW EXECUTE PROCEDURE
3121 "delete_snapshot_on_partial_delete_trigger"();
3123 COMMENT ON FUNCTION "delete_snapshot_on_partial_delete_trigger"() IS 'Implementation of trigger "delete_snapshot_on_partial_delete" on table "snapshot_issue"';
3124 COMMENT ON TRIGGER "delete_snapshot_on_partial_delete" ON "snapshot_issue" IS 'Deletes whole snapshot if one issue is deleted from the snapshot';
3128 ---------------------------------------------------------------
3129 -- Ensure that votes are not modified when issues are closed --
3130 ---------------------------------------------------------------
3132 -- NOTE: Frontends should ensure this anyway, but in case of programming
3133 -- errors the following triggers ensure data integrity.
3136 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
3137 RETURNS TRIGGER
3138 LANGUAGE 'plpgsql' VOLATILE AS $$
3139 DECLARE
3140 "issue_id_v" "issue"."id"%TYPE;
3141 "issue_row" "issue"%ROWTYPE;
3142 BEGIN
3143 IF EXISTS (
3144 SELECT NULL FROM "temporary_transaction_data"
3145 WHERE "txid" = txid_current()
3146 AND "key" = 'override_protection_triggers'
3147 AND "value" = TRUE::TEXT
3148 ) THEN
3149 RETURN NULL;
3150 END IF;
3151 IF TG_OP = 'DELETE' THEN
3152 "issue_id_v" := OLD."issue_id";
3153 ELSE
3154 "issue_id_v" := NEW."issue_id";
3155 END IF;
3156 SELECT INTO "issue_row" * FROM "issue"
3157 WHERE "id" = "issue_id_v" FOR SHARE;
3158 IF (
3159 "issue_row"."closed" NOTNULL OR (
3160 "issue_row"."state" = 'voting' AND
3161 "issue_row"."phase_finished" NOTNULL
3163 ) THEN
3164 IF
3165 TG_RELID = 'direct_voter'::regclass AND
3166 TG_OP = 'UPDATE'
3167 THEN
3168 IF
3169 OLD."issue_id" = NEW."issue_id" AND
3170 OLD."member_id" = NEW."member_id" AND
3171 OLD."weight" = NEW."weight"
3172 THEN
3173 RETURN NULL; -- allows changing of voter comment
3174 END IF;
3175 END IF;
3176 RAISE EXCEPTION 'Tried to modify data after voting has been closed.' USING
3177 ERRCODE = 'integrity_constraint_violation';
3178 END IF;
3179 RETURN NULL;
3180 END;
3181 $$;
3183 CREATE TRIGGER "forbid_changes_on_closed_issue"
3184 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
3185 FOR EACH ROW EXECUTE PROCEDURE
3186 "forbid_changes_on_closed_issue_trigger"();
3188 CREATE TRIGGER "forbid_changes_on_closed_issue"
3189 AFTER INSERT OR UPDATE OR DELETE ON "delegating_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 "vote"
3195 FOR EACH ROW EXECUTE PROCEDURE
3196 "forbid_changes_on_closed_issue_trigger"();
3198 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"';
3199 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';
3200 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';
3201 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';
3205 --------------------------------------------------------------------
3206 -- Auto-retrieval of fields only needed for referential integrity --
3207 --------------------------------------------------------------------
3210 CREATE FUNCTION "autofill_issue_id_trigger"()
3211 RETURNS TRIGGER
3212 LANGUAGE 'plpgsql' VOLATILE AS $$
3213 BEGIN
3214 IF NEW."issue_id" ISNULL THEN
3215 SELECT "issue_id" INTO NEW."issue_id"
3216 FROM "initiative" WHERE "id" = NEW."initiative_id";
3217 END IF;
3218 RETURN NEW;
3219 END;
3220 $$;
3222 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
3223 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3225 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
3226 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3228 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
3229 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
3230 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
3233 CREATE FUNCTION "autofill_initiative_id_trigger"()
3234 RETURNS TRIGGER
3235 LANGUAGE 'plpgsql' VOLATILE AS $$
3236 BEGIN
3237 IF NEW."initiative_id" ISNULL THEN
3238 SELECT "initiative_id" INTO NEW."initiative_id"
3239 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3240 END IF;
3241 RETURN NEW;
3242 END;
3243 $$;
3245 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
3246 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
3248 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
3249 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
3253 -------------------------------------------------------
3254 -- Automatic copying of values for indexing purposes --
3255 -------------------------------------------------------
3258 CREATE FUNCTION "copy_current_draft_data"
3259 ("initiative_id_p" "initiative"."id"%TYPE )
3260 RETURNS VOID
3261 LANGUAGE 'plpgsql' VOLATILE AS $$
3262 BEGIN
3263 PERFORM NULL FROM "initiative" WHERE "id" = "initiative_id_p"
3264 FOR UPDATE;
3265 UPDATE "initiative" SET
3266 "location" = "draft"."location",
3267 "draft_text_search_data" = "draft"."text_search_data"
3268 FROM "current_draft" AS "draft"
3269 WHERE "initiative"."id" = "initiative_id_p"
3270 AND "draft"."initiative_id" = "initiative_id_p";
3271 END;
3272 $$;
3274 COMMENT ON FUNCTION "copy_current_draft_data"
3275 ( "initiative"."id"%TYPE )
3276 IS 'Helper function for function "copy_current_draft_data_trigger"';
3279 CREATE FUNCTION "copy_current_draft_data_trigger"()
3280 RETURNS TRIGGER
3281 LANGUAGE 'plpgsql' VOLATILE AS $$
3282 BEGIN
3283 IF TG_OP='DELETE' THEN
3284 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3285 ELSE
3286 IF TG_OP='UPDATE' THEN
3287 IF COALESCE(OLD."inititiave_id" != NEW."initiative_id", TRUE) THEN
3288 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3289 END IF;
3290 END IF;
3291 PERFORM "copy_current_draft_data"(NEW."initiative_id");
3292 END IF;
3293 RETURN NULL;
3294 END;
3295 $$;
3297 CREATE TRIGGER "copy_current_draft_data"
3298 AFTER INSERT OR UPDATE OR DELETE ON "draft"
3299 FOR EACH ROW EXECUTE PROCEDURE
3300 "copy_current_draft_data_trigger"();
3302 COMMENT ON FUNCTION "copy_current_draft_data_trigger"() IS 'Implementation of trigger "copy_current_draft_data" on table "draft"';
3303 COMMENT ON TRIGGER "copy_current_draft_data" ON "draft" IS 'Copy certain fields from most recent "draft" to "initiative"';
3307 -----------------------------------------------------
3308 -- Automatic calculation of certain default values --
3309 -----------------------------------------------------
3312 CREATE FUNCTION "copy_timings_trigger"()
3313 RETURNS TRIGGER
3314 LANGUAGE 'plpgsql' VOLATILE AS $$
3315 DECLARE
3316 "policy_row" "policy"%ROWTYPE;
3317 BEGIN
3318 SELECT * INTO "policy_row" FROM "policy"
3319 WHERE "id" = NEW."policy_id";
3320 IF NEW."min_admission_time" ISNULL THEN
3321 NEW."min_admission_time" := "policy_row"."min_admission_time";
3322 END IF;
3323 IF NEW."max_admission_time" ISNULL THEN
3324 NEW."max_admission_time" := "policy_row"."max_admission_time";
3325 END IF;
3326 IF NEW."discussion_time" ISNULL THEN
3327 NEW."discussion_time" := "policy_row"."discussion_time";
3328 END IF;
3329 IF NEW."verification_time" ISNULL THEN
3330 NEW."verification_time" := "policy_row"."verification_time";
3331 END IF;
3332 IF NEW."voting_time" ISNULL THEN
3333 NEW."voting_time" := "policy_row"."voting_time";
3334 END IF;
3335 RETURN NEW;
3336 END;
3337 $$;
3339 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
3340 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
3342 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
3343 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
3346 CREATE FUNCTION "default_for_draft_id_trigger"()
3347 RETURNS TRIGGER
3348 LANGUAGE 'plpgsql' VOLATILE AS $$
3349 BEGIN
3350 IF NEW."draft_id" ISNULL THEN
3351 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
3352 WHERE "initiative_id" = NEW."initiative_id";
3353 END IF;
3354 RETURN NEW;
3355 END;
3356 $$;
3358 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
3359 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3360 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
3361 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3363 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
3364 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';
3365 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';
3369 ----------------------------------------
3370 -- Automatic creation of dependencies --
3371 ----------------------------------------
3374 CREATE FUNCTION "autocreate_interest_trigger"()
3375 RETURNS TRIGGER
3376 LANGUAGE 'plpgsql' VOLATILE AS $$
3377 BEGIN
3378 IF NOT EXISTS (
3379 SELECT NULL FROM "initiative" JOIN "interest"
3380 ON "initiative"."issue_id" = "interest"."issue_id"
3381 WHERE "initiative"."id" = NEW."initiative_id"
3382 AND "interest"."member_id" = NEW."member_id"
3383 ) THEN
3384 BEGIN
3385 INSERT INTO "interest" ("issue_id", "member_id")
3386 SELECT "issue_id", NEW."member_id"
3387 FROM "initiative" WHERE "id" = NEW."initiative_id";
3388 EXCEPTION WHEN unique_violation THEN END;
3389 END IF;
3390 RETURN NEW;
3391 END;
3392 $$;
3394 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
3395 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
3397 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
3398 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';
3401 CREATE FUNCTION "autocreate_supporter_trigger"()
3402 RETURNS TRIGGER
3403 LANGUAGE 'plpgsql' VOLATILE AS $$
3404 BEGIN
3405 IF NOT EXISTS (
3406 SELECT NULL FROM "suggestion" JOIN "supporter"
3407 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
3408 WHERE "suggestion"."id" = NEW."suggestion_id"
3409 AND "supporter"."member_id" = NEW."member_id"
3410 ) THEN
3411 BEGIN
3412 INSERT INTO "supporter" ("initiative_id", "member_id")
3413 SELECT "initiative_id", NEW."member_id"
3414 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3415 EXCEPTION WHEN unique_violation THEN END;
3416 END IF;
3417 RETURN NEW;
3418 END;
3419 $$;
3421 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
3422 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
3424 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
3425 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.';
3429 ------------------------------------------
3430 -- Views and helper functions for views --
3431 ------------------------------------------
3434 CREATE VIEW "member_eligible_to_be_notified" AS
3435 SELECT * FROM "member"
3436 WHERE "activated" NOTNULL AND "locked" = FALSE;
3438 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")';
3441 CREATE VIEW "member_to_notify" AS
3442 SELECT * FROM "member_eligible_to_be_notified"
3443 WHERE "disable_notifications" = FALSE;
3445 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)';
3448 CREATE VIEW "follower" AS
3449 SELECT
3450 "id" AS "follower_id",
3451 ( SELECT ARRAY["member"."id"] || array_agg("contact"."other_member_id")
3452 FROM "contact"
3453 WHERE "contact"."member_id" = "member"."id" AND "contact"."following" )
3454 AS "following_ids"
3455 FROM "member";
3457 COMMENT ON VIEW "follower" IS 'Provides the contacts of each member that are being followed (including the member itself) as an array of IDs';
3460 CREATE VIEW "area_quorum" AS
3461 SELECT
3462 "area"."id" AS "area_id",
3463 ceil(
3464 "area"."quorum_standard"::FLOAT8 * "quorum_factor"::FLOAT8 ^ (
3465 coalesce(
3466 ( SELECT sum(
3467 ( extract(epoch from "area"."quorum_time")::FLOAT8 /
3468 extract(epoch from
3469 ("issue"."accepted"-"issue"."created") +
3470 "issue"."discussion_time" +
3471 "issue"."verification_time" +
3472 "issue"."voting_time"
3473 )::FLOAT8
3474 ) ^ "area"."quorum_exponent"::FLOAT8
3476 FROM "issue" JOIN "policy"
3477 ON "issue"."policy_id" = "policy"."id"
3478 WHERE "issue"."area_id" = "area"."id"
3479 AND "issue"."accepted" NOTNULL
3480 AND "issue"."closed" ISNULL
3481 AND "policy"."polling" = FALSE
3482 )::FLOAT8, 0::FLOAT8
3483 ) / "area"."quorum_issues"::FLOAT8 - 1::FLOAT8
3484 ) * CASE WHEN "area"."quorum_den" ISNULL THEN 1 ELSE (
3485 SELECT "snapshot"."population"
3486 FROM "snapshot"
3487 WHERE "snapshot"."area_id" = "area"."id"
3488 AND "snapshot"."issue_id" ISNULL
3489 ORDER BY "snapshot"."id" DESC
3490 LIMIT 1
3491 ) END / coalesce("area"."quorum_den", 1)
3493 )::INT4 AS "issue_quorum"
3494 FROM "area";
3496 COMMENT ON VIEW "area_quorum" IS 'Area-based quorum considering number of open (accepted) issues';
3499 CREATE VIEW "issue_quorum" AS
3500 SELECT DISTINCT ON ("issue_id")
3501 "issue"."id" AS "issue_id",
3502 "subquery"."issue_quorum"
3503 FROM "issue"
3504 CROSS JOIN LATERAL (
3505 SELECT "area_quorum"."issue_quorum"
3506 FROM "area_quorum" WHERE "area_quorum"."area_id" = "issue"."area_id"
3507 UNION ALL
3508 SELECT "policy"."issue_quorum"
3509 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3510 UNION ALL
3511 SELECT
3512 ceil(
3513 ("issue"."population"::INT8 * "policy"."issue_quorum_num"::INT8) /
3514 "policy"."issue_quorum_den"::FLOAT8
3515 )::INT4
3516 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3517 ) AS "subquery"
3518 ORDER BY "issue_id", "issue_quorum" DESC;
3520 COMMENT ON VIEW "issue_quorum" IS 'Effective quorum for issue admission';
3523 CREATE VIEW "area_with_unaccepted_issues" AS
3524 SELECT DISTINCT ON ("area"."id") "area".*
3525 FROM "area" JOIN "issue" ON "area"."id" = "issue"."area_id"
3526 WHERE "issue"."state" = 'admission';
3528 COMMENT ON VIEW "area_with_unaccepted_issues" IS 'All areas with unaccepted open issues (needed for issue admission system)';
3531 CREATE VIEW "issue_for_admission" AS
3532 SELECT DISTINCT ON ("issue"."area_id")
3533 "issue".*,
3534 max("initiative"."supporter_count") AS "max_supporter_count"
3535 FROM "issue"
3536 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
3537 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
3538 JOIN "area" ON "issue"."area_id" = "area"."id"
3539 WHERE "issue"."state" = 'admission'::"issue_state"
3540 AND now() >= "issue"."created" + "issue"."min_admission_time"
3541 AND "initiative"."supporter_count" >= "policy"."issue_quorum"
3542 AND "initiative"."supporter_count" * "policy"."issue_quorum_den" >=
3543 "issue"."population" * "policy"."issue_quorum_num"
3544 AND "initiative"."supporter_count" >= "area"."issue_quorum"
3545 AND "initiative"."revoked" ISNULL
3546 GROUP BY "issue"."id"
3547 ORDER BY "issue"."area_id", "max_supporter_count" DESC, "issue"."id";
3549 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';
3552 CREATE VIEW "unit_delegation" AS
3553 SELECT
3554 "unit"."id" AS "unit_id",
3555 "delegation"."id",
3556 "delegation"."truster_id",
3557 "delegation"."trustee_id",
3558 "delegation"."scope"
3559 FROM "unit"
3560 JOIN "delegation"
3561 ON "delegation"."unit_id" = "unit"."id"
3562 JOIN "member"
3563 ON "delegation"."truster_id" = "member"."id"
3564 JOIN "privilege"
3565 ON "delegation"."unit_id" = "privilege"."unit_id"
3566 AND "delegation"."truster_id" = "privilege"."member_id"
3567 WHERE "member"."active" AND "privilege"."voting_right";
3569 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
3572 CREATE VIEW "area_delegation" AS
3573 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
3574 "area"."id" AS "area_id",
3575 "delegation"."id",
3576 "delegation"."truster_id",
3577 "delegation"."trustee_id",
3578 "delegation"."scope"
3579 FROM "area"
3580 JOIN "delegation"
3581 ON "delegation"."unit_id" = "area"."unit_id"
3582 OR "delegation"."area_id" = "area"."id"
3583 JOIN "member"
3584 ON "delegation"."truster_id" = "member"."id"
3585 JOIN "privilege"
3586 ON "area"."unit_id" = "privilege"."unit_id"
3587 AND "delegation"."truster_id" = "privilege"."member_id"
3588 WHERE "member"."active" AND "privilege"."voting_right"
3589 ORDER BY
3590 "area"."id",
3591 "delegation"."truster_id",
3592 "delegation"."scope" DESC;
3594 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
3597 CREATE VIEW "issue_delegation" AS
3598 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
3599 "issue"."id" AS "issue_id",
3600 "delegation"."id",
3601 "delegation"."truster_id",
3602 "delegation"."trustee_id",
3603 "delegation"."scope"
3604 FROM "issue"
3605 JOIN "area"
3606 ON "area"."id" = "issue"."area_id"
3607 JOIN "delegation"
3608 ON "delegation"."unit_id" = "area"."unit_id"
3609 OR "delegation"."area_id" = "area"."id"
3610 OR "delegation"."issue_id" = "issue"."id"
3611 JOIN "member"
3612 ON "delegation"."truster_id" = "member"."id"
3613 JOIN "privilege"
3614 ON "area"."unit_id" = "privilege"."unit_id"
3615 AND "delegation"."truster_id" = "privilege"."member_id"
3616 WHERE "member"."active" AND "privilege"."voting_right"
3617 ORDER BY
3618 "issue"."id",
3619 "delegation"."truster_id",
3620 "delegation"."scope" DESC;
3622 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
3625 CREATE VIEW "member_count_view" AS
3626 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
3628 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
3631 CREATE VIEW "unit_member" AS
3632 SELECT
3633 "unit"."id" AS "unit_id",
3634 "member"."id" AS "member_id"
3635 FROM "privilege"
3636 JOIN "unit" ON "unit"."id" = "privilege"."unit_id"
3637 JOIN "member" ON "member"."id" = "privilege"."member_id"
3638 WHERE "privilege"."voting_right" AND "member"."active";
3640 COMMENT ON VIEW "unit_member" IS 'Active members with voting right in a unit';
3643 CREATE VIEW "unit_member_count" AS
3644 SELECT
3645 "unit"."id" AS "unit_id",
3646 count("unit_member"."member_id") AS "member_count"
3647 FROM "unit" LEFT JOIN "unit_member"
3648 ON "unit"."id" = "unit_member"."unit_id"
3649 GROUP BY "unit"."id";
3651 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
3654 CREATE VIEW "opening_draft" AS
3655 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3656 ORDER BY "initiative_id", "id";
3658 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
3661 CREATE VIEW "current_draft" AS
3662 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3663 ORDER BY "initiative_id", "id" DESC;
3665 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
3668 CREATE VIEW "critical_opinion" AS
3669 SELECT * FROM "opinion"
3670 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
3671 OR ("degree" = -2 AND "fulfilled" = TRUE);
3673 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
3676 CREATE VIEW "issue_supporter_in_admission_state" AS
3677 SELECT
3678 "area"."unit_id",
3679 "issue"."area_id",
3680 "issue"."id" AS "issue_id",
3681 "supporter"."member_id",
3682 "direct_interest_snapshot"."weight"
3683 FROM "issue"
3684 JOIN "area" ON "area"."id" = "issue"."area_id"
3685 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
3686 JOIN "direct_interest_snapshot"
3687 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3688 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3689 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
3690 WHERE "issue"."state" = 'admission'::"issue_state";
3692 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';
3695 CREATE VIEW "initiative_suggestion_order_calculation" AS
3696 SELECT
3697 "initiative"."id" AS "initiative_id",
3698 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
3699 FROM "initiative" JOIN "issue"
3700 ON "initiative"."issue_id" = "issue"."id"
3701 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
3702 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
3704 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
3706 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';
3709 CREATE VIEW "individual_suggestion_ranking" AS
3710 SELECT
3711 "opinion"."initiative_id",
3712 "opinion"."member_id",
3713 "direct_interest_snapshot"."weight",
3714 CASE WHEN
3715 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
3716 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
3717 THEN 1 ELSE
3718 CASE WHEN
3719 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
3720 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
3721 THEN 2 ELSE
3722 CASE WHEN
3723 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
3724 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
3725 THEN 3 ELSE 4 END
3726 END
3727 END AS "preference",
3728 "opinion"."suggestion_id"
3729 FROM "opinion"
3730 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
3731 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3732 JOIN "direct_interest_snapshot"
3733 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3734 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3735 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
3737 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
3740 CREATE VIEW "battle_participant" AS
3741 SELECT "initiative"."id", "initiative"."issue_id"
3742 FROM "issue" JOIN "initiative"
3743 ON "issue"."id" = "initiative"."issue_id"
3744 WHERE "initiative"."admitted"
3745 UNION ALL
3746 SELECT NULL, "id" AS "issue_id"
3747 FROM "issue";
3749 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
3752 CREATE VIEW "battle_view" AS
3753 SELECT
3754 "issue"."id" AS "issue_id",
3755 "winning_initiative"."id" AS "winning_initiative_id",
3756 "losing_initiative"."id" AS "losing_initiative_id",
3757 sum(
3758 CASE WHEN
3759 coalesce("better_vote"."grade", 0) >
3760 coalesce("worse_vote"."grade", 0)
3761 THEN "direct_voter"."weight" ELSE 0 END
3762 ) AS "count"
3763 FROM "issue"
3764 LEFT JOIN "direct_voter"
3765 ON "issue"."id" = "direct_voter"."issue_id"
3766 JOIN "battle_participant" AS "winning_initiative"
3767 ON "issue"."id" = "winning_initiative"."issue_id"
3768 JOIN "battle_participant" AS "losing_initiative"
3769 ON "issue"."id" = "losing_initiative"."issue_id"
3770 LEFT JOIN "vote" AS "better_vote"
3771 ON "direct_voter"."member_id" = "better_vote"."member_id"
3772 AND "winning_initiative"."id" = "better_vote"."initiative_id"
3773 LEFT JOIN "vote" AS "worse_vote"
3774 ON "direct_voter"."member_id" = "worse_vote"."member_id"
3775 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
3776 WHERE "issue"."state" = 'voting'
3777 AND "issue"."phase_finished" NOTNULL
3778 AND (
3779 "winning_initiative"."id" != "losing_initiative"."id" OR
3780 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
3781 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
3782 GROUP BY
3783 "issue"."id",
3784 "winning_initiative"."id",
3785 "losing_initiative"."id";
3787 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';
3790 CREATE VIEW "expired_session" AS
3791 SELECT * FROM "session" WHERE now() > "expiry";
3793 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
3794 DELETE FROM "session" WHERE "id" = OLD."id";
3796 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
3797 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
3800 CREATE VIEW "expired_token" AS
3801 SELECT * FROM "token" WHERE now() > "expiry" AND NOT (
3802 "token_type" = 'authorization' AND "used" AND EXISTS (
3803 SELECT NULL FROM "token" AS "other"
3804 WHERE "other"."authorization_token_id" = "token"."id" ) );
3806 CREATE RULE "delete" AS ON DELETE TO "expired_token" DO INSTEAD
3807 DELETE FROM "token" WHERE "id" = OLD."id";
3809 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';
3812 CREATE VIEW "unused_snapshot" AS
3813 SELECT "snapshot".* FROM "snapshot"
3814 LEFT JOIN "issue"
3815 ON "snapshot"."id" = "issue"."latest_snapshot_id"
3816 OR "snapshot"."id" = "issue"."admission_snapshot_id"
3817 OR "snapshot"."id" = "issue"."half_freeze_snapshot_id"
3818 OR "snapshot"."id" = "issue"."full_freeze_snapshot_id"
3819 WHERE "issue"."id" ISNULL;
3821 CREATE RULE "delete" AS ON DELETE TO "unused_snapshot" DO INSTEAD
3822 DELETE FROM "snapshot" WHERE "id" = OLD."id";
3824 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)';
3827 CREATE VIEW "open_issue" AS
3828 SELECT * FROM "issue" WHERE "closed" ISNULL;
3830 COMMENT ON VIEW "open_issue" IS 'All open issues';
3833 CREATE VIEW "member_contingent" AS
3834 SELECT
3835 "member"."id" AS "member_id",
3836 "contingent"."polling",
3837 "contingent"."time_frame",
3838 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
3840 SELECT count(1) FROM "draft"
3841 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3842 WHERE "draft"."author_id" = "member"."id"
3843 AND "initiative"."polling" = "contingent"."polling"
3844 AND "draft"."created" > now() - "contingent"."time_frame"
3845 ) + (
3846 SELECT count(1) FROM "suggestion"
3847 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
3848 WHERE "suggestion"."author_id" = "member"."id"
3849 AND "contingent"."polling" = FALSE
3850 AND "suggestion"."created" > now() - "contingent"."time_frame"
3852 ELSE NULL END AS "text_entry_count",
3853 "contingent"."text_entry_limit",
3854 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
3855 SELECT count(1) FROM "opening_draft" AS "draft"
3856 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3857 WHERE "draft"."author_id" = "member"."id"
3858 AND "initiative"."polling" = "contingent"."polling"
3859 AND "draft"."created" > now() - "contingent"."time_frame"
3860 ) ELSE NULL END AS "initiative_count",
3861 "contingent"."initiative_limit"
3862 FROM "member" CROSS JOIN "contingent";
3864 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
3866 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
3867 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
3870 CREATE VIEW "member_contingent_left" AS
3871 SELECT
3872 "member_id",
3873 "polling",
3874 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
3875 max("initiative_limit" - "initiative_count") AS "initiatives_left"
3876 FROM "member_contingent" GROUP BY "member_id", "polling";
3878 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.';
3881 CREATE VIEW "event_for_notification" AS
3882 SELECT
3883 "member"."id" AS "recipient_id",
3884 "event".*
3885 FROM "member" CROSS JOIN "event"
3886 JOIN "issue" ON "issue"."id" = "event"."issue_id"
3887 JOIN "area" ON "area"."id" = "issue"."area_id"
3888 LEFT JOIN "privilege" ON
3889 "privilege"."member_id" = "member"."id" AND
3890 "privilege"."unit_id" = "area"."unit_id" AND
3891 "privilege"."voting_right" = TRUE
3892 LEFT JOIN "subscription" ON
3893 "subscription"."member_id" = "member"."id" AND
3894 "subscription"."unit_id" = "area"."unit_id"
3895 LEFT JOIN "ignored_area" ON
3896 "ignored_area"."member_id" = "member"."id" AND
3897 "ignored_area"."area_id" = "issue"."area_id"
3898 LEFT JOIN "interest" ON
3899 "interest"."member_id" = "member"."id" AND
3900 "interest"."issue_id" = "event"."issue_id"
3901 LEFT JOIN "supporter" ON
3902 "supporter"."member_id" = "member"."id" AND
3903 "supporter"."initiative_id" = "event"."initiative_id"
3904 WHERE ("privilege"."member_id" NOTNULL OR "subscription"."member_id" NOTNULL)
3905 AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL)
3906 AND (
3907 "event"."event" = 'issue_state_changed'::"event_type" OR
3908 ( "event"."event" = 'initiative_revoked'::"event_type" AND
3909 "supporter"."member_id" NOTNULL ) );
3911 COMMENT ON VIEW "event_for_notification" IS 'Entries of the "event" table which are of interest for a particular notification mail recipient';
3913 COMMENT ON COLUMN "event_for_notification"."recipient_id" IS 'member_id of the recipient of a notification mail';
3916 CREATE VIEW "updated_initiative" AS
3917 SELECT
3918 "supporter"."member_id" AS "recipient_id",
3919 FALSE AS "featured",
3920 "supporter"."initiative_id"
3921 FROM "supporter"
3922 JOIN "initiative" ON "supporter"."initiative_id" = "initiative"."id"
3923 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3924 LEFT JOIN "notification_initiative_sent" AS "sent" ON
3925 "sent"."member_id" = "supporter"."member_id" AND
3926 "sent"."initiative_id" = "supporter"."initiative_id"
3927 LEFT JOIN "ignored_initiative" ON
3928 "ignored_initiative"."member_id" = "supporter"."member_id" AND
3929 "ignored_initiative"."initiative_id" = "supporter"."initiative_id"
3930 WHERE "issue"."state" IN ('admission', 'discussion')
3931 AND "initiative"."revoked" ISNULL
3932 AND "ignored_initiative"."member_id" ISNULL
3933 AND (
3934 EXISTS (
3935 SELECT NULL FROM "draft"
3936 LEFT JOIN "ignored_member" ON
3937 "ignored_member"."member_id" = "supporter"."member_id" AND
3938 "ignored_member"."other_member_id" = "draft"."author_id"
3939 WHERE "draft"."initiative_id" = "supporter"."initiative_id"
3940 AND "draft"."id" > "supporter"."draft_id"
3941 AND "ignored_member"."member_id" ISNULL
3942 ) OR EXISTS (
3943 SELECT NULL FROM "suggestion"
3944 LEFT JOIN "opinion" ON
3945 "opinion"."member_id" = "supporter"."member_id" AND
3946 "opinion"."suggestion_id" = "suggestion"."id"
3947 LEFT JOIN "ignored_member" ON
3948 "ignored_member"."member_id" = "supporter"."member_id" AND
3949 "ignored_member"."other_member_id" = "suggestion"."author_id"
3950 WHERE "suggestion"."initiative_id" = "supporter"."initiative_id"
3951 AND "opinion"."member_id" ISNULL
3952 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
3953 AND "ignored_member"."member_id" ISNULL
3955 );
3957 COMMENT ON VIEW "updated_initiative" IS 'Helper view for view "updated_or_featured_initiative"';
3960 CREATE FUNCTION "featured_initiative"
3961 ( "recipient_id_p" "member"."id"%TYPE,
3962 "area_id_p" "area"."id"%TYPE )
3963 RETURNS SETOF "initiative"."id"%TYPE
3964 LANGUAGE 'plpgsql' STABLE AS $$
3965 DECLARE
3966 "counter_v" "member"."notification_counter"%TYPE;
3967 "sample_size_v" "member"."notification_sample_size"%TYPE;
3968 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
3969 "match_v" BOOLEAN;
3970 "member_id_v" "member"."id"%TYPE;
3971 "seed_v" TEXT;
3972 "initiative_id_v" "initiative"."id"%TYPE;
3973 BEGIN
3974 SELECT "notification_counter", "notification_sample_size"
3975 INTO "counter_v", "sample_size_v"
3976 FROM "member" WHERE "id" = "recipient_id_p";
3977 IF COALESCE("sample_size_v" <= 0, TRUE) THEN
3978 RETURN;
3979 END IF;
3980 "initiative_id_ary" := '{}';
3981 LOOP
3982 "match_v" := FALSE;
3983 FOR "member_id_v", "seed_v" IN
3984 SELECT * FROM (
3985 SELECT DISTINCT
3986 "supporter"."member_id",
3987 md5(
3988 "recipient_id_p" || '-' ||
3989 "counter_v" || '-' ||
3990 "area_id_p" || '-' ||
3991 "supporter"."member_id"
3992 ) AS "seed"
3993 FROM "supporter"
3994 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
3995 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3996 WHERE "supporter"."member_id" != "recipient_id_p"
3997 AND "issue"."area_id" = "area_id_p"
3998 AND "issue"."state" IN ('admission', 'discussion', 'verification')
3999 ) AS "subquery"
4000 ORDER BY "seed"
4001 LOOP
4002 SELECT "initiative"."id" INTO "initiative_id_v"
4003 FROM "initiative"
4004 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4005 JOIN "area" ON "area"."id" = "issue"."area_id"
4006 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
4007 LEFT JOIN "supporter" AS "self_support" ON
4008 "self_support"."initiative_id" = "initiative"."id" AND
4009 "self_support"."member_id" = "recipient_id_p"
4010 LEFT JOIN "privilege" ON
4011 "privilege"."member_id" = "recipient_id_p" AND
4012 "privilege"."unit_id" = "area"."unit_id" AND
4013 "privilege"."voting_right" = TRUE
4014 LEFT JOIN "subscription" ON
4015 "subscription"."member_id" = "recipient_id_p" AND
4016 "subscription"."unit_id" = "area"."unit_id"
4017 LEFT JOIN "ignored_initiative" ON
4018 "ignored_initiative"."member_id" = "recipient_id_p" AND
4019 "ignored_initiative"."initiative_id" = "initiative"."id"
4020 WHERE "supporter"."member_id" = "member_id_v"
4021 AND "issue"."area_id" = "area_id_p"
4022 AND "issue"."state" IN ('admission', 'discussion', 'verification')
4023 AND "initiative"."revoked" ISNULL
4024 AND "self_support"."member_id" ISNULL
4025 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
4026 AND (
4027 "privilege"."member_id" NOTNULL OR
4028 "subscription"."member_id" NOTNULL )
4029 AND "ignored_initiative"."member_id" ISNULL
4030 AND NOT EXISTS (
4031 SELECT NULL FROM "draft"
4032 JOIN "ignored_member" ON
4033 "ignored_member"."member_id" = "recipient_id_p" AND
4034 "ignored_member"."other_member_id" = "draft"."author_id"
4035 WHERE "draft"."initiative_id" = "initiative"."id"
4037 ORDER BY md5("seed_v" || '-' || "initiative"."id")
4038 LIMIT 1;
4039 IF FOUND THEN
4040 "match_v" := TRUE;
4041 RETURN NEXT "initiative_id_v";
4042 IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
4043 RETURN;
4044 END IF;
4045 "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
4046 END IF;
4047 END LOOP;
4048 EXIT WHEN NOT "match_v";
4049 END LOOP;
4050 RETURN;
4051 END;
4052 $$;
4054 COMMENT ON FUNCTION "featured_initiative"
4055 ( "recipient_id_p" "member"."id"%TYPE,
4056 "area_id_p" "area"."id"%TYPE )
4057 IS 'Helper function for view "updated_or_featured_initiative"';
4060 CREATE VIEW "updated_or_featured_initiative" AS
4061 SELECT
4062 "subquery".*,
4063 NOT EXISTS (
4064 SELECT NULL FROM "initiative" AS "better_initiative"
4065 WHERE "better_initiative"."issue_id" = "initiative"."issue_id"
4066 AND
4067 ( COALESCE("better_initiative"."supporter_count", -1),
4068 -"better_initiative"."id" ) >
4069 ( COALESCE("initiative"."supporter_count", -1),
4070 -"initiative"."id" )
4071 ) AS "leading"
4072 FROM (
4073 SELECT * FROM "updated_initiative"
4074 UNION ALL
4075 SELECT
4076 "member"."id" AS "recipient_id",
4077 TRUE AS "featured",
4078 "featured_initiative_id" AS "initiative_id"
4079 FROM "member" CROSS JOIN "area"
4080 CROSS JOIN LATERAL
4081 "featured_initiative"("member"."id", "area"."id") AS "featured_initiative_id"
4082 JOIN "initiative" ON "initiative"."id" = "featured_initiative_id"
4083 ) AS "subquery"
4084 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id";
4086 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';
4088 COMMENT ON COLUMN "updated_or_featured_initiative"."recipient_id" IS '"id" of the member who receives the notification mail';
4089 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")';
4090 COMMENT ON COLUMN "updated_or_featured_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4091 COMMENT ON COLUMN "updated_or_featured_initiative"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
4094 CREATE VIEW "leading_complement_initiative" AS
4095 SELECT * FROM (
4096 SELECT DISTINCT ON ("uf_initiative"."recipient_id", "initiative"."issue_id")
4097 "uf_initiative"."recipient_id",
4098 FALSE AS "featured",
4099 "uf_initiative"."initiative_id",
4100 TRUE AS "leading"
4101 FROM "updated_or_featured_initiative" AS "uf_initiative"
4102 JOIN "initiative" AS "uf_initiative_full" ON
4103 "uf_initiative_full"."id" = "uf_initiative"."initiative_id"
4104 JOIN "initiative" ON
4105 "initiative"."issue_id" = "uf_initiative_full"."issue_id"
4106 WHERE "initiative"."revoked" ISNULL
4107 ORDER BY
4108 "uf_initiative"."recipient_id",
4109 "initiative"."issue_id",
4110 "initiative"."supporter_count" DESC,
4111 "initiative"."id"
4112 ) AS "subquery"
4113 WHERE NOT EXISTS (
4114 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
4115 WHERE "other"."recipient_id" = "subquery"."recipient_id"
4116 AND "other"."initiative_id" = "subquery"."initiative_id"
4117 );
4119 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';
4120 COMMENT ON COLUMN "leading_complement_initiative"."featured" IS 'Always FALSE in this view';
4121 COMMENT ON COLUMN "leading_complement_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4122 COMMENT ON COLUMN "leading_complement_initiative"."leading" IS 'Always TRUE in this view';
4125 CREATE VIEW "unfiltered_initiative_for_notification" AS
4126 SELECT
4127 "subquery".*,
4128 "supporter"."member_id" NOTNULL AS "supported",
4129 CASE WHEN "supporter"."member_id" NOTNULL THEN
4130 EXISTS (
4131 SELECT NULL FROM "draft"
4132 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
4133 AND "draft"."id" > "supporter"."draft_id"
4135 ELSE
4136 EXISTS (
4137 SELECT NULL FROM "draft"
4138 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
4139 AND COALESCE("draft"."id" > "sent"."last_draft_id", TRUE)
4141 END AS "new_draft",
4142 CASE WHEN "supporter"."member_id" NOTNULL THEN
4143 ( SELECT count(1) FROM "suggestion"
4144 LEFT JOIN "opinion" ON
4145 "opinion"."member_id" = "supporter"."member_id" AND
4146 "opinion"."suggestion_id" = "suggestion"."id"
4147 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
4148 AND "opinion"."member_id" ISNULL
4149 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4151 ELSE
4152 ( SELECT count(1) FROM "suggestion"
4153 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
4154 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4156 END AS "new_suggestion_count"
4157 FROM (
4158 SELECT * FROM "updated_or_featured_initiative"
4159 UNION ALL
4160 SELECT * FROM "leading_complement_initiative"
4161 ) AS "subquery"
4162 LEFT JOIN "supporter" ON
4163 "supporter"."member_id" = "subquery"."recipient_id" AND
4164 "supporter"."initiative_id" = "subquery"."initiative_id"
4165 LEFT JOIN "notification_initiative_sent" AS "sent" ON
4166 "sent"."member_id" = "subquery"."recipient_id" AND
4167 "sent"."initiative_id" = "subquery"."initiative_id";
4169 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';
4171 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4172 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)';
4173 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")';
4176 CREATE VIEW "initiative_for_notification" AS
4177 SELECT "unfiltered1".*
4178 FROM "unfiltered_initiative_for_notification" "unfiltered1"
4179 JOIN "initiative" AS "initiative1" ON
4180 "initiative1"."id" = "unfiltered1"."initiative_id"
4181 JOIN "issue" AS "issue1" ON "issue1"."id" = "initiative1"."issue_id"
4182 WHERE EXISTS (
4183 SELECT NULL
4184 FROM "unfiltered_initiative_for_notification" "unfiltered2"
4185 JOIN "initiative" AS "initiative2" ON
4186 "initiative2"."id" = "unfiltered2"."initiative_id"
4187 JOIN "issue" AS "issue2" ON "issue2"."id" = "initiative2"."issue_id"
4188 WHERE "unfiltered1"."recipient_id" = "unfiltered2"."recipient_id"
4189 AND "issue1"."area_id" = "issue2"."area_id"
4190 AND ("unfiltered2"."new_draft" OR "unfiltered2"."new_suggestion_count" > 0 )
4191 );
4193 COMMENT ON VIEW "initiative_for_notification" IS 'Initiatives to be included in a scheduled notification mail';
4195 COMMENT ON COLUMN "initiative_for_notification"."recipient_id" IS '"id" of the member who receives the notification mail';
4196 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")';
4197 COMMENT ON COLUMN "initiative_for_notification"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4198 COMMENT ON COLUMN "initiative_for_notification"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
4199 COMMENT ON COLUMN "initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4200 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)';
4201 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")';
4204 CREATE VIEW "scheduled_notification_to_send" AS
4205 SELECT * FROM (
4206 SELECT
4207 "id" AS "recipient_id",
4208 now() - CASE WHEN "notification_dow" ISNULL THEN
4209 ( "notification_sent"::DATE + CASE
4210 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4211 THEN 0 ELSE 1 END
4212 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4213 ELSE
4214 ( "notification_sent"::DATE +
4215 ( 7 + "notification_dow" -
4216 EXTRACT(DOW FROM
4217 ( "notification_sent"::DATE + CASE
4218 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4219 THEN 0 ELSE 1 END
4220 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4221 )::INTEGER
4222 ) % 7 +
4223 CASE
4224 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4225 THEN 0 ELSE 1
4226 END
4227 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4228 END AS "pending"
4229 FROM (
4230 SELECT
4231 "id",
4232 COALESCE("notification_sent", "activated") AS "notification_sent",
4233 "notification_dow",
4234 "notification_hour"
4235 FROM "member_to_notify"
4236 WHERE "notification_hour" NOTNULL
4237 ) AS "subquery1"
4238 ) AS "subquery2"
4239 WHERE "pending" > '0'::INTERVAL;
4241 COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending';
4243 COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail';
4244 COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending';
4247 CREATE VIEW "newsletter_to_send" AS
4248 SELECT
4249 "member"."id" AS "recipient_id",
4250 "newsletter"."id" AS "newsletter_id",
4251 "newsletter"."published"
4252 FROM "newsletter" CROSS JOIN "member_eligible_to_be_notified" AS "member"
4253 LEFT JOIN "privilege" ON
4254 "privilege"."member_id" = "member"."id" AND
4255 "privilege"."unit_id" = "newsletter"."unit_id" AND
4256 "privilege"."voting_right" = TRUE
4257 LEFT JOIN "subscription" ON
4258 "subscription"."member_id" = "member"."id" AND
4259 "subscription"."unit_id" = "newsletter"."unit_id"
4260 WHERE "newsletter"."published" <= now()
4261 AND "newsletter"."sent" ISNULL
4262 AND (
4263 "member"."disable_notifications" = FALSE OR
4264 "newsletter"."include_all_members" = TRUE )
4265 AND (
4266 "newsletter"."unit_id" ISNULL OR
4267 "privilege"."member_id" NOTNULL OR
4268 "subscription"."member_id" NOTNULL );
4270 COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out';
4272 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter was supposed to be sent out (can be used for ordering)';
4276 ------------------------------------------------------
4277 -- Row set returning function for delegation chains --
4278 ------------------------------------------------------
4281 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
4282 ('first', 'intermediate', 'last', 'repetition');
4284 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
4287 CREATE TYPE "delegation_chain_row" AS (
4288 "index" INT4,
4289 "member_id" INT4,
4290 "member_valid" BOOLEAN,
4291 "participation" BOOLEAN,
4292 "overridden" BOOLEAN,
4293 "scope_in" "delegation_scope",
4294 "scope_out" "delegation_scope",
4295 "disabled_out" BOOLEAN,
4296 "loop" "delegation_chain_loop_tag" );
4298 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
4300 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
4301 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest; for area and global delegation chains: always null';
4302 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
4303 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
4304 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
4305 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
4306 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
4309 CREATE FUNCTION "delegation_chain_for_closed_issue"
4310 ( "member_id_p" "member"."id"%TYPE,
4311 "issue_id_p" "issue"."id"%TYPE )
4312 RETURNS SETOF "delegation_chain_row"
4313 LANGUAGE 'plpgsql' STABLE AS $$
4314 DECLARE
4315 "output_row" "delegation_chain_row";
4316 "direct_voter_row" "direct_voter"%ROWTYPE;
4317 "delegating_voter_row" "delegating_voter"%ROWTYPE;
4318 BEGIN
4319 "output_row"."index" := 0;
4320 "output_row"."member_id" := "member_id_p";
4321 "output_row"."member_valid" := TRUE;
4322 "output_row"."participation" := FALSE;
4323 "output_row"."overridden" := FALSE;
4324 "output_row"."disabled_out" := FALSE;
4325 LOOP
4326 SELECT INTO "direct_voter_row" * FROM "direct_voter"
4327 WHERE "issue_id" = "issue_id_p"
4328 AND "member_id" = "output_row"."member_id";
4329 IF "direct_voter_row"."member_id" NOTNULL THEN
4330 "output_row"."participation" := TRUE;
4331 "output_row"."scope_out" := NULL;
4332 "output_row"."disabled_out" := NULL;
4333 RETURN NEXT "output_row";
4334 RETURN;
4335 END IF;
4336 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
4337 WHERE "issue_id" = "issue_id_p"
4338 AND "member_id" = "output_row"."member_id";
4339 IF "delegating_voter_row"."member_id" ISNULL THEN
4340 RETURN;
4341 END IF;
4342 "output_row"."scope_out" := "delegating_voter_row"."scope";
4343 RETURN NEXT "output_row";
4344 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
4345 "output_row"."scope_in" := "output_row"."scope_out";
4346 END LOOP;
4347 END;
4348 $$;
4350 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
4351 ( "member"."id"%TYPE,
4352 "member"."id"%TYPE )
4353 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
4356 CREATE FUNCTION "delegation_chain"
4357 ( "member_id_p" "member"."id"%TYPE,
4358 "unit_id_p" "unit"."id"%TYPE,
4359 "area_id_p" "area"."id"%TYPE,
4360 "issue_id_p" "issue"."id"%TYPE,
4361 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4362 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4363 RETURNS SETOF "delegation_chain_row"
4364 LANGUAGE 'plpgsql' STABLE AS $$
4365 DECLARE
4366 "scope_v" "delegation_scope";
4367 "unit_id_v" "unit"."id"%TYPE;
4368 "area_id_v" "area"."id"%TYPE;
4369 "issue_row" "issue"%ROWTYPE;
4370 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
4371 "loop_member_id_v" "member"."id"%TYPE;
4372 "output_row" "delegation_chain_row";
4373 "output_rows" "delegation_chain_row"[];
4374 "simulate_v" BOOLEAN;
4375 "simulate_here_v" BOOLEAN;
4376 "delegation_row" "delegation"%ROWTYPE;
4377 "row_count" INT4;
4378 "i" INT4;
4379 "loop_v" BOOLEAN;
4380 BEGIN
4381 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
4382 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
4383 END IF;
4384 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
4385 "simulate_v" := TRUE;
4386 ELSE
4387 "simulate_v" := FALSE;
4388 END IF;
4389 IF
4390 "unit_id_p" NOTNULL AND
4391 "area_id_p" ISNULL AND
4392 "issue_id_p" ISNULL
4393 THEN
4394 "scope_v" := 'unit';
4395 "unit_id_v" := "unit_id_p";
4396 ELSIF
4397 "unit_id_p" ISNULL AND
4398 "area_id_p" NOTNULL AND
4399 "issue_id_p" ISNULL
4400 THEN
4401 "scope_v" := 'area';
4402 "area_id_v" := "area_id_p";
4403 SELECT "unit_id" INTO "unit_id_v"
4404 FROM "area" WHERE "id" = "area_id_v";
4405 ELSIF
4406 "unit_id_p" ISNULL AND
4407 "area_id_p" ISNULL AND
4408 "issue_id_p" NOTNULL
4409 THEN
4410 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
4411 IF "issue_row"."id" ISNULL THEN
4412 RETURN;
4413 END IF;
4414 IF "issue_row"."closed" NOTNULL THEN
4415 IF "simulate_v" THEN
4416 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
4417 END IF;
4418 FOR "output_row" IN
4419 SELECT * FROM
4420 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
4421 LOOP
4422 RETURN NEXT "output_row";
4423 END LOOP;
4424 RETURN;
4425 END IF;
4426 "scope_v" := 'issue';
4427 SELECT "area_id" INTO "area_id_v"
4428 FROM "issue" WHERE "id" = "issue_id_p";
4429 SELECT "unit_id" INTO "unit_id_v"
4430 FROM "area" WHERE "id" = "area_id_v";
4431 ELSE
4432 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
4433 END IF;
4434 "visited_member_ids" := '{}';
4435 "loop_member_id_v" := NULL;
4436 "output_rows" := '{}';
4437 "output_row"."index" := 0;
4438 "output_row"."member_id" := "member_id_p";
4439 "output_row"."member_valid" := TRUE;
4440 "output_row"."participation" := FALSE;
4441 "output_row"."overridden" := FALSE;
4442 "output_row"."disabled_out" := FALSE;
4443 "output_row"."scope_out" := NULL;
4444 LOOP
4445 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
4446 "loop_member_id_v" := "output_row"."member_id";
4447 ELSE
4448 "visited_member_ids" :=
4449 "visited_member_ids" || "output_row"."member_id";
4450 END IF;
4451 IF "output_row"."participation" ISNULL THEN
4452 "output_row"."overridden" := NULL;
4453 ELSIF "output_row"."participation" THEN
4454 "output_row"."overridden" := TRUE;
4455 END IF;
4456 "output_row"."scope_in" := "output_row"."scope_out";
4457 "output_row"."member_valid" := EXISTS (
4458 SELECT NULL FROM "member" JOIN "privilege"
4459 ON "privilege"."member_id" = "member"."id"
4460 AND "privilege"."unit_id" = "unit_id_v"
4461 WHERE "id" = "output_row"."member_id"
4462 AND "member"."active" AND "privilege"."voting_right"
4463 );
4464 "simulate_here_v" := (
4465 "simulate_v" AND
4466 "output_row"."member_id" = "member_id_p"
4467 );
4468 "delegation_row" := ROW(NULL);
4469 IF "output_row"."member_valid" OR "simulate_here_v" THEN
4470 IF "scope_v" = 'unit' THEN
4471 IF NOT "simulate_here_v" THEN
4472 SELECT * INTO "delegation_row" FROM "delegation"
4473 WHERE "truster_id" = "output_row"."member_id"
4474 AND "unit_id" = "unit_id_v";
4475 END IF;
4476 ELSIF "scope_v" = 'area' THEN
4477 IF "simulate_here_v" THEN
4478 IF "simulate_trustee_id_p" ISNULL THEN
4479 SELECT * INTO "delegation_row" FROM "delegation"
4480 WHERE "truster_id" = "output_row"."member_id"
4481 AND "unit_id" = "unit_id_v";
4482 END IF;
4483 ELSE
4484 SELECT * INTO "delegation_row" FROM "delegation"
4485 WHERE "truster_id" = "output_row"."member_id"
4486 AND (
4487 "unit_id" = "unit_id_v" OR
4488 "area_id" = "area_id_v"
4490 ORDER BY "scope" DESC;
4491 END IF;
4492 ELSIF "scope_v" = 'issue' THEN
4493 IF "issue_row"."fully_frozen" ISNULL THEN
4494 "output_row"."participation" := EXISTS (
4495 SELECT NULL FROM "interest"
4496 WHERE "issue_id" = "issue_id_p"
4497 AND "member_id" = "output_row"."member_id"
4498 );
4499 ELSE
4500 IF "output_row"."member_id" = "member_id_p" THEN
4501 "output_row"."participation" := EXISTS (
4502 SELECT NULL FROM "direct_voter"
4503 WHERE "issue_id" = "issue_id_p"
4504 AND "member_id" = "output_row"."member_id"
4505 );
4506 ELSE
4507 "output_row"."participation" := NULL;
4508 END IF;
4509 END IF;
4510 IF "simulate_here_v" THEN
4511 IF "simulate_trustee_id_p" ISNULL THEN
4512 SELECT * INTO "delegation_row" FROM "delegation"
4513 WHERE "truster_id" = "output_row"."member_id"
4514 AND (
4515 "unit_id" = "unit_id_v" OR
4516 "area_id" = "area_id_v"
4518 ORDER BY "scope" DESC;
4519 END IF;
4520 ELSE
4521 SELECT * INTO "delegation_row" FROM "delegation"
4522 WHERE "truster_id" = "output_row"."member_id"
4523 AND (
4524 "unit_id" = "unit_id_v" OR
4525 "area_id" = "area_id_v" OR
4526 "issue_id" = "issue_id_p"
4528 ORDER BY "scope" DESC;
4529 END IF;
4530 END IF;
4531 ELSE
4532 "output_row"."participation" := FALSE;
4533 END IF;
4534 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
4535 "output_row"."scope_out" := "scope_v";
4536 "output_rows" := "output_rows" || "output_row";
4537 "output_row"."member_id" := "simulate_trustee_id_p";
4538 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
4539 "output_row"."scope_out" := "delegation_row"."scope";
4540 "output_rows" := "output_rows" || "output_row";
4541 "output_row"."member_id" := "delegation_row"."trustee_id";
4542 ELSIF "delegation_row"."scope" NOTNULL THEN
4543 "output_row"."scope_out" := "delegation_row"."scope";
4544 "output_row"."disabled_out" := TRUE;
4545 "output_rows" := "output_rows" || "output_row";
4546 EXIT;
4547 ELSE
4548 "output_row"."scope_out" := NULL;
4549 "output_rows" := "output_rows" || "output_row";
4550 EXIT;
4551 END IF;
4552 EXIT WHEN "loop_member_id_v" NOTNULL;
4553 "output_row"."index" := "output_row"."index" + 1;
4554 END LOOP;
4555 "row_count" := array_upper("output_rows", 1);
4556 "i" := 1;
4557 "loop_v" := FALSE;
4558 LOOP
4559 "output_row" := "output_rows"["i"];
4560 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
4561 IF "loop_v" THEN
4562 IF "i" + 1 = "row_count" THEN
4563 "output_row"."loop" := 'last';
4564 ELSIF "i" = "row_count" THEN
4565 "output_row"."loop" := 'repetition';
4566 ELSE
4567 "output_row"."loop" := 'intermediate';
4568 END IF;
4569 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
4570 "output_row"."loop" := 'first';
4571 "loop_v" := TRUE;
4572 END IF;
4573 IF "scope_v" = 'unit' THEN
4574 "output_row"."participation" := NULL;
4575 END IF;
4576 RETURN NEXT "output_row";
4577 "i" := "i" + 1;
4578 END LOOP;
4579 RETURN;
4580 END;
4581 $$;
4583 COMMENT ON FUNCTION "delegation_chain"
4584 ( "member"."id"%TYPE,
4585 "unit"."id"%TYPE,
4586 "area"."id"%TYPE,
4587 "issue"."id"%TYPE,
4588 "member"."id"%TYPE,
4589 BOOLEAN )
4590 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
4594 ---------------------------------------------------------
4595 -- Single row returning function for delegation chains --
4596 ---------------------------------------------------------
4599 CREATE TYPE "delegation_info_loop_type" AS ENUM
4600 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
4602 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''';
4605 CREATE TYPE "delegation_info_type" AS (
4606 "own_participation" BOOLEAN,
4607 "own_delegation_scope" "delegation_scope",
4608 "first_trustee_id" INT4,
4609 "first_trustee_participation" BOOLEAN,
4610 "first_trustee_ellipsis" BOOLEAN,
4611 "other_trustee_id" INT4,
4612 "other_trustee_participation" BOOLEAN,
4613 "other_trustee_ellipsis" BOOLEAN,
4614 "delegation_loop" "delegation_info_loop_type",
4615 "participating_member_id" INT4 );
4617 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';
4619 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
4620 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
4621 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
4622 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
4623 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
4624 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
4625 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)';
4626 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
4627 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';
4628 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
4631 CREATE FUNCTION "delegation_info"
4632 ( "member_id_p" "member"."id"%TYPE,
4633 "unit_id_p" "unit"."id"%TYPE,
4634 "area_id_p" "area"."id"%TYPE,
4635 "issue_id_p" "issue"."id"%TYPE,
4636 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4637 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4638 RETURNS "delegation_info_type"
4639 LANGUAGE 'plpgsql' STABLE AS $$
4640 DECLARE
4641 "current_row" "delegation_chain_row";
4642 "result" "delegation_info_type";
4643 BEGIN
4644 "result"."own_participation" := FALSE;
4645 FOR "current_row" IN
4646 SELECT * FROM "delegation_chain"(
4647 "member_id_p",
4648 "unit_id_p", "area_id_p", "issue_id_p",
4649 "simulate_trustee_id_p", "simulate_default_p")
4650 LOOP
4651 IF
4652 "result"."participating_member_id" ISNULL AND
4653 "current_row"."participation"
4654 THEN
4655 "result"."participating_member_id" := "current_row"."member_id";
4656 END IF;
4657 IF "current_row"."member_id" = "member_id_p" THEN
4658 "result"."own_participation" := "current_row"."participation";
4659 "result"."own_delegation_scope" := "current_row"."scope_out";
4660 IF "current_row"."loop" = 'first' THEN
4661 "result"."delegation_loop" := 'own';
4662 END IF;
4663 ELSIF
4664 "current_row"."member_valid" AND
4665 ( "current_row"."loop" ISNULL OR
4666 "current_row"."loop" != 'repetition' )
4667 THEN
4668 IF "result"."first_trustee_id" ISNULL THEN
4669 "result"."first_trustee_id" := "current_row"."member_id";
4670 "result"."first_trustee_participation" := "current_row"."participation";
4671 "result"."first_trustee_ellipsis" := FALSE;
4672 IF "current_row"."loop" = 'first' THEN
4673 "result"."delegation_loop" := 'first';
4674 END IF;
4675 ELSIF "result"."other_trustee_id" ISNULL THEN
4676 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
4677 "result"."other_trustee_id" := "current_row"."member_id";
4678 "result"."other_trustee_participation" := TRUE;
4679 "result"."other_trustee_ellipsis" := FALSE;
4680 IF "current_row"."loop" = 'first' THEN
4681 "result"."delegation_loop" := 'other';
4682 END IF;
4683 ELSE
4684 "result"."first_trustee_ellipsis" := TRUE;
4685 IF "current_row"."loop" = 'first' THEN
4686 "result"."delegation_loop" := 'first_ellipsis';
4687 END IF;
4688 END IF;
4689 ELSE
4690 "result"."other_trustee_ellipsis" := TRUE;
4691 IF "current_row"."loop" = 'first' THEN
4692 "result"."delegation_loop" := 'other_ellipsis';
4693 END IF;
4694 END IF;
4695 END IF;
4696 END LOOP;
4697 RETURN "result";
4698 END;
4699 $$;
4701 COMMENT ON FUNCTION "delegation_info"
4702 ( "member"."id"%TYPE,
4703 "unit"."id"%TYPE,
4704 "area"."id"%TYPE,
4705 "issue"."id"%TYPE,
4706 "member"."id"%TYPE,
4707 BOOLEAN )
4708 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
4712 ------------------------
4713 -- Geospatial lookups --
4714 ------------------------
4716 /*
4717 CREATE FUNCTION "closed_initiatives_in_bounding_box"
4718 ( "bounding_box_p" EBOX,
4719 "limit_p" INT4 )
4720 RETURNS SETOF "initiative"
4721 LANGUAGE 'plpgsql' STABLE AS $$
4722 DECLARE
4723 "limit_v" INT4;
4724 "count_v" INT4;
4725 BEGIN
4726 "limit_v" := "limit_p" + 1;
4727 LOOP
4728 SELECT count(1) INTO "count_v"
4729 FROM "initiative"
4730 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4731 WHERE "issue"."closed" NOTNULL
4732 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4733 LIMIT "limit_v";
4734 IF "count_v" < "limit_v" THEN
4735 RETURN QUERY SELECT "initiative".*
4736 FROM (
4737 SELECT
4738 "initiative"."id" AS "initiative_id",
4739 "issue"."closed"
4740 FROM "initiative"
4741 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4742 WHERE "issue"."closed" NOTNULL
4743 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4744 ) AS "subquery"
4745 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4746 ORDER BY "subquery"."closed" DESC
4747 LIMIT "limit_p";
4748 RETURN;
4749 END IF;
4750 SELECT count(1) INTO "count_v"
4751 FROM (
4752 SELECT "initiative"."id" AS "initiative_id"
4753 FROM "initiative"
4754 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4755 WHERE "issue"."closed" NOTNULL
4756 ORDER BY "closed" DESC
4757 LIMIT "limit_v"
4758 ) AS "subquery"
4759 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4760 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4761 LIMIT "limit_p";
4762 IF "count_v" >= "limit_p" THEN
4763 RETURN QUERY SELECT "initiative".*
4764 FROM (
4765 SELECT
4766 "initiative"."id" AS "initiative_id",
4767 "issue"."closed"
4768 FROM "initiative"
4769 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4770 WHERE "issue"."closed" NOTNULL
4771 ORDER BY "closed" DESC
4772 LIMIT "limit_v"
4773 ) AS "subquery"
4774 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4775 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4776 ORDER BY "subquery"."closed" DESC
4777 LIMIT "limit_p";
4778 RETURN;
4779 END IF;
4780 "limit_v" := "limit_v" * 2;
4781 END LOOP;
4782 END;
4783 $$;
4785 COMMENT ON FUNCTION "closed_initiatives_in_bounding_box"
4786 ( EBOX, INT4 )
4787 IS 'TODO';
4788 */
4792 ---------------------------
4793 -- Transaction isolation --
4794 ---------------------------
4797 CREATE FUNCTION "require_transaction_isolation"()
4798 RETURNS VOID
4799 LANGUAGE 'plpgsql' VOLATILE AS $$
4800 BEGIN
4801 IF
4802 current_setting('transaction_isolation') NOT IN
4803 ('repeatable read', 'serializable')
4804 THEN
4805 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
4806 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
4807 END IF;
4808 RETURN;
4809 END;
4810 $$;
4812 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
4815 CREATE FUNCTION "dont_require_transaction_isolation"()
4816 RETURNS VOID
4817 LANGUAGE 'plpgsql' VOLATILE AS $$
4818 BEGIN
4819 IF
4820 current_setting('transaction_isolation') IN
4821 ('repeatable read', 'serializable')
4822 THEN
4823 RAISE WARNING 'Unneccessary transaction isolation level: %',
4824 current_setting('transaction_isolation');
4825 END IF;
4826 RETURN;
4827 END;
4828 $$;
4830 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
4834 -------------------------
4835 -- Notification system --
4836 -------------------------
4838 CREATE FUNCTION "get_initiatives_for_notification"
4839 ( "recipient_id_p" "member"."id"%TYPE )
4840 RETURNS SETOF "initiative_for_notification"
4841 LANGUAGE 'plpgsql' VOLATILE AS $$
4842 DECLARE
4843 "result_row" "initiative_for_notification"%ROWTYPE;
4844 "last_draft_id_v" "draft"."id"%TYPE;
4845 "last_suggestion_id_v" "suggestion"."id"%TYPE;
4846 BEGIN
4847 PERFORM "require_transaction_isolation"();
4848 PERFORM NULL FROM "member" WHERE "id" = "recipient_id_p" FOR UPDATE;
4849 FOR "result_row" IN
4850 SELECT * FROM "initiative_for_notification"
4851 WHERE "recipient_id" = "recipient_id_p"
4852 LOOP
4853 SELECT "id" INTO "last_draft_id_v" FROM "draft"
4854 WHERE "draft"."initiative_id" = "result_row"."initiative_id"
4855 ORDER BY "id" DESC LIMIT 1;
4856 SELECT "id" INTO "last_suggestion_id_v" FROM "suggestion"
4857 WHERE "suggestion"."initiative_id" = "result_row"."initiative_id"
4858 ORDER BY "id" DESC LIMIT 1;
4859 INSERT INTO "notification_initiative_sent"
4860 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
4861 VALUES (
4862 "recipient_id_p",
4863 "result_row"."initiative_id",
4864 "last_draft_id_v",
4865 "last_suggestion_id_v" )
4866 ON CONFLICT ("member_id", "initiative_id") DO UPDATE SET
4867 "last_draft_id" = "last_draft_id_v",
4868 "last_suggestion_id" = "last_suggestion_id_v";
4869 RETURN NEXT "result_row";
4870 END LOOP;
4871 DELETE FROM "notification_initiative_sent"
4872 USING "initiative", "issue"
4873 WHERE "notification_initiative_sent"."member_id" = "recipient_id_p"
4874 AND "initiative"."id" = "notification_initiative_sent"."initiative_id"
4875 AND "issue"."id" = "initiative"."issue_id"
4876 AND ( "issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL );
4877 UPDATE "member" SET
4878 "notification_counter" = "notification_counter" + 1,
4879 "notification_sent" = now()
4880 WHERE "id" = "recipient_id_p";
4881 RETURN;
4882 END;
4883 $$;
4885 COMMENT ON FUNCTION "get_initiatives_for_notification"
4886 ( "member"."id"%TYPE )
4887 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';
4891 ------------------------------------------------------------------------
4892 -- Regular tasks, except calculcation of snapshots and voting results --
4893 ------------------------------------------------------------------------
4896 CREATE FUNCTION "check_activity"()
4897 RETURNS VOID
4898 LANGUAGE 'plpgsql' VOLATILE AS $$
4899 DECLARE
4900 "system_setting_row" "system_setting"%ROWTYPE;
4901 BEGIN
4902 PERFORM "dont_require_transaction_isolation"();
4903 SELECT * INTO "system_setting_row" FROM "system_setting";
4904 IF "system_setting_row"."member_ttl" NOTNULL THEN
4905 UPDATE "member" SET "active" = FALSE
4906 WHERE "active" = TRUE
4907 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
4908 END IF;
4909 RETURN;
4910 END;
4911 $$;
4913 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
4916 CREATE FUNCTION "calculate_member_counts"()
4917 RETURNS VOID
4918 LANGUAGE 'plpgsql' VOLATILE AS $$
4919 BEGIN
4920 PERFORM "require_transaction_isolation"();
4921 DELETE FROM "member_count";
4922 INSERT INTO "member_count" ("total_count")
4923 SELECT "total_count" FROM "member_count_view";
4924 UPDATE "unit" SET "member_count" = "view"."member_count"
4925 FROM "unit_member_count" AS "view"
4926 WHERE "view"."unit_id" = "unit"."id";
4927 RETURN;
4928 END;
4929 $$;
4931 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"';
4935 ------------------------------------
4936 -- Calculation of harmonic weight --
4937 ------------------------------------
4940 CREATE VIEW "remaining_harmonic_supporter_weight" AS
4941 SELECT
4942 "direct_interest_snapshot"."snapshot_id",
4943 "direct_interest_snapshot"."issue_id",
4944 "direct_interest_snapshot"."member_id",
4945 "direct_interest_snapshot"."weight" AS "weight_num",
4946 count("initiative"."id") AS "weight_den"
4947 FROM "issue"
4948 JOIN "direct_interest_snapshot"
4949 ON "issue"."latest_snapshot_id" = "direct_interest_snapshot"."snapshot_id"
4950 AND "issue"."id" = "direct_interest_snapshot"."issue_id"
4951 JOIN "initiative"
4952 ON "issue"."id" = "initiative"."issue_id"
4953 AND "initiative"."harmonic_weight" ISNULL
4954 JOIN "direct_supporter_snapshot"
4955 ON "issue"."latest_snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
4956 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
4957 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
4958 AND (
4959 "direct_supporter_snapshot"."satisfied" = TRUE OR
4960 coalesce("initiative"."admitted", FALSE) = FALSE
4962 GROUP BY
4963 "direct_interest_snapshot"."snapshot_id",
4964 "direct_interest_snapshot"."issue_id",
4965 "direct_interest_snapshot"."member_id",
4966 "direct_interest_snapshot"."weight";
4968 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
4971 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
4972 SELECT
4973 "initiative"."issue_id",
4974 "initiative"."id" AS "initiative_id",
4975 "initiative"."admitted",
4976 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
4977 "remaining_harmonic_supporter_weight"."weight_den"
4978 FROM "remaining_harmonic_supporter_weight"
4979 JOIN "initiative"
4980 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
4981 AND "initiative"."harmonic_weight" ISNULL
4982 JOIN "direct_supporter_snapshot"
4983 ON "remaining_harmonic_supporter_weight"."snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
4984 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
4985 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
4986 AND (
4987 "direct_supporter_snapshot"."satisfied" = TRUE OR
4988 coalesce("initiative"."admitted", FALSE) = FALSE
4990 GROUP BY
4991 "initiative"."issue_id",
4992 "initiative"."id",
4993 "initiative"."admitted",
4994 "remaining_harmonic_supporter_weight"."weight_den";
4996 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
4999 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
5000 SELECT
5001 "issue_id",
5002 "id" AS "initiative_id",
5003 "admitted",
5004 0 AS "weight_num",
5005 1 AS "weight_den"
5006 FROM "initiative"
5007 WHERE "harmonic_weight" ISNULL;
5009 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';
5012 CREATE FUNCTION "set_harmonic_initiative_weights"
5013 ( "issue_id_p" "issue"."id"%TYPE )
5014 RETURNS VOID
5015 LANGUAGE 'plpgsql' VOLATILE AS $$
5016 DECLARE
5017 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
5018 "i" INT4;
5019 "count_v" INT4;
5020 "summand_v" FLOAT;
5021 "id_ary" INT4[];
5022 "weight_ary" FLOAT[];
5023 "min_weight_v" FLOAT;
5024 BEGIN
5025 PERFORM "require_transaction_isolation"();
5026 UPDATE "initiative" SET "harmonic_weight" = NULL
5027 WHERE "issue_id" = "issue_id_p";
5028 LOOP
5029 "min_weight_v" := NULL;
5030 "i" := 0;
5031 "count_v" := 0;
5032 FOR "weight_row" IN
5033 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
5034 WHERE "issue_id" = "issue_id_p"
5035 AND (
5036 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
5037 SELECT NULL FROM "initiative"
5038 WHERE "issue_id" = "issue_id_p"
5039 AND "harmonic_weight" ISNULL
5040 AND coalesce("admitted", FALSE) = FALSE
5043 UNION ALL -- needed for corner cases
5044 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
5045 WHERE "issue_id" = "issue_id_p"
5046 AND (
5047 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
5048 SELECT NULL FROM "initiative"
5049 WHERE "issue_id" = "issue_id_p"
5050 AND "harmonic_weight" ISNULL
5051 AND coalesce("admitted", FALSE) = FALSE
5054 ORDER BY "initiative_id" DESC, "weight_den" DESC
5055 -- NOTE: non-admitted initiatives placed first (at last positions),
5056 -- latest initiatives treated worse in case of tie
5057 LOOP
5058 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
5059 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
5060 "i" := "i" + 1;
5061 "count_v" := "i";
5062 "id_ary"["i"] := "weight_row"."initiative_id";
5063 "weight_ary"["i"] := "summand_v";
5064 ELSE
5065 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
5066 END IF;
5067 END LOOP;
5068 EXIT WHEN "count_v" = 0;
5069 "i" := 1;
5070 LOOP
5071 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
5072 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
5073 "min_weight_v" := "weight_ary"["i"];
5074 END IF;
5075 "i" := "i" + 1;
5076 EXIT WHEN "i" > "count_v";
5077 END LOOP;
5078 "i" := 1;
5079 LOOP
5080 IF "weight_ary"["i"] = "min_weight_v" THEN
5081 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
5082 WHERE "id" = "id_ary"["i"];
5083 EXIT;
5084 END IF;
5085 "i" := "i" + 1;
5086 END LOOP;
5087 END LOOP;
5088 UPDATE "initiative" SET "harmonic_weight" = 0
5089 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
5090 END;
5091 $$;
5093 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
5094 ( "issue"."id"%TYPE )
5095 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
5099 ------------------------------
5100 -- Calculation of snapshots --
5101 ------------------------------
5104 CREATE FUNCTION "weight_of_added_delegations_for_snapshot"
5105 ( "snapshot_id_p" "snapshot"."id"%TYPE,
5106 "issue_id_p" "issue"."id"%TYPE,
5107 "member_id_p" "member"."id"%TYPE,
5108 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
5109 RETURNS "direct_interest_snapshot"."weight"%TYPE
5110 LANGUAGE 'plpgsql' VOLATILE AS $$
5111 DECLARE
5112 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5113 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
5114 "weight_v" INT4;
5115 "sub_weight_v" INT4;
5116 BEGIN
5117 PERFORM "require_transaction_isolation"();
5118 "weight_v" := 0;
5119 FOR "issue_delegation_row" IN
5120 SELECT * FROM "issue_delegation"
5121 WHERE "trustee_id" = "member_id_p"
5122 AND "issue_id" = "issue_id_p"
5123 LOOP
5124 IF NOT EXISTS (
5125 SELECT NULL FROM "direct_interest_snapshot"
5126 WHERE "snapshot_id" = "snapshot_id_p"
5127 AND "issue_id" = "issue_id_p"
5128 AND "member_id" = "issue_delegation_row"."truster_id"
5129 ) AND NOT EXISTS (
5130 SELECT NULL FROM "delegating_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 ) THEN
5135 "delegate_member_ids_v" :=
5136 "member_id_p" || "delegate_member_ids_p";
5137 INSERT INTO "delegating_interest_snapshot" (
5138 "snapshot_id",
5139 "issue_id",
5140 "member_id",
5141 "scope",
5142 "delegate_member_ids"
5143 ) VALUES (
5144 "snapshot_id_p",
5145 "issue_id_p",
5146 "issue_delegation_row"."truster_id",
5147 "issue_delegation_row"."scope",
5148 "delegate_member_ids_v"
5149 );
5150 "sub_weight_v" := 1 +
5151 "weight_of_added_delegations_for_snapshot"(
5152 "snapshot_id_p",
5153 "issue_id_p",
5154 "issue_delegation_row"."truster_id",
5155 "delegate_member_ids_v"
5156 );
5157 UPDATE "delegating_interest_snapshot"
5158 SET "weight" = "sub_weight_v"
5159 WHERE "snapshot_id" = "snapshot_id_p"
5160 AND "issue_id" = "issue_id_p"
5161 AND "member_id" = "issue_delegation_row"."truster_id";
5162 "weight_v" := "weight_v" + "sub_weight_v";
5163 END IF;
5164 END LOOP;
5165 RETURN "weight_v";
5166 END;
5167 $$;
5169 COMMENT ON FUNCTION "weight_of_added_delegations_for_snapshot"
5170 ( "snapshot"."id"%TYPE,
5171 "issue"."id"%TYPE,
5172 "member"."id"%TYPE,
5173 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
5174 IS 'Helper function for "fill_snapshot" function';
5177 CREATE FUNCTION "take_snapshot"
5178 ( "issue_id_p" "issue"."id"%TYPE,
5179 "area_id_p" "area"."id"%TYPE = NULL )
5180 RETURNS "snapshot"."id"%TYPE
5181 LANGUAGE 'plpgsql' VOLATILE AS $$
5182 DECLARE
5183 "area_id_v" "area"."id"%TYPE;
5184 "unit_id_v" "unit"."id"%TYPE;
5185 "snapshot_id_v" "snapshot"."id"%TYPE;
5186 "issue_id_v" "issue"."id"%TYPE;
5187 "member_id_v" "member"."id"%TYPE;
5188 BEGIN
5189 IF "issue_id_p" NOTNULL AND "area_id_p" NOTNULL THEN
5190 RAISE EXCEPTION 'One of "issue_id_p" and "area_id_p" must be NULL';
5191 END IF;
5192 PERFORM "require_transaction_isolation"();
5193 IF "issue_id_p" ISNULL THEN
5194 "area_id_v" := "area_id_p";
5195 ELSE
5196 SELECT "area_id" INTO "area_id_v"
5197 FROM "issue" WHERE "id" = "issue_id_p";
5198 END IF;
5199 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5200 INSERT INTO "snapshot" ("area_id", "issue_id")
5201 VALUES ("area_id_v", "issue_id_p")
5202 RETURNING "id" INTO "snapshot_id_v";
5203 INSERT INTO "snapshot_population" ("snapshot_id", "member_id")
5204 SELECT "snapshot_id_v", "member_id"
5205 FROM "unit_member" WHERE "unit_id" = "unit_id_v";
5206 UPDATE "snapshot" SET
5207 "population" = (
5208 SELECT count(1) FROM "snapshot_population"
5209 WHERE "snapshot_id" = "snapshot_id_v"
5210 ) WHERE "id" = "snapshot_id_v";
5211 FOR "issue_id_v" IN
5212 SELECT "id" FROM "issue"
5213 WHERE CASE WHEN "issue_id_p" ISNULL THEN
5214 "area_id" = "area_id_p" AND
5215 "state" = 'admission'
5216 ELSE
5217 "id" = "issue_id_p"
5218 END
5219 LOOP
5220 INSERT INTO "snapshot_issue" ("snapshot_id", "issue_id")
5221 VALUES ("snapshot_id_v", "issue_id_v");
5222 INSERT INTO "direct_interest_snapshot"
5223 ("snapshot_id", "issue_id", "member_id")
5224 SELECT
5225 "snapshot_id_v" AS "snapshot_id",
5226 "issue_id_v" AS "issue_id",
5227 "member"."id" AS "member_id"
5228 FROM "issue"
5229 JOIN "area" ON "issue"."area_id" = "area"."id"
5230 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
5231 JOIN "member" ON "interest"."member_id" = "member"."id"
5232 JOIN "privilege"
5233 ON "privilege"."unit_id" = "area"."unit_id"
5234 AND "privilege"."member_id" = "member"."id"
5235 WHERE "issue"."id" = "issue_id_v"
5236 AND "member"."active" AND "privilege"."voting_right";
5237 FOR "member_id_v" IN
5238 SELECT "member_id" FROM "direct_interest_snapshot"
5239 WHERE "snapshot_id" = "snapshot_id_v"
5240 AND "issue_id" = "issue_id_v"
5241 LOOP
5242 UPDATE "direct_interest_snapshot" SET
5243 "weight" = 1 +
5244 "weight_of_added_delegations_for_snapshot"(
5245 "snapshot_id_v",
5246 "issue_id_v",
5247 "member_id_v",
5248 '{}'
5250 WHERE "snapshot_id" = "snapshot_id_v"
5251 AND "issue_id" = "issue_id_v"
5252 AND "member_id" = "member_id_v";
5253 END LOOP;
5254 INSERT INTO "direct_supporter_snapshot"
5255 ( "snapshot_id", "issue_id", "initiative_id", "member_id",
5256 "draft_id", "informed", "satisfied" )
5257 SELECT
5258 "snapshot_id_v" AS "snapshot_id",
5259 "issue_id_v" AS "issue_id",
5260 "initiative"."id" AS "initiative_id",
5261 "supporter"."member_id" AS "member_id",
5262 "supporter"."draft_id" AS "draft_id",
5263 "supporter"."draft_id" = "current_draft"."id" AS "informed",
5264 NOT EXISTS (
5265 SELECT NULL FROM "critical_opinion"
5266 WHERE "initiative_id" = "initiative"."id"
5267 AND "member_id" = "supporter"."member_id"
5268 ) AS "satisfied"
5269 FROM "initiative"
5270 JOIN "supporter"
5271 ON "supporter"."initiative_id" = "initiative"."id"
5272 JOIN "current_draft"
5273 ON "initiative"."id" = "current_draft"."initiative_id"
5274 JOIN "direct_interest_snapshot"
5275 ON "snapshot_id_v" = "direct_interest_snapshot"."snapshot_id"
5276 AND "supporter"."member_id" = "direct_interest_snapshot"."member_id"
5277 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
5278 WHERE "initiative"."issue_id" = "issue_id_v";
5279 DELETE FROM "temporary_suggestion_counts";
5280 INSERT INTO "temporary_suggestion_counts"
5281 ( "id",
5282 "minus2_unfulfilled_count", "minus2_fulfilled_count",
5283 "minus1_unfulfilled_count", "minus1_fulfilled_count",
5284 "plus1_unfulfilled_count", "plus1_fulfilled_count",
5285 "plus2_unfulfilled_count", "plus2_fulfilled_count" )
5286 SELECT
5287 "suggestion"."id",
5288 ( SELECT coalesce(sum("di"."weight"), 0)
5289 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5290 ON "di"."snapshot_id" = "snapshot_id_v"
5291 AND "di"."issue_id" = "issue_id_v"
5292 AND "di"."member_id" = "opinion"."member_id"
5293 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5294 AND "opinion"."degree" = -2
5295 AND "opinion"."fulfilled" = FALSE
5296 ) AS "minus2_unfulfilled_count",
5297 ( SELECT coalesce(sum("di"."weight"), 0)
5298 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5299 ON "di"."snapshot_id" = "snapshot_id_v"
5300 AND "di"."issue_id" = "issue_id_v"
5301 AND "di"."member_id" = "opinion"."member_id"
5302 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5303 AND "opinion"."degree" = -2
5304 AND "opinion"."fulfilled" = TRUE
5305 ) AS "minus2_fulfilled_count",
5306 ( SELECT coalesce(sum("di"."weight"), 0)
5307 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5308 ON "di"."snapshot_id" = "snapshot_id_v"
5309 AND "di"."issue_id" = "issue_id_v"
5310 AND "di"."member_id" = "opinion"."member_id"
5311 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5312 AND "opinion"."degree" = -1
5313 AND "opinion"."fulfilled" = FALSE
5314 ) AS "minus1_unfulfilled_count",
5315 ( SELECT coalesce(sum("di"."weight"), 0)
5316 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5317 ON "di"."snapshot_id" = "snapshot_id_v"
5318 AND "di"."issue_id" = "issue_id_v"
5319 AND "di"."member_id" = "opinion"."member_id"
5320 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5321 AND "opinion"."degree" = -1
5322 AND "opinion"."fulfilled" = TRUE
5323 ) AS "minus1_fulfilled_count",
5324 ( SELECT coalesce(sum("di"."weight"), 0)
5325 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5326 ON "di"."snapshot_id" = "snapshot_id_v"
5327 AND "di"."issue_id" = "issue_id_v"
5328 AND "di"."member_id" = "opinion"."member_id"
5329 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5330 AND "opinion"."degree" = 1
5331 AND "opinion"."fulfilled" = FALSE
5332 ) AS "plus1_unfulfilled_count",
5333 ( SELECT coalesce(sum("di"."weight"), 0)
5334 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5335 ON "di"."snapshot_id" = "snapshot_id_v"
5336 AND "di"."issue_id" = "issue_id_v"
5337 AND "di"."member_id" = "opinion"."member_id"
5338 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5339 AND "opinion"."degree" = 1
5340 AND "opinion"."fulfilled" = TRUE
5341 ) AS "plus1_fulfilled_count",
5342 ( SELECT coalesce(sum("di"."weight"), 0)
5343 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5344 ON "di"."snapshot_id" = "snapshot_id_v"
5345 AND "di"."issue_id" = "issue_id_v"
5346 AND "di"."member_id" = "opinion"."member_id"
5347 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5348 AND "opinion"."degree" = 2
5349 AND "opinion"."fulfilled" = FALSE
5350 ) AS "plus2_unfulfilled_count",
5351 ( SELECT coalesce(sum("di"."weight"), 0)
5352 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5353 ON "di"."snapshot_id" = "snapshot_id_v"
5354 AND "di"."issue_id" = "issue_id_v"
5355 AND "di"."member_id" = "opinion"."member_id"
5356 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5357 AND "opinion"."degree" = 2
5358 AND "opinion"."fulfilled" = TRUE
5359 ) AS "plus2_fulfilled_count"
5360 FROM "suggestion" JOIN "initiative"
5361 ON "suggestion"."initiative_id" = "initiative"."id"
5362 WHERE "initiative"."issue_id" = "issue_id_v";
5363 END LOOP;
5364 RETURN "snapshot_id_v";
5365 END;
5366 $$;
5368 COMMENT ON FUNCTION "take_snapshot"
5369 ( "issue"."id"%TYPE,
5370 "area"."id"%TYPE )
5371 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.';
5374 CREATE FUNCTION "finish_snapshot"
5375 ( "issue_id_p" "issue"."id"%TYPE )
5376 RETURNS VOID
5377 LANGUAGE 'plpgsql' VOLATILE AS $$
5378 DECLARE
5379 "snapshot_id_v" "snapshot"."id"%TYPE;
5380 BEGIN
5381 -- NOTE: function does not require snapshot isolation but we don't call
5382 -- "dont_require_snapshot_isolation" here because this function is
5383 -- also invoked by "check_issue"
5384 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
5385 SELECT "id" INTO "snapshot_id_v" FROM "snapshot"
5386 ORDER BY "id" DESC LIMIT 1;
5387 UPDATE "issue" SET
5388 "calculated" = "snapshot"."calculated",
5389 "latest_snapshot_id" = "snapshot_id_v",
5390 "population" = "snapshot"."population",
5391 "initiative_quorum" = CASE WHEN
5392 "policy"."initiative_quorum" > ceil(
5393 ( "issue"."population"::INT8 *
5394 "policy"."initiative_quorum_num"::INT8 ) /
5395 "policy"."initiative_quorum_den"::FLOAT8
5396 )::INT4
5397 THEN
5398 "policy"."initiative_quorum"
5399 ELSE
5400 ceil(
5401 ( "issue"."population"::INT8 *
5402 "policy"."initiative_quorum_num"::INT8 ) /
5403 "policy"."initiative_quorum_den"::FLOAT8
5404 )::INT4
5405 END
5406 FROM "snapshot", "policy"
5407 WHERE "issue"."id" = "issue_id_p"
5408 AND "snapshot"."id" = "snapshot_id_v"
5409 AND "policy"."id" = "issue"."policy_id";
5410 UPDATE "initiative" SET
5411 "supporter_count" = (
5412 SELECT coalesce(sum("di"."weight"), 0)
5413 FROM "direct_interest_snapshot" AS "di"
5414 JOIN "direct_supporter_snapshot" AS "ds"
5415 ON "di"."member_id" = "ds"."member_id"
5416 WHERE "di"."snapshot_id" = "snapshot_id_v"
5417 AND "di"."issue_id" = "issue_id_p"
5418 AND "ds"."snapshot_id" = "snapshot_id_v"
5419 AND "ds"."initiative_id" = "initiative"."id"
5420 ),
5421 "informed_supporter_count" = (
5422 SELECT coalesce(sum("di"."weight"), 0)
5423 FROM "direct_interest_snapshot" AS "di"
5424 JOIN "direct_supporter_snapshot" AS "ds"
5425 ON "di"."member_id" = "ds"."member_id"
5426 WHERE "di"."snapshot_id" = "snapshot_id_v"
5427 AND "di"."issue_id" = "issue_id_p"
5428 AND "ds"."snapshot_id" = "snapshot_id_v"
5429 AND "ds"."initiative_id" = "initiative"."id"
5430 AND "ds"."informed"
5431 ),
5432 "satisfied_supporter_count" = (
5433 SELECT coalesce(sum("di"."weight"), 0)
5434 FROM "direct_interest_snapshot" AS "di"
5435 JOIN "direct_supporter_snapshot" AS "ds"
5436 ON "di"."member_id" = "ds"."member_id"
5437 WHERE "di"."snapshot_id" = "snapshot_id_v"
5438 AND "di"."issue_id" = "issue_id_p"
5439 AND "ds"."snapshot_id" = "snapshot_id_v"
5440 AND "ds"."initiative_id" = "initiative"."id"
5441 AND "ds"."satisfied"
5442 ),
5443 "satisfied_informed_supporter_count" = (
5444 SELECT coalesce(sum("di"."weight"), 0)
5445 FROM "direct_interest_snapshot" AS "di"
5446 JOIN "direct_supporter_snapshot" AS "ds"
5447 ON "di"."member_id" = "ds"."member_id"
5448 WHERE "di"."snapshot_id" = "snapshot_id_v"
5449 AND "di"."issue_id" = "issue_id_p"
5450 AND "ds"."snapshot_id" = "snapshot_id_v"
5451 AND "ds"."initiative_id" = "initiative"."id"
5452 AND "ds"."informed"
5453 AND "ds"."satisfied"
5455 WHERE "issue_id" = "issue_id_p";
5456 UPDATE "suggestion" SET
5457 "minus2_unfulfilled_count" = "temp"."minus2_unfulfilled_count",
5458 "minus2_fulfilled_count" = "temp"."minus2_fulfilled_count",
5459 "minus1_unfulfilled_count" = "temp"."minus1_unfulfilled_count",
5460 "minus1_fulfilled_count" = "temp"."minus1_fulfilled_count",
5461 "plus1_unfulfilled_count" = "temp"."plus1_unfulfilled_count",
5462 "plus1_fulfilled_count" = "temp"."plus1_fulfilled_count",
5463 "plus2_unfulfilled_count" = "temp"."plus2_unfulfilled_count",
5464 "plus2_fulfilled_count" = "temp"."plus2_fulfilled_count"
5465 FROM "temporary_suggestion_counts" AS "temp", "initiative"
5466 WHERE "temp"."id" = "suggestion"."id"
5467 AND "initiative"."issue_id" = "issue_id_p"
5468 AND "suggestion"."initiative_id" = "initiative"."id";
5469 DELETE FROM "temporary_suggestion_counts";
5470 RETURN;
5471 END;
5472 $$;
5474 COMMENT ON FUNCTION "finish_snapshot"
5475 ( "issue"."id"%TYPE )
5476 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)';
5480 -----------------------
5481 -- Counting of votes --
5482 -----------------------
5485 CREATE FUNCTION "weight_of_added_vote_delegations"
5486 ( "issue_id_p" "issue"."id"%TYPE,
5487 "member_id_p" "member"."id"%TYPE,
5488 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
5489 RETURNS "direct_voter"."weight"%TYPE
5490 LANGUAGE 'plpgsql' VOLATILE AS $$
5491 DECLARE
5492 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5493 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
5494 "weight_v" INT4;
5495 "sub_weight_v" INT4;
5496 BEGIN
5497 PERFORM "require_transaction_isolation"();
5498 "weight_v" := 0;
5499 FOR "issue_delegation_row" IN
5500 SELECT * FROM "issue_delegation"
5501 WHERE "trustee_id" = "member_id_p"
5502 AND "issue_id" = "issue_id_p"
5503 LOOP
5504 IF NOT EXISTS (
5505 SELECT NULL FROM "direct_voter"
5506 WHERE "member_id" = "issue_delegation_row"."truster_id"
5507 AND "issue_id" = "issue_id_p"
5508 ) AND NOT EXISTS (
5509 SELECT NULL FROM "delegating_voter"
5510 WHERE "member_id" = "issue_delegation_row"."truster_id"
5511 AND "issue_id" = "issue_id_p"
5512 ) THEN
5513 "delegate_member_ids_v" :=
5514 "member_id_p" || "delegate_member_ids_p";
5515 INSERT INTO "delegating_voter" (
5516 "issue_id",
5517 "member_id",
5518 "scope",
5519 "delegate_member_ids"
5520 ) VALUES (
5521 "issue_id_p",
5522 "issue_delegation_row"."truster_id",
5523 "issue_delegation_row"."scope",
5524 "delegate_member_ids_v"
5525 );
5526 "sub_weight_v" := 1 +
5527 "weight_of_added_vote_delegations"(
5528 "issue_id_p",
5529 "issue_delegation_row"."truster_id",
5530 "delegate_member_ids_v"
5531 );
5532 UPDATE "delegating_voter"
5533 SET "weight" = "sub_weight_v"
5534 WHERE "issue_id" = "issue_id_p"
5535 AND "member_id" = "issue_delegation_row"."truster_id";
5536 "weight_v" := "weight_v" + "sub_weight_v";
5537 END IF;
5538 END LOOP;
5539 RETURN "weight_v";
5540 END;
5541 $$;
5543 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
5544 ( "issue"."id"%TYPE,
5545 "member"."id"%TYPE,
5546 "delegating_voter"."delegate_member_ids"%TYPE )
5547 IS 'Helper function for "add_vote_delegations" function';
5550 CREATE FUNCTION "add_vote_delegations"
5551 ( "issue_id_p" "issue"."id"%TYPE )
5552 RETURNS VOID
5553 LANGUAGE 'plpgsql' VOLATILE AS $$
5554 DECLARE
5555 "member_id_v" "member"."id"%TYPE;
5556 BEGIN
5557 PERFORM "require_transaction_isolation"();
5558 FOR "member_id_v" IN
5559 SELECT "member_id" FROM "direct_voter"
5560 WHERE "issue_id" = "issue_id_p"
5561 LOOP
5562 UPDATE "direct_voter" SET
5563 "weight" = "weight" + "weight_of_added_vote_delegations"(
5564 "issue_id_p",
5565 "member_id_v",
5566 '{}'
5568 WHERE "member_id" = "member_id_v"
5569 AND "issue_id" = "issue_id_p";
5570 END LOOP;
5571 RETURN;
5572 END;
5573 $$;
5575 COMMENT ON FUNCTION "add_vote_delegations"
5576 ( "issue_id_p" "issue"."id"%TYPE )
5577 IS 'Helper function for "close_voting" function';
5580 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
5581 RETURNS VOID
5582 LANGUAGE 'plpgsql' VOLATILE AS $$
5583 DECLARE
5584 "area_id_v" "area"."id"%TYPE;
5585 "unit_id_v" "unit"."id"%TYPE;
5586 "member_id_v" "member"."id"%TYPE;
5587 BEGIN
5588 PERFORM "require_transaction_isolation"();
5589 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
5590 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5591 -- override protection triggers:
5592 INSERT INTO "temporary_transaction_data" ("key", "value")
5593 VALUES ('override_protection_triggers', TRUE::TEXT);
5594 -- delete timestamp of voting comment:
5595 UPDATE "direct_voter" SET "comment_changed" = NULL
5596 WHERE "issue_id" = "issue_id_p";
5597 -- delete delegating votes (in cases of manual reset of issue state):
5598 DELETE FROM "delegating_voter"
5599 WHERE "issue_id" = "issue_id_p";
5600 -- delete votes from non-privileged voters:
5601 DELETE FROM "direct_voter"
5602 USING (
5603 SELECT
5604 "direct_voter"."member_id"
5605 FROM "direct_voter"
5606 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
5607 LEFT JOIN "privilege"
5608 ON "privilege"."unit_id" = "unit_id_v"
5609 AND "privilege"."member_id" = "direct_voter"."member_id"
5610 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
5611 "member"."active" = FALSE OR
5612 "privilege"."voting_right" ISNULL OR
5613 "privilege"."voting_right" = FALSE
5615 ) AS "subquery"
5616 WHERE "direct_voter"."issue_id" = "issue_id_p"
5617 AND "direct_voter"."member_id" = "subquery"."member_id";
5618 -- consider delegations:
5619 UPDATE "direct_voter" SET "weight" = 1
5620 WHERE "issue_id" = "issue_id_p";
5621 PERFORM "add_vote_delegations"("issue_id_p");
5622 -- mark first preferences:
5623 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
5624 FROM (
5625 SELECT
5626 "vote"."initiative_id",
5627 "vote"."member_id",
5628 CASE WHEN "vote"."grade" > 0 THEN
5629 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
5630 ELSE NULL
5631 END AS "first_preference"
5632 FROM "vote"
5633 JOIN "initiative" -- NOTE: due to missing index on issue_id
5634 ON "vote"."issue_id" = "initiative"."issue_id"
5635 JOIN "vote" AS "agg"
5636 ON "initiative"."id" = "agg"."initiative_id"
5637 AND "vote"."member_id" = "agg"."member_id"
5638 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
5639 ) AS "subquery"
5640 WHERE "vote"."issue_id" = "issue_id_p"
5641 AND "vote"."initiative_id" = "subquery"."initiative_id"
5642 AND "vote"."member_id" = "subquery"."member_id";
5643 -- finish overriding protection triggers (avoids garbage):
5644 DELETE FROM "temporary_transaction_data"
5645 WHERE "key" = 'override_protection_triggers';
5646 -- materialize battle_view:
5647 -- NOTE: "closed" column of issue must be set at this point
5648 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
5649 INSERT INTO "battle" (
5650 "issue_id",
5651 "winning_initiative_id", "losing_initiative_id",
5652 "count"
5653 ) SELECT
5654 "issue_id",
5655 "winning_initiative_id", "losing_initiative_id",
5656 "count"
5657 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
5658 -- set voter count:
5659 UPDATE "issue" SET
5660 "voter_count" = (
5661 SELECT coalesce(sum("weight"), 0)
5662 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
5664 WHERE "id" = "issue_id_p";
5665 -- copy "positive_votes" and "negative_votes" from "battle" table:
5666 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
5667 UPDATE "initiative" SET
5668 "first_preference_votes" = 0,
5669 "positive_votes" = "battle_win"."count",
5670 "negative_votes" = "battle_lose"."count"
5671 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
5672 WHERE
5673 "battle_win"."issue_id" = "issue_id_p" AND
5674 "battle_win"."winning_initiative_id" = "initiative"."id" AND
5675 "battle_win"."losing_initiative_id" ISNULL AND
5676 "battle_lose"."issue_id" = "issue_id_p" AND
5677 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
5678 "battle_lose"."winning_initiative_id" ISNULL;
5679 -- calculate "first_preference_votes":
5680 -- NOTE: will only set values not equal to zero
5681 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
5682 FROM (
5683 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
5684 FROM "vote" JOIN "direct_voter"
5685 ON "vote"."issue_id" = "direct_voter"."issue_id"
5686 AND "vote"."member_id" = "direct_voter"."member_id"
5687 WHERE "vote"."first_preference"
5688 GROUP BY "vote"."initiative_id"
5689 ) AS "subquery"
5690 WHERE "initiative"."issue_id" = "issue_id_p"
5691 AND "initiative"."admitted"
5692 AND "initiative"."id" = "subquery"."initiative_id";
5693 END;
5694 $$;
5696 COMMENT ON FUNCTION "close_voting"
5697 ( "issue"."id"%TYPE )
5698 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.';
5701 CREATE FUNCTION "defeat_strength"
5702 ( "positive_votes_p" INT4,
5703 "negative_votes_p" INT4,
5704 "defeat_strength_p" "defeat_strength" )
5705 RETURNS INT8
5706 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5707 BEGIN
5708 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
5709 IF "positive_votes_p" > "negative_votes_p" THEN
5710 RETURN "positive_votes_p";
5711 ELSE
5712 RETURN 0;
5713 END IF;
5714 ELSE
5715 IF "positive_votes_p" > "negative_votes_p" THEN
5716 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
5717 ELSIF "positive_votes_p" = "negative_votes_p" THEN
5718 RETURN 0;
5719 ELSE
5720 RETURN -1;
5721 END IF;
5722 END IF;
5723 END;
5724 $$;
5726 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")';
5729 CREATE FUNCTION "secondary_link_strength"
5730 ( "initiative1_ord_p" INT4,
5731 "initiative2_ord_p" INT4,
5732 "tie_breaking_p" "tie_breaking" )
5733 RETURNS INT8
5734 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5735 BEGIN
5736 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
5737 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
5738 END IF;
5739 RETURN (
5740 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
5742 ELSE
5743 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
5744 1::INT8 << 62
5745 ELSE 0 END
5747 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
5748 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
5749 ELSE
5750 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
5751 END
5752 END
5753 );
5754 END;
5755 $$;
5757 COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4, "tie_breaking") IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)';
5760 CREATE TYPE "link_strength" AS (
5761 "primary" INT8,
5762 "secondary" INT8 );
5764 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'')';
5767 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
5768 RETURNS "link_strength"[][]
5769 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5770 DECLARE
5771 "dimension_v" INT4;
5772 "matrix_p" "link_strength"[][];
5773 "i" INT4;
5774 "j" INT4;
5775 "k" INT4;
5776 BEGIN
5777 "dimension_v" := array_upper("matrix_d", 1);
5778 "matrix_p" := "matrix_d";
5779 "i" := 1;
5780 LOOP
5781 "j" := 1;
5782 LOOP
5783 IF "i" != "j" THEN
5784 "k" := 1;
5785 LOOP
5786 IF "i" != "k" AND "j" != "k" THEN
5787 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
5788 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
5789 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
5790 END IF;
5791 ELSE
5792 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
5793 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
5794 END IF;
5795 END IF;
5796 END IF;
5797 EXIT WHEN "k" = "dimension_v";
5798 "k" := "k" + 1;
5799 END LOOP;
5800 END IF;
5801 EXIT WHEN "j" = "dimension_v";
5802 "j" := "j" + 1;
5803 END LOOP;
5804 EXIT WHEN "i" = "dimension_v";
5805 "i" := "i" + 1;
5806 END LOOP;
5807 RETURN "matrix_p";
5808 END;
5809 $$;
5811 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
5814 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
5815 RETURNS VOID
5816 LANGUAGE 'plpgsql' VOLATILE AS $$
5817 DECLARE
5818 "issue_row" "issue"%ROWTYPE;
5819 "policy_row" "policy"%ROWTYPE;
5820 "dimension_v" INT4;
5821 "matrix_a" INT4[][]; -- absolute votes
5822 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
5823 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
5824 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
5825 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
5826 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
5827 "i" INT4;
5828 "j" INT4;
5829 "m" INT4;
5830 "n" INT4;
5831 "battle_row" "battle"%ROWTYPE;
5832 "rank_ary" INT4[];
5833 "rank_v" INT4;
5834 "initiative_id_v" "initiative"."id"%TYPE;
5835 BEGIN
5836 PERFORM "require_transaction_isolation"();
5837 SELECT * INTO "issue_row"
5838 FROM "issue" WHERE "id" = "issue_id_p";
5839 SELECT * INTO "policy_row"
5840 FROM "policy" WHERE "id" = "issue_row"."policy_id";
5841 SELECT count(1) INTO "dimension_v"
5842 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
5843 -- create "matrix_a" with absolute number of votes in pairwise
5844 -- comparison:
5845 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
5846 "i" := 1;
5847 "j" := 2;
5848 FOR "battle_row" IN
5849 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
5850 ORDER BY
5851 "winning_initiative_id" NULLS FIRST,
5852 "losing_initiative_id" NULLS FIRST
5853 LOOP
5854 "matrix_a"["i"]["j"] := "battle_row"."count";
5855 IF "j" = "dimension_v" THEN
5856 "i" := "i" + 1;
5857 "j" := 1;
5858 ELSE
5859 "j" := "j" + 1;
5860 IF "j" = "i" THEN
5861 "j" := "j" + 1;
5862 END IF;
5863 END IF;
5864 END LOOP;
5865 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
5866 RAISE EXCEPTION 'Wrong battle count (should not happen)';
5867 END IF;
5868 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
5869 -- and "secondary_link_strength" functions:
5870 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
5871 "i" := 1;
5872 LOOP
5873 "j" := 1;
5874 LOOP
5875 IF "i" != "j" THEN
5876 "matrix_d"["i"]["j"] := (
5877 "defeat_strength"(
5878 "matrix_a"["i"]["j"],
5879 "matrix_a"["j"]["i"],
5880 "policy_row"."defeat_strength"
5881 ),
5882 "secondary_link_strength"(
5883 "i",
5884 "j",
5885 "policy_row"."tie_breaking"
5887 )::"link_strength";
5888 END IF;
5889 EXIT WHEN "j" = "dimension_v";
5890 "j" := "j" + 1;
5891 END LOOP;
5892 EXIT WHEN "i" = "dimension_v";
5893 "i" := "i" + 1;
5894 END LOOP;
5895 -- find best paths:
5896 "matrix_p" := "find_best_paths"("matrix_d");
5897 -- create partial order:
5898 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
5899 "i" := 1;
5900 LOOP
5901 "j" := "i" + 1;
5902 LOOP
5903 IF "i" != "j" THEN
5904 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
5905 "matrix_b"["i"]["j"] := TRUE;
5906 "matrix_b"["j"]["i"] := FALSE;
5907 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
5908 "matrix_b"["i"]["j"] := FALSE;
5909 "matrix_b"["j"]["i"] := TRUE;
5910 END IF;
5911 END IF;
5912 EXIT WHEN "j" = "dimension_v";
5913 "j" := "j" + 1;
5914 END LOOP;
5915 EXIT WHEN "i" = "dimension_v" - 1;
5916 "i" := "i" + 1;
5917 END LOOP;
5918 -- tie-breaking by forbidding shared weakest links in beat-paths
5919 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
5920 -- is performed later by initiative id):
5921 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
5922 "m" := 1;
5923 LOOP
5924 "n" := "m" + 1;
5925 LOOP
5926 -- only process those candidates m and n, which are tied:
5927 IF "matrix_b"["m"]["n"] ISNULL THEN
5928 -- start with beat-paths prior tie-breaking:
5929 "matrix_t" := "matrix_p";
5930 -- start with all links allowed:
5931 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
5932 LOOP
5933 -- determine (and forbid) that link that is the weakest link
5934 -- in both the best path from candidate m to candidate n and
5935 -- from candidate n to candidate m:
5936 "i" := 1;
5937 <<forbid_one_link>>
5938 LOOP
5939 "j" := 1;
5940 LOOP
5941 IF "i" != "j" THEN
5942 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
5943 "matrix_f"["i"]["j"] := TRUE;
5944 -- exit for performance reasons,
5945 -- as exactly one link will be found:
5946 EXIT forbid_one_link;
5947 END IF;
5948 END IF;
5949 EXIT WHEN "j" = "dimension_v";
5950 "j" := "j" + 1;
5951 END LOOP;
5952 IF "i" = "dimension_v" THEN
5953 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
5954 END IF;
5955 "i" := "i" + 1;
5956 END LOOP;
5957 -- calculate best beat-paths while ignoring forbidden links:
5958 "i" := 1;
5959 LOOP
5960 "j" := 1;
5961 LOOP
5962 IF "i" != "j" THEN
5963 "matrix_t"["i"]["j"] := CASE
5964 WHEN "matrix_f"["i"]["j"]
5965 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
5966 ELSE "matrix_d"["i"]["j"] END;
5967 END IF;
5968 EXIT WHEN "j" = "dimension_v";
5969 "j" := "j" + 1;
5970 END LOOP;
5971 EXIT WHEN "i" = "dimension_v";
5972 "i" := "i" + 1;
5973 END LOOP;
5974 "matrix_t" := "find_best_paths"("matrix_t");
5975 -- extend partial order, if tie-breaking was successful:
5976 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
5977 "matrix_b"["m"]["n"] := TRUE;
5978 "matrix_b"["n"]["m"] := FALSE;
5979 EXIT;
5980 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
5981 "matrix_b"["m"]["n"] := FALSE;
5982 "matrix_b"["n"]["m"] := TRUE;
5983 EXIT;
5984 END IF;
5985 END LOOP;
5986 END IF;
5987 EXIT WHEN "n" = "dimension_v";
5988 "n" := "n" + 1;
5989 END LOOP;
5990 EXIT WHEN "m" = "dimension_v" - 1;
5991 "m" := "m" + 1;
5992 END LOOP;
5993 END IF;
5994 -- store a unique ranking in "rank_ary":
5995 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
5996 "rank_v" := 1;
5997 LOOP
5998 "i" := 1;
5999 <<assign_next_rank>>
6000 LOOP
6001 IF "rank_ary"["i"] ISNULL THEN
6002 "j" := 1;
6003 LOOP
6004 IF
6005 "i" != "j" AND
6006 "rank_ary"["j"] ISNULL AND
6007 ( "matrix_b"["j"]["i"] OR
6008 -- tie-breaking by "id"
6009 ( "matrix_b"["j"]["i"] ISNULL AND
6010 "j" < "i" ) )
6011 THEN
6012 -- someone else is better
6013 EXIT;
6014 END IF;
6015 IF "j" = "dimension_v" THEN
6016 -- noone is better
6017 "rank_ary"["i"] := "rank_v";
6018 EXIT assign_next_rank;
6019 END IF;
6020 "j" := "j" + 1;
6021 END LOOP;
6022 END IF;
6023 "i" := "i" + 1;
6024 IF "i" > "dimension_v" THEN
6025 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
6026 END IF;
6027 END LOOP;
6028 EXIT WHEN "rank_v" = "dimension_v";
6029 "rank_v" := "rank_v" + 1;
6030 END LOOP;
6031 -- write preliminary results:
6032 "i" := 2; -- omit status quo with "i" = 1
6033 FOR "initiative_id_v" IN
6034 SELECT "id" FROM "initiative"
6035 WHERE "issue_id" = "issue_id_p" AND "admitted"
6036 ORDER BY "id"
6037 LOOP
6038 UPDATE "initiative" SET
6039 "direct_majority" =
6040 CASE WHEN "policy_row"."direct_majority_strict" THEN
6041 "positive_votes" * "policy_row"."direct_majority_den" >
6042 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
6043 ELSE
6044 "positive_votes" * "policy_row"."direct_majority_den" >=
6045 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
6046 END
6047 AND "positive_votes" >= "policy_row"."direct_majority_positive"
6048 AND "issue_row"."voter_count"-"negative_votes" >=
6049 "policy_row"."direct_majority_non_negative",
6050 "indirect_majority" =
6051 CASE WHEN "policy_row"."indirect_majority_strict" THEN
6052 "positive_votes" * "policy_row"."indirect_majority_den" >
6053 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
6054 ELSE
6055 "positive_votes" * "policy_row"."indirect_majority_den" >=
6056 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
6057 END
6058 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
6059 AND "issue_row"."voter_count"-"negative_votes" >=
6060 "policy_row"."indirect_majority_non_negative",
6061 "schulze_rank" = "rank_ary"["i"],
6062 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
6063 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
6064 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
6065 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
6066 THEN NULL
6067 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
6068 "eligible" = FALSE,
6069 "winner" = FALSE,
6070 "rank" = NULL -- NOTE: in cases of manual reset of issue state
6071 WHERE "id" = "initiative_id_v";
6072 "i" := "i" + 1;
6073 END LOOP;
6074 IF "i" != "dimension_v" + 1 THEN
6075 RAISE EXCEPTION 'Wrong winner count (should not happen)';
6076 END IF;
6077 -- take indirect majorities into account:
6078 LOOP
6079 UPDATE "initiative" SET "indirect_majority" = TRUE
6080 FROM (
6081 SELECT "new_initiative"."id" AS "initiative_id"
6082 FROM "initiative" "old_initiative"
6083 JOIN "initiative" "new_initiative"
6084 ON "new_initiative"."issue_id" = "issue_id_p"
6085 AND "new_initiative"."indirect_majority" = FALSE
6086 JOIN "battle" "battle_win"
6087 ON "battle_win"."issue_id" = "issue_id_p"
6088 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
6089 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
6090 JOIN "battle" "battle_lose"
6091 ON "battle_lose"."issue_id" = "issue_id_p"
6092 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
6093 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
6094 WHERE "old_initiative"."issue_id" = "issue_id_p"
6095 AND "old_initiative"."indirect_majority" = TRUE
6096 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
6097 "battle_win"."count" * "policy_row"."indirect_majority_den" >
6098 "policy_row"."indirect_majority_num" *
6099 ("battle_win"."count"+"battle_lose"."count")
6100 ELSE
6101 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
6102 "policy_row"."indirect_majority_num" *
6103 ("battle_win"."count"+"battle_lose"."count")
6104 END
6105 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
6106 AND "issue_row"."voter_count"-"battle_lose"."count" >=
6107 "policy_row"."indirect_majority_non_negative"
6108 ) AS "subquery"
6109 WHERE "id" = "subquery"."initiative_id";
6110 EXIT WHEN NOT FOUND;
6111 END LOOP;
6112 -- set "multistage_majority" for remaining matching initiatives:
6113 UPDATE "initiative" SET "multistage_majority" = TRUE
6114 FROM (
6115 SELECT "losing_initiative"."id" AS "initiative_id"
6116 FROM "initiative" "losing_initiative"
6117 JOIN "initiative" "winning_initiative"
6118 ON "winning_initiative"."issue_id" = "issue_id_p"
6119 AND "winning_initiative"."admitted"
6120 JOIN "battle" "battle_win"
6121 ON "battle_win"."issue_id" = "issue_id_p"
6122 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
6123 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
6124 JOIN "battle" "battle_lose"
6125 ON "battle_lose"."issue_id" = "issue_id_p"
6126 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
6127 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
6128 WHERE "losing_initiative"."issue_id" = "issue_id_p"
6129 AND "losing_initiative"."admitted"
6130 AND "winning_initiative"."schulze_rank" <
6131 "losing_initiative"."schulze_rank"
6132 AND "battle_win"."count" > "battle_lose"."count"
6133 AND (
6134 "battle_win"."count" > "winning_initiative"."positive_votes" OR
6135 "battle_lose"."count" < "losing_initiative"."negative_votes" )
6136 ) AS "subquery"
6137 WHERE "id" = "subquery"."initiative_id";
6138 -- mark eligible initiatives:
6139 UPDATE "initiative" SET "eligible" = TRUE
6140 WHERE "issue_id" = "issue_id_p"
6141 AND "initiative"."direct_majority"
6142 AND "initiative"."indirect_majority"
6143 AND "initiative"."better_than_status_quo"
6144 AND (
6145 "policy_row"."no_multistage_majority" = FALSE OR
6146 "initiative"."multistage_majority" = FALSE )
6147 AND (
6148 "policy_row"."no_reverse_beat_path" = FALSE OR
6149 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
6150 -- mark final winner:
6151 UPDATE "initiative" SET "winner" = TRUE
6152 FROM (
6153 SELECT "id" AS "initiative_id"
6154 FROM "initiative"
6155 WHERE "issue_id" = "issue_id_p" AND "eligible"
6156 ORDER BY
6157 "schulze_rank",
6158 "id"
6159 LIMIT 1
6160 ) AS "subquery"
6161 WHERE "id" = "subquery"."initiative_id";
6162 -- write (final) ranks:
6163 "rank_v" := 1;
6164 FOR "initiative_id_v" IN
6165 SELECT "id"
6166 FROM "initiative"
6167 WHERE "issue_id" = "issue_id_p" AND "admitted"
6168 ORDER BY
6169 "winner" DESC,
6170 "eligible" DESC,
6171 "schulze_rank",
6172 "id"
6173 LOOP
6174 UPDATE "initiative" SET "rank" = "rank_v"
6175 WHERE "id" = "initiative_id_v";
6176 "rank_v" := "rank_v" + 1;
6177 END LOOP;
6178 -- set schulze rank of status quo and mark issue as finished:
6179 UPDATE "issue" SET
6180 "status_quo_schulze_rank" = "rank_ary"[1],
6181 "state" =
6182 CASE WHEN EXISTS (
6183 SELECT NULL FROM "initiative"
6184 WHERE "issue_id" = "issue_id_p" AND "winner"
6185 ) THEN
6186 'finished_with_winner'::"issue_state"
6187 ELSE
6188 'finished_without_winner'::"issue_state"
6189 END,
6190 "closed" = "phase_finished",
6191 "phase_finished" = NULL
6192 WHERE "id" = "issue_id_p";
6193 RETURN;
6194 END;
6195 $$;
6197 COMMENT ON FUNCTION "calculate_ranks"
6198 ( "issue"."id"%TYPE )
6199 IS 'Determine ranking (Votes have to be counted first)';
6203 -----------------------------
6204 -- Automatic state changes --
6205 -----------------------------
6208 CREATE FUNCTION "issue_admission"
6209 ( "area_id_p" "area"."id"%TYPE )
6210 RETURNS BOOLEAN
6211 LANGUAGE 'plpgsql' VOLATILE AS $$
6212 DECLARE
6213 "issue_id_v" "issue"."id"%TYPE;
6214 BEGIN
6215 PERFORM "dont_require_transaction_isolation"();
6216 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
6217 UPDATE "area" SET "issue_quorum" = "view"."issue_quorum"
6218 FROM "area_quorum" AS "view"
6219 WHERE "area"."id" = "view"."area_id"
6220 AND "area"."id" = "area_id_p";
6221 SELECT "id" INTO "issue_id_v" FROM "issue_for_admission"
6222 WHERE "area_id" = "area_id_p";
6223 IF "issue_id_v" ISNULL THEN RETURN FALSE; END IF;
6224 UPDATE "issue" SET
6225 "admission_snapshot_id" = "latest_snapshot_id",
6226 "state" = 'discussion',
6227 "accepted" = now(),
6228 "phase_finished" = NULL,
6229 "issue_quorum" = "issue_quorum"."issue_quorum"
6230 FROM "issue_quorum"
6231 WHERE "id" = "issue_id_v"
6232 AND "issue_quorum"."issue_id" = "issue_id_v";
6233 RETURN TRUE;
6234 END;
6235 $$;
6237 COMMENT ON FUNCTION "issue_admission"
6238 ( "area"."id"%TYPE )
6239 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';
6242 CREATE TYPE "check_issue_persistence" AS (
6243 "state" "issue_state",
6244 "phase_finished" BOOLEAN,
6245 "issue_revoked" BOOLEAN,
6246 "snapshot_created" BOOLEAN,
6247 "harmonic_weights_set" BOOLEAN,
6248 "closed_voting" BOOLEAN );
6250 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';
6253 CREATE FUNCTION "check_issue"
6254 ( "issue_id_p" "issue"."id"%TYPE,
6255 "persist" "check_issue_persistence" )
6256 RETURNS "check_issue_persistence"
6257 LANGUAGE 'plpgsql' VOLATILE AS $$
6258 DECLARE
6259 "issue_row" "issue"%ROWTYPE;
6260 "last_calculated_v" "snapshot"."calculated"%TYPE;
6261 "policy_row" "policy"%ROWTYPE;
6262 "initiative_row" "initiative"%ROWTYPE;
6263 "state_v" "issue_state";
6264 BEGIN
6265 PERFORM "require_transaction_isolation"();
6266 IF "persist" ISNULL THEN
6267 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6268 FOR UPDATE;
6269 SELECT "calculated" INTO "last_calculated_v"
6270 FROM "snapshot" JOIN "snapshot_issue"
6271 ON "snapshot"."id" = "snapshot_issue"."snapshot_id"
6272 WHERE "snapshot_issue"."issue_id" = "issue_id_p"
6273 ORDER BY "snapshot"."id" DESC;
6274 IF "issue_row"."closed" NOTNULL THEN
6275 RETURN NULL;
6276 END IF;
6277 "persist"."state" := "issue_row"."state";
6278 IF
6279 ( "issue_row"."state" = 'admission' AND "last_calculated_v" >=
6280 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
6281 ( "issue_row"."state" = 'discussion' AND now() >=
6282 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
6283 ( "issue_row"."state" = 'verification' AND now() >=
6284 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
6285 ( "issue_row"."state" = 'voting' AND now() >=
6286 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
6287 THEN
6288 "persist"."phase_finished" := TRUE;
6289 ELSE
6290 "persist"."phase_finished" := FALSE;
6291 END IF;
6292 IF
6293 NOT EXISTS (
6294 -- all initiatives are revoked
6295 SELECT NULL FROM "initiative"
6296 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6297 ) AND (
6298 -- and issue has not been accepted yet
6299 "persist"."state" = 'admission' OR
6300 -- or verification time has elapsed
6301 ( "persist"."state" = 'verification' AND
6302 "persist"."phase_finished" ) OR
6303 -- or no initiatives have been revoked lately
6304 NOT EXISTS (
6305 SELECT NULL FROM "initiative"
6306 WHERE "issue_id" = "issue_id_p"
6307 AND now() < "revoked" + "issue_row"."verification_time"
6310 THEN
6311 "persist"."issue_revoked" := TRUE;
6312 ELSE
6313 "persist"."issue_revoked" := FALSE;
6314 END IF;
6315 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
6316 UPDATE "issue" SET "phase_finished" = now()
6317 WHERE "id" = "issue_row"."id";
6318 RETURN "persist";
6319 ELSIF
6320 "persist"."state" IN ('admission', 'discussion', 'verification')
6321 THEN
6322 RETURN "persist";
6323 ELSE
6324 RETURN NULL;
6325 END IF;
6326 END IF;
6327 IF
6328 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6329 coalesce("persist"."snapshot_created", FALSE) = FALSE
6330 THEN
6331 IF "persist"."state" != 'admission' THEN
6332 PERFORM "take_snapshot"("issue_id_p");
6333 PERFORM "finish_snapshot"("issue_id_p");
6334 ELSE
6335 UPDATE "issue" SET "issue_quorum" = "issue_quorum"."issue_quorum"
6336 FROM "issue_quorum"
6337 WHERE "id" = "issue_id_p"
6338 AND "issue_quorum"."issue_id" = "issue_id_p";
6339 END IF;
6340 "persist"."snapshot_created" = TRUE;
6341 IF "persist"."phase_finished" THEN
6342 IF "persist"."state" = 'admission' THEN
6343 UPDATE "issue" SET "admission_snapshot_id" = "latest_snapshot_id"
6344 WHERE "id" = "issue_id_p";
6345 ELSIF "persist"."state" = 'discussion' THEN
6346 UPDATE "issue" SET "half_freeze_snapshot_id" = "latest_snapshot_id"
6347 WHERE "id" = "issue_id_p";
6348 ELSIF "persist"."state" = 'verification' THEN
6349 UPDATE "issue" SET "full_freeze_snapshot_id" = "latest_snapshot_id"
6350 WHERE "id" = "issue_id_p";
6351 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
6352 FOR "initiative_row" IN
6353 SELECT * FROM "initiative"
6354 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6355 FOR UPDATE
6356 LOOP
6357 IF
6358 "initiative_row"."polling" OR
6359 "initiative_row"."satisfied_supporter_count" >=
6360 "issue_row"."initiative_quorum"
6361 THEN
6362 UPDATE "initiative" SET "admitted" = TRUE
6363 WHERE "id" = "initiative_row"."id";
6364 ELSE
6365 UPDATE "initiative" SET "admitted" = FALSE
6366 WHERE "id" = "initiative_row"."id";
6367 END IF;
6368 END LOOP;
6369 END IF;
6370 END IF;
6371 RETURN "persist";
6372 END IF;
6373 IF
6374 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6375 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
6376 THEN
6377 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
6378 "persist"."harmonic_weights_set" = TRUE;
6379 IF
6380 "persist"."phase_finished" OR
6381 "persist"."issue_revoked" OR
6382 "persist"."state" = 'admission'
6383 THEN
6384 RETURN "persist";
6385 ELSE
6386 RETURN NULL;
6387 END IF;
6388 END IF;
6389 IF "persist"."issue_revoked" THEN
6390 IF "persist"."state" = 'admission' THEN
6391 "state_v" := 'canceled_revoked_before_accepted';
6392 ELSIF "persist"."state" = 'discussion' THEN
6393 "state_v" := 'canceled_after_revocation_during_discussion';
6394 ELSIF "persist"."state" = 'verification' THEN
6395 "state_v" := 'canceled_after_revocation_during_verification';
6396 END IF;
6397 UPDATE "issue" SET
6398 "state" = "state_v",
6399 "closed" = "phase_finished",
6400 "phase_finished" = NULL
6401 WHERE "id" = "issue_id_p";
6402 RETURN NULL;
6403 END IF;
6404 IF "persist"."state" = 'admission' THEN
6405 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6406 FOR UPDATE;
6407 IF "issue_row"."phase_finished" NOTNULL THEN
6408 UPDATE "issue" SET
6409 "state" = 'canceled_issue_not_accepted',
6410 "closed" = "phase_finished",
6411 "phase_finished" = NULL
6412 WHERE "id" = "issue_id_p";
6413 END IF;
6414 RETURN NULL;
6415 END IF;
6416 IF "persist"."phase_finished" THEN
6417 IF "persist"."state" = 'discussion' THEN
6418 UPDATE "issue" SET
6419 "state" = 'verification',
6420 "half_frozen" = "phase_finished",
6421 "phase_finished" = NULL
6422 WHERE "id" = "issue_id_p";
6423 RETURN NULL;
6424 END IF;
6425 IF "persist"."state" = 'verification' THEN
6426 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6427 FOR UPDATE;
6428 SELECT * INTO "policy_row" FROM "policy"
6429 WHERE "id" = "issue_row"."policy_id";
6430 IF EXISTS (
6431 SELECT NULL FROM "initiative"
6432 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
6433 ) THEN
6434 UPDATE "issue" SET
6435 "state" = 'voting',
6436 "fully_frozen" = "phase_finished",
6437 "phase_finished" = NULL
6438 WHERE "id" = "issue_id_p";
6439 ELSE
6440 UPDATE "issue" SET
6441 "state" = 'canceled_no_initiative_admitted',
6442 "fully_frozen" = "phase_finished",
6443 "closed" = "phase_finished",
6444 "phase_finished" = NULL
6445 WHERE "id" = "issue_id_p";
6446 -- NOTE: The following DELETE statements have effect only when
6447 -- issue state has been manipulated
6448 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
6449 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
6450 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
6451 END IF;
6452 RETURN NULL;
6453 END IF;
6454 IF "persist"."state" = 'voting' THEN
6455 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
6456 PERFORM "close_voting"("issue_id_p");
6457 "persist"."closed_voting" = TRUE;
6458 RETURN "persist";
6459 END IF;
6460 PERFORM "calculate_ranks"("issue_id_p");
6461 RETURN NULL;
6462 END IF;
6463 END IF;
6464 RAISE WARNING 'should not happen';
6465 RETURN NULL;
6466 END;
6467 $$;
6469 COMMENT ON FUNCTION "check_issue"
6470 ( "issue"."id"%TYPE,
6471 "check_issue_persistence" )
6472 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")';
6475 CREATE FUNCTION "check_everything"()
6476 RETURNS VOID
6477 LANGUAGE 'plpgsql' VOLATILE AS $$
6478 DECLARE
6479 "area_id_v" "area"."id"%TYPE;
6480 "snapshot_id_v" "snapshot"."id"%TYPE;
6481 "issue_id_v" "issue"."id"%TYPE;
6482 "persist_v" "check_issue_persistence";
6483 BEGIN
6484 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
6485 DELETE FROM "expired_session";
6486 DELETE FROM "expired_token";
6487 DELETE FROM "unused_snapshot";
6488 PERFORM "check_activity"();
6489 PERFORM "calculate_member_counts"();
6490 FOR "area_id_v" IN SELECT "id" FROM "area_with_unaccepted_issues" LOOP
6491 SELECT "take_snapshot"(NULL, "area_id_v") INTO "snapshot_id_v";
6492 PERFORM "finish_snapshot"("issue_id") FROM "snapshot_issue"
6493 WHERE "snapshot_id" = "snapshot_id_v";
6494 LOOP
6495 EXIT WHEN "issue_admission"("area_id_v") = FALSE;
6496 END LOOP;
6497 END LOOP;
6498 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
6499 "persist_v" := NULL;
6500 LOOP
6501 "persist_v" := "check_issue"("issue_id_v", "persist_v");
6502 EXIT WHEN "persist_v" ISNULL;
6503 END LOOP;
6504 END LOOP;
6505 DELETE FROM "unused_snapshot";
6506 RETURN;
6507 END;
6508 $$;
6510 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';
6514 ----------------------
6515 -- Deletion of data --
6516 ----------------------
6519 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
6520 RETURNS VOID
6521 LANGUAGE 'plpgsql' VOLATILE AS $$
6522 BEGIN
6523 IF EXISTS (
6524 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
6525 ) THEN
6526 -- override protection triggers:
6527 INSERT INTO "temporary_transaction_data" ("key", "value")
6528 VALUES ('override_protection_triggers', TRUE::TEXT);
6529 -- clean data:
6530 DELETE FROM "delegating_voter"
6531 WHERE "issue_id" = "issue_id_p";
6532 DELETE FROM "direct_voter"
6533 WHERE "issue_id" = "issue_id_p";
6534 DELETE FROM "delegating_interest_snapshot"
6535 WHERE "issue_id" = "issue_id_p";
6536 DELETE FROM "direct_interest_snapshot"
6537 WHERE "issue_id" = "issue_id_p";
6538 DELETE FROM "non_voter"
6539 WHERE "issue_id" = "issue_id_p";
6540 DELETE FROM "delegation"
6541 WHERE "issue_id" = "issue_id_p";
6542 DELETE FROM "supporter"
6543 USING "initiative" -- NOTE: due to missing index on issue_id
6544 WHERE "initiative"."issue_id" = "issue_id_p"
6545 AND "supporter"."initiative_id" = "initiative_id";
6546 -- mark issue as cleaned:
6547 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
6548 -- finish overriding protection triggers (avoids garbage):
6549 DELETE FROM "temporary_transaction_data"
6550 WHERE "key" = 'override_protection_triggers';
6551 END IF;
6552 RETURN;
6553 END;
6554 $$;
6556 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
6559 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
6560 RETURNS VOID
6561 LANGUAGE 'plpgsql' VOLATILE AS $$
6562 BEGIN
6563 UPDATE "member" SET
6564 "last_login" = NULL,
6565 "last_delegation_check" = NULL,
6566 "login" = NULL,
6567 "password" = NULL,
6568 "authority" = NULL,
6569 "authority_uid" = NULL,
6570 "authority_login" = NULL,
6571 "deleted" = coalesce("deleted", now()),
6572 "locked" = TRUE,
6573 "active" = FALSE,
6574 "notify_email" = NULL,
6575 "notify_email_unconfirmed" = NULL,
6576 "notify_email_secret" = NULL,
6577 "notify_email_secret_expiry" = NULL,
6578 "notify_email_lock_expiry" = NULL,
6579 "disable_notifications" = TRUE,
6580 "notification_counter" = DEFAULT,
6581 "notification_sample_size" = 0,
6582 "notification_dow" = NULL,
6583 "notification_hour" = NULL,
6584 "notification_sent" = NULL,
6585 "login_recovery_expiry" = NULL,
6586 "password_reset_secret" = NULL,
6587 "password_reset_secret_expiry" = NULL,
6588 "location" = NULL
6589 WHERE "id" = "member_id_p";
6590 -- "text_search_data" is updated by triggers
6591 DELETE FROM "member_settings" WHERE "member_id" = "member_id_p";
6592 DELETE FROM "member_profile" WHERE "member_id" = "member_id_p";
6593 DELETE FROM "rendered_member_statement" WHERE "member_id" = "member_id_p";
6594 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
6595 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
6596 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
6597 DELETE FROM "session" WHERE "member_id" = "member_id_p";
6598 DELETE FROM "member_application" WHERE "member_id" = "member_id_p";
6599 DELETE FROM "token" WHERE "member_id" = "member_id_p";
6600 DELETE FROM "subscription" WHERE "member_id" = "member_id_p";
6601 DELETE FROM "ignored_area" WHERE "member_id" = "member_id_p";
6602 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
6603 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
6604 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
6605 DELETE FROM "direct_voter" USING "issue"
6606 WHERE "direct_voter"."issue_id" = "issue"."id"
6607 AND "issue"."closed" ISNULL
6608 AND "member_id" = "member_id_p";
6609 DELETE FROM "notification_initiative_sent" WHERE "member_id" = "member_id_p";
6610 RETURN;
6611 END;
6612 $$;
6614 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)';
6617 CREATE FUNCTION "delete_private_data"()
6618 RETURNS VOID
6619 LANGUAGE 'plpgsql' VOLATILE AS $$
6620 BEGIN
6621 DELETE FROM "temporary_transaction_data";
6622 DELETE FROM "temporary_suggestion_counts";
6623 DELETE FROM "member" WHERE "activated" ISNULL;
6624 UPDATE "member" SET
6625 "invite_code" = NULL,
6626 "invite_code_expiry" = NULL,
6627 "admin_comment" = NULL,
6628 "last_login" = NULL,
6629 "last_delegation_check" = NULL,
6630 "login" = NULL,
6631 "password" = NULL,
6632 "authority" = NULL,
6633 "authority_uid" = NULL,
6634 "authority_login" = NULL,
6635 "lang" = NULL,
6636 "notify_email" = NULL,
6637 "notify_email_unconfirmed" = NULL,
6638 "notify_email_secret" = NULL,
6639 "notify_email_secret_expiry" = NULL,
6640 "notify_email_lock_expiry" = NULL,
6641 "disable_notifications" = TRUE,
6642 "notification_counter" = DEFAULT,
6643 "notification_sample_size" = 0,
6644 "notification_dow" = NULL,
6645 "notification_hour" = NULL,
6646 "notification_sent" = NULL,
6647 "login_recovery_expiry" = NULL,
6648 "password_reset_secret" = NULL,
6649 "password_reset_secret_expiry" = NULL,
6650 "location" = NULL;
6651 -- "text_search_data" is updated by triggers
6652 DELETE FROM "verification";
6653 DELETE FROM "member_settings";
6654 DELETE FROM "member_useterms";
6655 DELETE FROM "member_profile";
6656 DELETE FROM "rendered_member_statement";
6657 DELETE FROM "member_image";
6658 DELETE FROM "contact";
6659 DELETE FROM "ignored_member";
6660 DELETE FROM "session";
6661 DELETE FROM "system_application";
6662 DELETE FROM "system_application_redirect_uri";
6663 DELETE FROM "dynamic_application_scope";
6664 DELETE FROM "member_application";
6665 DELETE FROM "token";
6666 DELETE FROM "subscription";
6667 DELETE FROM "ignored_area";
6668 DELETE FROM "ignored_initiative";
6669 DELETE FROM "non_voter";
6670 DELETE FROM "direct_voter" USING "issue"
6671 WHERE "direct_voter"."issue_id" = "issue"."id"
6672 AND "issue"."closed" ISNULL;
6673 DELETE FROM "event_processed";
6674 DELETE FROM "notification_initiative_sent";
6675 DELETE FROM "newsletter";
6676 RETURN;
6677 END;
6678 $$;
6680 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.';
6684 COMMIT;

Impressum / About Us