jbe@615: CREATE OR REPLACE VIEW "liquid_feedback_version" AS jbe@615: SELECT * FROM (VALUES ('4.2.1-incomplete-update', 4, 2, -1)) jbe@615: AS "subquery"("string", "major", "minor", "revision"); jbe@615: jbe@615: BEGIN; jbe@615: jbe@616: ALTER TABLE "unit" ADD COLUMN "attr" JSONB NOT NULL DEFAULT '{}' CHECK (jsonb_typeof("attr") = 'object'); jbe@616: COMMENT ON COLUMN "unit"."attr" IS 'Opaque data structure to store any extended attributes used by frontend or middleware'; jbe@616: jbe@615: ALTER TABLE "unit" ADD COLUMN "member_weight" INT4; jbe@615: COMMENT ON COLUMN "unit"."member_weight" IS 'Sum of active members'' voting weight'; jbe@615: jbe@615: ALTER TABLE "snapshot_population" ADD COLUMN "weight" INT4 NOT NULL DEFAULT 1; jbe@615: ALTER TABLE "snapshot_population" ALTER COLUMN "weight" DROP DEFAULT; jbe@615: jbe@615: ALTER TABLE "privilege" ADD COLUMN "weight" INT4 NOT NULL DEFAULT 1 CHECK ("weight" >= 0); jbe@615: COMMENT ON COLUMN "privilege"."weight" IS 'Voting weight of member in unit'; jbe@615: jbe@615: CREATE TABLE "issue_privilege" ( jbe@615: PRIMARY KEY ("issue_id", "member_id"), jbe@615: "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@615: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@615: "initiative_right" BOOLEAN, jbe@615: "voting_right" BOOLEAN, jbe@615: "polling_right" BOOLEAN, jbe@615: "weight" INT4 CHECK ("weight" >= 0) ); jbe@615: CREATE INDEX "issue_privilege_idx" ON "issue_privilege" ("member_id"); jbe@615: COMMENT ON TABLE "issue_privilege" IS 'Override of "privilege" table for rights of members in certain issues'; jbe@615: jbe@615: ALTER TABLE "direct_interest_snapshot" ADD COLUMN "ownweight" INT4 NOT NULL DEFAULT 1; jbe@615: ALTER TABLE "direct_interest_snapshot" ALTER COLUMN "ownweight" DROP DEFAULT; jbe@615: COMMENT ON COLUMN "direct_interest_snapshot"."ownweight" IS 'Own voting weight of member, disregading delegations'; jbe@615: COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Voting weight of member according to own weight and "delegating_interest_snapshot"'; jbe@615: jbe@615: ALTER TABLE "delegating_interest_snapshot" ADD COLUMN "ownweight" INT4 NOT NULL DEFAULT 1; jbe@615: ALTER TABLE "delegating_interest_snapshot" ALTER COLUMN "ownweight" DROP DEFAULT; jbe@615: COMMENT ON COLUMN "delegating_interest_snapshot"."ownweight" IS 'Own voting weight of member, disregading delegations'; jbe@615: COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate voting weight considering incoming delegations'; jbe@615: jbe@615: ALTER TABLE "direct_voter" ADD COLUMN "ownweight" INT4 DEFAULT 1; jbe@615: ALTER TABLE "direct_voter" ALTER COLUMN "ownweight" DROP DEFAULT; jbe@615: COMMENT ON COLUMN "direct_voter"."ownweight" IS 'Own voting weight of member, disregarding delegations'; jbe@615: COMMENT ON COLUMN "direct_voter"."weight" IS 'Voting weight of member according to own weight and "delegating_interest_snapshot"'; jbe@615: jbe@615: ALTER TABLE "delegating_voter" ADD COLUMN "ownweight" INT4 NOT NULL DEFAULT 1; jbe@615: ALTER TABLE "delegating_voter" ALTER COLUMN "ownweight" DROP DEFAULT; jbe@615: COMMENT ON COLUMN "delegating_voter"."ownweight" IS 'Own voting weight of member, disregarding delegations'; jbe@615: COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate voting weight considering incoming delegations'; jbe@615: jbe@615: DROP VIEW "issue_delegation"; jbe@615: CREATE VIEW "issue_delegation" AS jbe@615: SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id") jbe@615: "issue"."id" AS "issue_id", jbe@615: "delegation"."id", jbe@615: "delegation"."truster_id", jbe@615: "delegation"."trustee_id", jbe@615: COALESCE("issue_privilege"."weight", "privilege"."weight") AS "weight", jbe@615: "delegation"."scope" jbe@615: FROM "issue" jbe@615: JOIN "area" jbe@615: ON "area"."id" = "issue"."area_id" jbe@615: JOIN "delegation" jbe@615: ON "delegation"."unit_id" = "area"."unit_id" jbe@615: OR "delegation"."area_id" = "area"."id" jbe@615: OR "delegation"."issue_id" = "issue"."id" jbe@615: JOIN "member" jbe@615: ON "delegation"."truster_id" = "member"."id" jbe@615: LEFT JOIN "privilege" jbe@615: ON "area"."unit_id" = "privilege"."unit_id" jbe@615: AND "delegation"."truster_id" = "privilege"."member_id" jbe@615: LEFT JOIN "issue_privilege" jbe@615: ON "issue"."id" = "issue_privilege"."issue_id" jbe@615: AND "delegation"."truster_id" = "issue_privilege"."member_id" jbe@615: WHERE "member"."active" jbe@615: AND COALESCE("issue_privilege"."voting_right", "privilege"."voting_right") jbe@615: ORDER BY jbe@615: "issue"."id", jbe@615: "delegation"."truster_id", jbe@615: "delegation"."scope" DESC; jbe@615: COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right'; jbe@615: jbe@615: CREATE OR REPLACE VIEW "unit_member" AS jbe@615: SELECT jbe@615: "privilege"."unit_id" AS "unit_id", jbe@615: "member"."id" AS "member_id", jbe@615: "privilege"."weight" jbe@615: FROM "privilege" JOIN "member" ON "member"."id" = "privilege"."member_id" jbe@615: WHERE "privilege"."voting_right" AND "member"."active"; jbe@615: jbe@615: CREATE OR REPLACE VIEW "unit_member_count" AS jbe@615: SELECT jbe@615: "unit"."id" AS "unit_id", jbe@615: count("unit_member"."member_id") AS "member_count", jbe@615: sum("unit_member"."weight") AS "member_weight" jbe@615: FROM "unit" LEFT JOIN "unit_member" jbe@615: ON "unit"."id" = "unit_member"."unit_id" jbe@615: GROUP BY "unit"."id"; jbe@615: jbe@615: CREATE OR REPLACE VIEW "event_for_notification" AS jbe@615: SELECT jbe@615: "member"."id" AS "recipient_id", jbe@615: "event".* jbe@615: FROM "member" CROSS JOIN "event" jbe@615: JOIN "issue" ON "issue"."id" = "event"."issue_id" jbe@615: JOIN "area" ON "area"."id" = "issue"."area_id" jbe@615: LEFT JOIN "privilege" ON jbe@615: "privilege"."member_id" = "member"."id" AND jbe@615: "privilege"."unit_id" = "area"."unit_id" jbe@615: LEFT JOIN "issue_privilege" ON jbe@615: "issue_privilege"."member_id" = "member"."id" AND jbe@615: "issue_privilege"."issue_id" = "event"."issue_id" jbe@615: LEFT JOIN "subscription" ON jbe@615: "subscription"."member_id" = "member"."id" AND jbe@615: "subscription"."unit_id" = "area"."unit_id" jbe@615: LEFT JOIN "ignored_area" ON jbe@615: "ignored_area"."member_id" = "member"."id" AND jbe@615: "ignored_area"."area_id" = "issue"."area_id" jbe@615: LEFT JOIN "interest" ON jbe@615: "interest"."member_id" = "member"."id" AND jbe@615: "interest"."issue_id" = "event"."issue_id" jbe@615: LEFT JOIN "supporter" ON jbe@615: "supporter"."member_id" = "member"."id" AND jbe@615: "supporter"."initiative_id" = "event"."initiative_id" jbe@615: WHERE ( jbe@615: COALESCE("issue_privilege"."voting_right", "privilege"."voting_right") OR jbe@615: "subscription"."member_id" NOTNULL jbe@615: ) AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL) jbe@615: AND ( jbe@615: "event"."event" = 'issue_state_changed'::"event_type" OR jbe@615: ( "event"."event" = 'initiative_revoked'::"event_type" AND jbe@615: "supporter"."member_id" NOTNULL ) ); jbe@615: jbe@615: CREATE OR REPLACE FUNCTION "featured_initiative" jbe@615: ( "recipient_id_p" "member"."id"%TYPE, jbe@615: "area_id_p" "area"."id"%TYPE ) jbe@615: RETURNS SETOF "initiative"."id"%TYPE jbe@615: LANGUAGE 'plpgsql' STABLE AS $$ jbe@615: DECLARE jbe@615: "counter_v" "member"."notification_counter"%TYPE; jbe@615: "sample_size_v" "member"."notification_sample_size"%TYPE; jbe@615: "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[] jbe@615: "match_v" BOOLEAN; jbe@615: "member_id_v" "member"."id"%TYPE; jbe@615: "seed_v" TEXT; jbe@615: "initiative_id_v" "initiative"."id"%TYPE; jbe@615: BEGIN jbe@615: SELECT "notification_counter", "notification_sample_size" jbe@615: INTO "counter_v", "sample_size_v" jbe@615: FROM "member" WHERE "id" = "recipient_id_p"; jbe@615: IF COALESCE("sample_size_v" <= 0, TRUE) THEN jbe@615: RETURN; jbe@615: END IF; jbe@615: "initiative_id_ary" := '{}'; jbe@615: LOOP jbe@615: "match_v" := FALSE; jbe@615: FOR "member_id_v", "seed_v" IN jbe@615: SELECT * FROM ( jbe@615: SELECT DISTINCT jbe@615: "supporter"."member_id", jbe@615: md5( jbe@615: "recipient_id_p" || '-' || jbe@615: "counter_v" || '-' || jbe@615: "area_id_p" || '-' || jbe@615: "supporter"."member_id" jbe@615: ) AS "seed" jbe@615: FROM "supporter" jbe@615: JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id" jbe@615: JOIN "issue" ON "issue"."id" = "initiative"."issue_id" jbe@615: WHERE "supporter"."member_id" != "recipient_id_p" jbe@615: AND "issue"."area_id" = "area_id_p" jbe@615: AND "issue"."state" IN ('admission', 'discussion', 'verification') jbe@615: ) AS "subquery" jbe@615: ORDER BY "seed" jbe@615: LOOP jbe@615: SELECT "initiative"."id" INTO "initiative_id_v" jbe@615: FROM "initiative" jbe@615: JOIN "issue" ON "issue"."id" = "initiative"."issue_id" jbe@615: JOIN "area" ON "area"."id" = "issue"."area_id" jbe@615: JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id" jbe@615: LEFT JOIN "supporter" AS "self_support" ON jbe@615: "self_support"."initiative_id" = "initiative"."id" AND jbe@615: "self_support"."member_id" = "recipient_id_p" jbe@615: LEFT JOIN "privilege" ON jbe@615: "privilege"."member_id" = "recipient_id_p" AND jbe@615: "privilege"."unit_id" = "area"."unit_id" jbe@615: LEFT JOIN "issue_privilege" ON jbe@617: "issue_privilege"."member_id" = "recipient_id_p" AND jbe@617: "issue_privilege"."issue_id" = "initiative"."issue_id" jbe@615: LEFT JOIN "subscription" ON jbe@615: "subscription"."member_id" = "recipient_id_p" AND jbe@615: "subscription"."unit_id" = "area"."unit_id" jbe@615: LEFT JOIN "ignored_initiative" ON jbe@615: "ignored_initiative"."member_id" = "recipient_id_p" AND jbe@615: "ignored_initiative"."initiative_id" = "initiative"."id" jbe@615: WHERE "supporter"."member_id" = "member_id_v" jbe@615: AND "issue"."area_id" = "area_id_p" jbe@615: AND "issue"."state" IN ('admission', 'discussion', 'verification') jbe@615: AND "initiative"."revoked" ISNULL jbe@615: AND "self_support"."member_id" ISNULL jbe@615: AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"] jbe@615: AND ( jbe@615: COALESCE( jbe@615: "issue_privilege"."voting_right", "privilege"."voting_right" jbe@615: ) OR "subscription"."member_id" NOTNULL ) jbe@615: AND "ignored_initiative"."member_id" ISNULL jbe@615: AND NOT EXISTS ( jbe@615: SELECT NULL FROM "draft" jbe@615: JOIN "ignored_member" ON jbe@615: "ignored_member"."member_id" = "recipient_id_p" AND jbe@615: "ignored_member"."other_member_id" = "draft"."author_id" jbe@615: WHERE "draft"."initiative_id" = "initiative"."id" jbe@615: ) jbe@615: ORDER BY md5("seed_v" || '-' || "initiative"."id") jbe@615: LIMIT 1; jbe@615: IF FOUND THEN jbe@615: "match_v" := TRUE; jbe@615: RETURN NEXT "initiative_id_v"; jbe@615: IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN jbe@615: RETURN; jbe@615: END IF; jbe@615: "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v"; jbe@615: END IF; jbe@615: END LOOP; jbe@615: EXIT WHEN NOT "match_v"; jbe@615: END LOOP; jbe@615: RETURN; jbe@615: END; jbe@615: $$; jbe@615: jbe@615: CREATE OR REPLACE FUNCTION "delegation_chain" jbe@615: ( "member_id_p" "member"."id"%TYPE, jbe@615: "unit_id_p" "unit"."id"%TYPE, jbe@615: "area_id_p" "area"."id"%TYPE, jbe@615: "issue_id_p" "issue"."id"%TYPE, jbe@615: "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL, jbe@615: "simulate_default_p" BOOLEAN DEFAULT FALSE ) jbe@615: RETURNS SETOF "delegation_chain_row" jbe@615: LANGUAGE 'plpgsql' STABLE AS $$ jbe@615: DECLARE jbe@615: "scope_v" "delegation_scope"; jbe@615: "unit_id_v" "unit"."id"%TYPE; jbe@615: "area_id_v" "area"."id"%TYPE; jbe@615: "issue_row" "issue"%ROWTYPE; jbe@615: "visited_member_ids" INT4[]; -- "member"."id"%TYPE[] jbe@615: "loop_member_id_v" "member"."id"%TYPE; jbe@615: "output_row" "delegation_chain_row"; jbe@615: "output_rows" "delegation_chain_row"[]; jbe@615: "simulate_v" BOOLEAN; jbe@615: "simulate_here_v" BOOLEAN; jbe@615: "delegation_row" "delegation"%ROWTYPE; jbe@615: "row_count" INT4; jbe@615: "i" INT4; jbe@615: "loop_v" BOOLEAN; jbe@615: BEGIN jbe@615: IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN jbe@615: RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true'; jbe@615: END IF; jbe@615: IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN jbe@615: "simulate_v" := TRUE; jbe@615: ELSE jbe@615: "simulate_v" := FALSE; jbe@615: END IF; jbe@615: IF jbe@615: "unit_id_p" NOTNULL AND jbe@615: "area_id_p" ISNULL AND jbe@615: "issue_id_p" ISNULL jbe@615: THEN jbe@615: "scope_v" := 'unit'; jbe@615: "unit_id_v" := "unit_id_p"; jbe@615: ELSIF jbe@615: "unit_id_p" ISNULL AND jbe@615: "area_id_p" NOTNULL AND jbe@615: "issue_id_p" ISNULL jbe@615: THEN jbe@615: "scope_v" := 'area'; jbe@615: "area_id_v" := "area_id_p"; jbe@615: SELECT "unit_id" INTO "unit_id_v" jbe@615: FROM "area" WHERE "id" = "area_id_v"; jbe@615: ELSIF jbe@615: "unit_id_p" ISNULL AND jbe@615: "area_id_p" ISNULL AND jbe@615: "issue_id_p" NOTNULL jbe@615: THEN jbe@615: SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p"; jbe@615: IF "issue_row"."id" ISNULL THEN jbe@615: RETURN; jbe@615: END IF; jbe@615: IF "issue_row"."closed" NOTNULL THEN jbe@615: IF "simulate_v" THEN jbe@615: RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.'; jbe@615: END IF; jbe@615: FOR "output_row" IN jbe@615: SELECT * FROM jbe@615: "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p") jbe@615: LOOP jbe@615: RETURN NEXT "output_row"; jbe@615: END LOOP; jbe@615: RETURN; jbe@615: END IF; jbe@615: "scope_v" := 'issue'; jbe@615: SELECT "area_id" INTO "area_id_v" jbe@615: FROM "issue" WHERE "id" = "issue_id_p"; jbe@615: SELECT "unit_id" INTO "unit_id_v" jbe@615: FROM "area" WHERE "id" = "area_id_v"; jbe@615: ELSE jbe@615: RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.'; jbe@615: END IF; jbe@615: "visited_member_ids" := '{}'; jbe@615: "loop_member_id_v" := NULL; jbe@615: "output_rows" := '{}'; jbe@615: "output_row"."index" := 0; jbe@615: "output_row"."member_id" := "member_id_p"; jbe@615: "output_row"."member_valid" := TRUE; jbe@615: "output_row"."participation" := FALSE; jbe@615: "output_row"."overridden" := FALSE; jbe@615: "output_row"."disabled_out" := FALSE; jbe@615: "output_row"."scope_out" := NULL; jbe@615: LOOP jbe@615: IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN jbe@615: "loop_member_id_v" := "output_row"."member_id"; jbe@615: ELSE jbe@615: "visited_member_ids" := jbe@615: "visited_member_ids" || "output_row"."member_id"; jbe@615: END IF; jbe@615: IF "output_row"."participation" ISNULL THEN jbe@615: "output_row"."overridden" := NULL; jbe@615: ELSIF "output_row"."participation" THEN jbe@615: "output_row"."overridden" := TRUE; jbe@615: END IF; jbe@615: "output_row"."scope_in" := "output_row"."scope_out"; jbe@615: "output_row"."member_valid" := EXISTS ( jbe@615: SELECT NULL FROM "member" jbe@615: LEFT JOIN "privilege" jbe@615: ON "privilege"."member_id" = "member"."id" jbe@615: AND "privilege"."unit_id" = "unit_id_v" jbe@615: LEFT JOIN "issue_privilege" jbe@615: ON "issue_privilege"."member_id" = "member"."id" jbe@615: AND "issue_privilege"."issue_id" = "issue_id_p" jbe@615: WHERE "id" = "output_row"."member_id" jbe@615: AND "member"."active" jbe@615: AND COALESCE( jbe@615: "issue_privilege"."voting_right", "privilege"."voting_right") jbe@615: ); jbe@615: "simulate_here_v" := ( jbe@615: "simulate_v" AND jbe@615: "output_row"."member_id" = "member_id_p" jbe@615: ); jbe@615: "delegation_row" := ROW(NULL); jbe@615: IF "output_row"."member_valid" OR "simulate_here_v" THEN jbe@615: IF "scope_v" = 'unit' THEN jbe@615: IF NOT "simulate_here_v" THEN jbe@615: SELECT * INTO "delegation_row" FROM "delegation" jbe@615: WHERE "truster_id" = "output_row"."member_id" jbe@615: AND "unit_id" = "unit_id_v"; jbe@615: END IF; jbe@615: ELSIF "scope_v" = 'area' THEN jbe@615: IF "simulate_here_v" THEN jbe@615: IF "simulate_trustee_id_p" ISNULL THEN jbe@615: SELECT * INTO "delegation_row" FROM "delegation" jbe@615: WHERE "truster_id" = "output_row"."member_id" jbe@615: AND "unit_id" = "unit_id_v"; jbe@615: END IF; jbe@615: ELSE jbe@615: SELECT * INTO "delegation_row" FROM "delegation" jbe@615: WHERE "truster_id" = "output_row"."member_id" jbe@615: AND ( jbe@615: "unit_id" = "unit_id_v" OR jbe@615: "area_id" = "area_id_v" jbe@615: ) jbe@615: ORDER BY "scope" DESC; jbe@615: END IF; jbe@615: ELSIF "scope_v" = 'issue' THEN jbe@615: IF "issue_row"."fully_frozen" ISNULL THEN jbe@615: "output_row"."participation" := EXISTS ( jbe@615: SELECT NULL FROM "interest" jbe@615: WHERE "issue_id" = "issue_id_p" jbe@615: AND "member_id" = "output_row"."member_id" jbe@615: ); jbe@615: ELSE jbe@615: IF "output_row"."member_id" = "member_id_p" THEN jbe@615: "output_row"."participation" := EXISTS ( jbe@615: SELECT NULL FROM "direct_voter" jbe@615: WHERE "issue_id" = "issue_id_p" jbe@615: AND "member_id" = "output_row"."member_id" jbe@615: ); jbe@615: ELSE jbe@615: "output_row"."participation" := NULL; jbe@615: END IF; jbe@615: END IF; jbe@615: IF "simulate_here_v" THEN jbe@615: IF "simulate_trustee_id_p" ISNULL THEN jbe@615: SELECT * INTO "delegation_row" FROM "delegation" jbe@615: WHERE "truster_id" = "output_row"."member_id" jbe@615: AND ( jbe@615: "unit_id" = "unit_id_v" OR jbe@615: "area_id" = "area_id_v" jbe@615: ) jbe@615: ORDER BY "scope" DESC; jbe@615: END IF; jbe@615: ELSE jbe@615: SELECT * INTO "delegation_row" FROM "delegation" jbe@615: WHERE "truster_id" = "output_row"."member_id" jbe@615: AND ( jbe@615: "unit_id" = "unit_id_v" OR jbe@615: "area_id" = "area_id_v" OR jbe@615: "issue_id" = "issue_id_p" jbe@615: ) jbe@615: ORDER BY "scope" DESC; jbe@615: END IF; jbe@615: END IF; jbe@615: ELSE jbe@615: "output_row"."participation" := FALSE; jbe@615: END IF; jbe@615: IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN jbe@615: "output_row"."scope_out" := "scope_v"; jbe@615: "output_rows" := "output_rows" || "output_row"; jbe@615: "output_row"."member_id" := "simulate_trustee_id_p"; jbe@615: ELSIF "delegation_row"."trustee_id" NOTNULL THEN jbe@615: "output_row"."scope_out" := "delegation_row"."scope"; jbe@615: "output_rows" := "output_rows" || "output_row"; jbe@615: "output_row"."member_id" := "delegation_row"."trustee_id"; jbe@615: ELSIF "delegation_row"."scope" NOTNULL THEN jbe@615: "output_row"."scope_out" := "delegation_row"."scope"; jbe@615: "output_row"."disabled_out" := TRUE; jbe@615: "output_rows" := "output_rows" || "output_row"; jbe@615: EXIT; jbe@615: ELSE jbe@615: "output_row"."scope_out" := NULL; jbe@615: "output_rows" := "output_rows" || "output_row"; jbe@615: EXIT; jbe@615: END IF; jbe@615: EXIT WHEN "loop_member_id_v" NOTNULL; jbe@615: "output_row"."index" := "output_row"."index" + 1; jbe@615: END LOOP; jbe@615: "row_count" := array_upper("output_rows", 1); jbe@615: "i" := 1; jbe@615: "loop_v" := FALSE; jbe@615: LOOP jbe@615: "output_row" := "output_rows"["i"]; jbe@615: EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results! jbe@615: IF "loop_v" THEN jbe@615: IF "i" + 1 = "row_count" THEN jbe@615: "output_row"."loop" := 'last'; jbe@615: ELSIF "i" = "row_count" THEN jbe@615: "output_row"."loop" := 'repetition'; jbe@615: ELSE jbe@615: "output_row"."loop" := 'intermediate'; jbe@615: END IF; jbe@615: ELSIF "output_row"."member_id" = "loop_member_id_v" THEN jbe@615: "output_row"."loop" := 'first'; jbe@615: "loop_v" := TRUE; jbe@615: END IF; jbe@615: IF "scope_v" = 'unit' THEN jbe@615: "output_row"."participation" := NULL; jbe@615: END IF; jbe@615: RETURN NEXT "output_row"; jbe@615: "i" := "i" + 1; jbe@615: END LOOP; jbe@615: RETURN; jbe@615: END; jbe@615: $$; jbe@615: jbe@615: CREATE OR REPLACE FUNCTION "calculate_member_counts"() jbe@615: RETURNS VOID jbe@615: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@615: BEGIN jbe@615: PERFORM "require_transaction_isolation"(); jbe@615: DELETE FROM "member_count"; jbe@615: INSERT INTO "member_count" ("total_count") jbe@615: SELECT "total_count" FROM "member_count_view"; jbe@615: UPDATE "unit" SET jbe@615: "member_count" = "view"."member_count", jbe@615: "member_weight" = "view"."member_weight" jbe@615: FROM "unit_member_count" AS "view" jbe@615: WHERE "view"."unit_id" = "unit"."id"; jbe@615: RETURN; jbe@615: END; jbe@615: $$; jbe@615: COMMENT ON FUNCTION "calculate_member_counts"() IS 'Updates "member_count" table and "member_count" and "member_weight" columns of table "area" by materializing data from views "member_count_view" and "unit_member_count"'; jbe@615: jbe@615: CREATE OR REPLACE FUNCTION "weight_of_added_delegations_for_snapshot" jbe@615: ( "snapshot_id_p" "snapshot"."id"%TYPE, jbe@615: "issue_id_p" "issue"."id"%TYPE, jbe@615: "member_id_p" "member"."id"%TYPE, jbe@615: "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE ) jbe@615: RETURNS "direct_interest_snapshot"."weight"%TYPE jbe@615: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@615: DECLARE jbe@615: "issue_delegation_row" "issue_delegation"%ROWTYPE; jbe@615: "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE; jbe@615: "weight_v" INT4; jbe@615: "sub_weight_v" INT4; jbe@615: BEGIN jbe@615: PERFORM "require_transaction_isolation"(); jbe@615: "weight_v" := 0; jbe@615: FOR "issue_delegation_row" IN jbe@615: SELECT * FROM "issue_delegation" jbe@615: WHERE "trustee_id" = "member_id_p" jbe@615: AND "issue_id" = "issue_id_p" jbe@615: LOOP jbe@615: IF NOT EXISTS ( jbe@615: SELECT NULL FROM "direct_interest_snapshot" jbe@615: WHERE "snapshot_id" = "snapshot_id_p" jbe@615: AND "issue_id" = "issue_id_p" jbe@615: AND "member_id" = "issue_delegation_row"."truster_id" jbe@615: ) AND NOT EXISTS ( jbe@615: SELECT NULL FROM "delegating_interest_snapshot" jbe@615: WHERE "snapshot_id" = "snapshot_id_p" jbe@615: AND "issue_id" = "issue_id_p" jbe@615: AND "member_id" = "issue_delegation_row"."truster_id" jbe@615: ) THEN jbe@615: "delegate_member_ids_v" := jbe@615: "member_id_p" || "delegate_member_ids_p"; jbe@615: INSERT INTO "delegating_interest_snapshot" ( jbe@615: "snapshot_id", jbe@615: "issue_id", jbe@615: "member_id", jbe@615: "ownweight", jbe@615: "scope", jbe@615: "delegate_member_ids" jbe@615: ) VALUES ( jbe@615: "snapshot_id_p", jbe@615: "issue_id_p", jbe@615: "issue_delegation_row"."truster_id", jbe@615: "issue_delegation_row"."weight", jbe@615: "issue_delegation_row"."scope", jbe@615: "delegate_member_ids_v" jbe@615: ); jbe@615: "sub_weight_v" := "issue_delegation_row"."weight" + jbe@615: "weight_of_added_delegations_for_snapshot"( jbe@615: "snapshot_id_p", jbe@615: "issue_id_p", jbe@615: "issue_delegation_row"."truster_id", jbe@615: "delegate_member_ids_v" jbe@615: ); jbe@615: UPDATE "delegating_interest_snapshot" jbe@615: SET "weight" = "sub_weight_v" jbe@615: WHERE "snapshot_id" = "snapshot_id_p" jbe@615: AND "issue_id" = "issue_id_p" jbe@615: AND "member_id" = "issue_delegation_row"."truster_id"; jbe@615: "weight_v" := "weight_v" + "sub_weight_v"; jbe@615: END IF; jbe@615: END LOOP; jbe@615: RETURN "weight_v"; jbe@615: END; jbe@615: $$; jbe@615: jbe@615: CREATE OR REPLACE FUNCTION "take_snapshot" jbe@615: ( "issue_id_p" "issue"."id"%TYPE, jbe@615: "area_id_p" "area"."id"%TYPE = NULL ) jbe@615: RETURNS "snapshot"."id"%TYPE jbe@615: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@615: DECLARE jbe@615: "area_id_v" "area"."id"%TYPE; jbe@615: "unit_id_v" "unit"."id"%TYPE; jbe@615: "snapshot_id_v" "snapshot"."id"%TYPE; jbe@615: "issue_id_v" "issue"."id"%TYPE; jbe@615: "member_id_v" "member"."id"%TYPE; jbe@615: BEGIN jbe@615: IF "issue_id_p" NOTNULL AND "area_id_p" NOTNULL THEN jbe@615: RAISE EXCEPTION 'One of "issue_id_p" and "area_id_p" must be NULL'; jbe@615: END IF; jbe@615: PERFORM "require_transaction_isolation"(); jbe@615: IF "issue_id_p" ISNULL THEN jbe@615: "area_id_v" := "area_id_p"; jbe@615: ELSE jbe@615: SELECT "area_id" INTO "area_id_v" jbe@615: FROM "issue" WHERE "id" = "issue_id_p"; jbe@615: END IF; jbe@615: SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v"; jbe@615: INSERT INTO "snapshot" ("area_id", "issue_id") jbe@615: VALUES ("area_id_v", "issue_id_p") jbe@615: RETURNING "id" INTO "snapshot_id_v"; jbe@615: INSERT INTO "snapshot_population" ("snapshot_id", "member_id", "weight") jbe@615: SELECT jbe@615: "snapshot_id_v", jbe@615: "member"."id", jbe@615: COALESCE("issue_privilege"."weight", "privilege"."weight") jbe@615: FROM "member" jbe@615: LEFT JOIN "privilege" jbe@615: ON "privilege"."unit_id" = "unit_id_v" jbe@615: AND "privilege"."member_id" = "member"."id" jbe@615: LEFT JOIN "issue_privilege" jbe@615: ON "issue_privilege"."issue_id" = "issue_id_p" jbe@615: AND "issue_privilege"."member_id" = "member"."id" jbe@615: WHERE "member"."active" AND COALESCE( jbe@615: "issue_privilege"."voting_right", "privilege"."voting_right"); jbe@615: UPDATE "snapshot" SET jbe@615: "population" = ( jbe@615: SELECT sum("weight") FROM "snapshot_population" jbe@615: WHERE "snapshot_id" = "snapshot_id_v" jbe@615: ) WHERE "id" = "snapshot_id_v"; jbe@615: FOR "issue_id_v" IN jbe@615: SELECT "id" FROM "issue" jbe@615: WHERE CASE WHEN "issue_id_p" ISNULL THEN jbe@615: "area_id" = "area_id_p" AND jbe@615: "state" = 'admission' jbe@615: ELSE jbe@615: "id" = "issue_id_p" jbe@615: END jbe@615: LOOP jbe@615: INSERT INTO "snapshot_issue" ("snapshot_id", "issue_id") jbe@615: VALUES ("snapshot_id_v", "issue_id_v"); jbe@615: INSERT INTO "direct_interest_snapshot" jbe@615: ("snapshot_id", "issue_id", "member_id", "ownweight") jbe@615: SELECT jbe@615: "snapshot_id_v" AS "snapshot_id", jbe@615: "issue_id_v" AS "issue_id", jbe@615: "member"."id" AS "member_id", jbe@615: COALESCE( jbe@615: "issue_privilege"."weight", "privilege"."weight" jbe@615: ) AS "ownweight" jbe@615: FROM "issue" jbe@615: JOIN "area" ON "issue"."area_id" = "area"."id" jbe@615: JOIN "interest" ON "issue"."id" = "interest"."issue_id" jbe@615: JOIN "member" ON "interest"."member_id" = "member"."id" jbe@615: LEFT JOIN "privilege" jbe@615: ON "privilege"."unit_id" = "area"."unit_id" jbe@615: AND "privilege"."member_id" = "member"."id" jbe@615: LEFT JOIN "issue_privilege" jbe@615: ON "issue_privilege"."issue_id" = "issue_id_v" jbe@615: AND "issue_privilege"."member_id" = "member"."id" jbe@615: WHERE "issue"."id" = "issue_id_v" jbe@615: AND "member"."active" AND COALESCE( jbe@615: "issue_privilege"."voting_right", "privilege"."voting_right"); jbe@615: FOR "member_id_v" IN jbe@615: SELECT "member_id" FROM "direct_interest_snapshot" jbe@615: WHERE "snapshot_id" = "snapshot_id_v" jbe@615: AND "issue_id" = "issue_id_v" jbe@615: LOOP jbe@615: UPDATE "direct_interest_snapshot" SET jbe@615: "weight" = "ownweight" + jbe@615: "weight_of_added_delegations_for_snapshot"( jbe@615: "snapshot_id_v", jbe@615: "issue_id_v", jbe@615: "member_id_v", jbe@615: '{}' jbe@615: ) jbe@615: WHERE "snapshot_id" = "snapshot_id_v" jbe@615: AND "issue_id" = "issue_id_v" jbe@615: AND "member_id" = "member_id_v"; jbe@615: END LOOP; jbe@615: INSERT INTO "direct_supporter_snapshot" jbe@615: ( "snapshot_id", "issue_id", "initiative_id", "member_id", jbe@615: "draft_id", "informed", "satisfied" ) jbe@615: SELECT jbe@615: "snapshot_id_v" AS "snapshot_id", jbe@615: "issue_id_v" AS "issue_id", jbe@615: "initiative"."id" AS "initiative_id", jbe@615: "supporter"."member_id" AS "member_id", jbe@615: "supporter"."draft_id" AS "draft_id", jbe@615: "supporter"."draft_id" = "current_draft"."id" AS "informed", jbe@615: NOT EXISTS ( jbe@615: SELECT NULL FROM "critical_opinion" jbe@615: WHERE "initiative_id" = "initiative"."id" jbe@615: AND "member_id" = "supporter"."member_id" jbe@615: ) AS "satisfied" jbe@615: FROM "initiative" jbe@615: JOIN "supporter" jbe@615: ON "supporter"."initiative_id" = "initiative"."id" jbe@615: JOIN "current_draft" jbe@615: ON "initiative"."id" = "current_draft"."initiative_id" jbe@615: JOIN "direct_interest_snapshot" jbe@615: ON "snapshot_id_v" = "direct_interest_snapshot"."snapshot_id" jbe@615: AND "supporter"."member_id" = "direct_interest_snapshot"."member_id" jbe@615: AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id" jbe@615: WHERE "initiative"."issue_id" = "issue_id_v"; jbe@615: DELETE FROM "temporary_suggestion_counts"; jbe@615: INSERT INTO "temporary_suggestion_counts" jbe@615: ( "id", jbe@615: "minus2_unfulfilled_count", "minus2_fulfilled_count", jbe@615: "minus1_unfulfilled_count", "minus1_fulfilled_count", jbe@615: "plus1_unfulfilled_count", "plus1_fulfilled_count", jbe@615: "plus2_unfulfilled_count", "plus2_fulfilled_count" ) jbe@615: SELECT jbe@615: "suggestion"."id", jbe@615: ( SELECT coalesce(sum("di"."weight"), 0) jbe@615: FROM "opinion" JOIN "direct_interest_snapshot" AS "di" jbe@615: ON "di"."snapshot_id" = "snapshot_id_v" jbe@615: AND "di"."issue_id" = "issue_id_v" jbe@615: AND "di"."member_id" = "opinion"."member_id" jbe@615: WHERE "opinion"."suggestion_id" = "suggestion"."id" jbe@615: AND "opinion"."degree" = -2 jbe@615: AND "opinion"."fulfilled" = FALSE jbe@615: ) AS "minus2_unfulfilled_count", jbe@615: ( SELECT coalesce(sum("di"."weight"), 0) jbe@615: FROM "opinion" JOIN "direct_interest_snapshot" AS "di" jbe@615: ON "di"."snapshot_id" = "snapshot_id_v" jbe@615: AND "di"."issue_id" = "issue_id_v" jbe@615: AND "di"."member_id" = "opinion"."member_id" jbe@615: WHERE "opinion"."suggestion_id" = "suggestion"."id" jbe@615: AND "opinion"."degree" = -2 jbe@615: AND "opinion"."fulfilled" = TRUE jbe@615: ) AS "minus2_fulfilled_count", jbe@615: ( SELECT coalesce(sum("di"."weight"), 0) jbe@615: FROM "opinion" JOIN "direct_interest_snapshot" AS "di" jbe@615: ON "di"."snapshot_id" = "snapshot_id_v" jbe@615: AND "di"."issue_id" = "issue_id_v" jbe@615: AND "di"."member_id" = "opinion"."member_id" jbe@615: WHERE "opinion"."suggestion_id" = "suggestion"."id" jbe@615: AND "opinion"."degree" = -1 jbe@615: AND "opinion"."fulfilled" = FALSE jbe@615: ) AS "minus1_unfulfilled_count", jbe@615: ( SELECT coalesce(sum("di"."weight"), 0) jbe@615: FROM "opinion" JOIN "direct_interest_snapshot" AS "di" jbe@615: ON "di"."snapshot_id" = "snapshot_id_v" jbe@615: AND "di"."issue_id" = "issue_id_v" jbe@615: AND "di"."member_id" = "opinion"."member_id" jbe@615: WHERE "opinion"."suggestion_id" = "suggestion"."id" jbe@615: AND "opinion"."degree" = -1 jbe@615: AND "opinion"."fulfilled" = TRUE jbe@615: ) AS "minus1_fulfilled_count", jbe@615: ( SELECT coalesce(sum("di"."weight"), 0) jbe@615: FROM "opinion" JOIN "direct_interest_snapshot" AS "di" jbe@615: ON "di"."snapshot_id" = "snapshot_id_v" jbe@615: AND "di"."issue_id" = "issue_id_v" jbe@615: AND "di"."member_id" = "opinion"."member_id" jbe@615: WHERE "opinion"."suggestion_id" = "suggestion"."id" jbe@615: AND "opinion"."degree" = 1 jbe@615: AND "opinion"."fulfilled" = FALSE jbe@615: ) AS "plus1_unfulfilled_count", jbe@615: ( SELECT coalesce(sum("di"."weight"), 0) jbe@615: FROM "opinion" JOIN "direct_interest_snapshot" AS "di" jbe@615: ON "di"."snapshot_id" = "snapshot_id_v" jbe@615: AND "di"."issue_id" = "issue_id_v" jbe@615: AND "di"."member_id" = "opinion"."member_id" jbe@615: WHERE "opinion"."suggestion_id" = "suggestion"."id" jbe@615: AND "opinion"."degree" = 1 jbe@615: AND "opinion"."fulfilled" = TRUE jbe@615: ) AS "plus1_fulfilled_count", jbe@615: ( SELECT coalesce(sum("di"."weight"), 0) jbe@615: FROM "opinion" JOIN "direct_interest_snapshot" AS "di" jbe@615: ON "di"."snapshot_id" = "snapshot_id_v" jbe@615: AND "di"."issue_id" = "issue_id_v" jbe@615: AND "di"."member_id" = "opinion"."member_id" jbe@615: WHERE "opinion"."suggestion_id" = "suggestion"."id" jbe@615: AND "opinion"."degree" = 2 jbe@615: AND "opinion"."fulfilled" = FALSE jbe@615: ) AS "plus2_unfulfilled_count", jbe@615: ( SELECT coalesce(sum("di"."weight"), 0) jbe@615: FROM "opinion" JOIN "direct_interest_snapshot" AS "di" jbe@615: ON "di"."snapshot_id" = "snapshot_id_v" jbe@615: AND "di"."issue_id" = "issue_id_v" jbe@615: AND "di"."member_id" = "opinion"."member_id" jbe@615: WHERE "opinion"."suggestion_id" = "suggestion"."id" jbe@615: AND "opinion"."degree" = 2 jbe@615: AND "opinion"."fulfilled" = TRUE jbe@615: ) AS "plus2_fulfilled_count" jbe@615: FROM "suggestion" JOIN "initiative" jbe@615: ON "suggestion"."initiative_id" = "initiative"."id" jbe@615: WHERE "initiative"."issue_id" = "issue_id_v"; jbe@615: END LOOP; jbe@615: RETURN "snapshot_id_v"; jbe@615: END; jbe@615: $$; jbe@615: jbe@615: CREATE OR REPLACE FUNCTION "weight_of_added_vote_delegations" jbe@615: ( "issue_id_p" "issue"."id"%TYPE, jbe@615: "member_id_p" "member"."id"%TYPE, jbe@615: "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE ) jbe@615: RETURNS "direct_voter"."weight"%TYPE jbe@615: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@615: DECLARE jbe@615: "issue_delegation_row" "issue_delegation"%ROWTYPE; jbe@615: "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE; jbe@615: "weight_v" INT4; jbe@615: "sub_weight_v" INT4; jbe@615: BEGIN jbe@615: PERFORM "require_transaction_isolation"(); jbe@615: "weight_v" := 0; jbe@615: FOR "issue_delegation_row" IN jbe@615: SELECT * FROM "issue_delegation" jbe@615: WHERE "trustee_id" = "member_id_p" jbe@615: AND "issue_id" = "issue_id_p" jbe@615: LOOP jbe@615: IF NOT EXISTS ( jbe@615: SELECT NULL FROM "direct_voter" jbe@615: WHERE "member_id" = "issue_delegation_row"."truster_id" jbe@615: AND "issue_id" = "issue_id_p" jbe@615: ) AND NOT EXISTS ( jbe@615: SELECT NULL FROM "delegating_voter" jbe@615: WHERE "member_id" = "issue_delegation_row"."truster_id" jbe@615: AND "issue_id" = "issue_id_p" jbe@615: ) THEN jbe@615: "delegate_member_ids_v" := jbe@615: "member_id_p" || "delegate_member_ids_p"; jbe@615: INSERT INTO "delegating_voter" ( jbe@615: "issue_id", jbe@615: "member_id", jbe@615: "ownweight", jbe@615: "scope", jbe@615: "delegate_member_ids" jbe@615: ) VALUES ( jbe@615: "issue_id_p", jbe@615: "issue_delegation_row"."truster_id", jbe@615: "issue_delegation_row"."weight", jbe@615: "issue_delegation_row"."scope", jbe@615: "delegate_member_ids_v" jbe@615: ); jbe@615: "sub_weight_v" := "issue_delegation_row"."weight" + jbe@615: "weight_of_added_vote_delegations"( jbe@615: "issue_id_p", jbe@615: "issue_delegation_row"."truster_id", jbe@615: "delegate_member_ids_v" jbe@615: ); jbe@615: UPDATE "delegating_voter" jbe@615: SET "weight" = "sub_weight_v" jbe@615: WHERE "issue_id" = "issue_id_p" jbe@615: AND "member_id" = "issue_delegation_row"."truster_id"; jbe@615: "weight_v" := "weight_v" + "sub_weight_v"; jbe@615: END IF; jbe@615: END LOOP; jbe@615: RETURN "weight_v"; jbe@615: END; jbe@615: $$; jbe@615: jbe@615: CREATE OR REPLACE FUNCTION "add_vote_delegations" jbe@615: ( "issue_id_p" "issue"."id"%TYPE ) jbe@615: RETURNS VOID jbe@615: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@615: DECLARE jbe@615: "member_id_v" "member"."id"%TYPE; jbe@615: BEGIN jbe@615: PERFORM "require_transaction_isolation"(); jbe@615: FOR "member_id_v" IN jbe@615: SELECT "member_id" FROM "direct_voter" jbe@615: WHERE "issue_id" = "issue_id_p" jbe@615: LOOP jbe@615: UPDATE "direct_voter" SET jbe@615: "weight" = "ownweight" + "weight_of_added_vote_delegations"( jbe@615: "issue_id_p", jbe@615: "member_id_v", jbe@615: '{}' jbe@615: ) jbe@615: WHERE "member_id" = "member_id_v" jbe@615: AND "issue_id" = "issue_id_p"; jbe@615: END LOOP; jbe@615: RETURN; jbe@615: END; jbe@615: $$; jbe@615: jbe@615: CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE) jbe@615: RETURNS VOID jbe@615: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@615: DECLARE jbe@615: "area_id_v" "area"."id"%TYPE; jbe@615: "unit_id_v" "unit"."id"%TYPE; jbe@615: "member_id_v" "member"."id"%TYPE; jbe@615: BEGIN jbe@615: PERFORM "require_transaction_isolation"(); jbe@615: SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p"; jbe@615: SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v"; jbe@615: -- override protection triggers: jbe@615: INSERT INTO "temporary_transaction_data" ("key", "value") jbe@615: VALUES ('override_protection_triggers', TRUE::TEXT); jbe@615: -- delete timestamp of voting comment: jbe@615: UPDATE "direct_voter" SET "comment_changed" = NULL jbe@615: WHERE "issue_id" = "issue_id_p"; jbe@615: -- delete delegating votes (in cases of manual reset of issue state): jbe@615: DELETE FROM "delegating_voter" jbe@615: WHERE "issue_id" = "issue_id_p"; jbe@615: -- delete votes from non-privileged voters: jbe@615: DELETE FROM "direct_voter" jbe@615: USING ( jbe@615: SELECT "direct_voter"."member_id" jbe@615: FROM "direct_voter" jbe@615: JOIN "member" ON "direct_voter"."member_id" = "member"."id" jbe@615: LEFT JOIN "privilege" jbe@615: ON "privilege"."unit_id" = "unit_id_v" jbe@615: AND "privilege"."member_id" = "direct_voter"."member_id" jbe@615: LEFT JOIN "issue_privilege" jbe@615: ON "issue_privilege"."issue_id" = "issue_id_p" jbe@615: AND "issue_privilege"."member_id" = "direct_voter"."member_id" jbe@615: WHERE "direct_voter"."issue_id" = "issue_id_p" AND ( jbe@615: "member"."active" = FALSE OR jbe@615: COALESCE( jbe@615: "issue_privilege"."voting_right", jbe@615: "privilege"."voting_right", jbe@615: FALSE jbe@615: ) = FALSE jbe@615: ) jbe@615: ) AS "subquery" jbe@615: WHERE "direct_voter"."issue_id" = "issue_id_p" jbe@615: AND "direct_voter"."member_id" = "subquery"."member_id"; jbe@615: -- consider voting weight and delegations: jbe@615: UPDATE "direct_voter" SET "ownweight" = "privilege"."weight" jbe@615: FROM "privilege" jbe@615: WHERE "issue_id" = "issue_id_p" jbe@615: AND "privilege"."unit_id" = "unit_id_v" jbe@615: AND "privilege"."member_id" = "direct_voter"."member_id"; jbe@615: UPDATE "direct_voter" SET "ownweight" = "issue_privilege"."weight" jbe@615: FROM "issue_privilege" jbe@615: WHERE "direct_voter"."issue_id" = "issue_id_p" jbe@615: AND "issue_privilege"."issue_id" = "issue_id_p" jbe@615: AND "issue_privilege"."member_id" = "direct_voter"."member_id"; jbe@615: PERFORM "add_vote_delegations"("issue_id_p"); jbe@615: -- mark first preferences: jbe@615: UPDATE "vote" SET "first_preference" = "subquery"."first_preference" jbe@615: FROM ( jbe@615: SELECT jbe@615: "vote"."initiative_id", jbe@615: "vote"."member_id", jbe@615: CASE WHEN "vote"."grade" > 0 THEN jbe@615: CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END jbe@615: ELSE NULL jbe@615: END AS "first_preference" jbe@615: FROM "vote" jbe@615: JOIN "initiative" -- NOTE: due to missing index on issue_id jbe@615: ON "vote"."issue_id" = "initiative"."issue_id" jbe@615: JOIN "vote" AS "agg" jbe@615: ON "initiative"."id" = "agg"."initiative_id" jbe@615: AND "vote"."member_id" = "agg"."member_id" jbe@615: GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade" jbe@615: ) AS "subquery" jbe@615: WHERE "vote"."issue_id" = "issue_id_p" jbe@615: AND "vote"."initiative_id" = "subquery"."initiative_id" jbe@615: AND "vote"."member_id" = "subquery"."member_id"; jbe@615: -- finish overriding protection triggers (avoids garbage): jbe@615: DELETE FROM "temporary_transaction_data" jbe@615: WHERE "key" = 'override_protection_triggers'; jbe@615: -- materialize battle_view: jbe@615: -- NOTE: "closed" column of issue must be set at this point jbe@615: DELETE FROM "battle" WHERE "issue_id" = "issue_id_p"; jbe@615: INSERT INTO "battle" ( jbe@615: "issue_id", jbe@615: "winning_initiative_id", "losing_initiative_id", jbe@615: "count" jbe@615: ) SELECT jbe@615: "issue_id", jbe@615: "winning_initiative_id", "losing_initiative_id", jbe@615: "count" jbe@615: FROM "battle_view" WHERE "issue_id" = "issue_id_p"; jbe@615: -- set voter count: jbe@615: UPDATE "issue" SET jbe@615: "voter_count" = ( jbe@615: SELECT coalesce(sum("weight"), 0) jbe@615: FROM "direct_voter" WHERE "issue_id" = "issue_id_p" jbe@615: ) jbe@615: WHERE "id" = "issue_id_p"; jbe@615: -- copy "positive_votes" and "negative_votes" from "battle" table: jbe@615: -- NOTE: "first_preference_votes" is set to a default of 0 at this step jbe@615: UPDATE "initiative" SET jbe@615: "first_preference_votes" = 0, jbe@615: "positive_votes" = "battle_win"."count", jbe@615: "negative_votes" = "battle_lose"."count" jbe@615: FROM "battle" AS "battle_win", "battle" AS "battle_lose" jbe@615: WHERE jbe@615: "battle_win"."issue_id" = "issue_id_p" AND jbe@615: "battle_win"."winning_initiative_id" = "initiative"."id" AND jbe@615: "battle_win"."losing_initiative_id" ISNULL AND jbe@615: "battle_lose"."issue_id" = "issue_id_p" AND jbe@615: "battle_lose"."losing_initiative_id" = "initiative"."id" AND jbe@615: "battle_lose"."winning_initiative_id" ISNULL; jbe@615: -- calculate "first_preference_votes": jbe@615: -- NOTE: will only set values not equal to zero jbe@615: UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum" jbe@615: FROM ( jbe@615: SELECT "vote"."initiative_id", sum("direct_voter"."weight") jbe@615: FROM "vote" JOIN "direct_voter" jbe@615: ON "vote"."issue_id" = "direct_voter"."issue_id" jbe@615: AND "vote"."member_id" = "direct_voter"."member_id" jbe@615: WHERE "vote"."first_preference" jbe@615: GROUP BY "vote"."initiative_id" jbe@615: ) AS "subquery" jbe@615: WHERE "initiative"."issue_id" = "issue_id_p" jbe@615: AND "initiative"."admitted" jbe@615: AND "initiative"."id" = "subquery"."initiative_id"; jbe@615: END; jbe@615: $$; jbe@615: jbe@615: COMMIT;