liquid_feedback_core

annotate update/core-update.v2.0.8-v2.0.9.sql @ 245:8423373fbadd

Fixed update script from v1.4.0 to v2.0.0: Keep unused invite codes
author jbe
date Thu May 10 22:44:13 2012 +0200 (2012-05-10)
parents d09c17b01c5d
children 4b8cc6fc2d00
rev   line source
jbe@244 1 BEGIN;
jbe@244 2
jbe@244 3 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
jbe@244 4 SELECT * FROM (VALUES ('2.0.9', 2, 0, 9))
jbe@244 5 AS "subquery"("string", "major", "minor", "revision");
jbe@244 6
jbe@244 7 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
jbe@244 8
jbe@244 9 CREATE FUNCTION "delegation_chain_for_closed_issue"
jbe@244 10 ( "member_id_p" "member"."id"%TYPE,
jbe@244 11 "issue_id_p" "issue"."id"%TYPE )
jbe@244 12 RETURNS SETOF "delegation_chain_row"
jbe@244 13 LANGUAGE 'plpgsql' STABLE AS $$
jbe@244 14 DECLARE
jbe@244 15 "output_row" "delegation_chain_row";
jbe@244 16 "direct_voter_row" "direct_voter"%ROWTYPE;
jbe@244 17 "delegating_voter_row" "delegating_voter"%ROWTYPE;
jbe@244 18 BEGIN
jbe@244 19 "output_row"."index" := 0;
jbe@244 20 "output_row"."member_id" := "member_id_p";
jbe@244 21 "output_row"."member_valid" := TRUE;
jbe@244 22 "output_row"."participation" := FALSE;
jbe@244 23 "output_row"."overridden" := FALSE;
jbe@244 24 "output_row"."disabled_out" := FALSE;
jbe@244 25 LOOP
jbe@244 26 SELECT INTO "direct_voter_row" * FROM "direct_voter"
jbe@244 27 WHERE "issue_id" = "issue_id_p"
jbe@244 28 AND "member_id" = "output_row"."member_id";
jbe@244 29 IF "direct_voter_row"."member_id" NOTNULL THEN
jbe@244 30 "output_row"."participation" := TRUE;
jbe@244 31 "output_row"."scope_out" := NULL;
jbe@244 32 "output_row"."disabled_out" := NULL;
jbe@244 33 RETURN NEXT "output_row";
jbe@244 34 RETURN;
jbe@244 35 END IF;
jbe@244 36 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
jbe@244 37 WHERE "issue_id" = "issue_id_p"
jbe@244 38 AND "member_id" = "output_row"."member_id";
jbe@244 39 IF "delegating_voter_row"."member_id" ISNULL THEN
jbe@244 40 RETURN;
jbe@244 41 END IF;
jbe@244 42 "output_row"."scope_out" := "delegating_voter_row"."scope";
jbe@244 43 RETURN NEXT "output_row";
jbe@244 44 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
jbe@244 45 "output_row"."scope_in" := "output_row"."scope_out";
jbe@244 46 END LOOP;
jbe@244 47 END;
jbe@244 48 $$;
jbe@244 49
jbe@244 50 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
jbe@244 51 ( "member"."id"%TYPE,
jbe@244 52 "member"."id"%TYPE )
jbe@244 53 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
jbe@244 54
jbe@244 55 DROP FUNCTION "delegation_chain"
jbe@244 56 ( "member"."id"%TYPE,
jbe@244 57 "unit"."id"%TYPE,
jbe@244 58 "area"."id"%TYPE,
jbe@244 59 "issue"."id"%TYPE );
jbe@244 60
jbe@244 61 DROP FUNCTION "delegation_chain"
jbe@244 62 ( "member"."id"%TYPE,
jbe@244 63 "unit"."id"%TYPE,
jbe@244 64 "area"."id"%TYPE,
jbe@244 65 "issue"."id"%TYPE,
jbe@244 66 "member"."id"%TYPE );
jbe@244 67
jbe@244 68 CREATE FUNCTION "delegation_chain"
jbe@244 69 ( "member_id_p" "member"."id"%TYPE,
jbe@244 70 "unit_id_p" "unit"."id"%TYPE,
jbe@244 71 "area_id_p" "area"."id"%TYPE,
jbe@244 72 "issue_id_p" "issue"."id"%TYPE,
jbe@244 73 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL )
jbe@244 74 RETURNS SETOF "delegation_chain_row"
jbe@244 75 LANGUAGE 'plpgsql' STABLE AS $$
jbe@244 76 DECLARE
jbe@244 77 "scope_v" "delegation_scope";
jbe@244 78 "unit_id_v" "unit"."id"%TYPE;
jbe@244 79 "area_id_v" "area"."id"%TYPE;
jbe@244 80 "issue_row" "issue"%ROWTYPE;
jbe@244 81 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
jbe@244 82 "loop_member_id_v" "member"."id"%TYPE;
jbe@244 83 "output_row" "delegation_chain_row";
jbe@244 84 "output_rows" "delegation_chain_row"[];
jbe@244 85 "delegation_row" "delegation"%ROWTYPE;
jbe@244 86 "row_count" INT4;
jbe@244 87 "i" INT4;
jbe@244 88 "loop_v" BOOLEAN;
jbe@244 89 BEGIN
jbe@244 90 IF
jbe@244 91 "unit_id_p" NOTNULL AND
jbe@244 92 "area_id_p" ISNULL AND
jbe@244 93 "issue_id_p" ISNULL
jbe@244 94 THEN
jbe@244 95 "scope_v" := 'unit';
jbe@244 96 "unit_id_v" := "unit_id_p";
jbe@244 97 ELSIF
jbe@244 98 "unit_id_p" ISNULL AND
jbe@244 99 "area_id_p" NOTNULL AND
jbe@244 100 "issue_id_p" ISNULL
jbe@244 101 THEN
jbe@244 102 "scope_v" := 'area';
jbe@244 103 "area_id_v" := "area_id_p";
jbe@244 104 SELECT "unit_id" INTO "unit_id_v"
jbe@244 105 FROM "area" WHERE "id" = "area_id_v";
jbe@244 106 ELSIF
jbe@244 107 "unit_id_p" ISNULL AND
jbe@244 108 "area_id_p" ISNULL AND
jbe@244 109 "issue_id_p" NOTNULL
jbe@244 110 THEN
jbe@244 111 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
jbe@244 112 IF "issue_row"."id" ISNULL THEN
jbe@244 113 RETURN;
jbe@244 114 END IF;
jbe@244 115 IF "issue_row"."closed" NOTNULL THEN
jbe@244 116 IF "simulate_trustee_id_p" NOTNULL THEN
jbe@244 117 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
jbe@244 118 END IF;
jbe@244 119 FOR "output_row" IN
jbe@244 120 SELECT * FROM
jbe@244 121 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
jbe@244 122 LOOP
jbe@244 123 RETURN NEXT "output_row";
jbe@244 124 END LOOP;
jbe@244 125 RETURN;
jbe@244 126 END IF;
jbe@244 127 "scope_v" := 'issue';
jbe@244 128 SELECT "area_id" INTO "area_id_v"
jbe@244 129 FROM "issue" WHERE "id" = "issue_id_p";
jbe@244 130 SELECT "unit_id" INTO "unit_id_v"
jbe@244 131 FROM "area" WHERE "id" = "area_id_v";
jbe@244 132 ELSE
jbe@244 133 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
jbe@244 134 END IF;
jbe@244 135 "visited_member_ids" := '{}';
jbe@244 136 "loop_member_id_v" := NULL;
jbe@244 137 "output_rows" := '{}';
jbe@244 138 "output_row"."index" := 0;
jbe@244 139 "output_row"."member_id" := "member_id_p";
jbe@244 140 "output_row"."member_valid" := TRUE;
jbe@244 141 "output_row"."participation" := FALSE;
jbe@244 142 "output_row"."overridden" := FALSE;
jbe@244 143 "output_row"."disabled_out" := FALSE;
jbe@244 144 "output_row"."scope_out" := NULL;
jbe@244 145 LOOP
jbe@244 146 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
jbe@244 147 "loop_member_id_v" := "output_row"."member_id";
jbe@244 148 ELSE
jbe@244 149 "visited_member_ids" :=
jbe@244 150 "visited_member_ids" || "output_row"."member_id";
jbe@244 151 END IF;
jbe@244 152 IF "output_row"."participation" ISNULL THEN
jbe@244 153 "output_row"."overridden" := NULL;
jbe@244 154 ELSIF "output_row"."participation" THEN
jbe@244 155 "output_row"."overridden" := TRUE;
jbe@244 156 END IF;
jbe@244 157 "output_row"."scope_in" := "output_row"."scope_out";
jbe@244 158 IF EXISTS (
jbe@244 159 SELECT NULL FROM "member" JOIN "privilege"
jbe@244 160 ON "privilege"."member_id" = "member"."id"
jbe@244 161 AND "privilege"."unit_id" = "unit_id_v"
jbe@244 162 WHERE "id" = "output_row"."member_id"
jbe@244 163 AND "member"."active" AND "privilege"."voting_right"
jbe@244 164 ) THEN
jbe@244 165 IF "scope_v" = 'unit' THEN
jbe@244 166 SELECT * INTO "delegation_row" FROM "delegation"
jbe@244 167 WHERE "truster_id" = "output_row"."member_id"
jbe@244 168 AND "unit_id" = "unit_id_v";
jbe@244 169 ELSIF "scope_v" = 'area' THEN
jbe@244 170 "output_row"."participation" := EXISTS (
jbe@244 171 SELECT NULL FROM "membership"
jbe@244 172 WHERE "area_id" = "area_id_p"
jbe@244 173 AND "member_id" = "output_row"."member_id"
jbe@244 174 );
jbe@244 175 SELECT * INTO "delegation_row" FROM "delegation"
jbe@244 176 WHERE "truster_id" = "output_row"."member_id"
jbe@244 177 AND (
jbe@244 178 "unit_id" = "unit_id_v" OR
jbe@244 179 "area_id" = "area_id_v"
jbe@244 180 )
jbe@244 181 ORDER BY "scope" DESC;
jbe@244 182 ELSIF "scope_v" = 'issue' THEN
jbe@244 183 IF "issue_row"."fully_frozen" ISNULL THEN
jbe@244 184 "output_row"."participation" := EXISTS (
jbe@244 185 SELECT NULL FROM "interest"
jbe@244 186 WHERE "issue_id" = "issue_id_p"
jbe@244 187 AND "member_id" = "output_row"."member_id"
jbe@244 188 );
jbe@244 189 ELSE
jbe@244 190 IF "output_row"."member_id" = "member_id_p" THEN
jbe@244 191 "output_row"."participation" := EXISTS (
jbe@244 192 SELECT NULL FROM "direct_voter"
jbe@244 193 WHERE "issue_id" = "issue_id_p"
jbe@244 194 AND "member_id" = "output_row"."member_id"
jbe@244 195 );
jbe@244 196 ELSE
jbe@244 197 "output_row"."participation" := NULL;
jbe@244 198 END IF;
jbe@244 199 END IF;
jbe@244 200 SELECT * INTO "delegation_row" FROM "delegation"
jbe@244 201 WHERE "truster_id" = "output_row"."member_id"
jbe@244 202 AND (
jbe@244 203 "unit_id" = "unit_id_v" OR
jbe@244 204 "area_id" = "area_id_v" OR
jbe@244 205 "issue_id" = "issue_id_p"
jbe@244 206 )
jbe@244 207 ORDER BY "scope" DESC;
jbe@244 208 END IF;
jbe@244 209 ELSE
jbe@244 210 "output_row"."member_valid" := FALSE;
jbe@244 211 "output_row"."participation" := FALSE;
jbe@244 212 "output_row"."scope_out" := NULL;
jbe@244 213 "delegation_row" := ROW(NULL);
jbe@244 214 END IF;
jbe@244 215 IF
jbe@244 216 "output_row"."member_id" = "member_id_p" AND
jbe@244 217 "simulate_trustee_id_p" NOTNULL
jbe@244 218 THEN
jbe@244 219 "output_row"."scope_out" := "scope_v";
jbe@244 220 "output_rows" := "output_rows" || "output_row";
jbe@244 221 "output_row"."member_id" := "simulate_trustee_id_p";
jbe@244 222 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
jbe@244 223 "output_row"."scope_out" := "delegation_row"."scope";
jbe@244 224 "output_rows" := "output_rows" || "output_row";
jbe@244 225 "output_row"."member_id" := "delegation_row"."trustee_id";
jbe@244 226 ELSIF "delegation_row"."scope" NOTNULL THEN
jbe@244 227 "output_row"."scope_out" := "delegation_row"."scope";
jbe@244 228 "output_row"."disabled_out" := TRUE;
jbe@244 229 "output_rows" := "output_rows" || "output_row";
jbe@244 230 EXIT;
jbe@244 231 ELSE
jbe@244 232 "output_row"."scope_out" := NULL;
jbe@244 233 "output_rows" := "output_rows" || "output_row";
jbe@244 234 EXIT;
jbe@244 235 END IF;
jbe@244 236 EXIT WHEN "loop_member_id_v" NOTNULL;
jbe@244 237 "output_row"."index" := "output_row"."index" + 1;
jbe@244 238 END LOOP;
jbe@244 239 "row_count" := array_upper("output_rows", 1);
jbe@244 240 "i" := 1;
jbe@244 241 "loop_v" := FALSE;
jbe@244 242 LOOP
jbe@244 243 "output_row" := "output_rows"["i"];
jbe@244 244 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
jbe@244 245 IF "loop_v" THEN
jbe@244 246 IF "i" + 1 = "row_count" THEN
jbe@244 247 "output_row"."loop" := 'last';
jbe@244 248 ELSIF "i" = "row_count" THEN
jbe@244 249 "output_row"."loop" := 'repetition';
jbe@244 250 ELSE
jbe@244 251 "output_row"."loop" := 'intermediate';
jbe@244 252 END IF;
jbe@244 253 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
jbe@244 254 "output_row"."loop" := 'first';
jbe@244 255 "loop_v" := TRUE;
jbe@244 256 END IF;
jbe@244 257 IF "scope_v" = 'unit' THEN
jbe@244 258 "output_row"."participation" := NULL;
jbe@244 259 END IF;
jbe@244 260 RETURN NEXT "output_row";
jbe@244 261 "i" := "i" + 1;
jbe@244 262 END LOOP;
jbe@244 263 RETURN;
jbe@244 264 END;
jbe@244 265 $$;
jbe@244 266
jbe@244 267 COMMENT ON FUNCTION "delegation_chain"
jbe@244 268 ( "member"."id"%TYPE,
jbe@244 269 "unit"."id"%TYPE,
jbe@244 270 "area"."id"%TYPE,
jbe@244 271 "issue"."id"%TYPE,
jbe@244 272 "member"."id"%TYPE )
jbe@244 273 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
jbe@244 274
jbe@244 275 CREATE TYPE "delegation_info_loop_type" AS ENUM
jbe@244 276 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
jbe@244 277
jbe@244 278 COMMENT ON TYPE "delegation_info_loop_type" IS 'Type of "delegation_loop" in "delegation_info_type"; ''own'' means loop to self, ''first'' means loop to first trustee, ''first_ellipsis'' means loop to ellipsis after first trustee, ''other'' means loop to other trustee, ''other_ellipsis'' means loop to ellipsis after other trustee''';
jbe@244 279
jbe@244 280 CREATE TYPE "delegation_info_type" AS (
jbe@244 281 "own_participation" BOOLEAN,
jbe@244 282 "own_delegation_scope" "delegation_scope",
jbe@244 283 "first_trustee_id" INT4,
jbe@244 284 "first_trustee_participation" BOOLEAN,
jbe@244 285 "first_trustee_ellipsis" BOOLEAN,
jbe@244 286 "other_trustee_id" INT4,
jbe@244 287 "other_trustee_participation" BOOLEAN,
jbe@244 288 "other_trustee_ellipsis" BOOLEAN,
jbe@244 289 "delegation_loop" "delegation_info_loop_type");
jbe@244 290
jbe@244 291 COMMENT ON TYPE "delegation_info_type" IS 'Type of result returned by "delegation_info" function; For meaning of "participation" check comment on "delegation_chain_row" type';
jbe@244 292
jbe@244 293 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
jbe@244 294 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
jbe@244 295 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
jbe@244 296 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
jbe@244 297 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
jbe@244 298 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
jbe@244 299 COMMENT ON COLUMN "delegation_info_type"."other_trustee_participation" IS 'Another trustee is participating (redundant field: if "other_trustee_id" is set, then "other_trustee_participation" is always TRUE, else "other_trustee_participation" is NULL)';
jbe@244 300 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
jbe@244 301 COMMENT ON COLUMN "delegation_info_type"."delegation_loop" IS 'Non-NULL value, if delegation chain contains a circle; See comment on "delegation_info_loop_type" for details';
jbe@244 302
jbe@244 303 CREATE FUNCTION "delegation_info"
jbe@244 304 ( "member_id_p" "member"."id"%TYPE,
jbe@244 305 "unit_id_p" "unit"."id"%TYPE,
jbe@244 306 "area_id_p" "area"."id"%TYPE,
jbe@244 307 "issue_id_p" "issue"."id"%TYPE,
jbe@244 308 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL )
jbe@244 309 RETURNS "delegation_info_type"
jbe@244 310 LANGUAGE 'plpgsql' STABLE AS $$
jbe@244 311 DECLARE
jbe@244 312 "current_row" "delegation_chain_row";
jbe@244 313 "result" "delegation_info_type";
jbe@244 314 BEGIN
jbe@244 315 "result"."own_participation" := FALSE;
jbe@244 316 FOR "current_row" IN
jbe@244 317 SELECT * FROM "delegation_chain"(
jbe@244 318 "member_id_p",
jbe@244 319 "unit_id_p", "area_id_p", "issue_id_p",
jbe@244 320 "simulate_trustee_id_p")
jbe@244 321 LOOP
jbe@244 322 IF "current_row"."member_id" = "member_id_p" THEN
jbe@244 323 "result"."own_participation" := "current_row"."participation";
jbe@244 324 "result"."own_delegation_scope" := "current_row"."scope_out";
jbe@244 325 IF "current_row"."loop" = 'first' THEN
jbe@244 326 "result"."delegation_loop" := 'own';
jbe@244 327 END IF;
jbe@244 328 ELSIF
jbe@244 329 "current_row"."member_valid" AND
jbe@244 330 ( "current_row"."loop" ISNULL OR
jbe@244 331 "current_row"."loop" != 'repetition' )
jbe@244 332 THEN
jbe@244 333 IF "result"."first_trustee_id" ISNULL THEN
jbe@244 334 "result"."first_trustee_id" := "current_row"."member_id";
jbe@244 335 "result"."first_trustee_participation" := "current_row"."participation";
jbe@244 336 "result"."first_trustee_ellipsis" := FALSE;
jbe@244 337 IF "current_row"."loop" = 'first' THEN
jbe@244 338 "result"."delegation_loop" := 'first';
jbe@244 339 END IF;
jbe@244 340 ELSIF "result"."other_trustee_id" ISNULL THEN
jbe@244 341 IF "current_row"."participation" THEN
jbe@244 342 "result"."other_trustee_id" := "current_row"."member_id";
jbe@244 343 "result"."other_trustee_participation" := TRUE;
jbe@244 344 "result"."other_trustee_ellipsis" := FALSE;
jbe@244 345 IF "current_row"."loop" = 'first' THEN
jbe@244 346 "result"."delegation_loop" := 'other';
jbe@244 347 END IF;
jbe@244 348 ELSE
jbe@244 349 "result"."first_trustee_ellipsis" := TRUE;
jbe@244 350 IF "current_row"."loop" = 'first' THEN
jbe@244 351 "result"."delegation_loop" := 'first_ellipsis';
jbe@244 352 END IF;
jbe@244 353 END IF;
jbe@244 354 ELSE
jbe@244 355 "result"."other_trustee_ellipsis" := TRUE;
jbe@244 356 IF "current_row"."loop" = 'first' THEN
jbe@244 357 "result"."delegation_loop" := 'other_ellipsis';
jbe@244 358 END IF;
jbe@244 359 END IF;
jbe@244 360 END IF;
jbe@244 361 END LOOP;
jbe@244 362 RETURN "result";
jbe@244 363 END;
jbe@244 364 $$;
jbe@244 365
jbe@244 366 COMMENT ON FUNCTION "delegation_info"
jbe@244 367 ( "member"."id"%TYPE,
jbe@244 368 "unit"."id"%TYPE,
jbe@244 369 "area"."id"%TYPE,
jbe@244 370 "issue"."id"%TYPE,
jbe@244 371 "member"."id"%TYPE )
jbe@244 372 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
jbe@244 373
jbe@244 374 COMMIT;

Impressum / About Us