liquid_feedback_core

view core.sql @ 578:02a6149822e0

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

Impressum / About Us