rev |
line source |
jbe@0
|
1
|
jbe@92
|
2 -- Execute the following command manually for PostgreSQL prior version 9.0:
|
jbe@92
|
3 -- CREATE LANGUAGE plpgsql;
|
jbe@0
|
4
|
jbe@0
|
5 -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index
|
jbe@0
|
6
|
jbe@0
|
7 BEGIN;
|
jbe@0
|
8
|
jbe@5
|
9 CREATE VIEW "liquid_feedback_version" AS
|
jbe@134
|
10 SELECT * FROM (VALUES ('1.4.0_rc1', 1, 4, -1))
|
jbe@5
|
11 AS "subquery"("string", "major", "minor", "revision");
|
jbe@5
|
12
|
jbe@0
|
13
|
jbe@0
|
14
|
jbe@7
|
15 ----------------------
|
jbe@7
|
16 -- Full text search --
|
jbe@7
|
17 ----------------------
|
jbe@7
|
18
|
jbe@7
|
19
|
jbe@7
|
20 CREATE FUNCTION "text_search_query"("query_text_p" TEXT)
|
jbe@7
|
21 RETURNS TSQUERY
|
jbe@7
|
22 LANGUAGE 'plpgsql' IMMUTABLE AS $$
|
jbe@7
|
23 BEGIN
|
jbe@7
|
24 RETURN plainto_tsquery('pg_catalog.simple', "query_text_p");
|
jbe@7
|
25 END;
|
jbe@7
|
26 $$;
|
jbe@7
|
27
|
jbe@7
|
28 COMMENT ON FUNCTION "text_search_query"(TEXT) IS 'Usage: WHERE "text_search_data" @@ "text_search_query"(''<user query>'')';
|
jbe@7
|
29
|
jbe@7
|
30
|
jbe@7
|
31 CREATE FUNCTION "highlight"
|
jbe@7
|
32 ( "body_p" TEXT,
|
jbe@7
|
33 "query_text_p" TEXT )
|
jbe@7
|
34 RETURNS TEXT
|
jbe@7
|
35 LANGUAGE 'plpgsql' IMMUTABLE AS $$
|
jbe@7
|
36 BEGIN
|
jbe@7
|
37 RETURN ts_headline(
|
jbe@7
|
38 'pg_catalog.simple',
|
jbe@8
|
39 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
|
jbe@7
|
40 "text_search_query"("query_text_p"),
|
jbe@7
|
41 'StartSel=* StopSel=* HighlightAll=TRUE' );
|
jbe@7
|
42 END;
|
jbe@7
|
43 $$;
|
jbe@7
|
44
|
jbe@7
|
45 COMMENT ON FUNCTION "highlight"
|
jbe@7
|
46 ( "body_p" TEXT,
|
jbe@7
|
47 "query_text_p" TEXT )
|
jbe@7
|
48 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.';
|
jbe@7
|
49
|
jbe@7
|
50
|
jbe@7
|
51
|
jbe@0
|
52 -------------------------
|
jbe@0
|
53 -- Tables and indicies --
|
jbe@0
|
54 -------------------------
|
jbe@0
|
55
|
jbe@8
|
56
|
jbe@104
|
57 CREATE TABLE "system_setting" (
|
jbe@104
|
58 "member_ttl" INTERVAL );
|
jbe@104
|
59 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1));
|
jbe@104
|
60
|
jbe@104
|
61 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.';
|
jbe@104
|
62 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.';
|
jbe@104
|
63
|
jbe@104
|
64 COMMENT ON COLUMN "system_setting"."member_ttl" IS 'Time after members get their "active" flag set to FALSE, if they do not login anymore.';
|
jbe@104
|
65
|
jbe@104
|
66
|
jbe@111
|
67 CREATE TABLE "contingent" (
|
jbe@111
|
68 "time_frame" INTERVAL PRIMARY KEY,
|
jbe@111
|
69 "text_entry_limit" INT4,
|
jbe@111
|
70 "initiative_limit" INT4 );
|
jbe@111
|
71
|
jbe@111
|
72 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.';
|
jbe@111
|
73
|
jbe@111
|
74 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';
|
jbe@111
|
75 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame';
|
jbe@111
|
76
|
jbe@111
|
77
|
jbe@113
|
78 CREATE TYPE "notify_level" AS ENUM
|
jbe@113
|
79 ('none', 'voting', 'verification', 'discussion', 'all');
|
jbe@113
|
80
|
jbe@113
|
81 COMMENT ON TYPE "notify_level" IS 'Level of notification: ''none'' = no notifications, ''voting'' = notifications about finished issues and issues in voting, ''verification'' = notifications about finished issues, issues in voting and verification phase, ''discussion'' = notifications about everything except issues in admission phase, ''all'' = notifications about everything';
|
jbe@113
|
82
|
jbe@113
|
83
|
jbe@0
|
84 CREATE TABLE "member" (
|
jbe@0
|
85 "id" SERIAL4 PRIMARY KEY,
|
jbe@13
|
86 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
|
jbe@42
|
87 "last_login" TIMESTAMPTZ,
|
jbe@103
|
88 "last_login_public" DATE,
|
jbe@45
|
89 "login" TEXT UNIQUE,
|
jbe@0
|
90 "password" TEXT,
|
jbe@99
|
91 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@0
|
92 "active" BOOLEAN NOT NULL DEFAULT TRUE,
|
jbe@0
|
93 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@7
|
94 "notify_email" TEXT,
|
jbe@11
|
95 "notify_email_unconfirmed" TEXT,
|
jbe@11
|
96 "notify_email_secret" TEXT UNIQUE,
|
jbe@11
|
97 "notify_email_secret_expiry" TIMESTAMPTZ,
|
jbe@55
|
98 "notify_email_lock_expiry" TIMESTAMPTZ,
|
jbe@113
|
99 "notify_level" "notify_level" NOT NULL DEFAULT 'none',
|
jbe@113
|
100 "notify_event_id" INT8,
|
jbe@11
|
101 "password_reset_secret" TEXT UNIQUE,
|
jbe@11
|
102 "password_reset_secret_expiry" TIMESTAMPTZ,
|
jbe@7
|
103 "name" TEXT NOT NULL UNIQUE,
|
jbe@7
|
104 "identification" TEXT UNIQUE,
|
jbe@7
|
105 "organizational_unit" TEXT,
|
jbe@7
|
106 "internal_posts" TEXT,
|
jbe@7
|
107 "realname" TEXT,
|
jbe@7
|
108 "birthday" DATE,
|
jbe@7
|
109 "address" TEXT,
|
jbe@7
|
110 "email" TEXT,
|
jbe@7
|
111 "xmpp_address" TEXT,
|
jbe@7
|
112 "website" TEXT,
|
jbe@7
|
113 "phone" TEXT,
|
jbe@7
|
114 "mobile_phone" TEXT,
|
jbe@7
|
115 "profession" TEXT,
|
jbe@7
|
116 "external_memberships" TEXT,
|
jbe@7
|
117 "external_posts" TEXT,
|
jbe@7
|
118 "statement" TEXT,
|
jbe@10
|
119 "text_search_data" TSVECTOR );
|
jbe@0
|
120 CREATE INDEX "member_active_idx" ON "member" ("active");
|
jbe@8
|
121 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
|
jbe@7
|
122 CREATE TRIGGER "update_text_search_data"
|
jbe@7
|
123 BEFORE INSERT OR UPDATE ON "member"
|
jbe@7
|
124 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@7
|
125 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
|
jbe@7
|
126 "name", "identification", "organizational_unit", "internal_posts",
|
jbe@7
|
127 "realname", "external_memberships", "external_posts", "statement" );
|
jbe@0
|
128
|
jbe@0
|
129 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
|
jbe@0
|
130
|
jbe@103
|
131 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
|
jbe@103
|
132 COMMENT ON COLUMN "member"."last_login_public" IS 'Date of last login (time stripped for privacy reasons, updated only after day change)';
|
jbe@10
|
133 COMMENT ON COLUMN "member"."login" IS 'Login name';
|
jbe@10
|
134 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
|
jbe@99
|
135 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
|
jbe@99
|
136 COMMENT ON COLUMN "member"."active" IS 'Memberships, support and votes are taken into account when corresponding members are marked as active. When the user does not log in for an extended period of time, this flag may be set to FALSE. If the user is not locked, he/she may reset the active flag by logging in.';
|
jbe@10
|
137 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
|
jbe@10
|
138 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
|
jbe@10
|
139 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
|
jbe@10
|
140 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
|
jbe@10
|
141 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
|
jbe@55
|
142 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
|
jbe@113
|
143 COMMENT ON COLUMN "member"."notify_level" IS 'Selects which event notifications are to be sent to the "notify_email" mail address';
|
jbe@113
|
144 COMMENT ON COLUMN "member"."notify_event_id" IS 'Latest "id" of an "event" the member was notified about';
|
jbe@10
|
145 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member';
|
jbe@10
|
146 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
|
jbe@10
|
147 COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to';
|
jbe@10
|
148 COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization';
|
jbe@10
|
149 COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"';
|
jbe@10
|
150 COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications';
|
jbe@10
|
151 COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in';
|
jbe@10
|
152 COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization';
|
jbe@10
|
153 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his homepage within the system';
|
jbe@7
|
154
|
jbe@7
|
155
|
jbe@13
|
156 CREATE TABLE "member_history" (
|
jbe@13
|
157 "id" SERIAL8 PRIMARY KEY,
|
jbe@13
|
158 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@13
|
159 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
|
jbe@42
|
160 "active" BOOLEAN NOT NULL,
|
jbe@13
|
161 "name" TEXT NOT NULL );
|
jbe@45
|
162 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
|
jbe@13
|
163
|
jbe@57
|
164 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
|
jbe@13
|
165
|
jbe@13
|
166 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
|
jbe@57
|
167 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
|
jbe@13
|
168
|
jbe@13
|
169
|
jbe@9
|
170 CREATE TABLE "invite_code" (
|
jbe@97
|
171 "id" SERIAL8 PRIMARY KEY,
|
jbe@97
|
172 "code" TEXT NOT NULL UNIQUE,
|
jbe@9
|
173 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
|
jbe@9
|
174 "used" TIMESTAMPTZ,
|
jbe@9
|
175 "member_id" INT4 UNIQUE REFERENCES "member" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
|
jbe@9
|
176 "comment" TEXT,
|
jbe@9
|
177 CONSTRAINT "only_used_codes_may_refer_to_member" CHECK ("used" NOTNULL OR "member_id" ISNULL) );
|
jbe@9
|
178
|
jbe@9
|
179 COMMENT ON TABLE "invite_code" IS 'Invite codes can be used once to create a new member account.';
|
jbe@9
|
180
|
jbe@9
|
181 COMMENT ON COLUMN "invite_code"."code" IS 'Secret code';
|
jbe@9
|
182 COMMENT ON COLUMN "invite_code"."created" IS 'Time of creation of the secret code';
|
jbe@9
|
183 COMMENT ON COLUMN "invite_code"."used" IS 'NULL, if not used yet, otherwise tells when this code was used to create a member account';
|
jbe@9
|
184 COMMENT ON COLUMN "invite_code"."member_id" IS 'References the member whose account was created with this code';
|
jbe@9
|
185 COMMENT ON COLUMN "invite_code"."comment" IS 'Comment on the code, which is to be used for administrative reasons only';
|
jbe@9
|
186
|
jbe@9
|
187
|
jbe@9
|
188 CREATE TABLE "setting" (
|
jbe@9
|
189 PRIMARY KEY ("member_id", "key"),
|
jbe@9
|
190 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@9
|
191 "key" TEXT NOT NULL,
|
jbe@9
|
192 "value" TEXT NOT NULL );
|
jbe@9
|
193 CREATE INDEX "setting_key_idx" ON "setting" ("key");
|
jbe@9
|
194
|
jbe@38
|
195 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
|
jbe@9
|
196
|
jbe@9
|
197 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
|
jbe@9
|
198
|
jbe@9
|
199
|
jbe@16
|
200 CREATE TABLE "setting_map" (
|
jbe@16
|
201 PRIMARY KEY ("member_id", "key", "subkey"),
|
jbe@16
|
202 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@16
|
203 "key" TEXT NOT NULL,
|
jbe@16
|
204 "subkey" TEXT NOT NULL,
|
jbe@16
|
205 "value" TEXT NOT NULL );
|
jbe@16
|
206 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
|
jbe@16
|
207
|
jbe@23
|
208 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
|
jbe@16
|
209
|
jbe@16
|
210 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
|
jbe@16
|
211 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
|
jbe@16
|
212 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
|
jbe@16
|
213
|
jbe@16
|
214
|
jbe@23
|
215 CREATE TABLE "member_relation_setting" (
|
jbe@23
|
216 PRIMARY KEY ("member_id", "key", "other_member_id"),
|
jbe@23
|
217 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
218 "key" TEXT NOT NULL,
|
jbe@23
|
219 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
220 "value" TEXT NOT NULL );
|
jbe@23
|
221
|
jbe@38
|
222 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
|
jbe@23
|
223
|
jbe@23
|
224
|
jbe@7
|
225 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
|
jbe@7
|
226
|
jbe@7
|
227 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
|
jbe@7
|
228
|
jbe@7
|
229
|
jbe@7
|
230 CREATE TABLE "member_image" (
|
jbe@7
|
231 PRIMARY KEY ("member_id", "image_type", "scaled"),
|
jbe@7
|
232 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@7
|
233 "image_type" "member_image_type",
|
jbe@7
|
234 "scaled" BOOLEAN,
|
jbe@7
|
235 "content_type" TEXT,
|
jbe@7
|
236 "data" BYTEA NOT NULL );
|
jbe@7
|
237
|
jbe@7
|
238 COMMENT ON TABLE "member_image" IS 'Images of members';
|
jbe@7
|
239
|
jbe@7
|
240 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
|
jbe@0
|
241
|
jbe@0
|
242
|
jbe@4
|
243 CREATE TABLE "member_count" (
|
jbe@5
|
244 "calculated" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
jbe@5
|
245 "total_count" INT4 NOT NULL );
|
jbe@4
|
246
|
jbe@5
|
247 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';
|
jbe@4
|
248
|
jbe@5
|
249 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
|
jbe@5
|
250 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
|
jbe@4
|
251
|
jbe@4
|
252
|
jbe@0
|
253 CREATE TABLE "contact" (
|
jbe@0
|
254 PRIMARY KEY ("member_id", "other_member_id"),
|
jbe@0
|
255 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
256 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@11
|
257 "public" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@11
|
258 CONSTRAINT "cant_save_yourself_as_contact"
|
jbe@11
|
259 CHECK ("member_id" != "other_member_id") );
|
jbe@113
|
260 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
|
jbe@0
|
261
|
jbe@0
|
262 COMMENT ON TABLE "contact" IS 'Contact lists';
|
jbe@0
|
263
|
jbe@0
|
264 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
|
jbe@0
|
265 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
|
jbe@0
|
266 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
|
jbe@0
|
267
|
jbe@0
|
268
|
jbe@113
|
269 CREATE TABLE "ignored_member" (
|
jbe@113
|
270 PRIMARY KEY ("member_id", "other_member_id"),
|
jbe@113
|
271 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@113
|
272 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
|
jbe@113
|
273 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
|
jbe@113
|
274
|
jbe@113
|
275 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
|
jbe@113
|
276
|
jbe@113
|
277 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
|
jbe@113
|
278 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
|
jbe@113
|
279
|
jbe@113
|
280
|
jbe@0
|
281 CREATE TABLE "session" (
|
jbe@0
|
282 "ident" TEXT PRIMARY KEY,
|
jbe@0
|
283 "additional_secret" TEXT,
|
jbe@0
|
284 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
|
jbe@0
|
285 "member_id" INT8 REFERENCES "member" ("id") ON DELETE SET NULL,
|
jbe@0
|
286 "lang" TEXT );
|
jbe@0
|
287 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
|
jbe@0
|
288
|
jbe@0
|
289 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend';
|
jbe@0
|
290
|
jbe@0
|
291 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
|
jbe@0
|
292 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
|
jbe@0
|
293 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
|
jbe@0
|
294 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
|
jbe@0
|
295
|
jbe@0
|
296
|
jbe@0
|
297 CREATE TABLE "policy" (
|
jbe@0
|
298 "id" SERIAL4 PRIMARY KEY,
|
jbe@9
|
299 "index" INT4 NOT NULL,
|
jbe@0
|
300 "active" BOOLEAN NOT NULL DEFAULT TRUE,
|
jbe@0
|
301 "name" TEXT NOT NULL UNIQUE,
|
jbe@0
|
302 "description" TEXT NOT NULL DEFAULT '',
|
jbe@0
|
303 "admission_time" INTERVAL NOT NULL,
|
jbe@0
|
304 "discussion_time" INTERVAL NOT NULL,
|
jbe@3
|
305 "verification_time" INTERVAL NOT NULL,
|
jbe@0
|
306 "voting_time" INTERVAL NOT NULL,
|
jbe@0
|
307 "issue_quorum_num" INT4 NOT NULL,
|
jbe@0
|
308 "issue_quorum_den" INT4 NOT NULL,
|
jbe@0
|
309 "initiative_quorum_num" INT4 NOT NULL,
|
jbe@10
|
310 "initiative_quorum_den" INT4 NOT NULL,
|
jbe@10
|
311 "majority_num" INT4 NOT NULL DEFAULT 1,
|
jbe@10
|
312 "majority_den" INT4 NOT NULL DEFAULT 2,
|
jbe@139
|
313 "majority_strict" BOOLEAN NOT NULL DEFAULT TRUE );
|
jbe@0
|
314 CREATE INDEX "policy_active_idx" ON "policy" ("active");
|
jbe@0
|
315
|
jbe@0
|
316 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
|
jbe@0
|
317
|
jbe@9
|
318 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
|
jbe@0
|
319 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
|
jbe@0
|
320 COMMENT ON COLUMN "policy"."admission_time" IS 'Maximum time an issue stays open without being "accepted"';
|
jbe@3
|
321 COMMENT ON COLUMN "policy"."discussion_time" IS 'Regular time until an issue is "half_frozen" after being "accepted"';
|
jbe@3
|
322 COMMENT ON COLUMN "policy"."verification_time" IS 'Regular time until an issue is "fully_frozen" after being "half_frozen"';
|
jbe@3
|
323 COMMENT ON COLUMN "policy"."voting_time" IS 'Time after an issue is "fully_frozen" but not "closed"';
|
jbe@10
|
324 COMMENT ON COLUMN "policy"."issue_quorum_num" IS 'Numerator of potential supporter quorum to be reached by one initiative of an issue to be "accepted"';
|
jbe@10
|
325 COMMENT ON COLUMN "policy"."issue_quorum_den" IS 'Denominator of potential supporter quorum to be reached by one initiative of an issue to be "accepted"';
|
jbe@10
|
326 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
|
jbe@10
|
327 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
|
jbe@10
|
328 COMMENT ON COLUMN "policy"."majority_num" IS 'Numerator of fraction of majority to be reached during voting by an initiative to be aggreed upon';
|
jbe@10
|
329 COMMENT ON COLUMN "policy"."majority_den" IS 'Denominator of fraction of majority to be reached during voting by an initiative to be aggreed upon';
|
jbe@10
|
330 COMMENT ON COLUMN "policy"."majority_strict" IS 'If TRUE, then the majority must be strictly greater than "majority_num"/"majority_den", otherwise it may also be equal.';
|
jbe@0
|
331
|
jbe@0
|
332
|
jbe@97
|
333 CREATE TABLE "unit" (
|
jbe@97
|
334 "id" SERIAL4 PRIMARY KEY,
|
jbe@97
|
335 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@97
|
336 "active" BOOLEAN NOT NULL DEFAULT TRUE,
|
jbe@97
|
337 "name" TEXT NOT NULL,
|
jbe@97
|
338 "description" TEXT NOT NULL DEFAULT '',
|
jbe@97
|
339 "member_count" INT4,
|
jbe@97
|
340 "text_search_data" TSVECTOR );
|
jbe@97
|
341 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
|
jbe@97
|
342 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
|
jbe@97
|
343 CREATE INDEX "unit_active_idx" ON "unit" ("active");
|
jbe@97
|
344 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
|
jbe@97
|
345 CREATE TRIGGER "update_text_search_data"
|
jbe@97
|
346 BEFORE INSERT OR UPDATE ON "unit"
|
jbe@97
|
347 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@97
|
348 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
|
jbe@97
|
349 "name", "description" );
|
jbe@97
|
350
|
jbe@97
|
351 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
|
jbe@97
|
352
|
jbe@97
|
353 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
|
jbe@97
|
354 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in units of this area';
|
jbe@97
|
355 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
|
jbe@97
|
356
|
jbe@97
|
357
|
jbe@0
|
358 CREATE TABLE "area" (
|
jbe@0
|
359 "id" SERIAL4 PRIMARY KEY,
|
jbe@97
|
360 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
361 "active" BOOLEAN NOT NULL DEFAULT TRUE,
|
jbe@0
|
362 "name" TEXT NOT NULL,
|
jbe@4
|
363 "description" TEXT NOT NULL DEFAULT '',
|
jbe@5
|
364 "direct_member_count" INT4,
|
jbe@5
|
365 "member_weight" INT4,
|
jbe@7
|
366 "autoreject_weight" INT4,
|
jbe@7
|
367 "text_search_data" TSVECTOR );
|
jbe@97
|
368 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
|
jbe@0
|
369 CREATE INDEX "area_active_idx" ON "area" ("active");
|
jbe@8
|
370 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
|
jbe@7
|
371 CREATE TRIGGER "update_text_search_data"
|
jbe@7
|
372 BEFORE INSERT OR UPDATE ON "area"
|
jbe@7
|
373 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@7
|
374 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
|
jbe@7
|
375 "name", "description" );
|
jbe@0
|
376
|
jbe@0
|
377 COMMENT ON TABLE "area" IS 'Subject areas';
|
jbe@0
|
378
|
jbe@5
|
379 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
|
jbe@5
|
380 COMMENT ON COLUMN "area"."direct_member_count" IS 'Number of active members of that area (ignoring their weight), as calculated from view "area_member_count"';
|
jbe@5
|
381 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
|
jbe@5
|
382 COMMENT ON COLUMN "area"."autoreject_weight" IS 'Sum of weight of members using the autoreject feature';
|
jbe@0
|
383
|
jbe@0
|
384
|
jbe@23
|
385 CREATE TABLE "area_setting" (
|
jbe@23
|
386 PRIMARY KEY ("member_id", "key", "area_id"),
|
jbe@23
|
387 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
388 "key" TEXT NOT NULL,
|
jbe@23
|
389 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
390 "value" TEXT NOT NULL );
|
jbe@23
|
391
|
jbe@23
|
392 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
|
jbe@23
|
393
|
jbe@23
|
394
|
jbe@9
|
395 CREATE TABLE "allowed_policy" (
|
jbe@9
|
396 PRIMARY KEY ("area_id", "policy_id"),
|
jbe@9
|
397 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@9
|
398 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@9
|
399 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
|
jbe@9
|
400 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
|
jbe@9
|
401
|
jbe@9
|
402 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
|
jbe@9
|
403
|
jbe@9
|
404 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
|
jbe@9
|
405
|
jbe@9
|
406
|
jbe@21
|
407 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
|
jbe@21
|
408
|
jbe@21
|
409 COMMENT ON TYPE "snapshot_event" IS 'Reason for snapshots: ''periodic'' = due to periodic recalculation, ''end_of_admission'' = saved state at end of admission period, ''half_freeze'' = saved state at end of discussion period, ''full_freeze'' = saved state at end of verification period';
|
jbe@8
|
410
|
jbe@8
|
411
|
jbe@112
|
412 CREATE TYPE "issue_state" AS ENUM (
|
jbe@112
|
413 'admission', 'discussion', 'verification', 'voting',
|
jbe@113
|
414 'canceled_revoked_before_accepted',
|
jbe@113
|
415 'canceled_issue_not_accepted',
|
jbe@113
|
416 'canceled_after_revocation_during_discussion',
|
jbe@113
|
417 'canceled_after_revocation_during_verification',
|
jbe@113
|
418 'calculation',
|
jbe@113
|
419 'canceled_no_initiative_admitted',
|
jbe@112
|
420 'finished_without_winner', 'finished_with_winner');
|
jbe@111
|
421
|
jbe@111
|
422 COMMENT ON TYPE "issue_state" IS 'State of issues';
|
jbe@111
|
423
|
jbe@111
|
424
|
jbe@0
|
425 CREATE TABLE "issue" (
|
jbe@0
|
426 "id" SERIAL4 PRIMARY KEY,
|
jbe@0
|
427 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
428 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
|
jbe@111
|
429 "state" "issue_state" NOT NULL DEFAULT 'admission',
|
jbe@0
|
430 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
|
jbe@0
|
431 "accepted" TIMESTAMPTZ,
|
jbe@3
|
432 "half_frozen" TIMESTAMPTZ,
|
jbe@3
|
433 "fully_frozen" TIMESTAMPTZ,
|
jbe@0
|
434 "closed" TIMESTAMPTZ,
|
jbe@0
|
435 "ranks_available" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@59
|
436 "cleaned" TIMESTAMPTZ,
|
jbe@22
|
437 "admission_time" INTERVAL NOT NULL,
|
jbe@22
|
438 "discussion_time" INTERVAL NOT NULL,
|
jbe@22
|
439 "verification_time" INTERVAL NOT NULL,
|
jbe@22
|
440 "voting_time" INTERVAL NOT NULL,
|
jbe@0
|
441 "snapshot" TIMESTAMPTZ,
|
jbe@8
|
442 "latest_snapshot_event" "snapshot_event",
|
jbe@0
|
443 "population" INT4,
|
jbe@0
|
444 "vote_now" INT4,
|
jbe@0
|
445 "vote_later" INT4,
|
jbe@4
|
446 "voter_count" INT4,
|
jbe@111
|
447 CONSTRAINT "valid_state" CHECK ((
|
jbe@3
|
448 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
|
jbe@3
|
449 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
|
jbe@3
|
450 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
|
jbe@34
|
451 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
|
jbe@3
|
452 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
|
jbe@34
|
453 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
|
jbe@3
|
454 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
|
jbe@3
|
455 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
|
jbe@111
|
456 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = TRUE)) AND (
|
jbe@111
|
457 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
|
jbe@111
|
458 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
|
jbe@111
|
459 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
|
jbe@111
|
460 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
|
jbe@113
|
461 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
|
jbe@113
|
462 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
|
jbe@113
|
463 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
|
jbe@113
|
464 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
|
jbe@113
|
465 ("state" = 'calculation' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = FALSE) OR
|
jbe@113
|
466 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
|
jbe@113
|
467 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
|
jbe@113
|
468 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE)
|
jbe@111
|
469 )),
|
jbe@3
|
470 CONSTRAINT "state_change_order" CHECK (
|
jbe@10
|
471 "created" <= "accepted" AND
|
jbe@10
|
472 "accepted" <= "half_frozen" AND
|
jbe@10
|
473 "half_frozen" <= "fully_frozen" AND
|
jbe@3
|
474 "fully_frozen" <= "closed" ),
|
jbe@61
|
475 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
|
jbe@61
|
476 "cleaned" ISNULL OR "closed" NOTNULL ),
|
jbe@10
|
477 CONSTRAINT "last_snapshot_on_full_freeze"
|
jbe@10
|
478 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
|
jbe@10
|
479 CONSTRAINT "freeze_requires_snapshot"
|
jbe@10
|
480 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
|
jbe@10
|
481 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
|
jbe@10
|
482 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) );
|
jbe@0
|
483 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
|
jbe@0
|
484 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
|
jbe@16
|
485 CREATE INDEX "issue_created_idx" ON "issue" ("created");
|
jbe@16
|
486 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
|
jbe@16
|
487 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
|
jbe@16
|
488 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
|
jbe@16
|
489 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
|
jbe@0
|
490 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
|
jbe@16
|
491 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
|
jbe@0
|
492
|
jbe@0
|
493 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
|
jbe@0
|
494
|
jbe@8
|
495 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
|
jbe@10
|
496 COMMENT ON COLUMN "issue"."half_frozen" IS 'Point in time, when "discussion_time" has elapsed, or members voted for voting; 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.';
|
jbe@86
|
497 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.';
|
jbe@10
|
498 COMMENT ON COLUMN "issue"."closed" IS 'Point in time, when "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.';
|
jbe@8
|
499 COMMENT ON COLUMN "issue"."ranks_available" IS 'TRUE = ranks have been calculated';
|
jbe@59
|
500 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
|
jbe@22
|
501 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue';
|
jbe@22
|
502 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
|
jbe@22
|
503 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
|
jbe@22
|
504 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
|
jbe@8
|
505 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population", "vote_now", "vote_later" and *_count values were precalculated';
|
jbe@8
|
506 COMMENT ON COLUMN "issue"."latest_snapshot_event" IS 'Event type of latest snapshot for issue; Can be used to select the latest snapshot data in the snapshot tables';
|
jbe@8
|
507 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
|
jbe@8
|
508 COMMENT ON COLUMN "issue"."vote_now" IS 'Number of votes in favor of voting now, as calculated from table "direct_interest_snapshot"';
|
jbe@8
|
509 COMMENT ON COLUMN "issue"."vote_later" IS 'Number of votes against voting now, as calculated from table "direct_interest_snapshot"';
|
jbe@8
|
510 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';
|
jbe@0
|
511
|
jbe@0
|
512
|
jbe@23
|
513 CREATE TABLE "issue_setting" (
|
jbe@23
|
514 PRIMARY KEY ("member_id", "key", "issue_id"),
|
jbe@23
|
515 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
516 "key" TEXT NOT NULL,
|
jbe@23
|
517 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
518 "value" TEXT NOT NULL );
|
jbe@23
|
519
|
jbe@23
|
520 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
|
jbe@23
|
521
|
jbe@23
|
522
|
jbe@0
|
523 CREATE TABLE "initiative" (
|
jbe@0
|
524 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
|
jbe@0
|
525 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
526 "id" SERIAL4 PRIMARY KEY,
|
jbe@0
|
527 "name" TEXT NOT NULL,
|
jbe@8
|
528 "discussion_url" TEXT,
|
jbe@0
|
529 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
|
jbe@0
|
530 "revoked" TIMESTAMPTZ,
|
jbe@112
|
531 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
|
jbe@14
|
532 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
533 "admitted" BOOLEAN,
|
jbe@0
|
534 "supporter_count" INT4,
|
jbe@0
|
535 "informed_supporter_count" INT4,
|
jbe@0
|
536 "satisfied_supporter_count" INT4,
|
jbe@0
|
537 "satisfied_informed_supporter_count" INT4,
|
jbe@0
|
538 "positive_votes" INT4,
|
jbe@0
|
539 "negative_votes" INT4,
|
jbe@128
|
540 "attainable" BOOLEAN,
|
jbe@128
|
541 "favored" BOOLEAN,
|
jbe@128
|
542 "unfavored" BOOLEAN,
|
jbe@139
|
543 "preliminary_rank" INT4,
|
jbe@139
|
544 "final_rank" INT4,
|
jbe@139
|
545 "disqualified" BOOLEAN,
|
jbe@126
|
546 "winner" BOOLEAN,
|
jbe@7
|
547 "text_search_data" TSVECTOR,
|
jbe@112
|
548 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
|
jbe@112
|
549 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL),
|
jbe@14
|
550 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
|
jbe@14
|
551 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
|
jbe@0
|
552 CONSTRAINT "revoked_initiatives_cant_be_admitted"
|
jbe@0
|
553 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
|
jbe@128
|
554 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
|
jbe@128
|
555 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
|
jbe@128
|
556 ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
|
jbe@128
|
557 "attainable" ISNULL AND "favored" ISNULL AND "unfavored" ISNULL AND
|
jbe@139
|
558 "disqualified" ISNULL AND "preliminary_rank" ISNULL AND
|
jbe@139
|
559 "final_rank" ISNULL AND "winner" ISNULL ) ),
|
jbe@139
|
560 CONSTRAINT "favored_excludes_unfavored" CHECK (NOT ("favored" AND "unfavored")) );
|
jbe@16
|
561 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
|
jbe@16
|
562 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
|
jbe@8
|
563 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
|
jbe@7
|
564 CREATE TRIGGER "update_text_search_data"
|
jbe@7
|
565 BEFORE INSERT OR UPDATE ON "initiative"
|
jbe@7
|
566 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@8
|
567 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
|
jbe@8
|
568 "name", "discussion_url");
|
jbe@0
|
569
|
jbe@10
|
570 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.';
|
jbe@0
|
571
|
jbe@112
|
572 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
|
jbe@112
|
573 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
|
jbe@112
|
574 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoked the initiative';
|
jbe@112
|
575 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
|
jbe@0
|
576 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
|
jbe@0
|
577 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
|
jbe@0
|
578 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
|
jbe@0
|
579 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
|
jbe@139
|
580 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
|
jbe@139
|
581 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
|
jbe@139
|
582 COMMENT ON COLUMN "initiative"."attainable" IS 'TRUE, if "positive_votes"/("positive_votes"+"negative_votes") is strictly greater or greater-equal than "majority_num"/"majority_den"';
|
jbe@139
|
583 COMMENT ON COLUMN "initiative"."favored" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
|
jbe@139
|
584 COMMENT ON COLUMN "initiative"."unfavored" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
|
jbe@139
|
585 COMMENT ON COLUMN "initiative"."preliminary_rank" IS 'Schulze-Ranking without tie-breaking';
|
jbe@139
|
586 COMMENT ON COLUMN "initiative"."final_rank" IS 'Schulze-Ranking after tie-breaking';
|
jbe@139
|
587 COMMENT ON COLUMN "initiative"."disqualified" IS 'TRUE, if initiative may not win, because it is directly beaten with a simple majority by a better ranked initiative or by a better ranked status quo (without tie-breaking)';
|
jbe@139
|
588 COMMENT ON COLUMN "initiative"."winner" IS 'TRUE, if initiative is final winner (best ranked initiative being "attainable", "favored", and not "disqualified")';
|
jbe@0
|
589
|
jbe@0
|
590
|
jbe@61
|
591 CREATE TABLE "battle" (
|
jbe@126
|
592 "issue_id" INT4 NOT NULL,
|
jbe@61
|
593 "winning_initiative_id" INT4,
|
jbe@61
|
594 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@61
|
595 "losing_initiative_id" INT4,
|
jbe@61
|
596 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@126
|
597 "count" INT4 NOT NULL,
|
jbe@126
|
598 CONSTRAINT "initiative_ids_not_equal" CHECK (
|
jbe@126
|
599 "winning_initiative_id" != "losing_initiative_id" OR
|
jbe@126
|
600 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
|
jbe@126
|
601 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
|
jbe@126
|
602 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
|
jbe@126
|
603 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
|
jbe@126
|
604 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
|
jbe@126
|
605
|
jbe@126
|
606 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';
|
jbe@61
|
607
|
jbe@61
|
608
|
jbe@113
|
609 CREATE TABLE "ignored_initiative" (
|
jbe@113
|
610 PRIMARY KEY ("initiative_id", "member_id"),
|
jbe@113
|
611 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@113
|
612 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
|
jbe@113
|
613 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
|
jbe@113
|
614
|
jbe@113
|
615 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
|
jbe@113
|
616
|
jbe@113
|
617
|
jbe@23
|
618 CREATE TABLE "initiative_setting" (
|
jbe@23
|
619 PRIMARY KEY ("member_id", "key", "initiative_id"),
|
jbe@23
|
620 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
621 "key" TEXT NOT NULL,
|
jbe@23
|
622 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
623 "value" TEXT NOT NULL );
|
jbe@23
|
624
|
jbe@23
|
625 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
|
jbe@23
|
626
|
jbe@23
|
627
|
jbe@0
|
628 CREATE TABLE "draft" (
|
jbe@0
|
629 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
|
jbe@0
|
630 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
631 "id" SERIAL8 PRIMARY KEY,
|
jbe@0
|
632 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
|
jbe@0
|
633 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
|
jbe@9
|
634 "formatting_engine" TEXT,
|
jbe@7
|
635 "content" TEXT NOT NULL,
|
jbe@7
|
636 "text_search_data" TSVECTOR );
|
jbe@16
|
637 CREATE INDEX "draft_created_idx" ON "draft" ("created");
|
jbe@9
|
638 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
|
jbe@8
|
639 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
|
jbe@7
|
640 CREATE TRIGGER "update_text_search_data"
|
jbe@7
|
641 BEFORE INSERT OR UPDATE ON "draft"
|
jbe@7
|
642 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@7
|
643 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
|
jbe@0
|
644
|
jbe@10
|
645 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.';
|
jbe@0
|
646
|
jbe@9
|
647 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
|
jbe@9
|
648 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
|
jbe@9
|
649
|
jbe@0
|
650
|
jbe@63
|
651 CREATE TABLE "rendered_draft" (
|
jbe@63
|
652 PRIMARY KEY ("draft_id", "format"),
|
jbe@63
|
653 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@63
|
654 "format" TEXT,
|
jbe@63
|
655 "content" TEXT NOT NULL );
|
jbe@63
|
656
|
jbe@63
|
657 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)';
|
jbe@63
|
658
|
jbe@63
|
659
|
jbe@0
|
660 CREATE TABLE "suggestion" (
|
jbe@0
|
661 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
|
jbe@0
|
662 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
663 "id" SERIAL8 PRIMARY KEY,
|
jbe@0
|
664 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
|
jbe@0
|
665 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
|
jbe@0
|
666 "name" TEXT NOT NULL,
|
jbe@0
|
667 "description" TEXT NOT NULL DEFAULT '',
|
jbe@7
|
668 "text_search_data" TSVECTOR,
|
jbe@0
|
669 "minus2_unfulfilled_count" INT4,
|
jbe@0
|
670 "minus2_fulfilled_count" INT4,
|
jbe@0
|
671 "minus1_unfulfilled_count" INT4,
|
jbe@0
|
672 "minus1_fulfilled_count" INT4,
|
jbe@0
|
673 "plus1_unfulfilled_count" INT4,
|
jbe@0
|
674 "plus1_fulfilled_count" INT4,
|
jbe@0
|
675 "plus2_unfulfilled_count" INT4,
|
jbe@0
|
676 "plus2_fulfilled_count" INT4 );
|
jbe@16
|
677 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
|
jbe@9
|
678 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
|
jbe@8
|
679 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
|
jbe@7
|
680 CREATE TRIGGER "update_text_search_data"
|
jbe@7
|
681 BEFORE INSERT OR UPDATE ON "suggestion"
|
jbe@7
|
682 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@7
|
683 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
|
jbe@7
|
684 "name", "description");
|
jbe@0
|
685
|
jbe@10
|
686 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';
|
jbe@0
|
687
|
jbe@0
|
688 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
|
jbe@0
|
689 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
|
jbe@0
|
690 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
|
jbe@0
|
691 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
|
jbe@0
|
692 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
|
jbe@0
|
693 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
|
jbe@0
|
694 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
|
jbe@0
|
695 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
|
jbe@0
|
696
|
jbe@0
|
697
|
jbe@23
|
698 CREATE TABLE "suggestion_setting" (
|
jbe@23
|
699 PRIMARY KEY ("member_id", "key", "suggestion_id"),
|
jbe@23
|
700 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
701 "key" TEXT NOT NULL,
|
jbe@23
|
702 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
703 "value" TEXT NOT NULL );
|
jbe@23
|
704
|
jbe@23
|
705 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
|
jbe@23
|
706
|
jbe@23
|
707
|
jbe@97
|
708 CREATE TABLE "invite_code_unit" (
|
jbe@97
|
709 PRIMARY KEY ("invite_code_id", "unit_id"),
|
jbe@97
|
710 "invite_code_id" INT8 REFERENCES "invite_code" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@97
|
711 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
|
jbe@97
|
712
|
jbe@97
|
713 COMMENT ON TABLE "invite_code_unit" IS 'Units where accounts created with a given invite codes get voting rights';
|
jbe@97
|
714
|
jbe@97
|
715
|
jbe@97
|
716 CREATE TABLE "privilege" (
|
jbe@97
|
717 PRIMARY KEY ("unit_id", "member_id"),
|
jbe@97
|
718 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@97
|
719 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@97
|
720 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@97
|
721 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@97
|
722 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@97
|
723 "voting_right_manager" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@97
|
724 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE );
|
jbe@97
|
725
|
jbe@97
|
726 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
|
jbe@97
|
727
|
jbe@97
|
728 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke admin privileges to/from other users';
|
jbe@97
|
729 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create or lock sub units';
|
jbe@97
|
730 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create or lock areas and set area parameters';
|
jbe@97
|
731 COMMENT ON COLUMN "privilege"."voting_right_manager" IS 'Select which members are allowed to discuss and vote inside the unit';
|
jbe@97
|
732 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to discuss and vote';
|
jbe@97
|
733
|
jbe@97
|
734
|
jbe@0
|
735 CREATE TABLE "membership" (
|
jbe@0
|
736 PRIMARY KEY ("area_id", "member_id"),
|
jbe@0
|
737 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
738 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@113
|
739 "autoreject" BOOLEAN NOT NULL DEFAULT FALSE );
|
jbe@0
|
740 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
|
jbe@0
|
741
|
jbe@0
|
742 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
|
jbe@0
|
743
|
jbe@114
|
744 COMMENT ON COLUMN "membership"."autoreject" IS 'TRUE = member votes against all initiatives, if he is neither direct_ or delegating_voter; Entries in the "interest" table can override this setting.';
|
jbe@0
|
745
|
jbe@0
|
746
|
jbe@0
|
747 CREATE TABLE "interest" (
|
jbe@0
|
748 PRIMARY KEY ("issue_id", "member_id"),
|
jbe@0
|
749 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
750 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@86
|
751 "autoreject" BOOLEAN,
|
jbe@0
|
752 "voting_requested" BOOLEAN );
|
jbe@0
|
753 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
|
jbe@0
|
754
|
jbe@10
|
755 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.';
|
jbe@0
|
756
|
jbe@0
|
757 COMMENT ON COLUMN "interest"."autoreject" IS 'TRUE = member votes against all initiatives in case of not explicitly taking part in the voting procedure';
|
jbe@0
|
758 COMMENT ON COLUMN "interest"."voting_requested" IS 'TRUE = member wants to vote now, FALSE = member wants to vote later, NULL = policy rules should apply';
|
jbe@0
|
759
|
jbe@0
|
760
|
jbe@0
|
761 CREATE TABLE "initiator" (
|
jbe@0
|
762 PRIMARY KEY ("initiative_id", "member_id"),
|
jbe@0
|
763 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
764 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@14
|
765 "accepted" BOOLEAN );
|
jbe@0
|
766 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
|
jbe@0
|
767
|
jbe@10
|
768 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.';
|
jbe@0
|
769
|
jbe@14
|
770 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.';
|
jbe@0
|
771
|
jbe@0
|
772
|
jbe@0
|
773 CREATE TABLE "supporter" (
|
jbe@0
|
774 "issue_id" INT4 NOT NULL,
|
jbe@0
|
775 PRIMARY KEY ("initiative_id", "member_id"),
|
jbe@0
|
776 "initiative_id" INT4,
|
jbe@0
|
777 "member_id" INT4,
|
jbe@0
|
778 "draft_id" INT8 NOT NULL,
|
jbe@10
|
779 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
780 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE );
|
jbe@0
|
781 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
|
jbe@0
|
782
|
jbe@10
|
783 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.';
|
jbe@0
|
784
|
jbe@90
|
785 COMMENT ON COLUMN "supporter"."draft_id" IS 'Latest seen draft, defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
|
jbe@84
|
786
|
jbe@0
|
787
|
jbe@0
|
788 CREATE TABLE "opinion" (
|
jbe@0
|
789 "initiative_id" INT4 NOT NULL,
|
jbe@0
|
790 PRIMARY KEY ("suggestion_id", "member_id"),
|
jbe@0
|
791 "suggestion_id" INT8,
|
jbe@0
|
792 "member_id" INT4,
|
jbe@0
|
793 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
|
jbe@0
|
794 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@42
|
795 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
796 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
|
jbe@10
|
797 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
|
jbe@0
|
798
|
jbe@10
|
799 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.';
|
jbe@0
|
800
|
jbe@0
|
801 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
|
jbe@0
|
802
|
jbe@0
|
803
|
jbe@97
|
804 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
|
jbe@97
|
805
|
jbe@97
|
806 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
|
jbe@10
|
807
|
jbe@10
|
808
|
jbe@0
|
809 CREATE TABLE "delegation" (
|
jbe@0
|
810 "id" SERIAL8 PRIMARY KEY,
|
jbe@0
|
811 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@86
|
812 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@10
|
813 "scope" "delegation_scope" NOT NULL,
|
jbe@97
|
814 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
815 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
816 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
817 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
|
jbe@97
|
818 CONSTRAINT "no_unit_delegation_to_null"
|
jbe@97
|
819 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
|
jbe@10
|
820 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
|
jbe@97
|
821 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
|
jbe@97
|
822 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
|
jbe@97
|
823 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
|
jbe@97
|
824 UNIQUE ("unit_id", "truster_id"),
|
jbe@74
|
825 UNIQUE ("area_id", "truster_id"),
|
jbe@74
|
826 UNIQUE ("issue_id", "truster_id") );
|
jbe@0
|
827 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
|
jbe@0
|
828 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
|
jbe@0
|
829
|
jbe@0
|
830 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
|
jbe@0
|
831
|
jbe@97
|
832 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
|
jbe@0
|
833 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
|
jbe@0
|
834 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
|
jbe@0
|
835
|
jbe@0
|
836
|
jbe@0
|
837 CREATE TABLE "direct_population_snapshot" (
|
jbe@0
|
838 PRIMARY KEY ("issue_id", "event", "member_id"),
|
jbe@0
|
839 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
840 "event" "snapshot_event",
|
jbe@45
|
841 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
|
jbe@54
|
842 "weight" INT4 );
|
jbe@0
|
843 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
|
jbe@0
|
844
|
jbe@0
|
845 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"';
|
jbe@0
|
846
|
jbe@0
|
847 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
|
jbe@0
|
848 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
|
jbe@0
|
849
|
jbe@0
|
850
|
jbe@0
|
851 CREATE TABLE "delegating_population_snapshot" (
|
jbe@0
|
852 PRIMARY KEY ("issue_id", "event", "member_id"),
|
jbe@0
|
853 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
854 "event" "snapshot_event",
|
jbe@45
|
855 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
|
jbe@8
|
856 "weight" INT4,
|
jbe@10
|
857 "scope" "delegation_scope" NOT NULL,
|
jbe@0
|
858 "delegate_member_ids" INT4[] NOT NULL );
|
jbe@0
|
859 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
|
jbe@0
|
860
|
jbe@0
|
861 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table';
|
jbe@0
|
862
|
jbe@0
|
863 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
|
jbe@0
|
864 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
|
jbe@8
|
865 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
|
jbe@0
|
866 COMMENT ON COLUMN "delegating_population_snapshot"."delegate_member_ids" IS 'Chain of members who act as delegates; last entry referes to "member_id" column of table "direct_population_snapshot"';
|
jbe@0
|
867
|
jbe@0
|
868
|
jbe@0
|
869 CREATE TABLE "direct_interest_snapshot" (
|
jbe@0
|
870 PRIMARY KEY ("issue_id", "event", "member_id"),
|
jbe@0
|
871 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
872 "event" "snapshot_event",
|
jbe@45
|
873 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
|
jbe@0
|
874 "weight" INT4,
|
jbe@0
|
875 "voting_requested" BOOLEAN );
|
jbe@0
|
876 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
|
jbe@0
|
877
|
jbe@0
|
878 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"';
|
jbe@0
|
879
|
jbe@0
|
880 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
|
jbe@0
|
881 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
|
jbe@0
|
882 COMMENT ON COLUMN "direct_interest_snapshot"."voting_requested" IS 'Copied from column "voting_requested" of table "interest"';
|
jbe@0
|
883
|
jbe@0
|
884
|
jbe@0
|
885 CREATE TABLE "delegating_interest_snapshot" (
|
jbe@0
|
886 PRIMARY KEY ("issue_id", "event", "member_id"),
|
jbe@0
|
887 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
888 "event" "snapshot_event",
|
jbe@45
|
889 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
|
jbe@8
|
890 "weight" INT4,
|
jbe@10
|
891 "scope" "delegation_scope" NOT NULL,
|
jbe@0
|
892 "delegate_member_ids" INT4[] NOT NULL );
|
jbe@0
|
893 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
|
jbe@0
|
894
|
jbe@0
|
895 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table';
|
jbe@0
|
896
|
jbe@0
|
897 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
|
jbe@0
|
898 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
|
jbe@8
|
899 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
|
jbe@0
|
900 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"';
|
jbe@0
|
901
|
jbe@0
|
902
|
jbe@0
|
903 CREATE TABLE "direct_supporter_snapshot" (
|
jbe@0
|
904 "issue_id" INT4 NOT NULL,
|
jbe@0
|
905 PRIMARY KEY ("initiative_id", "event", "member_id"),
|
jbe@0
|
906 "initiative_id" INT4,
|
jbe@0
|
907 "event" "snapshot_event",
|
jbe@45
|
908 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
|
jbe@0
|
909 "informed" BOOLEAN NOT NULL,
|
jbe@0
|
910 "satisfied" BOOLEAN NOT NULL,
|
jbe@0
|
911 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
912 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
|
jbe@0
|
913 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
|
jbe@0
|
914
|
jbe@8
|
915 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
|
jbe@0
|
916
|
jbe@0
|
917 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
|
jbe@0
|
918 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
|
jbe@0
|
919 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
|
jbe@0
|
920
|
jbe@0
|
921
|
jbe@113
|
922 CREATE TABLE "non_voter" (
|
jbe@113
|
923 PRIMARY KEY ("issue_id", "member_id"),
|
jbe@113
|
924 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@113
|
925 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
|
jbe@113
|
926 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
|
jbe@113
|
927
|
jbe@113
|
928 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
|
jbe@113
|
929
|
jbe@113
|
930
|
jbe@0
|
931 CREATE TABLE "direct_voter" (
|
jbe@0
|
932 PRIMARY KEY ("issue_id", "member_id"),
|
jbe@0
|
933 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@45
|
934 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
|
jbe@0
|
935 "weight" INT4,
|
jbe@0
|
936 "autoreject" BOOLEAN NOT NULL DEFAULT FALSE );
|
jbe@0
|
937 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
|
jbe@0
|
938
|
jbe@10
|
939 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.';
|
jbe@0
|
940
|
jbe@0
|
941 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
|
jbe@0
|
942 COMMENT ON COLUMN "direct_voter"."autoreject" IS 'Votes were inserted due to "autoreject" feature';
|
jbe@0
|
943
|
jbe@0
|
944
|
jbe@0
|
945 CREATE TABLE "delegating_voter" (
|
jbe@0
|
946 PRIMARY KEY ("issue_id", "member_id"),
|
jbe@0
|
947 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@45
|
948 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
|
jbe@8
|
949 "weight" INT4,
|
jbe@10
|
950 "scope" "delegation_scope" NOT NULL,
|
jbe@0
|
951 "delegate_member_ids" INT4[] NOT NULL );
|
jbe@52
|
952 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
|
jbe@0
|
953
|
jbe@0
|
954 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
|
jbe@0
|
955
|
jbe@0
|
956 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
|
jbe@8
|
957 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
|
jbe@0
|
958 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"';
|
jbe@0
|
959
|
jbe@0
|
960
|
jbe@0
|
961 CREATE TABLE "vote" (
|
jbe@0
|
962 "issue_id" INT4 NOT NULL,
|
jbe@0
|
963 PRIMARY KEY ("initiative_id", "member_id"),
|
jbe@0
|
964 "initiative_id" INT4,
|
jbe@0
|
965 "member_id" INT4,
|
jbe@0
|
966 "grade" INT4,
|
jbe@0
|
967 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
968 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
|
jbe@0
|
969 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
|
jbe@0
|
970
|
jbe@10
|
971 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.';
|
jbe@0
|
972
|
jbe@0
|
973 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.';
|
jbe@0
|
974
|
jbe@0
|
975
|
jbe@111
|
976 CREATE TABLE "issue_comment" (
|
jbe@111
|
977 PRIMARY KEY ("issue_id", "member_id"),
|
jbe@111
|
978 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@111
|
979 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@111
|
980 "changed" TIMESTAMPTZ NOT NULL DEFAULT now(),
|
jbe@111
|
981 "formatting_engine" TEXT,
|
jbe@111
|
982 "content" TEXT NOT NULL,
|
jbe@111
|
983 "text_search_data" TSVECTOR );
|
jbe@111
|
984 CREATE INDEX "issue_comment_member_id_idx" ON "issue_comment" ("member_id");
|
jbe@111
|
985 CREATE INDEX "issue_comment_text_search_data_idx" ON "issue_comment" USING gin ("text_search_data");
|
jbe@111
|
986 CREATE TRIGGER "update_text_search_data"
|
jbe@111
|
987 BEFORE INSERT OR UPDATE ON "issue_comment"
|
jbe@111
|
988 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@111
|
989 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
|
jbe@111
|
990
|
jbe@111
|
991 COMMENT ON TABLE "issue_comment" IS 'Place to store free comments of members related to issues';
|
jbe@111
|
992
|
jbe@111
|
993 COMMENT ON COLUMN "issue_comment"."changed" IS 'Time the comment was last changed';
|
jbe@111
|
994
|
jbe@111
|
995
|
jbe@111
|
996 CREATE TABLE "rendered_issue_comment" (
|
jbe@111
|
997 PRIMARY KEY ("issue_id", "member_id", "format"),
|
jbe@111
|
998 FOREIGN KEY ("issue_id", "member_id")
|
jbe@111
|
999 REFERENCES "issue_comment" ("issue_id", "member_id")
|
jbe@111
|
1000 ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@111
|
1001 "issue_id" INT4,
|
jbe@111
|
1002 "member_id" INT4,
|
jbe@111
|
1003 "format" TEXT,
|
jbe@111
|
1004 "content" TEXT NOT NULL );
|
jbe@111
|
1005
|
jbe@111
|
1006 COMMENT ON TABLE "rendered_issue_comment" IS 'This table may be used by frontends to cache "rendered" issue comments (e.g. HTML output generated from wiki text)';
|
jbe@111
|
1007
|
jbe@111
|
1008
|
jbe@111
|
1009 CREATE TABLE "voting_comment" (
|
jbe@111
|
1010 PRIMARY KEY ("issue_id", "member_id"),
|
jbe@111
|
1011 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@111
|
1012 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@111
|
1013 "changed" TIMESTAMPTZ,
|
jbe@111
|
1014 "formatting_engine" TEXT,
|
jbe@111
|
1015 "content" TEXT NOT NULL,
|
jbe@111
|
1016 "text_search_data" TSVECTOR );
|
jbe@111
|
1017 CREATE INDEX "voting_comment_member_id_idx" ON "voting_comment" ("member_id");
|
jbe@111
|
1018 CREATE INDEX "voting_comment_text_search_data_idx" ON "voting_comment" USING gin ("text_search_data");
|
jbe@111
|
1019 CREATE TRIGGER "update_text_search_data"
|
jbe@111
|
1020 BEFORE INSERT OR UPDATE ON "voting_comment"
|
jbe@111
|
1021 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@111
|
1022 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
|
jbe@111
|
1023
|
jbe@111
|
1024 COMMENT ON TABLE "voting_comment" IS 'Storage for comments of voters to be published after voting has finished.';
|
jbe@111
|
1025
|
jbe@111
|
1026 COMMENT ON COLUMN "voting_comment"."changed" 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.';
|
jbe@111
|
1027
|
jbe@111
|
1028
|
jbe@111
|
1029 CREATE TABLE "rendered_voting_comment" (
|
jbe@111
|
1030 PRIMARY KEY ("issue_id", "member_id", "format"),
|
jbe@111
|
1031 FOREIGN KEY ("issue_id", "member_id")
|
jbe@111
|
1032 REFERENCES "voting_comment" ("issue_id", "member_id")
|
jbe@111
|
1033 ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@111
|
1034 "issue_id" INT4,
|
jbe@111
|
1035 "member_id" INT4,
|
jbe@111
|
1036 "format" TEXT,
|
jbe@111
|
1037 "content" TEXT NOT NULL );
|
jbe@111
|
1038
|
jbe@111
|
1039 COMMENT ON TABLE "rendered_voting_comment" IS 'This table may be used by frontends to cache "rendered" voting comments (e.g. HTML output generated from wiki text)';
|
jbe@111
|
1040
|
jbe@111
|
1041
|
jbe@112
|
1042 CREATE TYPE "event_type" AS ENUM (
|
jbe@112
|
1043 'issue_state_changed',
|
jbe@112
|
1044 'initiative_created_in_new_issue',
|
jbe@112
|
1045 'initiative_created_in_existing_issue',
|
jbe@112
|
1046 'initiative_revoked',
|
jbe@112
|
1047 'new_draft_created',
|
jbe@112
|
1048 'suggestion_created');
|
jbe@112
|
1049
|
jbe@112
|
1050 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
|
jbe@112
|
1051
|
jbe@112
|
1052
|
jbe@112
|
1053 CREATE TABLE "event" (
|
jbe@112
|
1054 "id" SERIAL8 PRIMARY KEY,
|
jbe@112
|
1055 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
|
jbe@112
|
1056 "event" "event_type" NOT NULL,
|
jbe@112
|
1057 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
|
jbe@112
|
1058 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@112
|
1059 "state" "issue_state" CHECK ("state" != 'calculation'),
|
jbe@112
|
1060 "initiative_id" INT4,
|
jbe@112
|
1061 "draft_id" INT8,
|
jbe@112
|
1062 "suggestion_id" INT8,
|
jbe@112
|
1063 FOREIGN KEY ("issue_id", "initiative_id")
|
jbe@112
|
1064 REFERENCES "initiative" ("issue_id", "id")
|
jbe@112
|
1065 ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@112
|
1066 FOREIGN KEY ("initiative_id", "draft_id")
|
jbe@112
|
1067 REFERENCES "draft" ("initiative_id", "id")
|
jbe@112
|
1068 ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@112
|
1069 FOREIGN KEY ("initiative_id", "suggestion_id")
|
jbe@112
|
1070 REFERENCES "suggestion" ("initiative_id", "id")
|
jbe@112
|
1071 ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@112
|
1072 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
|
jbe@112
|
1073 "event" != 'issue_state_changed' OR (
|
jbe@112
|
1074 "member_id" ISNULL AND
|
jbe@112
|
1075 "issue_id" NOTNULL AND
|
jbe@113
|
1076 "state" NOTNULL AND
|
jbe@112
|
1077 "initiative_id" ISNULL AND
|
jbe@112
|
1078 "draft_id" ISNULL AND
|
jbe@112
|
1079 "suggestion_id" ISNULL )),
|
jbe@112
|
1080 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
|
jbe@112
|
1081 "event" NOT IN (
|
jbe@112
|
1082 'initiative_created_in_new_issue',
|
jbe@112
|
1083 'initiative_created_in_existing_issue',
|
jbe@112
|
1084 'initiative_revoked',
|
jbe@112
|
1085 'new_draft_created'
|
jbe@112
|
1086 ) OR (
|
jbe@112
|
1087 "member_id" NOTNULL AND
|
jbe@112
|
1088 "issue_id" NOTNULL AND
|
jbe@113
|
1089 "state" NOTNULL AND
|
jbe@112
|
1090 "initiative_id" NOTNULL AND
|
jbe@112
|
1091 "draft_id" NOTNULL AND
|
jbe@112
|
1092 "suggestion_id" ISNULL )),
|
jbe@112
|
1093 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
|
jbe@112
|
1094 "event" != 'suggestion_created' OR (
|
jbe@112
|
1095 "member_id" NOTNULL AND
|
jbe@112
|
1096 "issue_id" NOTNULL AND
|
jbe@113
|
1097 "state" NOTNULL AND
|
jbe@112
|
1098 "initiative_id" NOTNULL AND
|
jbe@112
|
1099 "draft_id" ISNULL AND
|
jbe@112
|
1100 "suggestion_id" NOTNULL )) );
|
jbe@112
|
1101
|
jbe@112
|
1102 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
|
jbe@112
|
1103
|
jbe@114
|
1104 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
|
jbe@114
|
1105 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
|
jbe@114
|
1106 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
|
jbe@114
|
1107 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
|
jbe@114
|
1108
|
jbe@112
|
1109
|
jbe@112
|
1110
|
jbe@112
|
1111 ----------------------------------------------
|
jbe@112
|
1112 -- Writing of history entries and event log --
|
jbe@112
|
1113 ----------------------------------------------
|
jbe@13
|
1114
|
jbe@13
|
1115 CREATE FUNCTION "write_member_history_trigger"()
|
jbe@13
|
1116 RETURNS TRIGGER
|
jbe@13
|
1117 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@13
|
1118 BEGIN
|
jbe@42
|
1119 IF
|
jbe@42
|
1120 NEW."active" != OLD."active" OR
|
jbe@42
|
1121 NEW."name" != OLD."name"
|
jbe@42
|
1122 THEN
|
jbe@42
|
1123 INSERT INTO "member_history"
|
jbe@57
|
1124 ("member_id", "active", "name")
|
jbe@57
|
1125 VALUES (NEW."id", OLD."active", OLD."name");
|
jbe@13
|
1126 END IF;
|
jbe@13
|
1127 RETURN NULL;
|
jbe@13
|
1128 END;
|
jbe@13
|
1129 $$;
|
jbe@13
|
1130
|
jbe@13
|
1131 CREATE TRIGGER "write_member_history"
|
jbe@13
|
1132 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
|
jbe@13
|
1133 "write_member_history_trigger"();
|
jbe@13
|
1134
|
jbe@13
|
1135 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
|
jbe@57
|
1136 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
|
jbe@13
|
1137
|
jbe@13
|
1138
|
jbe@112
|
1139 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
|
jbe@112
|
1140 RETURNS TRIGGER
|
jbe@112
|
1141 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@112
|
1142 BEGIN
|
jbe@112
|
1143 IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
|
jbe@112
|
1144 INSERT INTO "event" ("event", "issue_id", "state")
|
jbe@112
|
1145 VALUES ('issue_state_changed', NEW."id", NEW."state");
|
jbe@112
|
1146 END IF;
|
jbe@112
|
1147 RETURN NULL;
|
jbe@112
|
1148 END;
|
jbe@112
|
1149 $$;
|
jbe@112
|
1150
|
jbe@112
|
1151 CREATE TRIGGER "write_event_issue_state_changed"
|
jbe@112
|
1152 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
|
jbe@112
|
1153 "write_event_issue_state_changed_trigger"();
|
jbe@112
|
1154
|
jbe@112
|
1155 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
|
jbe@112
|
1156 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
|
jbe@112
|
1157
|
jbe@112
|
1158
|
jbe@112
|
1159 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
|
jbe@112
|
1160 RETURNS TRIGGER
|
jbe@112
|
1161 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@112
|
1162 DECLARE
|
jbe@112
|
1163 "initiative_row" "initiative"%ROWTYPE;
|
jbe@113
|
1164 "issue_row" "issue"%ROWTYPE;
|
jbe@112
|
1165 "event_v" "event_type";
|
jbe@112
|
1166 BEGIN
|
jbe@112
|
1167 SELECT * INTO "initiative_row" FROM "initiative"
|
jbe@112
|
1168 WHERE "id" = NEW."initiative_id";
|
jbe@113
|
1169 SELECT * INTO "issue_row" FROM "issue"
|
jbe@113
|
1170 WHERE "id" = "initiative_row"."issue_id";
|
jbe@112
|
1171 IF EXISTS (
|
jbe@112
|
1172 SELECT NULL FROM "draft"
|
jbe@112
|
1173 WHERE "initiative_id" = NEW."initiative_id"
|
jbe@112
|
1174 AND "id" != NEW."id"
|
jbe@112
|
1175 ) THEN
|
jbe@112
|
1176 "event_v" := 'new_draft_created';
|
jbe@112
|
1177 ELSE
|
jbe@112
|
1178 IF EXISTS (
|
jbe@112
|
1179 SELECT NULL FROM "initiative"
|
jbe@112
|
1180 WHERE "issue_id" = "initiative_row"."issue_id"
|
jbe@112
|
1181 AND "id" != "initiative_row"."id"
|
jbe@112
|
1182 ) THEN
|
jbe@112
|
1183 "event_v" := 'initiative_created_in_existing_issue';
|
jbe@112
|
1184 ELSE
|
jbe@112
|
1185 "event_v" := 'initiative_created_in_new_issue';
|
jbe@112
|
1186 END IF;
|
jbe@112
|
1187 END IF;
|
jbe@112
|
1188 INSERT INTO "event" (
|
jbe@112
|
1189 "event", "member_id",
|
jbe@113
|
1190 "issue_id", "state", "initiative_id", "draft_id"
|
jbe@112
|
1191 ) VALUES (
|
jbe@112
|
1192 "event_v",
|
jbe@112
|
1193 NEW."author_id",
|
jbe@112
|
1194 "initiative_row"."issue_id",
|
jbe@113
|
1195 "issue_row"."state",
|
jbe@112
|
1196 "initiative_row"."id",
|
jbe@112
|
1197 NEW."id" );
|
jbe@112
|
1198 RETURN NULL;
|
jbe@112
|
1199 END;
|
jbe@112
|
1200 $$;
|
jbe@112
|
1201
|
jbe@112
|
1202 CREATE TRIGGER "write_event_initiative_or_draft_created"
|
jbe@112
|
1203 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
|
jbe@112
|
1204 "write_event_initiative_or_draft_created_trigger"();
|
jbe@112
|
1205
|
jbe@112
|
1206 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
|
jbe@112
|
1207 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
|
jbe@112
|
1208
|
jbe@112
|
1209
|
jbe@112
|
1210 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
|
jbe@112
|
1211 RETURNS TRIGGER
|
jbe@112
|
1212 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@113
|
1213 DECLARE
|
jbe@113
|
1214 "issue_row" "issue"%ROWTYPE;
|
jbe@112
|
1215 BEGIN
|
jbe@113
|
1216 SELECT * INTO "issue_row" FROM "issue"
|
jbe@113
|
1217 WHERE "id" = NEW."issue_id";
|
jbe@112
|
1218 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
|
jbe@112
|
1219 INSERT INTO "event" (
|
jbe@113
|
1220 "event", "member_id", "issue_id", "state", "initiative_id"
|
jbe@112
|
1221 ) VALUES (
|
jbe@112
|
1222 'initiative_revoked',
|
jbe@112
|
1223 NEW."revoked_by_member_id",
|
jbe@112
|
1224 NEW."issue_id",
|
jbe@113
|
1225 "issue_row"."state",
|
jbe@112
|
1226 NEW."id" );
|
jbe@112
|
1227 END IF;
|
jbe@112
|
1228 RETURN NULL;
|
jbe@112
|
1229 END;
|
jbe@112
|
1230 $$;
|
jbe@112
|
1231
|
jbe@112
|
1232 CREATE TRIGGER "write_event_initiative_revoked"
|
jbe@112
|
1233 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
|
jbe@112
|
1234 "write_event_initiative_revoked_trigger"();
|
jbe@112
|
1235
|
jbe@112
|
1236 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
|
jbe@112
|
1237 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
|
jbe@112
|
1238
|
jbe@112
|
1239
|
jbe@112
|
1240 CREATE FUNCTION "write_event_suggestion_created_trigger"()
|
jbe@112
|
1241 RETURNS TRIGGER
|
jbe@112
|
1242 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@112
|
1243 DECLARE
|
jbe@112
|
1244 "initiative_row" "initiative"%ROWTYPE;
|
jbe@113
|
1245 "issue_row" "issue"%ROWTYPE;
|
jbe@112
|
1246 BEGIN
|
jbe@112
|
1247 SELECT * INTO "initiative_row" FROM "initiative"
|
jbe@112
|
1248 WHERE "id" = NEW."initiative_id";
|
jbe@113
|
1249 SELECT * INTO "issue_row" FROM "issue"
|
jbe@113
|
1250 WHERE "id" = "initiative_row"."issue_id";
|
jbe@112
|
1251 INSERT INTO "event" (
|
jbe@112
|
1252 "event", "member_id",
|
jbe@113
|
1253 "issue_id", "state", "initiative_id", "suggestion_id"
|
jbe@112
|
1254 ) VALUES (
|
jbe@112
|
1255 'suggestion_created',
|
jbe@112
|
1256 NEW."author_id",
|
jbe@112
|
1257 "initiative_row"."issue_id",
|
jbe@113
|
1258 "issue_row"."state",
|
jbe@112
|
1259 "initiative_row"."id",
|
jbe@112
|
1260 NEW."id" );
|
jbe@112
|
1261 RETURN NULL;
|
jbe@112
|
1262 END;
|
jbe@112
|
1263 $$;
|
jbe@112
|
1264
|
jbe@112
|
1265 CREATE TRIGGER "write_event_suggestion_created"
|
jbe@112
|
1266 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
|
jbe@112
|
1267 "write_event_suggestion_created_trigger"();
|
jbe@112
|
1268
|
jbe@112
|
1269 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
|
jbe@112
|
1270 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
|
jbe@112
|
1271
|
jbe@112
|
1272
|
jbe@13
|
1273
|
jbe@0
|
1274 ----------------------------
|
jbe@0
|
1275 -- Additional constraints --
|
jbe@0
|
1276 ----------------------------
|
jbe@0
|
1277
|
jbe@0
|
1278
|
jbe@0
|
1279 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
|
jbe@0
|
1280 RETURNS TRIGGER
|
jbe@0
|
1281 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1282 BEGIN
|
jbe@0
|
1283 IF NOT EXISTS (
|
jbe@0
|
1284 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
|
jbe@0
|
1285 ) THEN
|
jbe@0
|
1286 --RAISE 'Cannot create issue without an initial initiative.' USING
|
jbe@0
|
1287 -- ERRCODE = 'integrity_constraint_violation',
|
jbe@0
|
1288 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
|
jbe@0
|
1289 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
|
jbe@0
|
1290 END IF;
|
jbe@0
|
1291 RETURN NULL;
|
jbe@0
|
1292 END;
|
jbe@0
|
1293 $$;
|
jbe@0
|
1294
|
jbe@0
|
1295 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
|
jbe@0
|
1296 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
|
jbe@0
|
1297 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@0
|
1298 "issue_requires_first_initiative_trigger"();
|
jbe@0
|
1299
|
jbe@0
|
1300 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
|
jbe@0
|
1301 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
|
jbe@0
|
1302
|
jbe@0
|
1303
|
jbe@0
|
1304 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
|
jbe@0
|
1305 RETURNS TRIGGER
|
jbe@0
|
1306 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1307 DECLARE
|
jbe@0
|
1308 "reference_lost" BOOLEAN;
|
jbe@0
|
1309 BEGIN
|
jbe@0
|
1310 IF TG_OP = 'DELETE' THEN
|
jbe@0
|
1311 "reference_lost" := TRUE;
|
jbe@0
|
1312 ELSE
|
jbe@0
|
1313 "reference_lost" := NEW."issue_id" != OLD."issue_id";
|
jbe@0
|
1314 END IF;
|
jbe@0
|
1315 IF
|
jbe@0
|
1316 "reference_lost" AND NOT EXISTS (
|
jbe@0
|
1317 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
|
jbe@0
|
1318 )
|
jbe@0
|
1319 THEN
|
jbe@0
|
1320 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
|
jbe@0
|
1321 END IF;
|
jbe@0
|
1322 RETURN NULL;
|
jbe@0
|
1323 END;
|
jbe@0
|
1324 $$;
|
jbe@0
|
1325
|
jbe@0
|
1326 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
|
jbe@0
|
1327 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
|
jbe@0
|
1328 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@0
|
1329 "last_initiative_deletes_issue_trigger"();
|
jbe@0
|
1330
|
jbe@0
|
1331 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
|
jbe@0
|
1332 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
|
jbe@0
|
1333
|
jbe@0
|
1334
|
jbe@0
|
1335 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
|
jbe@0
|
1336 RETURNS TRIGGER
|
jbe@0
|
1337 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1338 BEGIN
|
jbe@0
|
1339 IF NOT EXISTS (
|
jbe@0
|
1340 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
|
jbe@0
|
1341 ) THEN
|
jbe@0
|
1342 --RAISE 'Cannot create initiative without an initial draft.' USING
|
jbe@0
|
1343 -- ERRCODE = 'integrity_constraint_violation',
|
jbe@0
|
1344 -- HINT = 'Create issue, initiative and draft within the same transaction.';
|
jbe@0
|
1345 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
|
jbe@0
|
1346 END IF;
|
jbe@0
|
1347 RETURN NULL;
|
jbe@0
|
1348 END;
|
jbe@0
|
1349 $$;
|
jbe@0
|
1350
|
jbe@0
|
1351 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
|
jbe@0
|
1352 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
|
jbe@0
|
1353 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@0
|
1354 "initiative_requires_first_draft_trigger"();
|
jbe@0
|
1355
|
jbe@0
|
1356 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
|
jbe@0
|
1357 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
|
jbe@0
|
1358
|
jbe@0
|
1359
|
jbe@0
|
1360 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
|
jbe@0
|
1361 RETURNS TRIGGER
|
jbe@0
|
1362 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1363 DECLARE
|
jbe@0
|
1364 "reference_lost" BOOLEAN;
|
jbe@0
|
1365 BEGIN
|
jbe@0
|
1366 IF TG_OP = 'DELETE' THEN
|
jbe@0
|
1367 "reference_lost" := TRUE;
|
jbe@0
|
1368 ELSE
|
jbe@0
|
1369 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
|
jbe@0
|
1370 END IF;
|
jbe@0
|
1371 IF
|
jbe@0
|
1372 "reference_lost" AND NOT EXISTS (
|
jbe@0
|
1373 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
|
jbe@0
|
1374 )
|
jbe@0
|
1375 THEN
|
jbe@0
|
1376 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
|
jbe@0
|
1377 END IF;
|
jbe@0
|
1378 RETURN NULL;
|
jbe@0
|
1379 END;
|
jbe@0
|
1380 $$;
|
jbe@0
|
1381
|
jbe@0
|
1382 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
|
jbe@0
|
1383 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
|
jbe@0
|
1384 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@0
|
1385 "last_draft_deletes_initiative_trigger"();
|
jbe@0
|
1386
|
jbe@0
|
1387 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
|
jbe@0
|
1388 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
|
jbe@0
|
1389
|
jbe@0
|
1390
|
jbe@0
|
1391 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
|
jbe@0
|
1392 RETURNS TRIGGER
|
jbe@0
|
1393 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1394 BEGIN
|
jbe@0
|
1395 IF NOT EXISTS (
|
jbe@0
|
1396 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
|
jbe@0
|
1397 ) THEN
|
jbe@0
|
1398 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
|
jbe@0
|
1399 END IF;
|
jbe@0
|
1400 RETURN NULL;
|
jbe@0
|
1401 END;
|
jbe@0
|
1402 $$;
|
jbe@0
|
1403
|
jbe@0
|
1404 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
|
jbe@0
|
1405 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
|
jbe@0
|
1406 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@0
|
1407 "suggestion_requires_first_opinion_trigger"();
|
jbe@0
|
1408
|
jbe@0
|
1409 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
|
jbe@0
|
1410 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
|
jbe@0
|
1411
|
jbe@0
|
1412
|
jbe@0
|
1413 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
|
jbe@0
|
1414 RETURNS TRIGGER
|
jbe@0
|
1415 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1416 DECLARE
|
jbe@0
|
1417 "reference_lost" BOOLEAN;
|
jbe@0
|
1418 BEGIN
|
jbe@0
|
1419 IF TG_OP = 'DELETE' THEN
|
jbe@0
|
1420 "reference_lost" := TRUE;
|
jbe@0
|
1421 ELSE
|
jbe@0
|
1422 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
|
jbe@0
|
1423 END IF;
|
jbe@0
|
1424 IF
|
jbe@0
|
1425 "reference_lost" AND NOT EXISTS (
|
jbe@0
|
1426 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
|
jbe@0
|
1427 )
|
jbe@0
|
1428 THEN
|
jbe@0
|
1429 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
|
jbe@0
|
1430 END IF;
|
jbe@0
|
1431 RETURN NULL;
|
jbe@0
|
1432 END;
|
jbe@0
|
1433 $$;
|
jbe@0
|
1434
|
jbe@0
|
1435 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
|
jbe@0
|
1436 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
|
jbe@0
|
1437 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@0
|
1438 "last_opinion_deletes_suggestion_trigger"();
|
jbe@0
|
1439
|
jbe@0
|
1440 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
|
jbe@0
|
1441 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
|
jbe@0
|
1442
|
jbe@0
|
1443
|
jbe@0
|
1444
|
jbe@20
|
1445 ---------------------------------------------------------------
|
jbe@20
|
1446 -- Ensure that votes are not modified when issues are frozen --
|
jbe@20
|
1447 ---------------------------------------------------------------
|
jbe@20
|
1448
|
jbe@20
|
1449 -- NOTE: Frontends should ensure this anyway, but in case of programming
|
jbe@20
|
1450 -- errors the following triggers ensure data integrity.
|
jbe@20
|
1451
|
jbe@20
|
1452
|
jbe@20
|
1453 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
|
jbe@20
|
1454 RETURNS TRIGGER
|
jbe@20
|
1455 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@20
|
1456 DECLARE
|
jbe@32
|
1457 "issue_id_v" "issue"."id"%TYPE;
|
jbe@32
|
1458 "issue_row" "issue"%ROWTYPE;
|
jbe@20
|
1459 BEGIN
|
jbe@32
|
1460 IF TG_OP = 'DELETE' THEN
|
jbe@32
|
1461 "issue_id_v" := OLD."issue_id";
|
jbe@32
|
1462 ELSE
|
jbe@32
|
1463 "issue_id_v" := NEW."issue_id";
|
jbe@32
|
1464 END IF;
|
jbe@20
|
1465 SELECT INTO "issue_row" * FROM "issue"
|
jbe@32
|
1466 WHERE "id" = "issue_id_v" FOR SHARE;
|
jbe@20
|
1467 IF "issue_row"."closed" NOTNULL THEN
|
jbe@20
|
1468 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
|
jbe@20
|
1469 END IF;
|
jbe@20
|
1470 RETURN NULL;
|
jbe@20
|
1471 END;
|
jbe@20
|
1472 $$;
|
jbe@20
|
1473
|
jbe@20
|
1474 CREATE TRIGGER "forbid_changes_on_closed_issue"
|
jbe@20
|
1475 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
|
jbe@20
|
1476 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@20
|
1477 "forbid_changes_on_closed_issue_trigger"();
|
jbe@20
|
1478
|
jbe@20
|
1479 CREATE TRIGGER "forbid_changes_on_closed_issue"
|
jbe@20
|
1480 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
|
jbe@20
|
1481 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@20
|
1482 "forbid_changes_on_closed_issue_trigger"();
|
jbe@20
|
1483
|
jbe@20
|
1484 CREATE TRIGGER "forbid_changes_on_closed_issue"
|
jbe@20
|
1485 AFTER INSERT OR UPDATE OR DELETE ON "vote"
|
jbe@20
|
1486 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@20
|
1487 "forbid_changes_on_closed_issue_trigger"();
|
jbe@20
|
1488
|
jbe@20
|
1489 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"';
|
jbe@20
|
1490 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';
|
jbe@20
|
1491 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';
|
jbe@20
|
1492 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';
|
jbe@20
|
1493
|
jbe@20
|
1494
|
jbe@20
|
1495
|
jbe@0
|
1496 --------------------------------------------------------------------
|
jbe@0
|
1497 -- Auto-retrieval of fields only needed for referential integrity --
|
jbe@0
|
1498 --------------------------------------------------------------------
|
jbe@0
|
1499
|
jbe@20
|
1500
|
jbe@0
|
1501 CREATE FUNCTION "autofill_issue_id_trigger"()
|
jbe@0
|
1502 RETURNS TRIGGER
|
jbe@0
|
1503 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1504 BEGIN
|
jbe@0
|
1505 IF NEW."issue_id" ISNULL THEN
|
jbe@0
|
1506 SELECT "issue_id" INTO NEW."issue_id"
|
jbe@0
|
1507 FROM "initiative" WHERE "id" = NEW."initiative_id";
|
jbe@0
|
1508 END IF;
|
jbe@0
|
1509 RETURN NEW;
|
jbe@0
|
1510 END;
|
jbe@0
|
1511 $$;
|
jbe@0
|
1512
|
jbe@0
|
1513 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
|
jbe@0
|
1514 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
|
jbe@0
|
1515
|
jbe@0
|
1516 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
|
jbe@0
|
1517 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
|
jbe@0
|
1518
|
jbe@0
|
1519 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
|
jbe@0
|
1520 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
|
jbe@0
|
1521 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
|
jbe@0
|
1522
|
jbe@0
|
1523
|
jbe@0
|
1524 CREATE FUNCTION "autofill_initiative_id_trigger"()
|
jbe@0
|
1525 RETURNS TRIGGER
|
jbe@0
|
1526 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1527 BEGIN
|
jbe@0
|
1528 IF NEW."initiative_id" ISNULL THEN
|
jbe@0
|
1529 SELECT "initiative_id" INTO NEW."initiative_id"
|
jbe@0
|
1530 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
|
jbe@0
|
1531 END IF;
|
jbe@0
|
1532 RETURN NEW;
|
jbe@0
|
1533 END;
|
jbe@0
|
1534 $$;
|
jbe@0
|
1535
|
jbe@0
|
1536 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
|
jbe@0
|
1537 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
|
jbe@0
|
1538
|
jbe@0
|
1539 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
|
jbe@0
|
1540 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
|
jbe@0
|
1541
|
jbe@0
|
1542
|
jbe@0
|
1543
|
jbe@4
|
1544 -----------------------------------------------------
|
jbe@4
|
1545 -- Automatic calculation of certain default values --
|
jbe@4
|
1546 -----------------------------------------------------
|
jbe@0
|
1547
|
jbe@22
|
1548
|
jbe@22
|
1549 CREATE FUNCTION "copy_timings_trigger"()
|
jbe@22
|
1550 RETURNS TRIGGER
|
jbe@22
|
1551 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@22
|
1552 DECLARE
|
jbe@22
|
1553 "policy_row" "policy"%ROWTYPE;
|
jbe@22
|
1554 BEGIN
|
jbe@22
|
1555 SELECT * INTO "policy_row" FROM "policy"
|
jbe@22
|
1556 WHERE "id" = NEW."policy_id";
|
jbe@22
|
1557 IF NEW."admission_time" ISNULL THEN
|
jbe@22
|
1558 NEW."admission_time" := "policy_row"."admission_time";
|
jbe@22
|
1559 END IF;
|
jbe@22
|
1560 IF NEW."discussion_time" ISNULL THEN
|
jbe@22
|
1561 NEW."discussion_time" := "policy_row"."discussion_time";
|
jbe@22
|
1562 END IF;
|
jbe@22
|
1563 IF NEW."verification_time" ISNULL THEN
|
jbe@22
|
1564 NEW."verification_time" := "policy_row"."verification_time";
|
jbe@22
|
1565 END IF;
|
jbe@22
|
1566 IF NEW."voting_time" ISNULL THEN
|
jbe@22
|
1567 NEW."voting_time" := "policy_row"."voting_time";
|
jbe@22
|
1568 END IF;
|
jbe@22
|
1569 RETURN NEW;
|
jbe@22
|
1570 END;
|
jbe@22
|
1571 $$;
|
jbe@22
|
1572
|
jbe@22
|
1573 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
|
jbe@22
|
1574 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
|
jbe@22
|
1575
|
jbe@22
|
1576 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
|
jbe@22
|
1577 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
|
jbe@22
|
1578
|
jbe@22
|
1579
|
jbe@2
|
1580 CREATE FUNCTION "supporter_default_for_draft_id_trigger"()
|
jbe@2
|
1581 RETURNS TRIGGER
|
jbe@2
|
1582 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@2
|
1583 BEGIN
|
jbe@2
|
1584 IF NEW."draft_id" ISNULL THEN
|
jbe@2
|
1585 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
|
jbe@2
|
1586 WHERE "initiative_id" = NEW."initiative_id";
|
jbe@2
|
1587 END IF;
|
jbe@2
|
1588 RETURN NEW;
|
jbe@2
|
1589 END;
|
jbe@2
|
1590 $$;
|
jbe@2
|
1591
|
jbe@2
|
1592 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
|
jbe@2
|
1593 FOR EACH ROW EXECUTE PROCEDURE "supporter_default_for_draft_id_trigger"();
|
jbe@2
|
1594
|
jbe@2
|
1595 COMMENT ON FUNCTION "supporter_default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on table "supporter"';
|
jbe@2
|
1596 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';
|
jbe@2
|
1597
|
jbe@2
|
1598
|
jbe@0
|
1599
|
jbe@0
|
1600 ----------------------------------------
|
jbe@0
|
1601 -- Automatic creation of dependencies --
|
jbe@0
|
1602 ----------------------------------------
|
jbe@0
|
1603
|
jbe@22
|
1604
|
jbe@0
|
1605 CREATE FUNCTION "autocreate_interest_trigger"()
|
jbe@0
|
1606 RETURNS TRIGGER
|
jbe@0
|
1607 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1608 BEGIN
|
jbe@0
|
1609 IF NOT EXISTS (
|
jbe@0
|
1610 SELECT NULL FROM "initiative" JOIN "interest"
|
jbe@0
|
1611 ON "initiative"."issue_id" = "interest"."issue_id"
|
jbe@0
|
1612 WHERE "initiative"."id" = NEW."initiative_id"
|
jbe@0
|
1613 AND "interest"."member_id" = NEW."member_id"
|
jbe@0
|
1614 ) THEN
|
jbe@0
|
1615 BEGIN
|
jbe@0
|
1616 INSERT INTO "interest" ("issue_id", "member_id")
|
jbe@0
|
1617 SELECT "issue_id", NEW."member_id"
|
jbe@0
|
1618 FROM "initiative" WHERE "id" = NEW."initiative_id";
|
jbe@0
|
1619 EXCEPTION WHEN unique_violation THEN END;
|
jbe@0
|
1620 END IF;
|
jbe@0
|
1621 RETURN NEW;
|
jbe@0
|
1622 END;
|
jbe@0
|
1623 $$;
|
jbe@0
|
1624
|
jbe@0
|
1625 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
|
jbe@0
|
1626 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
|
jbe@0
|
1627
|
jbe@0
|
1628 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
|
jbe@0
|
1629 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';
|
jbe@0
|
1630
|
jbe@0
|
1631
|
jbe@0
|
1632 CREATE FUNCTION "autocreate_supporter_trigger"()
|
jbe@0
|
1633 RETURNS TRIGGER
|
jbe@0
|
1634 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1635 BEGIN
|
jbe@0
|
1636 IF NOT EXISTS (
|
jbe@0
|
1637 SELECT NULL FROM "suggestion" JOIN "supporter"
|
jbe@0
|
1638 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
|
jbe@0
|
1639 WHERE "suggestion"."id" = NEW."suggestion_id"
|
jbe@0
|
1640 AND "supporter"."member_id" = NEW."member_id"
|
jbe@0
|
1641 ) THEN
|
jbe@0
|
1642 BEGIN
|
jbe@0
|
1643 INSERT INTO "supporter" ("initiative_id", "member_id")
|
jbe@0
|
1644 SELECT "initiative_id", NEW."member_id"
|
jbe@0
|
1645 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
|
jbe@0
|
1646 EXCEPTION WHEN unique_violation THEN END;
|
jbe@0
|
1647 END IF;
|
jbe@0
|
1648 RETURN NEW;
|
jbe@0
|
1649 END;
|
jbe@0
|
1650 $$;
|
jbe@0
|
1651
|
jbe@0
|
1652 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
|
jbe@0
|
1653 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
|
jbe@0
|
1654
|
jbe@0
|
1655 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
|
jbe@0
|
1656 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.';
|
jbe@0
|
1657
|
jbe@0
|
1658
|
jbe@0
|
1659
|
jbe@0
|
1660 ------------------------------------------
|
jbe@0
|
1661 -- Views and helper functions for views --
|
jbe@0
|
1662 ------------------------------------------
|
jbe@0
|
1663
|
jbe@5
|
1664
|
jbe@97
|
1665 CREATE VIEW "unit_delegation" AS
|
jbe@97
|
1666 SELECT
|
jbe@97
|
1667 "unit"."id" AS "unit_id",
|
jbe@97
|
1668 "delegation"."id",
|
jbe@97
|
1669 "delegation"."truster_id",
|
jbe@97
|
1670 "delegation"."trustee_id",
|
jbe@97
|
1671 "delegation"."scope"
|
jbe@97
|
1672 FROM "unit"
|
jbe@97
|
1673 JOIN "delegation"
|
jbe@97
|
1674 ON "delegation"."unit_id" = "unit"."id"
|
jbe@97
|
1675 JOIN "member"
|
jbe@97
|
1676 ON "delegation"."truster_id" = "member"."id"
|
jbe@97
|
1677 JOIN "privilege"
|
jbe@97
|
1678 ON "delegation"."unit_id" = "privilege"."unit_id"
|
jbe@97
|
1679 AND "delegation"."truster_id" = "privilege"."member_id"
|
jbe@97
|
1680 WHERE "member"."active" AND "privilege"."voting_right";
|
jbe@97
|
1681
|
jbe@97
|
1682 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
|
jbe@5
|
1683
|
jbe@5
|
1684
|
jbe@5
|
1685 CREATE VIEW "area_delegation" AS
|
jbe@70
|
1686 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
|
jbe@70
|
1687 "area"."id" AS "area_id",
|
jbe@70
|
1688 "delegation"."id",
|
jbe@70
|
1689 "delegation"."truster_id",
|
jbe@70
|
1690 "delegation"."trustee_id",
|
jbe@70
|
1691 "delegation"."scope"
|
jbe@97
|
1692 FROM "area"
|
jbe@97
|
1693 JOIN "delegation"
|
jbe@97
|
1694 ON "delegation"."unit_id" = "area"."unit_id"
|
jbe@97
|
1695 OR "delegation"."area_id" = "area"."id"
|
jbe@97
|
1696 JOIN "member"
|
jbe@97
|
1697 ON "delegation"."truster_id" = "member"."id"
|
jbe@97
|
1698 JOIN "privilege"
|
jbe@97
|
1699 ON "area"."unit_id" = "privilege"."unit_id"
|
jbe@97
|
1700 AND "delegation"."truster_id" = "privilege"."member_id"
|
jbe@97
|
1701 WHERE "member"."active" AND "privilege"."voting_right"
|
jbe@70
|
1702 ORDER BY
|
jbe@70
|
1703 "area"."id",
|
jbe@70
|
1704 "delegation"."truster_id",
|
jbe@70
|
1705 "delegation"."scope" DESC;
|
jbe@70
|
1706
|
jbe@97
|
1707 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
|
jbe@5
|
1708
|
jbe@5
|
1709
|
jbe@5
|
1710 CREATE VIEW "issue_delegation" AS
|
jbe@70
|
1711 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
|
jbe@70
|
1712 "issue"."id" AS "issue_id",
|
jbe@70
|
1713 "delegation"."id",
|
jbe@70
|
1714 "delegation"."truster_id",
|
jbe@70
|
1715 "delegation"."trustee_id",
|
jbe@70
|
1716 "delegation"."scope"
|
jbe@97
|
1717 FROM "issue"
|
jbe@97
|
1718 JOIN "area"
|
jbe@97
|
1719 ON "area"."id" = "issue"."area_id"
|
jbe@97
|
1720 JOIN "delegation"
|
jbe@97
|
1721 ON "delegation"."unit_id" = "area"."unit_id"
|
jbe@97
|
1722 OR "delegation"."area_id" = "area"."id"
|
jbe@97
|
1723 OR "delegation"."issue_id" = "issue"."id"
|
jbe@97
|
1724 JOIN "member"
|
jbe@97
|
1725 ON "delegation"."truster_id" = "member"."id"
|
jbe@97
|
1726 JOIN "privilege"
|
jbe@97
|
1727 ON "area"."unit_id" = "privilege"."unit_id"
|
jbe@97
|
1728 AND "delegation"."truster_id" = "privilege"."member_id"
|
jbe@97
|
1729 WHERE "member"."active" AND "privilege"."voting_right"
|
jbe@70
|
1730 ORDER BY
|
jbe@70
|
1731 "issue"."id",
|
jbe@70
|
1732 "delegation"."truster_id",
|
jbe@70
|
1733 "delegation"."scope" DESC;
|
jbe@70
|
1734
|
jbe@97
|
1735 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
|
jbe@5
|
1736
|
jbe@5
|
1737
|
jbe@5
|
1738 CREATE FUNCTION "membership_weight_with_skipping"
|
jbe@5
|
1739 ( "area_id_p" "area"."id"%TYPE,
|
jbe@5
|
1740 "member_id_p" "member"."id"%TYPE,
|
jbe@5
|
1741 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
|
jbe@5
|
1742 RETURNS INT4
|
jbe@5
|
1743 LANGUAGE 'plpgsql' STABLE AS $$
|
jbe@5
|
1744 DECLARE
|
jbe@5
|
1745 "sum_v" INT4;
|
jbe@5
|
1746 "delegation_row" "area_delegation"%ROWTYPE;
|
jbe@5
|
1747 BEGIN
|
jbe@5
|
1748 "sum_v" := 1;
|
jbe@5
|
1749 FOR "delegation_row" IN
|
jbe@5
|
1750 SELECT "area_delegation".*
|
jbe@5
|
1751 FROM "area_delegation" LEFT JOIN "membership"
|
jbe@5
|
1752 ON "membership"."area_id" = "area_id_p"
|
jbe@5
|
1753 AND "membership"."member_id" = "area_delegation"."truster_id"
|
jbe@5
|
1754 WHERE "area_delegation"."area_id" = "area_id_p"
|
jbe@5
|
1755 AND "area_delegation"."trustee_id" = "member_id_p"
|
jbe@5
|
1756 AND "membership"."member_id" ISNULL
|
jbe@5
|
1757 LOOP
|
jbe@5
|
1758 IF NOT
|
jbe@5
|
1759 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
|
jbe@5
|
1760 THEN
|
jbe@5
|
1761 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
|
jbe@5
|
1762 "area_id_p",
|
jbe@5
|
1763 "delegation_row"."truster_id",
|
jbe@5
|
1764 "skip_member_ids_p" || "delegation_row"."truster_id"
|
jbe@5
|
1765 );
|
jbe@5
|
1766 END IF;
|
jbe@5
|
1767 END LOOP;
|
jbe@5
|
1768 RETURN "sum_v";
|
jbe@5
|
1769 END;
|
jbe@5
|
1770 $$;
|
jbe@5
|
1771
|
jbe@8
|
1772 COMMENT ON FUNCTION "membership_weight_with_skipping"
|
jbe@8
|
1773 ( "area"."id"%TYPE,
|
jbe@8
|
1774 "member"."id"%TYPE,
|
jbe@8
|
1775 INT4[] )
|
jbe@8
|
1776 IS 'Helper function for "membership_weight" function';
|
jbe@8
|
1777
|
jbe@8
|
1778
|
jbe@5
|
1779 CREATE FUNCTION "membership_weight"
|
jbe@5
|
1780 ( "area_id_p" "area"."id"%TYPE,
|
jbe@5
|
1781 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
|
jbe@5
|
1782 RETURNS INT4
|
jbe@5
|
1783 LANGUAGE 'plpgsql' STABLE AS $$
|
jbe@5
|
1784 BEGIN
|
jbe@5
|
1785 RETURN "membership_weight_with_skipping"(
|
jbe@5
|
1786 "area_id_p",
|
jbe@5
|
1787 "member_id_p",
|
jbe@5
|
1788 ARRAY["member_id_p"]
|
jbe@5
|
1789 );
|
jbe@5
|
1790 END;
|
jbe@5
|
1791 $$;
|
jbe@5
|
1792
|
jbe@8
|
1793 COMMENT ON FUNCTION "membership_weight"
|
jbe@8
|
1794 ( "area"."id"%TYPE,
|
jbe@8
|
1795 "member"."id"%TYPE )
|
jbe@8
|
1796 IS 'Calculates the potential voting weight of a member in a given area';
|
jbe@8
|
1797
|
jbe@5
|
1798
|
jbe@4
|
1799 CREATE VIEW "member_count_view" AS
|
jbe@5
|
1800 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
|
jbe@4
|
1801
|
jbe@4
|
1802 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
|
jbe@4
|
1803
|
jbe@4
|
1804
|
jbe@97
|
1805 CREATE VIEW "unit_member_count" AS
|
jbe@97
|
1806 SELECT
|
jbe@97
|
1807 "unit"."id" AS "unit_id",
|
jbe@97
|
1808 sum("member"."id") AS "member_count"
|
jbe@97
|
1809 FROM "unit"
|
jbe@97
|
1810 LEFT JOIN "privilege"
|
jbe@97
|
1811 ON "privilege"."unit_id" = "unit"."id"
|
jbe@97
|
1812 AND "privilege"."voting_right"
|
jbe@97
|
1813 LEFT JOIN "member"
|
jbe@97
|
1814 ON "member"."id" = "privilege"."member_id"
|
jbe@97
|
1815 AND "member"."active"
|
jbe@97
|
1816 GROUP BY "unit"."id";
|
jbe@97
|
1817
|
jbe@97
|
1818 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
|
jbe@97
|
1819
|
jbe@97
|
1820
|
jbe@4
|
1821 CREATE VIEW "area_member_count" AS
|
jbe@5
|
1822 SELECT
|
jbe@5
|
1823 "area"."id" AS "area_id",
|
jbe@5
|
1824 count("member"."id") AS "direct_member_count",
|
jbe@5
|
1825 coalesce(
|
jbe@5
|
1826 sum(
|
jbe@5
|
1827 CASE WHEN "member"."id" NOTNULL THEN
|
jbe@5
|
1828 "membership_weight"("area"."id", "member"."id")
|
jbe@5
|
1829 ELSE 0 END
|
jbe@5
|
1830 )
|
jbe@5
|
1831 ) AS "member_weight",
|
jbe@5
|
1832 coalesce(
|
jbe@5
|
1833 sum(
|
jbe@5
|
1834 CASE WHEN "member"."id" NOTNULL AND "membership"."autoreject" THEN
|
jbe@5
|
1835 "membership_weight"("area"."id", "member"."id")
|
jbe@5
|
1836 ELSE 0 END
|
jbe@5
|
1837 )
|
jbe@5
|
1838 ) AS "autoreject_weight"
|
jbe@4
|
1839 FROM "area"
|
jbe@4
|
1840 LEFT JOIN "membership"
|
jbe@4
|
1841 ON "area"."id" = "membership"."area_id"
|
jbe@97
|
1842 LEFT JOIN "privilege"
|
jbe@97
|
1843 ON "privilege"."unit_id" = "area"."unit_id"
|
jbe@97
|
1844 AND "privilege"."member_id" = "membership"."member_id"
|
jbe@97
|
1845 AND "privilege"."voting_right"
|
jbe@4
|
1846 LEFT JOIN "member"
|
jbe@97
|
1847 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
|
jbe@4
|
1848 AND "member"."active"
|
jbe@4
|
1849 GROUP BY "area"."id";
|
jbe@4
|
1850
|
jbe@97
|
1851 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count", "member_weight" and "autoreject_weight" columns of table "area"';
|
jbe@4
|
1852
|
jbe@4
|
1853
|
jbe@9
|
1854 CREATE VIEW "opening_draft" AS
|
jbe@9
|
1855 SELECT "draft".* FROM (
|
jbe@9
|
1856 SELECT
|
jbe@9
|
1857 "initiative"."id" AS "initiative_id",
|
jbe@9
|
1858 min("draft"."id") AS "draft_id"
|
jbe@9
|
1859 FROM "initiative" JOIN "draft"
|
jbe@9
|
1860 ON "initiative"."id" = "draft"."initiative_id"
|
jbe@9
|
1861 GROUP BY "initiative"."id"
|
jbe@9
|
1862 ) AS "subquery"
|
jbe@9
|
1863 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
|
jbe@9
|
1864
|
jbe@9
|
1865 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
|
jbe@9
|
1866
|
jbe@9
|
1867
|
jbe@0
|
1868 CREATE VIEW "current_draft" AS
|
jbe@0
|
1869 SELECT "draft".* FROM (
|
jbe@0
|
1870 SELECT
|
jbe@0
|
1871 "initiative"."id" AS "initiative_id",
|
jbe@0
|
1872 max("draft"."id") AS "draft_id"
|
jbe@0
|
1873 FROM "initiative" JOIN "draft"
|
jbe@0
|
1874 ON "initiative"."id" = "draft"."initiative_id"
|
jbe@0
|
1875 GROUP BY "initiative"."id"
|
jbe@0
|
1876 ) AS "subquery"
|
jbe@0
|
1877 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
|
jbe@0
|
1878
|
jbe@0
|
1879 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
|
jbe@0
|
1880
|
jbe@0
|
1881
|
jbe@0
|
1882 CREATE VIEW "critical_opinion" AS
|
jbe@0
|
1883 SELECT * FROM "opinion"
|
jbe@0
|
1884 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
|
jbe@0
|
1885 OR ("degree" = -2 AND "fulfilled" = TRUE);
|
jbe@0
|
1886
|
jbe@0
|
1887 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
|
jbe@0
|
1888
|
jbe@0
|
1889
|
jbe@126
|
1890 CREATE VIEW "battle_participant" AS
|
jbe@126
|
1891 SELECT "initiative"."id", "initiative"."issue_id"
|
jbe@126
|
1892 FROM "issue" JOIN "initiative"
|
jbe@126
|
1893 ON "issue"."id" = "initiative"."issue_id"
|
jbe@126
|
1894 WHERE "initiative"."admitted"
|
jbe@126
|
1895 UNION ALL
|
jbe@126
|
1896 SELECT NULL, "id" AS "issue_id"
|
jbe@126
|
1897 FROM "issue";
|
jbe@126
|
1898
|
jbe@126
|
1899 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
|
jbe@126
|
1900
|
jbe@126
|
1901
|
jbe@61
|
1902 CREATE VIEW "battle_view" AS
|
jbe@0
|
1903 SELECT
|
jbe@0
|
1904 "issue"."id" AS "issue_id",
|
jbe@10
|
1905 "winning_initiative"."id" AS "winning_initiative_id",
|
jbe@10
|
1906 "losing_initiative"."id" AS "losing_initiative_id",
|
jbe@0
|
1907 sum(
|
jbe@0
|
1908 CASE WHEN
|
jbe@0
|
1909 coalesce("better_vote"."grade", 0) >
|
jbe@0
|
1910 coalesce("worse_vote"."grade", 0)
|
jbe@0
|
1911 THEN "direct_voter"."weight" ELSE 0 END
|
jbe@0
|
1912 ) AS "count"
|
jbe@0
|
1913 FROM "issue"
|
jbe@0
|
1914 LEFT JOIN "direct_voter"
|
jbe@0
|
1915 ON "issue"."id" = "direct_voter"."issue_id"
|
jbe@126
|
1916 JOIN "battle_participant" AS "winning_initiative"
|
jbe@10
|
1917 ON "issue"."id" = "winning_initiative"."issue_id"
|
jbe@126
|
1918 JOIN "battle_participant" AS "losing_initiative"
|
jbe@10
|
1919 ON "issue"."id" = "losing_initiative"."issue_id"
|
jbe@0
|
1920 LEFT JOIN "vote" AS "better_vote"
|
jbe@10
|
1921 ON "direct_voter"."member_id" = "better_vote"."member_id"
|
jbe@10
|
1922 AND "winning_initiative"."id" = "better_vote"."initiative_id"
|
jbe@0
|
1923 LEFT JOIN "vote" AS "worse_vote"
|
jbe@10
|
1924 ON "direct_voter"."member_id" = "worse_vote"."member_id"
|
jbe@10
|
1925 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
|
jbe@61
|
1926 WHERE "issue"."closed" NOTNULL
|
jbe@61
|
1927 AND "issue"."cleaned" ISNULL
|
jbe@126
|
1928 AND (
|
jbe@126
|
1929 "winning_initiative"."id" != "losing_initiative"."id" OR
|
jbe@126
|
1930 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
|
jbe@126
|
1931 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
|
jbe@0
|
1932 GROUP BY
|
jbe@0
|
1933 "issue"."id",
|
jbe@10
|
1934 "winning_initiative"."id",
|
jbe@10
|
1935 "losing_initiative"."id";
|
jbe@0
|
1936
|
jbe@126
|
1937 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';
|
jbe@0
|
1938
|
jbe@0
|
1939
|
jbe@1
|
1940 CREATE VIEW "expired_session" AS
|
jbe@1
|
1941 SELECT * FROM "session" WHERE now() > "expiry";
|
jbe@1
|
1942
|
jbe@1
|
1943 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
|
jbe@1
|
1944 DELETE FROM "session" WHERE "ident" = OLD."ident";
|
jbe@1
|
1945
|
jbe@1
|
1946 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
|
jbe@1
|
1947 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
|
jbe@1
|
1948
|
jbe@1
|
1949
|
jbe@0
|
1950 CREATE VIEW "open_issue" AS
|
jbe@0
|
1951 SELECT * FROM "issue" WHERE "closed" ISNULL;
|
jbe@0
|
1952
|
jbe@0
|
1953 COMMENT ON VIEW "open_issue" IS 'All open issues';
|
jbe@0
|
1954
|
jbe@0
|
1955
|
jbe@0
|
1956 CREATE VIEW "issue_with_ranks_missing" AS
|
jbe@0
|
1957 SELECT * FROM "issue"
|
jbe@3
|
1958 WHERE "fully_frozen" NOTNULL
|
jbe@0
|
1959 AND "closed" NOTNULL
|
jbe@0
|
1960 AND "ranks_available" = FALSE;
|
jbe@0
|
1961
|
jbe@0
|
1962 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
|
jbe@0
|
1963
|
jbe@0
|
1964
|
jbe@9
|
1965 CREATE VIEW "member_contingent" AS
|
jbe@9
|
1966 SELECT
|
jbe@9
|
1967 "member"."id" AS "member_id",
|
jbe@9
|
1968 "contingent"."time_frame",
|
jbe@9
|
1969 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
|
jbe@9
|
1970 (
|
jbe@9
|
1971 SELECT count(1) FROM "draft"
|
jbe@9
|
1972 WHERE "draft"."author_id" = "member"."id"
|
jbe@9
|
1973 AND "draft"."created" > now() - "contingent"."time_frame"
|
jbe@9
|
1974 ) + (
|
jbe@9
|
1975 SELECT count(1) FROM "suggestion"
|
jbe@9
|
1976 WHERE "suggestion"."author_id" = "member"."id"
|
jbe@9
|
1977 AND "suggestion"."created" > now() - "contingent"."time_frame"
|
jbe@9
|
1978 )
|
jbe@9
|
1979 ELSE NULL END AS "text_entry_count",
|
jbe@9
|
1980 "contingent"."text_entry_limit",
|
jbe@9
|
1981 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
|
jbe@9
|
1982 SELECT count(1) FROM "opening_draft"
|
jbe@9
|
1983 WHERE "opening_draft"."author_id" = "member"."id"
|
jbe@9
|
1984 AND "opening_draft"."created" > now() - "contingent"."time_frame"
|
jbe@9
|
1985 ) ELSE NULL END AS "initiative_count",
|
jbe@9
|
1986 "contingent"."initiative_limit"
|
jbe@9
|
1987 FROM "member" CROSS JOIN "contingent";
|
jbe@9
|
1988
|
jbe@9
|
1989 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
|
jbe@9
|
1990
|
jbe@9
|
1991 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
|
jbe@9
|
1992 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
|
jbe@9
|
1993
|
jbe@9
|
1994
|
jbe@9
|
1995 CREATE VIEW "member_contingent_left" AS
|
jbe@9
|
1996 SELECT
|
jbe@9
|
1997 "member_id",
|
jbe@9
|
1998 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
|
jbe@9
|
1999 max("initiative_limit" - "initiative_count") AS "initiatives_left"
|
jbe@9
|
2000 FROM "member_contingent" GROUP BY "member_id";
|
jbe@9
|
2001
|
jbe@9
|
2002 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.';
|
jbe@9
|
2003
|
jbe@9
|
2004
|
jbe@113
|
2005 CREATE VIEW "event_seen_by_member" AS
|
jbe@113
|
2006 SELECT
|
jbe@113
|
2007 "member"."id" AS "seen_by_member_id",
|
jbe@113
|
2008 CASE WHEN "event"."state" IN (
|
jbe@113
|
2009 'voting',
|
jbe@113
|
2010 'finished_without_winner',
|
jbe@113
|
2011 'finished_with_winner'
|
jbe@113
|
2012 ) THEN
|
jbe@113
|
2013 'voting'::"notify_level"
|
jbe@113
|
2014 ELSE
|
jbe@113
|
2015 CASE WHEN "event"."state" IN (
|
jbe@113
|
2016 'verification',
|
jbe@113
|
2017 'canceled_after_revocation_during_verification',
|
jbe@113
|
2018 'canceled_no_initiative_admitted'
|
jbe@113
|
2019 ) THEN
|
jbe@113
|
2020 'verification'::"notify_level"
|
jbe@113
|
2021 ELSE
|
jbe@113
|
2022 CASE WHEN "event"."state" IN (
|
jbe@113
|
2023 'discussion',
|
jbe@113
|
2024 'canceled_after_revocation_during_discussion'
|
jbe@113
|
2025 ) THEN
|
jbe@113
|
2026 'discussion'::"notify_level"
|
jbe@113
|
2027 ELSE
|
jbe@113
|
2028 'all'::"notify_level"
|
jbe@113
|
2029 END
|
jbe@113
|
2030 END
|
jbe@113
|
2031 END AS "notify_level",
|
jbe@113
|
2032 "event".*
|
jbe@113
|
2033 FROM "member" CROSS JOIN "event"
|
jbe@113
|
2034 LEFT JOIN "issue"
|
jbe@113
|
2035 ON "event"."issue_id" = "issue"."id"
|
jbe@113
|
2036 LEFT JOIN "membership"
|
jbe@113
|
2037 ON "member"."id" = "membership"."member_id"
|
jbe@113
|
2038 AND "issue"."area_id" = "membership"."area_id"
|
jbe@113
|
2039 LEFT JOIN "interest"
|
jbe@113
|
2040 ON "member"."id" = "interest"."member_id"
|
jbe@113
|
2041 AND "event"."issue_id" = "interest"."issue_id"
|
jbe@113
|
2042 LEFT JOIN "supporter"
|
jbe@113
|
2043 ON "member"."id" = "supporter"."member_id"
|
jbe@113
|
2044 AND "event"."initiative_id" = "supporter"."initiative_id"
|
jbe@113
|
2045 LEFT JOIN "ignored_member"
|
jbe@113
|
2046 ON "member"."id" = "ignored_member"."member_id"
|
jbe@113
|
2047 AND "event"."member_id" = "ignored_member"."other_member_id"
|
jbe@113
|
2048 LEFT JOIN "ignored_initiative"
|
jbe@113
|
2049 ON "member"."id" = "ignored_initiative"."member_id"
|
jbe@113
|
2050 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
|
jbe@113
|
2051 WHERE (
|
jbe@113
|
2052 "supporter"."member_id" NOTNULL OR
|
jbe@113
|
2053 "interest"."member_id" NOTNULL OR
|
jbe@113
|
2054 ( "membership"."member_id" NOTNULL AND
|
jbe@113
|
2055 "event"."event" IN (
|
jbe@113
|
2056 'issue_state_changed',
|
jbe@113
|
2057 'initiative_created_in_new_issue',
|
jbe@113
|
2058 'initiative_created_in_existing_issue',
|
jbe@113
|
2059 'initiative_revoked' ) ) )
|
jbe@113
|
2060 AND "ignored_member"."member_id" ISNULL
|
jbe@113
|
2061 AND "ignored_initiative"."member_id" ISNULL;
|
jbe@113
|
2062
|
jbe@113
|
2063 COMMENT ON VIEW "event_seen_by_member" IS 'Events as seen by a member, depending on its memberships, interests and support';
|
jbe@113
|
2064
|
jbe@113
|
2065
|
jbe@113
|
2066 CREATE VIEW "pending_notification" AS
|
jbe@113
|
2067 SELECT
|
jbe@113
|
2068 "member"."id" AS "seen_by_member_id",
|
jbe@113
|
2069 "event".*
|
jbe@113
|
2070 FROM "member" CROSS JOIN "event"
|
jbe@113
|
2071 LEFT JOIN "issue"
|
jbe@113
|
2072 ON "event"."issue_id" = "issue"."id"
|
jbe@113
|
2073 LEFT JOIN "membership"
|
jbe@113
|
2074 ON "member"."id" = "membership"."member_id"
|
jbe@113
|
2075 AND "issue"."area_id" = "membership"."area_id"
|
jbe@113
|
2076 LEFT JOIN "interest"
|
jbe@113
|
2077 ON "member"."id" = "interest"."member_id"
|
jbe@113
|
2078 AND "event"."issue_id" = "interest"."issue_id"
|
jbe@113
|
2079 LEFT JOIN "supporter"
|
jbe@113
|
2080 ON "member"."id" = "supporter"."member_id"
|
jbe@113
|
2081 AND "event"."initiative_id" = "supporter"."initiative_id"
|
jbe@113
|
2082 LEFT JOIN "ignored_member"
|
jbe@113
|
2083 ON "member"."id" = "ignored_member"."member_id"
|
jbe@113
|
2084 AND "event"."member_id" = "ignored_member"."other_member_id"
|
jbe@113
|
2085 LEFT JOIN "ignored_initiative"
|
jbe@113
|
2086 ON "member"."id" = "ignored_initiative"."member_id"
|
jbe@113
|
2087 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
|
jbe@113
|
2088 WHERE (
|
jbe@113
|
2089 "member"."notify_event_id" ISNULL OR
|
jbe@113
|
2090 ( "member"."notify_event_id" NOTNULL AND
|
jbe@113
|
2091 "member"."notify_event_id" < "event"."id" ) )
|
jbe@113
|
2092 AND (
|
jbe@113
|
2093 ( "member"."notify_level" >= 'all' ) OR
|
jbe@113
|
2094 ( "member"."notify_level" >= 'voting' AND
|
jbe@113
|
2095 "event"."state" IN (
|
jbe@113
|
2096 'voting',
|
jbe@113
|
2097 'finished_without_winner',
|
jbe@113
|
2098 'finished_with_winner' ) ) OR
|
jbe@113
|
2099 ( "member"."notify_level" >= 'verification' AND
|
jbe@113
|
2100 "event"."state" IN (
|
jbe@113
|
2101 'verification',
|
jbe@113
|
2102 'canceled_after_revocation_during_verification',
|
jbe@113
|
2103 'canceled_no_initiative_admitted' ) ) OR
|
jbe@113
|
2104 ( "member"."notify_level" >= 'discussion' AND
|
jbe@113
|
2105 "event"."state" IN (
|
jbe@113
|
2106 'discussion',
|
jbe@113
|
2107 'canceled_after_revocation_during_discussion' ) ) )
|
jbe@113
|
2108 AND (
|
jbe@113
|
2109 "supporter"."member_id" NOTNULL OR
|
jbe@113
|
2110 "interest"."member_id" NOTNULL OR
|
jbe@113
|
2111 ( "membership"."member_id" NOTNULL AND
|
jbe@113
|
2112 "event"."event" IN (
|
jbe@113
|
2113 'issue_state_changed',
|
jbe@113
|
2114 'initiative_created_in_new_issue',
|
jbe@113
|
2115 'initiative_created_in_existing_issue',
|
jbe@113
|
2116 'initiative_revoked' ) ) )
|
jbe@113
|
2117 AND "ignored_member"."member_id" ISNULL
|
jbe@113
|
2118 AND "ignored_initiative"."member_id" ISNULL;
|
jbe@113
|
2119
|
jbe@113
|
2120 COMMENT ON VIEW "pending_notification" IS 'Events to be sent to "notify_email" address of member referred to by "seen_by_member_id"';
|
jbe@113
|
2121
|
jbe@113
|
2122
|
jbe@16
|
2123 CREATE TYPE "timeline_event" AS ENUM (
|
jbe@16
|
2124 'issue_created',
|
jbe@16
|
2125 'issue_canceled',
|
jbe@16
|
2126 'issue_accepted',
|
jbe@16
|
2127 'issue_half_frozen',
|
jbe@16
|
2128 'issue_finished_without_voting',
|
jbe@16
|
2129 'issue_voting_started',
|
jbe@16
|
2130 'issue_finished_after_voting',
|
jbe@16
|
2131 'initiative_created',
|
jbe@16
|
2132 'initiative_revoked',
|
jbe@16
|
2133 'draft_created',
|
jbe@16
|
2134 'suggestion_created');
|
jbe@16
|
2135
|
jbe@112
|
2136 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
|
jbe@16
|
2137
|
jbe@16
|
2138
|
jbe@16
|
2139 CREATE VIEW "timeline_issue" AS
|
jbe@16
|
2140 SELECT
|
jbe@16
|
2141 "created" AS "occurrence",
|
jbe@16
|
2142 'issue_created'::"timeline_event" AS "event",
|
jbe@16
|
2143 "id" AS "issue_id"
|
jbe@16
|
2144 FROM "issue"
|
jbe@16
|
2145 UNION ALL
|
jbe@16
|
2146 SELECT
|
jbe@16
|
2147 "closed" AS "occurrence",
|
jbe@16
|
2148 'issue_canceled'::"timeline_event" AS "event",
|
jbe@16
|
2149 "id" AS "issue_id"
|
jbe@16
|
2150 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
|
jbe@16
|
2151 UNION ALL
|
jbe@16
|
2152 SELECT
|
jbe@16
|
2153 "accepted" AS "occurrence",
|
jbe@16
|
2154 'issue_accepted'::"timeline_event" AS "event",
|
jbe@16
|
2155 "id" AS "issue_id"
|
jbe@16
|
2156 FROM "issue" WHERE "accepted" NOTNULL
|
jbe@16
|
2157 UNION ALL
|
jbe@16
|
2158 SELECT
|
jbe@16
|
2159 "half_frozen" AS "occurrence",
|
jbe@16
|
2160 'issue_half_frozen'::"timeline_event" AS "event",
|
jbe@16
|
2161 "id" AS "issue_id"
|
jbe@16
|
2162 FROM "issue" WHERE "half_frozen" NOTNULL
|
jbe@16
|
2163 UNION ALL
|
jbe@16
|
2164 SELECT
|
jbe@16
|
2165 "fully_frozen" AS "occurrence",
|
jbe@16
|
2166 'issue_voting_started'::"timeline_event" AS "event",
|
jbe@16
|
2167 "id" AS "issue_id"
|
jbe@16
|
2168 FROM "issue"
|
jbe@17
|
2169 WHERE "fully_frozen" NOTNULL
|
jbe@17
|
2170 AND ("closed" ISNULL OR "closed" != "fully_frozen")
|
jbe@16
|
2171 UNION ALL
|
jbe@16
|
2172 SELECT
|
jbe@16
|
2173 "closed" AS "occurrence",
|
jbe@16
|
2174 CASE WHEN "fully_frozen" = "closed" THEN
|
jbe@16
|
2175 'issue_finished_without_voting'::"timeline_event"
|
jbe@16
|
2176 ELSE
|
jbe@16
|
2177 'issue_finished_after_voting'::"timeline_event"
|
jbe@16
|
2178 END AS "event",
|
jbe@16
|
2179 "id" AS "issue_id"
|
jbe@16
|
2180 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
|
jbe@16
|
2181
|
jbe@112
|
2182 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
|
jbe@16
|
2183
|
jbe@16
|
2184
|
jbe@16
|
2185 CREATE VIEW "timeline_initiative" AS
|
jbe@16
|
2186 SELECT
|
jbe@16
|
2187 "created" AS "occurrence",
|
jbe@16
|
2188 'initiative_created'::"timeline_event" AS "event",
|
jbe@16
|
2189 "id" AS "initiative_id"
|
jbe@16
|
2190 FROM "initiative"
|
jbe@16
|
2191 UNION ALL
|
jbe@16
|
2192 SELECT
|
jbe@16
|
2193 "revoked" AS "occurrence",
|
jbe@16
|
2194 'initiative_revoked'::"timeline_event" AS "event",
|
jbe@16
|
2195 "id" AS "initiative_id"
|
jbe@16
|
2196 FROM "initiative" WHERE "revoked" NOTNULL;
|
jbe@16
|
2197
|
jbe@112
|
2198 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
|
jbe@16
|
2199
|
jbe@16
|
2200
|
jbe@16
|
2201 CREATE VIEW "timeline_draft" AS
|
jbe@16
|
2202 SELECT
|
jbe@16
|
2203 "created" AS "occurrence",
|
jbe@16
|
2204 'draft_created'::"timeline_event" AS "event",
|
jbe@16
|
2205 "id" AS "draft_id"
|
jbe@16
|
2206 FROM "draft";
|
jbe@16
|
2207
|
jbe@112
|
2208 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
|
jbe@16
|
2209
|
jbe@16
|
2210
|
jbe@16
|
2211 CREATE VIEW "timeline_suggestion" AS
|
jbe@16
|
2212 SELECT
|
jbe@16
|
2213 "created" AS "occurrence",
|
jbe@16
|
2214 'suggestion_created'::"timeline_event" AS "event",
|
jbe@16
|
2215 "id" AS "suggestion_id"
|
jbe@16
|
2216 FROM "suggestion";
|
jbe@16
|
2217
|
jbe@112
|
2218 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
|
jbe@16
|
2219
|
jbe@16
|
2220
|
jbe@16
|
2221 CREATE VIEW "timeline" AS
|
jbe@16
|
2222 SELECT
|
jbe@16
|
2223 "occurrence",
|
jbe@16
|
2224 "event",
|
jbe@16
|
2225 "issue_id",
|
jbe@16
|
2226 NULL AS "initiative_id",
|
jbe@16
|
2227 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
|
jbe@16
|
2228 NULL::INT8 AS "suggestion_id"
|
jbe@16
|
2229 FROM "timeline_issue"
|
jbe@16
|
2230 UNION ALL
|
jbe@16
|
2231 SELECT
|
jbe@16
|
2232 "occurrence",
|
jbe@16
|
2233 "event",
|
jbe@16
|
2234 NULL AS "issue_id",
|
jbe@16
|
2235 "initiative_id",
|
jbe@16
|
2236 NULL AS "draft_id",
|
jbe@16
|
2237 NULL AS "suggestion_id"
|
jbe@16
|
2238 FROM "timeline_initiative"
|
jbe@16
|
2239 UNION ALL
|
jbe@16
|
2240 SELECT
|
jbe@16
|
2241 "occurrence",
|
jbe@16
|
2242 "event",
|
jbe@16
|
2243 NULL AS "issue_id",
|
jbe@16
|
2244 NULL AS "initiative_id",
|
jbe@16
|
2245 "draft_id",
|
jbe@16
|
2246 NULL AS "suggestion_id"
|
jbe@16
|
2247 FROM "timeline_draft"
|
jbe@16
|
2248 UNION ALL
|
jbe@16
|
2249 SELECT
|
jbe@16
|
2250 "occurrence",
|
jbe@16
|
2251 "event",
|
jbe@16
|
2252 NULL AS "issue_id",
|
jbe@16
|
2253 NULL AS "initiative_id",
|
jbe@16
|
2254 NULL AS "draft_id",
|
jbe@16
|
2255 "suggestion_id"
|
jbe@16
|
2256 FROM "timeline_suggestion";
|
jbe@16
|
2257
|
jbe@112
|
2258 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
|
jbe@16
|
2259
|
jbe@16
|
2260
|
jbe@0
|
2261
|
jbe@5
|
2262 --------------------------------------------------
|
jbe@5
|
2263 -- Set returning function for delegation chains --
|
jbe@5
|
2264 --------------------------------------------------
|
jbe@5
|
2265
|
jbe@5
|
2266
|
jbe@5
|
2267 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
|
jbe@5
|
2268 ('first', 'intermediate', 'last', 'repetition');
|
jbe@5
|
2269
|
jbe@5
|
2270 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
|
jbe@5
|
2271
|
jbe@5
|
2272
|
jbe@5
|
2273 CREATE TYPE "delegation_chain_row" AS (
|
jbe@5
|
2274 "index" INT4,
|
jbe@5
|
2275 "member_id" INT4,
|
jbe@97
|
2276 "member_valid" BOOLEAN,
|
jbe@5
|
2277 "participation" BOOLEAN,
|
jbe@5
|
2278 "overridden" BOOLEAN,
|
jbe@5
|
2279 "scope_in" "delegation_scope",
|
jbe@5
|
2280 "scope_out" "delegation_scope",
|
jbe@86
|
2281 "disabled_out" BOOLEAN,
|
jbe@5
|
2282 "loop" "delegation_chain_loop_tag" );
|
jbe@5
|
2283
|
jbe@5
|
2284 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain"(...) functions';
|
jbe@5
|
2285
|
jbe@5
|
2286 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
|
jbe@5
|
2287 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest, for areas: membership, for global delegation chains: always null';
|
jbe@5
|
2288 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
|
jbe@5
|
2289 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
|
jbe@5
|
2290 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
|
jbe@86
|
2291 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
|
jbe@5
|
2292 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
|
jbe@5
|
2293
|
jbe@5
|
2294
|
jbe@5
|
2295 CREATE FUNCTION "delegation_chain"
|
jbe@5
|
2296 ( "member_id_p" "member"."id"%TYPE,
|
jbe@97
|
2297 "unit_id_p" "unit"."id"%TYPE,
|
jbe@5
|
2298 "area_id_p" "area"."id"%TYPE,
|
jbe@5
|
2299 "issue_id_p" "issue"."id"%TYPE,
|
jbe@5
|
2300 "simulate_trustee_id_p" "member"."id"%TYPE )
|
jbe@5
|
2301 RETURNS SETOF "delegation_chain_row"
|
jbe@5
|
2302 LANGUAGE 'plpgsql' STABLE AS $$
|
jbe@5
|
2303 DECLARE
|
jbe@97
|
2304 "scope_v" "delegation_scope";
|
jbe@97
|
2305 "unit_id_v" "unit"."id"%TYPE;
|
jbe@97
|
2306 "area_id_v" "area"."id"%TYPE;
|
jbe@5
|
2307 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
|
jbe@5
|
2308 "loop_member_id_v" "member"."id"%TYPE;
|
jbe@5
|
2309 "output_row" "delegation_chain_row";
|
jbe@5
|
2310 "output_rows" "delegation_chain_row"[];
|
jbe@5
|
2311 "delegation_row" "delegation"%ROWTYPE;
|
jbe@5
|
2312 "row_count" INT4;
|
jbe@5
|
2313 "i" INT4;
|
jbe@5
|
2314 "loop_v" BOOLEAN;
|
jbe@5
|
2315 BEGIN
|
jbe@97
|
2316 IF
|
jbe@97
|
2317 "unit_id_p" NOTNULL AND
|
jbe@97
|
2318 "area_id_p" ISNULL AND
|
jbe@97
|
2319 "issue_id_p" ISNULL
|
jbe@97
|
2320 THEN
|
jbe@97
|
2321 "scope_v" := 'unit';
|
jbe@97
|
2322 "unit_id_v" := "unit_id_p";
|
jbe@97
|
2323 ELSIF
|
jbe@97
|
2324 "unit_id_p" ISNULL AND
|
jbe@97
|
2325 "area_id_p" NOTNULL AND
|
jbe@97
|
2326 "issue_id_p" ISNULL
|
jbe@97
|
2327 THEN
|
jbe@97
|
2328 "scope_v" := 'area';
|
jbe@97
|
2329 "area_id_v" := "area_id_p";
|
jbe@97
|
2330 SELECT "unit_id" INTO "unit_id_v"
|
jbe@97
|
2331 FROM "area" WHERE "id" = "area_id_v";
|
jbe@97
|
2332 ELSIF
|
jbe@97
|
2333 "unit_id_p" ISNULL AND
|
jbe@97
|
2334 "area_id_p" ISNULL AND
|
jbe@97
|
2335 "issue_id_p" NOTNULL
|
jbe@97
|
2336 THEN
|
jbe@97
|
2337 "scope_v" := 'issue';
|
jbe@97
|
2338 SELECT "area_id" INTO "area_id_v"
|
jbe@97
|
2339 FROM "issue" WHERE "id" = "issue_id_p";
|
jbe@97
|
2340 SELECT "unit_id" INTO "unit_id_v"
|
jbe@97
|
2341 FROM "area" WHERE "id" = "area_id_v";
|
jbe@97
|
2342 ELSE
|
jbe@97
|
2343 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
|
jbe@97
|
2344 END IF;
|
jbe@5
|
2345 "visited_member_ids" := '{}';
|
jbe@5
|
2346 "loop_member_id_v" := NULL;
|
jbe@5
|
2347 "output_rows" := '{}';
|
jbe@5
|
2348 "output_row"."index" := 0;
|
jbe@5
|
2349 "output_row"."member_id" := "member_id_p";
|
jbe@97
|
2350 "output_row"."member_valid" := TRUE;
|
jbe@5
|
2351 "output_row"."participation" := FALSE;
|
jbe@5
|
2352 "output_row"."overridden" := FALSE;
|
jbe@86
|
2353 "output_row"."disabled_out" := FALSE;
|
jbe@5
|
2354 "output_row"."scope_out" := NULL;
|
jbe@5
|
2355 LOOP
|
jbe@5
|
2356 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
|
jbe@5
|
2357 "loop_member_id_v" := "output_row"."member_id";
|
jbe@5
|
2358 ELSE
|
jbe@5
|
2359 "visited_member_ids" :=
|
jbe@5
|
2360 "visited_member_ids" || "output_row"."member_id";
|
jbe@5
|
2361 END IF;
|
jbe@5
|
2362 IF "output_row"."participation" THEN
|
jbe@5
|
2363 "output_row"."overridden" := TRUE;
|
jbe@5
|
2364 END IF;
|
jbe@5
|
2365 "output_row"."scope_in" := "output_row"."scope_out";
|
jbe@5
|
2366 IF EXISTS (
|
jbe@97
|
2367 SELECT NULL FROM "member" JOIN "privilege"
|
jbe@97
|
2368 ON "privilege"."member_id" = "member"."id"
|
jbe@97
|
2369 AND "privilege"."unit_id" = "unit_id_v"
|
jbe@97
|
2370 WHERE "id" = "output_row"."member_id"
|
jbe@97
|
2371 AND "member"."active" AND "privilege"."voting_right"
|
jbe@5
|
2372 ) THEN
|
jbe@97
|
2373 IF "scope_v" = 'unit' THEN
|
jbe@5
|
2374 SELECT * INTO "delegation_row" FROM "delegation"
|
jbe@5
|
2375 WHERE "truster_id" = "output_row"."member_id"
|
jbe@97
|
2376 AND "unit_id" = "unit_id_v";
|
jbe@97
|
2377 ELSIF "scope_v" = 'area' THEN
|
jbe@5
|
2378 "output_row"."participation" := EXISTS (
|
jbe@5
|
2379 SELECT NULL FROM "membership"
|
jbe@5
|
2380 WHERE "area_id" = "area_id_p"
|
jbe@5
|
2381 AND "member_id" = "output_row"."member_id"
|
jbe@5
|
2382 );
|
jbe@5
|
2383 SELECT * INTO "delegation_row" FROM "delegation"
|
jbe@5
|
2384 WHERE "truster_id" = "output_row"."member_id"
|
jbe@97
|
2385 AND (
|
jbe@97
|
2386 "unit_id" = "unit_id_v" OR
|
jbe@97
|
2387 "area_id" = "area_id_v"
|
jbe@97
|
2388 )
|
jbe@10
|
2389 ORDER BY "scope" DESC;
|
jbe@97
|
2390 ELSIF "scope_v" = 'issue' THEN
|
jbe@5
|
2391 "output_row"."participation" := EXISTS (
|
jbe@5
|
2392 SELECT NULL FROM "interest"
|
jbe@5
|
2393 WHERE "issue_id" = "issue_id_p"
|
jbe@5
|
2394 AND "member_id" = "output_row"."member_id"
|
jbe@5
|
2395 );
|
jbe@5
|
2396 SELECT * INTO "delegation_row" FROM "delegation"
|
jbe@5
|
2397 WHERE "truster_id" = "output_row"."member_id"
|
jbe@97
|
2398 AND (
|
jbe@97
|
2399 "unit_id" = "unit_id_v" OR
|
jbe@97
|
2400 "area_id" = "area_id_v" OR
|
jbe@10
|
2401 "issue_id" = "issue_id_p"
|
jbe@10
|
2402 )
|
jbe@10
|
2403 ORDER BY "scope" DESC;
|
jbe@5
|
2404 END IF;
|
jbe@5
|
2405 ELSE
|
jbe@97
|
2406 "output_row"."member_valid" := FALSE;
|
jbe@5
|
2407 "output_row"."participation" := FALSE;
|
jbe@5
|
2408 "output_row"."scope_out" := NULL;
|
jbe@5
|
2409 "delegation_row" := ROW(NULL);
|
jbe@5
|
2410 END IF;
|
jbe@5
|
2411 IF
|
jbe@5
|
2412 "output_row"."member_id" = "member_id_p" AND
|
jbe@5
|
2413 "simulate_trustee_id_p" NOTNULL
|
jbe@5
|
2414 THEN
|
jbe@97
|
2415 "output_row"."scope_out" := "scope_v";
|
jbe@5
|
2416 "output_rows" := "output_rows" || "output_row";
|
jbe@5
|
2417 "output_row"."member_id" := "simulate_trustee_id_p";
|
jbe@5
|
2418 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
|
jbe@10
|
2419 "output_row"."scope_out" := "delegation_row"."scope";
|
jbe@5
|
2420 "output_rows" := "output_rows" || "output_row";
|
jbe@5
|
2421 "output_row"."member_id" := "delegation_row"."trustee_id";
|
jbe@86
|
2422 ELSIF "delegation_row"."scope" NOTNULL THEN
|
jbe@86
|
2423 "output_row"."scope_out" := "delegation_row"."scope";
|
jbe@86
|
2424 "output_row"."disabled_out" := TRUE;
|
jbe@86
|
2425 "output_rows" := "output_rows" || "output_row";
|
jbe@86
|
2426 EXIT;
|
jbe@5
|
2427 ELSE
|
jbe@5
|
2428 "output_row"."scope_out" := NULL;
|
jbe@5
|
2429 "output_rows" := "output_rows" || "output_row";
|
jbe@5
|
2430 EXIT;
|
jbe@5
|
2431 END IF;
|
jbe@5
|
2432 EXIT WHEN "loop_member_id_v" NOTNULL;
|
jbe@5
|
2433 "output_row"."index" := "output_row"."index" + 1;
|
jbe@5
|
2434 END LOOP;
|
jbe@5
|
2435 "row_count" := array_upper("output_rows", 1);
|
jbe@5
|
2436 "i" := 1;
|
jbe@5
|
2437 "loop_v" := FALSE;
|
jbe@5
|
2438 LOOP
|
jbe@5
|
2439 "output_row" := "output_rows"["i"];
|
jbe@98
|
2440 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
|
jbe@5
|
2441 IF "loop_v" THEN
|
jbe@5
|
2442 IF "i" + 1 = "row_count" THEN
|
jbe@5
|
2443 "output_row"."loop" := 'last';
|
jbe@5
|
2444 ELSIF "i" = "row_count" THEN
|
jbe@5
|
2445 "output_row"."loop" := 'repetition';
|
jbe@5
|
2446 ELSE
|
jbe@5
|
2447 "output_row"."loop" := 'intermediate';
|
jbe@5
|
2448 END IF;
|
jbe@5
|
2449 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
|
jbe@5
|
2450 "output_row"."loop" := 'first';
|
jbe@5
|
2451 "loop_v" := TRUE;
|
jbe@5
|
2452 END IF;
|
jbe@97
|
2453 IF "scope_v" = 'unit' THEN
|
jbe@5
|
2454 "output_row"."participation" := NULL;
|
jbe@5
|
2455 END IF;
|
jbe@5
|
2456 RETURN NEXT "output_row";
|
jbe@5
|
2457 "i" := "i" + 1;
|
jbe@5
|
2458 END LOOP;
|
jbe@5
|
2459 RETURN;
|
jbe@5
|
2460 END;
|
jbe@5
|
2461 $$;
|
jbe@5
|
2462
|
jbe@5
|
2463 COMMENT ON FUNCTION "delegation_chain"
|
jbe@5
|
2464 ( "member"."id"%TYPE,
|
jbe@97
|
2465 "unit"."id"%TYPE,
|
jbe@5
|
2466 "area"."id"%TYPE,
|
jbe@5
|
2467 "issue"."id"%TYPE,
|
jbe@5
|
2468 "member"."id"%TYPE )
|
jbe@5
|
2469 IS 'Helper function for frontends to display delegation chains; Not part of internal voting logic';
|
jbe@5
|
2470
|
jbe@97
|
2471
|
jbe@5
|
2472 CREATE FUNCTION "delegation_chain"
|
jbe@5
|
2473 ( "member_id_p" "member"."id"%TYPE,
|
jbe@97
|
2474 "unit_id_p" "unit"."id"%TYPE,
|
jbe@5
|
2475 "area_id_p" "area"."id"%TYPE,
|
jbe@5
|
2476 "issue_id_p" "issue"."id"%TYPE )
|
jbe@5
|
2477 RETURNS SETOF "delegation_chain_row"
|
jbe@5
|
2478 LANGUAGE 'plpgsql' STABLE AS $$
|
jbe@5
|
2479 DECLARE
|
jbe@5
|
2480 "result_row" "delegation_chain_row";
|
jbe@5
|
2481 BEGIN
|
jbe@5
|
2482 FOR "result_row" IN
|
jbe@5
|
2483 SELECT * FROM "delegation_chain"(
|
jbe@123
|
2484 "member_id_p", "unit_id_p", "area_id_p", "issue_id_p", NULL
|
jbe@5
|
2485 )
|
jbe@5
|
2486 LOOP
|
jbe@5
|
2487 RETURN NEXT "result_row";
|
jbe@5
|
2488 END LOOP;
|
jbe@5
|
2489 RETURN;
|
jbe@5
|
2490 END;
|
jbe@5
|
2491 $$;
|
jbe@5
|
2492
|
jbe@5
|
2493 COMMENT ON FUNCTION "delegation_chain"
|
jbe@5
|
2494 ( "member"."id"%TYPE,
|
jbe@97
|
2495 "unit"."id"%TYPE,
|
jbe@5
|
2496 "area"."id"%TYPE,
|
jbe@5
|
2497 "issue"."id"%TYPE )
|
jbe@5
|
2498 IS 'Shortcut for "delegation_chain"(...) function where 4th parameter is null';
|
jbe@5
|
2499
|
jbe@5
|
2500
|
jbe@5
|
2501
|
jbe@0
|
2502 ------------------------------
|
jbe@0
|
2503 -- Comparison by vote count --
|
jbe@0
|
2504 ------------------------------
|
jbe@0
|
2505
|
jbe@0
|
2506 CREATE FUNCTION "vote_ratio"
|
jbe@0
|
2507 ( "positive_votes_p" "initiative"."positive_votes"%TYPE,
|
jbe@0
|
2508 "negative_votes_p" "initiative"."negative_votes"%TYPE )
|
jbe@0
|
2509 RETURNS FLOAT8
|
jbe@0
|
2510 LANGUAGE 'plpgsql' STABLE AS $$
|
jbe@0
|
2511 BEGIN
|
jbe@30
|
2512 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN
|
jbe@30
|
2513 RETURN
|
jbe@30
|
2514 "positive_votes_p"::FLOAT8 /
|
jbe@30
|
2515 ("positive_votes_p" + "negative_votes_p")::FLOAT8;
|
jbe@30
|
2516 ELSIF "positive_votes_p" > 0 THEN
|
jbe@30
|
2517 RETURN "positive_votes_p";
|
jbe@30
|
2518 ELSIF "negative_votes_p" > 0 THEN
|
jbe@30
|
2519 RETURN 1 - "negative_votes_p";
|
jbe@0
|
2520 ELSE
|
jbe@0
|
2521 RETURN 0.5;
|
jbe@0
|
2522 END IF;
|
jbe@0
|
2523 END;
|
jbe@0
|
2524 $$;
|
jbe@0
|
2525
|
jbe@0
|
2526 COMMENT ON FUNCTION "vote_ratio"
|
jbe@0
|
2527 ( "initiative"."positive_votes"%TYPE,
|
jbe@0
|
2528 "initiative"."negative_votes"%TYPE )
|
jbe@30
|
2529 IS 'Returns a number, which can be used for comparison of initiatives based on count of approvals and disapprovals. Greater numbers indicate a better result. This function is NOT injective.';
|
jbe@0
|
2530
|
jbe@0
|
2531
|
jbe@0
|
2532
|
jbe@0
|
2533 ------------------------------------------------
|
jbe@0
|
2534 -- Locking for snapshots and voting procedure --
|
jbe@0
|
2535 ------------------------------------------------
|
jbe@0
|
2536
|
jbe@67
|
2537
|
jbe@67
|
2538 CREATE FUNCTION "share_row_lock_issue_trigger"()
|
jbe@67
|
2539 RETURNS TRIGGER
|
jbe@67
|
2540 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@67
|
2541 BEGIN
|
jbe@67
|
2542 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
|
jbe@67
|
2543 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
|
jbe@67
|
2544 END IF;
|
jbe@67
|
2545 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
|
jbe@67
|
2546 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
|
jbe@67
|
2547 RETURN NEW;
|
jbe@67
|
2548 ELSE
|
jbe@67
|
2549 RETURN OLD;
|
jbe@67
|
2550 END IF;
|
jbe@67
|
2551 END;
|
jbe@67
|
2552 $$;
|
jbe@67
|
2553
|
jbe@67
|
2554 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
|
jbe@67
|
2555
|
jbe@67
|
2556
|
jbe@67
|
2557 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
|
jbe@67
|
2558 RETURNS TRIGGER
|
jbe@0
|
2559 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
2560 BEGIN
|
jbe@67
|
2561 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
|
jbe@67
|
2562 PERFORM NULL FROM "issue"
|
jbe@67
|
2563 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
|
jbe@67
|
2564 WHERE "initiative"."id" = OLD."initiative_id"
|
jbe@67
|
2565 FOR SHARE OF "issue";
|
jbe@67
|
2566 END IF;
|
jbe@67
|
2567 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
|
jbe@67
|
2568 PERFORM NULL FROM "issue"
|
jbe@67
|
2569 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
|
jbe@67
|
2570 WHERE "initiative"."id" = NEW."initiative_id"
|
jbe@67
|
2571 FOR SHARE OF "issue";
|
jbe@67
|
2572 RETURN NEW;
|
jbe@67
|
2573 ELSE
|
jbe@67
|
2574 RETURN OLD;
|
jbe@67
|
2575 END IF;
|
jbe@67
|
2576 END;
|
jbe@67
|
2577 $$;
|
jbe@67
|
2578
|
jbe@67
|
2579 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
|
jbe@67
|
2580
|
jbe@67
|
2581
|
jbe@67
|
2582 CREATE TRIGGER "share_row_lock_issue"
|
jbe@67
|
2583 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
|
jbe@67
|
2584 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@67
|
2585 "share_row_lock_issue_trigger"();
|
jbe@67
|
2586
|
jbe@67
|
2587 CREATE TRIGGER "share_row_lock_issue"
|
jbe@67
|
2588 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
|
jbe@67
|
2589 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@67
|
2590 "share_row_lock_issue_trigger"();
|
jbe@67
|
2591
|
jbe@67
|
2592 CREATE TRIGGER "share_row_lock_issue"
|
jbe@67
|
2593 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
|
jbe@67
|
2594 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@67
|
2595 "share_row_lock_issue_trigger"();
|
jbe@67
|
2596
|
jbe@67
|
2597 CREATE TRIGGER "share_row_lock_issue_via_initiative"
|
jbe@67
|
2598 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
|
jbe@67
|
2599 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@67
|
2600 "share_row_lock_issue_via_initiative_trigger"();
|
jbe@67
|
2601
|
jbe@67
|
2602 CREATE TRIGGER "share_row_lock_issue"
|
jbe@67
|
2603 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
|
jbe@67
|
2604 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@67
|
2605 "share_row_lock_issue_trigger"();
|
jbe@67
|
2606
|
jbe@67
|
2607 CREATE TRIGGER "share_row_lock_issue"
|
jbe@67
|
2608 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
|
jbe@67
|
2609 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@67
|
2610 "share_row_lock_issue_trigger"();
|
jbe@67
|
2611
|
jbe@67
|
2612 CREATE TRIGGER "share_row_lock_issue"
|
jbe@67
|
2613 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
|
jbe@67
|
2614 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@67
|
2615 "share_row_lock_issue_trigger"();
|
jbe@67
|
2616
|
jbe@67
|
2617 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
|
jbe@67
|
2618 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
|
jbe@67
|
2619 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
|
jbe@67
|
2620 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
|
jbe@67
|
2621 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
|
jbe@67
|
2622 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
|
jbe@67
|
2623 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
|
jbe@67
|
2624
|
jbe@67
|
2625
|
jbe@67
|
2626 CREATE FUNCTION "lock_issue"
|
jbe@67
|
2627 ( "issue_id_p" "issue"."id"%TYPE )
|
jbe@67
|
2628 RETURNS VOID
|
jbe@67
|
2629 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@67
|
2630 BEGIN
|
jbe@67
|
2631 LOCK TABLE "member" IN SHARE MODE;
|
jbe@97
|
2632 LOCK TABLE "privilege" IN SHARE MODE;
|
jbe@67
|
2633 LOCK TABLE "membership" IN SHARE MODE;
|
jbe@67
|
2634 LOCK TABLE "policy" IN SHARE MODE;
|
jbe@67
|
2635 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
|
jbe@67
|
2636 -- NOTE: The row-level exclusive lock in combination with the
|
jbe@67
|
2637 -- share_row_lock_issue(_via_initiative)_trigger functions (which
|
jbe@67
|
2638 -- acquire a row-level share lock on the issue) ensure that no data
|
jbe@67
|
2639 -- is changed, which could affect calculation of snapshots or
|
jbe@67
|
2640 -- counting of votes. Table "delegation" must be table-level-locked,
|
jbe@67
|
2641 -- as it also contains issue- and global-scope delegations.
|
jbe@67
|
2642 LOCK TABLE "delegation" IN SHARE MODE;
|
jbe@0
|
2643 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
|
jbe@0
|
2644 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
|
jbe@0
|
2645 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
|
jbe@0
|
2646 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
|
jbe@0
|
2647 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
|
jbe@0
|
2648 RETURN;
|
jbe@0
|
2649 END;
|
jbe@0
|
2650 $$;
|
jbe@0
|
2651
|
jbe@67
|
2652 COMMENT ON FUNCTION "lock_issue"
|
jbe@67
|
2653 ( "issue"."id"%TYPE )
|
jbe@67
|
2654 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
|
jbe@0
|
2655
|
jbe@0
|
2656
|
jbe@0
|
2657
|
jbe@103
|
2658 ------------------------------------------------------------------------
|
jbe@103
|
2659 -- Regular tasks, except calculcation of snapshots and voting results --
|
jbe@103
|
2660 ------------------------------------------------------------------------
|
jbe@103
|
2661
|
jbe@104
|
2662 CREATE FUNCTION "check_last_login"()
|
jbe@103
|
2663 RETURNS VOID
|
jbe@103
|
2664 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@104
|
2665 DECLARE
|
jbe@104
|
2666 "system_setting_row" "system_setting"%ROWTYPE;
|
jbe@103
|
2667 BEGIN
|
jbe@104
|
2668 SELECT * INTO "system_setting_row" FROM "system_setting";
|
jbe@103
|
2669 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
|
jbe@103
|
2670 UPDATE "member" SET "last_login_public" = "last_login"::date
|
jbe@105
|
2671 FROM (
|
jbe@105
|
2672 SELECT DISTINCT "member"."id"
|
jbe@105
|
2673 FROM "member" LEFT JOIN "member_history"
|
jbe@105
|
2674 ON "member"."id" = "member_history"."member_id"
|
jbe@105
|
2675 WHERE "member"."last_login"::date < 'today' OR (
|
jbe@105
|
2676 "member_history"."until"::date >= 'today' AND
|
jbe@105
|
2677 "member_history"."active" = FALSE AND "member"."active" = TRUE
|
jbe@105
|
2678 )
|
jbe@105
|
2679 ) AS "subquery"
|
jbe@105
|
2680 WHERE "member"."id" = "subquery"."id";
|
jbe@104
|
2681 IF "system_setting_row"."member_ttl" NOTNULL THEN
|
jbe@104
|
2682 UPDATE "member" SET "active" = FALSE
|
jbe@104
|
2683 WHERE "active" = TRUE
|
jbe@106
|
2684 AND "last_login"::date < 'today'
|
jbe@104
|
2685 AND "last_login_public" <
|
jbe@104
|
2686 (now() - "system_setting_row"."member_ttl")::date;
|
jbe@104
|
2687 END IF;
|
jbe@103
|
2688 RETURN;
|
jbe@103
|
2689 END;
|
jbe@103
|
2690 $$;
|
jbe@103
|
2691
|
jbe@105
|
2692 COMMENT ON FUNCTION "check_last_login"() IS 'Updates "last_login_public" field, which contains the date but not the time of the last login, and deactivates members who do not login for the time specified in "system_setting"."member_ttl". For privacy reasons this function does not update "last_login_public", if the last login of a member has been today (except when member was reactivated today).';
|
jbe@103
|
2693
|
jbe@4
|
2694
|
jbe@4
|
2695 CREATE FUNCTION "calculate_member_counts"()
|
jbe@4
|
2696 RETURNS VOID
|
jbe@4
|
2697 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@4
|
2698 BEGIN
|
jbe@67
|
2699 LOCK TABLE "member" IN SHARE MODE;
|
jbe@67
|
2700 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
|
jbe@97
|
2701 LOCK TABLE "unit" IN EXCLUSIVE MODE;
|
jbe@67
|
2702 LOCK TABLE "area" IN EXCLUSIVE MODE;
|
jbe@97
|
2703 LOCK TABLE "privilege" IN SHARE MODE;
|
jbe@67
|
2704 LOCK TABLE "membership" IN SHARE MODE;
|
jbe@4
|
2705 DELETE FROM "member_count";
|
jbe@5
|
2706 INSERT INTO "member_count" ("total_count")
|
jbe@5
|
2707 SELECT "total_count" FROM "member_count_view";
|
jbe@97
|
2708 UPDATE "unit" SET "member_count" = "view"."member_count"
|
jbe@97
|
2709 FROM "unit_member_count" AS "view"
|
jbe@97
|
2710 WHERE "view"."unit_id" = "unit"."id";
|
jbe@5
|
2711 UPDATE "area" SET
|
jbe@5
|
2712 "direct_member_count" = "view"."direct_member_count",
|
jbe@5
|
2713 "member_weight" = "view"."member_weight",
|
jbe@5
|
2714 "autoreject_weight" = "view"."autoreject_weight"
|
jbe@5
|
2715 FROM "area_member_count" AS "view"
|
jbe@5
|
2716 WHERE "view"."area_id" = "area"."id";
|
jbe@4
|
2717 RETURN;
|
jbe@4
|
2718 END;
|
jbe@4
|
2719 $$;
|
jbe@4
|
2720
|
jbe@4
|
2721 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 "area_member_count"';
|
jbe@4
|
2722
|
jbe@4
|
2723
|
jbe@4
|
2724
|
jbe@0
|
2725 ------------------------------
|
jbe@0
|
2726 -- Calculation of snapshots --
|
jbe@0
|
2727 ------------------------------
|
jbe@0
|
2728
|
jbe@0
|
2729 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
|
jbe@0
|
2730 ( "issue_id_p" "issue"."id"%TYPE,
|
jbe@0
|
2731 "member_id_p" "member"."id"%TYPE,
|
jbe@0
|
2732 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
|
jbe@0
|
2733 RETURNS "direct_population_snapshot"."weight"%TYPE
|
jbe@0
|
2734 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
2735 DECLARE
|
jbe@0
|
2736 "issue_delegation_row" "issue_delegation"%ROWTYPE;
|
jbe@0
|
2737 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
|
jbe@0
|
2738 "weight_v" INT4;
|
jbe@8
|
2739 "sub_weight_v" INT4;
|
jbe@0
|
2740 BEGIN
|
jbe@0
|
2741 "weight_v" := 0;
|
jbe@0
|
2742 FOR "issue_delegation_row" IN
|
jbe@0
|
2743 SELECT * FROM "issue_delegation"
|
jbe@0
|
2744 WHERE "trustee_id" = "member_id_p"
|
jbe@0
|
2745 AND "issue_id" = "issue_id_p"
|
jbe@0
|
2746 LOOP
|
jbe@0
|
2747 IF NOT EXISTS (
|
jbe@0
|
2748 SELECT NULL FROM "direct_population_snapshot"
|
jbe@0
|
2749 WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
2750 AND "event" = 'periodic'
|
jbe@0
|
2751 AND "member_id" = "issue_delegation_row"."truster_id"
|
jbe@0
|
2752 ) AND NOT EXISTS (
|
jbe@0
|
2753 SELECT NULL FROM "delegating_population_snapshot"
|
jbe@0
|
2754 WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
2755 AND "event" = 'periodic'
|
jbe@0
|
2756 AND "member_id" = "issue_delegation_row"."truster_id"
|
jbe@0
|
2757 ) THEN
|
jbe@0
|
2758 "delegate_member_ids_v" :=
|
jbe@0
|
2759 "member_id_p" || "delegate_member_ids_p";
|
jbe@10
|
2760 INSERT INTO "delegating_population_snapshot" (
|
jbe@10
|
2761 "issue_id",
|
jbe@10
|
2762 "event",
|
jbe@10
|
2763 "member_id",
|
jbe@10
|
2764 "scope",
|
jbe@10
|
2765 "delegate_member_ids"
|
jbe@10
|
2766 ) VALUES (
|
jbe@0
|
2767 "issue_id_p",
|
jbe@0
|
2768 'periodic',
|
jbe@0
|
2769 "issue_delegation_row"."truster_id",
|
jbe@10
|
2770 "issue_delegation_row"."scope",
|
jbe@0
|
2771 "delegate_member_ids_v"
|
jbe@0
|
2772 );
|
jbe@8
|
2773 "sub_weight_v" := 1 +
|
jbe@0
|
2774 "weight_of_added_delegations_for_population_snapshot"(
|
jbe@0
|
2775 "issue_id_p",
|
jbe@0
|
2776 "issue_delegation_row"."truster_id",
|
jbe@0
|
2777 "delegate_member_ids_v"
|
jbe@0
|
2778 );
|
jbe@8
|
2779 UPDATE "delegating_population_snapshot"
|
jbe@8
|
2780 SET "weight" = "sub_weight_v"
|
jbe@8
|
2781 WHERE "issue_id" = "issue_id_p"
|
jbe@8
|
2782 AND "event" = 'periodic'
|
jbe@8
|
2783 AND "member_id" = "issue_delegation_row"."truster_id";
|
jbe@8
|
2784 "weight_v" := "weight_v" + "sub_weight_v";
|
jbe@0
|
2785 END IF;
|
jbe@0
|
2786 END LOOP;
|
jbe@0
|
2787 RETURN "weight_v";
|
jbe@0
|
2788 END;
|
jbe@0
|
2789 $$;
|
jbe@0
|
2790
|
jbe@0
|
2791 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
|
jbe@0
|
2792 ( "issue"."id"%TYPE,
|
jbe@0
|
2793 "member"."id"%TYPE,
|
jbe@0
|
2794 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
|
jbe@0
|
2795 IS 'Helper function for "create_population_snapshot" function';
|
jbe@0
|
2796
|
jbe@0
|
2797
|
jbe@0
|
2798 CREATE FUNCTION "create_population_snapshot"
|
jbe@0
|
2799 ( "issue_id_p" "issue"."id"%TYPE )
|
jbe@0
|
2800 RETURNS VOID
|
jbe@0
|
2801 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
2802 DECLARE
|
jbe@0
|
2803 "member_id_v" "member"."id"%TYPE;
|
jbe@0
|
2804 BEGIN
|
jbe@0
|
2805 DELETE FROM "direct_population_snapshot"
|
jbe@0
|
2806 WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
2807 AND "event" = 'periodic';
|
jbe@0
|
2808 DELETE FROM "delegating_population_snapshot"
|
jbe@0
|
2809 WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
2810 AND "event" = 'periodic';
|
jbe@0
|
2811 INSERT INTO "direct_population_snapshot"
|
jbe@54
|
2812 ("issue_id", "event", "member_id")
|
jbe@54
|
2813 SELECT
|
jbe@54
|
2814 "issue_id_p" AS "issue_id",
|
jbe@54
|
2815 'periodic'::"snapshot_event" AS "event",
|
jbe@54
|
2816 "member"."id" AS "member_id"
|
jbe@54
|
2817 FROM "issue"
|
jbe@54
|
2818 JOIN "area" ON "issue"."area_id" = "area"."id"
|
jbe@54
|
2819 JOIN "membership" ON "area"."id" = "membership"."area_id"
|
jbe@54
|
2820 JOIN "member" ON "membership"."member_id" = "member"."id"
|
jbe@97
|
2821 JOIN "privilege"
|
jbe@97
|
2822 ON "privilege"."unit_id" = "area"."unit_id"
|
jbe@97
|
2823 AND "privilege"."member_id" = "member"."id"
|
jbe@54
|
2824 WHERE "issue"."id" = "issue_id_p"
|
jbe@97
|
2825 AND "member"."active" AND "privilege"."voting_right"
|
jbe@54
|
2826 UNION
|
jbe@54
|
2827 SELECT
|
jbe@54
|
2828 "issue_id_p" AS "issue_id",
|
jbe@54
|
2829 'periodic'::"snapshot_event" AS "event",
|
jbe@54
|
2830 "member"."id" AS "member_id"
|
jbe@97
|
2831 FROM "issue"
|
jbe@97
|
2832 JOIN "area" ON "issue"."area_id" = "area"."id"
|
jbe@97
|
2833 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
|
jbe@97
|
2834 JOIN "member" ON "interest"."member_id" = "member"."id"
|
jbe@97
|
2835 JOIN "privilege"
|
jbe@97
|
2836 ON "privilege"."unit_id" = "area"."unit_id"
|
jbe@97
|
2837 AND "privilege"."member_id" = "member"."id"
|
jbe@97
|
2838 WHERE "issue"."id" = "issue_id_p"
|
jbe@97
|
2839 AND "member"."active" AND "privilege"."voting_right";
|
jbe@0
|
2840 FOR "member_id_v" IN
|
jbe@0
|
2841 SELECT "member_id" FROM "direct_population_snapshot"
|
jbe@0
|
2842 WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
2843 AND "event" = 'periodic'
|
jbe@0
|
2844 LOOP
|
jbe@0
|
2845 UPDATE "direct_population_snapshot" SET
|
jbe@0
|
2846 "weight" = 1 +
|
jbe@0
|
2847 "weight_of_added_delegations_for_population_snapshot"(
|
jbe@0
|
2848 "issue_id_p",
|
jbe@0
|
2849 "member_id_v",
|
jbe@0
|
2850 '{}'
|
jbe@0
|
2851 )
|
jbe@0
|
2852 WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
2853 AND "event" = 'periodic'
|
jbe@0
|
2854 AND "member_id" = "member_id_v";
|
jbe@0
|
2855 END LOOP;
|
jbe@0
|
2856 RETURN;
|
jbe@0
|
2857 END;
|
jbe@0
|
2858 $$;
|
jbe@0
|
2859
|
jbe@0
|
2860 COMMENT ON FUNCTION "create_population_snapshot"
|
jbe@67
|
2861 ( "issue"."id"%TYPE )
|
jbe@0
|
2862 IS 'This function creates a new ''periodic'' population snapshot for the given issue. It does neither lock any tables, nor updates precalculated values in other tables.';
|
jbe@0
|
2863
|
jbe@0
|
2864
|
jbe@0
|
2865 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
|
jbe@0
|
2866 ( "issue_id_p" "issue"."id"%TYPE,
|
jbe@0
|
2867 "member_id_p" "member"."id"%TYPE,
|
jbe@0
|
2868 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
|
jbe@0
|
2869 RETURNS "direct_interest_snapshot"."weight"%TYPE
|
jbe@0
|
2870 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
2871 DECLARE
|
jbe@0
|
2872 "issue_delegation_row" "issue_delegation"%ROWTYPE;
|
jbe@0
|
2873 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
|
jbe@0
|
2874 "weight_v" INT4;
|
jbe@8
|
2875 "sub_weight_v" INT4;
|
jbe@0
|
2876 BEGIN
|
jbe@0
|
2877 "weight_v" := 0;
|
jbe@0
|
2878 FOR "issue_delegation_row" IN
|
jbe@0
|
2879 SELECT * FROM "issue_delegation"
|
jbe@0
|
2880 WHERE "trustee_id" = "member_id_p"
|
jbe@0
|
2881 AND "issue_id" = "issue_id_p"
|
jbe@0
|
2882 LOOP
|
jbe@0
|
2883 IF NOT EXISTS (
|
jbe@0
|
2884 SELECT NULL FROM "direct_interest_snapshot"
|
jbe@0
|
2885 WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
2886 AND "event" = 'periodic'
|
jbe@0
|
2887 AND "member_id" = "issue_delegation_row"."truster_id"
|
jbe@0
|
2888 ) AND NOT EXISTS (
|
jbe@0
|
2889 SELECT NULL FROM "delegating_interest_snapshot"
|
jbe@0
|
2890 WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
2891 AND "event" = 'periodic'
|
jbe@0
|
2892 AND "member_id" = "issue_delegation_row"."truster_id"
|
jbe@0
|
2893 ) THEN
|
jbe@0
|
2894 "delegate_member_ids_v" :=
|
jbe@0
|
2895 "member_id_p" || "delegate_member_ids_p";
|
jbe@10
|
2896 INSERT INTO "delegating_interest_snapshot" (
|
jbe@10
|
2897 "issue_id",
|
jbe@10
|
2898 "event",
|
jbe@10
|
2899 "member_id",
|
jbe@10
|
2900 "scope",
|
jbe@10
|
2901 "delegate_member_ids"
|
jbe@10
|
2902 ) VALUES (
|
jbe@0
|
2903 "issue_id_p",
|
jbe@0
|
2904 'periodic',
|
jbe@0
|
2905 "issue_delegation_row"."truster_id",
|
jbe@10
|
2906 "issue_delegation_row"."scope",
|
jbe@0
|
2907 "delegate_member_ids_v"
|
jbe@0
|
2908 );
|
jbe@8
|
2909 "sub_weight_v" := 1 +
|
jbe@0
|
2910 "weight_of_added_delegations_for_interest_snapshot"(
|
jbe@0
|
2911 "issue_id_p",
|
jbe@0
|
2912 "issue_delegation_row"."truster_id",
|
jbe@0
|
2913 "delegate_member_ids_v"
|
jbe@0
|
2914 );
|
jbe@8
|
2915 UPDATE "delegating_interest_snapshot"
|
jbe@8
|
2916 SET "weight" = "sub_weight_v"
|
jbe@8
|
2917 WHERE "issue_id" = "issue_id_p"
|
jbe@8
|
2918 AND "event" = 'periodic'
|
jbe@8
|
2919 AND "member_id" = "issue_delegation_row"."truster_id";
|
jbe@8
|
2920 "weight_v" := "weight_v" + "sub_weight_v";
|
jbe@0
|
2921 END IF;
|
jbe@0
|
2922 END LOOP;
|
jbe@0
|
2923 RETURN "weight_v";
|
jbe@0
|
2924 END;
|
jbe@0
|
2925 $$;
|
jbe@0
|
2926
|
jbe@0
|
2927 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
|
jbe@0
|
2928 ( "issue"."id"%TYPE,
|
jbe@0
|
2929 "member"."id"%TYPE,
|
jbe@0
|
2930 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
|
jbe@0
|
2931 IS 'Helper function for "create_interest_snapshot" function';
|
jbe@0
|
2932
|
jbe@0
|
2933
|
jbe@0
|
2934 CREATE FUNCTION "create_interest_snapshot"
|
jbe@0
|
2935 ( "issue_id_p" "issue"."id"%TYPE )
|
jbe@0
|
2936 RETURNS VOID
|
jbe@0
|
2937 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
2938 DECLARE
|
jbe@0
|
2939 "member_id_v" "member"."id"%TYPE;
|
jbe@0
|
2940 BEGIN
|
jbe@0
|
2941 DELETE FROM "direct_interest_snapshot"
|
jbe@0
|
2942 WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
2943 AND "event" = 'periodic';
|
jbe@0
|
2944 DELETE FROM "delegating_interest_snapshot"
|
jbe@0
|
2945 WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
2946 AND "event" = 'periodic';
|
jbe@0
|
2947 DELETE FROM "direct_supporter_snapshot"
|
jbe@0
|
2948 WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
2949 AND "event" = 'periodic';
|
jbe@0
|
2950 INSERT INTO "direct_interest_snapshot"
|
jbe@0
|
2951 ("issue_id", "event", "member_id", "voting_requested")
|
jbe@0
|
2952 SELECT
|
jbe@0
|
2953 "issue_id_p" AS "issue_id",
|
jbe@0
|
2954 'periodic' AS "event",
|
jbe@0
|
2955 "member"."id" AS "member_id",
|
jbe@0
|
2956 "interest"."voting_requested"
|
jbe@97
|
2957 FROM "issue"
|
jbe@97
|
2958 JOIN "area" ON "issue"."area_id" = "area"."id"
|
jbe@97
|
2959 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
|
jbe@97
|
2960 JOIN "member" ON "interest"."member_id" = "member"."id"
|
jbe@97
|
2961 JOIN "privilege"
|
jbe@97
|
2962 ON "privilege"."unit_id" = "area"."unit_id"
|
jbe@97
|
2963 AND "privilege"."member_id" = "member"."id"
|
jbe@97
|
2964 WHERE "issue"."id" = "issue_id_p"
|
jbe@97
|
2965 AND "member"."active" AND "privilege"."voting_right";
|
jbe@0
|
2966 FOR "member_id_v" IN
|
jbe@0
|
2967 SELECT "member_id" FROM "direct_interest_snapshot"
|
jbe@0
|
2968 WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
2969 AND "event" = 'periodic'
|
jbe@0
|
2970 LOOP
|
jbe@0
|
2971 UPDATE "direct_interest_snapshot" SET
|
jbe@0
|
2972 "weight" = 1 +
|
jbe@0
|
2973 "weight_of_added_delegations_for_interest_snapshot"(
|
jbe@0
|
2974 "issue_id_p",
|
jbe@0
|
2975 "member_id_v",
|
jbe@0
|
2976 '{}'
|
jbe@0
|
2977 )
|
jbe@0
|
2978 WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
2979 AND "event" = 'periodic'
|
jbe@0
|
2980 AND "member_id" = "member_id_v";
|
jbe@0
|
2981 END LOOP;
|
jbe@0
|
2982 INSERT INTO "direct_supporter_snapshot"
|
jbe@0
|
2983 ( "issue_id", "initiative_id", "event", "member_id",
|
jbe@0
|
2984 "informed", "satisfied" )
|
jbe@0
|
2985 SELECT
|
jbe@96
|
2986 "issue_id_p" AS "issue_id",
|
jbe@96
|
2987 "initiative"."id" AS "initiative_id",
|
jbe@96
|
2988 'periodic' AS "event",
|
jbe@96
|
2989 "supporter"."member_id" AS "member_id",
|
jbe@0
|
2990 "supporter"."draft_id" = "current_draft"."id" AS "informed",
|
jbe@0
|
2991 NOT EXISTS (
|
jbe@0
|
2992 SELECT NULL FROM "critical_opinion"
|
jbe@0
|
2993 WHERE "initiative_id" = "initiative"."id"
|
jbe@96
|
2994 AND "member_id" = "supporter"."member_id"
|
jbe@0
|
2995 ) AS "satisfied"
|
jbe@96
|
2996 FROM "initiative"
|
jbe@96
|
2997 JOIN "supporter"
|
jbe@0
|
2998 ON "supporter"."initiative_id" = "initiative"."id"
|
jbe@0
|
2999 JOIN "current_draft"
|
jbe@0
|
3000 ON "initiative"."id" = "current_draft"."initiative_id"
|
jbe@0
|
3001 JOIN "direct_interest_snapshot"
|
jbe@96
|
3002 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
|
jbe@0
|
3003 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
|
jbe@3
|
3004 AND "event" = 'periodic'
|
jbe@96
|
3005 WHERE "initiative"."issue_id" = "issue_id_p";
|
jbe@0
|
3006 RETURN;
|
jbe@0
|
3007 END;
|
jbe@0
|
3008 $$;
|
jbe@0
|
3009
|
jbe@0
|
3010 COMMENT ON FUNCTION "create_interest_snapshot"
|
jbe@0
|
3011 ( "issue"."id"%TYPE )
|
jbe@0
|
3012 IS 'This function creates a new ''periodic'' interest/supporter snapshot for the given issue. It does neither lock any tables, nor updates precalculated values in other tables.';
|
jbe@0
|
3013
|
jbe@0
|
3014
|
jbe@0
|
3015 CREATE FUNCTION "create_snapshot"
|
jbe@0
|
3016 ( "issue_id_p" "issue"."id"%TYPE )
|
jbe@0
|
3017 RETURNS VOID
|
jbe@0
|
3018 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
3019 DECLARE
|
jbe@0
|
3020 "initiative_id_v" "initiative"."id"%TYPE;
|
jbe@0
|
3021 "suggestion_id_v" "suggestion"."id"%TYPE;
|
jbe@0
|
3022 BEGIN
|
jbe@67
|
3023 PERFORM "lock_issue"("issue_id_p");
|
jbe@0
|
3024 PERFORM "create_population_snapshot"("issue_id_p");
|
jbe@0
|
3025 PERFORM "create_interest_snapshot"("issue_id_p");
|
jbe@0
|
3026 UPDATE "issue" SET
|
jbe@8
|
3027 "snapshot" = now(),
|
jbe@8
|
3028 "latest_snapshot_event" = 'periodic',
|
jbe@0
|
3029 "population" = (
|
jbe@0
|
3030 SELECT coalesce(sum("weight"), 0)
|
jbe@0
|
3031 FROM "direct_population_snapshot"
|
jbe@0
|
3032 WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
3033 AND "event" = 'periodic'
|
jbe@0
|
3034 ),
|
jbe@8
|
3035 "vote_now" = (
|
jbe@0
|
3036 SELECT coalesce(sum("weight"), 0)
|
jbe@0
|
3037 FROM "direct_interest_snapshot"
|
jbe@0
|
3038 WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
3039 AND "event" = 'periodic'
|
jbe@0
|
3040 AND "voting_requested" = TRUE
|
jbe@0
|
3041 ),
|
jbe@0
|
3042 "vote_later" = (
|
jbe@0
|
3043 SELECT coalesce(sum("weight"), 0)
|
jbe@0
|
3044 FROM "direct_interest_snapshot"
|
jbe@0
|
3045 WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
3046 AND "event" = 'periodic'
|
jbe@0
|
3047 AND "voting_requested" = FALSE
|
jbe@0
|
3048 )
|
jbe@0
|
3049 WHERE "id" = "issue_id_p";
|
jbe@0
|
3050 FOR "initiative_id_v" IN
|
jbe@0
|
3051 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
3052 LOOP
|
jbe@0
|
3053 UPDATE "initiative" SET
|
jbe@0
|
3054 "supporter_count" = (
|
jbe@0
|
3055 SELECT coalesce(sum("di"."weight"), 0)
|
jbe@0
|
3056 FROM "direct_interest_snapshot" AS "di"
|
jbe@0
|
3057 JOIN "direct_supporter_snapshot" AS "ds"
|
jbe@0
|
3058 ON "di"."member_id" = "ds"."member_id"
|
jbe@0
|
3059 WHERE "di"."issue_id" = "issue_id_p"
|
jbe@0
|
3060 AND "di"."event" = 'periodic'
|
jbe@0
|
3061 AND "ds"."initiative_id" = "initiative_id_v"
|
jbe@0
|
3062 AND "ds"."event" = 'periodic'
|
jbe@0
|
3063 ),
|
jbe@0
|
3064 "informed_supporter_count" = (
|
jbe@0
|
3065 SELECT coalesce(sum("di"."weight"), 0)
|
jbe@0
|
3066 FROM "direct_interest_snapshot" AS "di"
|
jbe@0
|
3067 JOIN "direct_supporter_snapshot" AS "ds"
|
jbe@0
|
3068 ON "di"."member_id" = "ds"."member_id"
|
jbe@0
|
3069 WHERE "di"."issue_id" = "issue_id_p"
|
jbe@0
|
3070 AND "di"."event" = 'periodic'
|
jbe@0
|
3071 AND "ds"."initiative_id" = "initiative_id_v"
|
jbe@0
|
3072 AND "ds"."event" = 'periodic'
|
jbe@0
|
3073 AND "ds"."informed"
|
jbe@0
|
3074 ),
|
jbe@0
|
3075 "satisfied_supporter_count" = (
|
jbe@0
|
3076 SELECT coalesce(sum("di"."weight"), 0)
|
jbe@0
|
3077 FROM "direct_interest_snapshot" AS "di"
|
jbe@0
|
3078 JOIN "direct_supporter_snapshot" AS "ds"
|
jbe@0
|
3079 ON "di"."member_id" = "ds"."member_id"
|
jbe@0
|
3080 WHERE "di"."issue_id" = "issue_id_p"
|
jbe@0
|
3081 AND "di"."event" = 'periodic'
|
jbe@0
|
3082 AND "ds"."initiative_id" = "initiative_id_v"
|
jbe@0
|
3083 AND "ds"."event" = 'periodic'
|
jbe@0
|
3084 AND "ds"."satisfied"
|
jbe@0
|
3085 ),
|
jbe@0
|
3086 "satisfied_informed_supporter_count" = (
|
jbe@0
|
3087 SELECT coalesce(sum("di"."weight"), 0)
|
jbe@0
|
3088 FROM "direct_interest_snapshot" AS "di"
|
jbe@0
|
3089 JOIN "direct_supporter_snapshot" AS "ds"
|
jbe@0
|
3090 ON "di"."member_id" = "ds"."member_id"
|
jbe@0
|
3091 WHERE "di"."issue_id" = "issue_id_p"
|
jbe@0
|
3092 AND "di"."event" = 'periodic'
|
jbe@0
|
3093 AND "ds"."initiative_id" = "initiative_id_v"
|
jbe@0
|
3094 AND "ds"."event" = 'periodic'
|
jbe@0
|
3095 AND "ds"."informed"
|
jbe@0
|
3096 AND "ds"."satisfied"
|
jbe@0
|
3097 )
|
jbe@0
|
3098 WHERE "id" = "initiative_id_v";
|
jbe@0
|
3099 FOR "suggestion_id_v" IN
|
jbe@0
|
3100 SELECT "id" FROM "suggestion"
|
jbe@0
|
3101 WHERE "initiative_id" = "initiative_id_v"
|
jbe@0
|
3102 LOOP
|
jbe@0
|
3103 UPDATE "suggestion" SET
|
jbe@0
|
3104 "minus2_unfulfilled_count" = (
|
jbe@0
|
3105 SELECT coalesce(sum("snapshot"."weight"), 0)
|
jbe@36
|
3106 FROM "issue" CROSS JOIN "opinion"
|
jbe@36
|
3107 JOIN "direct_interest_snapshot" AS "snapshot"
|
jbe@36
|
3108 ON "snapshot"."issue_id" = "issue"."id"
|
jbe@36
|
3109 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
jbe@36
|
3110 AND "snapshot"."member_id" = "opinion"."member_id"
|
jbe@36
|
3111 WHERE "issue"."id" = "issue_id_p"
|
jbe@36
|
3112 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
jbe@0
|
3113 AND "opinion"."degree" = -2
|
jbe@0
|
3114 AND "opinion"."fulfilled" = FALSE
|
jbe@0
|
3115 ),
|
jbe@0
|
3116 "minus2_fulfilled_count" = (
|
jbe@0
|
3117 SELECT coalesce(sum("snapshot"."weight"), 0)
|
jbe@36
|
3118 FROM "issue" CROSS JOIN "opinion"
|
jbe@36
|
3119 JOIN "direct_interest_snapshot" AS "snapshot"
|
jbe@36
|
3120 ON "snapshot"."issue_id" = "issue"."id"
|
jbe@36
|
3121 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
jbe@36
|
3122 AND "snapshot"."member_id" = "opinion"."member_id"
|
jbe@36
|
3123 WHERE "issue"."id" = "issue_id_p"
|
jbe@36
|
3124 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
jbe@0
|
3125 AND "opinion"."degree" = -2
|
jbe@0
|
3126 AND "opinion"."fulfilled" = TRUE
|
jbe@0
|
3127 ),
|
jbe@0
|
3128 "minus1_unfulfilled_count" = (
|
jbe@0
|
3129 SELECT coalesce(sum("snapshot"."weight"), 0)
|
jbe@36
|
3130 FROM "issue" CROSS JOIN "opinion"
|
jbe@36
|
3131 JOIN "direct_interest_snapshot" AS "snapshot"
|
jbe@36
|
3132 ON "snapshot"."issue_id" = "issue"."id"
|
jbe@36
|
3133 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
jbe@36
|
3134 AND "snapshot"."member_id" = "opinion"."member_id"
|
jbe@36
|
3135 WHERE "issue"."id" = "issue_id_p"
|
jbe@36
|
3136 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
jbe@0
|
3137 AND "opinion"."degree" = -1
|
jbe@0
|
3138 AND "opinion"."fulfilled" = FALSE
|
jbe@0
|
3139 ),
|
jbe@0
|
3140 "minus1_fulfilled_count" = (
|
jbe@0
|
3141 SELECT coalesce(sum("snapshot"."weight"), 0)
|
jbe@36
|
3142 FROM "issue" CROSS JOIN "opinion"
|
jbe@36
|
3143 JOIN "direct_interest_snapshot" AS "snapshot"
|
jbe@36
|
3144 ON "snapshot"."issue_id" = "issue"."id"
|
jbe@36
|
3145 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
jbe@36
|
3146 AND "snapshot"."member_id" = "opinion"."member_id"
|
jbe@36
|
3147 WHERE "issue"."id" = "issue_id_p"
|
jbe@36
|
3148 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
jbe@0
|
3149 AND "opinion"."degree" = -1
|
jbe@0
|
3150 AND "opinion"."fulfilled" = TRUE
|
jbe@0
|
3151 ),
|
jbe@0
|
3152 "plus1_unfulfilled_count" = (
|
jbe@0
|
3153 SELECT coalesce(sum("snapshot"."weight"), 0)
|
jbe@36
|
3154 FROM "issue" CROSS JOIN "opinion"
|
jbe@36
|
3155 JOIN "direct_interest_snapshot" AS "snapshot"
|
jbe@36
|
3156 ON "snapshot"."issue_id" = "issue"."id"
|
jbe@36
|
3157 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
jbe@36
|
3158 AND "snapshot"."member_id" = "opinion"."member_id"
|
jbe@36
|
3159 WHERE "issue"."id" = "issue_id_p"
|
jbe@36
|
3160 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
jbe@0
|
3161 AND "opinion"."degree" = 1
|
jbe@0
|
3162 AND "opinion"."fulfilled" = FALSE
|
jbe@0
|
3163 ),
|
jbe@0
|
3164 "plus1_fulfilled_count" = (
|
jbe@0
|
3165 SELECT coalesce(sum("snapshot"."weight"), 0)
|
jbe@36
|
3166 FROM "issue" CROSS JOIN "opinion"
|
jbe@36
|
3167 JOIN "direct_interest_snapshot" AS "snapshot"
|
jbe@36
|
3168 ON "snapshot"."issue_id" = "issue"."id"
|
jbe@36
|
3169 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
jbe@36
|
3170 AND "snapshot"."member_id" = "opinion"."member_id"
|
jbe@36
|
3171 WHERE "issue"."id" = "issue_id_p"
|
jbe@36
|
3172 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
jbe@0
|
3173 AND "opinion"."degree" = 1
|
jbe@0
|
3174 AND "opinion"."fulfilled" = TRUE
|
jbe@0
|
3175 ),
|
jbe@0
|
3176 "plus2_unfulfilled_count" = (
|
jbe@0
|
3177 SELECT coalesce(sum("snapshot"."weight"), 0)
|
jbe@36
|
3178 FROM "issue" CROSS JOIN "opinion"
|
jbe@36
|
3179 JOIN "direct_interest_snapshot" AS "snapshot"
|
jbe@36
|
3180 ON "snapshot"."issue_id" = "issue"."id"
|
jbe@36
|
3181 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
jbe@36
|
3182 AND "snapshot"."member_id" = "opinion"."member_id"
|
jbe@36
|
3183 WHERE "issue"."id" = "issue_id_p"
|
jbe@36
|
3184 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
jbe@0
|
3185 AND "opinion"."degree" = 2
|
jbe@0
|
3186 AND "opinion"."fulfilled" = FALSE
|
jbe@0
|
3187 ),
|
jbe@0
|
3188 "plus2_fulfilled_count" = (
|
jbe@0
|
3189 SELECT coalesce(sum("snapshot"."weight"), 0)
|
jbe@36
|
3190 FROM "issue" CROSS JOIN "opinion"
|
jbe@36
|
3191 JOIN "direct_interest_snapshot" AS "snapshot"
|
jbe@36
|
3192 ON "snapshot"."issue_id" = "issue"."id"
|
jbe@36
|
3193 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
jbe@36
|
3194 AND "snapshot"."member_id" = "opinion"."member_id"
|
jbe@36
|
3195 WHERE "issue"."id" = "issue_id_p"
|
jbe@36
|
3196 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
jbe@0
|
3197 AND "opinion"."degree" = 2
|
jbe@0
|
3198 AND "opinion"."fulfilled" = TRUE
|
jbe@0
|
3199 )
|
jbe@0
|
3200 WHERE "suggestion"."id" = "suggestion_id_v";
|
jbe@0
|
3201 END LOOP;
|
jbe@0
|
3202 END LOOP;
|
jbe@0
|
3203 RETURN;
|
jbe@0
|
3204 END;
|
jbe@0
|
3205 $$;
|
jbe@0
|
3206
|
jbe@0
|
3207 COMMENT ON FUNCTION "create_snapshot"
|
jbe@0
|
3208 ( "issue"."id"%TYPE )
|
jbe@0
|
3209 IS 'This function creates a complete new ''periodic'' snapshot of population, interest and support for the given issue. All involved tables are locked, and after completion precalculated values in the source tables are updated.';
|
jbe@0
|
3210
|
jbe@0
|
3211
|
jbe@0
|
3212 CREATE FUNCTION "set_snapshot_event"
|
jbe@0
|
3213 ( "issue_id_p" "issue"."id"%TYPE,
|
jbe@0
|
3214 "event_p" "snapshot_event" )
|
jbe@0
|
3215 RETURNS VOID
|
jbe@0
|
3216 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@21
|
3217 DECLARE
|
jbe@21
|
3218 "event_v" "issue"."latest_snapshot_event"%TYPE;
|
jbe@0
|
3219 BEGIN
|
jbe@21
|
3220 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
|
jbe@21
|
3221 WHERE "id" = "issue_id_p" FOR UPDATE;
|
jbe@8
|
3222 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
|
jbe@8
|
3223 WHERE "id" = "issue_id_p";
|
jbe@3
|
3224 UPDATE "direct_population_snapshot" SET "event" = "event_p"
|
jbe@21
|
3225 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
|
jbe@3
|
3226 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
|
jbe@21
|
3227 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
|
jbe@3
|
3228 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
|
jbe@21
|
3229 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
|
jbe@3
|
3230 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
|
jbe@21
|
3231 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
|
jbe@3
|
3232 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
|
jbe@21
|
3233 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
|
jbe@0
|
3234 RETURN;
|
jbe@0
|
3235 END;
|
jbe@0
|
3236 $$;
|
jbe@0
|
3237
|
jbe@0
|
3238 COMMENT ON FUNCTION "set_snapshot_event"
|
jbe@0
|
3239 ( "issue"."id"%TYPE,
|
jbe@0
|
3240 "snapshot_event" )
|
jbe@0
|
3241 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
|
jbe@0
|
3242
|
jbe@0
|
3243
|
jbe@0
|
3244
|
jbe@0
|
3245 ---------------------
|
jbe@0
|
3246 -- Freezing issues --
|
jbe@0
|
3247 ---------------------
|
jbe@0
|
3248
|
jbe@0
|
3249 CREATE FUNCTION "freeze_after_snapshot"
|
jbe@0
|
3250 ( "issue_id_p" "issue"."id"%TYPE )
|
jbe@0
|
3251 RETURNS VOID
|
jbe@0
|
3252 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
3253 DECLARE
|
jbe@0
|
3254 "issue_row" "issue"%ROWTYPE;
|
jbe@0
|
3255 "policy_row" "policy"%ROWTYPE;
|
jbe@0
|
3256 "initiative_row" "initiative"%ROWTYPE;
|
jbe@0
|
3257 BEGIN
|
jbe@0
|
3258 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
|
jbe@0
|
3259 SELECT * INTO "policy_row"
|
jbe@0
|
3260 FROM "policy" WHERE "id" = "issue_row"."policy_id";
|
jbe@21
|
3261 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
|
jbe@0
|
3262 FOR "initiative_row" IN
|
jbe@15
|
3263 SELECT * FROM "initiative"
|
jbe@15
|
3264 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
|
jbe@0
|
3265 LOOP
|
jbe@0
|
3266 IF
|
jbe@0
|
3267 "initiative_row"."satisfied_supporter_count" > 0 AND
|
jbe@0
|
3268 "initiative_row"."satisfied_supporter_count" *
|
jbe@0
|
3269 "policy_row"."initiative_quorum_den" >=
|
jbe@0
|
3270 "issue_row"."population" * "policy_row"."initiative_quorum_num"
|
jbe@0
|
3271 THEN
|
jbe@0
|
3272 UPDATE "initiative" SET "admitted" = TRUE
|
jbe@0
|
3273 WHERE "id" = "initiative_row"."id";
|
jbe@0
|
3274 ELSE
|
jbe@0
|
3275 UPDATE "initiative" SET "admitted" = FALSE
|
jbe@0
|
3276 WHERE "id" = "initiative_row"."id";
|
jbe@0
|
3277 END IF;
|
jbe@0
|
3278 END LOOP;
|
jbe@113
|
3279 IF EXISTS (
|
jbe@9
|
3280 SELECT NULL FROM "initiative"
|
jbe@9
|
3281 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
|
jbe@9
|
3282 ) THEN
|
jbe@113
|
3283 UPDATE "issue" SET
|
jbe@113
|
3284 "state" = 'voting',
|
jbe@113
|
3285 "accepted" = coalesce("accepted", now()),
|
jbe@113
|
3286 "half_frozen" = coalesce("half_frozen", now()),
|
jbe@113
|
3287 "fully_frozen" = now()
|
jbe@113
|
3288 WHERE "id" = "issue_id_p";
|
jbe@113
|
3289 ELSE
|
jbe@113
|
3290 UPDATE "issue" SET
|
jbe@121
|
3291 "state" = 'canceled_no_initiative_admitted',
|
jbe@121
|
3292 "accepted" = coalesce("accepted", now()),
|
jbe@121
|
3293 "half_frozen" = coalesce("half_frozen", now()),
|
jbe@121
|
3294 "fully_frozen" = now(),
|
jbe@121
|
3295 "closed" = now(),
|
jbe@121
|
3296 "ranks_available" = TRUE
|
jbe@113
|
3297 WHERE "id" = "issue_id_p";
|
jbe@113
|
3298 -- NOTE: The following DELETE statements have effect only when
|
jbe@113
|
3299 -- issue state has been manipulated
|
jbe@113
|
3300 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
|
jbe@113
|
3301 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
|
jbe@113
|
3302 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
|
jbe@9
|
3303 END IF;
|
jbe@0
|
3304 RETURN;
|
jbe@0
|
3305 END;
|
jbe@0
|
3306 $$;
|
jbe@0
|
3307
|
jbe@0
|
3308 COMMENT ON FUNCTION "freeze_after_snapshot"
|
jbe@0
|
3309 ( "issue"."id"%TYPE )
|
jbe@9
|
3310 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
|
jbe@0
|
3311
|
jbe@0
|
3312
|
jbe@0
|
3313 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
|
jbe@0
|
3314 RETURNS VOID
|
jbe@0
|
3315 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
3316 DECLARE
|
jbe@0
|
3317 "issue_row" "issue"%ROWTYPE;
|
jbe@0
|
3318 BEGIN
|
jbe@0
|
3319 PERFORM "create_snapshot"("issue_id_p");
|
jbe@0
|
3320 PERFORM "freeze_after_snapshot"("issue_id_p");
|
jbe@0
|
3321 RETURN;
|
jbe@0
|
3322 END;
|
jbe@0
|
3323 $$;
|
jbe@0
|
3324
|
jbe@55
|
3325 COMMENT ON FUNCTION "manual_freeze"
|
jbe@0
|
3326 ( "issue"."id"%TYPE )
|
jbe@3
|
3327 IS 'Freeze an issue manually (fully) and start voting';
|
jbe@0
|
3328
|
jbe@0
|
3329
|
jbe@0
|
3330
|
jbe@0
|
3331 -----------------------
|
jbe@0
|
3332 -- Counting of votes --
|
jbe@0
|
3333 -----------------------
|
jbe@0
|
3334
|
jbe@0
|
3335
|
jbe@5
|
3336 CREATE FUNCTION "weight_of_added_vote_delegations"
|
jbe@0
|
3337 ( "issue_id_p" "issue"."id"%TYPE,
|
jbe@0
|
3338 "member_id_p" "member"."id"%TYPE,
|
jbe@0
|
3339 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
|
jbe@0
|
3340 RETURNS "direct_voter"."weight"%TYPE
|
jbe@0
|
3341 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
3342 DECLARE
|
jbe@0
|
3343 "issue_delegation_row" "issue_delegation"%ROWTYPE;
|
jbe@0
|
3344 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
|
jbe@0
|
3345 "weight_v" INT4;
|
jbe@8
|
3346 "sub_weight_v" INT4;
|
jbe@0
|
3347 BEGIN
|
jbe@0
|
3348 "weight_v" := 0;
|
jbe@0
|
3349 FOR "issue_delegation_row" IN
|
jbe@0
|
3350 SELECT * FROM "issue_delegation"
|
jbe@0
|
3351 WHERE "trustee_id" = "member_id_p"
|
jbe@0
|
3352 AND "issue_id" = "issue_id_p"
|
jbe@0
|
3353 LOOP
|
jbe@0
|
3354 IF NOT EXISTS (
|
jbe@0
|
3355 SELECT NULL FROM "direct_voter"
|
jbe@0
|
3356 WHERE "member_id" = "issue_delegation_row"."truster_id"
|
jbe@0
|
3357 AND "issue_id" = "issue_id_p"
|
jbe@0
|
3358 ) AND NOT EXISTS (
|
jbe@0
|
3359 SELECT NULL FROM "delegating_voter"
|
jbe@0
|
3360 WHERE "member_id" = "issue_delegation_row"."truster_id"
|
jbe@0
|
3361 AND "issue_id" = "issue_id_p"
|
jbe@0
|
3362 ) THEN
|
jbe@0
|
3363 "delegate_member_ids_v" :=
|
jbe@0
|
3364 "member_id_p" || "delegate_member_ids_p";
|
jbe@10
|
3365 INSERT INTO "delegating_voter" (
|
jbe@10
|
3366 "issue_id",
|
jbe@10
|
3367 "member_id",
|
jbe@10
|
3368 "scope",
|
jbe@10
|
3369 "delegate_member_ids"
|
jbe@10
|
3370 ) VALUES (
|
jbe@5
|
3371 "issue_id_p",
|
jbe@5
|
3372 "issue_delegation_row"."truster_id",
|
jbe@10
|
3373 "issue_delegation_row"."scope",
|
jbe@5
|
3374 "delegate_member_ids_v"
|
jbe@5
|
3375 );
|
jbe@8
|
3376 "sub_weight_v" := 1 +
|
jbe@8
|
3377 "weight_of_added_vote_delegations"(
|
jbe@8
|
3378 "issue_id_p",
|
jbe@8
|
3379 "issue_delegation_row"."truster_id",
|
jbe@8
|
3380 "delegate_member_ids_v"
|
jbe@8
|
3381 );
|
jbe@8
|
3382 UPDATE "delegating_voter"
|
jbe@8
|
3383 SET "weight" = "sub_weight_v"
|
jbe@8
|
3384 WHERE "issue_id" = "issue_id_p"
|
jbe@8
|
3385 AND "member_id" = "issue_delegation_row"."truster_id";
|
jbe@8
|
3386 "weight_v" := "weight_v" + "sub_weight_v";
|
jbe@0
|
3387 END IF;
|
jbe@0
|
3388 END LOOP;
|
jbe@0
|
3389 RETURN "weight_v";
|
jbe@0
|
3390 END;
|
jbe@0
|
3391 $$;
|
jbe@0
|
3392
|
jbe@5
|
3393 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
|
jbe@0
|
3394 ( "issue"."id"%TYPE,
|
jbe@0
|
3395 "member"."id"%TYPE,
|
jbe@0
|
3396 "delegating_voter"."delegate_member_ids"%TYPE )
|
jbe@0
|
3397 IS 'Helper function for "add_vote_delegations" function';
|
jbe@0
|
3398
|
jbe@0
|
3399
|
jbe@0
|
3400 CREATE FUNCTION "add_vote_delegations"
|
jbe@0
|
3401 ( "issue_id_p" "issue"."id"%TYPE )
|
jbe@0
|
3402 RETURNS VOID
|
jbe@0
|
3403 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
3404 DECLARE
|
jbe@0
|
3405 "member_id_v" "member"."id"%TYPE;
|
jbe@0
|
3406 BEGIN
|
jbe@0
|
3407 FOR "member_id_v" IN
|
jbe@0
|
3408 SELECT "member_id" FROM "direct_voter"
|
jbe@0
|
3409 WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
3410 LOOP
|
jbe@0
|
3411 UPDATE "direct_voter" SET
|
jbe@5
|
3412 "weight" = "weight" + "weight_of_added_vote_delegations"(
|
jbe@0
|
3413 "issue_id_p",
|
jbe@0
|
3414 "member_id_v",
|
jbe@0
|
3415 '{}'
|
jbe@0
|
3416 )
|
jbe@0
|
3417 WHERE "member_id" = "member_id_v"
|
jbe@0
|
3418 AND "issue_id" = "issue_id_p";
|
jbe@0
|
3419 END LOOP;
|
jbe@0
|
3420 RETURN;
|
jbe@0
|
3421 END;
|
jbe@0
|
3422 $$;
|
jbe@0
|
3423
|
jbe@0
|
3424 COMMENT ON FUNCTION "add_vote_delegations"
|
jbe@0
|
3425 ( "issue_id_p" "issue"."id"%TYPE )
|
jbe@0
|
3426 IS 'Helper function for "close_voting" function';
|
jbe@0
|
3427
|
jbe@0
|
3428
|
jbe@0
|
3429 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
|
jbe@0
|
3430 RETURNS VOID
|
jbe@0
|
3431 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
3432 DECLARE
|
jbe@97
|
3433 "area_id_v" "area"."id"%TYPE;
|
jbe@97
|
3434 "unit_id_v" "unit"."id"%TYPE;
|
jbe@0
|
3435 "member_id_v" "member"."id"%TYPE;
|
jbe@0
|
3436 BEGIN
|
jbe@67
|
3437 PERFORM "lock_issue"("issue_id_p");
|
jbe@129
|
3438 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
|
jbe@129
|
3439 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
|
jbe@137
|
3440 -- consider delegations and auto-reject:
|
jbe@0
|
3441 DELETE FROM "delegating_voter"
|
jbe@0
|
3442 WHERE "issue_id" = "issue_id_p";
|
jbe@0
|
3443 DELETE FROM "direct_voter"
|
jbe@0
|
3444 WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
3445 AND "autoreject" = TRUE;
|
jbe@97
|
3446 DELETE FROM "direct_voter"
|
jbe@97
|
3447 USING (
|
jbe@97
|
3448 SELECT
|
jbe@97
|
3449 "direct_voter"."member_id"
|
jbe@97
|
3450 FROM "direct_voter"
|
jbe@97
|
3451 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
|
jbe@97
|
3452 LEFT JOIN "privilege"
|
jbe@97
|
3453 ON "privilege"."unit_id" = "unit_id_v"
|
jbe@97
|
3454 AND "privilege"."member_id" = "direct_voter"."member_id"
|
jbe@97
|
3455 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
|
jbe@97
|
3456 "member"."active" = FALSE OR
|
jbe@97
|
3457 "privilege"."voting_right" ISNULL OR
|
jbe@97
|
3458 "privilege"."voting_right" = FALSE
|
jbe@97
|
3459 )
|
jbe@97
|
3460 ) AS "subquery"
|
jbe@97
|
3461 WHERE "direct_voter"."issue_id" = "issue_id_p"
|
jbe@97
|
3462 AND "direct_voter"."member_id" = "subquery"."member_id";
|
jbe@0
|
3463 UPDATE "direct_voter" SET "weight" = 1
|
jbe@0
|
3464 WHERE "issue_id" = "issue_id_p";
|
jbe@0
|
3465 PERFORM "add_vote_delegations"("issue_id_p");
|
jbe@0
|
3466 FOR "member_id_v" IN
|
jbe@0
|
3467 SELECT "interest"."member_id"
|
jbe@0
|
3468 FROM "interest"
|
jbe@87
|
3469 JOIN "member"
|
jbe@87
|
3470 ON "interest"."member_id" = "member"."id"
|
jbe@0
|
3471 LEFT JOIN "direct_voter"
|
jbe@0
|
3472 ON "interest"."member_id" = "direct_voter"."member_id"
|
jbe@0
|
3473 AND "interest"."issue_id" = "direct_voter"."issue_id"
|
jbe@0
|
3474 LEFT JOIN "delegating_voter"
|
jbe@0
|
3475 ON "interest"."member_id" = "delegating_voter"."member_id"
|
jbe@0
|
3476 AND "interest"."issue_id" = "delegating_voter"."issue_id"
|
jbe@0
|
3477 WHERE "interest"."issue_id" = "issue_id_p"
|
jbe@0
|
3478 AND "interest"."autoreject" = TRUE
|
jbe@87
|
3479 AND "member"."active"
|
jbe@0
|
3480 AND "direct_voter"."member_id" ISNULL
|
jbe@0
|
3481 AND "delegating_voter"."member_id" ISNULL
|
jbe@0
|
3482 UNION SELECT "membership"."member_id"
|
jbe@0
|
3483 FROM "membership"
|
jbe@87
|
3484 JOIN "member"
|
jbe@87
|
3485 ON "membership"."member_id" = "member"."id"
|
jbe@0
|
3486 LEFT JOIN "interest"
|
jbe@0
|
3487 ON "membership"."member_id" = "interest"."member_id"
|
jbe@0
|
3488 AND "interest"."issue_id" = "issue_id_p"
|
jbe@0
|
3489 LEFT JOIN "direct_voter"
|
jbe@0
|
3490 ON "membership"."member_id" = "direct_voter"."member_id"
|
jbe@0
|
3491 AND "direct_voter"."issue_id" = "issue_id_p"
|
jbe@0
|
3492 LEFT JOIN "delegating_voter"
|
jbe@0
|
3493 ON "membership"."member_id" = "delegating_voter"."member_id"
|
jbe@0
|
3494 AND "delegating_voter"."issue_id" = "issue_id_p"
|
jbe@97
|
3495 WHERE "membership"."area_id" = "area_id_v"
|
jbe@0
|
3496 AND "membership"."autoreject" = TRUE
|
jbe@87
|
3497 AND "member"."active"
|
jbe@0
|
3498 AND "interest"."autoreject" ISNULL
|
jbe@0
|
3499 AND "direct_voter"."member_id" ISNULL
|
jbe@0
|
3500 AND "delegating_voter"."member_id" ISNULL
|
jbe@0
|
3501 LOOP
|
jbe@11
|
3502 INSERT INTO "direct_voter"
|
jbe@11
|
3503 ("member_id", "issue_id", "weight", "autoreject") VALUES
|
jbe@11
|
3504 ("member_id_v", "issue_id_p", 1, TRUE);
|
jbe@0
|
3505 INSERT INTO "vote" (
|
jbe@0
|
3506 "member_id",
|
jbe@0
|
3507 "issue_id",
|
jbe@0
|
3508 "initiative_id",
|
jbe@0
|
3509 "grade"
|
jbe@0
|
3510 ) SELECT
|
jbe@0
|
3511 "member_id_v" AS "member_id",
|
jbe@0
|
3512 "issue_id_p" AS "issue_id",
|
jbe@0
|
3513 "id" AS "initiative_id",
|
jbe@0
|
3514 -1 AS "grade"
|
jbe@0
|
3515 FROM "initiative" WHERE "issue_id" = "issue_id_p";
|
jbe@0
|
3516 END LOOP;
|
jbe@0
|
3517 PERFORM "add_vote_delegations"("issue_id_p");
|
jbe@137
|
3518 -- set voter count and mark issue as being calculated:
|
jbe@4
|
3519 UPDATE "issue" SET
|
jbe@111
|
3520 "state" = 'calculation',
|
jbe@61
|
3521 "closed" = now(),
|
jbe@4
|
3522 "voter_count" = (
|
jbe@4
|
3523 SELECT coalesce(sum("weight"), 0)
|
jbe@4
|
3524 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
|
jbe@6
|
3525 )
|
jbe@6
|
3526 WHERE "id" = "issue_id_p";
|
jbe@139
|
3527 -- calculate "positive_votes", "negative_votes" and "attainable":
|
jbe@0
|
3528 UPDATE "initiative" SET
|
jbe@10
|
3529 "positive_votes" = "vote_counts"."positive_votes",
|
jbe@10
|
3530 "negative_votes" = "vote_counts"."negative_votes",
|
jbe@128
|
3531 "attainable" = CASE WHEN "majority_strict" THEN
|
jbe@10
|
3532 "vote_counts"."positive_votes" * "majority_den" >
|
jbe@10
|
3533 "majority_num" *
|
jbe@10
|
3534 ("vote_counts"."positive_votes"+"vote_counts"."negative_votes")
|
jbe@10
|
3535 ELSE
|
jbe@10
|
3536 "vote_counts"."positive_votes" * "majority_den" >=
|
jbe@10
|
3537 "majority_num" *
|
jbe@10
|
3538 ("vote_counts"."positive_votes"+"vote_counts"."negative_votes")
|
jbe@10
|
3539 END
|
jbe@10
|
3540 FROM
|
jbe@10
|
3541 ( SELECT
|
jbe@10
|
3542 "initiative"."id" AS "initiative_id",
|
jbe@10
|
3543 coalesce(
|
jbe@10
|
3544 sum(
|
jbe@10
|
3545 CASE WHEN "grade" > 0 THEN "direct_voter"."weight" ELSE 0 END
|
jbe@10
|
3546 ),
|
jbe@10
|
3547 0
|
jbe@10
|
3548 ) AS "positive_votes",
|
jbe@10
|
3549 coalesce(
|
jbe@10
|
3550 sum(
|
jbe@10
|
3551 CASE WHEN "grade" < 0 THEN "direct_voter"."weight" ELSE 0 END
|
jbe@10
|
3552 ),
|
jbe@10
|
3553 0
|
jbe@10
|
3554 ) AS "negative_votes"
|
jbe@10
|
3555 FROM "initiative"
|
jbe@10
|
3556 JOIN "issue" ON "initiative"."issue_id" = "issue"."id"
|
jbe@10
|
3557 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
|
jbe@10
|
3558 LEFT JOIN "direct_voter"
|
jbe@10
|
3559 ON "direct_voter"."issue_id" = "initiative"."issue_id"
|
jbe@10
|
3560 LEFT JOIN "vote"
|
jbe@10
|
3561 ON "vote"."initiative_id" = "initiative"."id"
|
jbe@10
|
3562 AND "vote"."member_id" = "direct_voter"."member_id"
|
jbe@10
|
3563 WHERE "initiative"."issue_id" = "issue_id_p"
|
jbe@15
|
3564 AND "initiative"."admitted" -- NOTE: NULL case is handled too
|
jbe@10
|
3565 GROUP BY "initiative"."id"
|
jbe@10
|
3566 ) AS "vote_counts",
|
jbe@10
|
3567 "issue",
|
jbe@10
|
3568 "policy"
|
jbe@10
|
3569 WHERE "vote_counts"."initiative_id" = "initiative"."id"
|
jbe@10
|
3570 AND "issue"."id" = "initiative"."issue_id"
|
jbe@10
|
3571 AND "policy"."id" = "issue"."policy_id";
|
jbe@137
|
3572 -- materialize battle_view:
|
jbe@61
|
3573 -- NOTE: "closed" column of issue must be set at this point
|
jbe@61
|
3574 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
|
jbe@61
|
3575 INSERT INTO "battle" (
|
jbe@61
|
3576 "issue_id",
|
jbe@61
|
3577 "winning_initiative_id", "losing_initiative_id",
|
jbe@61
|
3578 "count"
|
jbe@61
|
3579 ) SELECT
|
jbe@61
|
3580 "issue_id",
|
jbe@61
|
3581 "winning_initiative_id", "losing_initiative_id",
|
jbe@61
|
3582 "count"
|
jbe@61
|
3583 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
|
jbe@0
|
3584 END;
|
jbe@0
|
3585 $$;
|
jbe@0
|
3586
|
jbe@0
|
3587 COMMENT ON FUNCTION "close_voting"
|
jbe@0
|
3588 ( "issue"."id"%TYPE )
|
jbe@0
|
3589 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.';
|
jbe@0
|
3590
|
jbe@0
|
3591
|
jbe@30
|
3592 CREATE FUNCTION "defeat_strength"
|
jbe@30
|
3593 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
|
jbe@30
|
3594 RETURNS INT8
|
jbe@30
|
3595 LANGUAGE 'plpgsql' IMMUTABLE AS $$
|
jbe@30
|
3596 BEGIN
|
jbe@30
|
3597 IF "positive_votes_p" > "negative_votes_p" THEN
|
jbe@30
|
3598 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
|
jbe@30
|
3599 ELSIF "positive_votes_p" = "negative_votes_p" THEN
|
jbe@30
|
3600 RETURN 0;
|
jbe@30
|
3601 ELSE
|
jbe@30
|
3602 RETURN -1;
|
jbe@30
|
3603 END IF;
|
jbe@30
|
3604 END;
|
jbe@30
|
3605 $$;
|
jbe@30
|
3606
|
jbe@30
|
3607 COMMENT ON FUNCTION "defeat_strength"(INT4, INT4) IS 'Calculates defeat strength (INT8!) of a pairwise defeat primarily by the absolute number of votes for the winner and secondarily by the absolute number of votes for the loser';
|
jbe@30
|
3608
|
jbe@30
|
3609
|
jbe@30
|
3610 CREATE FUNCTION "array_init_string"("dim_p" INTEGER)
|
jbe@30
|
3611 RETURNS TEXT
|
jbe@0
|
3612 LANGUAGE 'plpgsql' IMMUTABLE AS $$
|
jbe@0
|
3613 DECLARE
|
jbe@0
|
3614 "i" INTEGER;
|
jbe@0
|
3615 "ary_text_v" TEXT;
|
jbe@0
|
3616 BEGIN
|
jbe@0
|
3617 IF "dim_p" >= 1 THEN
|
jbe@0
|
3618 "ary_text_v" := '{NULL';
|
jbe@0
|
3619 "i" := "dim_p";
|
jbe@0
|
3620 LOOP
|
jbe@0
|
3621 "i" := "i" - 1;
|
jbe@0
|
3622 EXIT WHEN "i" = 0;
|
jbe@0
|
3623 "ary_text_v" := "ary_text_v" || ',NULL';
|
jbe@0
|
3624 END LOOP;
|
jbe@0
|
3625 "ary_text_v" := "ary_text_v" || '}';
|
jbe@30
|
3626 RETURN "ary_text_v";
|
jbe@0
|
3627 ELSE
|
jbe@0
|
3628 RAISE EXCEPTION 'Dimension needs to be at least 1.';
|
jbe@0
|
3629 END IF;
|
jbe@0
|
3630 END;
|
jbe@0
|
3631 $$;
|
jbe@0
|
3632
|
jbe@30
|
3633 COMMENT ON FUNCTION "array_init_string"(INTEGER) IS 'Needed for PostgreSQL < 8.4, due to missing "array_fill" function';
|
jbe@30
|
3634
|
jbe@30
|
3635
|
jbe@30
|
3636 CREATE FUNCTION "square_matrix_init_string"("dim_p" INTEGER)
|
jbe@30
|
3637 RETURNS TEXT
|
jbe@0
|
3638 LANGUAGE 'plpgsql' IMMUTABLE AS $$
|
jbe@0
|
3639 DECLARE
|
jbe@0
|
3640 "i" INTEGER;
|
jbe@0
|
3641 "row_text_v" TEXT;
|
jbe@0
|
3642 "ary_text_v" TEXT;
|
jbe@0
|
3643 BEGIN
|
jbe@0
|
3644 IF "dim_p" >= 1 THEN
|
jbe@0
|
3645 "row_text_v" := '{NULL';
|
jbe@0
|
3646 "i" := "dim_p";
|
jbe@0
|
3647 LOOP
|
jbe@0
|
3648 "i" := "i" - 1;
|
jbe@0
|
3649 EXIT WHEN "i" = 0;
|
jbe@0
|
3650 "row_text_v" := "row_text_v" || ',NULL';
|
jbe@0
|
3651 END LOOP;
|
jbe@0
|
3652 "row_text_v" := "row_text_v" || '}';
|
jbe@0
|
3653 "ary_text_v" := '{' || "row_text_v";
|
jbe@0
|
3654 "i" := "dim_p";
|
jbe@0
|
3655 LOOP
|
jbe@0
|
3656 "i" := "i" - 1;
|
jbe@0
|
3657 EXIT WHEN "i" = 0;
|
jbe@0
|
3658 "ary_text_v" := "ary_text_v" || ',' || "row_text_v";
|
jbe@0
|
3659 END LOOP;
|
jbe@0
|
3660 "ary_text_v" := "ary_text_v" || '}';
|
jbe@30
|
3661 RETURN "ary_text_v";
|
jbe@0
|
3662 ELSE
|
jbe@0
|
3663 RAISE EXCEPTION 'Dimension needs to be at least 1.';
|
jbe@0
|
3664 END IF;
|
jbe@0
|
3665 END;
|
jbe@0
|
3666 $$;
|
jbe@0
|
3667
|
jbe@30
|
3668 COMMENT ON FUNCTION "square_matrix_init_string"(INTEGER) IS 'Needed for PostgreSQL < 8.4, due to missing "array_fill" function';
|
jbe@0
|
3669
|
jbe@0
|
3670
|
jbe@0
|
3671 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
|
jbe@0
|
3672 RETURNS VOID
|
jbe@0
|
3673 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
3674 DECLARE
|
jbe@134
|
3675 "dimension_v" INTEGER;
|
jbe@134
|
3676 "vote_matrix" INT4[][]; -- absolute votes
|
jbe@134
|
3677 "matrix" INT8[][]; -- defeat strength / best paths
|
jbe@134
|
3678 "i" INTEGER;
|
jbe@134
|
3679 "j" INTEGER;
|
jbe@134
|
3680 "k" INTEGER;
|
jbe@134
|
3681 "battle_row" "battle"%ROWTYPE;
|
jbe@134
|
3682 "rank_ary" INT4[];
|
jbe@134
|
3683 "rank_v" INT4;
|
jbe@134
|
3684 "done_v" INTEGER;
|
jbe@134
|
3685 "winners_ary" INTEGER[];
|
jbe@134
|
3686 "initiative_id_v" "initiative"."id"%TYPE;
|
jbe@0
|
3687 BEGIN
|
jbe@0
|
3688 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
|
jbe@126
|
3689 SELECT count(1) INTO "dimension_v"
|
jbe@126
|
3690 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
|
jbe@126
|
3691 IF "dimension_v" > 1 THEN
|
jbe@30
|
3692 -- Create "vote_matrix" with absolute number of votes in pairwise
|
jbe@30
|
3693 -- comparison:
|
jbe@30
|
3694 "vote_matrix" := "square_matrix_init_string"("dimension_v"); -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
|
jbe@0
|
3695 "i" := 1;
|
jbe@0
|
3696 "j" := 2;
|
jbe@0
|
3697 FOR "battle_row" IN
|
jbe@0
|
3698 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
|
jbe@126
|
3699 ORDER BY
|
jbe@126
|
3700 "winning_initiative_id" NULLS LAST,
|
jbe@126
|
3701 "losing_initiative_id" NULLS LAST
|
jbe@0
|
3702 LOOP
|
jbe@30
|
3703 "vote_matrix"["i"]["j"] := "battle_row"."count";
|
jbe@0
|
3704 IF "j" = "dimension_v" THEN
|
jbe@0
|
3705 "i" := "i" + 1;
|
jbe@0
|
3706 "j" := 1;
|
jbe@0
|
3707 ELSE
|
jbe@0
|
3708 "j" := "j" + 1;
|
jbe@0
|
3709 IF "j" = "i" THEN
|
jbe@0
|
3710 "j" := "j" + 1;
|
jbe@0
|
3711 END IF;
|
jbe@0
|
3712 END IF;
|
jbe@0
|
3713 END LOOP;
|
jbe@0
|
3714 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
|
jbe@0
|
3715 RAISE EXCEPTION 'Wrong battle count (should not happen)';
|
jbe@0
|
3716 END IF;
|
jbe@30
|
3717 -- Store defeat strengths in "matrix" using "defeat_strength"
|
jbe@30
|
3718 -- function:
|
jbe@30
|
3719 "matrix" := "square_matrix_init_string"("dimension_v"); -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
|
jbe@0
|
3720 "i" := 1;
|
jbe@0
|
3721 LOOP
|
jbe@30
|
3722 "j" := 1;
|
jbe@0
|
3723 LOOP
|
jbe@0
|
3724 IF "i" != "j" THEN
|
jbe@30
|
3725 "matrix"["i"]["j"] := "defeat_strength"(
|
jbe@30
|
3726 "vote_matrix"["i"]["j"],
|
jbe@30
|
3727 "vote_matrix"["j"]["i"]
|
jbe@30
|
3728 );
|
jbe@0
|
3729 END IF;
|
jbe@0
|
3730 EXIT WHEN "j" = "dimension_v";
|
jbe@0
|
3731 "j" := "j" + 1;
|
jbe@0
|
3732 END LOOP;
|
jbe@30
|
3733 EXIT WHEN "i" = "dimension_v";
|
jbe@0
|
3734 "i" := "i" + 1;
|
jbe@0
|
3735 END LOOP;
|
jbe@0
|
3736 -- Find best paths:
|
jbe@0
|
3737 "i" := 1;
|
jbe@0
|
3738 LOOP
|
jbe@0
|
3739 "j" := 1;
|
jbe@0
|
3740 LOOP
|
jbe@0
|
3741 IF "i" != "j" THEN
|
jbe@0
|
3742 "k" := 1;
|
jbe@0
|
3743 LOOP
|
jbe@0
|
3744 IF "i" != "k" AND "j" != "k" THEN
|
jbe@0
|
3745 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
|
jbe@0
|
3746 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
|
jbe@0
|
3747 "matrix"["j"]["k"] := "matrix"["j"]["i"];
|
jbe@0
|
3748 END IF;
|
jbe@0
|
3749 ELSE
|
jbe@0
|
3750 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
|
jbe@0
|
3751 "matrix"["j"]["k"] := "matrix"["i"]["k"];
|
jbe@0
|
3752 END IF;
|
jbe@0
|
3753 END IF;
|
jbe@0
|
3754 END IF;
|
jbe@0
|
3755 EXIT WHEN "k" = "dimension_v";
|
jbe@0
|
3756 "k" := "k" + 1;
|
jbe@0
|
3757 END LOOP;
|
jbe@0
|
3758 END IF;
|
jbe@0
|
3759 EXIT WHEN "j" = "dimension_v";
|
jbe@0
|
3760 "j" := "j" + 1;
|
jbe@0
|
3761 END LOOP;
|
jbe@0
|
3762 EXIT WHEN "i" = "dimension_v";
|
jbe@0
|
3763 "i" := "i" + 1;
|
jbe@0
|
3764 END LOOP;
|
jbe@0
|
3765 -- Determine order of winners:
|
jbe@30
|
3766 "rank_ary" := "array_init_string"("dimension_v"); -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
|
jbe@0
|
3767 "rank_v" := 1;
|
jbe@0
|
3768 "done_v" := 0;
|
jbe@0
|
3769 LOOP
|
jbe@0
|
3770 "winners_ary" := '{}';
|
jbe@0
|
3771 "i" := 1;
|
jbe@0
|
3772 LOOP
|
jbe@0
|
3773 IF "rank_ary"["i"] ISNULL THEN
|
jbe@0
|
3774 "j" := 1;
|
jbe@0
|
3775 LOOP
|
jbe@0
|
3776 IF
|
jbe@0
|
3777 "i" != "j" AND
|
jbe@0
|
3778 "rank_ary"["j"] ISNULL AND
|
jbe@0
|
3779 "matrix"["j"]["i"] > "matrix"["i"]["j"]
|
jbe@0
|
3780 THEN
|
jbe@0
|
3781 -- someone else is better
|
jbe@0
|
3782 EXIT;
|
jbe@0
|
3783 END IF;
|
jbe@0
|
3784 IF "j" = "dimension_v" THEN
|
jbe@0
|
3785 -- noone is better
|
jbe@0
|
3786 "winners_ary" := "winners_ary" || "i";
|
jbe@0
|
3787 EXIT;
|
jbe@0
|
3788 END IF;
|
jbe@0
|
3789 "j" := "j" + 1;
|
jbe@0
|
3790 END LOOP;
|
jbe@0
|
3791 END IF;
|
jbe@0
|
3792 EXIT WHEN "i" = "dimension_v";
|
jbe@0
|
3793 "i" := "i" + 1;
|
jbe@0
|
3794 END LOOP;
|
jbe@0
|
3795 "i" := 1;
|
jbe@0
|
3796 LOOP
|
jbe@0
|
3797 "rank_ary"["winners_ary"["i"]] := "rank_v";
|
jbe@0
|
3798 "done_v" := "done_v" + 1;
|
jbe@0
|
3799 EXIT WHEN "i" = array_upper("winners_ary", 1);
|
jbe@0
|
3800 "i" := "i" + 1;
|
jbe@0
|
3801 END LOOP;
|
jbe@0
|
3802 EXIT WHEN "done_v" = "dimension_v";
|
jbe@0
|
3803 "rank_v" := "rank_v" + 1;
|
jbe@0
|
3804 END LOOP;
|
jbe@128
|
3805 -- write preliminary results:
|
jbe@0
|
3806 "i" := 1;
|
jbe@0
|
3807 FOR "initiative_id_v" IN
|
jbe@10
|
3808 SELECT "id" FROM "initiative"
|
jbe@126
|
3809 WHERE "issue_id" = "issue_id_p" AND "admitted"
|
jbe@10
|
3810 ORDER BY "id"
|
jbe@0
|
3811 LOOP
|
jbe@128
|
3812 UPDATE "initiative" SET
|
jbe@139
|
3813 "favored" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
|
jbe@139
|
3814 "unfavored" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
|
jbe@139
|
3815 "preliminary_rank" = "rank_ary"["i"],
|
jbe@139
|
3816 "disqualified" = FALSE,
|
jbe@139
|
3817 "winner" = FALSE
|
jbe@0
|
3818 WHERE "id" = "initiative_id_v";
|
jbe@0
|
3819 "i" := "i" + 1;
|
jbe@0
|
3820 END LOOP;
|
jbe@126
|
3821 IF "i" != "dimension_v" THEN
|
jbe@0
|
3822 RAISE EXCEPTION 'Wrong winner count (should not happen)';
|
jbe@0
|
3823 END IF;
|
jbe@139
|
3824 -- remove possible gap in preliminary ranks:
|
jbe@139
|
3825 IF NOT EXISTS (
|
jbe@139
|
3826 SELECT NULL FROM "initiative"
|
jbe@139
|
3827 WHERE "issue_id" = "issue_id_p"
|
jbe@139
|
3828 AND "favored"=FALSE AND "unfavored"=FALSE
|
jbe@139
|
3829 ) THEN
|
jbe@139
|
3830 UPDATE "initiative" SET "preliminary_rank" = "preliminary_rank" - 1
|
jbe@139
|
3831 WHERE "issue_id" = "issue_id_p" AND "unfavored";
|
jbe@139
|
3832 END IF;
|
jbe@139
|
3833 -- disqualify certain initiatives to enforce a stable result:
|
jbe@139
|
3834 UPDATE "initiative" SET "disqualified" = TRUE
|
jbe@139
|
3835 FROM (
|
jbe@139
|
3836 SELECT "losing_initiative"."id" AS "initiative_id"
|
jbe@141
|
3837 FROM "initiative" "losing_initiative"
|
jbe@139
|
3838 JOIN "battle_participant" "winning_participant"
|
jbe@139
|
3839 ON "winning_participant"."issue_id" = "issue_id_p"
|
jbe@139
|
3840 LEFT JOIN "initiative" "winning_initiative"
|
jbe@139
|
3841 ON "winning_initiative"."id" = "winning_participant"."id"
|
jbe@139
|
3842 -- NOTE: winner may be status quo:
|
jbe@139
|
3843 -- "losing_initiative"."id" is always NOTNULL
|
jbe@139
|
3844 -- while "winning_initiative"."id" may be NULL
|
jbe@139
|
3845 JOIN "battle" "battle_win"
|
jbe@139
|
3846 ON "battle_win"."issue_id" = "issue_id_p"
|
jbe@139
|
3847 AND (
|
jbe@139
|
3848 "battle_win"."winning_initiative_id" = "winning_initiative"."id" OR
|
jbe@139
|
3849 ( "battle_win"."winning_initiative_id" ISNULL AND
|
jbe@139
|
3850 "winning_initiative"."id" ISNULL ) )
|
jbe@139
|
3851 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
|
jbe@139
|
3852 JOIN "battle" "battle_lose"
|
jbe@139
|
3853 ON "battle_lose"."issue_id" = "issue_id_p"
|
jbe@139
|
3854 AND (
|
jbe@139
|
3855 "battle_lose"."losing_initiative_id" = "winning_initiative"."id" OR
|
jbe@139
|
3856 ( "battle_lose"."losing_initiative_id" ISNULL AND
|
jbe@139
|
3857 "winning_initiative"."id" ISNULL ) )
|
jbe@139
|
3858 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
|
jbe@141
|
3859 WHERE "losing_initiative"."issue_id" = "issue_id_p"
|
jbe@141
|
3860 AND "losing_initiative"."admitted"
|
jbe@139
|
3861 AND (
|
jbe@139
|
3862 ("winning_initiative"."id" ISNULL AND "losing_initiative"."unfavored") OR
|
jbe@139
|
3863 ( "winning_initiative"."preliminary_rank" <
|
jbe@139
|
3864 "losing_initiative"."preliminary_rank" ) )
|
jbe@140
|
3865 AND "battle_win"."count" > "battle_lose"."count"
|
jbe@139
|
3866 ) AS "subquery"
|
jbe@139
|
3867 WHERE "id" = "subquery"."initiative_id";
|
jbe@139
|
3868 -- calculate final ranks (start counting with 1, no equal ranks):
|
jbe@0
|
3869 "rank_v" := 1;
|
jbe@0
|
3870 FOR "initiative_id_v" IN
|
jbe@0
|
3871 SELECT "id" FROM "initiative"
|
jbe@134
|
3872 WHERE "issue_id" = "issue_id_p" AND "admitted"
|
jbe@139
|
3873 ORDER BY "preliminary_rank", "id"
|
jbe@0
|
3874 LOOP
|
jbe@139
|
3875 UPDATE "initiative" SET "final_rank" = "rank_v"
|
jbe@0
|
3876 WHERE "id" = "initiative_id_v";
|
jbe@0
|
3877 "rank_v" := "rank_v" + 1;
|
jbe@0
|
3878 END LOOP;
|
jbe@139
|
3879 -- mark final winner:
|
jbe@139
|
3880 UPDATE "initiative" SET "winner" = TRUE
|
jbe@139
|
3881 FROM (
|
jbe@139
|
3882 SELECT "id" AS "initiative_id"
|
jbe@139
|
3883 FROM "initiative"
|
jbe@139
|
3884 WHERE "issue_id" = "issue_id_p"
|
jbe@139
|
3885 AND "attainable" AND "favored" AND NOT "disqualified"
|
jbe@139
|
3886 ORDER BY "final_rank"
|
jbe@139
|
3887 LIMIT 1
|
jbe@139
|
3888 ) AS "subquery"
|
jbe@139
|
3889 WHERE "id" = "subquery"."initiative_id";
|
jbe@0
|
3890 END IF;
|
jbe@139
|
3891 -- mark issue as finished:
|
jbe@111
|
3892 UPDATE "issue" SET
|
jbe@111
|
3893 "state" =
|
jbe@139
|
3894 CASE WHEN EXISTS (
|
jbe@139
|
3895 SELECT NULL FROM "initiative"
|
jbe@139
|
3896 WHERE "issue_id" = "issue_id_p" AND "winner"
|
jbe@139
|
3897 ) THEN
|
jbe@139
|
3898 'finished_with_winner'::"issue_state"
|
jbe@139
|
3899 ELSE
|
jbe@121
|
3900 'finished_without_winner'::"issue_state"
|
jbe@111
|
3901 END,
|
jbe@111
|
3902 "ranks_available" = TRUE
|
jbe@0
|
3903 WHERE "id" = "issue_id_p";
|
jbe@0
|
3904 RETURN;
|
jbe@0
|
3905 END;
|
jbe@0
|
3906 $$;
|
jbe@0
|
3907
|
jbe@0
|
3908 COMMENT ON FUNCTION "calculate_ranks"
|
jbe@0
|
3909 ( "issue"."id"%TYPE )
|
jbe@0
|
3910 IS 'Determine ranking (Votes have to be counted first)';
|
jbe@0
|
3911
|
jbe@0
|
3912
|
jbe@0
|
3913
|
jbe@0
|
3914 -----------------------------
|
jbe@0
|
3915 -- Automatic state changes --
|
jbe@0
|
3916 -----------------------------
|
jbe@0
|
3917
|
jbe@0
|
3918
|
jbe@0
|
3919 CREATE FUNCTION "check_issue"
|
jbe@0
|
3920 ( "issue_id_p" "issue"."id"%TYPE )
|
jbe@0
|
3921 RETURNS VOID
|
jbe@0
|
3922 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
3923 DECLARE
|
jbe@0
|
3924 "issue_row" "issue"%ROWTYPE;
|
jbe@0
|
3925 "policy_row" "policy"%ROWTYPE;
|
jbe@0
|
3926 "voting_requested_v" BOOLEAN;
|
jbe@0
|
3927 BEGIN
|
jbe@67
|
3928 PERFORM "lock_issue"("issue_id_p");
|
jbe@0
|
3929 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
|
jbe@24
|
3930 -- only process open issues:
|
jbe@0
|
3931 IF "issue_row"."closed" ISNULL THEN
|
jbe@0
|
3932 SELECT * INTO "policy_row" FROM "policy"
|
jbe@0
|
3933 WHERE "id" = "issue_row"."policy_id";
|
jbe@24
|
3934 -- create a snapshot, unless issue is already fully frozen:
|
jbe@3
|
3935 IF "issue_row"."fully_frozen" ISNULL THEN
|
jbe@0
|
3936 PERFORM "create_snapshot"("issue_id_p");
|
jbe@0
|
3937 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
|
jbe@0
|
3938 END IF;
|
jbe@24
|
3939 -- eventually close or accept issues, which have not been accepted:
|
jbe@0
|
3940 IF "issue_row"."accepted" ISNULL THEN
|
jbe@0
|
3941 IF EXISTS (
|
jbe@0
|
3942 SELECT NULL FROM "initiative"
|
jbe@0
|
3943 WHERE "issue_id" = "issue_id_p"
|
jbe@0
|
3944 AND "supporter_count" > 0
|
jbe@0
|
3945 AND "supporter_count" * "policy_row"."issue_quorum_den"
|
jbe@0
|
3946 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
|
jbe@0
|
3947 ) THEN
|
jbe@24
|
3948 -- accept issues, if supporter count is high enough
|
jbe@3
|
3949 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
|
jbe@111
|
3950 -- NOTE: "issue_row" used later
|
jbe@111
|
3951 "issue_row"."state" := 'discussion';
|
jbe@111
|
3952 "issue_row"."accepted" := now();
|
jbe@111
|
3953 UPDATE "issue" SET
|
jbe@111
|
3954 "state" = "issue_row"."state",
|
jbe@111
|
3955 "accepted" = "issue_row"."accepted"
|
jbe@0
|
3956 WHERE "id" = "issue_row"."id";
|
jbe@0
|
3957 ELSIF
|
jbe@22
|
3958 now() >= "issue_row"."created" + "issue_row"."admission_time"
|
jbe@0
|
3959 THEN
|
jbe@24
|
3960 -- close issues, if admission time has expired
|
jbe@0
|
3961 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
|
jbe@111
|
3962 UPDATE "issue" SET
|
jbe@111
|
3963 "state" = 'canceled_issue_not_accepted',
|
jbe@111
|
3964 "closed" = now()
|
jbe@0
|
3965 WHERE "id" = "issue_row"."id";
|
jbe@0
|
3966 END IF;
|
jbe@0
|
3967 END IF;
|
jbe@24
|
3968 -- eventually half freeze issues:
|
jbe@0
|
3969 IF
|
jbe@24
|
3970 -- NOTE: issue can't be closed at this point, if it has been accepted
|
jbe@0
|
3971 "issue_row"."accepted" NOTNULL AND
|
jbe@3
|
3972 "issue_row"."half_frozen" ISNULL
|
jbe@0
|
3973 THEN
|
jbe@0
|
3974 SELECT
|
jbe@0
|
3975 CASE
|
jbe@0
|
3976 WHEN "vote_now" * 2 > "issue_row"."population" THEN
|
jbe@0
|
3977 TRUE
|
jbe@0
|
3978 WHEN "vote_later" * 2 > "issue_row"."population" THEN
|
jbe@0
|
3979 FALSE
|
jbe@0
|
3980 ELSE NULL
|
jbe@0
|
3981 END
|
jbe@0
|
3982 INTO "voting_requested_v"
|
jbe@0
|
3983 FROM "issue" WHERE "id" = "issue_id_p";
|
jbe@0
|
3984 IF
|
jbe@0
|
3985 "voting_requested_v" OR (
|
jbe@3
|
3986 "voting_requested_v" ISNULL AND
|
jbe@22
|
3987 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
|
jbe@0
|
3988 )
|
jbe@0
|
3989 THEN
|
jbe@21
|
3990 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
|
jbe@111
|
3991 -- NOTE: "issue_row" used later
|
jbe@111
|
3992 "issue_row"."state" := 'verification';
|
jbe@111
|
3993 "issue_row"."half_frozen" := now();
|
jbe@111
|
3994 UPDATE "issue" SET
|
jbe@111
|
3995 "state" = "issue_row"."state",
|
jbe@111
|
3996 "half_frozen" = "issue_row"."half_frozen"
|
jbe@3
|
3997 WHERE "id" = "issue_row"."id";
|
jbe@0
|
3998 END IF;
|
jbe@0
|
3999 END IF;
|
jbe@24
|
4000 -- close issues after some time, if all initiatives have been revoked:
|
jbe@24
|
4001 IF
|
jbe@24
|
4002 "issue_row"."closed" ISNULL AND
|
jbe@24
|
4003 NOT EXISTS (
|
jbe@24
|
4004 -- all initiatives are revoked
|
jbe@24
|
4005 SELECT NULL FROM "initiative"
|
jbe@24
|
4006 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
|
jbe@24
|
4007 ) AND (
|
jbe@111
|
4008 -- and issue has not been accepted yet
|
jbe@111
|
4009 "issue_row"."accepted" ISNULL OR
|
jbe@24
|
4010 NOT EXISTS (
|
jbe@111
|
4011 -- or no initiatives have been revoked lately
|
jbe@24
|
4012 SELECT NULL FROM "initiative"
|
jbe@24
|
4013 WHERE "issue_id" = "issue_id_p"
|
jbe@24
|
4014 AND now() < "revoked" + "issue_row"."verification_time"
|
jbe@24
|
4015 ) OR (
|
jbe@24
|
4016 -- or verification time has elapsed
|
jbe@24
|
4017 "issue_row"."half_frozen" NOTNULL AND
|
jbe@24
|
4018 "issue_row"."fully_frozen" ISNULL AND
|
jbe@24
|
4019 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
|
jbe@24
|
4020 )
|
jbe@24
|
4021 )
|
jbe@24
|
4022 THEN
|
jbe@111
|
4023 -- NOTE: "issue_row" used later
|
jbe@113
|
4024 IF "issue_row"."accepted" ISNULL THEN
|
jbe@113
|
4025 "issue_row"."state" := 'canceled_revoked_before_accepted';
|
jbe@113
|
4026 ELSIF "issue_row"."half_frozen" ISNULL THEN
|
jbe@113
|
4027 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
|
jbe@113
|
4028 ELSE
|
jbe@113
|
4029 "issue_row"."state" := 'canceled_after_revocation_during_verification';
|
jbe@113
|
4030 END IF;
|
jbe@111
|
4031 "issue_row"."closed" := now();
|
jbe@111
|
4032 UPDATE "issue" SET
|
jbe@111
|
4033 "state" = "issue_row"."state",
|
jbe@111
|
4034 "closed" = "issue_row"."closed"
|
jbe@24
|
4035 WHERE "id" = "issue_row"."id";
|
jbe@24
|
4036 END IF;
|
jbe@24
|
4037 -- fully freeze issue after verification time:
|
jbe@0
|
4038 IF
|
jbe@3
|
4039 "issue_row"."half_frozen" NOTNULL AND
|
jbe@3
|
4040 "issue_row"."fully_frozen" ISNULL AND
|
jbe@24
|
4041 "issue_row"."closed" ISNULL AND
|
jbe@22
|
4042 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
|
jbe@3
|
4043 THEN
|
jbe@3
|
4044 PERFORM "freeze_after_snapshot"("issue_id_p");
|
jbe@24
|
4045 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
|
jbe@3
|
4046 END IF;
|
jbe@9
|
4047 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
|
jbe@24
|
4048 -- close issue by calling close_voting(...) after voting time:
|
jbe@3
|
4049 IF
|
jbe@9
|
4050 "issue_row"."closed" ISNULL AND
|
jbe@3
|
4051 "issue_row"."fully_frozen" NOTNULL AND
|
jbe@22
|
4052 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
|
jbe@0
|
4053 THEN
|
jbe@0
|
4054 PERFORM "close_voting"("issue_id_p");
|
jbe@111
|
4055 -- calculate ranks will not consume much time and can be done now
|
jbe@111
|
4056 PERFORM "calculate_ranks"("issue_id_p");
|
jbe@0
|
4057 END IF;
|
jbe@0
|
4058 END IF;
|
jbe@0
|
4059 RETURN;
|
jbe@0
|
4060 END;
|
jbe@0
|
4061 $$;
|
jbe@0
|
4062
|
jbe@0
|
4063 COMMENT ON FUNCTION "check_issue"
|
jbe@0
|
4064 ( "issue"."id"%TYPE )
|
jbe@0
|
4065 IS 'Precalculate supporter counts etc. for a given issue, and check, if status change is required; At end of voting the ranking is not calculated by this function, but must be calculated in a seperate transaction using the "calculate_ranks" function.';
|
jbe@0
|
4066
|
jbe@0
|
4067
|
jbe@0
|
4068 CREATE FUNCTION "check_everything"()
|
jbe@0
|
4069 RETURNS VOID
|
jbe@0
|
4070 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
4071 DECLARE
|
jbe@0
|
4072 "issue_id_v" "issue"."id"%TYPE;
|
jbe@0
|
4073 BEGIN
|
jbe@1
|
4074 DELETE FROM "expired_session";
|
jbe@104
|
4075 PERFORM "check_last_login"();
|
jbe@4
|
4076 PERFORM "calculate_member_counts"();
|
jbe@4
|
4077 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
|
jbe@0
|
4078 PERFORM "check_issue"("issue_id_v");
|
jbe@0
|
4079 END LOOP;
|
jbe@4
|
4080 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
|
jbe@0
|
4081 PERFORM "calculate_ranks"("issue_id_v");
|
jbe@0
|
4082 END LOOP;
|
jbe@0
|
4083 RETURN;
|
jbe@0
|
4084 END;
|
jbe@0
|
4085 $$;
|
jbe@0
|
4086
|
jbe@103
|
4087 COMMENT ON FUNCTION "check_everything"() IS 'Amongst other regular tasks this function performs "check_issue" for every open issue, and if possible, automatically calculates ranks. Use this function only for development and debugging purposes, as long transactions with exclusive locking may result. In productive environments you should call the lf_update program instead.';
|
jbe@0
|
4088
|
jbe@0
|
4089
|
jbe@0
|
4090
|
jbe@59
|
4091 ----------------------
|
jbe@59
|
4092 -- Deletion of data --
|
jbe@59
|
4093 ----------------------
|
jbe@59
|
4094
|
jbe@59
|
4095
|
jbe@59
|
4096 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
|
jbe@59
|
4097 RETURNS VOID
|
jbe@59
|
4098 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@59
|
4099 DECLARE
|
jbe@59
|
4100 "issue_row" "issue"%ROWTYPE;
|
jbe@59
|
4101 BEGIN
|
jbe@59
|
4102 SELECT * INTO "issue_row"
|
jbe@59
|
4103 FROM "issue" WHERE "id" = "issue_id_p"
|
jbe@59
|
4104 FOR UPDATE;
|
jbe@59
|
4105 IF "issue_row"."cleaned" ISNULL THEN
|
jbe@139
|
4106 -- TODO: might be broken due to new constraints!
|
jbe@59
|
4107 UPDATE "issue" SET
|
jbe@59
|
4108 "closed" = NULL,
|
jbe@59
|
4109 "ranks_available" = FALSE
|
jbe@59
|
4110 WHERE "id" = "issue_id_p";
|
jbe@59
|
4111 DELETE FROM "delegating_voter"
|
jbe@59
|
4112 WHERE "issue_id" = "issue_id_p";
|
jbe@59
|
4113 DELETE FROM "direct_voter"
|
jbe@59
|
4114 WHERE "issue_id" = "issue_id_p";
|
jbe@59
|
4115 DELETE FROM "delegating_interest_snapshot"
|
jbe@59
|
4116 WHERE "issue_id" = "issue_id_p";
|
jbe@59
|
4117 DELETE FROM "direct_interest_snapshot"
|
jbe@59
|
4118 WHERE "issue_id" = "issue_id_p";
|
jbe@59
|
4119 DELETE FROM "delegating_population_snapshot"
|
jbe@59
|
4120 WHERE "issue_id" = "issue_id_p";
|
jbe@59
|
4121 DELETE FROM "direct_population_snapshot"
|
jbe@59
|
4122 WHERE "issue_id" = "issue_id_p";
|
jbe@113
|
4123 DELETE FROM "non_voter"
|
jbe@94
|
4124 WHERE "issue_id" = "issue_id_p";
|
jbe@59
|
4125 DELETE FROM "delegation"
|
jbe@59
|
4126 WHERE "issue_id" = "issue_id_p";
|
jbe@59
|
4127 DELETE FROM "supporter"
|
jbe@59
|
4128 WHERE "issue_id" = "issue_id_p";
|
jbe@59
|
4129 UPDATE "issue" SET
|
jbe@59
|
4130 "closed" = "issue_row"."closed",
|
jbe@59
|
4131 "ranks_available" = "issue_row"."ranks_available",
|
jbe@59
|
4132 "cleaned" = now()
|
jbe@59
|
4133 WHERE "id" = "issue_id_p";
|
jbe@59
|
4134 END IF;
|
jbe@59
|
4135 RETURN;
|
jbe@59
|
4136 END;
|
jbe@59
|
4137 $$;
|
jbe@59
|
4138
|
jbe@59
|
4139 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
|
jbe@8
|
4140
|
jbe@8
|
4141
|
jbe@54
|
4142 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
|
jbe@8
|
4143 RETURNS VOID
|
jbe@8
|
4144 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@8
|
4145 BEGIN
|
jbe@9
|
4146 UPDATE "member" SET
|
jbe@57
|
4147 "last_login" = NULL,
|
jbe@103
|
4148 "last_login_public" = NULL,
|
jbe@45
|
4149 "login" = NULL,
|
jbe@11
|
4150 "password" = NULL,
|
jbe@101
|
4151 "locked" = TRUE,
|
jbe@54
|
4152 "active" = FALSE,
|
jbe@11
|
4153 "notify_email" = NULL,
|
jbe@11
|
4154 "notify_email_unconfirmed" = NULL,
|
jbe@11
|
4155 "notify_email_secret" = NULL,
|
jbe@11
|
4156 "notify_email_secret_expiry" = NULL,
|
jbe@57
|
4157 "notify_email_lock_expiry" = NULL,
|
jbe@11
|
4158 "password_reset_secret" = NULL,
|
jbe@11
|
4159 "password_reset_secret_expiry" = NULL,
|
jbe@11
|
4160 "organizational_unit" = NULL,
|
jbe@11
|
4161 "internal_posts" = NULL,
|
jbe@11
|
4162 "realname" = NULL,
|
jbe@11
|
4163 "birthday" = NULL,
|
jbe@11
|
4164 "address" = NULL,
|
jbe@11
|
4165 "email" = NULL,
|
jbe@11
|
4166 "xmpp_address" = NULL,
|
jbe@11
|
4167 "website" = NULL,
|
jbe@11
|
4168 "phone" = NULL,
|
jbe@11
|
4169 "mobile_phone" = NULL,
|
jbe@11
|
4170 "profession" = NULL,
|
jbe@11
|
4171 "external_memberships" = NULL,
|
jbe@11
|
4172 "external_posts" = NULL,
|
jbe@45
|
4173 "statement" = NULL
|
jbe@45
|
4174 WHERE "id" = "member_id_p";
|
jbe@11
|
4175 -- "text_search_data" is updated by triggers
|
jbe@45
|
4176 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
|
jbe@45
|
4177 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
|
jbe@45
|
4178 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
|
jbe@45
|
4179 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
|
jbe@45
|
4180 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
|
jbe@113
|
4181 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
|
jbe@113
|
4182 DELETE FROM "session" WHERE "member_id" = "member_id_p";
|
jbe@45
|
4183 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
|
jbe@45
|
4184 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
|
jbe@113
|
4185 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
|
jbe@45
|
4186 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
|
jbe@45
|
4187 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
|
jbe@54
|
4188 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
|
jbe@54
|
4189 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
|
jbe@113
|
4190 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
|
jbe@57
|
4191 DELETE FROM "direct_voter" USING "issue"
|
jbe@57
|
4192 WHERE "direct_voter"."issue_id" = "issue"."id"
|
jbe@57
|
4193 AND "issue"."closed" ISNULL
|
jbe@57
|
4194 AND "member_id" = "member_id_p";
|
jbe@45
|
4195 RETURN;
|
jbe@45
|
4196 END;
|
jbe@45
|
4197 $$;
|
jbe@45
|
4198
|
jbe@57
|
4199 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)';
|
jbe@45
|
4200
|
jbe@45
|
4201
|
jbe@45
|
4202 CREATE FUNCTION "delete_private_data"()
|
jbe@45
|
4203 RETURNS VOID
|
jbe@45
|
4204 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@45
|
4205 BEGIN
|
jbe@50
|
4206 UPDATE "member" SET
|
jbe@57
|
4207 "last_login" = NULL,
|
jbe@50
|
4208 "login" = NULL,
|
jbe@50
|
4209 "password" = NULL,
|
jbe@50
|
4210 "notify_email" = NULL,
|
jbe@50
|
4211 "notify_email_unconfirmed" = NULL,
|
jbe@50
|
4212 "notify_email_secret" = NULL,
|
jbe@50
|
4213 "notify_email_secret_expiry" = NULL,
|
jbe@57
|
4214 "notify_email_lock_expiry" = NULL,
|
jbe@50
|
4215 "password_reset_secret" = NULL,
|
jbe@50
|
4216 "password_reset_secret_expiry" = NULL,
|
jbe@50
|
4217 "organizational_unit" = NULL,
|
jbe@50
|
4218 "internal_posts" = NULL,
|
jbe@50
|
4219 "realname" = NULL,
|
jbe@50
|
4220 "birthday" = NULL,
|
jbe@50
|
4221 "address" = NULL,
|
jbe@50
|
4222 "email" = NULL,
|
jbe@50
|
4223 "xmpp_address" = NULL,
|
jbe@50
|
4224 "website" = NULL,
|
jbe@50
|
4225 "phone" = NULL,
|
jbe@50
|
4226 "mobile_phone" = NULL,
|
jbe@50
|
4227 "profession" = NULL,
|
jbe@50
|
4228 "external_memberships" = NULL,
|
jbe@50
|
4229 "external_posts" = NULL,
|
jbe@50
|
4230 "statement" = NULL;
|
jbe@50
|
4231 -- "text_search_data" is updated by triggers
|
jbe@54
|
4232 DELETE FROM "invite_code";
|
jbe@50
|
4233 DELETE FROM "setting";
|
jbe@50
|
4234 DELETE FROM "setting_map";
|
jbe@50
|
4235 DELETE FROM "member_relation_setting";
|
jbe@50
|
4236 DELETE FROM "member_image";
|
jbe@50
|
4237 DELETE FROM "contact";
|
jbe@113
|
4238 DELETE FROM "ignored_member";
|
jbe@54
|
4239 DELETE FROM "session";
|
jbe@50
|
4240 DELETE FROM "area_setting";
|
jbe@50
|
4241 DELETE FROM "issue_setting";
|
jbe@113
|
4242 DELETE FROM "ignored_initiative";
|
jbe@50
|
4243 DELETE FROM "initiative_setting";
|
jbe@50
|
4244 DELETE FROM "suggestion_setting";
|
jbe@113
|
4245 DELETE FROM "non_voter";
|
jbe@8
|
4246 DELETE FROM "direct_voter" USING "issue"
|
jbe@8
|
4247 WHERE "direct_voter"."issue_id" = "issue"."id"
|
jbe@8
|
4248 AND "issue"."closed" ISNULL;
|
jbe@8
|
4249 RETURN;
|
jbe@8
|
4250 END;
|
jbe@8
|
4251 $$;
|
jbe@8
|
4252
|
jbe@103
|
4253 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.';
|
jbe@8
|
4254
|
jbe@8
|
4255
|
jbe@8
|
4256
|
jbe@0
|
4257 COMMIT;
|