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