liquid_feedback_core

annotate core.sql @ 528:3e28fd842354

Work on new issue admission system (replacing current approach of 1st quorum); Added support for geo-tagging and spatial indexing
author jbe
date Sun May 29 20:42:40 2016 +0200 (2016-05-29)
parents 2a2f76da1177
children 96ee2db56bec
rev   line source
jbe@0 1
jbe@0 2 -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index
jbe@0 3
jbe@0 4 BEGIN;
jbe@0 5
jbe@5 6 CREATE VIEW "liquid_feedback_version" AS
jbe@457 7 SELECT * FROM (VALUES ('4.0.0', 4, 0, 0))
jbe@5 8 AS "subquery"("string", "major", "minor", "revision");
jbe@5 9
jbe@0 10
jbe@0 11
jbe@7 12 ----------------------
jbe@7 13 -- Full text search --
jbe@7 14 ----------------------
jbe@7 15
jbe@7 16
jbe@7 17 CREATE FUNCTION "text_search_query"("query_text_p" TEXT)
jbe@7 18 RETURNS TSQUERY
jbe@7 19 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@7 20 BEGIN
jbe@7 21 RETURN plainto_tsquery('pg_catalog.simple', "query_text_p");
jbe@7 22 END;
jbe@7 23 $$;
jbe@7 24
jbe@7 25 COMMENT ON FUNCTION "text_search_query"(TEXT) IS 'Usage: WHERE "text_search_data" @@ "text_search_query"(''<user query>'')';
jbe@7 26
jbe@7 27
jbe@7 28 CREATE FUNCTION "highlight"
jbe@7 29 ( "body_p" TEXT,
jbe@7 30 "query_text_p" TEXT )
jbe@7 31 RETURNS TEXT
jbe@7 32 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@7 33 BEGIN
jbe@7 34 RETURN ts_headline(
jbe@7 35 'pg_catalog.simple',
jbe@8 36 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
jbe@7 37 "text_search_query"("query_text_p"),
jbe@7 38 'StartSel=* StopSel=* HighlightAll=TRUE' );
jbe@7 39 END;
jbe@7 40 $$;
jbe@7 41
jbe@7 42 COMMENT ON FUNCTION "highlight"
jbe@7 43 ( "body_p" TEXT,
jbe@7 44 "query_text_p" TEXT )
jbe@7 45 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 46
jbe@7 47
jbe@7 48
jbe@528 49 -----------------------------------------------
jbe@528 50 -- spatial indexing and distance calculation --
jbe@528 51 -----------------------------------------------
jbe@528 52
jbe@528 53
jbe@528 54 CREATE DOMAIN "geoindex" AS point CHECK (VALUE <@ '((-1,-1),(1,1))'::box);
jbe@528 55
jbe@528 56 COMMENT ON DOMAIN "geoindex" IS 'Data type used for indexing geographical coordinates';
jbe@528 57
jbe@528 58
jbe@528 59 CREATE FUNCTION "geoindex"
jbe@528 60 ( "latitude_p" FLOAT,
jbe@528 61 "longitude_p" FLOAT )
jbe@528 62 RETURNS "geoindex"
jbe@528 63 LANGUAGE sql IMMUTABLE STRICT AS $$
jbe@528 64 SELECT point("latitude_p" / 90, "longitude_p" / 180)::"geoindex"
jbe@528 65 $$;
jbe@528 66
jbe@528 67 COMMENT ON FUNCTION "geoindex"
jbe@528 68 (FLOAT, FLOAT)
jbe@528 69 IS 'Transforms coordinates given as latitude (from -90 to 90) and logitude (from -180 to 180) into a data type suitable for a quadtree index';
jbe@528 70
jbe@528 71
jbe@528 72 CREATE TYPE "geosearch" AS (
jbe@528 73 "lat" FLOAT,
jbe@528 74 "lon" FLOAT,
jbe@528 75 "c3" FLOAT,
jbe@528 76 "c2" FLOAT,
jbe@528 77 "c1" FLOAT,
jbe@528 78 "c0" FLOAT,
jbe@528 79 "dist" FLOAT,
jbe@528 80 "bbox1" BOX,
jbe@528 81 "bbox2" BOX );
jbe@528 82
jbe@528 83 COMMENT ON TYPE "geosearch" IS 'Structure returned by function "geosearch" holding one or two bounding boxes ("bbox1" and optionally "bbox2") for index lookup as well as the starting point (i.e. center point given by "lat" and "lon") and coefficients ("c3" through "c0") for distance approximation';
jbe@528 84
jbe@528 85 COMMENT ON COLUMN "geosearch"."lat" IS 'Latitude of center of search area';
jbe@528 86 COMMENT ON COLUMN "geosearch"."lon" IS 'Longitude of center of search area';
jbe@528 87 COMMENT ON COLUMN "geosearch"."c3" IS 'Coefficient for distance calculation';
jbe@528 88 COMMENT ON COLUMN "geosearch"."c2" IS 'Coefficient for distance calculation';
jbe@528 89 COMMENT ON COLUMN "geosearch"."c1" IS 'Coefficient for distance calculation';
jbe@528 90 COMMENT ON COLUMN "geosearch"."c0" IS 'Coefficient for distance calculation';
jbe@528 91 COMMENT ON COLUMN "geosearch"."bbox1" IS 'Bounding box suitable for use with output of "geoindex" function';
jbe@528 92 COMMENT ON COLUMN "geosearch"."bbox2" IS 'Second bounding box (see column "bbox1") set if search crosses the 180th meridian';
jbe@528 93
jbe@528 94
jbe@528 95 CREATE FUNCTION "geosearch"
jbe@528 96 ( "latitude_p" FLOAT,
jbe@528 97 "longitude_p" FLOAT )
jbe@528 98 RETURNS "geosearch"
jbe@528 99 LANGUAGE plpgsql IMMUTABLE STRICT AS $$
jbe@528 100 DECLARE
jbe@528 101 -- constants:
jbe@528 102 -- (with a = radius at equator, and b = radius at pole)
jbe@528 103 "degrad" FLOAT := 0.017453292519943295; -- pi / 180
jbe@528 104 "degrad2" FLOAT := 0.00030461741978670857; -- (pi / 180)^2
jbe@528 105 "a2" FLOAT := 40680631590769; -- a^2
jbe@528 106 "eps2" FLOAT := 0.006694379990141316; -- (a^2 - b^2) / a^2
jbe@528 107 "subeps2" FLOAT := 0.9933056200098587; -- 1 - "eps2"
jbe@528 108 "subeps22" FLOAT := 0.9866560547431698; -- (1 - "eps2")^2
jbe@528 109 -- latitude in radians:
jbe@528 110 "phi0rad" FLOAT := "degrad" * "latitude_p";
jbe@528 111 -- helper variables:
jbe@528 112 "sinp0" FLOAT; -- sin("phi0rad")
jbe@528 113 "cosp0" FLOAT; -- cos("phi0rad")
jbe@528 114 "sinp02" FLOAT; -- sin("phi0rad")^2
jbe@528 115 "e2sinp02" FLOAT; -- "eps2" * sin("phi0rad")^2
jbe@528 116 "subsin" FLOAT; -- 1 - sin("phi0rad")^2
jbe@528 117 "subse" FLOAT; -- 1 - "eps2" * sin("phi0rad")^2
jbe@528 118 "subse2" FLOAT; -- ("subse")^2
jbe@528 119 "t20" FLOAT; -- taylor coefficient for (delta latitude)^2
jbe@528 120 "t02" FLOAT; -- taylor coefficient for (delta longitude)^2 / "t20"
jbe@528 121 "t12" FLOAT; -- taylor coefficient for (d lat)^1*(d lon)^2 / "t20"
jbe@528 122 "t22" FLOAT; -- taylor coefficient for (d lat)^2*(d lon)^2 / "t20"
jbe@528 123 -- result:
jbe@528 124 "res" "geosearch";
jbe@528 125 BEGIN
jbe@528 126 PERFORM "geoindex"("latitude_p", "longitude_p"); -- check bounds
jbe@528 127 "sinp0" := sin("phi0rad");
jbe@528 128 "cosp0" := cos("phi0rad");
jbe@528 129 "sinp02" := "sinp0" * "sinp0";
jbe@528 130 "e2sinp02" := "eps2" * "sinp02";
jbe@528 131 "subsin" := 1 - "sinp02";
jbe@528 132 "subse" := 1 - "e2sinp02";
jbe@528 133 "subse2" := "subse" * "subse";
jbe@528 134 "t20" := "a2" * "subeps22" / ("subse" * "subse2");
jbe@528 135 "t02" := "subsin" * "subse2" / "subeps22";
jbe@528 136 "t12" := -"sinp0" * "cosp0" * "subse" / "subeps2";
jbe@528 137 "t22" := -"subsin" * (0.5+"e2sinp02") / "subeps2";
jbe@528 138 "res"."lat" := "latitude_p";
jbe@528 139 "res"."lon" := "longitude_p";
jbe@528 140 "res"."c3" := "degrad2" * "t20";
jbe@528 141 "res"."c2" := "degrad2" * "t22";
jbe@528 142 "res"."c1" := "degrad" * ("t12" - 2 * "t22" * "phi0rad");
jbe@528 143 "res"."c0" := ("t22" * "phi0rad" - "t12") * "phi0rad" + "t02";
jbe@528 144 "res"."dist" := 'Infinity'::FLOAT;
jbe@528 145 "res"."bbox1" := box(point(1, 1), point(-1, -1));
jbe@528 146 "res"."bbox2" := NULL;
jbe@528 147 RETURN "res";
jbe@528 148 END;
jbe@528 149 $$;
jbe@528 150
jbe@528 151 COMMENT ON FUNCTION "geosearch"
jbe@528 152 ( FLOAT, FLOAT )
jbe@528 153 IS 'Takes latitude and longitude (in degrees), and returns a "geosearch" structure suitable for distance calculation; NOTE: use function with same name but three arguments, i.e. "geosearch"(FLOAT, FLOAT, FLOAT), for searches with limited radius';
jbe@528 154
jbe@528 155
jbe@528 156 CREATE FUNCTION "geosearch"
jbe@528 157 ( "latitude_p" FLOAT,
jbe@528 158 "longitude_p" FLOAT,
jbe@528 159 "radius_p" FLOAT )
jbe@528 160 RETURNS "geosearch"
jbe@528 161 LANGUAGE plpgsql IMMUTABLE AS $$
jbe@528 162 DECLARE
jbe@528 163 -- constants:
jbe@528 164 "philimit" FLOAT := 84; -- maximum latitude (needs to be less than 90)
jbe@528 165 "margin" FLOAT := 1.0001; -- slightly increase search area
jbe@528 166 -- NOTE: search area is increased by "margin", search radius gets
jbe@528 167 -- increased by sqrt("margin"); choose a value > 1.0 to avoid
jbe@528 168 -- floating point errors
jbe@528 169 "fixzero" FLOAT := 0.0001; -- small value > 0 to fix singularity
jbe@528 170 -- result:
jbe@528 171 "res" "geosearch";
jbe@528 172 -- helper variables:
jbe@528 173 "rc3mar" FLOAT; -- ("radius_p")^2 / "c3", multiplied with "margin"
jbe@528 174 "subc02" FLOAT; -- 2 * ("c0" - "c2" * "rc3mar")
jbe@528 175 "b4" FLOAT; -- ("c2")^2
jbe@528 176 "b3" FLOAT; -- 2 * "c1" * "c2"
jbe@528 177 "b2" FLOAT; -- ("c1")^2 + "subc02" * "c2"
jbe@528 178 "b1" FLOAT; -- "subc02" * "c1"
jbe@528 179 "b0" FLOAT; -- ("c2")^2 * ("rc3mar")^2 +
jbe@528 180 -- 2 * "c0" * "c2" - ("c1")^2 * ("rc3mar")^1 +
jbe@528 181 -- ("c0")^2 * ("rc3mar")^0
jbe@528 182 "sqrtval" FLOAT; -- "b4" * ("latitude_p")^4 +
jbe@528 183 -- "b3" * ("latitude_p")^3 +
jbe@528 184 -- "b2" * ("latitude_p")^2 +
jbe@528 185 -- "b1" * ("latitude_p")^1 +
jbe@528 186 -- "b0" * ("latitude_p")^0
jbe@528 187 "phic" FLOAT; -- ( "c2" * (("latitude_p")^2 - "rc3mar") - "c0"
jbe@528 188 -- + sqrt("sqrtval")
jbe@528 189 -- ) / ( 2 * "c2" * "latitude_p" + "c1" )
jbe@528 190 "dlat" FLOAT; -- delta latitude in degrees = sqrt("rc3mar")
jbe@528 191 "dlon2" FLOAT; -- square of delta longitude
jbe@528 192 "dlon" FLOAT; -- delta longitude in degrees =
jbe@528 193 -- sqrt(
jbe@528 194 -- ( "rc3mar" - ("phic" - "latitude_p")^2 ) /
jbe@528 195 -- ( "c2" * ("phic")^2 +
jbe@528 196 -- "c1" * ("phic")^1 +
jbe@528 197 -- "c0" )
jbe@528 198 -- )
jbe@528 199 "lat_min" FLOAT;
jbe@528 200 "lat_max" FLOAT;
jbe@528 201 "lon_min" FLOAT;
jbe@528 202 "lon_max" FLOAT;
jbe@528 203 BEGIN
jbe@528 204 "res" := "geosearch"("latitude_p", "longitude_p");
jbe@528 205 IF "res" ISNULL THEN RETURN NULL; END IF;
jbe@528 206 IF "radius_p" ISNULL OR "radius_p" = 'Infinity'::FLOAT THEN
jbe@528 207 RETURN "res";
jbe@528 208 END IF;
jbe@528 209 "res"."dist" := "radius_p";
jbe@528 210 "rc3mar" := "margin" * "radius_p" * "radius_p" / "res"."c3";
jbe@528 211 "subc02" := 2 * ("res"."c0" - "res"."c2" * "rc3mar");
jbe@528 212 "b4" := "res"."c2" * "res"."c2";
jbe@528 213 "b3" := 2 * "res"."c1" * "res"."c2";
jbe@528 214 "b2" := "res"."c1" * "res"."c1" + "subc02" * "res"."c2";
jbe@528 215 "b1" := "subc02" * "res"."c1";
jbe@528 216 "b0" := ( "b4" * "rc3mar" +
jbe@528 217 2 * "res"."c0" * "res"."c2" - "res"."c1" * "res"."c1"
jbe@528 218 ) * "rc3mar" + "res"."c0" * "res"."c0";
jbe@528 219 "sqrtval" := ( ( ( ( "b4"
jbe@528 220 ) * "latitude_p" + "b3"
jbe@528 221 ) * "latitude_p" + "b2"
jbe@528 222 ) * "latitude_p" + "b1"
jbe@528 223 ) * "latitude_p" + "b0";
jbe@528 224 IF "sqrtval" < 0 THEN
jbe@528 225 IF "latitude_p" >= 0 THEN "phic" := "philimit";
jbe@528 226 ELSE "phic" := -"philimit"; END IF;
jbe@528 227 ELSE
jbe@528 228 IF abs("latitude_p") <= "fixzero" THEN
jbe@528 229 "phic" := "latitude_p";
jbe@528 230 ELSE
jbe@528 231 "phic" := (
jbe@528 232 "res"."c2" * ("latitude_p" * "latitude_p" - "rc3mar")
jbe@528 233 - "res"."c0" + sqrt("sqrtval")
jbe@528 234 ) / (
jbe@528 235 2 * "res"."c2" * "latitude_p" + "res"."c1"
jbe@528 236 );
jbe@528 237 IF "phic" > "philimit" THEN "phic" := "philimit";
jbe@528 238 ELSIF "phic" < -"philimit" THEN "phic" := -"philimit"; END IF;
jbe@528 239 END IF;
jbe@528 240 END IF;
jbe@528 241 "dlat" := sqrt("rc3mar");
jbe@528 242 "dlon2" := (
jbe@528 243 ( "rc3mar" - ("phic" - "latitude_p")^2 ) /
jbe@528 244 ( ( "res"."c2" * "phic" + "res"."c1" ) * "phic" + "res"."c0" )
jbe@528 245 );
jbe@528 246 IF "dlon2" > 0 THEN "dlon" := sqrt("dlon2");
jbe@528 247 ELSE "dlon" := 0; END IF;
jbe@528 248 "lat_min" := "latitude_p" - "dlat";
jbe@528 249 "lat_max" := "latitude_p" + "dlat";
jbe@528 250 IF "lat_min" < -90 THEN "lat_min" := -90; END IF;
jbe@528 251 IF "lat_max" > 90 THEN "lat_max" := 90; END IF;
jbe@528 252 "lon_min" := "longitude_p" - "dlon";
jbe@528 253 "lon_max" := "longitude_p" + "dlon";
jbe@528 254 IF "lon_min" < -180 THEN
jbe@528 255 IF "lon_max" > 180 THEN
jbe@528 256 "res"."bbox1" := box(
jbe@528 257 "geoindex"("lat_min", -180),
jbe@528 258 "geoindex"("lat_max", 180) );
jbe@528 259 "res"."bbox2" := NULL;
jbe@528 260 ELSE
jbe@528 261 "res"."bbox1" := box(
jbe@528 262 "geoindex"("lat_min", -180),
jbe@528 263 "geoindex"("lat_max", "lon_max") );
jbe@528 264 "res"."bbox2" := box(
jbe@528 265 "geoindex"("lat_min", "lon_min" + 360),
jbe@528 266 "geoindex"("lat_max", 180) );
jbe@528 267 END IF;
jbe@528 268 ELSIF "lon_max" > 180 THEN
jbe@528 269 "res"."bbox1" := box(
jbe@528 270 "geoindex"("lat_min", "lon_min"),
jbe@528 271 "geoindex"("lat_max", 180) );
jbe@528 272 "res"."bbox2" := box(
jbe@528 273 "geoindex"("lat_min", -180),
jbe@528 274 "geoindex"("lat_max", "lon_max" - 360) );
jbe@528 275 ELSE
jbe@528 276 "res"."bbox1" := box(
jbe@528 277 "geoindex"("lat_min", "lon_min"),
jbe@528 278 "geoindex"("lat_max", "lon_max") );
jbe@528 279 "res"."bbox2" := NULL;
jbe@528 280 END IF;
jbe@528 281 RETURN "res";
jbe@528 282 END;
jbe@528 283 $$;
jbe@528 284
jbe@528 285 COMMENT ON FUNCTION "geosearch"
jbe@528 286 ( FLOAT, FLOAT, FLOAT )
jbe@528 287 IS 'Takes latitude, longitude (both in degrees), and a radius (in meters), and returns a "geoindex" structure suitable for searching and distance calculation';
jbe@528 288
jbe@528 289
jbe@528 290 CREATE FUNCTION "geodist"
jbe@528 291 ( "geosearch_p" "geosearch",
jbe@528 292 "latitude_p" FLOAT,
jbe@528 293 "longitude_p" FLOAT )
jbe@528 294 RETURNS FLOAT
jbe@528 295 LANGUAGE sql IMMUTABLE AS $$
jbe@528 296 SELECT sqrt(
jbe@528 297 "geosearch_p"."c3" * (
jbe@528 298 ("latitude_p" - "geosearch_p"."lat")^2 +
jbe@528 299 ( ( "geosearch_p"."c2" * "latitude_p" + "geosearch_p"."c1" )
jbe@528 300 * "latitude_p" + "geosearch_p"."c0" ) *
jbe@528 301 ( "longitude_p" +
jbe@528 302 CASE WHEN "longitude_p" - "geosearch_p"."lon" > 180
jbe@528 303 THEN -360 ELSE
jbe@528 304 CASE WHEN "longitude_p" - "geosearch_p"."lon" < -180
jbe@528 305 THEN 360
jbe@528 306 ELSE 0 END
jbe@528 307 END - "geosearch_p"."lon"
jbe@528 308 )^2
jbe@528 309 )
jbe@528 310 )
jbe@528 311 $$;
jbe@528 312
jbe@528 313 COMMENT ON FUNCTION "geodist"
jbe@528 314 ( "geosearch", FLOAT, FLOAT )
jbe@528 315 IS 'Takes a "geosearch" structure as well as geographical coordinates in degrees and returns the distance on earth in meters';
jbe@528 316
jbe@528 317
jbe@528 318 /* Usage of spatial indexing and distance calculation functions for points:
jbe@528 319
jbe@528 320 -- create table containing geographical coordinates in degrees:
jbe@528 321 CREATE TABLE "t1" (
jbe@528 322 "id" SERIAL4 PRIMARY KEY,
jbe@528 323 "latitude" NUMERIC NOT NULL,
jbe@528 324 "longitude" NUMERIC NOT NULL );
jbe@528 325
jbe@528 326 -- create an SP-GiST index (with default quad_point_ops operator class):
jbe@528 327 CREATE INDEX "t1_geoindex" ON "t1" USING spgist (("geoindex"("latitude", "longitude")));
jbe@528 328
jbe@528 329 -- return results within 10,000 meters of Brandenburg Gate:
jbe@528 330 SELECT "t1".*, "distance"
jbe@528 331 FROM "t1"
jbe@528 332 CROSS JOIN "geosearch"(52.5162746, 13.377704, 10000)
jbe@528 333 CROSS JOIN LATERAL "geodist"("geosearch", "latitude", "longitude") AS "distance"
jbe@528 334 WHERE (
jbe@528 335 "geoindex"("latitude", "longitude") <@ "geosearch"."bbox1" OR
jbe@528 336 "geoindex"("latitude", "longitude") <@ "geosearch"."bbox2" )
jbe@528 337 AND "distance" <= "geosearch"."dist";
jbe@528 338
jbe@528 339 */
jbe@528 340
jbe@528 341
jbe@528 342 CREATE FUNCTION "polyindex"
jbe@528 343 ( "point_p" POINT )
jbe@528 344 RETURNS POLYGON
jbe@528 345 LANGUAGE sql IMMUTABLE STRICT AS $$
jbe@528 346 SELECT "point_p"::TEXT::POLYGON;
jbe@528 347 $$;
jbe@528 348
jbe@528 349 COMMENT ON FUNCTION "polyindex"(POINT) IS 'Converts a point (with latitude in degrees as first value and longitude in degrees as second value) into a polygon suitable for GiST poly_ops indexing';
jbe@528 350
jbe@528 351
jbe@528 352 CREATE FUNCTION "polyindex"
jbe@528 353 ( "latitude_p" FLOAT,
jbe@528 354 "longitude_p" FLOAT )
jbe@528 355 RETURNS POLYGON
jbe@528 356 LANGUAGE sql IMMUTABLE STRICT AS $$
jbe@528 357 SELECT "polyindex"(point("latitude_p", "longitude_p"))
jbe@528 358 $$;
jbe@528 359
jbe@528 360 COMMENT ON FUNCTION "polyindex"(POINT) IS 'Converts a point given as latitude and longitude in degrees into a polygon suitable for GiST poly_ops indexing';
jbe@528 361
jbe@528 362
jbe@528 363 CREATE FUNCTION "polyindex"
jbe@528 364 ( "polygon_p" POLYGON )
jbe@528 365 RETURNS POLYGON
jbe@528 366 LANGUAGE sql IMMUTABLE STRICT AS $$
jbe@528 367 SELECT "polygon_p"
jbe@528 368 $$;
jbe@528 369
jbe@528 370 COMMENT ON FUNCTION "polyindex"(POLYGON) IS 'Does nothing but returning the polygon unchanged (for GiST poly_ops indexing)';
jbe@528 371
jbe@528 372
jbe@528 373 CREATE FUNCTION "polyindex"
jbe@528 374 ( "box_p" BOX )
jbe@528 375 RETURNS POLYGON
jbe@528 376 LANGUAGE sql IMMUTABLE STRICT AS $$
jbe@528 377 SELECT "box_p"::POLYGON
jbe@528 378 $$;
jbe@528 379
jbe@528 380 COMMENT ON FUNCTION "polyindex"(POINT) IS 'Converts a box (with latitude in degrees as first value and longitude in degrees as second value in each point) into a polygon suitable for GiST poly_ops indexing';
jbe@528 381
jbe@528 382
jbe@528 383 CREATE FUNCTION "polyindex"
jbe@528 384 ( "path_p" PATH )
jbe@528 385 RETURNS POLYGON
jbe@528 386 LANGUAGE plpgsql IMMUTABLE STRICT AS $$
jbe@528 387 DECLARE
jbe@528 388 "match_v" TEXT[];
jbe@528 389 "points_v" TEXT[];
jbe@528 390 "idx1" INTEGER;
jbe@528 391 "idx2" INTEGER;
jbe@528 392 BEGIN
jbe@528 393 IF isclosed("path_p") THEN
jbe@528 394 RETURN "path_p"::POLYGON;
jbe@528 395 ELSE
jbe@528 396 "points_v" := '{}';
jbe@528 397 "idx1" := 0;
jbe@528 398 FOR "match_v" IN
jbe@528 399 SELECT regexp_matches("path_p"::TEXT, E'\\(([^()]*)\\)', 'g')
jbe@528 400 LOOP
jbe@528 401 "idx1" := "idx1" + 1;
jbe@528 402 "points_v"["idx1"] := "match_v"[1];
jbe@528 403 END LOOP;
jbe@528 404 "idx2" := "idx1";
jbe@528 405 LOOP
jbe@528 406 EXIT WHEN "idx1" < 3;
jbe@528 407 "idx1" := "idx1" - 1;
jbe@528 408 "idx2" := "idx2" + 1;
jbe@528 409 "points_v"["idx2"] := "points_v"["idx1"];
jbe@528 410 END LOOP;
jbe@528 411 RETURN array_to_string("points_v", ',')::POLYGON;
jbe@528 412 END IF;
jbe@528 413 END;
jbe@528 414 $$;
jbe@528 415
jbe@528 416 COMMENT ON FUNCTION "polyindex"(POINT) IS 'Converts a path (with latitude in degrees as first value and longitude in degrees as second value in each point) into a polygon suitable for GiST poly_ops indexing; NOTE: closed PATHs where isclosed(path)=TRUE represent filled polygons, use an open PATH with the last point equal to the first point (e.g. "[1,1,3,4,6,6,1,1]") for a non-filled structure';
jbe@528 417
jbe@528 418
jbe@528 419 CREATE FUNCTION "polyindex"
jbe@528 420 ( "lseg_p" LSEG )
jbe@528 421 RETURNS POLYGON
jbe@528 422 LANGUAGE sql IMMUTABLE STRICT AS $$
jbe@528 423 SELECT "polyindex"("lseg_p"::TEXT::PATH)
jbe@528 424 $$;
jbe@528 425
jbe@528 426 COMMENT ON FUNCTION "polyindex"(POINT) IS 'Converts a line segment (with latitude in degrees as first value and longitude in degrees as second value in each point) into a polygon suitable for GiST poly_ops indexing';
jbe@528 427
jbe@528 428
jbe@528 429 CREATE FUNCTION "geoshift180"
jbe@528 430 ( "point_p" POINT )
jbe@528 431 RETURNS POINT
jbe@528 432 LANGUAGE sql IMMUTABLE STRICT AS $$
jbe@528 433 SELECT CASE WHEN "point_p" <^ '0,0'::POINT THEN
jbe@528 434 "point_p" + '0,360'::POINT
jbe@528 435 ELSE
jbe@528 436 "point_p" - '0,360'::POINT
jbe@528 437 END
jbe@528 438 $$;
jbe@528 439
jbe@528 440 COMMENT ON FUNCTION "geoshift180"(POINT) IS 'Returns a point (latitude and longitude in degrees) with its longitude translated by 360 degress to allow for searches crossing the 180th meridian';
jbe@528 441
jbe@528 442
jbe@528 443 CREATE FUNCTION "geoshift180"
jbe@528 444 ( "polygon_p" POLYGON )
jbe@528 445 RETURNS POLYGON
jbe@528 446 LANGUAGE sql IMMUTABLE STRICT AS $$
jbe@528 447 SELECT CASE WHEN center("polygon_p"::CIRCLE) <^ '0,0'::POINT THEN
jbe@528 448 ("polygon_p"::PATH + '0,360'::POINT)::POLYGON
jbe@528 449 ELSE
jbe@528 450 ("polygon_p"::PATH - '0,360'::POINT)::POLYGON
jbe@528 451 END
jbe@528 452 $$;
jbe@528 453
jbe@528 454 COMMENT ON FUNCTION "geoshift180"(POLYGON) IS 'Returns a polygon (latitude and longitude in degrees) with its longitude translated by 360 degress to allow for searches crossing the 180th meridian';
jbe@528 455
jbe@528 456
jbe@528 457 CREATE FUNCTION "polysearch"
jbe@528 458 ( "geosearch_p" "geosearch",
jbe@528 459 "steps_p" INTEGER = 24 )
jbe@528 460 RETURNS POLYGON
jbe@528 461 LANGUAGE plpgsql IMMUTABLE STRICT AS $$
jbe@528 462 DECLARE
jbe@528 463 "philimit" FLOAT := 84; -- maximum latitude (needs to be less than 90)
jbe@528 464 "halfsteps" INTEGER;
jbe@528 465 "step" INTEGER := 0;
jbe@528 466 "angle" FLOAT;
jbe@528 467 "dlat" FLOAT := "geosearch_p"."dist" / sqrt("geosearch_p"."c3");
jbe@528 468 "lat" FLOAT;
jbe@528 469 "dlon" FLOAT;
jbe@528 470 "coords" TEXT[];
jbe@528 471 BEGIN
jbe@528 472 IF "steps_p" < 4 OR "steps_p" % 2 != 0 THEN
jbe@528 473 RAISE EXCEPTION 'Invalid step count';
jbe@528 474 END IF;
jbe@528 475 "halfsteps" := "steps_p" / 2;
jbe@528 476 LOOP
jbe@528 477 "angle" := 2.0 * pi() * "step" / "steps_p";
jbe@528 478 "lat" := "geosearch_p"."lat" + "dlat" * cos("angle");
jbe@528 479 IF "lat" > "philimit" THEN "lat" := "philimit";
jbe@528 480 ELSIF "lat" < -"philimit" THEN "lat" := -"philimit";
jbe@528 481 END IF;
jbe@528 482 "dlon" := "dlat" * sin("angle") / sqrt(
jbe@528 483 ("geosearch_p"."c2" * "lat" + "geosearch_p"."c1") * "lat" +
jbe@528 484 "geosearch_p"."c0" );
jbe@528 485 "coords"[2*"step"+1] := "lat";
jbe@528 486 "coords"[2*"step"+2] := "geosearch_p"."lon" + "dlon";
jbe@528 487 EXIT WHEN "step" >= "halfsteps";
jbe@528 488 IF "step" > 0 THEN
jbe@528 489 "coords"[2*("steps_p"-"step")+1] := "lat";
jbe@528 490 "coords"[2*("steps_p"-"step")+2] := "geosearch_p"."lon" - "dlon";
jbe@528 491 END IF;
jbe@528 492 "step" := "step" + 1;
jbe@528 493 END LOOP;
jbe@528 494 RETURN array_to_string("coords", ',')::POLYGON;
jbe@528 495 END;
jbe@528 496 $$;
jbe@528 497
jbe@528 498 COMMENT ON FUNCTION "polysearch"
jbe@528 499 ("geosearch", INTEGER)
jbe@528 500 IS 'Returns a polygon approximating the search circle represented by a given "geosearch" structure; The optional second parameter denotes the number of vertices (defaults to 24)';
jbe@528 501
jbe@528 502
jbe@528 503 CREATE FUNCTION "polysearch"
jbe@528 504 ( "latitude_p" FLOAT,
jbe@528 505 "longitude_p" FLOAT,
jbe@528 506 "radius_p" FLOAT,
jbe@528 507 "steps_p" INTEGER = 24 )
jbe@528 508 RETURNS POLYGON
jbe@528 509 LANGUAGE plpgsql IMMUTABLE STRICT AS $$
jbe@528 510 DECLARE
jbe@528 511 "geosearch_v" "geosearch";
jbe@528 512 BEGIN
jbe@528 513 "geosearch_v" := "geosearch"("latitude_p", "longitude_p");
jbe@528 514 "geosearch_v"."dist" := "radius_p";
jbe@528 515 RETURN "polysearch"("geosearch_v", "steps_p");
jbe@528 516 END;
jbe@528 517 $$;
jbe@528 518
jbe@528 519 COMMENT ON FUNCTION "polysearch"
jbe@528 520 ("geosearch", INTEGER)
jbe@528 521 IS 'Returns a polygon approximating a search circle around a point given as latitude and longitude in degrees as well as the radius in meters; The optional second parameter denotes the number of vertices (defaults to 24)';
jbe@528 522
jbe@528 523
jbe@528 524 /* Usage of spatial indexing for other basic geometric objects:
jbe@528 525
jbe@528 526 -- create table containing geographical coordinates in degrees:
jbe@528 527 CREATE TABLE "t2" (
jbe@528 528 "id" SERIAL4 PRIMARY KEY,
jbe@528 529 "geometry" PATH );
jbe@528 530
jbe@528 531 -- create a GiST (not SP-GiST!) index (with default poly_ops operator class):
jbe@528 532 CREATE INDEX "t2_geoindex" ON "t2" USING gist (("polyindex"("geometry")));
jbe@528 533
jbe@528 534 -- return results within 10,000 meters of Brandenburg Gate:
jbe@528 535 -- NOTE: use && operator for overlapping, use <@ operator for containment
jbe@528 536 SELECT "t2".*
jbe@528 537 FROM "t2"
jbe@528 538 CROSS JOIN "polysearch"(52.5162746, 13.377704, 10000) AS "poly1"
jbe@528 539 CROSS JOIN LATERAL "geoshift180"("poly1") AS "poly2"
jbe@528 540 WHERE (
jbe@528 541 "polyindex"("geometry") && "poly1" OR
jbe@528 542 "polyindex"("geometry") && "poly2" );
jbe@528 543
jbe@528 544 */
jbe@528 545
jbe@528 546
jbe@528 547 CREATE FUNCTION "scattered_polygon_contains_point"
jbe@528 548 ( "scattered_polygon_p" POLYGON[],
jbe@528 549 "point_p" POINT )
jbe@528 550 RETURNS BOOLEAN
jbe@528 551 LANGUAGE sql IMMUTABLE STRICT AS $$
jbe@528 552 SELECT count(1) % 2 = 1
jbe@528 553 FROM unnest("scattered_polygon_p") AS "entry"
jbe@528 554 WHERE "entry" @> "point_p"
jbe@528 555 $$;
jbe@528 556
jbe@528 557 COMMENT ON FUNCTION "scattered_polygon_contains_point"
jbe@528 558 ( POLYGON[], POINT )
jbe@528 559 IS 'Takes a scattered (or hollow) polygon represented as an array of polygons and, as a second argument, a point; returns TRUE if the number of polygons in which the point is contained is odd';
jbe@528 560
jbe@528 561
jbe@528 562 CREATE FUNCTION "scattered_polygon_contains_point"
jbe@528 563 ( "scattered_polygon_p" POLYGON[],
jbe@528 564 "point_x_p" FLOAT,
jbe@528 565 "point_y_p" FLOAT )
jbe@528 566 RETURNS BOOLEAN
jbe@528 567 LANGUAGE sql IMMUTABLE STRICT AS $$
jbe@528 568 SELECT "scattered_polygon_contains_point"(
jbe@528 569 "scattered_polygon_p",
jbe@528 570 point("point_x_p", "point_y_p")
jbe@528 571 )
jbe@528 572 $$;
jbe@528 573
jbe@528 574 COMMENT ON FUNCTION "scattered_polygon_contains_point"
jbe@528 575 ( POLYGON[], FLOAT, FLOAT )
jbe@528 576 IS 'Takes a scattered (or hollow) polygon represented as an array of polygons and, as second and third arguments, two coordinates representing a point; returns TRUE if the number of polygons in which the point is contained is odd';
jbe@528 577
jbe@528 578
jbe@528 579 CREATE FUNCTION "scattered_polygon_bound_box"
jbe@528 580 ( "scattered_polygon_p" POLYGON[] )
jbe@528 581 RETURNS BOX
jbe@528 582 LANGUAGE plpgsql IMMUTABLE STRICT AS $$
jbe@528 583 DECLARE
jbe@528 584 "first_v" BOOLEAN;
jbe@528 585 "bound_box_v" BOX;
jbe@528 586 "polygon_v" POLYGON;
jbe@528 587 BEGIN
jbe@528 588 "first_v" := TRUE;
jbe@528 589 FOR "polygon_v" IN SELECT * FROM unnest("scattered_polygon_p") LOOP
jbe@528 590 IF "first_v" THEN
jbe@528 591 "bound_box_v" := box("polygon_v");
jbe@528 592 "first_v" := FALSE;
jbe@528 593 ELSE
jbe@528 594 "bound_box_v" := bound_box("bound_box_v", box("polygon_v"));
jbe@528 595 END IF;
jbe@528 596 END LOOP;
jbe@528 597 RETURN "bound_box_v";
jbe@528 598 END;
jbe@528 599 $$;
jbe@528 600
jbe@528 601 COMMENT ON FUNCTION "scattered_polygon_bound_box"
jbe@528 602 ( POLYGON[] )
jbe@528 603 IS 'Takes a scattered (or hollow) polygon represented as an array of polygons and returns a bounding box';
jbe@528 604
jbe@528 605
jbe@528 606 /* Usage of spatial indexing for scattered (or hollow) polygons:
jbe@528 607
jbe@528 608 -- create table containing geographical coordinates in degrees:
jbe@528 609 CREATE TABLE "t3" (
jbe@528 610 "id" SERIAL4 PRIMARY KEY,
jbe@528 611 "region" POLYGON[] );
jbe@528 612
jbe@528 613 -- create a GiST (not SP-GiST!) index (with default box_ops operator class):
jbe@528 614 CREATE INDEX "t3_geoindex" ON "t3" USING gist (("scattered_polygon_bound_box"("region")));
jbe@528 615
jbe@528 616 -- return rows containing Brandenburg Gate's location:
jbe@528 617 SELECT "t3".*
jbe@528 618 FROM "t3"
jbe@528 619 CROSS JOIN point(52.5162746, 13.377704) AS "point1"
jbe@528 620 CROSS JOIN LATERAL "geoshift180"("point1") AS "point2"
jbe@528 621 WHERE (
jbe@528 622 "scattered_polygon_contains_point"("region", "point1") OR
jbe@528 623 "scattered_polygon_contains_point"("region", "point2") );
jbe@528 624
jbe@528 625 */
jbe@528 626
jbe@528 627
jbe@528 628
jbe@0 629 -------------------------
jbe@0 630 -- Tables and indicies --
jbe@0 631 -------------------------
jbe@0 632
jbe@8 633
jbe@385 634 CREATE TABLE "temporary_transaction_data" (
jbe@385 635 PRIMARY KEY ("txid", "key"),
jbe@385 636 "txid" INT8 DEFAULT txid_current(),
jbe@383 637 "key" TEXT,
jbe@383 638 "value" TEXT NOT NULL );
jbe@383 639
jbe@385 640 COMMENT ON TABLE "temporary_transaction_data" IS 'Table to store temporary transaction data; shall be emptied before a transaction is committed';
jbe@385 641
jbe@385 642 COMMENT ON COLUMN "temporary_transaction_data"."txid" IS 'Value returned by function txid_current(); should be added to WHERE clause, when doing SELECT on this table, but ignored when doing DELETE on this table';
jbe@383 643
jbe@383 644
jbe@104 645 CREATE TABLE "system_setting" (
jbe@104 646 "member_ttl" INTERVAL );
jbe@104 647 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1));
jbe@104 648
jbe@104 649 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.';
jbe@104 650 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.';
jbe@104 651
jbe@184 652 COMMENT ON COLUMN "system_setting"."member_ttl" IS 'Time after members get their "active" flag set to FALSE, if they do not show any activity.';
jbe@104 653
jbe@104 654
jbe@111 655 CREATE TABLE "contingent" (
jbe@293 656 PRIMARY KEY ("polling", "time_frame"),
jbe@293 657 "polling" BOOLEAN,
jbe@293 658 "time_frame" INTERVAL,
jbe@111 659 "text_entry_limit" INT4,
jbe@111 660 "initiative_limit" INT4 );
jbe@111 661
jbe@111 662 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 663
jbe@293 664 COMMENT ON COLUMN "contingent"."polling" IS 'Determines if settings are for creating initiatives and new drafts of initiatives with "polling" flag set';
jbe@111 665 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 666 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame';
jbe@111 667
jbe@111 668
jbe@0 669 CREATE TABLE "member" (
jbe@0 670 "id" SERIAL4 PRIMARY KEY,
jbe@13 671 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@181 672 "invite_code" TEXT UNIQUE,
jbe@232 673 "invite_code_expiry" TIMESTAMPTZ,
jbe@182 674 "admin_comment" TEXT,
jbe@181 675 "activated" TIMESTAMPTZ,
jbe@184 676 "last_activity" DATE,
jbe@42 677 "last_login" TIMESTAMPTZ,
jbe@387 678 "last_delegation_check" TIMESTAMPTZ,
jbe@45 679 "login" TEXT UNIQUE,
jbe@0 680 "password" TEXT,
jbe@440 681 "authority" TEXT,
jbe@440 682 "authority_uid" TEXT,
jbe@440 683 "authority_login" TEXT,
jbe@99 684 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@181 685 "active" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@0 686 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@221 687 "lang" TEXT,
jbe@7 688 "notify_email" TEXT,
jbe@11 689 "notify_email_unconfirmed" TEXT,
jbe@11 690 "notify_email_secret" TEXT UNIQUE,
jbe@11 691 "notify_email_secret_expiry" TIMESTAMPTZ,
jbe@55 692 "notify_email_lock_expiry" TIMESTAMPTZ,
jbe@486 693 "disable_notifications" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@486 694 "notification_counter" INT4 NOT NULL DEFAULT 1,
jbe@486 695 "notification_sample_size" INT4 NOT NULL DEFAULT 3,
jbe@486 696 "notification_dow" INT4 CHECK ("notification_dow" BETWEEN 0 AND 6),
jbe@515 697 "notification_hour" INT4 DEFAULT floor(random() * 24) CHECK ("notification_hour" BETWEEN 0 AND 23),
jbe@504 698 "notification_sent" TIMESTAMP,
jbe@387 699 "login_recovery_expiry" TIMESTAMPTZ,
jbe@11 700 "password_reset_secret" TEXT UNIQUE,
jbe@11 701 "password_reset_secret_expiry" TIMESTAMPTZ,
jbe@225 702 "name" TEXT UNIQUE,
jbe@7 703 "identification" TEXT UNIQUE,
jbe@214 704 "authentication" TEXT,
jbe@7 705 "organizational_unit" TEXT,
jbe@7 706 "internal_posts" TEXT,
jbe@7 707 "realname" TEXT,
jbe@7 708 "birthday" DATE,
jbe@7 709 "address" TEXT,
jbe@7 710 "email" TEXT,
jbe@7 711 "xmpp_address" TEXT,
jbe@7 712 "website" TEXT,
jbe@7 713 "phone" TEXT,
jbe@7 714 "mobile_phone" TEXT,
jbe@7 715 "profession" TEXT,
jbe@7 716 "external_memberships" TEXT,
jbe@7 717 "external_posts" TEXT,
jbe@159 718 "formatting_engine" TEXT,
jbe@7 719 "statement" TEXT,
jbe@528 720 "latitude" NUMERIC,
jbe@528 721 "longitude" NUMERIC,
jbe@181 722 "text_search_data" TSVECTOR,
jbe@184 723 CONSTRAINT "active_requires_activated_and_last_activity"
jbe@225 724 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)),
jbe@440 725 CONSTRAINT "authority_requires_uid_and_vice_versa"
jbe@447 726 CHECK (("authority" NOTNULL) = ("authority_uid" NOTNULL)),
jbe@440 727 CONSTRAINT "authority_uid_unique_per_authority"
jbe@440 728 UNIQUE ("authority", "authority_uid"),
jbe@440 729 CONSTRAINT "authority_login_requires_authority"
jbe@440 730 CHECK ("authority" NOTNULL OR "authority_login" ISNULL),
jbe@505 731 CONSTRAINT "notification_dow_requires_notification_hour"
jbe@505 732 CHECK ("notification_dow" ISNULL OR "notification_hour" NOTNULL),
jbe@225 733 CONSTRAINT "name_not_null_if_activated"
jbe@528 734 CHECK ("activated" ISNULL OR "name" NOTNULL),
jbe@528 735 CONSTRAINT "latitude_and_lontitude_both_null_or_not_null"
jbe@528 736 CHECK (("latitude" NOTNULL) = ("longitude" NOTNULL)) );
jbe@440 737 CREATE INDEX "member_authority_login_idx" ON "member" ("authority_login");
jbe@0 738 CREATE INDEX "member_active_idx" ON "member" ("active");
jbe@528 739 CREATE INDEX "member_geolocation_idx" ON "member" USING spgist (("geoindex"("latitude", "longitude")));
jbe@8 740 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
jbe@7 741 CREATE TRIGGER "update_text_search_data"
jbe@7 742 BEFORE INSERT OR UPDATE ON "member"
jbe@7 743 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 744 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@7 745 "name", "identification", "organizational_unit", "internal_posts",
jbe@7 746 "realname", "external_memberships", "external_posts", "statement" );
jbe@0 747
jbe@0 748 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
jbe@0 749
jbe@181 750 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
jbe@181 751 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
jbe@232 752 COMMENT ON COLUMN "member"."invite_code_expiry" IS 'Expiry data/time for "invite_code"';
jbe@182 753 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
jbe@207 754 COMMENT ON COLUMN "member"."activated" IS 'Timestamp of first activation of account (i.e. usage of "invite_code"); required to be set for "active" members';
jbe@184 755 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
jbe@103 756 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
jbe@387 757 COMMENT ON COLUMN "member"."last_delegation_check" IS 'Timestamp of last delegation check (i.e. confirmation of all unit and area delegations)';
jbe@10 758 COMMENT ON COLUMN "member"."login" IS 'Login name';
jbe@10 759 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
jbe@440 760 COMMENT ON COLUMN "member"."authority" IS 'NULL if LiquidFeedback Core is authoritative for the member account; otherwise a string that indicates the source/authority of the external account (e.g. ''LDAP'' for an LDAP account)';
jbe@440 761 COMMENT ON COLUMN "member"."authority_uid" IS 'Unique identifier (unique per "authority") that allows to identify an external account (e.g. even if the login name changes)';
jbe@440 762 COMMENT ON COLUMN "member"."authority_login" IS 'Login name for external accounts (field is not unique!)';
jbe@99 763 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
jbe@184 764 COMMENT ON COLUMN "member"."active" IS 'Memberships, support and votes are taken into account when corresponding members are marked as active. Automatically set to FALSE, if "last_activity" is older than "system_setting"."member_ttl".';
jbe@10 765 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
jbe@221 766 COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member';
jbe@10 767 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
jbe@10 768 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 769 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
jbe@10 770 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
jbe@55 771 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
jbe@508 772 COMMENT ON COLUMN "member"."disable_notifications" IS 'TRUE if member does not want to receive notifications';
jbe@508 773 COMMENT ON COLUMN "member"."notification_counter" IS 'Sequential number of next scheduled notification message (used as a seed for pseudo-random initiative selection algorithm)';
jbe@508 774 COMMENT ON COLUMN "member"."notification_sample_size" IS 'Number of featured initiatives per issue in scheduled notification messages';
jbe@508 775 COMMENT ON COLUMN "member"."notification_dow" IS 'Day of week for scheduled notifications (NULL to receive a daily digest)';
jbe@508 776 COMMENT ON COLUMN "member"."notification_hour" IS 'Time of day when scheduled notifications are sent out';
jbe@508 777 COMMENT ON COLUMN "member"."notification_sent" IS 'Timestamp of last scheduled notification mail that has been sent out';
jbe@387 778 COMMENT ON COLUMN "member"."login_recovery_expiry" IS 'Date/time after which another login recovery attempt is allowed';
jbe@387 779 COMMENT ON COLUMN "member"."password_reset_secret" IS 'Secret string sent via e-mail for password recovery';
jbe@387 780 COMMENT ON COLUMN "member"."password_reset_secret_expiry" IS 'Date/time until the password recovery secret is valid, and date/time after which another password recovery attempt is allowed';
jbe@225 781 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member, may be NULL if account has not been activated yet';
jbe@10 782 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
jbe@214 783 COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated';
jbe@10 784 COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to';
jbe@10 785 COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization';
jbe@10 786 COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"';
jbe@10 787 COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications';
jbe@10 788 COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in';
jbe@10 789 COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization';
jbe@159 790 COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
jbe@207 791 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his/her profile';
jbe@528 792 COMMENT ON COLUMN "member"."latitude" IS 'Latitude (in degrees) of member''s location';
jbe@528 793 COMMENT ON COLUMN "member"."longitude" IS 'Longitude (in degrees) of member''s location';
jbe@7 794
jbe@7 795
jbe@13 796 CREATE TABLE "member_history" (
jbe@13 797 "id" SERIAL8 PRIMARY KEY,
jbe@13 798 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@13 799 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@42 800 "active" BOOLEAN NOT NULL,
jbe@13 801 "name" TEXT NOT NULL );
jbe@45 802 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
jbe@13 803
jbe@57 804 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
jbe@13 805
jbe@13 806 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
jbe@57 807 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
jbe@13 808
jbe@13 809
jbe@159 810 CREATE TABLE "rendered_member_statement" (
jbe@159 811 PRIMARY KEY ("member_id", "format"),
jbe@461 812 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@159 813 "format" TEXT,
jbe@159 814 "content" TEXT NOT NULL );
jbe@159 815
jbe@159 816 COMMENT ON TABLE "rendered_member_statement" IS 'This table may be used by frontends to cache "rendered" member statements (e.g. HTML output generated from wiki text)';
jbe@9 817
jbe@9 818
jbe@9 819 CREATE TABLE "setting" (
jbe@9 820 PRIMARY KEY ("member_id", "key"),
jbe@9 821 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@9 822 "key" TEXT NOT NULL,
jbe@9 823 "value" TEXT NOT NULL );
jbe@9 824 CREATE INDEX "setting_key_idx" ON "setting" ("key");
jbe@9 825
jbe@38 826 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
jbe@9 827
jbe@9 828 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
jbe@9 829
jbe@9 830
jbe@16 831 CREATE TABLE "setting_map" (
jbe@16 832 PRIMARY KEY ("member_id", "key", "subkey"),
jbe@16 833 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@16 834 "key" TEXT NOT NULL,
jbe@16 835 "subkey" TEXT NOT NULL,
jbe@16 836 "value" TEXT NOT NULL );
jbe@16 837 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
jbe@16 838
jbe@23 839 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
jbe@16 840
jbe@16 841 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
jbe@16 842 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
jbe@16 843 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
jbe@16 844
jbe@16 845
jbe@23 846 CREATE TABLE "member_relation_setting" (
jbe@23 847 PRIMARY KEY ("member_id", "key", "other_member_id"),
jbe@23 848 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 849 "key" TEXT NOT NULL,
jbe@23 850 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 851 "value" TEXT NOT NULL );
jbe@23 852
jbe@38 853 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
jbe@23 854
jbe@23 855
jbe@7 856 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
jbe@7 857
jbe@7 858 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
jbe@7 859
jbe@7 860
jbe@7 861 CREATE TABLE "member_image" (
jbe@7 862 PRIMARY KEY ("member_id", "image_type", "scaled"),
jbe@7 863 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@7 864 "image_type" "member_image_type",
jbe@7 865 "scaled" BOOLEAN,
jbe@7 866 "content_type" TEXT,
jbe@7 867 "data" BYTEA NOT NULL );
jbe@7 868
jbe@7 869 COMMENT ON TABLE "member_image" IS 'Images of members';
jbe@7 870
jbe@7 871 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
jbe@0 872
jbe@0 873
jbe@4 874 CREATE TABLE "member_count" (
jbe@341 875 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@5 876 "total_count" INT4 NOT NULL );
jbe@4 877
jbe@5 878 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 879
jbe@5 880 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
jbe@5 881 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
jbe@4 882
jbe@4 883
jbe@0 884 CREATE TABLE "contact" (
jbe@0 885 PRIMARY KEY ("member_id", "other_member_id"),
jbe@0 886 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 887 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@11 888 "public" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@11 889 CONSTRAINT "cant_save_yourself_as_contact"
jbe@11 890 CHECK ("member_id" != "other_member_id") );
jbe@113 891 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
jbe@0 892
jbe@0 893 COMMENT ON TABLE "contact" IS 'Contact lists';
jbe@0 894
jbe@0 895 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
jbe@0 896 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
jbe@0 897 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
jbe@0 898
jbe@0 899
jbe@113 900 CREATE TABLE "ignored_member" (
jbe@113 901 PRIMARY KEY ("member_id", "other_member_id"),
jbe@113 902 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@113 903 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@113 904 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
jbe@113 905
jbe@113 906 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
jbe@113 907
jbe@113 908 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
jbe@113 909 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
jbe@113 910
jbe@113 911
jbe@220 912 CREATE TABLE "session" (
jbe@220 913 "ident" TEXT PRIMARY KEY,
jbe@220 914 "additional_secret" TEXT,
jbe@220 915 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
jbe@461 916 "member_id" INT4 REFERENCES "member" ("id") ON DELETE SET NULL,
jbe@440 917 "authority" TEXT,
jbe@440 918 "authority_uid" TEXT,
jbe@440 919 "authority_login" TEXT,
jbe@387 920 "needs_delegation_check" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@220 921 "lang" TEXT );
jbe@220 922 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
jbe@220 923
jbe@220 924 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
jbe@220 925
jbe@220 926 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
jbe@220 927 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
jbe@220 928 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
jbe@440 929 COMMENT ON COLUMN "session"."authority" IS 'Temporary store for "member"."authority" during member account creation';
jbe@440 930 COMMENT ON COLUMN "session"."authority_uid" IS 'Temporary store for "member"."authority_uid" during member account creation';
jbe@440 931 COMMENT ON COLUMN "session"."authority_login" IS 'Temporary store for "member"."authority_login" during member account creation';
jbe@387 932 COMMENT ON COLUMN "session"."needs_delegation_check" IS 'Set to TRUE, if member must perform a delegation check to proceed with login; see column "last_delegation_check" in "member" table';
jbe@220 933 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
jbe@220 934
jbe@220 935
jbe@424 936 CREATE TYPE "defeat_strength" AS ENUM ('simple', 'tuple');
jbe@424 937
jbe@424 938 COMMENT ON TYPE "defeat_strength" IS 'How pairwise defeats are measured for the Schulze method: ''simple'' = only the number of winning votes, ''tuple'' = primarily the number of winning votes, secondarily the number of losing votes';
jbe@424 939
jbe@424 940
jbe@424 941 CREATE TYPE "tie_breaking" AS ENUM ('simple', 'variant1', 'variant2');
jbe@424 942
jbe@424 943 COMMENT ON TYPE "tie_breaking" IS 'Tie-breaker for the Schulze method: ''simple'' = only initiative ids are used, ''variant1'' = use initiative ids in variant 1 for tie breaking of the links (TBRL) and sequentially forbid shared links, ''variant2'' = use initiative ids in variant 2 for tie breaking of the links (TBRL) and sequentially forbid shared links';
jbe@424 944
jbe@424 945
jbe@0 946 CREATE TABLE "policy" (
jbe@0 947 "id" SERIAL4 PRIMARY KEY,
jbe@9 948 "index" INT4 NOT NULL,
jbe@0 949 "active" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@0 950 "name" TEXT NOT NULL UNIQUE,
jbe@0 951 "description" TEXT NOT NULL DEFAULT '',
jbe@261 952 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@447 953 "min_admission_time" INTERVAL,
jbe@447 954 "max_admission_time" INTERVAL,
jbe@261 955 "discussion_time" INTERVAL,
jbe@261 956 "verification_time" INTERVAL,
jbe@261 957 "voting_time" INTERVAL,
jbe@458 958 "issue_quorum" INT4 NOT NULL,
jbe@0 959 "initiative_quorum_num" INT4 NOT NULL,
jbe@10 960 "initiative_quorum_den" INT4 NOT NULL,
jbe@424 961 "defeat_strength" "defeat_strength" NOT NULL DEFAULT 'tuple',
jbe@424 962 "tie_breaking" "tie_breaking" NOT NULL DEFAULT 'variant1',
jbe@167 963 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
jbe@167 964 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
jbe@167 965 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@167 966 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
jbe@167 967 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
jbe@167 968 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
jbe@167 969 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
jbe@167 970 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@167 971 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
jbe@167 972 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
jbe@429 973 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@260 974 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@458 975 CONSTRAINT "issue_quorum_if_and_only_if_not_polling" CHECK (
jbe@458 976 "polling" = ("issue_quorum" ISNULL) ),
jbe@528 977 CONSTRAINT "min_admission_time_smaller_than_max_admission_time" CHECK (
jbe@528 978 "min_admission_time" < "max_admission_time" ),
jbe@528 979 CONSTRAINT "timing_null_or_not_null_constraints" CHECK (
jbe@261 980 ( "polling" = FALSE AND
jbe@447 981 "min_admission_time" NOTNULL AND "max_admission_time" NOTNULL AND
jbe@447 982 "discussion_time" NOTNULL AND
jbe@447 983 "verification_time" NOTNULL AND
jbe@447 984 "voting_time" NOTNULL ) OR
jbe@261 985 ( "polling" = TRUE AND
jbe@447 986 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
jbe@447 987 "discussion_time" NOTNULL AND
jbe@447 988 "verification_time" NOTNULL AND
jbe@447 989 "voting_time" NOTNULL ) OR
jbe@447 990 ( "polling" = TRUE AND
jbe@447 991 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
jbe@447 992 "discussion_time" ISNULL AND
jbe@447 993 "verification_time" ISNULL AND
jbe@447 994 "voting_time" ISNULL ) ),
jbe@429 995 CONSTRAINT "no_reverse_beat_path_requires_tuple_defeat_strength" CHECK (
jbe@429 996 "defeat_strength" = 'tuple'::"defeat_strength" OR
jbe@429 997 "no_reverse_beat_path" = FALSE ) );
jbe@0 998 CREATE INDEX "policy_active_idx" ON "policy" ("active");
jbe@0 999
jbe@0 1000 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
jbe@0 1001
jbe@9 1002 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
jbe@0 1003 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
jbe@447 1004 COMMENT ON COLUMN "policy"."polling" IS 'TRUE = special policy for non-user-generated issues without issue quorum, where certain initiatives (those having the "polling" flag set) do not need to pass the initiative quorum; "min_admission_time" and "max_admission_time" MUST be set to NULL, the other timings may be set to NULL altogether, allowing individual timing for those issues';
jbe@528 1005 COMMENT ON COLUMN "policy"."min_admission_time" IS 'Minimum duration of issue state ''admission''; Minimum time an issue stays open; Note: should be considerably smaller than "max_admission_time"';
jbe@447 1006 COMMENT ON COLUMN "policy"."max_admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
jbe@207 1007 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
jbe@207 1008 COMMENT ON COLUMN "policy"."verification_time" IS 'Duration of issue state ''verification''; Regular time until an issue is "fully_frozen" (e.g. entering issue state ''voting'') after being "half_frozen"';
jbe@207 1009 COMMENT ON COLUMN "policy"."voting_time" IS 'Duration of issue state ''voting''; Time after an issue is "fully_frozen" but not "closed" (duration of issue state ''voting'')';
jbe@458 1010 COMMENT ON COLUMN "policy"."issue_quorum" IS 'Minimum number of supporters needed for one initiative of an issue to allow the issue to pass from ''admission'' to ''discussion'' state (Note: further requirements apply, see tables "admission_rule" and "admission_rule_condition")';
jbe@528 1011 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 1012 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@428 1013 COMMENT ON COLUMN "policy"."defeat_strength" IS 'How pairwise defeats are measured for the Schulze method; see type "defeat_strength"; ''tuple'' is the recommended setting';
jbe@428 1014 COMMENT ON COLUMN "policy"."tie_breaking" IS 'Tie-breaker for the Schulze method; see type "tie_breaking"; ''variant1'' or ''variant2'' are recommended';
jbe@167 1015 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
jbe@167 1016 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
jbe@167 1017 COMMENT ON COLUMN "policy"."direct_majority_strict" IS 'If TRUE, then the direct majority must be strictly greater than "direct_majority_num"/"direct_majority_den", otherwise it may also be equal.';
jbe@167 1018 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
jbe@167 1019 COMMENT ON COLUMN "policy"."direct_majority_non_negative" IS 'Absolute number of sum of "positive_votes" and abstentions neccessary for an initiative to be attainable as winner';
jbe@167 1020 COMMENT ON COLUMN "policy"."indirect_majority_num" IS 'Numerator of fraction of neccessary indirect majority (through beat path) for initiatives to be attainable as winner';
jbe@167 1021 COMMENT ON COLUMN "policy"."indirect_majority_den" IS 'Denominator of fraction of neccessary indirect majority (through beat path) for initiatives to be attainable as winner';
jbe@167 1022 COMMENT ON COLUMN "policy"."indirect_majority_strict" IS 'If TRUE, then the indirect majority must be strictly greater than "indirect_majority_num"/"indirect_majority_den", otherwise it may also be equal.';
jbe@167 1023 COMMENT ON COLUMN "policy"."indirect_majority_positive" IS 'Absolute number of votes in favor of the winner neccessary in a beat path to the status quo for an initaitive to be attainable as winner';
jbe@167 1024 COMMENT ON COLUMN "policy"."indirect_majority_non_negative" IS 'Absolute number of sum of votes in favor and abstentions in a beat path to the status quo for an initiative to be attainable as winner';
jbe@429 1025 COMMENT ON COLUMN "policy"."no_reverse_beat_path" IS 'EXPERIMENTAL FEATURE: Causes initiatives with "reverse_beat_path" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."reverse_beat_path". This option ensures both that a winning initiative is never tied in a (weak) condorcet paradox with the status quo and a winning initiative always beats the status quo directly with a simple majority.';
jbe@429 1026 COMMENT ON COLUMN "policy"."no_multistage_majority" IS 'EXPERIMENTAL FEATURE: Causes initiatives with "multistage_majority" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."multistage_majority". This disqualifies initiatives which could cause an instable result. An instable result in this meaning is a result such that repeating the ballot with same preferences but with the winner of the first ballot as status quo would lead to a different winner in the second ballot. If there are no direct majorities required for the winner, or if in direct comparison only simple majorities are required and "no_reverse_beat_path" is true, then results are always stable and this flag does not have any effect on the winner (but still affects the "eligible" flag of an "initiative").';
jbe@0 1027
jbe@0 1028
jbe@97 1029 CREATE TABLE "unit" (
jbe@97 1030 "id" SERIAL4 PRIMARY KEY,
jbe@97 1031 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@97 1032 "active" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@97 1033 "name" TEXT NOT NULL,
jbe@97 1034 "description" TEXT NOT NULL DEFAULT '',
jbe@444 1035 "external_reference" TEXT,
jbe@97 1036 "member_count" INT4,
jbe@528 1037 "region" POLYGON[],
jbe@97 1038 "text_search_data" TSVECTOR );
jbe@97 1039 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
jbe@97 1040 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
jbe@97 1041 CREATE INDEX "unit_active_idx" ON "unit" ("active");
jbe@528 1042 CREATE INDEX "unit_geolocation_idx" ON "unit" USING gist (("scattered_polygon_bound_box"("region")));
jbe@97 1043 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
jbe@97 1044 CREATE TRIGGER "update_text_search_data"
jbe@97 1045 BEFORE INSERT OR UPDATE ON "unit"
jbe@97 1046 FOR EACH ROW EXECUTE PROCEDURE
jbe@97 1047 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@97 1048 "name", "description" );
jbe@97 1049
jbe@97 1050 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
jbe@97 1051
jbe@444 1052 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
jbe@444 1053 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
jbe@444 1054 COMMENT ON COLUMN "unit"."external_reference" IS 'Opaque data field to store an external reference';
jbe@528 1055 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege" (only active members counted)';
jbe@528 1056 COMMENT ON COLUMN "unit"."region" IS 'Scattered (or hollow) polygon represented as an array of polygons indicating valid coordinates for initiatives of issues with this policy';
jbe@97 1057
jbe@97 1058
jbe@465 1059 CREATE TABLE "subscription" (
jbe@465 1060 PRIMARY KEY ("member_id", "unit_id"),
jbe@465 1061 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@465 1062 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@465 1063 CREATE INDEX "subscription_unit_id_idx" ON "subscription" ("unit_id");
jbe@465 1064
jbe@465 1065 COMMENT ON TABLE "subscription" IS 'An entry in this table denotes that the member wishes to receive notifications regardless of his/her privileges in the given unit';
jbe@465 1066
jbe@465 1067
jbe@203 1068 CREATE TABLE "unit_setting" (
jbe@203 1069 PRIMARY KEY ("member_id", "key", "unit_id"),
jbe@203 1070 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@203 1071 "key" TEXT NOT NULL,
jbe@203 1072 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@203 1073 "value" TEXT NOT NULL );
jbe@203 1074
jbe@203 1075 COMMENT ON TABLE "unit_setting" IS 'Place for frontend to store unit specific settings of members as strings';
jbe@203 1076
jbe@203 1077
jbe@0 1078 CREATE TABLE "area" (
jbe@457 1079 UNIQUE ("unit_id", "id"), -- index needed for foreign-key on table "admission_rule_condition"
jbe@457 1080 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1081 "id" SERIAL4 PRIMARY KEY,
jbe@0 1082 "active" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@0 1083 "name" TEXT NOT NULL,
jbe@4 1084 "description" TEXT NOT NULL DEFAULT '',
jbe@444 1085 "external_reference" TEXT,
jbe@528 1086 "region" POLYGON[],
jbe@7 1087 "text_search_data" TSVECTOR );
jbe@97 1088 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
jbe@0 1089 CREATE INDEX "area_active_idx" ON "area" ("active");
jbe@528 1090 CREATE INDEX "area_geolocation_idx" ON "area" USING gist (("scattered_polygon_bound_box"("region")));
jbe@8 1091 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
jbe@7 1092 CREATE TRIGGER "update_text_search_data"
jbe@7 1093 BEFORE INSERT OR UPDATE ON "area"
jbe@7 1094 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 1095 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@7 1096 "name", "description" );
jbe@0 1097
jbe@0 1098 COMMENT ON TABLE "area" IS 'Subject areas';
jbe@0 1099
jbe@528 1100 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
jbe@528 1101 COMMENT ON COLUMN "area"."external_reference" IS 'Opaque data field to store an external reference';
jbe@528 1102 COMMENT ON COLUMN "area"."region" IS 'Scattered (or hollow) polygon represented as an array of polygons indicating valid coordinates for initiatives of issues with this policy';
jbe@0 1103
jbe@0 1104
jbe@465 1105 CREATE TABLE "ignored_area" (
jbe@465 1106 PRIMARY KEY ("member_id", "area_id"),
jbe@465 1107 "member_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@465 1108 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@465 1109 CREATE INDEX "ignored_area_area_id_idx" ON "ignored_area" ("area_id");
jbe@465 1110
jbe@465 1111 COMMENT ON TABLE "ignored_area" IS 'An entry in this table denotes that the member does not wish to receive notifications for the given subject area unless he/she declared interested in a particular issue';
jbe@465 1112
jbe@465 1113
jbe@23 1114 CREATE TABLE "area_setting" (
jbe@23 1115 PRIMARY KEY ("member_id", "key", "area_id"),
jbe@23 1116 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 1117 "key" TEXT NOT NULL,
jbe@23 1118 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 1119 "value" TEXT NOT NULL );
jbe@23 1120
jbe@23 1121 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
jbe@23 1122
jbe@23 1123
jbe@9 1124 CREATE TABLE "allowed_policy" (
jbe@9 1125 PRIMARY KEY ("area_id", "policy_id"),
jbe@9 1126 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@9 1127 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@9 1128 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
jbe@9 1129 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
jbe@9 1130
jbe@9 1131 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
jbe@9 1132
jbe@9 1133 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
jbe@9 1134
jbe@9 1135
jbe@457 1136 CREATE TABLE "admission_rule" (
jbe@457 1137 UNIQUE ("unit_id", "id"), -- index needed for foreign-key on table "admission_rule_condition"
jbe@457 1138 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@528 1139 "id" SERIAL4 PRIMARY KEY,
jbe@528 1140 "name" TEXT NOT NULL,
jbe@528 1141 "description" TEXT NOT NULL DEFAULT '' );
jbe@457 1142
jbe@457 1143 COMMENT ON TABLE "admission_rule" IS 'Groups entries in "admission_rule_condition" to regulate how many issues may pass from ''admission'' to ''discussion'' state in a given time';
jbe@457 1144
jbe@457 1145
jbe@457 1146 CREATE TABLE "admission_rule_condition" (
jbe@457 1147 "unit_id" INT4 NOT NULL,
jbe@457 1148 "admission_rule_id" INT4,
jbe@457 1149 FOREIGN KEY ("unit_id", "admission_rule_id") REFERENCES "admission_rule" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@457 1150 "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@457 1151 "area_id" INT4,
jbe@457 1152 FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@457 1153 "holdoff_time" INTERVAL NOT NULL );
jbe@457 1154 CREATE UNIQUE INDEX "admission_rule_condition_unit_idx" ON "admission_rule_condition" ("admission_rule_id") WHERE "policy_id" ISNULL AND "area_id" ISNULL;
jbe@457 1155 CREATE UNIQUE INDEX "admission_rule_condition_policy_idx" ON "admission_rule_condition" ("admission_rule_id", "policy_id") WHERE "area_id" ISNULL;
jbe@457 1156 CREATE UNIQUE INDEX "admission_rule_condition_area_idx" ON "admission_rule_condition" ("admission_rule_id", "area_id") WHERE "policy_id" ISNULL;
jbe@457 1157 CREATE UNIQUE INDEX "admission_rule_condition_policy_area_idx" ON "admission_rule_condition" ("admission_rule_id", "policy_id", "area_id");
jbe@457 1158
jbe@457 1159 COMMENT ON TABLE "admission_rule_condition" IS 'Regulates how many issues may pass from ''admission'' to ''discussion'' state in a given time; See definition of "issue_for_admission" view for details';
jbe@457 1160
jbe@457 1161 COMMENT ON COLUMN "admission_rule_condition"."unit_id" IS 'Grouped "admission_rule_condition" rows must have the same "unit_id"';
jbe@457 1162 COMMENT ON COLUMN "admission_rule_condition"."admission_rule_id" IS 'Grouping several "admission_rule_condition" rows';
jbe@457 1163 COMMENT ON COLUMN "admission_rule_condition"."policy_id" IS 'Set to link the condition with a given policy, NULL for any policy in the issue';
jbe@457 1164 COMMENT ON COLUMN "admission_rule_condition"."area_id" IS 'Set to link the condition with a given policy, NULL for any area in the issue';
jbe@457 1165 COMMENT ON COLUMN "admission_rule_condition"."holdoff_time" IS 'After an issue in the given unit, policy, and/or area has been admitted, the "admission_rule" is disabled for the selected "holdoff_time", e.g. a "holdoff_time" of ''6 hours'' causes four issues per day to be admitted';
jbe@457 1166
jbe@457 1167
jbe@528 1168 CREATE TABLE "snapshot" (
jbe@528 1169 "id" SERIAL8 PRIMARY KEY,
jbe@528 1170 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now() );
jbe@528 1171
jbe@528 1172 COMMENT ON TABLE "snapshot" IS 'Point in time when a snapshot of one or more issues (see table "snapshot_issue") and their supporter situation is taken';
jbe@8 1173
jbe@8 1174
jbe@112 1175 CREATE TYPE "issue_state" AS ENUM (
jbe@112 1176 'admission', 'discussion', 'verification', 'voting',
jbe@389 1177 'canceled_by_admin',
jbe@113 1178 'canceled_revoked_before_accepted',
jbe@113 1179 'canceled_issue_not_accepted',
jbe@113 1180 'canceled_after_revocation_during_discussion',
jbe@113 1181 'canceled_after_revocation_during_verification',
jbe@113 1182 'canceled_no_initiative_admitted',
jbe@112 1183 'finished_without_winner', 'finished_with_winner');
jbe@111 1184
jbe@111 1185 COMMENT ON TYPE "issue_state" IS 'State of issues';
jbe@111 1186
jbe@111 1187
jbe@0 1188 CREATE TABLE "issue" (
jbe@0 1189 "id" SERIAL4 PRIMARY KEY,
jbe@0 1190 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1191 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@389 1192 "admin_notice" TEXT,
jbe@444 1193 "external_reference" TEXT,
jbe@111 1194 "state" "issue_state" NOT NULL DEFAULT 'admission',
jbe@328 1195 "phase_finished" TIMESTAMPTZ,
jbe@0 1196 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 1197 "accepted" TIMESTAMPTZ,
jbe@3 1198 "half_frozen" TIMESTAMPTZ,
jbe@3 1199 "fully_frozen" TIMESTAMPTZ,
jbe@0 1200 "closed" TIMESTAMPTZ,
jbe@59 1201 "cleaned" TIMESTAMPTZ,
jbe@447 1202 "min_admission_time" INTERVAL,
jbe@447 1203 "max_admission_time" INTERVAL,
jbe@22 1204 "discussion_time" INTERVAL NOT NULL,
jbe@22 1205 "verification_time" INTERVAL NOT NULL,
jbe@22 1206 "voting_time" INTERVAL NOT NULL,
jbe@528 1207 "latest_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@528 1208 "admission_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
jbe@528 1209 "half_freeze_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@528 1210 "full_freeze_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@0 1211 "population" INT4,
jbe@4 1212 "voter_count" INT4,
jbe@170 1213 "status_quo_schulze_rank" INT4,
jbe@291 1214 CONSTRAINT "admission_time_not_null_unless_instantly_accepted" CHECK (
jbe@447 1215 ("min_admission_time" NOTNULL) = ("max_admission_time" NOTNULL) AND
jbe@452 1216 ("min_admission_time" NOTNULL OR ("accepted" NOTNULL AND "accepted" = "created")) ),
jbe@340 1217 CONSTRAINT "valid_state" CHECK (
jbe@340 1218 (
jbe@340 1219 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
jbe@340 1220 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
jbe@340 1221 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL ) OR
jbe@340 1222 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL)
jbe@340 1223 ) AND (
jbe@340 1224 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
jbe@340 1225 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
jbe@340 1226 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
jbe@340 1227 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
jbe@389 1228 ("state" = 'canceled_by_admin' AND "closed" NOTNULL) OR
jbe@340 1229 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
jbe@340 1230 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
jbe@340 1231 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
jbe@340 1232 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
jbe@340 1233 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" = "fully_frozen") OR
jbe@340 1234 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen") OR
jbe@340 1235 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen")
jbe@111 1236 )),
jbe@328 1237 CONSTRAINT "phase_finished_only_when_not_closed" CHECK (
jbe@328 1238 "phase_finished" ISNULL OR "closed" ISNULL ),
jbe@3 1239 CONSTRAINT "state_change_order" CHECK (
jbe@10 1240 "created" <= "accepted" AND
jbe@10 1241 "accepted" <= "half_frozen" AND
jbe@10 1242 "half_frozen" <= "fully_frozen" AND
jbe@3 1243 "fully_frozen" <= "closed" ),
jbe@61 1244 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
jbe@61 1245 "cleaned" ISNULL OR "closed" NOTNULL ),
jbe@528 1246 CONSTRAINT "snapshot_required" CHECK (
jbe@528 1247 --("accepted" ISNULL OR "admission_snapshot_id" NOTNULL) AND
jbe@528 1248 ("half_frozen" ISNULL OR "half_freeze_snapshot_id" NOTNULL) AND
jbe@528 1249 ("fully_frozen" ISNULL OR "full_freeze_snapshot_id" NOTNULL) ) );
jbe@0 1250 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
jbe@0 1251 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
jbe@528 1252 CREATE INDEX "issue_state_idx" ON "issue" ("state");
jbe@16 1253 CREATE INDEX "issue_created_idx" ON "issue" ("created");
jbe@16 1254 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
jbe@16 1255 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
jbe@16 1256 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
jbe@16 1257 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
jbe@0 1258 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
jbe@16 1259 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
jbe@528 1260 CREATE INDEX "issue_latest_snapshot_id" ON "issue" ("latest_snapshot_id");
jbe@528 1261 CREATE INDEX "issue_admission_snapshot_id" ON "issue" ("admission_snapshot_id");
jbe@528 1262 CREATE INDEX "issue_half_freeze_snapshot_id" ON "issue" ("half_freeze_snapshot_id");
jbe@528 1263 CREATE INDEX "issue_full_freeze_snapshot_id" ON "issue" ("full_freeze_snapshot_id");
jbe@0 1264
jbe@0 1265 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
jbe@0 1266
jbe@389 1267 COMMENT ON COLUMN "issue"."admin_notice" IS 'Public notice by admin to explain manual interventions, or to announce corrections';
jbe@444 1268 COMMENT ON COLUMN "issue"."external_reference" IS 'Opaque data field to store an external reference';
jbe@328 1269 COMMENT ON COLUMN "issue"."phase_finished" IS 'Set to a value NOTNULL, if the current phase has finished, but calculations are pending; No changes in this issue shall be made by the frontend or API when this value is set';
jbe@528 1270 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when the issue was accepted for further discussion (see table "admission_rule" and column "issue_quorum" of table "policy")';
jbe@170 1271 COMMENT ON COLUMN "issue"."half_frozen" IS 'Point in time, when "discussion_time" has elapsed; Frontends must ensure that for half_frozen issues a) initiatives are not revoked, b) no new drafts are created, c) no initiators are added or removed.';
jbe@170 1272 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@447 1273 COMMENT ON COLUMN "issue"."closed" IS 'Point in time, when "max_admission_time" or "voting_time" have elapsed, and issue is no longer active; Frontends must ensure that for closed issues additionally to the restrictions for half_frozen and fully_frozen issues a) no voter is added or removed to/from the direct_voter table, b) no votes are added, modified or removed.';
jbe@170 1274 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
jbe@447 1275 COMMENT ON COLUMN "issue"."min_admission_time" IS 'Copied from "policy" table at creation of issue';
jbe@447 1276 COMMENT ON COLUMN "issue"."max_admission_time" IS 'Copied from "policy" table at creation of issue';
jbe@170 1277 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
jbe@170 1278 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
jbe@170 1279 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
jbe@528 1280 COMMENT ON COLUMN "issue"."latest_snapshot_id" IS 'Snapshot id of most recent snapshot';
jbe@528 1281 COMMENT ON COLUMN "issue"."admission_snapshot_id" IS 'Snapshot id when issue as accepted or canceled in admission phase';
jbe@528 1282 COMMENT ON COLUMN "issue"."half_freeze_snapshot_id" IS 'Snapshot id at end of discussion phase';
jbe@528 1283 COMMENT ON COLUMN "issue"."full_freeze_snapshot_id" IS 'Snapshot id at end of verification phase';
jbe@170 1284 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
jbe@170 1285 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@170 1286 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
jbe@0 1287
jbe@0 1288
jbe@410 1289 CREATE TABLE "issue_order_in_admission_state" (
jbe@400 1290 "id" INT8 PRIMARY KEY, --REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@410 1291 "order_in_area" INT4,
jbe@410 1292 "order_in_unit" INT4 );
jbe@410 1293
jbe@410 1294 COMMENT ON TABLE "issue_order_in_admission_state" IS 'Ordering information for issues that are not stored in the "issue" table to avoid locking of multiple issues at once; Filled/updated by "lf_update_issue_order"';
jbe@410 1295
jbe@410 1296 COMMENT ON COLUMN "issue_order_in_admission_state"."id" IS 'References "issue" ("id") but has no referential integrity trigger associated, due to performance/locking issues';
jbe@410 1297 COMMENT ON COLUMN "issue_order_in_admission_state"."order_in_area" IS 'Order of issues in admission state within a single area; NULL values sort last';
jbe@410 1298 COMMENT ON COLUMN "issue_order_in_admission_state"."order_in_unit" IS 'Order of issues in admission state within all areas of a unit; NULL values sort last';
jbe@0 1299
jbe@0 1300
jbe@23 1301 CREATE TABLE "issue_setting" (
jbe@23 1302 PRIMARY KEY ("member_id", "key", "issue_id"),
jbe@23 1303 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 1304 "key" TEXT NOT NULL,
jbe@23 1305 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 1306 "value" TEXT NOT NULL );
jbe@23 1307
jbe@23 1308 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
jbe@23 1309
jbe@23 1310
jbe@0 1311 CREATE TABLE "initiative" (
jbe@0 1312 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
jbe@0 1313 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1314 "id" SERIAL4 PRIMARY KEY,
jbe@0 1315 "name" TEXT NOT NULL,
jbe@261 1316 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@0 1317 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 1318 "revoked" TIMESTAMPTZ,
jbe@112 1319 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@14 1320 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@528 1321 "latitude1" NUMERIC,
jbe@528 1322 "longitude1" NUMERIC,
jbe@528 1323 "latitude2" NUMERIC,
jbe@528 1324 "longitude2" NUMERIC,
jbe@444 1325 "external_reference" TEXT,
jbe@0 1326 "admitted" BOOLEAN,
jbe@0 1327 "supporter_count" INT4,
jbe@0 1328 "informed_supporter_count" INT4,
jbe@0 1329 "satisfied_supporter_count" INT4,
jbe@0 1330 "satisfied_informed_supporter_count" INT4,
jbe@313 1331 "harmonic_weight" NUMERIC(12, 3),
jbe@352 1332 "final_suggestion_order_calculated" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@414 1333 "first_preference_votes" INT4,
jbe@0 1334 "positive_votes" INT4,
jbe@0 1335 "negative_votes" INT4,
jbe@167 1336 "direct_majority" BOOLEAN,
jbe@167 1337 "indirect_majority" BOOLEAN,
jbe@170 1338 "schulze_rank" INT4,
jbe@167 1339 "better_than_status_quo" BOOLEAN,
jbe@167 1340 "worse_than_status_quo" BOOLEAN,
jbe@429 1341 "reverse_beat_path" BOOLEAN,
jbe@154 1342 "multistage_majority" BOOLEAN,
jbe@154 1343 "eligible" BOOLEAN,
jbe@126 1344 "winner" BOOLEAN,
jbe@0 1345 "rank" INT4,
jbe@7 1346 "text_search_data" TSVECTOR,
jbe@528 1347 "draft_text_search_data" TSVECTOR,
jbe@112 1348 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
jbe@447 1349 CHECK (("revoked" NOTNULL) = ("revoked_by_member_id" NOTNULL)),
jbe@14 1350 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
jbe@14 1351 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
jbe@528 1352 CONSTRAINT "latitude1_and_lontitude1_both_null_or_not_null"
jbe@528 1353 CHECK (("latitude1" NOTNULL) = ("longitude1" NOTNULL)),
jbe@528 1354 CONSTRAINT "latitude2_and_longitude2_both_null_or_not_null"
jbe@528 1355 CHECK (("latitude2" NOTNULL) = ("longitude2" NOTNULL)),
jbe@528 1356 CONSTRAINT "latutude2_requires_latitude1"
jbe@528 1357 CHECK ("latitude2" ISNULL OR "latitude1" NOTNULL),
jbe@0 1358 CONSTRAINT "revoked_initiatives_cant_be_admitted"
jbe@0 1359 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
jbe@128 1360 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
jbe@128 1361 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
jbe@414 1362 ( "first_preference_votes" ISNULL AND
jbe@414 1363 "positive_votes" ISNULL AND "negative_votes" ISNULL AND
jbe@167 1364 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
jbe@173 1365 "schulze_rank" ISNULL AND
jbe@167 1366 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
jbe@429 1367 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
jbe@173 1368 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
jbe@173 1369 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
jbe@175 1370 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
jbe@175 1371 "eligible" = FALSE OR
jbe@175 1372 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
jbe@175 1373 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
jbe@175 1374 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
jbe@176 1375 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
jbe@173 1376 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
jbe@16 1377 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
jbe@16 1378 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
jbe@528 1379 CREATE INDEX "initiative_geolocation1_idx" ON "initiative" USING spgist (("geoindex"("latitude1", "longitude1")));
jbe@528 1380 CREATE INDEX "initiative_geolocation2_idx" ON "initiative" USING spgist (("geoindex"("latitude2", "longitude2")));
jbe@8 1381 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
jbe@528 1382 CREATE INDEX "initiative_draft_text_search_data_idx" ON "initiative" USING gin ("draft_text_search_data");
jbe@7 1383 CREATE TRIGGER "update_text_search_data"
jbe@7 1384 BEFORE INSERT OR UPDATE ON "initiative"
jbe@7 1385 FOR EACH ROW EXECUTE PROCEDURE
jbe@450 1386 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "name");
jbe@0 1387
jbe@10 1388 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 1389
jbe@289 1390 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
jbe@210 1391 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
jbe@210 1392 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
jbe@528 1393 COMMENT ON COLUMN "initiative"."latitude1" IS 'Latitude (in degrees) of initiative (automatically copied from most recent draft)';
jbe@528 1394 COMMENT ON COLUMN "initiative"."longitude1" IS 'Longitude (in degrees) of initiative (automatically copied from most recent draft)';
jbe@528 1395 COMMENT ON COLUMN "initiative"."latitude2" IS 'Latitude (in degrees) of initiative''s second marker (automatically copied from most recent draft)';
jbe@528 1396 COMMENT ON COLUMN "initiative"."longitude2" IS 'Longitude (in degrees) of initiative''s second marker (automatically copied from most recent draft)';
jbe@444 1397 COMMENT ON COLUMN "initiative"."external_reference" IS 'Opaque data field to store an external reference';
jbe@210 1398 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
jbe@0 1399 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@0 1400 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@0 1401 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@0 1402 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@320 1403 COMMENT ON COLUMN "initiative"."harmonic_weight" IS 'Indicates the relevancy of the initiative, calculated from the potential supporters weighted with the harmonic series to avoid a large number of clones affecting other initiative''s sorting positions too much; shall be used as secondary sorting key after "admitted" as primary sorting key';
jbe@352 1404 COMMENT ON COLUMN "initiative"."final_suggestion_order_calculated" IS 'Set to TRUE, when "proportional_order" of suggestions has been calculated the last time';
jbe@414 1405 COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice';
jbe@414 1406 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo';
jbe@414 1407 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo';
jbe@210 1408 COMMENT ON COLUMN "initiative"."direct_majority" IS 'TRUE, if "positive_votes"/("positive_votes"+"negative_votes") is strictly greater or greater-equal than "direct_majority_num"/"direct_majority_den", and "positive_votes" is greater-equal than "direct_majority_positive", and ("positive_votes"+abstentions) is greater-equal than "direct_majority_non_negative"';
jbe@210 1409 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
jbe@411 1410 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking';
jbe@411 1411 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo';
jbe@411 1412 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (DEPRECATED, since schulze-ranking is unique per issue; use "better_than_status_quo"=FALSE)';
jbe@429 1413 COMMENT ON COLUMN "initiative"."reverse_beat_path" IS 'TRUE, if there is a beat path (may include ties) from this initiative to the status quo; set to NULL if "policy"."defeat_strength" is set to ''simple''';
jbe@210 1414 COMMENT ON COLUMN "initiative"."multistage_majority" IS 'TRUE, if either (a) this initiative has no better rank than the status quo, or (b) there exists a better ranked initiative X, which directly beats this initiative, and either more voters prefer X to this initiative than voters preferring X to the status quo or less voters prefer this initiative to X than voters preferring the status quo to X';
jbe@429 1415 COMMENT ON COLUMN "initiative"."eligible" IS 'Initiative has a "direct_majority" and an "indirect_majority", is "better_than_status_quo" and depending on selected policy the initiative has no "reverse_beat_path" or "multistage_majority"';
jbe@411 1416 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank"';
jbe@210 1417 COMMENT ON COLUMN "initiative"."rank" IS 'Unique ranking for all "admitted" initiatives per issue; lower rank is better; a winner always has rank 1, but rank 1 does not imply that an initiative is winner; initiatives with "direct_majority" AND "indirect_majority" always have a better (lower) rank than other initiatives';
jbe@0 1418
jbe@0 1419
jbe@61 1420 CREATE TABLE "battle" (
jbe@126 1421 "issue_id" INT4 NOT NULL,
jbe@61 1422 "winning_initiative_id" INT4,
jbe@61 1423 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@61 1424 "losing_initiative_id" INT4,
jbe@61 1425 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@126 1426 "count" INT4 NOT NULL,
jbe@126 1427 CONSTRAINT "initiative_ids_not_equal" CHECK (
jbe@126 1428 "winning_initiative_id" != "losing_initiative_id" OR
jbe@126 1429 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
jbe@126 1430 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
jbe@126 1431 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
jbe@126 1432 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
jbe@126 1433 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
jbe@126 1434
jbe@126 1435 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 1436
jbe@61 1437
jbe@113 1438 CREATE TABLE "ignored_initiative" (
jbe@465 1439 PRIMARY KEY ("member_id", "initiative_id"),
jbe@465 1440 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@465 1441 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@465 1442 CREATE INDEX "ignored_initiative_initiative_id_idx" ON "ignored_initiative" ("initiative_id");
jbe@113 1443
jbe@509 1444 COMMENT ON TABLE "ignored_initiative" IS 'An entry in this table denotes that the member does not wish to receive notifications for the given initiative';
jbe@113 1445
jbe@113 1446
jbe@23 1447 CREATE TABLE "initiative_setting" (
jbe@23 1448 PRIMARY KEY ("member_id", "key", "initiative_id"),
jbe@23 1449 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 1450 "key" TEXT NOT NULL,
jbe@23 1451 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 1452 "value" TEXT NOT NULL );
jbe@23 1453
jbe@23 1454 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
jbe@23 1455
jbe@23 1456
jbe@0 1457 CREATE TABLE "draft" (
jbe@0 1458 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
jbe@0 1459 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1460 "id" SERIAL8 PRIMARY KEY,
jbe@0 1461 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 1462 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@9 1463 "formatting_engine" TEXT,
jbe@7 1464 "content" TEXT NOT NULL,
jbe@528 1465 "latitude1" NUMERIC,
jbe@528 1466 "longitude1" NUMERIC,
jbe@528 1467 "latitude2" NUMERIC,
jbe@528 1468 "longitude2" NUMERIC,
jbe@444 1469 "external_reference" TEXT,
jbe@528 1470 "text_search_data" TSVECTOR,
jbe@528 1471 CONSTRAINT "latitude1_and_lontitude1_both_null_or_not_null"
jbe@528 1472 CHECK (("latitude1" NOTNULL) = ("longitude1" NOTNULL)),
jbe@528 1473 CONSTRAINT "latitude2_and_longitude2_both_null_or_not_null"
jbe@528 1474 CHECK (("latitude2" NOTNULL) = ("longitude2" NOTNULL)),
jbe@528 1475 CONSTRAINT "latutude2_requires_latitude1"
jbe@528 1476 CHECK ("latitude2" ISNULL OR "latitude1" NOTNULL) );
jbe@16 1477 CREATE INDEX "draft_created_idx" ON "draft" ("created");
jbe@9 1478 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
jbe@528 1479 CREATE INDEX "draft_geolocation1_idx" ON "draft" USING spgist (("geoindex"("latitude1", "longitude1")));
jbe@528 1480 CREATE INDEX "draft_geolocation2_idx" ON "draft" USING spgist (("geoindex"("latitude2", "longitude2")));
jbe@8 1481 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
jbe@7 1482 CREATE TRIGGER "update_text_search_data"
jbe@7 1483 BEFORE INSERT OR UPDATE ON "draft"
jbe@7 1484 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 1485 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
jbe@0 1486
jbe@10 1487 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 1488
jbe@444 1489 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
jbe@444 1490 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
jbe@528 1491 COMMENT ON COLUMN "draft"."latitude1" IS 'Latitude (in degrees) of initiative (automatically copied to "initiative" table if draft is most recent)';
jbe@528 1492 COMMENT ON COLUMN "draft"."longitude1" IS 'Longitude (in degrees) of initiative (automatically copied to "initiative" table if draft is most recent)';
jbe@528 1493 COMMENT ON COLUMN "draft"."latitude2" IS 'Latitude (in degrees) of initiative''s second marker (automatically copied to "initiative" table if draft is most recent)';
jbe@528 1494 COMMENT ON COLUMN "draft"."longitude2" IS 'Longitude (in degrees) of initiative''s second marker (automatically copied to "initiative" table if draft is most recent)';
jbe@444 1495 COMMENT ON COLUMN "draft"."external_reference" IS 'Opaque data field to store an external reference';
jbe@9 1496
jbe@0 1497
jbe@63 1498 CREATE TABLE "rendered_draft" (
jbe@63 1499 PRIMARY KEY ("draft_id", "format"),
jbe@63 1500 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@63 1501 "format" TEXT,
jbe@63 1502 "content" TEXT NOT NULL );
jbe@63 1503
jbe@63 1504 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 1505
jbe@63 1506
jbe@0 1507 CREATE TABLE "suggestion" (
jbe@0 1508 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
jbe@0 1509 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1510 "id" SERIAL8 PRIMARY KEY,
jbe@160 1511 "draft_id" INT8 NOT NULL,
jbe@160 1512 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
jbe@0 1513 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 1514 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@0 1515 "name" TEXT NOT NULL,
jbe@159 1516 "formatting_engine" TEXT,
jbe@159 1517 "content" TEXT NOT NULL DEFAULT '',
jbe@528 1518 "latitude1" NUMERIC,
jbe@528 1519 "longitude1" NUMERIC,
jbe@528 1520 "latitude2" NUMERIC,
jbe@528 1521 "longitude2" NUMERIC,
jbe@444 1522 "external_reference" TEXT,
jbe@7 1523 "text_search_data" TSVECTOR,
jbe@0 1524 "minus2_unfulfilled_count" INT4,
jbe@0 1525 "minus2_fulfilled_count" INT4,
jbe@0 1526 "minus1_unfulfilled_count" INT4,
jbe@0 1527 "minus1_fulfilled_count" INT4,
jbe@0 1528 "plus1_unfulfilled_count" INT4,
jbe@0 1529 "plus1_fulfilled_count" INT4,
jbe@0 1530 "plus2_unfulfilled_count" INT4,
jbe@352 1531 "plus2_fulfilled_count" INT4,
jbe@528 1532 "proportional_order" INT4,
jbe@528 1533 CONSTRAINT "latitude1_and_lontitude1_both_null_or_not_null"
jbe@528 1534 CHECK (("latitude1" NOTNULL) = ("longitude1" NOTNULL)),
jbe@528 1535 CONSTRAINT "latitude2_and_longitude2_both_null_or_not_null"
jbe@528 1536 CHECK (("latitude2" NOTNULL) = ("longitude2" NOTNULL)),
jbe@528 1537 CONSTRAINT "latutude2_requires_latitude1"
jbe@528 1538 CHECK ("latitude2" ISNULL OR "latitude1" NOTNULL) );
jbe@16 1539 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
jbe@9 1540 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
jbe@528 1541 CREATE INDEX "suggestion_geolocation1_idx" ON "suggestion" USING spgist (("geoindex"("latitude1", "longitude1")));
jbe@528 1542 CREATE INDEX "suggestion_geolocation2_idx" ON "suggestion" USING spgist (("geoindex"("latitude2", "longitude2")));
jbe@8 1543 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
jbe@7 1544 CREATE TRIGGER "update_text_search_data"
jbe@7 1545 BEFORE INSERT OR UPDATE ON "suggestion"
jbe@7 1546 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 1547 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@159 1548 "name", "content");
jbe@0 1549
jbe@10 1550 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 1551
jbe@160 1552 COMMENT ON COLUMN "suggestion"."draft_id" IS 'Draft, which the author has seen when composing the suggestion; should always be set by a frontend, but defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
jbe@528 1553 COMMENT ON COLUMN "suggestion"."latitude1" IS 'Latitude (in degrees) of suggestion';
jbe@528 1554 COMMENT ON COLUMN "suggestion"."longitude1" IS 'Longitude (in degrees) of suggestion';
jbe@528 1555 COMMENT ON COLUMN "suggestion"."latitude2" IS 'Latitude (in degrees) of suggestion''s second marker';
jbe@528 1556 COMMENT ON COLUMN "suggestion"."longitude2" IS 'Longitude (in degrees) of suggestion''s second marker';
jbe@444 1557 COMMENT ON COLUMN "suggestion"."external_reference" IS 'Opaque data field to store an external reference';
jbe@0 1558 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 1559 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 1560 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 1561 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 1562 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 1563 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 1564 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 1565 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@378 1566 COMMENT ON COLUMN "suggestion"."proportional_order" IS 'To be used for sorting suggestions within an initiative; NULL values sort last; updated by "lf_update_suggestion_order"';
jbe@0 1567
jbe@0 1568
jbe@159 1569 CREATE TABLE "rendered_suggestion" (
jbe@159 1570 PRIMARY KEY ("suggestion_id", "format"),
jbe@159 1571 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@159 1572 "format" TEXT,
jbe@159 1573 "content" TEXT NOT NULL );
jbe@159 1574
jbe@159 1575 COMMENT ON TABLE "rendered_suggestion" IS 'This table may be used by frontends to cache "rendered" drafts (e.g. HTML output generated from wiki text)';
jbe@159 1576
jbe@159 1577
jbe@23 1578 CREATE TABLE "suggestion_setting" (
jbe@23 1579 PRIMARY KEY ("member_id", "key", "suggestion_id"),
jbe@23 1580 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 1581 "key" TEXT NOT NULL,
jbe@23 1582 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 1583 "value" TEXT NOT NULL );
jbe@23 1584
jbe@23 1585 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
jbe@23 1586
jbe@23 1587
jbe@528 1588 CREATE TABLE "temporary_suggestion_counts" (
jbe@528 1589 "id" INT8 PRIMARY KEY, --REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@528 1590 "minus2_unfulfilled_count" INT4 NOT NULL,
jbe@528 1591 "minus2_fulfilled_count" INT4 NOT NULL,
jbe@528 1592 "minus1_unfulfilled_count" INT4 NOT NULL,
jbe@528 1593 "minus1_fulfilled_count" INT4 NOT NULL,
jbe@528 1594 "plus1_unfulfilled_count" INT4 NOT NULL,
jbe@528 1595 "plus1_fulfilled_count" INT4 NOT NULL,
jbe@528 1596 "plus2_unfulfilled_count" INT4 NOT NULL,
jbe@528 1597 "plus2_fulfilled_count" INT4 NOT NULL );
jbe@528 1598
jbe@528 1599 COMMENT ON TABLE "temporary_suggestion_counts" IS 'Holds certain calculated values (suggestion counts) temporarily until they can be copied into table "suggestion"';
jbe@528 1600
jbe@528 1601 COMMENT ON COLUMN "temporary_suggestion_counts"."id" IS 'References "suggestion" ("id") but has no referential integrity trigger associated, due to performance/locking issues';
jbe@528 1602
jbe@528 1603
jbe@97 1604 CREATE TABLE "privilege" (
jbe@97 1605 PRIMARY KEY ("unit_id", "member_id"),
jbe@97 1606 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@97 1607 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@97 1608 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@97 1609 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@97 1610 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@261 1611 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@261 1612 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@261 1613 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@261 1614 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
jbe@97 1615
jbe@97 1616 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
jbe@97 1617
jbe@289 1618 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
jbe@289 1619 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
jbe@289 1620 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
jbe@289 1621 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
jbe@289 1622 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
jbe@289 1623 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
jbe@289 1624 COMMENT ON COLUMN "privilege"."polling_right" IS 'Right to create issues with policies having the "policy"."polling" flag set, and to add initiatives having the "initiative"."polling" flag set to those issues';
jbe@97 1625
jbe@97 1626
jbe@0 1627 CREATE TABLE "interest" (
jbe@0 1628 PRIMARY KEY ("issue_id", "member_id"),
jbe@0 1629 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@148 1630 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@0 1631 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
jbe@0 1632
jbe@10 1633 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 1634
jbe@0 1635
jbe@0 1636 CREATE TABLE "initiator" (
jbe@0 1637 PRIMARY KEY ("initiative_id", "member_id"),
jbe@0 1638 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1639 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@14 1640 "accepted" BOOLEAN );
jbe@0 1641 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
jbe@0 1642
jbe@10 1643 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 1644
jbe@14 1645 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 1646
jbe@0 1647
jbe@0 1648 CREATE TABLE "supporter" (
jbe@0 1649 "issue_id" INT4 NOT NULL,
jbe@0 1650 PRIMARY KEY ("initiative_id", "member_id"),
jbe@0 1651 "initiative_id" INT4,
jbe@0 1652 "member_id" INT4,
jbe@0 1653 "draft_id" INT8 NOT NULL,
jbe@10 1654 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@160 1655 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
jbe@0 1656 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
jbe@0 1657
jbe@10 1658 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 1659
jbe@207 1660 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
jbe@160 1661 COMMENT ON COLUMN "supporter"."draft_id" IS 'Latest seen draft; should always be set by a frontend, but defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
jbe@84 1662
jbe@0 1663
jbe@0 1664 CREATE TABLE "opinion" (
jbe@0 1665 "initiative_id" INT4 NOT NULL,
jbe@0 1666 PRIMARY KEY ("suggestion_id", "member_id"),
jbe@0 1667 "suggestion_id" INT8,
jbe@0 1668 "member_id" INT4,
jbe@0 1669 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
jbe@0 1670 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@42 1671 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1672 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@10 1673 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
jbe@0 1674
jbe@10 1675 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 1676
jbe@0 1677 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
jbe@0 1678
jbe@0 1679
jbe@97 1680 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
jbe@97 1681
jbe@97 1682 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
jbe@10 1683
jbe@10 1684
jbe@0 1685 CREATE TABLE "delegation" (
jbe@0 1686 "id" SERIAL8 PRIMARY KEY,
jbe@0 1687 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@86 1688 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@10 1689 "scope" "delegation_scope" NOT NULL,
jbe@97 1690 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1691 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1692 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1693 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
jbe@97 1694 CONSTRAINT "no_unit_delegation_to_null"
jbe@97 1695 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
jbe@10 1696 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
jbe@97 1697 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
jbe@97 1698 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
jbe@97 1699 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
jbe@97 1700 UNIQUE ("unit_id", "truster_id"),
jbe@74 1701 UNIQUE ("area_id", "truster_id"),
jbe@74 1702 UNIQUE ("issue_id", "truster_id") );
jbe@0 1703 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
jbe@0 1704 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
jbe@0 1705
jbe@0 1706 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
jbe@0 1707
jbe@97 1708 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
jbe@0 1709 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
jbe@0 1710 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
jbe@0 1711
jbe@0 1712
jbe@528 1713 CREATE TABLE "snapshot_issue" (
jbe@528 1714 PRIMARY KEY ("snapshot_id", "issue_id"),
jbe@528 1715 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@528 1716 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@528 1717 CREATE INDEX "snapshot_issue_issue_id_idx" ON "snapshot_issue" ("issue_id");
jbe@528 1718
jbe@528 1719 COMMENT ON TABLE "snapshot_issue" IS 'List of issues included in a snapshot';
jbe@0 1720
jbe@0 1721
jbe@0 1722 CREATE TABLE "direct_interest_snapshot" (
jbe@528 1723 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
jbe@528 1724 "snapshot_id" INT8,
jbe@528 1725 "issue_id" INT4,
jbe@528 1726 FOREIGN KEY ("snapshot_id", "issue_id")
jbe@528 1727 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@45 1728 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@144 1729 "weight" INT4 );
jbe@0 1730 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
jbe@0 1731
jbe@389 1732 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"; for corrections refer to column "issue_notice" of "issue" table';
jbe@0 1733
jbe@528 1734 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
jbe@0 1735
jbe@0 1736
jbe@0 1737 CREATE TABLE "delegating_interest_snapshot" (
jbe@528 1738 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
jbe@528 1739 "snapshot_id" INT8,
jbe@528 1740 "issue_id" INT4,
jbe@528 1741 FOREIGN KEY ("snapshot_id", "issue_id")
jbe@528 1742 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@45 1743 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@8 1744 "weight" INT4,
jbe@10 1745 "scope" "delegation_scope" NOT NULL,
jbe@0 1746 "delegate_member_ids" INT4[] NOT NULL );
jbe@0 1747 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
jbe@0 1748
jbe@389 1749 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table; for corrections refer to column "issue_notice" of "issue" table';
jbe@0 1750
jbe@0 1751 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
jbe@8 1752 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
jbe@0 1753 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 1754
jbe@0 1755
jbe@0 1756 CREATE TABLE "direct_supporter_snapshot" (
jbe@528 1757 PRIMARY KEY ("snapshot_id", "initiative_id", "member_id"),
jbe@528 1758 "snapshot_id" INT8,
jbe@0 1759 "issue_id" INT4 NOT NULL,
jbe@528 1760 FOREIGN KEY ("snapshot_id", "issue_id")
jbe@528 1761 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1762 "initiative_id" INT4,
jbe@45 1763 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@204 1764 "draft_id" INT8 NOT NULL,
jbe@0 1765 "informed" BOOLEAN NOT NULL,
jbe@0 1766 "satisfied" BOOLEAN NOT NULL,
jbe@0 1767 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@204 1768 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
jbe@528 1769 FOREIGN KEY ("snapshot_id", "issue_id", "member_id") REFERENCES "direct_interest_snapshot" ("snapshot_id", "issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@0 1770 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
jbe@0 1771
jbe@389 1772 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot"); for corrections refer to column "issue_notice" of "issue" table';
jbe@0 1773
jbe@207 1774 COMMENT ON COLUMN "direct_supporter_snapshot"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
jbe@0 1775 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
jbe@0 1776 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
jbe@0 1777
jbe@0 1778
jbe@113 1779 CREATE TABLE "non_voter" (
jbe@528 1780 PRIMARY KEY ("member_id", "issue_id"),
jbe@528 1781 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@528 1782 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@528 1783 CREATE INDEX "non_voter_issue_id_idx" ON "non_voter" ("issue_id");
jbe@113 1784
jbe@113 1785 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
jbe@113 1786
jbe@113 1787
jbe@0 1788 CREATE TABLE "direct_voter" (
jbe@0 1789 PRIMARY KEY ("issue_id", "member_id"),
jbe@0 1790 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@45 1791 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@285 1792 "weight" INT4,
jbe@285 1793 "comment_changed" TIMESTAMPTZ,
jbe@285 1794 "formatting_engine" TEXT,
jbe@285 1795 "comment" TEXT,
jbe@285 1796 "text_search_data" TSVECTOR );
jbe@0 1797 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
jbe@285 1798 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
jbe@285 1799 CREATE TRIGGER "update_text_search_data"
jbe@285 1800 BEFORE INSERT OR UPDATE ON "direct_voter"
jbe@285 1801 FOR EACH ROW EXECUTE PROCEDURE
jbe@285 1802 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
jbe@0 1803
jbe@389 1804 COMMENT ON TABLE "direct_voter" IS 'Members having directly voted for/against initiatives of an issue; frontends must ensure that no voters are added or removed to/from this table when the issue has been closed; for corrections refer to column "issue_notice" of "issue" table';
jbe@0 1805
jbe@285 1806 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
jbe@285 1807 COMMENT ON COLUMN "direct_voter"."comment_changed" IS 'Shall be set on comment change, to indicate a comment being modified after voting has been finished; Automatically set to NULL after voting phase; Automatically set to NULL by trigger, if "comment" is set to NULL';
jbe@285 1808 COMMENT ON COLUMN "direct_voter"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "direct_voter"."comment"; Automatically set to NULL by trigger, if "comment" is set to NULL';
jbe@285 1809 COMMENT ON COLUMN "direct_voter"."comment" IS 'Is to be set or updated by the frontend, if comment was inserted or updated AFTER the issue has been closed. Otherwise it shall be set to NULL.';
jbe@285 1810
jbe@285 1811
jbe@285 1812 CREATE TABLE "rendered_voter_comment" (
jbe@285 1813 PRIMARY KEY ("issue_id", "member_id", "format"),
jbe@285 1814 FOREIGN KEY ("issue_id", "member_id")
jbe@285 1815 REFERENCES "direct_voter" ("issue_id", "member_id")
jbe@285 1816 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@285 1817 "issue_id" INT4,
jbe@285 1818 "member_id" INT4,
jbe@285 1819 "format" TEXT,
jbe@285 1820 "content" TEXT NOT NULL );
jbe@285 1821
jbe@285 1822 COMMENT ON TABLE "rendered_voter_comment" IS 'This table may be used by frontends to cache "rendered" voter comments (e.g. HTML output generated from wiki text)';
jbe@0 1823
jbe@0 1824
jbe@0 1825 CREATE TABLE "delegating_voter" (
jbe@0 1826 PRIMARY KEY ("issue_id", "member_id"),
jbe@0 1827 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@45 1828 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@8 1829 "weight" INT4,
jbe@10 1830 "scope" "delegation_scope" NOT NULL,
jbe@0 1831 "delegate_member_ids" INT4[] NOT NULL );
jbe@52 1832 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
jbe@0 1833
jbe@389 1834 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table; for corrections refer to column "issue_notice" of "issue" table';
jbe@0 1835
jbe@0 1836 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
jbe@8 1837 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
jbe@0 1838 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 1839
jbe@0 1840
jbe@0 1841 CREATE TABLE "vote" (
jbe@0 1842 "issue_id" INT4 NOT NULL,
jbe@0 1843 PRIMARY KEY ("initiative_id", "member_id"),
jbe@0 1844 "initiative_id" INT4,
jbe@0 1845 "member_id" INT4,
jbe@414 1846 "grade" INT4 NOT NULL,
jbe@414 1847 "first_preference" BOOLEAN,
jbe@0 1848 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@414 1849 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@414 1850 CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
jbe@414 1851 CHECK ("grade" > 0 OR "first_preference" ISNULL) );
jbe@0 1852 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
jbe@0 1853
jbe@389 1854 COMMENT ON TABLE "vote" IS 'Manual and delegated votes without abstentions; frontends must ensure that no votes are added modified or removed when the issue has been closed; for corrections refer to column "issue_notice" of "issue" table';
jbe@0 1855
jbe@414 1856 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
jbe@414 1857 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@414 1858 COMMENT ON COLUMN "vote"."first_preference" IS 'Value is automatically set after voting is finished. For positive grades, this value is set to true for the highest (i.e. best) grade.';
jbe@0 1859
jbe@0 1860
jbe@112 1861 CREATE TYPE "event_type" AS ENUM (
jbe@112 1862 'issue_state_changed',
jbe@112 1863 'initiative_created_in_new_issue',
jbe@112 1864 'initiative_created_in_existing_issue',
jbe@112 1865 'initiative_revoked',
jbe@112 1866 'new_draft_created',
jbe@112 1867 'suggestion_created');
jbe@112 1868
jbe@112 1869 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
jbe@112 1870
jbe@112 1871
jbe@112 1872 CREATE TABLE "event" (
jbe@112 1873 "id" SERIAL8 PRIMARY KEY,
jbe@112 1874 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@112 1875 "event" "event_type" NOT NULL,
jbe@112 1876 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@112 1877 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@328 1878 "state" "issue_state",
jbe@112 1879 "initiative_id" INT4,
jbe@112 1880 "draft_id" INT8,
jbe@112 1881 "suggestion_id" INT8,
jbe@112 1882 FOREIGN KEY ("issue_id", "initiative_id")
jbe@112 1883 REFERENCES "initiative" ("issue_id", "id")
jbe@112 1884 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@112 1885 FOREIGN KEY ("initiative_id", "draft_id")
jbe@112 1886 REFERENCES "draft" ("initiative_id", "id")
jbe@112 1887 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@112 1888 FOREIGN KEY ("initiative_id", "suggestion_id")
jbe@112 1889 REFERENCES "suggestion" ("initiative_id", "id")
jbe@112 1890 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@451 1891 CONSTRAINT "null_constr_for_issue_state_changed" CHECK (
jbe@112 1892 "event" != 'issue_state_changed' OR (
jbe@112 1893 "member_id" ISNULL AND
jbe@112 1894 "issue_id" NOTNULL AND
jbe@113 1895 "state" NOTNULL AND
jbe@112 1896 "initiative_id" ISNULL AND
jbe@112 1897 "draft_id" ISNULL AND
jbe@112 1898 "suggestion_id" ISNULL )),
jbe@451 1899 CONSTRAINT "null_constr_for_initiative_creation_or_revocation_or_new_draft" CHECK (
jbe@112 1900 "event" NOT IN (
jbe@112 1901 'initiative_created_in_new_issue',
jbe@112 1902 'initiative_created_in_existing_issue',
jbe@112 1903 'initiative_revoked',
jbe@112 1904 'new_draft_created'
jbe@112 1905 ) OR (
jbe@112 1906 "member_id" NOTNULL AND
jbe@112 1907 "issue_id" NOTNULL AND
jbe@113 1908 "state" NOTNULL AND
jbe@112 1909 "initiative_id" NOTNULL AND
jbe@112 1910 "draft_id" NOTNULL AND
jbe@112 1911 "suggestion_id" ISNULL )),
jbe@451 1912 CONSTRAINT "null_constr_for_suggestion_creation" CHECK (
jbe@112 1913 "event" != 'suggestion_created' OR (
jbe@112 1914 "member_id" NOTNULL AND
jbe@112 1915 "issue_id" NOTNULL AND
jbe@113 1916 "state" NOTNULL AND
jbe@112 1917 "initiative_id" NOTNULL AND
jbe@112 1918 "draft_id" ISNULL AND
jbe@112 1919 "suggestion_id" NOTNULL )) );
jbe@223 1920 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
jbe@112 1921
jbe@112 1922 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
jbe@112 1923
jbe@114 1924 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
jbe@114 1925 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
jbe@114 1926 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
jbe@114 1927 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
jbe@114 1928
jbe@112 1929
jbe@507 1930 CREATE TABLE "notification_event_sent" (
jbe@222 1931 "event_id" INT8 NOT NULL );
jbe@507 1932 CREATE UNIQUE INDEX "notification_event_sent_singleton_idx" ON "notification_event_sent" ((1));
jbe@507 1933
jbe@507 1934 COMMENT ON TABLE "notification_event_sent" IS 'This table stores one row with the last event_id, for which notifications have been sent out';
jbe@507 1935 COMMENT ON INDEX "notification_event_sent_singleton_idx" IS 'This index ensures that "notification_event_sent" only contains one row maximum.';
jbe@507 1936
jbe@507 1937
jbe@507 1938 CREATE TABLE "notification_initiative_sent" (
jbe@486 1939 PRIMARY KEY ("member_id", "initiative_id"),
jbe@486 1940 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@486 1941 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@486 1942 "last_draft_id" INT8 NOT NULL,
jbe@495 1943 "last_suggestion_id" INT8 );
jbe@507 1944 CREATE INDEX "notification_initiative_sent_initiative_idx" ON "notification_initiative_sent" ("initiative_id");
jbe@486 1945
jbe@508 1946 COMMENT ON TABLE "notification_initiative_sent" IS 'Information which initiatives have been promoted to a member in a scheduled notification mail';
jbe@508 1947
jbe@508 1948 COMMENT ON COLUMN "notification_initiative_sent"."last_draft_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
jbe@508 1949 COMMENT ON COLUMN "notification_initiative_sent"."last_suggestion_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
jbe@508 1950
jbe@486 1951
jbe@496 1952 CREATE TABLE "newsletter" (
jbe@496 1953 "id" SERIAL4 PRIMARY KEY,
jbe@496 1954 "published" TIMESTAMPTZ NOT NULL,
jbe@496 1955 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@496 1956 "include_all_members" BOOLEAN NOT NULL,
jbe@496 1957 "sent" TIMESTAMPTZ,
jbe@496 1958 "subject" TEXT NOT NULL,
jbe@496 1959 "content" TEXT NOT NULL );
jbe@496 1960 CREATE INDEX "newsletter_unit_id_idx" ON "newsletter" ("unit_id", "published");
jbe@496 1961 CREATE INDEX "newsletter_all_units_published_idx" ON "newsletter" ("published") WHERE "unit_id" ISNULL;
jbe@496 1962 CREATE INDEX "newsletter_published_idx" ON "newsletter" ("published");
jbe@496 1963
jbe@508 1964 COMMENT ON TABLE "newsletter" IS 'Contains newsletters created by administrators to be sent out and for further reference';
jbe@508 1965
jbe@508 1966 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter is to be sent out (and made available in the frontend)';
jbe@508 1967 COMMENT ON COLUMN "newsletter"."unit_id" IS 'If set, only members with voting right in the given unit are considered to be recipients';
jbe@508 1968 COMMENT ON COLUMN "newsletter"."include_all_members" IS 'TRUE = include all members regardless of their ''disable_notifications'' setting';
jbe@508 1969 COMMENT ON COLUMN "newsletter"."sent" IS 'Timestamp when the newsletter has been mailed out';
jbe@508 1970 COMMENT ON COLUMN "newsletter"."subject" IS 'Subject line (e.g. to be used for the email)';
jbe@508 1971 COMMENT ON COLUMN "newsletter"."content" IS 'Plain text content of the newsletter';
jbe@222 1972
jbe@222 1973
jbe@112 1974
jbe@112 1975 ----------------------------------------------
jbe@112 1976 -- Writing of history entries and event log --
jbe@112 1977 ----------------------------------------------
jbe@13 1978
jbe@181 1979
jbe@13 1980 CREATE FUNCTION "write_member_history_trigger"()
jbe@13 1981 RETURNS TRIGGER
jbe@13 1982 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@13 1983 BEGIN
jbe@42 1984 IF
jbe@230 1985 ( NEW."active" != OLD."active" OR
jbe@230 1986 NEW."name" != OLD."name" ) AND
jbe@230 1987 OLD."activated" NOTNULL
jbe@42 1988 THEN
jbe@42 1989 INSERT INTO "member_history"
jbe@57 1990 ("member_id", "active", "name")
jbe@57 1991 VALUES (NEW."id", OLD."active", OLD."name");
jbe@13 1992 END IF;
jbe@13 1993 RETURN NULL;
jbe@13 1994 END;
jbe@13 1995 $$;
jbe@13 1996
jbe@13 1997 CREATE TRIGGER "write_member_history"
jbe@13 1998 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
jbe@13 1999 "write_member_history_trigger"();
jbe@13 2000
jbe@13 2001 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
jbe@57 2002 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 2003
jbe@13 2004
jbe@112 2005 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
jbe@112 2006 RETURNS TRIGGER
jbe@112 2007 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@112 2008 BEGIN
jbe@328 2009 IF NEW."state" != OLD."state" THEN
jbe@112 2010 INSERT INTO "event" ("event", "issue_id", "state")
jbe@112 2011 VALUES ('issue_state_changed', NEW."id", NEW."state");
jbe@112 2012 END IF;
jbe@112 2013 RETURN NULL;
jbe@112 2014 END;
jbe@112 2015 $$;
jbe@112 2016
jbe@112 2017 CREATE TRIGGER "write_event_issue_state_changed"
jbe@112 2018 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 2019 "write_event_issue_state_changed_trigger"();
jbe@112 2020
jbe@112 2021 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
jbe@112 2022 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
jbe@112 2023
jbe@112 2024
jbe@112 2025 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
jbe@112 2026 RETURNS TRIGGER
jbe@112 2027 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@112 2028 DECLARE
jbe@112 2029 "initiative_row" "initiative"%ROWTYPE;
jbe@113 2030 "issue_row" "issue"%ROWTYPE;
jbe@112 2031 "event_v" "event_type";
jbe@112 2032 BEGIN
jbe@112 2033 SELECT * INTO "initiative_row" FROM "initiative"
jbe@112 2034 WHERE "id" = NEW."initiative_id";
jbe@113 2035 SELECT * INTO "issue_row" FROM "issue"
jbe@113 2036 WHERE "id" = "initiative_row"."issue_id";
jbe@112 2037 IF EXISTS (
jbe@112 2038 SELECT NULL FROM "draft"
jbe@112 2039 WHERE "initiative_id" = NEW."initiative_id"
jbe@112 2040 AND "id" != NEW."id"
jbe@112 2041 ) THEN
jbe@112 2042 "event_v" := 'new_draft_created';
jbe@112 2043 ELSE
jbe@112 2044 IF EXISTS (
jbe@112 2045 SELECT NULL FROM "initiative"
jbe@112 2046 WHERE "issue_id" = "initiative_row"."issue_id"
jbe@112 2047 AND "id" != "initiative_row"."id"
jbe@112 2048 ) THEN
jbe@112 2049 "event_v" := 'initiative_created_in_existing_issue';
jbe@112 2050 ELSE
jbe@112 2051 "event_v" := 'initiative_created_in_new_issue';
jbe@112 2052 END IF;
jbe@112 2053 END IF;
jbe@112 2054 INSERT INTO "event" (
jbe@112 2055 "event", "member_id",
jbe@113 2056 "issue_id", "state", "initiative_id", "draft_id"
jbe@112 2057 ) VALUES (
jbe@112 2058 "event_v",
jbe@112 2059 NEW."author_id",
jbe@112 2060 "initiative_row"."issue_id",
jbe@113 2061 "issue_row"."state",
jbe@112 2062 "initiative_row"."id",
jbe@112 2063 NEW."id" );
jbe@112 2064 RETURN NULL;
jbe@112 2065 END;
jbe@112 2066 $$;
jbe@112 2067
jbe@112 2068 CREATE TRIGGER "write_event_initiative_or_draft_created"
jbe@112 2069 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 2070 "write_event_initiative_or_draft_created_trigger"();
jbe@112 2071
jbe@112 2072 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 2073 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
jbe@112 2074
jbe@112 2075
jbe@112 2076 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
jbe@112 2077 RETURNS TRIGGER
jbe@112 2078 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@113 2079 DECLARE
jbe@231 2080 "issue_row" "issue"%ROWTYPE;
jbe@231 2081 "draft_id_v" "draft"."id"%TYPE;
jbe@112 2082 BEGIN
jbe@112 2083 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
jbe@231 2084 SELECT * INTO "issue_row" FROM "issue"
jbe@231 2085 WHERE "id" = NEW."issue_id";
jbe@231 2086 SELECT "id" INTO "draft_id_v" FROM "current_draft"
jbe@231 2087 WHERE "initiative_id" = NEW."id";
jbe@112 2088 INSERT INTO "event" (
jbe@231 2089 "event", "member_id", "issue_id", "state", "initiative_id", "draft_id"
jbe@112 2090 ) VALUES (
jbe@112 2091 'initiative_revoked',
jbe@112 2092 NEW."revoked_by_member_id",
jbe@112 2093 NEW."issue_id",
jbe@113 2094 "issue_row"."state",
jbe@231 2095 NEW."id",
jbe@231 2096 "draft_id_v");
jbe@112 2097 END IF;
jbe@112 2098 RETURN NULL;
jbe@112 2099 END;
jbe@112 2100 $$;
jbe@112 2101
jbe@112 2102 CREATE TRIGGER "write_event_initiative_revoked"
jbe@112 2103 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 2104 "write_event_initiative_revoked_trigger"();
jbe@112 2105
jbe@112 2106 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
jbe@112 2107 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
jbe@112 2108
jbe@112 2109
jbe@112 2110 CREATE FUNCTION "write_event_suggestion_created_trigger"()
jbe@112 2111 RETURNS TRIGGER
jbe@112 2112 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@112 2113 DECLARE
jbe@112 2114 "initiative_row" "initiative"%ROWTYPE;
jbe@113 2115 "issue_row" "issue"%ROWTYPE;
jbe@112 2116 BEGIN
jbe@112 2117 SELECT * INTO "initiative_row" FROM "initiative"
jbe@112 2118 WHERE "id" = NEW."initiative_id";
jbe@113 2119 SELECT * INTO "issue_row" FROM "issue"
jbe@113 2120 WHERE "id" = "initiative_row"."issue_id";
jbe@112 2121 INSERT INTO "event" (
jbe@112 2122 "event", "member_id",
jbe@113 2123 "issue_id", "state", "initiative_id", "suggestion_id"
jbe@112 2124 ) VALUES (
jbe@112 2125 'suggestion_created',
jbe@112 2126 NEW."author_id",
jbe@112 2127 "initiative_row"."issue_id",
jbe@113 2128 "issue_row"."state",
jbe@112 2129 "initiative_row"."id",
jbe@112 2130 NEW."id" );
jbe@112 2131 RETURN NULL;
jbe@112 2132 END;
jbe@112 2133 $$;
jbe@112 2134
jbe@112 2135 CREATE TRIGGER "write_event_suggestion_created"
jbe@112 2136 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 2137 "write_event_suggestion_created_trigger"();
jbe@112 2138
jbe@112 2139 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
jbe@112 2140 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
jbe@112 2141
jbe@112 2142
jbe@13 2143
jbe@0 2144 ----------------------------
jbe@0 2145 -- Additional constraints --
jbe@0 2146 ----------------------------
jbe@0 2147
jbe@0 2148
jbe@0 2149 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
jbe@0 2150 RETURNS TRIGGER
jbe@0 2151 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2152 BEGIN
jbe@0 2153 IF NOT EXISTS (
jbe@0 2154 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
jbe@0 2155 ) THEN
jbe@463 2156 RAISE EXCEPTION 'Cannot create issue without an initial initiative.' USING
jbe@463 2157 ERRCODE = 'integrity_constraint_violation',
jbe@463 2158 HINT = 'Create issue, initiative, and draft within the same transaction.';
jbe@0 2159 END IF;
jbe@0 2160 RETURN NULL;
jbe@0 2161 END;
jbe@0 2162 $$;
jbe@0 2163
jbe@0 2164 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
jbe@0 2165 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
jbe@0 2166 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 2167 "issue_requires_first_initiative_trigger"();
jbe@0 2168
jbe@0 2169 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
jbe@0 2170 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
jbe@0 2171
jbe@0 2172
jbe@0 2173 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
jbe@0 2174 RETURNS TRIGGER
jbe@0 2175 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2176 DECLARE
jbe@0 2177 "reference_lost" BOOLEAN;
jbe@0 2178 BEGIN
jbe@0 2179 IF TG_OP = 'DELETE' THEN
jbe@0 2180 "reference_lost" := TRUE;
jbe@0 2181 ELSE
jbe@0 2182 "reference_lost" := NEW."issue_id" != OLD."issue_id";
jbe@0 2183 END IF;
jbe@0 2184 IF
jbe@0 2185 "reference_lost" AND NOT EXISTS (
jbe@0 2186 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
jbe@0 2187 )
jbe@0 2188 THEN
jbe@0 2189 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
jbe@0 2190 END IF;
jbe@0 2191 RETURN NULL;
jbe@0 2192 END;
jbe@0 2193 $$;
jbe@0 2194
jbe@0 2195 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
jbe@0 2196 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
jbe@0 2197 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 2198 "last_initiative_deletes_issue_trigger"();
jbe@0 2199
jbe@0 2200 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
jbe@0 2201 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
jbe@0 2202
jbe@0 2203
jbe@0 2204 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
jbe@0 2205 RETURNS TRIGGER
jbe@0 2206 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2207 BEGIN
jbe@0 2208 IF NOT EXISTS (
jbe@0 2209 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
jbe@0 2210 ) THEN
jbe@463 2211 RAISE EXCEPTION 'Cannot create initiative without an initial draft.' USING
jbe@463 2212 ERRCODE = 'integrity_constraint_violation',
jbe@463 2213 HINT = 'Create issue, initiative and draft within the same transaction.';
jbe@0 2214 END IF;
jbe@0 2215 RETURN NULL;
jbe@0 2216 END;
jbe@0 2217 $$;
jbe@0 2218
jbe@0 2219 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
jbe@0 2220 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
jbe@0 2221 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 2222 "initiative_requires_first_draft_trigger"();
jbe@0 2223
jbe@0 2224 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
jbe@0 2225 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
jbe@0 2226
jbe@0 2227
jbe@0 2228 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
jbe@0 2229 RETURNS TRIGGER
jbe@0 2230 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2231 DECLARE
jbe@0 2232 "reference_lost" BOOLEAN;
jbe@0 2233 BEGIN
jbe@0 2234 IF TG_OP = 'DELETE' THEN
jbe@0 2235 "reference_lost" := TRUE;
jbe@0 2236 ELSE
jbe@0 2237 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
jbe@0 2238 END IF;
jbe@0 2239 IF
jbe@0 2240 "reference_lost" AND NOT EXISTS (
jbe@0 2241 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
jbe@0 2242 )
jbe@0 2243 THEN
jbe@0 2244 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
jbe@0 2245 END IF;
jbe@0 2246 RETURN NULL;
jbe@0 2247 END;
jbe@0 2248 $$;
jbe@0 2249
jbe@0 2250 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
jbe@0 2251 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
jbe@0 2252 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 2253 "last_draft_deletes_initiative_trigger"();
jbe@0 2254
jbe@0 2255 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
jbe@0 2256 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
jbe@0 2257
jbe@0 2258
jbe@0 2259 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
jbe@0 2260 RETURNS TRIGGER
jbe@0 2261 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2262 BEGIN
jbe@0 2263 IF NOT EXISTS (
jbe@0 2264 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
jbe@0 2265 ) THEN
jbe@463 2266 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.' USING
jbe@463 2267 ERRCODE = 'integrity_constraint_violation',
jbe@463 2268 HINT = 'Create suggestion and opinion within the same transaction.';
jbe@0 2269 END IF;
jbe@0 2270 RETURN NULL;
jbe@0 2271 END;
jbe@0 2272 $$;
jbe@0 2273
jbe@0 2274 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
jbe@0 2275 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
jbe@0 2276 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 2277 "suggestion_requires_first_opinion_trigger"();
jbe@0 2278
jbe@0 2279 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
jbe@0 2280 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
jbe@0 2281
jbe@0 2282
jbe@0 2283 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
jbe@0 2284 RETURNS TRIGGER
jbe@0 2285 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2286 DECLARE
jbe@0 2287 "reference_lost" BOOLEAN;
jbe@0 2288 BEGIN
jbe@0 2289 IF TG_OP = 'DELETE' THEN
jbe@0 2290 "reference_lost" := TRUE;
jbe@0 2291 ELSE
jbe@0 2292 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
jbe@0 2293 END IF;
jbe@0 2294 IF
jbe@0 2295 "reference_lost" AND NOT EXISTS (
jbe@0 2296 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
jbe@0 2297 )
jbe@0 2298 THEN
jbe@0 2299 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
jbe@0 2300 END IF;
jbe@0 2301 RETURN NULL;
jbe@0 2302 END;
jbe@0 2303 $$;
jbe@0 2304
jbe@0 2305 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
jbe@0 2306 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
jbe@0 2307 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 2308 "last_opinion_deletes_suggestion_trigger"();
jbe@0 2309
jbe@0 2310 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
jbe@0 2311 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
jbe@0 2312
jbe@0 2313
jbe@284 2314 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
jbe@284 2315 RETURNS TRIGGER
jbe@284 2316 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@284 2317 BEGIN
jbe@284 2318 DELETE FROM "direct_voter"
jbe@284 2319 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
jbe@284 2320 RETURN NULL;
jbe@284 2321 END;
jbe@284 2322 $$;
jbe@284 2323
jbe@284 2324 CREATE TRIGGER "non_voter_deletes_direct_voter"
jbe@284 2325 AFTER INSERT OR UPDATE ON "non_voter"
jbe@284 2326 FOR EACH ROW EXECUTE PROCEDURE
jbe@284 2327 "non_voter_deletes_direct_voter_trigger"();
jbe@284 2328
jbe@284 2329 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
jbe@284 2330 COMMENT ON TRIGGER "non_voter_deletes_direct_voter" ON "non_voter" IS 'An entry in the "non_voter" table deletes an entry in the "direct_voter" table (and vice versa due to trigger "direct_voter_deletes_non_voter" on table "direct_voter")';
jbe@284 2331
jbe@284 2332
jbe@284 2333 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
jbe@284 2334 RETURNS TRIGGER
jbe@284 2335 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@284 2336 BEGIN
jbe@284 2337 DELETE FROM "non_voter"
jbe@284 2338 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
jbe@284 2339 RETURN NULL;
jbe@284 2340 END;
jbe@284 2341 $$;
jbe@284 2342
jbe@284 2343 CREATE TRIGGER "direct_voter_deletes_non_voter"
jbe@284 2344 AFTER INSERT OR UPDATE ON "direct_voter"
jbe@284 2345 FOR EACH ROW EXECUTE PROCEDURE
jbe@284 2346 "direct_voter_deletes_non_voter_trigger"();
jbe@284 2347
jbe@284 2348 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
jbe@284 2349 COMMENT ON TRIGGER "direct_voter_deletes_non_voter" ON "direct_voter" IS 'An entry in the "direct_voter" table deletes an entry in the "non_voter" table (and vice versa due to trigger "non_voter_deletes_direct_voter" on table "non_voter")';
jbe@284 2350
jbe@284 2351
jbe@285 2352 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
jbe@285 2353 RETURNS TRIGGER
jbe@285 2354 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@285 2355 BEGIN
jbe@285 2356 IF NEW."comment" ISNULL THEN
jbe@285 2357 NEW."comment_changed" := NULL;
jbe@285 2358 NEW."formatting_engine" := NULL;
jbe@285 2359 END IF;
jbe@285 2360 RETURN NEW;
jbe@285 2361 END;
jbe@285 2362 $$;
jbe@285 2363
jbe@285 2364 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
jbe@285 2365 BEFORE INSERT OR UPDATE ON "direct_voter"
jbe@285 2366 FOR EACH ROW EXECUTE PROCEDURE
jbe@285 2367 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
jbe@285 2368
jbe@285 2369 COMMENT ON FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"() IS 'Implementation of trigger "voter_comment_fields_only_set_when_voter_comment_is_set" ON table "direct_voter"';
jbe@285 2370 COMMENT ON TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set" ON "direct_voter" IS 'If "comment" is set to NULL, then other comment related fields are also set to NULL.';
jbe@285 2371
jbe@0 2372
jbe@528 2373
jbe@528 2374 ---------------------------------
jbe@528 2375 -- Delete incomplete snapshots --
jbe@528 2376 ---------------------------------
jbe@528 2377
jbe@528 2378
jbe@528 2379 CREATE FUNCTION "delete_snapshot_on_partial_delete_trigger"()
jbe@528 2380 RETURNS TRIGGER
jbe@528 2381 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@528 2382 BEGIN
jbe@528 2383 DELETE FROM "snapshot" WHERE "id" = OLD."snapshot_id";
jbe@528 2384 RETURN NULL;
jbe@528 2385 END;
jbe@528 2386 $$;
jbe@528 2387
jbe@528 2388 CREATE TRIGGER "delete_snapshot_on_partial_delete"
jbe@528 2389 AFTER DELETE ON "snapshot_issue"
jbe@528 2390 FOR EACH ROW EXECUTE PROCEDURE
jbe@528 2391 "delete_snapshot_on_partial_delete_trigger"();
jbe@528 2392
jbe@528 2393 COMMENT ON FUNCTION "delete_snapshot_on_partial_delete_trigger"() IS 'Implementation of trigger "delete_snapshot_on_partial_delete" on table "snapshot_issue"';
jbe@528 2394 COMMENT ON TRIGGER "delete_snapshot_on_partial_delete" ON "snapshot_issue" IS 'Deletes whole snapshot if one issue is deleted from the snapshot';
jbe@528 2395
jbe@528 2396
jbe@528 2397
jbe@20 2398 ---------------------------------------------------------------
jbe@333 2399 -- Ensure that votes are not modified when issues are closed --
jbe@20 2400 ---------------------------------------------------------------
jbe@20 2401
jbe@20 2402 -- NOTE: Frontends should ensure this anyway, but in case of programming
jbe@20 2403 -- errors the following triggers ensure data integrity.
jbe@20 2404
jbe@20 2405
jbe@20 2406 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
jbe@20 2407 RETURNS TRIGGER
jbe@20 2408 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@20 2409 DECLARE
jbe@336 2410 "issue_id_v" "issue"."id"%TYPE;
jbe@336 2411 "issue_row" "issue"%ROWTYPE;
jbe@20 2412 BEGIN
jbe@383 2413 IF EXISTS (
jbe@385 2414 SELECT NULL FROM "temporary_transaction_data"
jbe@385 2415 WHERE "txid" = txid_current()
jbe@383 2416 AND "key" = 'override_protection_triggers'
jbe@383 2417 AND "value" = TRUE::TEXT
jbe@383 2418 ) THEN
jbe@383 2419 RETURN NULL;
jbe@383 2420 END IF;
jbe@32 2421 IF TG_OP = 'DELETE' THEN
jbe@32 2422 "issue_id_v" := OLD."issue_id";
jbe@32 2423 ELSE
jbe@32 2424 "issue_id_v" := NEW."issue_id";
jbe@32 2425 END IF;
jbe@20 2426 SELECT INTO "issue_row" * FROM "issue"
jbe@32 2427 WHERE "id" = "issue_id_v" FOR SHARE;
jbe@383 2428 IF (
jbe@383 2429 "issue_row"."closed" NOTNULL OR (
jbe@383 2430 "issue_row"."state" = 'voting' AND
jbe@383 2431 "issue_row"."phase_finished" NOTNULL
jbe@383 2432 )
jbe@383 2433 ) THEN
jbe@332 2434 IF
jbe@332 2435 TG_RELID = 'direct_voter'::regclass AND
jbe@332 2436 TG_OP = 'UPDATE'
jbe@332 2437 THEN
jbe@332 2438 IF
jbe@332 2439 OLD."issue_id" = NEW."issue_id" AND
jbe@332 2440 OLD."member_id" = NEW."member_id" AND
jbe@332 2441 OLD."weight" = NEW."weight"
jbe@332 2442 THEN
jbe@332 2443 RETURN NULL; -- allows changing of voter comment
jbe@332 2444 END IF;
jbe@332 2445 END IF;
jbe@463 2446 RAISE EXCEPTION 'Tried to modify data after voting has been closed.' USING
jbe@463 2447 ERRCODE = 'integrity_constraint_violation';
jbe@20 2448 END IF;
jbe@20 2449 RETURN NULL;
jbe@20 2450 END;
jbe@20 2451 $$;
jbe@20 2452
jbe@20 2453 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 2454 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
jbe@20 2455 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 2456 "forbid_changes_on_closed_issue_trigger"();
jbe@20 2457
jbe@20 2458 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 2459 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
jbe@20 2460 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 2461 "forbid_changes_on_closed_issue_trigger"();
jbe@20 2462
jbe@20 2463 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 2464 AFTER INSERT OR UPDATE OR DELETE ON "vote"
jbe@20 2465 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 2466 "forbid_changes_on_closed_issue_trigger"();
jbe@20 2467
jbe@20 2468 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 2469 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 2470 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 2471 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 2472
jbe@20 2473
jbe@20 2474
jbe@0 2475 --------------------------------------------------------------------
jbe@0 2476 -- Auto-retrieval of fields only needed for referential integrity --
jbe@0 2477 --------------------------------------------------------------------
jbe@0 2478
jbe@20 2479
jbe@457 2480 CREATE FUNCTION "autofill_unit_id_from_admission_rule_trigger"()
jbe@457 2481 RETURNS TRIGGER
jbe@457 2482 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@457 2483 BEGIN
jbe@457 2484 IF NEW."unit_id" ISNULL THEN
jbe@457 2485 SELECT "unit_id" INTO NEW."unit_id"
jbe@457 2486 FROM "admission_rule" WHERE "id" = NEW."admission_rule_id";
jbe@457 2487 END IF;
jbe@457 2488 RETURN NEW;
jbe@457 2489 END;
jbe@457 2490 $$;
jbe@457 2491
jbe@457 2492 CREATE TRIGGER "autofill_unit_id" BEFORE INSERT ON "admission_rule_condition"
jbe@457 2493 FOR EACH ROW EXECUTE PROCEDURE "autofill_unit_id_from_admission_rule_trigger"();
jbe@457 2494
jbe@457 2495 COMMENT ON FUNCTION "autofill_unit_id_from_admission_rule_trigger"() IS 'Implementation of trigger "autofill_admission_rule_id" on table "admission_rule_entry"';
jbe@457 2496 COMMENT ON TRIGGER "autofill_unit_id" ON "admission_rule_condition" IS 'Set "unit_id" field automatically, if NULL';
jbe@457 2497
jbe@457 2498
jbe@0 2499 CREATE FUNCTION "autofill_issue_id_trigger"()
jbe@0 2500 RETURNS TRIGGER
jbe@0 2501 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2502 BEGIN
jbe@0 2503 IF NEW."issue_id" ISNULL THEN
jbe@0 2504 SELECT "issue_id" INTO NEW."issue_id"
jbe@0 2505 FROM "initiative" WHERE "id" = NEW."initiative_id";
jbe@0 2506 END IF;
jbe@0 2507 RETURN NEW;
jbe@0 2508 END;
jbe@0 2509 $$;
jbe@0 2510
jbe@0 2511 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
jbe@0 2512 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
jbe@0 2513
jbe@0 2514 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
jbe@0 2515 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
jbe@0 2516
jbe@0 2517 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
jbe@0 2518 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
jbe@0 2519 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
jbe@0 2520
jbe@0 2521
jbe@0 2522 CREATE FUNCTION "autofill_initiative_id_trigger"()
jbe@0 2523 RETURNS TRIGGER
jbe@0 2524 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2525 BEGIN
jbe@0 2526 IF NEW."initiative_id" ISNULL THEN
jbe@0 2527 SELECT "initiative_id" INTO NEW."initiative_id"
jbe@0 2528 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
jbe@0 2529 END IF;
jbe@0 2530 RETURN NEW;
jbe@0 2531 END;
jbe@0 2532 $$;
jbe@0 2533
jbe@0 2534 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
jbe@0 2535 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
jbe@0 2536
jbe@0 2537 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
jbe@0 2538 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
jbe@0 2539
jbe@0 2540
jbe@0 2541
jbe@528 2542 -------------------------------------------------------
jbe@528 2543 -- Automatic copying of values for indexing purposes --
jbe@528 2544 -------------------------------------------------------
jbe@528 2545
jbe@528 2546
jbe@528 2547 CREATE FUNCTION "copy_current_draft_data"
jbe@528 2548 ("initiative_id_p" "initiative"."id"%TYPE )
jbe@528 2549 RETURNS VOID
jbe@528 2550 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@528 2551 BEGIN
jbe@528 2552 PERFORM NULL FROM "initiative" WHERE "id" = "initiative_id_p"
jbe@528 2553 FOR UPDATE;
jbe@528 2554 UPDATE "initiative" SET
jbe@528 2555 "latitude1" = "draft"."latitude1",
jbe@528 2556 "longitude1" = "draft"."longitude1",
jbe@528 2557 "latitude2" = "draft"."latitude2",
jbe@528 2558 "longitude2" = "draft"."longitude2",
jbe@528 2559 "draft_text_search_data" = "draft"."text_search_data"
jbe@528 2560 FROM "current_draft" AS "draft"
jbe@528 2561 WHERE "initiative"."id" = "initiative_id_p"
jbe@528 2562 AND "draft"."initiative_id" = "initiative_id_p";
jbe@528 2563 END;
jbe@528 2564 $$;
jbe@528 2565
jbe@528 2566 COMMENT ON FUNCTION "copy_current_draft_data"
jbe@528 2567 ( "initiative"."id"%TYPE )
jbe@528 2568 IS 'Helper function for function "copy_current_draft_data_trigger"';
jbe@528 2569
jbe@528 2570
jbe@528 2571 CREATE FUNCTION "copy_current_draft_data_trigger"()
jbe@528 2572 RETURNS TRIGGER
jbe@528 2573 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@528 2574 BEGIN
jbe@528 2575 IF TG_OP='DELETE' THEN
jbe@528 2576 PERFORM "copy_current_draft_data"(OLD."initiative_id");
jbe@528 2577 ELSE
jbe@528 2578 IF TG_OP='UPDATE' THEN
jbe@528 2579 IF COALESCE(OLD."inititiave_id" != NEW."initiative_id", TRUE) THEN
jbe@528 2580 PERFORM "copy_current_draft_data"(OLD."initiative_id");
jbe@528 2581 END IF;
jbe@528 2582 END IF;
jbe@528 2583 PERFORM "copy_current_draft_data"(NEW."initiative_id");
jbe@528 2584 END IF;
jbe@528 2585 RETURN NULL;
jbe@528 2586 END;
jbe@528 2587 $$;
jbe@528 2588
jbe@528 2589 CREATE TRIGGER "copy_current_draft_data"
jbe@528 2590 AFTER INSERT OR UPDATE OR DELETE ON "draft"
jbe@528 2591 FOR EACH ROW EXECUTE PROCEDURE
jbe@528 2592 "copy_current_draft_data_trigger"();
jbe@528 2593
jbe@528 2594 COMMENT ON FUNCTION "copy_current_draft_data_trigger"() IS 'Implementation of trigger "copy_current_draft_data" on table "draft"';
jbe@528 2595 COMMENT ON TRIGGER "copy_current_draft_data" ON "draft" IS 'Copy certain fields from most recent "draft" to "initiative"';
jbe@528 2596
jbe@528 2597
jbe@528 2598
jbe@4 2599 -----------------------------------------------------
jbe@4 2600 -- Automatic calculation of certain default values --
jbe@4 2601 -----------------------------------------------------
jbe@0 2602
jbe@22 2603
jbe@22 2604 CREATE FUNCTION "copy_timings_trigger"()
jbe@22 2605 RETURNS TRIGGER
jbe@22 2606 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@22 2607 DECLARE
jbe@22 2608 "policy_row" "policy"%ROWTYPE;
jbe@22 2609 BEGIN
jbe@22 2610 SELECT * INTO "policy_row" FROM "policy"
jbe@22 2611 WHERE "id" = NEW."policy_id";
jbe@447 2612 IF NEW."min_admission_time" ISNULL THEN
jbe@447 2613 NEW."min_admission_time" := "policy_row"."min_admission_time";
jbe@447 2614 END IF;
jbe@447 2615 IF NEW."max_admission_time" ISNULL THEN
jbe@447 2616 NEW."max_admission_time" := "policy_row"."max_admission_time";
jbe@22 2617 END IF;
jbe@22 2618 IF NEW."discussion_time" ISNULL THEN
jbe@22 2619 NEW."discussion_time" := "policy_row"."discussion_time";
jbe@22 2620 END IF;
jbe@22 2621 IF NEW."verification_time" ISNULL THEN
jbe@22 2622 NEW."verification_time" := "policy_row"."verification_time";
jbe@22 2623 END IF;
jbe@22 2624 IF NEW."voting_time" ISNULL THEN
jbe@22 2625 NEW."voting_time" := "policy_row"."voting_time";
jbe@22 2626 END IF;
jbe@22 2627 RETURN NEW;
jbe@22 2628 END;
jbe@22 2629 $$;
jbe@22 2630
jbe@22 2631 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
jbe@22 2632 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
jbe@22 2633
jbe@22 2634 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
jbe@22 2635 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
jbe@22 2636
jbe@22 2637
jbe@160 2638 CREATE FUNCTION "default_for_draft_id_trigger"()
jbe@2 2639 RETURNS TRIGGER
jbe@2 2640 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@2 2641 BEGIN
jbe@2 2642 IF NEW."draft_id" ISNULL THEN
jbe@2 2643 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
jbe@2 2644 WHERE "initiative_id" = NEW."initiative_id";
jbe@2 2645 END IF;
jbe@2 2646 RETURN NEW;
jbe@2 2647 END;
jbe@2 2648 $$;
jbe@2 2649
jbe@160 2650 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
jbe@160 2651 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
jbe@2 2652 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
jbe@160 2653 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
jbe@160 2654
jbe@160 2655 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
jbe@160 2656 COMMENT ON TRIGGER "default_for_draft_id" ON "suggestion" IS 'If "draft_id" is NULL, then use the current draft of the initiative as default';
jbe@160 2657 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 2658
jbe@2 2659
jbe@0 2660
jbe@0 2661 ----------------------------------------
jbe@0 2662 -- Automatic creation of dependencies --
jbe@0 2663 ----------------------------------------
jbe@0 2664
jbe@22 2665
jbe@0 2666 CREATE FUNCTION "autocreate_interest_trigger"()
jbe@0 2667 RETURNS TRIGGER
jbe@0 2668 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2669 BEGIN
jbe@0 2670 IF NOT EXISTS (
jbe@0 2671 SELECT NULL FROM "initiative" JOIN "interest"
jbe@0 2672 ON "initiative"."issue_id" = "interest"."issue_id"
jbe@0 2673 WHERE "initiative"."id" = NEW."initiative_id"
jbe@0 2674 AND "interest"."member_id" = NEW."member_id"
jbe@0 2675 ) THEN
jbe@0 2676 BEGIN
jbe@0 2677 INSERT INTO "interest" ("issue_id", "member_id")
jbe@0 2678 SELECT "issue_id", NEW."member_id"
jbe@0 2679 FROM "initiative" WHERE "id" = NEW."initiative_id";
jbe@0 2680 EXCEPTION WHEN unique_violation THEN END;
jbe@0 2681 END IF;
jbe@0 2682 RETURN NEW;
jbe@0 2683 END;
jbe@0 2684 $$;
jbe@0 2685
jbe@0 2686 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
jbe@0 2687 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
jbe@0 2688
jbe@0 2689 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
jbe@0 2690 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 2691
jbe@0 2692
jbe@0 2693 CREATE FUNCTION "autocreate_supporter_trigger"()
jbe@0 2694 RETURNS TRIGGER
jbe@0 2695 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2696 BEGIN
jbe@0 2697 IF NOT EXISTS (
jbe@0 2698 SELECT NULL FROM "suggestion" JOIN "supporter"
jbe@0 2699 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
jbe@0 2700 WHERE "suggestion"."id" = NEW."suggestion_id"
jbe@0 2701 AND "supporter"."member_id" = NEW."member_id"
jbe@0 2702 ) THEN
jbe@0 2703 BEGIN
jbe@0 2704 INSERT INTO "supporter" ("initiative_id", "member_id")
jbe@0 2705 SELECT "initiative_id", NEW."member_id"
jbe@0 2706 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
jbe@0 2707 EXCEPTION WHEN unique_violation THEN END;
jbe@0 2708 END IF;
jbe@0 2709 RETURN NEW;
jbe@0 2710 END;
jbe@0 2711 $$;
jbe@0 2712
jbe@0 2713 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
jbe@0 2714 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
jbe@0 2715
jbe@0 2716 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
jbe@0 2717 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 2718
jbe@0 2719
jbe@0 2720
jbe@0 2721 ------------------------------------------
jbe@0 2722 -- Views and helper functions for views --
jbe@0 2723 ------------------------------------------
jbe@0 2724
jbe@5 2725
jbe@524 2726 CREATE VIEW "member_eligible_to_be_notified" AS
jbe@524 2727 SELECT * FROM "member"
jbe@524 2728 WHERE "activated" NOTNULL AND "locked" = FALSE;
jbe@524 2729
jbe@524 2730 COMMENT ON VIEW "member_eligible_to_be_notified" IS 'Filtered "member" table containing only activated and non-locked members (used as helper view for "member_to_notify" and "newsletter_to_send")';
jbe@524 2731
jbe@524 2732
jbe@524 2733 CREATE VIEW "member_to_notify" AS
jbe@524 2734 SELECT * FROM "member_eligible_to_be_notified"
jbe@524 2735 WHERE "disable_notifications" = FALSE;
jbe@524 2736
jbe@524 2737 COMMENT ON VIEW "member_to_notify" IS 'Filtered "member" table containing only members that are eligible to and wish to receive notifications; NOTE: "notify_email" may still be NULL and might need to be checked by frontend (this allows other means of messaging)';
jbe@524 2738
jbe@524 2739
jbe@457 2740 CREATE VIEW "matching_admission_rule_condition" AS
jbe@457 2741 SELECT DISTINCT ON ("issue_id", "admission_rule_condition"."admission_rule_id")
jbe@457 2742 "issue"."id" AS "issue_id",
jbe@457 2743 "admission_rule_condition".*
jbe@457 2744 FROM "admission_rule_condition"
jbe@457 2745 JOIN "area" ON "admission_rule_condition"."unit_id" = "area"."unit_id"
jbe@457 2746 JOIN "issue" ON "area"."id" = "issue"."area_id"
jbe@457 2747 WHERE (
jbe@457 2748 "admission_rule_condition"."policy_id" ISNULL OR
jbe@457 2749 "admission_rule_condition"."policy_id" = "issue"."policy_id"
jbe@457 2750 ) AND (
jbe@457 2751 "admission_rule_condition"."area_id" ISNULL OR
jbe@457 2752 "admission_rule_condition"."area_id" = "area"."id"
jbe@457 2753 )
jbe@457 2754 ORDER BY
jbe@457 2755 "issue_id",
jbe@457 2756 "admission_rule_condition"."admission_rule_id",
jbe@457 2757 "admission_rule_condition"."policy_id" ISNULL,
jbe@457 2758 "admission_rule_condition"."area_id" ISNULL;
jbe@457 2759
jbe@457 2760 COMMENT ON VIEW "matching_admission_rule_condition" IS 'Selects the most fitting "admission_rule_condition" for a given pair of "issue" and "admission_rule"';
jbe@457 2761
jbe@457 2762
jbe@457 2763 CREATE VIEW "applicable_admission_rule" AS
jbe@457 2764 SELECT * FROM "admission_rule"
jbe@457 2765 WHERE NOT EXISTS (
jbe@457 2766 SELECT NULL FROM "issue"
jbe@457 2767 JOIN "matching_admission_rule_condition" AS "condition"
jbe@457 2768 ON "issue"."id" = "condition"."issue_id"
jbe@457 2769 WHERE "condition"."admission_rule_id" = "admission_rule"."id"
jbe@457 2770 AND "issue"."accepted" > now() - "condition"."holdoff_time"
jbe@457 2771 );
jbe@457 2772
jbe@457 2773 COMMENT ON VIEW "applicable_admission_rule" IS 'Filters "admission_rule"s which are not blocked by a recently admitted issue';
jbe@457 2774
jbe@457 2775
jbe@457 2776 CREATE VIEW "issue_for_admission" AS
jbe@457 2777 SELECT
jbe@457 2778 "issue".*,
jbe@457 2779 max("initiative"."supporter_count") AS "max_supporter_count"
jbe@457 2780 FROM "issue"
jbe@528 2781 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
jbe@457 2782 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
jbe@457 2783 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@457 2784 JOIN "admission_rule_condition"
jbe@457 2785 ON "admission_rule_condition"."unit_id" = "area"."unit_id"
jbe@457 2786 AND (
jbe@457 2787 "admission_rule_condition"."policy_id" ISNULL OR
jbe@457 2788 "admission_rule_condition"."policy_id" = "issue"."policy_id"
jbe@457 2789 )
jbe@457 2790 AND (
jbe@457 2791 "admission_rule_condition"."area_id" ISNULL OR
jbe@528 2792 "admission_rule_condition"."area_id" = "issue"."area_id"
jbe@457 2793 )
jbe@457 2794 JOIN "applicable_admission_rule"
jbe@457 2795 ON "admission_rule_condition"."admission_rule_id" = "applicable_admission_rule"."id"
jbe@457 2796 WHERE "issue"."state" = 'admission'::"issue_state"
jbe@528 2797 AND now() >= "issue"."created" + "issue"."min_admission_time"
jbe@528 2798 AND "initiative"."supporter_count" >= "policy"."issue_quorum"
jbe@528 2799 AND "initiative"."revoked" ISNULL
jbe@457 2800 GROUP BY "issue"."id"
jbe@528 2801 ORDER BY "max_supporter_count" DESC, "issue"."id"
jbe@528 2802 LIMIT 1;
jbe@528 2803
jbe@528 2804 COMMENT ON VIEW "issue_for_admission" IS 'Contains up to 1 issue eligible to pass from ''admission'' to ''discussion'' state; needs to be recalculated after admitting the issue in this view';
jbe@457 2805
jbe@457 2806
jbe@97 2807 CREATE VIEW "unit_delegation" AS
jbe@97 2808 SELECT
jbe@97 2809 "unit"."id" AS "unit_id",
jbe@97 2810 "delegation"."id",
jbe@97 2811 "delegation"."truster_id",
jbe@97 2812 "delegation"."trustee_id",
jbe@97 2813 "delegation"."scope"
jbe@97 2814 FROM "unit"
jbe@97 2815 JOIN "delegation"
jbe@97 2816 ON "delegation"."unit_id" = "unit"."id"
jbe@97 2817 JOIN "member"
jbe@97 2818 ON "delegation"."truster_id" = "member"."id"
jbe@97 2819 JOIN "privilege"
jbe@97 2820 ON "delegation"."unit_id" = "privilege"."unit_id"
jbe@97 2821 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@97 2822 WHERE "member"."active" AND "privilege"."voting_right";
jbe@97 2823
jbe@97 2824 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
jbe@5 2825
jbe@5 2826
jbe@5 2827 CREATE VIEW "area_delegation" AS
jbe@70 2828 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
jbe@70 2829 "area"."id" AS "area_id",
jbe@70 2830 "delegation"."id",
jbe@70 2831 "delegation"."truster_id",
jbe@70 2832 "delegation"."trustee_id",
jbe@70 2833 "delegation"."scope"
jbe@97 2834 FROM "area"
jbe@97 2835 JOIN "delegation"
jbe@97 2836 ON "delegation"."unit_id" = "area"."unit_id"
jbe@97 2837 OR "delegation"."area_id" = "area"."id"
jbe@97 2838 JOIN "member"
jbe@97 2839 ON "delegation"."truster_id" = "member"."id"
jbe@97 2840 JOIN "privilege"
jbe@97 2841 ON "area"."unit_id" = "privilege"."unit_id"
jbe@97 2842 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@97 2843 WHERE "member"."active" AND "privilege"."voting_right"
jbe@70 2844 ORDER BY
jbe@70 2845 "area"."id",
jbe@70 2846 "delegation"."truster_id",
jbe@70 2847 "delegation"."scope" DESC;
jbe@70 2848
jbe@97 2849 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
jbe@5 2850
jbe@5 2851
jbe@5 2852 CREATE VIEW "issue_delegation" AS
jbe@70 2853 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
jbe@70 2854 "issue"."id" AS "issue_id",
jbe@70 2855 "delegation"."id",
jbe@70 2856 "delegation"."truster_id",
jbe@70 2857 "delegation"."trustee_id",
jbe@70 2858 "delegation"."scope"
jbe@97 2859 FROM "issue"
jbe@97 2860 JOIN "area"
jbe@97 2861 ON "area"."id" = "issue"."area_id"
jbe@97 2862 JOIN "delegation"
jbe@97 2863 ON "delegation"."unit_id" = "area"."unit_id"
jbe@97 2864 OR "delegation"."area_id" = "area"."id"
jbe@97 2865 OR "delegation"."issue_id" = "issue"."id"
jbe@97 2866 JOIN "member"
jbe@97 2867 ON "delegation"."truster_id" = "member"."id"
jbe@97 2868 JOIN "privilege"
jbe@97 2869 ON "area"."unit_id" = "privilege"."unit_id"
jbe@97 2870 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@97 2871 WHERE "member"."active" AND "privilege"."voting_right"
jbe@70 2872 ORDER BY
jbe@70 2873 "issue"."id",
jbe@70 2874 "delegation"."truster_id",
jbe@70 2875 "delegation"."scope" DESC;
jbe@70 2876
jbe@97 2877 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
jbe@5 2878
jbe@5 2879
jbe@4 2880 CREATE VIEW "member_count_view" AS
jbe@5 2881 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
jbe@4 2882
jbe@4 2883 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
jbe@4 2884
jbe@4 2885
jbe@97 2886 CREATE VIEW "unit_member_count" AS
jbe@97 2887 SELECT
jbe@97 2888 "unit"."id" AS "unit_id",
jbe@248 2889 count("member"."id") AS "member_count"
jbe@97 2890 FROM "unit"
jbe@97 2891 LEFT JOIN "privilege"
jbe@97 2892 ON "privilege"."unit_id" = "unit"."id"
jbe@97 2893 AND "privilege"."voting_right"
jbe@97 2894 LEFT JOIN "member"
jbe@97 2895 ON "member"."id" = "privilege"."member_id"
jbe@97 2896 AND "member"."active"
jbe@97 2897 GROUP BY "unit"."id";
jbe@97 2898
jbe@97 2899 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
jbe@97 2900
jbe@97 2901
jbe@9 2902 CREATE VIEW "opening_draft" AS
jbe@528 2903 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
jbe@528 2904 ORDER BY "initiative_id", "id";
jbe@9 2905
jbe@9 2906 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
jbe@9 2907
jbe@9 2908
jbe@0 2909 CREATE VIEW "current_draft" AS
jbe@528 2910 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
jbe@528 2911 ORDER BY "initiative_id", "id" DESC;
jbe@0 2912
jbe@0 2913 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
jbe@0 2914
jbe@0 2915
jbe@0 2916 CREATE VIEW "critical_opinion" AS
jbe@0 2917 SELECT * FROM "opinion"
jbe@0 2918 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
jbe@0 2919 OR ("degree" = -2 AND "fulfilled" = TRUE);
jbe@0 2920
jbe@0 2921 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
jbe@0 2922
jbe@0 2923
jbe@392 2924 CREATE VIEW "issue_supporter_in_admission_state" AS
jbe@528 2925 SELECT
jbe@410 2926 "area"."unit_id",
jbe@392 2927 "issue"."area_id",
jbe@392 2928 "issue"."id" AS "issue_id",
jbe@392 2929 "supporter"."member_id",
jbe@392 2930 "direct_interest_snapshot"."weight"
jbe@392 2931 FROM "issue"
jbe@410 2932 JOIN "area" ON "area"."id" = "issue"."area_id"
jbe@392 2933 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
jbe@392 2934 JOIN "direct_interest_snapshot"
jbe@528 2935 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
jbe@528 2936 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
jbe@392 2937 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
jbe@392 2938 WHERE "issue"."state" = 'admission'::"issue_state";
jbe@392 2939
jbe@392 2940 COMMENT ON VIEW "issue_supporter_in_admission_state" IS 'Helper view for "lf_update_issue_order" to allow a (proportional) ordering of issues within an area';
jbe@392 2941
jbe@392 2942
jbe@352 2943 CREATE VIEW "initiative_suggestion_order_calculation" AS
jbe@352 2944 SELECT
jbe@352 2945 "initiative"."id" AS "initiative_id",
jbe@352 2946 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
jbe@352 2947 FROM "initiative" JOIN "issue"
jbe@352 2948 ON "initiative"."issue_id" = "issue"."id"
jbe@352 2949 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
jbe@352 2950 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
jbe@352 2951
jbe@352 2952 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
jbe@352 2953
jbe@360 2954 COMMENT ON COLUMN "initiative_suggestion_order_calculation"."final" IS 'Set to TRUE, if the issue is fully frozen or closed, and the calculation has to be done only once for one last time';
jbe@352 2955
jbe@352 2956
jbe@352 2957 CREATE VIEW "individual_suggestion_ranking" AS
jbe@352 2958 SELECT
jbe@352 2959 "opinion"."initiative_id",
jbe@352 2960 "opinion"."member_id",
jbe@352 2961 "direct_interest_snapshot"."weight",
jbe@352 2962 CASE WHEN
jbe@352 2963 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
jbe@352 2964 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
jbe@352 2965 THEN 1 ELSE
jbe@352 2966 CASE WHEN
jbe@352 2967 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
jbe@352 2968 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
jbe@352 2969 THEN 2 ELSE
jbe@352 2970 CASE WHEN
jbe@352 2971 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
jbe@352 2972 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
jbe@352 2973 THEN 3 ELSE 4 END
jbe@352 2974 END
jbe@352 2975 END AS "preference",
jbe@352 2976 "opinion"."suggestion_id"
jbe@352 2977 FROM "opinion"
jbe@352 2978 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
jbe@352 2979 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@352 2980 JOIN "direct_interest_snapshot"
jbe@528 2981 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
jbe@528 2982 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
jbe@352 2983 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
jbe@352 2984
jbe@352 2985 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
jbe@352 2986
jbe@352 2987
jbe@126 2988 CREATE VIEW "battle_participant" AS
jbe@126 2989 SELECT "initiative"."id", "initiative"."issue_id"
jbe@126 2990 FROM "issue" JOIN "initiative"
jbe@126 2991 ON "issue"."id" = "initiative"."issue_id"
jbe@126 2992 WHERE "initiative"."admitted"
jbe@126 2993 UNION ALL
jbe@126 2994 SELECT NULL, "id" AS "issue_id"
jbe@126 2995 FROM "issue";
jbe@126 2996
jbe@126 2997 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 2998
jbe@126 2999
jbe@61 3000 CREATE VIEW "battle_view" AS
jbe@0 3001 SELECT
jbe@0 3002 "issue"."id" AS "issue_id",
jbe@10 3003 "winning_initiative"."id" AS "winning_initiative_id",
jbe@10 3004 "losing_initiative"."id" AS "losing_initiative_id",
jbe@0 3005 sum(
jbe@0 3006 CASE WHEN
jbe@0 3007 coalesce("better_vote"."grade", 0) >
jbe@0 3008 coalesce("worse_vote"."grade", 0)
jbe@0 3009 THEN "direct_voter"."weight" ELSE 0 END
jbe@0 3010 ) AS "count"
jbe@0 3011 FROM "issue"
jbe@0 3012 LEFT JOIN "direct_voter"
jbe@0 3013 ON "issue"."id" = "direct_voter"."issue_id"
jbe@126 3014 JOIN "battle_participant" AS "winning_initiative"
jbe@10 3015 ON "issue"."id" = "winning_initiative"."issue_id"
jbe@126 3016 JOIN "battle_participant" AS "losing_initiative"
jbe@10 3017 ON "issue"."id" = "losing_initiative"."issue_id"
jbe@0 3018 LEFT JOIN "vote" AS "better_vote"
jbe@10 3019 ON "direct_voter"."member_id" = "better_vote"."member_id"
jbe@10 3020 AND "winning_initiative"."id" = "better_vote"."initiative_id"
jbe@0 3021 LEFT JOIN "vote" AS "worse_vote"
jbe@10 3022 ON "direct_voter"."member_id" = "worse_vote"."member_id"
jbe@10 3023 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
jbe@328 3024 WHERE "issue"."state" = 'voting'
jbe@328 3025 AND "issue"."phase_finished" NOTNULL
jbe@126 3026 AND (
jbe@126 3027 "winning_initiative"."id" != "losing_initiative"."id" OR
jbe@126 3028 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
jbe@126 3029 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
jbe@0 3030 GROUP BY
jbe@0 3031 "issue"."id",
jbe@10 3032 "winning_initiative"."id",
jbe@10 3033 "losing_initiative"."id";
jbe@0 3034
jbe@126 3035 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@1 3036
jbe@1 3037
jbe@235 3038 CREATE VIEW "expired_session" AS
jbe@235 3039 SELECT * FROM "session" WHERE now() > "expiry";
jbe@235 3040
jbe@235 3041 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
jbe@235 3042 DELETE FROM "session" WHERE "ident" = OLD."ident";
jbe@235 3043
jbe@235 3044 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
jbe@235 3045 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
jbe@235 3046
jbe@235 3047
jbe@0 3048 CREATE VIEW "open_issue" AS
jbe@0 3049 SELECT * FROM "issue" WHERE "closed" ISNULL;
jbe@0 3050
jbe@0 3051 COMMENT ON VIEW "open_issue" IS 'All open issues';
jbe@0 3052
jbe@0 3053
jbe@9 3054 CREATE VIEW "member_contingent" AS
jbe@9 3055 SELECT
jbe@9 3056 "member"."id" AS "member_id",
jbe@293 3057 "contingent"."polling",
jbe@9 3058 "contingent"."time_frame",
jbe@9 3059 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
jbe@9 3060 (
jbe@9 3061 SELECT count(1) FROM "draft"
jbe@293 3062 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
jbe@9 3063 WHERE "draft"."author_id" = "member"."id"
jbe@293 3064 AND "initiative"."polling" = "contingent"."polling"
jbe@9 3065 AND "draft"."created" > now() - "contingent"."time_frame"
jbe@9 3066 ) + (
jbe@9 3067 SELECT count(1) FROM "suggestion"
jbe@293 3068 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
jbe@9 3069 WHERE "suggestion"."author_id" = "member"."id"
jbe@293 3070 AND "contingent"."polling" = FALSE
jbe@9 3071 AND "suggestion"."created" > now() - "contingent"."time_frame"
jbe@9 3072 )
jbe@9 3073 ELSE NULL END AS "text_entry_count",
jbe@9 3074 "contingent"."text_entry_limit",
jbe@9 3075 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
jbe@293 3076 SELECT count(1) FROM "opening_draft" AS "draft"
jbe@293 3077 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
jbe@293 3078 WHERE "draft"."author_id" = "member"."id"
jbe@293 3079 AND "initiative"."polling" = "contingent"."polling"
jbe@293 3080 AND "draft"."created" > now() - "contingent"."time_frame"
jbe@9 3081 ) ELSE NULL END AS "initiative_count",
jbe@9 3082 "contingent"."initiative_limit"
jbe@9 3083 FROM "member" CROSS JOIN "contingent";
jbe@9 3084
jbe@9 3085 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 3086
jbe@9 3087 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
jbe@9 3088 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
jbe@9 3089
jbe@9 3090
jbe@9 3091 CREATE VIEW "member_contingent_left" AS
jbe@9 3092 SELECT
jbe@9 3093 "member_id",
jbe@293 3094 "polling",
jbe@9 3095 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
jbe@9 3096 max("initiative_limit" - "initiative_count") AS "initiatives_left"
jbe@293 3097 FROM "member_contingent" GROUP BY "member_id", "polling";
jbe@9 3098
jbe@9 3099 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 3100
jbe@9 3101
jbe@499 3102 CREATE VIEW "event_for_notification" AS
jbe@113 3103 SELECT
jbe@499 3104 "member"."id" AS "recipient_id",
jbe@113 3105 "event".*
jbe@113 3106 FROM "member" CROSS JOIN "event"
jbe@499 3107 JOIN "issue" ON "issue"."id" = "event"."issue_id"
jbe@499 3108 JOIN "area" ON "area"."id" = "issue"."area_id"
jbe@499 3109 LEFT JOIN "privilege" ON
jbe@499 3110 "privilege"."member_id" = "member"."id" AND
jbe@499 3111 "privilege"."unit_id" = "area"."unit_id" AND
jbe@499 3112 "privilege"."voting_right" = TRUE
jbe@499 3113 LEFT JOIN "subscription" ON
jbe@499 3114 "subscription"."member_id" = "member"."id" AND
jbe@499 3115 "subscription"."unit_id" = "area"."unit_id"
jbe@499 3116 LEFT JOIN "ignored_area" ON
jbe@499 3117 "ignored_area"."member_id" = "member"."id" AND
jbe@499 3118 "ignored_area"."area_id" = "issue"."area_id"
jbe@499 3119 LEFT JOIN "interest" ON
jbe@499 3120 "interest"."member_id" = "member"."id" AND
jbe@499 3121 "interest"."issue_id" = "event"."issue_id"
jbe@499 3122 LEFT JOIN "supporter" ON
jbe@499 3123 "supporter"."member_id" = "member"."id" AND
jbe@499 3124 "supporter"."initiative_id" = "event"."initiative_id"
jbe@499 3125 WHERE ("privilege"."member_id" NOTNULL OR "subscription"."member_id" NOTNULL)
jbe@499 3126 AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL)
jbe@499 3127 AND (
jbe@499 3128 "event"."event" = 'issue_state_changed'::"event_type" OR
jbe@499 3129 ( "event"."event" = 'initiative_revoked'::"event_type" AND
jbe@499 3130 "supporter"."member_id" NOTNULL ) );
jbe@499 3131
jbe@508 3132 COMMENT ON VIEW "event_for_notification" IS 'Entries of the "event" table which are of interest for a particular notification mail recipient';
jbe@508 3133
jbe@508 3134 COMMENT ON COLUMN "event_for_notification"."recipient_id" IS 'member_id of the recipient of a notification mail';
jbe@222 3135
jbe@222 3136
jbe@473 3137 CREATE VIEW "updated_initiative" AS
jbe@113 3138 SELECT
jbe@499 3139 "supporter"."member_id" AS "recipient_id",
jbe@477 3140 FALSE AS "featured",
jbe@499 3141 "supporter"."initiative_id"
jbe@499 3142 FROM "supporter"
jbe@499 3143 JOIN "initiative" ON "supporter"."initiative_id" = "initiative"."id"
jbe@473 3144 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@507 3145 LEFT JOIN "notification_initiative_sent" AS "sent" ON
jbe@499 3146 "sent"."member_id" = "supporter"."member_id" AND
jbe@499 3147 "sent"."initiative_id" = "supporter"."initiative_id"
jbe@499 3148 LEFT JOIN "ignored_initiative" ON
jbe@499 3149 "ignored_initiative"."member_id" = "supporter"."member_id" AND
jbe@499 3150 "ignored_initiative"."initiative_id" = "supporter"."initiative_id"
jbe@480 3151 WHERE "issue"."state" IN ('admission', 'discussion')
jbe@503 3152 AND "initiative"."revoked" ISNULL
jbe@499 3153 AND "ignored_initiative"."member_id" ISNULL
jbe@473 3154 AND (
jbe@473 3155 EXISTS (
jbe@473 3156 SELECT NULL FROM "draft"
jbe@499 3157 LEFT JOIN "ignored_member" ON
jbe@499 3158 "ignored_member"."member_id" = "supporter"."member_id" AND
jbe@499 3159 "ignored_member"."other_member_id" = "draft"."author_id"
jbe@499 3160 WHERE "draft"."initiative_id" = "supporter"."initiative_id"
jbe@473 3161 AND "draft"."id" > "supporter"."draft_id"
jbe@499 3162 AND "ignored_member"."member_id" ISNULL
jbe@473 3163 ) OR EXISTS (
jbe@473 3164 SELECT NULL FROM "suggestion"
jbe@487 3165 LEFT JOIN "opinion" ON
jbe@487 3166 "opinion"."member_id" = "supporter"."member_id" AND
jbe@487 3167 "opinion"."suggestion_id" = "suggestion"."id"
jbe@499 3168 LEFT JOIN "ignored_member" ON
jbe@499 3169 "ignored_member"."member_id" = "supporter"."member_id" AND
jbe@499 3170 "ignored_member"."other_member_id" = "suggestion"."author_id"
jbe@499 3171 WHERE "suggestion"."initiative_id" = "supporter"."initiative_id"
jbe@487 3172 AND "opinion"."member_id" ISNULL
jbe@499 3173 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
jbe@499 3174 AND "ignored_member"."member_id" ISNULL
jbe@473 3175 )
jbe@473 3176 );
jbe@473 3177
jbe@508 3178 COMMENT ON VIEW "updated_initiative" IS 'Helper view for view "updated_or_featured_initiative"';
jbe@508 3179
jbe@508 3180
jbe@474 3181 CREATE FUNCTION "featured_initiative"
jbe@499 3182 ( "recipient_id_p" "member"."id"%TYPE,
jbe@499 3183 "area_id_p" "area"."id"%TYPE )
jbe@499 3184 RETURNS SETOF "initiative"."id"%TYPE
jbe@474 3185 LANGUAGE 'plpgsql' STABLE AS $$
jbe@474 3186 DECLARE
jbe@499 3187 "counter_v" "member"."notification_counter"%TYPE;
jbe@499 3188 "sample_size_v" "member"."notification_sample_size"%TYPE;
jbe@499 3189 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
jbe@499 3190 "match_v" BOOLEAN;
jbe@474 3191 "member_id_v" "member"."id"%TYPE;
jbe@474 3192 "seed_v" TEXT;
jbe@499 3193 "initiative_id_v" "initiative"."id"%TYPE;
jbe@474 3194 BEGIN
jbe@499 3195 SELECT "notification_counter", "notification_sample_size"
jbe@499 3196 INTO "counter_v", "sample_size_v"
jbe@499 3197 FROM "member" WHERE "id" = "recipient_id_p";
jbe@520 3198 IF COALESCE("sample_size_v" <= 0, TRUE) THEN
jbe@520 3199 RETURN;
jbe@520 3200 END IF;
jbe@474 3201 "initiative_id_ary" := '{}';
jbe@474 3202 LOOP
jbe@474 3203 "match_v" := FALSE;
jbe@474 3204 FOR "member_id_v", "seed_v" IN
jbe@474 3205 SELECT * FROM (
jbe@474 3206 SELECT DISTINCT
jbe@474 3207 "supporter"."member_id",
jbe@499 3208 md5(
jbe@499 3209 "recipient_id_p" || '-' ||
jbe@499 3210 "counter_v" || '-' ||
jbe@499 3211 "area_id_p" || '-' ||
jbe@499 3212 "supporter"."member_id"
jbe@499 3213 ) AS "seed"
jbe@474 3214 FROM "supporter"
jbe@474 3215 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
jbe@474 3216 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@499 3217 WHERE "supporter"."member_id" != "recipient_id_p"
jbe@474 3218 AND "issue"."area_id" = "area_id_p"
jbe@474 3219 AND "issue"."state" IN ('admission', 'discussion', 'verification')
jbe@474 3220 ) AS "subquery"
jbe@474 3221 ORDER BY "seed"
jbe@474 3222 LOOP
jbe@499 3223 SELECT "initiative"."id" INTO "initiative_id_v"
jbe@476 3224 FROM "initiative"
jbe@474 3225 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@499 3226 JOIN "area" ON "area"."id" = "issue"."area_id"
jbe@474 3227 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
jbe@474 3228 LEFT JOIN "supporter" AS "self_support" ON
jbe@474 3229 "self_support"."initiative_id" = "initiative"."id" AND
jbe@499 3230 "self_support"."member_id" = "recipient_id_p"
jbe@499 3231 LEFT JOIN "privilege" ON
jbe@499 3232 "privilege"."member_id" = "recipient_id_p" AND
jbe@499 3233 "privilege"."unit_id" = "area"."unit_id" AND
jbe@499 3234 "privilege"."voting_right" = TRUE
jbe@499 3235 LEFT JOIN "subscription" ON
jbe@499 3236 "subscription"."member_id" = "recipient_id_p" AND
jbe@499 3237 "subscription"."unit_id" = "area"."unit_id"
jbe@499 3238 LEFT JOIN "ignored_initiative" ON
jbe@499 3239 "ignored_initiative"."member_id" = "recipient_id_p" AND
jbe@499 3240 "ignored_initiative"."initiative_id" = "initiative"."id"
jbe@474 3241 WHERE "supporter"."member_id" = "member_id_v"
jbe@474 3242 AND "issue"."area_id" = "area_id_p"
jbe@474 3243 AND "issue"."state" IN ('admission', 'discussion', 'verification')
jbe@503 3244 AND "initiative"."revoked" ISNULL
jbe@474 3245 AND "self_support"."member_id" ISNULL
jbe@476 3246 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
jbe@499 3247 AND (
jbe@499 3248 "privilege"."member_id" NOTNULL OR
jbe@499 3249 "subscription"."member_id" NOTNULL )
jbe@499 3250 AND "ignored_initiative"."member_id" ISNULL
jbe@499 3251 AND NOT EXISTS (
jbe@499 3252 SELECT NULL FROM "draft"
jbe@499 3253 JOIN "ignored_member" ON
jbe@499 3254 "ignored_member"."member_id" = "recipient_id_p" AND
jbe@499 3255 "ignored_member"."other_member_id" = "draft"."author_id"
jbe@499 3256 WHERE "draft"."initiative_id" = "initiative"."id"
jbe@499 3257 )
jbe@474 3258 ORDER BY md5("seed_v" || '-' || "initiative"."id")
jbe@476 3259 LIMIT 1;
jbe@476 3260 IF FOUND THEN
jbe@476 3261 "match_v" := TRUE;
jbe@499 3262 RETURN NEXT "initiative_id_v";
jbe@499 3263 IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
jbe@476 3264 RETURN;
jbe@474 3265 END IF;
jbe@499 3266 "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
jbe@476 3267 END IF;
jbe@474 3268 END LOOP;
jbe@474 3269 EXIT WHEN NOT "match_v";
jbe@474 3270 END LOOP;
jbe@474 3271 RETURN;
jbe@474 3272 END;
jbe@474 3273 $$;
jbe@474 3274
jbe@508 3275 COMMENT ON FUNCTION "featured_initiative"
jbe@508 3276 ( "recipient_id_p" "member"."id"%TYPE,
jbe@508 3277 "area_id_p" "area"."id"%TYPE )
jbe@508 3278 IS 'Helper function for view "updated_or_featured_initiative"';
jbe@508 3279
jbe@508 3280
jbe@474 3281 CREATE VIEW "updated_or_featured_initiative" AS
jbe@474 3282 SELECT
jbe@499 3283 "subquery".*,
jbe@477 3284 NOT EXISTS (
jbe@477 3285 SELECT NULL FROM "initiative" AS "better_initiative"
jbe@499 3286 WHERE "better_initiative"."issue_id" = "initiative"."issue_id"
jbe@484 3287 AND
jbe@502 3288 ( COALESCE("better_initiative"."supporter_count", -1),
jbe@484 3289 -"better_initiative"."id" ) >
jbe@502 3290 ( COALESCE("initiative"."supporter_count", -1),
jbe@485 3291 -"initiative"."id" )
jbe@499 3292 ) AS "leading"
jbe@499 3293 FROM (
jbe@499 3294 SELECT * FROM "updated_initiative"
jbe@499 3295 UNION ALL
jbe@499 3296 SELECT
jbe@499 3297 "member"."id" AS "recipient_id",
jbe@499 3298 TRUE AS "featured",
jbe@499 3299 "featured_initiative_id" AS "initiative_id"
jbe@499 3300 FROM "member" CROSS JOIN "area"
jbe@499 3301 CROSS JOIN LATERAL
jbe@499 3302 "featured_initiative"("member"."id", "area"."id") AS "featured_initiative_id"
jbe@499 3303 JOIN "initiative" ON "initiative"."id" = "featured_initiative_id"
jbe@499 3304 ) AS "subquery"
jbe@499 3305 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id";
jbe@474 3306
jbe@508 3307 COMMENT ON VIEW "updated_or_featured_initiative" IS 'Initiatives to be included in a scheduled notification mail because (a) they have been updated or (b) they are featured';
jbe@508 3308
jbe@508 3309 COMMENT ON COLUMN "updated_or_featured_initiative"."recipient_id" IS '"id" of the member who receives the notification mail';
jbe@508 3310 COMMENT ON COLUMN "updated_or_featured_initiative"."featured" IS 'TRUE if the initiative has been included because it was selected by the "featured_initiative" algorithm (see source of function "featured_initiative")';
jbe@508 3311 COMMENT ON COLUMN "updated_or_featured_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
jbe@508 3312 COMMENT ON COLUMN "updated_or_featured_initiative"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
jbe@508 3313
jbe@508 3314
jbe@474 3315 CREATE VIEW "leading_complement_initiative" AS
jbe@477 3316 SELECT * FROM (
jbe@499 3317 SELECT DISTINCT ON ("uf_initiative"."recipient_id", "initiative"."issue_id")
jbe@499 3318 "uf_initiative"."recipient_id",
jbe@477 3319 FALSE AS "featured",
jbe@499 3320 "uf_initiative"."initiative_id",
jbe@499 3321 TRUE AS "leading"
jbe@489 3322 FROM "updated_or_featured_initiative" AS "uf_initiative"
jbe@499 3323 JOIN "initiative" AS "uf_initiative_full" ON
jbe@499 3324 "uf_initiative_full"."id" = "uf_initiative"."initiative_id"
jbe@489 3325 JOIN "initiative" ON
jbe@499 3326 "initiative"."issue_id" = "uf_initiative_full"."issue_id"
jbe@503 3327 WHERE "initiative"."revoked" ISNULL
jbe@477 3328 ORDER BY
jbe@499 3329 "uf_initiative"."recipient_id",
jbe@477 3330 "initiative"."issue_id",
jbe@502 3331 "initiative"."supporter_count" DESC,
jbe@477 3332 "initiative"."id"
jbe@477 3333 ) AS "subquery"
jbe@477 3334 WHERE NOT EXISTS (
jbe@477 3335 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
jbe@499 3336 WHERE "other"."recipient_id" = "subquery"."recipient_id"
jbe@499 3337 AND "other"."initiative_id" = "subquery"."initiative_id"
jbe@477 3338 );
jbe@474 3339
jbe@508 3340 COMMENT ON VIEW "leading_complement_initiative" IS 'Helper view for view "unfiltered_initiative_for_notification" in order to always include the most supported initiative of an issue';
jbe@508 3341 COMMENT ON COLUMN "leading_complement_initiative"."featured" IS 'Always FALSE in this view';
jbe@508 3342 COMMENT ON COLUMN "leading_complement_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
jbe@508 3343 COMMENT ON COLUMN "leading_complement_initiative"."leading" IS 'Always TRUE in this view';
jbe@508 3344
jbe@508 3345
jbe@490 3346 CREATE VIEW "unfiltered_initiative_for_notification" AS
jbe@499 3347 SELECT
jbe@499 3348 "subquery".*,
jbe@499 3349 "supporter"."member_id" NOTNULL AS "supported",
jbe@499 3350 CASE WHEN "supporter"."member_id" NOTNULL THEN
jbe@499 3351 EXISTS (
jbe@499 3352 SELECT NULL FROM "draft"
jbe@499 3353 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
jbe@499 3354 AND "draft"."id" > "supporter"."draft_id"
jbe@499 3355 )
jbe@222 3356 ELSE
jbe@499 3357 EXISTS (
jbe@499 3358 SELECT NULL FROM "draft"
jbe@499 3359 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
jbe@499 3360 AND COALESCE("draft"."id" > "sent"."last_draft_id", TRUE)
jbe@499 3361 )
jbe@499 3362 END AS "new_draft",
jbe@499 3363 CASE WHEN "supporter"."member_id" NOTNULL THEN
jbe@499 3364 ( SELECT count(1) FROM "suggestion"
jbe@499 3365 LEFT JOIN "opinion" ON
jbe@499 3366 "opinion"."member_id" = "supporter"."member_id" AND
jbe@499 3367 "opinion"."suggestion_id" = "suggestion"."id"
jbe@499 3368 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
jbe@499 3369 AND "opinion"."member_id" ISNULL
jbe@499 3370 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
jbe@499 3371 )
jbe@499 3372 ELSE
jbe@499 3373 ( SELECT count(1) FROM "suggestion"
jbe@499 3374 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
jbe@499 3375 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
jbe@499 3376 )
jbe@499 3377 END AS "new_suggestion_count"
jbe@499 3378 FROM (
jbe@499 3379 SELECT * FROM "updated_or_featured_initiative"
jbe@499 3380 UNION ALL
jbe@499 3381 SELECT * FROM "leading_complement_initiative"
jbe@499 3382 ) AS "subquery"
jbe@499 3383 LEFT JOIN "supporter" ON
jbe@499 3384 "supporter"."member_id" = "subquery"."recipient_id" AND
jbe@499 3385 "supporter"."initiative_id" = "subquery"."initiative_id"
jbe@507 3386 LEFT JOIN "notification_initiative_sent" AS "sent" ON
jbe@499 3387 "sent"."member_id" = "subquery"."recipient_id" AND
jbe@499 3388 "sent"."initiative_id" = "subquery"."initiative_id";
jbe@474 3389
jbe@508 3390 COMMENT ON VIEW "unfiltered_initiative_for_notification" IS 'Helper view which simply combines the views "updated_or_featured_initiative" and "leading_complement_initiative" and adds columns "supported", "new_draft", and "new_suggestion_count';
jbe@508 3391
jbe@508 3392 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
jbe@508 3393 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."new_draft" IS 'TRUE if a new draft exists (using the "draft_id" column of the "supporter" table in case of "supported" initiatives and the "last_draft_id" column of the "notification_initiative_sent" table in all other cases)';
jbe@508 3394 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."new_suggestion_count" IS 'Number of new suggestions (using the "last_suggestion_id" column of the "notification_initiative_sent" table while ignoring suggestions with an "opinion")';
jbe@508 3395
jbe@508 3396
jbe@490 3397 CREATE VIEW "initiative_for_notification" AS
jbe@499 3398 SELECT "unfiltered1".*
jbe@499 3399 FROM "unfiltered_initiative_for_notification" "unfiltered1"
jbe@499 3400 JOIN "initiative" AS "initiative1" ON
jbe@499 3401 "initiative1"."id" = "unfiltered1"."initiative_id"
jbe@499 3402 JOIN "issue" AS "issue1" ON "issue1"."id" = "initiative1"."issue_id"
jbe@490 3403 WHERE EXISTS (
jbe@490 3404 SELECT NULL
jbe@499 3405 FROM "unfiltered_initiative_for_notification" "unfiltered2"
jbe@499 3406 JOIN "initiative" AS "initiative2" ON
jbe@499 3407 "initiative2"."id" = "unfiltered2"."initiative_id"
jbe@499 3408 JOIN "issue" AS "issue2" ON "issue2"."id" = "initiative2"."issue_id"
jbe@499 3409 WHERE "unfiltered1"."recipient_id" = "unfiltered2"."recipient_id"
jbe@490 3410 AND "issue1"."area_id" = "issue2"."area_id"
jbe@499 3411 AND ("unfiltered2"."new_draft" OR "unfiltered2"."new_suggestion_count" > 0 )
jbe@490 3412 );
jbe@490 3413
jbe@508 3414 COMMENT ON VIEW "initiative_for_notification" IS 'Initiatives to be included in a scheduled notification mail';
jbe@508 3415
jbe@508 3416 COMMENT ON COLUMN "initiative_for_notification"."recipient_id" IS '"id" of the member who receives the notification mail';
jbe@508 3417 COMMENT ON COLUMN "initiative_for_notification"."featured" IS 'TRUE if the initiative has been included because it was selected by the "featured_initiative" algorithm (see source of function "featured_initiative")';
jbe@508 3418 COMMENT ON COLUMN "initiative_for_notification"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
jbe@508 3419 COMMENT ON COLUMN "initiative_for_notification"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
jbe@508 3420 COMMENT ON COLUMN "initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
jbe@508 3421 COMMENT ON COLUMN "initiative_for_notification"."new_draft" IS 'TRUE if a new draft exists (using the "draft_id" column of the "supporter" table in case of "supported" initiatives and the "last_draft_id" column of the "notification_initiative_sent" table in all other cases)';
jbe@508 3422 COMMENT ON COLUMN "initiative_for_notification"."new_suggestion_count" IS 'Number of new suggestions (using the "last_suggestion_id" column of the "notification_initiative_sent" table while ignoring suggestions with an "opinion")';
jbe@508 3423
jbe@508 3424
jbe@504 3425 CREATE VIEW "scheduled_notification_to_send" AS
jbe@505 3426 SELECT * FROM (
jbe@505 3427 SELECT
jbe@505 3428 "id" AS "recipient_id",
jbe@505 3429 now() - CASE WHEN "notification_dow" ISNULL THEN
jbe@505 3430 ( "notification_sent"::DATE + CASE
jbe@505 3431 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
jbe@505 3432 THEN 0 ELSE 1 END
jbe@505 3433 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
jbe@222 3434 ELSE
jbe@505 3435 ( "notification_sent"::DATE +
jbe@505 3436 ( 7 + "notification_dow" -
jbe@505 3437 EXTRACT(DOW FROM
jbe@505 3438 ( "notification_sent"::DATE + CASE
jbe@505 3439 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
jbe@505 3440 THEN 0 ELSE 1 END
jbe@505 3441 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
jbe@505 3442 )::INTEGER
jbe@505 3443 ) % 7 +
jbe@505 3444 CASE
jbe@505 3445 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
jbe@505 3446 THEN 0 ELSE 1
jbe@505 3447 END
jbe@505 3448 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
jbe@505 3449 END AS "pending"
jbe@505 3450 FROM (
jbe@505 3451 SELECT
jbe@505 3452 "id",
jbe@505 3453 COALESCE("notification_sent", "activated") AS "notification_sent",
jbe@505 3454 "notification_dow",
jbe@505 3455 "notification_hour"
jbe@524 3456 FROM "member_to_notify"
jbe@524 3457 WHERE "notification_hour" NOTNULL
jbe@505 3458 ) AS "subquery1"
jbe@505 3459 ) AS "subquery2"
jbe@505 3460 WHERE "pending" > '0'::INTERVAL;
jbe@504 3461
jbe@508 3462 COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending';
jbe@508 3463
jbe@508 3464 COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail';
jbe@508 3465 COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending';
jbe@508 3466
jbe@508 3467
jbe@497 3468 CREATE VIEW "newsletter_to_send" AS
jbe@497 3469 SELECT
jbe@499 3470 "member"."id" AS "recipient_id",
jbe@514 3471 "newsletter"."id" AS "newsletter_id",
jbe@514 3472 "newsletter"."published"
jbe@524 3473 FROM "newsletter" CROSS JOIN "member_eligible_to_be_notified" AS "member"
jbe@497 3474 LEFT JOIN "privilege" ON
jbe@497 3475 "privilege"."member_id" = "member"."id" AND
jbe@497 3476 "privilege"."unit_id" = "newsletter"."unit_id" AND
jbe@497 3477 "privilege"."voting_right" = TRUE
jbe@497 3478 LEFT JOIN "subscription" ON
jbe@497 3479 "subscription"."member_id" = "member"."id" AND
jbe@497 3480 "subscription"."unit_id" = "newsletter"."unit_id"
jbe@498 3481 WHERE "newsletter"."published" <= now()
jbe@497 3482 AND "newsletter"."sent" ISNULL
jbe@113 3483 AND (
jbe@497 3484 "member"."disable_notifications" = FALSE OR
jbe@497 3485 "newsletter"."include_all_members" = TRUE )
jbe@497 3486 AND (
jbe@497 3487 "newsletter"."unit_id" ISNULL OR
jbe@497 3488 "privilege"."member_id" NOTNULL OR
jbe@497 3489 "subscription"."member_id" NOTNULL );
jbe@497 3490
jbe@508 3491 COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out';
jbe@508 3492
jbe@514 3493 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter was supposed to be sent out (can be used for ordering)';
jbe@113 3494
jbe@113 3495
jbe@0 3496
jbe@242 3497 ------------------------------------------------------
jbe@242 3498 -- Row set returning function for delegation chains --
jbe@242 3499 ------------------------------------------------------
jbe@5 3500
jbe@5 3501
jbe@5 3502 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
jbe@5 3503 ('first', 'intermediate', 'last', 'repetition');
jbe@5 3504
jbe@5 3505 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
jbe@5 3506
jbe@5 3507
jbe@5 3508 CREATE TYPE "delegation_chain_row" AS (
jbe@5 3509 "index" INT4,
jbe@5 3510 "member_id" INT4,
jbe@97 3511 "member_valid" BOOLEAN,
jbe@5 3512 "participation" BOOLEAN,
jbe@5 3513 "overridden" BOOLEAN,
jbe@5 3514 "scope_in" "delegation_scope",
jbe@5 3515 "scope_out" "delegation_scope",
jbe@86 3516 "disabled_out" BOOLEAN,
jbe@5 3517 "loop" "delegation_chain_loop_tag" );
jbe@5 3518
jbe@243 3519 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
jbe@5 3520
jbe@5 3521 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
jbe@5 3522 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 3523 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
jbe@5 3524 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
jbe@5 3525 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
jbe@86 3526 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 3527 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 3528
jbe@5 3529
jbe@242 3530 CREATE FUNCTION "delegation_chain_for_closed_issue"
jbe@242 3531 ( "member_id_p" "member"."id"%TYPE,
jbe@242 3532 "issue_id_p" "issue"."id"%TYPE )
jbe@242 3533 RETURNS SETOF "delegation_chain_row"
jbe@242 3534 LANGUAGE 'plpgsql' STABLE AS $$
jbe@242 3535 DECLARE
jbe@242 3536 "output_row" "delegation_chain_row";
jbe@242 3537 "direct_voter_row" "direct_voter"%ROWTYPE;
jbe@242 3538 "delegating_voter_row" "delegating_voter"%ROWTYPE;
jbe@242 3539 BEGIN
jbe@242 3540 "output_row"."index" := 0;
jbe@242 3541 "output_row"."member_id" := "member_id_p";
jbe@242 3542 "output_row"."member_valid" := TRUE;
jbe@242 3543 "output_row"."participation" := FALSE;
jbe@242 3544 "output_row"."overridden" := FALSE;
jbe@242 3545 "output_row"."disabled_out" := FALSE;
jbe@242 3546 LOOP
jbe@242 3547 SELECT INTO "direct_voter_row" * FROM "direct_voter"
jbe@242 3548 WHERE "issue_id" = "issue_id_p"
jbe@242 3549 AND "member_id" = "output_row"."member_id";
jbe@242 3550 IF "direct_voter_row"."member_id" NOTNULL THEN
jbe@242 3551 "output_row"."participation" := TRUE;
jbe@242 3552 "output_row"."scope_out" := NULL;
jbe@242 3553 "output_row"."disabled_out" := NULL;
jbe@242 3554 RETURN NEXT "output_row";
jbe@242 3555 RETURN;
jbe@242 3556 END IF;
jbe@242 3557 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
jbe@242 3558 WHERE "issue_id" = "issue_id_p"
jbe@242 3559 AND "member_id" = "output_row"."member_id";
jbe@242 3560 IF "delegating_voter_row"."member_id" ISNULL THEN
jbe@242 3561 RETURN;
jbe@242 3562 END IF;
jbe@242 3563 "output_row"."scope_out" := "delegating_voter_row"."scope";
jbe@242 3564 RETURN NEXT "output_row";
jbe@242 3565 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
jbe@242 3566 "output_row"."scope_in" := "output_row"."scope_out";
jbe@242 3567 END LOOP;
jbe@242 3568 END;
jbe@242 3569 $$;
jbe@242 3570
jbe@242 3571 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
jbe@242 3572 ( "member"."id"%TYPE,
jbe@242 3573 "member"."id"%TYPE )
jbe@242 3574 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
jbe@242 3575
jbe@242 3576
jbe@5 3577 CREATE FUNCTION "delegation_chain"
jbe@5 3578 ( "member_id_p" "member"."id"%TYPE,
jbe@97 3579 "unit_id_p" "unit"."id"%TYPE,
jbe@5 3580 "area_id_p" "area"."id"%TYPE,
jbe@5 3581 "issue_id_p" "issue"."id"%TYPE,
jbe@255 3582 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
jbe@255 3583 "simulate_default_p" BOOLEAN DEFAULT FALSE )
jbe@5 3584 RETURNS SETOF "delegation_chain_row"
jbe@5 3585 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 3586 DECLARE
jbe@97 3587 "scope_v" "delegation_scope";
jbe@97 3588 "unit_id_v" "unit"."id"%TYPE;
jbe@97 3589 "area_id_v" "area"."id"%TYPE;
jbe@241 3590 "issue_row" "issue"%ROWTYPE;
jbe@5 3591 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
jbe@5 3592 "loop_member_id_v" "member"."id"%TYPE;
jbe@5 3593 "output_row" "delegation_chain_row";
jbe@5 3594 "output_rows" "delegation_chain_row"[];
jbe@255 3595 "simulate_v" BOOLEAN;
jbe@255 3596 "simulate_here_v" BOOLEAN;
jbe@5 3597 "delegation_row" "delegation"%ROWTYPE;
jbe@5 3598 "row_count" INT4;
jbe@5 3599 "i" INT4;
jbe@5 3600 "loop_v" BOOLEAN;
jbe@5 3601 BEGIN
jbe@255 3602 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
jbe@255 3603 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
jbe@255 3604 END IF;
jbe@255 3605 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
jbe@255 3606 "simulate_v" := TRUE;
jbe@255 3607 ELSE
jbe@255 3608 "simulate_v" := FALSE;
jbe@255 3609 END IF;
jbe@97 3610 IF
jbe@97 3611 "unit_id_p" NOTNULL AND
jbe@97 3612 "area_id_p" ISNULL AND
jbe@97 3613 "issue_id_p" ISNULL
jbe@97 3614 THEN
jbe@97 3615 "scope_v" := 'unit';
jbe@97 3616 "unit_id_v" := "unit_id_p";
jbe@97 3617 ELSIF
jbe@97 3618 "unit_id_p" ISNULL AND
jbe@97 3619 "area_id_p" NOTNULL AND
jbe@97 3620 "issue_id_p" ISNULL
jbe@97 3621 THEN
jbe@97 3622 "scope_v" := 'area';
jbe@97 3623 "area_id_v" := "area_id_p";
jbe@97 3624 SELECT "unit_id" INTO "unit_id_v"
jbe@97 3625 FROM "area" WHERE "id" = "area_id_v";
jbe@97 3626 ELSIF
jbe@97 3627 "unit_id_p" ISNULL AND
jbe@97 3628 "area_id_p" ISNULL AND
jbe@97 3629 "issue_id_p" NOTNULL
jbe@97 3630 THEN
jbe@242 3631 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
jbe@242 3632 IF "issue_row"."id" ISNULL THEN
jbe@242 3633 RETURN;
jbe@242 3634 END IF;
jbe@242 3635 IF "issue_row"."closed" NOTNULL THEN
jbe@255 3636 IF "simulate_v" THEN
jbe@242 3637 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
jbe@242 3638 END IF;
jbe@242 3639 FOR "output_row" IN
jbe@242 3640 SELECT * FROM
jbe@242 3641 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
jbe@242 3642 LOOP
jbe@242 3643 RETURN NEXT "output_row";
jbe@242 3644 END LOOP;
jbe@242 3645 RETURN;
jbe@242 3646 END IF;
jbe@97 3647 "scope_v" := 'issue';
jbe@97 3648 SELECT "area_id" INTO "area_id_v"
jbe@97 3649 FROM "issue" WHERE "id" = "issue_id_p";
jbe@97 3650 SELECT "unit_id" INTO "unit_id_v"
jbe@97 3651 FROM "area" WHERE "id" = "area_id_v";
jbe@97 3652 ELSE
jbe@97 3653 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
jbe@97 3654 END IF;
jbe@5 3655 "visited_member_ids" := '{}';
jbe@5 3656 "loop_member_id_v" := NULL;
jbe@5 3657 "output_rows" := '{}';
jbe@5 3658 "output_row"."index" := 0;
jbe@5 3659 "output_row"."member_id" := "member_id_p";
jbe@97 3660 "output_row"."member_valid" := TRUE;
jbe@5 3661 "output_row"."participation" := FALSE;
jbe@5 3662 "output_row"."overridden" := FALSE;
jbe@86 3663 "output_row"."disabled_out" := FALSE;
jbe@5 3664 "output_row"."scope_out" := NULL;
jbe@5 3665 LOOP
jbe@5 3666 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
jbe@5 3667 "loop_member_id_v" := "output_row"."member_id";
jbe@5 3668 ELSE
jbe@5 3669 "visited_member_ids" :=
jbe@5 3670 "visited_member_ids" || "output_row"."member_id";
jbe@5 3671 END IF;
jbe@241 3672 IF "output_row"."participation" ISNULL THEN
jbe@241 3673 "output_row"."overridden" := NULL;
jbe@241 3674 ELSIF "output_row"."participation" THEN
jbe@5 3675 "output_row"."overridden" := TRUE;
jbe@5 3676 END IF;
jbe@5 3677 "output_row"."scope_in" := "output_row"."scope_out";
jbe@255 3678 "output_row"."member_valid" := EXISTS (
jbe@97 3679 SELECT NULL FROM "member" JOIN "privilege"
jbe@97 3680 ON "privilege"."member_id" = "member"."id"
jbe@97 3681 AND "privilege"."unit_id" = "unit_id_v"
jbe@97 3682 WHERE "id" = "output_row"."member_id"
jbe@97 3683 AND "member"."active" AND "privilege"."voting_right"
jbe@255 3684 );
jbe@255 3685 "simulate_here_v" := (
jbe@255 3686 "simulate_v" AND
jbe@255 3687 "output_row"."member_id" = "member_id_p"
jbe@255 3688 );
jbe@255 3689 "delegation_row" := ROW(NULL);
jbe@255 3690 IF "output_row"."member_valid" OR "simulate_here_v" THEN
jbe@97 3691 IF "scope_v" = 'unit' THEN
jbe@255 3692 IF NOT "simulate_here_v" THEN
jbe@255 3693 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 3694 WHERE "truster_id" = "output_row"."member_id"
jbe@255 3695 AND "unit_id" = "unit_id_v";
jbe@255 3696 END IF;
jbe@97 3697 ELSIF "scope_v" = 'area' THEN
jbe@5 3698 "output_row"."participation" := EXISTS (
jbe@5 3699 SELECT NULL FROM "membership"
jbe@5 3700 WHERE "area_id" = "area_id_p"
jbe@5 3701 AND "member_id" = "output_row"."member_id"
jbe@5 3702 );
jbe@255 3703 IF "simulate_here_v" THEN
jbe@255 3704 IF "simulate_trustee_id_p" ISNULL THEN
jbe@255 3705 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 3706 WHERE "truster_id" = "output_row"."member_id"
jbe@255 3707 AND "unit_id" = "unit_id_v";
jbe@255 3708 END IF;
jbe@255 3709 ELSE
jbe@255 3710 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 3711 WHERE "truster_id" = "output_row"."member_id"
jbe@255 3712 AND (
jbe@255 3713 "unit_id" = "unit_id_v" OR
jbe@255 3714 "area_id" = "area_id_v"
jbe@255 3715 )
jbe@255 3716 ORDER BY "scope" DESC;
jbe@255 3717 END IF;
jbe@97 3718 ELSIF "scope_v" = 'issue' THEN
jbe@241 3719 IF "issue_row"."fully_frozen" ISNULL THEN
jbe@241 3720 "output_row"."participation" := EXISTS (
jbe@241 3721 SELECT NULL FROM "interest"
jbe@241 3722 WHERE "issue_id" = "issue_id_p"
jbe@241 3723 AND "member_id" = "output_row"."member_id"
jbe@241 3724 );
jbe@241 3725 ELSE
jbe@241 3726 IF "output_row"."member_id" = "member_id_p" THEN
jbe@241 3727 "output_row"."participation" := EXISTS (
jbe@241 3728 SELECT NULL FROM "direct_voter"
jbe@241 3729 WHERE "issue_id" = "issue_id_p"
jbe@241 3730 AND "member_id" = "output_row"."member_id"
jbe@241 3731 );
jbe@241 3732 ELSE
jbe@241 3733 "output_row"."participation" := NULL;
jbe@241 3734 END IF;
jbe@241 3735 END IF;
jbe@255 3736 IF "simulate_here_v" THEN
jbe@255 3737 IF "simulate_trustee_id_p" ISNULL THEN
jbe@255 3738 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 3739 WHERE "truster_id" = "output_row"."member_id"
jbe@255 3740 AND (
jbe@255 3741 "unit_id" = "unit_id_v" OR
jbe@255 3742 "area_id" = "area_id_v"
jbe@255 3743 )
jbe@255 3744 ORDER BY "scope" DESC;
jbe@255 3745 END IF;
jbe@255 3746 ELSE
jbe@255 3747 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 3748 WHERE "truster_id" = "output_row"."member_id"
jbe@255 3749 AND (
jbe@255 3750 "unit_id" = "unit_id_v" OR
jbe@255 3751 "area_id" = "area_id_v" OR
jbe@255 3752 "issue_id" = "issue_id_p"
jbe@255 3753 )
jbe@255 3754 ORDER BY "scope" DESC;
jbe@255 3755 END IF;
jbe@5 3756 END IF;
jbe@5 3757 ELSE
jbe@5 3758 "output_row"."participation" := FALSE;
jbe@5 3759 END IF;
jbe@255 3760 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
jbe@97 3761 "output_row"."scope_out" := "scope_v";
jbe@5 3762 "output_rows" := "output_rows" || "output_row";
jbe@5 3763 "output_row"."member_id" := "simulate_trustee_id_p";
jbe@5 3764 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
jbe@10 3765 "output_row"."scope_out" := "delegation_row"."scope";
jbe@5 3766 "output_rows" := "output_rows" || "output_row";
jbe@5 3767 "output_row"."member_id" := "delegation_row"."trustee_id";
jbe@86 3768 ELSIF "delegation_row"."scope" NOTNULL THEN
jbe@86 3769 "output_row"."scope_out" := "delegation_row"."scope";
jbe@86 3770 "output_row"."disabled_out" := TRUE;
jbe@86 3771 "output_rows" := "output_rows" || "output_row";
jbe@86 3772 EXIT;
jbe@5 3773 ELSE
jbe@5 3774 "output_row"."scope_out" := NULL;
jbe@5 3775 "output_rows" := "output_rows" || "output_row";
jbe@5 3776 EXIT;
jbe@5 3777 END IF;
jbe@5 3778 EXIT WHEN "loop_member_id_v" NOTNULL;
jbe@5 3779 "output_row"."index" := "output_row"."index" + 1;
jbe@5 3780 END LOOP;
jbe@5 3781 "row_count" := array_upper("output_rows", 1);
jbe@5 3782 "i" := 1;
jbe@5 3783 "loop_v" := FALSE;
jbe@5 3784 LOOP
jbe@5 3785 "output_row" := "output_rows"["i"];
jbe@98 3786 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
jbe@5 3787 IF "loop_v" THEN
jbe@5 3788 IF "i" + 1 = "row_count" THEN
jbe@5 3789 "output_row"."loop" := 'last';
jbe@5 3790 ELSIF "i" = "row_count" THEN
jbe@5 3791 "output_row"."loop" := 'repetition';
jbe@5 3792 ELSE
jbe@5 3793 "output_row"."loop" := 'intermediate';
jbe@5 3794 END IF;
jbe@5 3795 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
jbe@5 3796 "output_row"."loop" := 'first';
jbe@5 3797 "loop_v" := TRUE;
jbe@5 3798 END IF;
jbe@97 3799 IF "scope_v" = 'unit' THEN
jbe@5 3800 "output_row"."participation" := NULL;
jbe@5 3801 END IF;
jbe@5 3802 RETURN NEXT "output_row";
jbe@5 3803 "i" := "i" + 1;
jbe@5 3804 END LOOP;
jbe@5 3805 RETURN;
jbe@5 3806 END;
jbe@5 3807 $$;
jbe@5 3808
jbe@5 3809 COMMENT ON FUNCTION "delegation_chain"
jbe@5 3810 ( "member"."id"%TYPE,
jbe@97 3811 "unit"."id"%TYPE,
jbe@5 3812 "area"."id"%TYPE,
jbe@5 3813 "issue"."id"%TYPE,
jbe@255 3814 "member"."id"%TYPE,
jbe@255 3815 BOOLEAN )
jbe@242 3816 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
jbe@242 3817
jbe@242 3818
jbe@242 3819
jbe@242 3820 ---------------------------------------------------------
jbe@242 3821 -- Single row returning function for delegation chains --
jbe@242 3822 ---------------------------------------------------------
jbe@242 3823
jbe@242 3824
jbe@242 3825 CREATE TYPE "delegation_info_loop_type" AS ENUM
jbe@242 3826 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
jbe@240 3827
jbe@243 3828 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@243 3829
jbe@243 3830
jbe@240 3831 CREATE TYPE "delegation_info_type" AS (
jbe@242 3832 "own_participation" BOOLEAN,
jbe@242 3833 "own_delegation_scope" "delegation_scope",
jbe@242 3834 "first_trustee_id" INT4,
jbe@240 3835 "first_trustee_participation" BOOLEAN,
jbe@242 3836 "first_trustee_ellipsis" BOOLEAN,
jbe@242 3837 "other_trustee_id" INT4,
jbe@240 3838 "other_trustee_participation" BOOLEAN,
jbe@242 3839 "other_trustee_ellipsis" BOOLEAN,
jbe@253 3840 "delegation_loop" "delegation_info_loop_type",
jbe@253 3841 "participating_member_id" INT4 );
jbe@240 3842
jbe@243 3843 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@243 3844
jbe@243 3845 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
jbe@243 3846 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
jbe@243 3847 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
jbe@243 3848 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
jbe@243 3849 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
jbe@243 3850 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
jbe@243 3851 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@243 3852 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
jbe@243 3853 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@253 3854 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
jbe@243 3855
jbe@243 3856
jbe@240 3857 CREATE FUNCTION "delegation_info"
jbe@242 3858 ( "member_id_p" "member"."id"%TYPE,
jbe@242 3859 "unit_id_p" "unit"."id"%TYPE,
jbe@242 3860 "area_id_p" "area"."id"%TYPE,
jbe@242 3861 "issue_id_p" "issue"."id"%TYPE,
jbe@255 3862 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
jbe@255 3863 "simulate_default_p" BOOLEAN DEFAULT FALSE )
jbe@240 3864 RETURNS "delegation_info_type"
jbe@240 3865 LANGUAGE 'plpgsql' STABLE AS $$
jbe@240 3866 DECLARE
jbe@242 3867 "current_row" "delegation_chain_row";
jbe@242 3868 "result" "delegation_info_type";
jbe@240 3869 BEGIN
jbe@242 3870 "result"."own_participation" := FALSE;
jbe@242 3871 FOR "current_row" IN
jbe@242 3872 SELECT * FROM "delegation_chain"(
jbe@242 3873 "member_id_p",
jbe@242 3874 "unit_id_p", "area_id_p", "issue_id_p",
jbe@255 3875 "simulate_trustee_id_p", "simulate_default_p")
jbe@242 3876 LOOP
jbe@253 3877 IF
jbe@253 3878 "result"."participating_member_id" ISNULL AND
jbe@253 3879 "current_row"."participation"
jbe@253 3880 THEN
jbe@253 3881 "result"."participating_member_id" := "current_row"."member_id";
jbe@253 3882 END IF;
jbe@242 3883 IF "current_row"."member_id" = "member_id_p" THEN
jbe@242 3884 "result"."own_participation" := "current_row"."participation";
jbe@242 3885 "result"."own_delegation_scope" := "current_row"."scope_out";
jbe@242 3886 IF "current_row"."loop" = 'first' THEN
jbe@242 3887 "result"."delegation_loop" := 'own';
jbe@242 3888 END IF;
jbe@242 3889 ELSIF
jbe@242 3890 "current_row"."member_valid" AND
jbe@242 3891 ( "current_row"."loop" ISNULL OR
jbe@242 3892 "current_row"."loop" != 'repetition' )
jbe@242 3893 THEN
jbe@242 3894 IF "result"."first_trustee_id" ISNULL THEN
jbe@242 3895 "result"."first_trustee_id" := "current_row"."member_id";
jbe@242 3896 "result"."first_trustee_participation" := "current_row"."participation";
jbe@242 3897 "result"."first_trustee_ellipsis" := FALSE;
jbe@242 3898 IF "current_row"."loop" = 'first' THEN
jbe@242 3899 "result"."delegation_loop" := 'first';
jbe@242 3900 END IF;
jbe@242 3901 ELSIF "result"."other_trustee_id" ISNULL THEN
jbe@247 3902 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
jbe@242 3903 "result"."other_trustee_id" := "current_row"."member_id";
jbe@242 3904 "result"."other_trustee_participation" := TRUE;
jbe@242 3905 "result"."other_trustee_ellipsis" := FALSE;
jbe@242 3906 IF "current_row"."loop" = 'first' THEN
jbe@242 3907 "result"."delegation_loop" := 'other';
jbe@240 3908 END IF;
jbe@240 3909 ELSE
jbe@242 3910 "result"."first_trustee_ellipsis" := TRUE;
jbe@242 3911 IF "current_row"."loop" = 'first' THEN
jbe@242 3912 "result"."delegation_loop" := 'first_ellipsis';
jbe@242 3913 END IF;
jbe@242 3914 END IF;
jbe@242 3915 ELSE
jbe@242 3916 "result"."other_trustee_ellipsis" := TRUE;
jbe@242 3917 IF "current_row"."loop" = 'first' THEN
jbe@242 3918 "result"."delegation_loop" := 'other_ellipsis';
jbe@240 3919 END IF;
jbe@240 3920 END IF;
jbe@240 3921 END IF;
jbe@242 3922 END LOOP;
jbe@240 3923 RETURN "result";
jbe@240 3924 END;
jbe@240 3925 $$;
jbe@240 3926
jbe@243 3927 COMMENT ON FUNCTION "delegation_info"
jbe@243 3928 ( "member"."id"%TYPE,
jbe@243 3929 "unit"."id"%TYPE,
jbe@243 3930 "area"."id"%TYPE,
jbe@243 3931 "issue"."id"%TYPE,
jbe@255 3932 "member"."id"%TYPE,
jbe@255 3933 BOOLEAN )
jbe@243 3934 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
jbe@243 3935
jbe@240 3936
jbe@240 3937
jbe@333 3938 ---------------------------
jbe@333 3939 -- Transaction isolation --
jbe@333 3940 ---------------------------
jbe@333 3941
jbe@344 3942
jbe@333 3943 CREATE FUNCTION "require_transaction_isolation"()
jbe@333 3944 RETURNS VOID
jbe@333 3945 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@333 3946 BEGIN
jbe@333 3947 IF
jbe@333 3948 current_setting('transaction_isolation') NOT IN
jbe@333 3949 ('repeatable read', 'serializable')
jbe@333 3950 THEN
jbe@463 3951 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
jbe@463 3952 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
jbe@333 3953 END IF;
jbe@333 3954 RETURN;
jbe@333 3955 END;
jbe@333 3956 $$;
jbe@333 3957
jbe@344 3958 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
jbe@344 3959
jbe@333 3960
jbe@333 3961 CREATE FUNCTION "dont_require_transaction_isolation"()
jbe@333 3962 RETURNS VOID
jbe@333 3963 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@333 3964 BEGIN
jbe@333 3965 IF
jbe@333 3966 current_setting('transaction_isolation') IN
jbe@333 3967 ('repeatable read', 'serializable')
jbe@333 3968 THEN
jbe@333 3969 RAISE WARNING 'Unneccessary transaction isolation level: %',
jbe@333 3970 current_setting('transaction_isolation');
jbe@333 3971 END IF;
jbe@333 3972 RETURN;
jbe@333 3973 END;
jbe@333 3974 $$;
jbe@333 3975
jbe@344 3976 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
jbe@344 3977
jbe@333 3978
jbe@333 3979
jbe@491 3980 -------------------------
jbe@491 3981 -- Notification system --
jbe@491 3982 -------------------------
jbe@491 3983
jbe@491 3984 CREATE FUNCTION "get_initiatives_for_notification"
jbe@501 3985 ( "recipient_id_p" "member"."id"%TYPE )
jbe@491 3986 RETURNS SETOF "initiative_for_notification"
jbe@491 3987 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@491 3988 DECLARE
jbe@491 3989 "result_row" "initiative_for_notification"%ROWTYPE;
jbe@491 3990 "last_draft_id_v" "draft"."id"%TYPE;
jbe@491 3991 "last_suggestion_id_v" "suggestion"."id"%TYPE;
jbe@491 3992 BEGIN
jbe@491 3993 PERFORM "require_transaction_isolation"();
jbe@501 3994 PERFORM NULL FROM "member" WHERE "id" = "recipient_id_p" FOR UPDATE;
jbe@491 3995 FOR "result_row" IN
jbe@491 3996 SELECT * FROM "initiative_for_notification"
jbe@501 3997 WHERE "recipient_id" = "recipient_id_p"
jbe@491 3998 LOOP
jbe@491 3999 SELECT "id" INTO "last_draft_id_v" FROM "draft"
jbe@499 4000 WHERE "draft"."initiative_id" = "result_row"."initiative_id"
jbe@491 4001 ORDER BY "id" DESC LIMIT 1;
jbe@491 4002 SELECT "id" INTO "last_suggestion_id_v" FROM "suggestion"
jbe@499 4003 WHERE "suggestion"."initiative_id" = "result_row"."initiative_id"
jbe@491 4004 ORDER BY "id" DESC LIMIT 1;
jbe@517 4005 /* compatibility with PostgreSQL 9.1 */
jbe@517 4006 DELETE FROM "notification_initiative_sent"
jbe@517 4007 WHERE "member_id" = "recipient_id_p"
jbe@517 4008 AND "initiative_id" = "result_row"."initiative_id";
jbe@517 4009 INSERT INTO "notification_initiative_sent"
jbe@517 4010 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
jbe@517 4011 VALUES (
jbe@517 4012 "recipient_id_p",
jbe@517 4013 "result_row"."initiative_id",
jbe@517 4014 "last_draft_id_v",
jbe@517 4015 "last_suggestion_id_v" );
jbe@517 4016 /* TODO: use alternative code below, requires PostgreSQL 9.5 or higher
jbe@507 4017 INSERT INTO "notification_initiative_sent"
jbe@491 4018 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
jbe@491 4019 VALUES (
jbe@501 4020 "recipient_id_p",
jbe@499 4021 "result_row"."initiative_id",
jbe@493 4022 "last_draft_id_v",
jbe@493 4023 "last_suggestion_id_v" )
jbe@491 4024 ON CONFLICT ("member_id", "initiative_id") DO UPDATE SET
jbe@517 4025 "last_draft_id" = "last_draft_id_v",
jbe@517 4026 "last_suggestion_id" = "last_suggestion_id_v";
jbe@517 4027 */
jbe@491 4028 RETURN NEXT "result_row";
jbe@491 4029 END LOOP;
jbe@507 4030 DELETE FROM "notification_initiative_sent"
jbe@491 4031 USING "initiative", "issue"
jbe@507 4032 WHERE "notification_initiative_sent"."member_id" = "recipient_id_p"
jbe@507 4033 AND "initiative"."id" = "notification_initiative_sent"."initiative_id"
jbe@491 4034 AND "issue"."id" = "initiative"."issue_id"
jbe@491 4035 AND ( "issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL );
jbe@505 4036 UPDATE "member" SET
jbe@506 4037 "notification_counter" = "notification_counter" + 1,
jbe@505 4038 "notification_sent" = now()
jbe@501 4039 WHERE "id" = "recipient_id_p";
jbe@491 4040 RETURN;
jbe@491 4041 END;
jbe@491 4042 $$;
jbe@491 4043
jbe@511 4044 COMMENT ON FUNCTION "get_initiatives_for_notification"
jbe@511 4045 ( "member"."id"%TYPE )
jbe@511 4046 IS 'Returns rows from view "initiative_for_notification" for a given recipient while updating table "notification_initiative_sent" and columns "notification_counter" and "notification_sent" of "member" table';
jbe@511 4047
jbe@491 4048
jbe@491 4049
jbe@103 4050 ------------------------------------------------------------------------
jbe@103 4051 -- Regular tasks, except calculcation of snapshots and voting results --
jbe@103 4052 ------------------------------------------------------------------------
jbe@103 4053
jbe@333 4054
jbe@184 4055 CREATE FUNCTION "check_activity"()
jbe@103 4056 RETURNS VOID
jbe@103 4057 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@104 4058 DECLARE
jbe@104 4059 "system_setting_row" "system_setting"%ROWTYPE;
jbe@103 4060 BEGIN
jbe@333 4061 PERFORM "dont_require_transaction_isolation"();
jbe@104 4062 SELECT * INTO "system_setting_row" FROM "system_setting";
jbe@104 4063 IF "system_setting_row"."member_ttl" NOTNULL THEN
jbe@104 4064 UPDATE "member" SET "active" = FALSE
jbe@104 4065 WHERE "active" = TRUE
jbe@184 4066 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
jbe@104 4067 END IF;
jbe@103 4068 RETURN;
jbe@103 4069 END;
jbe@103 4070 $$;
jbe@103 4071
jbe@184 4072 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
jbe@103 4073
jbe@4 4074
jbe@4 4075 CREATE FUNCTION "calculate_member_counts"()
jbe@4 4076 RETURNS VOID
jbe@4 4077 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@4 4078 BEGIN
jbe@333 4079 PERFORM "require_transaction_isolation"();
jbe@4 4080 DELETE FROM "member_count";
jbe@5 4081 INSERT INTO "member_count" ("total_count")
jbe@5 4082 SELECT "total_count" FROM "member_count_view";
jbe@97 4083 UPDATE "unit" SET "member_count" = "view"."member_count"
jbe@97 4084 FROM "unit_member_count" AS "view"
jbe@97 4085 WHERE "view"."unit_id" = "unit"."id";
jbe@4 4086 RETURN;
jbe@4 4087 END;
jbe@4 4088 $$;
jbe@4 4089
jbe@4 4090 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 4091
jbe@4 4092
jbe@4 4093
jbe@327 4094 ------------------------------------
jbe@327 4095 -- Calculation of harmonic weight --
jbe@327 4096 ------------------------------------
jbe@310 4097
jbe@312 4098
jbe@310 4099 CREATE VIEW "remaining_harmonic_supporter_weight" AS
jbe@310 4100 SELECT
jbe@528 4101 "direct_interest_snapshot"."snapshot_id",
jbe@310 4102 "direct_interest_snapshot"."issue_id",
jbe@310 4103 "direct_interest_snapshot"."member_id",
jbe@310 4104 "direct_interest_snapshot"."weight" AS "weight_num",
jbe@310 4105 count("initiative"."id") AS "weight_den"
jbe@312 4106 FROM "issue"
jbe@312 4107 JOIN "direct_interest_snapshot"
jbe@528 4108 ON "issue"."latest_snapshot_id" = "direct_interest_snapshot"."snapshot_id"
jbe@528 4109 AND "issue"."id" = "direct_interest_snapshot"."issue_id"
jbe@327 4110 JOIN "initiative"
jbe@327 4111 ON "issue"."id" = "initiative"."issue_id"
jbe@327 4112 AND "initiative"."harmonic_weight" ISNULL
jbe@310 4113 JOIN "direct_supporter_snapshot"
jbe@528 4114 ON "issue"."latest_snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
jbe@528 4115 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
jbe@310 4116 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
jbe@321 4117 AND (
jbe@321 4118 "direct_supporter_snapshot"."satisfied" = TRUE OR
jbe@321 4119 coalesce("initiative"."admitted", FALSE) = FALSE
jbe@321 4120 )
jbe@310 4121 GROUP BY
jbe@528 4122 "direct_interest_snapshot"."snapshot_id",
jbe@310 4123 "direct_interest_snapshot"."issue_id",
jbe@310 4124 "direct_interest_snapshot"."member_id",
jbe@310 4125 "direct_interest_snapshot"."weight";
jbe@310 4126
jbe@310 4127 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
jbe@310 4128
jbe@310 4129
jbe@310 4130 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
jbe@310 4131 SELECT
jbe@310 4132 "initiative"."issue_id",
jbe@310 4133 "initiative"."id" AS "initiative_id",
jbe@320 4134 "initiative"."admitted",
jbe@310 4135 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
jbe@310 4136 "remaining_harmonic_supporter_weight"."weight_den"
jbe@310 4137 FROM "remaining_harmonic_supporter_weight"
jbe@327 4138 JOIN "initiative"
jbe@327 4139 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
jbe@327 4140 AND "initiative"."harmonic_weight" ISNULL
jbe@310 4141 JOIN "direct_supporter_snapshot"
jbe@528 4142 ON "remaining_harmonic_supporter_weight"."snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
jbe@528 4143 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
jbe@310 4144 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
jbe@321 4145 AND (
jbe@321 4146 "direct_supporter_snapshot"."satisfied" = TRUE OR
jbe@321 4147 coalesce("initiative"."admitted", FALSE) = FALSE
jbe@321 4148 )
jbe@310 4149 GROUP BY
jbe@310 4150 "initiative"."issue_id",
jbe@310 4151 "initiative"."id",
jbe@320 4152 "initiative"."admitted",
jbe@310 4153 "remaining_harmonic_supporter_weight"."weight_den";
jbe@310 4154
jbe@310 4155 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
jbe@310 4156
jbe@310 4157
jbe@349 4158 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
jbe@349 4159 SELECT
jbe@349 4160 "issue_id",
jbe@349 4161 "id" AS "initiative_id",
jbe@349 4162 "admitted",
jbe@349 4163 0 AS "weight_num",
jbe@349 4164 1 AS "weight_den"
jbe@349 4165 FROM "initiative"
jbe@349 4166 WHERE "harmonic_weight" ISNULL;
jbe@349 4167
jbe@349 4168 COMMENT ON VIEW "remaining_harmonic_initiative_weight_dummies" IS 'Helper view for function "set_harmonic_initiative_weights" providing dummy weights of zero value, which are needed for corner cases where there are no supporters for an initiative at all';
jbe@349 4169
jbe@349 4170
jbe@310 4171 CREATE FUNCTION "set_harmonic_initiative_weights"
jbe@310 4172 ( "issue_id_p" "issue"."id"%TYPE )
jbe@310 4173 RETURNS VOID
jbe@310 4174 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@310 4175 DECLARE
jbe@310 4176 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
jbe@310 4177 "i" INT4;
jbe@310 4178 "count_v" INT4;
jbe@310 4179 "summand_v" FLOAT;
jbe@310 4180 "id_ary" INT4[];
jbe@310 4181 "weight_ary" FLOAT[];
jbe@310 4182 "min_weight_v" FLOAT;
jbe@310 4183 BEGIN
jbe@333 4184 PERFORM "require_transaction_isolation"();
jbe@312 4185 UPDATE "initiative" SET "harmonic_weight" = NULL
jbe@312 4186 WHERE "issue_id" = "issue_id_p";
jbe@310 4187 LOOP
jbe@310 4188 "min_weight_v" := NULL;
jbe@310 4189 "i" := 0;
jbe@310 4190 "count_v" := 0;
jbe@310 4191 FOR "weight_row" IN
jbe@310 4192 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
jbe@310 4193 WHERE "issue_id" = "issue_id_p"
jbe@320 4194 AND (
jbe@320 4195 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
jbe@320 4196 SELECT NULL FROM "initiative"
jbe@320 4197 WHERE "issue_id" = "issue_id_p"
jbe@320 4198 AND "harmonic_weight" ISNULL
jbe@320 4199 AND coalesce("admitted", FALSE) = FALSE
jbe@320 4200 )
jbe@320 4201 )
jbe@349 4202 UNION ALL -- needed for corner cases
jbe@349 4203 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
jbe@349 4204 WHERE "issue_id" = "issue_id_p"
jbe@349 4205 AND (
jbe@349 4206 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
jbe@349 4207 SELECT NULL FROM "initiative"
jbe@349 4208 WHERE "issue_id" = "issue_id_p"
jbe@349 4209 AND "harmonic_weight" ISNULL
jbe@349 4210 AND coalesce("admitted", FALSE) = FALSE
jbe@349 4211 )
jbe@349 4212 )
jbe@310 4213 ORDER BY "initiative_id" DESC, "weight_den" DESC
jbe@320 4214 -- NOTE: non-admitted initiatives placed first (at last positions),
jbe@320 4215 -- latest initiatives treated worse in case of tie
jbe@310 4216 LOOP
jbe@310 4217 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
jbe@310 4218 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
jbe@310 4219 "i" := "i" + 1;
jbe@310 4220 "count_v" := "i";
jbe@310 4221 "id_ary"["i"] := "weight_row"."initiative_id";
jbe@310 4222 "weight_ary"["i"] := "summand_v";
jbe@310 4223 ELSE
jbe@310 4224 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
jbe@310 4225 END IF;
jbe@310 4226 END LOOP;
jbe@310 4227 EXIT WHEN "count_v" = 0;
jbe@310 4228 "i" := 1;
jbe@310 4229 LOOP
jbe@313 4230 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
jbe@310 4231 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
jbe@310 4232 "min_weight_v" := "weight_ary"["i"];
jbe@310 4233 END IF;
jbe@310 4234 "i" := "i" + 1;
jbe@310 4235 EXIT WHEN "i" > "count_v";
jbe@310 4236 END LOOP;
jbe@310 4237 "i" := 1;
jbe@310 4238 LOOP
jbe@310 4239 IF "weight_ary"["i"] = "min_weight_v" THEN
jbe@310 4240 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
jbe@310 4241 WHERE "id" = "id_ary"["i"];
jbe@310 4242 EXIT;
jbe@310 4243 END IF;
jbe@310 4244 "i" := "i" + 1;
jbe@310 4245 END LOOP;
jbe@310 4246 END LOOP;
jbe@316 4247 UPDATE "initiative" SET "harmonic_weight" = 0
jbe@316 4248 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
jbe@310 4249 END;
jbe@310 4250 $$;
jbe@310 4251
jbe@310 4252 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
jbe@310 4253 ( "issue"."id"%TYPE )
jbe@310 4254 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
jbe@310 4255
jbe@310 4256
jbe@312 4257
jbe@0 4258 ------------------------------
jbe@0 4259 -- Calculation of snapshots --
jbe@0 4260 ------------------------------
jbe@0 4261
jbe@312 4262
jbe@528 4263 CREATE FUNCTION "weight_of_added_delegations_for_snapshot"
jbe@528 4264 ( "snapshot_id_p" "snapshot"."id"%TYPE,
jbe@528 4265 "issue_id_p" "issue"."id"%TYPE,
jbe@0 4266 "member_id_p" "member"."id"%TYPE,
jbe@0 4267 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@0 4268 RETURNS "direct_interest_snapshot"."weight"%TYPE
jbe@0 4269 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4270 DECLARE
jbe@0 4271 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 4272 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
jbe@0 4273 "weight_v" INT4;
jbe@8 4274 "sub_weight_v" INT4;
jbe@0 4275 BEGIN
jbe@336 4276 PERFORM "require_transaction_isolation"();
jbe@0 4277 "weight_v" := 0;
jbe@0 4278 FOR "issue_delegation_row" IN
jbe@0 4279 SELECT * FROM "issue_delegation"
jbe@0 4280 WHERE "trustee_id" = "member_id_p"
jbe@0 4281 AND "issue_id" = "issue_id_p"
jbe@0 4282 LOOP
jbe@0 4283 IF NOT EXISTS (
jbe@0 4284 SELECT NULL FROM "direct_interest_snapshot"
jbe@528 4285 WHERE "snapshot_id" = "snapshot_id_p"
jbe@528 4286 AND "issue_id" = "issue_id_p"
jbe@0 4287 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 4288 ) AND NOT EXISTS (
jbe@0 4289 SELECT NULL FROM "delegating_interest_snapshot"
jbe@528 4290 WHERE "snapshot_id" = "snapshot_id_p"
jbe@528 4291 AND "issue_id" = "issue_id_p"
jbe@0 4292 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 4293 ) THEN
jbe@0 4294 "delegate_member_ids_v" :=
jbe@0 4295 "member_id_p" || "delegate_member_ids_p";
jbe@10 4296 INSERT INTO "delegating_interest_snapshot" (
jbe@528 4297 "snapshot_id",
jbe@10 4298 "issue_id",
jbe@10 4299 "member_id",
jbe@10 4300 "scope",
jbe@10 4301 "delegate_member_ids"
jbe@10 4302 ) VALUES (
jbe@528 4303 "snapshot_id_p",
jbe@0 4304 "issue_id_p",
jbe@0 4305 "issue_delegation_row"."truster_id",
jbe@10 4306 "issue_delegation_row"."scope",
jbe@0 4307 "delegate_member_ids_v"
jbe@0 4308 );
jbe@8 4309 "sub_weight_v" := 1 +
jbe@528 4310 "weight_of_added_delegations_for_snapshot"(
jbe@528 4311 "snapshot_id_p",
jbe@0 4312 "issue_id_p",
jbe@0 4313 "issue_delegation_row"."truster_id",
jbe@0 4314 "delegate_member_ids_v"
jbe@0 4315 );
jbe@8 4316 UPDATE "delegating_interest_snapshot"
jbe@8 4317 SET "weight" = "sub_weight_v"
jbe@528 4318 WHERE "snapshot_id" = "snapshot_id_p"
jbe@528 4319 AND "issue_id" = "issue_id_p"
jbe@8 4320 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 4321 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 4322 END IF;
jbe@0 4323 END LOOP;
jbe@0 4324 RETURN "weight_v";
jbe@0 4325 END;
jbe@0 4326 $$;
jbe@0 4327
jbe@528 4328 COMMENT ON FUNCTION "weight_of_added_delegations_for_snapshot"
jbe@528 4329 ( "snapshot"."id"%TYPE,
jbe@528 4330 "issue"."id"%TYPE,
jbe@0 4331 "member"."id"%TYPE,
jbe@0 4332 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@528 4333 IS 'Helper function for "fill_snapshot" function';
jbe@528 4334
jbe@528 4335
jbe@528 4336 CREATE FUNCTION "take_snapshot"
jbe@0 4337 ( "issue_id_p" "issue"."id"%TYPE )
jbe@528 4338 RETURNS "snapshot"."id"%TYPE
jbe@0 4339 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4340 DECLARE
jbe@528 4341 "snapshot_id_v" "snapshot"."id"%TYPE;
jbe@528 4342 "issue_id_v" "issue"."id"%TYPE;
jbe@528 4343 "member_id_v" "member"."id"%TYPE;
jbe@0 4344 BEGIN
jbe@336 4345 PERFORM "require_transaction_isolation"();
jbe@528 4346 INSERT INTO "snapshot" DEFAULT VALUES
jbe@528 4347 RETURNING "id" INTO "snapshot_id_v";
jbe@528 4348 FOR "issue_id_v" IN
jbe@528 4349 SELECT "id" FROM "issue"
jbe@528 4350 WHERE CASE WHEN "issue_id_p" ISNULL THEN
jbe@528 4351 "state" = 'admission'
jbe@528 4352 ELSE
jbe@528 4353 "id" = "issue_id_p"
jbe@528 4354 END
jbe@0 4355 LOOP
jbe@528 4356 INSERT INTO "snapshot_issue" ("snapshot_id", "issue_id")
jbe@528 4357 VALUES ("snapshot_id_v", "issue_id_v");
jbe@528 4358 INSERT INTO "direct_interest_snapshot"
jbe@528 4359 ("snapshot_id", "issue_id", "member_id")
jbe@528 4360 SELECT
jbe@528 4361 "snapshot_id_v" AS "snapshot_id",
jbe@528 4362 "issue_id_v" AS "issue_id",
jbe@528 4363 "member"."id" AS "member_id"
jbe@528 4364 FROM "issue"
jbe@528 4365 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@528 4366 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
jbe@528 4367 JOIN "member" ON "interest"."member_id" = "member"."id"
jbe@528 4368 JOIN "privilege"
jbe@528 4369 ON "privilege"."unit_id" = "area"."unit_id"
jbe@528 4370 AND "privilege"."member_id" = "member"."id"
jbe@528 4371 WHERE "issue"."id" = "issue_id_v"
jbe@528 4372 AND "member"."active" AND "privilege"."voting_right";
jbe@528 4373 FOR "member_id_v" IN
jbe@528 4374 SELECT "member_id" FROM "direct_interest_snapshot"
jbe@528 4375 WHERE "snapshot_id" = "snapshot_id_v"
jbe@528 4376 AND "issue_id" = "issue_id_v"
jbe@528 4377 LOOP
jbe@528 4378 UPDATE "direct_interest_snapshot" SET
jbe@528 4379 "weight" = 1 +
jbe@528 4380 "weight_of_added_delegations_for_snapshot"(
jbe@528 4381 "snapshot_id_v",
jbe@528 4382 "issue_id_v",
jbe@528 4383 "member_id_v",
jbe@528 4384 '{}'
jbe@528 4385 )
jbe@528 4386 WHERE "snapshot_id" = "snapshot_id_v"
jbe@528 4387 AND "issue_id" = "issue_id_v"
jbe@528 4388 AND "member_id" = "member_id_v";
jbe@528 4389 END LOOP;
jbe@528 4390 INSERT INTO "direct_supporter_snapshot"
jbe@528 4391 ( "snapshot_id", "issue_id", "initiative_id", "member_id",
jbe@528 4392 "draft_id", "informed", "satisfied" )
jbe@528 4393 SELECT
jbe@528 4394 "snapshot_id_v" AS "snapshot_id",
jbe@528 4395 "issue_id_v" AS "issue_id",
jbe@528 4396 "initiative"."id" AS "initiative_id",
jbe@528 4397 "supporter"."member_id" AS "member_id",
jbe@528 4398 "supporter"."draft_id" AS "draft_id",
jbe@528 4399 "supporter"."draft_id" = "current_draft"."id" AS "informed",
jbe@528 4400 NOT EXISTS (
jbe@528 4401 SELECT NULL FROM "critical_opinion"
jbe@528 4402 WHERE "initiative_id" = "initiative"."id"
jbe@528 4403 AND "member_id" = "supporter"."member_id"
jbe@528 4404 ) AS "satisfied"
jbe@528 4405 FROM "initiative"
jbe@528 4406 JOIN "supporter"
jbe@528 4407 ON "supporter"."initiative_id" = "initiative"."id"
jbe@528 4408 JOIN "current_draft"
jbe@528 4409 ON "initiative"."id" = "current_draft"."initiative_id"
jbe@528 4410 JOIN "direct_interest_snapshot"
jbe@528 4411 ON "snapshot_id_v" = "direct_interest_snapshot"."snapshot_id"
jbe@528 4412 AND "supporter"."member_id" = "direct_interest_snapshot"."member_id"
jbe@528 4413 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
jbe@528 4414 WHERE "initiative"."issue_id" = "issue_id_v";
jbe@528 4415 DELETE FROM "temporary_suggestion_counts";
jbe@528 4416 INSERT INTO "temporary_suggestion_counts"
jbe@528 4417 ( "id",
jbe@528 4418 "minus2_unfulfilled_count", "minus2_fulfilled_count",
jbe@528 4419 "minus1_unfulfilled_count", "minus1_fulfilled_count",
jbe@528 4420 "plus1_unfulfilled_count", "plus1_fulfilled_count",
jbe@528 4421 "plus2_unfulfilled_count", "plus2_fulfilled_count" )
jbe@528 4422 SELECT
jbe@528 4423 "suggestion"."id",
jbe@528 4424 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@528 4425 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@528 4426 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@528 4427 AND "di"."issue_id" = "issue_id_v"
jbe@528 4428 AND "di"."member_id" = "opinion"."member_id"
jbe@528 4429 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@528 4430 AND "opinion"."degree" = -2
jbe@528 4431 AND "opinion"."fulfilled" = FALSE
jbe@528 4432 ) AS "minus2_unfulfilled_count",
jbe@528 4433 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@528 4434 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@528 4435 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@528 4436 AND "di"."issue_id" = "issue_id_v"
jbe@528 4437 AND "di"."member_id" = "opinion"."member_id"
jbe@528 4438 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@528 4439 AND "opinion"."degree" = -2
jbe@528 4440 AND "opinion"."fulfilled" = TRUE
jbe@528 4441 ) AS "minus2_fulfilled_count",
jbe@528 4442 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@528 4443 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@528 4444 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@528 4445 AND "di"."issue_id" = "issue_id_v"
jbe@528 4446 AND "di"."member_id" = "opinion"."member_id"
jbe@528 4447 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@528 4448 AND "opinion"."degree" = -1
jbe@528 4449 AND "opinion"."fulfilled" = FALSE
jbe@528 4450 ) AS "minus1_unfulfilled_count",
jbe@528 4451 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@528 4452 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@528 4453 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@528 4454 AND "di"."issue_id" = "issue_id_v"
jbe@528 4455 AND "di"."member_id" = "opinion"."member_id"
jbe@528 4456 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@528 4457 AND "opinion"."degree" = -1
jbe@528 4458 AND "opinion"."fulfilled" = TRUE
jbe@528 4459 ) AS "minus1_fulfilled_count",
jbe@528 4460 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@528 4461 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@528 4462 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@528 4463 AND "di"."issue_id" = "issue_id_v"
jbe@528 4464 AND "di"."member_id" = "opinion"."member_id"
jbe@528 4465 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@528 4466 AND "opinion"."degree" = 1
jbe@528 4467 AND "opinion"."fulfilled" = FALSE
jbe@528 4468 ) AS "plus1_unfulfilled_count",
jbe@528 4469 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@528 4470 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@528 4471 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@528 4472 AND "di"."issue_id" = "issue_id_v"
jbe@528 4473 AND "di"."member_id" = "opinion"."member_id"
jbe@528 4474 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@528 4475 AND "opinion"."degree" = 1
jbe@528 4476 AND "opinion"."fulfilled" = TRUE
jbe@528 4477 ) AS "plus1_fulfilled_count",
jbe@528 4478 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@528 4479 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@528 4480 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@528 4481 AND "di"."issue_id" = "issue_id_v"
jbe@528 4482 AND "di"."member_id" = "opinion"."member_id"
jbe@528 4483 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@528 4484 AND "opinion"."degree" = 2
jbe@528 4485 AND "opinion"."fulfilled" = FALSE
jbe@528 4486 ) AS "plus2_unfulfilled_count",
jbe@528 4487 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@528 4488 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@528 4489 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@528 4490 AND "di"."issue_id" = "issue_id_v"
jbe@528 4491 AND "di"."member_id" = "opinion"."member_id"
jbe@528 4492 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@528 4493 AND "opinion"."degree" = 2
jbe@528 4494 AND "opinion"."fulfilled" = TRUE
jbe@528 4495 ) AS "plus2_fulfilled_count"
jbe@528 4496 FROM "suggestion" JOIN "initiative"
jbe@528 4497 ON "suggestion"."initiative_id" = "initiative"."id"
jbe@528 4498 WHERE "initiative"."issue_id" = "issue_id_v";
jbe@0 4499 END LOOP;
jbe@528 4500 RETURN "snapshot_id_v";
jbe@0 4501 END;
jbe@0 4502 $$;
jbe@0 4503
jbe@528 4504 COMMENT ON FUNCTION "take_snapshot"
jbe@0 4505 ( "issue"."id"%TYPE )
jbe@528 4506 IS 'This function creates a new interest/supporter snapshot of a particular issue, or, if the argument is NULL, for all issues in ''admission'' phase. It must be executed with TRANSACTION ISOLATION LEVEL REPEATABLE READ. The snapshot must later be finished by calling "finish_snapshot" for every issue.';
jbe@528 4507
jbe@528 4508
jbe@528 4509 CREATE FUNCTION "finish_snapshot"
jbe@0 4510 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 4511 RETURNS VOID
jbe@0 4512 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4513 DECLARE
jbe@528 4514 "snapshot_id_v" "snapshot"."id"%TYPE;
jbe@0 4515 BEGIN
jbe@528 4516 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
jbe@528 4517 SELECT "id" INTO "snapshot_id_v" FROM "snapshot"
jbe@528 4518 ORDER BY "id" DESC LIMIT 1;
jbe@0 4519 UPDATE "issue" SET
jbe@528 4520 "latest_snapshot_id" = "snapshot_id_v",
jbe@0 4521 "population" = (
jbe@0 4522 SELECT coalesce(sum("weight"), 0)
jbe@528 4523 FROM "direct_interest_snapshot"
jbe@528 4524 WHERE "snapshot_id" = "snapshot_id_v"
jbe@528 4525 AND "issue_id" = "issue_id_p"
jbe@0 4526 )
jbe@0 4527 WHERE "id" = "issue_id_p";
jbe@528 4528 UPDATE "initiative" SET
jbe@528 4529 "supporter_count" = (
jbe@528 4530 SELECT coalesce(sum("di"."weight"), 0)
jbe@528 4531 FROM "direct_interest_snapshot" AS "di"
jbe@528 4532 JOIN "direct_supporter_snapshot" AS "ds"
jbe@528 4533 ON "di"."member_id" = "ds"."member_id"
jbe@528 4534 WHERE "di"."snapshot_id" = "snapshot_id_v"
jbe@528 4535 AND "di"."issue_id" = "issue_id_p"
jbe@528 4536 AND "ds"."snapshot_id" = "snapshot_id_v"
jbe@528 4537 AND "ds"."initiative_id" = "initiative"."id"
jbe@528 4538 ),
jbe@528 4539 "informed_supporter_count" = (
jbe@528 4540 SELECT coalesce(sum("di"."weight"), 0)
jbe@528 4541 FROM "direct_interest_snapshot" AS "di"
jbe@528 4542 JOIN "direct_supporter_snapshot" AS "ds"
jbe@528 4543 ON "di"."member_id" = "ds"."member_id"
jbe@528 4544 WHERE "di"."snapshot_id" = "snapshot_id_v"
jbe@528 4545 AND "di"."issue_id" = "issue_id_p"
jbe@528 4546 AND "ds"."snapshot_id" = "snapshot_id_v"
jbe@528 4547 AND "ds"."initiative_id" = "initiative"."id"
jbe@528 4548 AND "ds"."informed"
jbe@528 4549 ),
jbe@528 4550 "satisfied_supporter_count" = (
jbe@528 4551 SELECT coalesce(sum("di"."weight"), 0)
jbe@528 4552 FROM "direct_interest_snapshot" AS "di"
jbe@528 4553 JOIN "direct_supporter_snapshot" AS "ds"
jbe@528 4554 ON "di"."member_id" = "ds"."member_id"
jbe@528 4555 WHERE "di"."snapshot_id" = "snapshot_id_v"
jbe@528 4556 AND "di"."issue_id" = "issue_id_p"
jbe@528 4557 AND "ds"."snapshot_id" = "snapshot_id_v"
jbe@528 4558 AND "ds"."initiative_id" = "initiative"."id"
jbe@528 4559 AND "ds"."satisfied"
jbe@528 4560 ),
jbe@528 4561 "satisfied_informed_supporter_count" = (
jbe@528 4562 SELECT coalesce(sum("di"."weight"), 0)
jbe@528 4563 FROM "direct_interest_snapshot" AS "di"
jbe@528 4564 JOIN "direct_supporter_snapshot" AS "ds"
jbe@528 4565 ON "di"."member_id" = "ds"."member_id"
jbe@528 4566 WHERE "di"."snapshot_id" = "snapshot_id_v"
jbe@528 4567 AND "di"."issue_id" = "issue_id_p"
jbe@528 4568 AND "ds"."snapshot_id" = "snapshot_id_v"
jbe@528 4569 AND "ds"."initiative_id" = "initiative"."id"
jbe@528 4570 AND "ds"."informed"
jbe@528 4571 AND "ds"."satisfied"
jbe@528 4572 )
jbe@528 4573 WHERE "issue_id" = "issue_id_p";
jbe@528 4574 UPDATE "suggestion" SET
jbe@528 4575 "minus2_unfulfilled_count" = "temp"."minus2_unfulfilled_count",
jbe@528 4576 "minus2_fulfilled_count" = "temp"."minus2_fulfilled_count",
jbe@528 4577 "minus1_unfulfilled_count" = "temp"."minus1_unfulfilled_count",
jbe@528 4578 "minus1_fulfilled_count" = "temp"."minus1_fulfilled_count",
jbe@528 4579 "plus1_unfulfilled_count" = "temp"."plus1_unfulfilled_count",
jbe@528 4580 "plus1_fulfilled_count" = "temp"."plus1_fulfilled_count",
jbe@528 4581 "plus2_unfulfilled_count" = "temp"."plus2_unfulfilled_count",
jbe@528 4582 "plus2_fulfilled_count" = "temp"."plus2_fulfilled_count"
jbe@528 4583 FROM "temporary_suggestion_counts" AS "temp", "initiative"
jbe@528 4584 WHERE "temp"."id" = "suggestion"."id"
jbe@528 4585 AND "initiative"."issue_id" = "issue_id_p"
jbe@528 4586 AND "suggestion"."initiative_id" = "initiative"."id";
jbe@528 4587 DELETE FROM "temporary_suggestion_counts";
jbe@0 4588 RETURN;
jbe@0 4589 END;
jbe@0 4590 $$;
jbe@0 4591
jbe@528 4592 COMMENT ON FUNCTION "finish_snapshot"
jbe@0 4593 ( "issue"."id"%TYPE )
jbe@528 4594 IS 'After calling "take_snapshot", this function "finish_snapshot" needs to be called for every issue in the snapshot (separate function calls keep locking time minimal)';
jbe@0 4595
jbe@0 4596
jbe@0 4597
jbe@0 4598 -----------------------
jbe@0 4599 -- Counting of votes --
jbe@0 4600 -----------------------
jbe@0 4601
jbe@0 4602
jbe@5 4603 CREATE FUNCTION "weight_of_added_vote_delegations"
jbe@0 4604 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 4605 "member_id_p" "member"."id"%TYPE,
jbe@0 4606 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
jbe@0 4607 RETURNS "direct_voter"."weight"%TYPE
jbe@0 4608 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4609 DECLARE
jbe@0 4610 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 4611 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
jbe@0 4612 "weight_v" INT4;
jbe@8 4613 "sub_weight_v" INT4;
jbe@0 4614 BEGIN
jbe@336 4615 PERFORM "require_transaction_isolation"();
jbe@0 4616 "weight_v" := 0;
jbe@0 4617 FOR "issue_delegation_row" IN
jbe@0 4618 SELECT * FROM "issue_delegation"
jbe@0 4619 WHERE "trustee_id" = "member_id_p"
jbe@0 4620 AND "issue_id" = "issue_id_p"
jbe@0 4621 LOOP
jbe@0 4622 IF NOT EXISTS (
jbe@0 4623 SELECT NULL FROM "direct_voter"
jbe@0 4624 WHERE "member_id" = "issue_delegation_row"."truster_id"
jbe@0 4625 AND "issue_id" = "issue_id_p"
jbe@0 4626 ) AND NOT EXISTS (
jbe@0 4627 SELECT NULL FROM "delegating_voter"
jbe@0 4628 WHERE "member_id" = "issue_delegation_row"."truster_id"
jbe@0 4629 AND "issue_id" = "issue_id_p"
jbe@0 4630 ) THEN
jbe@0 4631 "delegate_member_ids_v" :=
jbe@0 4632 "member_id_p" || "delegate_member_ids_p";
jbe@10 4633 INSERT INTO "delegating_voter" (
jbe@10 4634 "issue_id",
jbe@10 4635 "member_id",
jbe@10 4636 "scope",
jbe@10 4637 "delegate_member_ids"
jbe@10 4638 ) VALUES (
jbe@5 4639 "issue_id_p",
jbe@5 4640 "issue_delegation_row"."truster_id",
jbe@10 4641 "issue_delegation_row"."scope",
jbe@5 4642 "delegate_member_ids_v"
jbe@5 4643 );
jbe@8 4644 "sub_weight_v" := 1 +
jbe@8 4645 "weight_of_added_vote_delegations"(
jbe@8 4646 "issue_id_p",
jbe@8 4647 "issue_delegation_row"."truster_id",
jbe@8 4648 "delegate_member_ids_v"
jbe@8 4649 );
jbe@8 4650 UPDATE "delegating_voter"
jbe@8 4651 SET "weight" = "sub_weight_v"
jbe@8 4652 WHERE "issue_id" = "issue_id_p"
jbe@8 4653 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 4654 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 4655 END IF;
jbe@0 4656 END LOOP;
jbe@0 4657 RETURN "weight_v";
jbe@0 4658 END;
jbe@0 4659 $$;
jbe@0 4660
jbe@5 4661 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
jbe@0 4662 ( "issue"."id"%TYPE,
jbe@0 4663 "member"."id"%TYPE,
jbe@0 4664 "delegating_voter"."delegate_member_ids"%TYPE )
jbe@0 4665 IS 'Helper function for "add_vote_delegations" function';
jbe@0 4666
jbe@0 4667
jbe@0 4668 CREATE FUNCTION "add_vote_delegations"
jbe@0 4669 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 4670 RETURNS VOID
jbe@0 4671 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4672 DECLARE
jbe@0 4673 "member_id_v" "member"."id"%TYPE;
jbe@0 4674 BEGIN
jbe@336 4675 PERFORM "require_transaction_isolation"();
jbe@0 4676 FOR "member_id_v" IN
jbe@0 4677 SELECT "member_id" FROM "direct_voter"
jbe@0 4678 WHERE "issue_id" = "issue_id_p"
jbe@0 4679 LOOP
jbe@0 4680 UPDATE "direct_voter" SET
jbe@5 4681 "weight" = "weight" + "weight_of_added_vote_delegations"(
jbe@0 4682 "issue_id_p",
jbe@0 4683 "member_id_v",
jbe@0 4684 '{}'
jbe@0 4685 )
jbe@0 4686 WHERE "member_id" = "member_id_v"
jbe@0 4687 AND "issue_id" = "issue_id_p";
jbe@0 4688 END LOOP;
jbe@0 4689 RETURN;
jbe@0 4690 END;
jbe@0 4691 $$;
jbe@0 4692
jbe@0 4693 COMMENT ON FUNCTION "add_vote_delegations"
jbe@0 4694 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 4695 IS 'Helper function for "close_voting" function';
jbe@0 4696
jbe@0 4697
jbe@0 4698 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
jbe@0 4699 RETURNS VOID
jbe@0 4700 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4701 DECLARE
jbe@97 4702 "area_id_v" "area"."id"%TYPE;
jbe@97 4703 "unit_id_v" "unit"."id"%TYPE;
jbe@0 4704 "member_id_v" "member"."id"%TYPE;
jbe@0 4705 BEGIN
jbe@333 4706 PERFORM "require_transaction_isolation"();
jbe@129 4707 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
jbe@129 4708 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
jbe@383 4709 -- override protection triggers:
jbe@385 4710 INSERT INTO "temporary_transaction_data" ("key", "value")
jbe@385 4711 VALUES ('override_protection_triggers', TRUE::TEXT);
jbe@285 4712 -- delete timestamp of voting comment:
jbe@285 4713 UPDATE "direct_voter" SET "comment_changed" = NULL
jbe@285 4714 WHERE "issue_id" = "issue_id_p";
jbe@169 4715 -- delete delegating votes (in cases of manual reset of issue state):
jbe@0 4716 DELETE FROM "delegating_voter"
jbe@0 4717 WHERE "issue_id" = "issue_id_p";
jbe@169 4718 -- delete votes from non-privileged voters:
jbe@97 4719 DELETE FROM "direct_voter"
jbe@97 4720 USING (
jbe@97 4721 SELECT
jbe@97 4722 "direct_voter"."member_id"
jbe@97 4723 FROM "direct_voter"
jbe@97 4724 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
jbe@97 4725 LEFT JOIN "privilege"
jbe@97 4726 ON "privilege"."unit_id" = "unit_id_v"
jbe@97 4727 AND "privilege"."member_id" = "direct_voter"."member_id"
jbe@97 4728 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
jbe@97 4729 "member"."active" = FALSE OR
jbe@97 4730 "privilege"."voting_right" ISNULL OR
jbe@97 4731 "privilege"."voting_right" = FALSE
jbe@97 4732 )
jbe@97 4733 ) AS "subquery"
jbe@97 4734 WHERE "direct_voter"."issue_id" = "issue_id_p"
jbe@97 4735 AND "direct_voter"."member_id" = "subquery"."member_id";
jbe@169 4736 -- consider delegations:
jbe@0 4737 UPDATE "direct_voter" SET "weight" = 1
jbe@0 4738 WHERE "issue_id" = "issue_id_p";
jbe@0 4739 PERFORM "add_vote_delegations"("issue_id_p");
jbe@414 4740 -- mark first preferences:
jbe@414 4741 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
jbe@414 4742 FROM (
jbe@414 4743 SELECT
jbe@414 4744 "vote"."initiative_id",
jbe@414 4745 "vote"."member_id",
jbe@414 4746 CASE WHEN "vote"."grade" > 0 THEN
jbe@414 4747 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
jbe@414 4748 ELSE NULL
jbe@414 4749 END AS "first_preference"
jbe@415 4750 FROM "vote"
jbe@415 4751 JOIN "initiative" -- NOTE: due to missing index on issue_id
jbe@415 4752 ON "vote"."issue_id" = "initiative"."issue_id"
jbe@415 4753 JOIN "vote" AS "agg"
jbe@415 4754 ON "initiative"."id" = "agg"."initiative_id"
jbe@415 4755 AND "vote"."member_id" = "agg"."member_id"
jbe@433 4756 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
jbe@414 4757 ) AS "subquery"
jbe@414 4758 WHERE "vote"."issue_id" = "issue_id_p"
jbe@414 4759 AND "vote"."initiative_id" = "subquery"."initiative_id"
jbe@414 4760 AND "vote"."member_id" = "subquery"."member_id";
jbe@385 4761 -- finish overriding protection triggers (avoids garbage):
jbe@385 4762 DELETE FROM "temporary_transaction_data"
jbe@385 4763 WHERE "key" = 'override_protection_triggers';
jbe@137 4764 -- materialize battle_view:
jbe@61 4765 -- NOTE: "closed" column of issue must be set at this point
jbe@61 4766 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@61 4767 INSERT INTO "battle" (
jbe@61 4768 "issue_id",
jbe@61 4769 "winning_initiative_id", "losing_initiative_id",
jbe@61 4770 "count"
jbe@61 4771 ) SELECT
jbe@61 4772 "issue_id",
jbe@61 4773 "winning_initiative_id", "losing_initiative_id",
jbe@61 4774 "count"
jbe@61 4775 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
jbe@331 4776 -- set voter count:
jbe@331 4777 UPDATE "issue" SET
jbe@331 4778 "voter_count" = (
jbe@331 4779 SELECT coalesce(sum("weight"), 0)
jbe@331 4780 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
jbe@331 4781 )
jbe@331 4782 WHERE "id" = "issue_id_p";
jbe@437 4783 -- copy "positive_votes" and "negative_votes" from "battle" table:
jbe@437 4784 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
jbe@437 4785 UPDATE "initiative" SET
jbe@437 4786 "first_preference_votes" = 0,
jbe@437 4787 "positive_votes" = "battle_win"."count",
jbe@437 4788 "negative_votes" = "battle_lose"."count"
jbe@437 4789 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
jbe@437 4790 WHERE
jbe@437 4791 "battle_win"."issue_id" = "issue_id_p" AND
jbe@437 4792 "battle_win"."winning_initiative_id" = "initiative"."id" AND
jbe@437 4793 "battle_win"."losing_initiative_id" ISNULL AND
jbe@437 4794 "battle_lose"."issue_id" = "issue_id_p" AND
jbe@437 4795 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
jbe@437 4796 "battle_lose"."winning_initiative_id" ISNULL;
jbe@414 4797 -- calculate "first_preference_votes":
jbe@437 4798 -- NOTE: will only set values not equal to zero
jbe@437 4799 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
jbe@414 4800 FROM (
jbe@414 4801 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
jbe@414 4802 FROM "vote" JOIN "direct_voter"
jbe@414 4803 ON "vote"."issue_id" = "direct_voter"."issue_id"
jbe@414 4804 AND "vote"."member_id" = "direct_voter"."member_id"
jbe@414 4805 WHERE "vote"."first_preference"
jbe@414 4806 GROUP BY "vote"."initiative_id"
jbe@414 4807 ) AS "subquery"
jbe@414 4808 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@414 4809 AND "initiative"."admitted"
jbe@414 4810 AND "initiative"."id" = "subquery"."initiative_id";
jbe@0 4811 END;
jbe@0 4812 $$;
jbe@0 4813
jbe@0 4814 COMMENT ON FUNCTION "close_voting"
jbe@0 4815 ( "issue"."id"%TYPE )
jbe@0 4816 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 4817
jbe@0 4818
jbe@30 4819 CREATE FUNCTION "defeat_strength"
jbe@424 4820 ( "positive_votes_p" INT4,
jbe@424 4821 "negative_votes_p" INT4,
jbe@424 4822 "defeat_strength_p" "defeat_strength" )
jbe@30 4823 RETURNS INT8
jbe@30 4824 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@30 4825 BEGIN
jbe@424 4826 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
jbe@424 4827 IF "positive_votes_p" > "negative_votes_p" THEN
jbe@424 4828 RETURN "positive_votes_p";
jbe@424 4829 ELSE
jbe@424 4830 RETURN 0;
jbe@424 4831 END IF;
jbe@30 4832 ELSE
jbe@424 4833 IF "positive_votes_p" > "negative_votes_p" THEN
jbe@424 4834 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
jbe@424 4835 ELSIF "positive_votes_p" = "negative_votes_p" THEN
jbe@424 4836 RETURN 0;
jbe@424 4837 ELSE
jbe@424 4838 RETURN -1;
jbe@424 4839 END IF;
jbe@30 4840 END IF;
jbe@30 4841 END;
jbe@30 4842 $$;
jbe@30 4843
jbe@425 4844 COMMENT ON FUNCTION "defeat_strength"(INT4, INT4, "defeat_strength") IS 'Calculates defeat strength (INT8!) according to the "defeat_strength" option (see comment on type "defeat_strength")';
jbe@30 4845
jbe@30 4846
jbe@423 4847 CREATE FUNCTION "secondary_link_strength"
jbe@426 4848 ( "initiative1_ord_p" INT4,
jbe@426 4849 "initiative2_ord_p" INT4,
jbe@424 4850 "tie_breaking_p" "tie_breaking" )
jbe@423 4851 RETURNS INT8
jbe@423 4852 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@423 4853 BEGIN
jbe@426 4854 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
jbe@423 4855 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
jbe@423 4856 END IF;
jbe@423 4857 RETURN (
jbe@426 4858 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
jbe@426 4859 0
jbe@424 4860 ELSE
jbe@426 4861 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
jbe@426 4862 1::INT8 << 62
jbe@426 4863 ELSE 0 END
jbe@426 4864 +
jbe@426 4865 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
jbe@426 4866 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
jbe@426 4867 ELSE
jbe@426 4868 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
jbe@426 4869 END
jbe@424 4870 END
jbe@423 4871 );
jbe@423 4872 END;
jbe@423 4873 $$;
jbe@423 4874
jbe@424 4875 COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4, "tie_breaking") IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)';
jbe@423 4876
jbe@423 4877
jbe@426 4878 CREATE TYPE "link_strength" AS (
jbe@426 4879 "primary" INT8,
jbe@426 4880 "secondary" INT8 );
jbe@426 4881
jbe@428 4882 COMMENT ON TYPE "link_strength" IS 'Type to store the defeat strength of a link between two candidates plus a secondary criterion to create unique link strengths between the candidates (needed for tie-breaking ''variant1'' and ''variant2'')';
jbe@427 4883
jbe@427 4884
jbe@427 4885 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
jbe@427 4886 RETURNS "link_strength"[][]
jbe@427 4887 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@427 4888 DECLARE
jbe@427 4889 "dimension_v" INT4;
jbe@427 4890 "matrix_p" "link_strength"[][];
jbe@427 4891 "i" INT4;
jbe@427 4892 "j" INT4;
jbe@427 4893 "k" INT4;
jbe@427 4894 BEGIN
jbe@427 4895 "dimension_v" := array_upper("matrix_d", 1);
jbe@427 4896 "matrix_p" := "matrix_d";
jbe@427 4897 "i" := 1;
jbe@427 4898 LOOP
jbe@427 4899 "j" := 1;
jbe@427 4900 LOOP
jbe@427 4901 IF "i" != "j" THEN
jbe@427 4902 "k" := 1;
jbe@427 4903 LOOP
jbe@427 4904 IF "i" != "k" AND "j" != "k" THEN
jbe@427 4905 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
jbe@427 4906 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
jbe@427 4907 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
jbe@427 4908 END IF;
jbe@427 4909 ELSE
jbe@427 4910 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
jbe@427 4911 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
jbe@427 4912 END IF;
jbe@427 4913 END IF;
jbe@427 4914 END IF;
jbe@427 4915 EXIT WHEN "k" = "dimension_v";
jbe@427 4916 "k" := "k" + 1;
jbe@427 4917 END LOOP;
jbe@427 4918 END IF;
jbe@427 4919 EXIT WHEN "j" = "dimension_v";
jbe@427 4920 "j" := "j" + 1;
jbe@427 4921 END LOOP;
jbe@427 4922 EXIT WHEN "i" = "dimension_v";
jbe@427 4923 "i" := "i" + 1;
jbe@427 4924 END LOOP;
jbe@427 4925 RETURN "matrix_p";
jbe@427 4926 END;
jbe@427 4927 $$;
jbe@427 4928
jbe@428 4929 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
jbe@426 4930
jbe@426 4931
jbe@0 4932 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
jbe@0 4933 RETURNS VOID
jbe@0 4934 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4935 DECLARE
jbe@427 4936 "issue_row" "issue"%ROWTYPE;
jbe@427 4937 "policy_row" "policy"%ROWTYPE;
jbe@427 4938 "dimension_v" INT4;
jbe@427 4939 "matrix_a" INT4[][]; -- absolute votes
jbe@427 4940 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
jbe@427 4941 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
jbe@427 4942 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
jbe@427 4943 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
jbe@427 4944 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
jbe@427 4945 "i" INT4;
jbe@427 4946 "j" INT4;
jbe@427 4947 "m" INT4;
jbe@427 4948 "n" INT4;
jbe@427 4949 "battle_row" "battle"%ROWTYPE;
jbe@427 4950 "rank_ary" INT4[];
jbe@427 4951 "rank_v" INT4;
jbe@427 4952 "initiative_id_v" "initiative"."id"%TYPE;
jbe@0 4953 BEGIN
jbe@333 4954 PERFORM "require_transaction_isolation"();
jbe@155 4955 SELECT * INTO "issue_row"
jbe@331 4956 FROM "issue" WHERE "id" = "issue_id_p";
jbe@155 4957 SELECT * INTO "policy_row"
jbe@155 4958 FROM "policy" WHERE "id" = "issue_row"."policy_id";
jbe@126 4959 SELECT count(1) INTO "dimension_v"
jbe@126 4960 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
jbe@428 4961 -- create "matrix_a" with absolute number of votes in pairwise
jbe@170 4962 -- comparison:
jbe@427 4963 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
jbe@170 4964 "i" := 1;
jbe@170 4965 "j" := 2;
jbe@170 4966 FOR "battle_row" IN
jbe@170 4967 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
jbe@170 4968 ORDER BY
jbe@411 4969 "winning_initiative_id" NULLS FIRST,
jbe@411 4970 "losing_initiative_id" NULLS FIRST
jbe@170 4971 LOOP
jbe@427 4972 "matrix_a"["i"]["j"] := "battle_row"."count";
jbe@170 4973 IF "j" = "dimension_v" THEN
jbe@170 4974 "i" := "i" + 1;
jbe@170 4975 "j" := 1;
jbe@170 4976 ELSE
jbe@170 4977 "j" := "j" + 1;
jbe@170 4978 IF "j" = "i" THEN
jbe@170 4979 "j" := "j" + 1;
jbe@170 4980 END IF;
jbe@170 4981 END IF;
jbe@170 4982 END LOOP;
jbe@170 4983 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
jbe@170 4984 RAISE EXCEPTION 'Wrong battle count (should not happen)';
jbe@170 4985 END IF;
jbe@428 4986 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
jbe@427 4987 -- and "secondary_link_strength" functions:
jbe@427 4988 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
jbe@170 4989 "i" := 1;
jbe@170 4990 LOOP
jbe@170 4991 "j" := 1;
jbe@0 4992 LOOP
jbe@170 4993 IF "i" != "j" THEN
jbe@427 4994 "matrix_d"["i"]["j"] := (
jbe@426 4995 "defeat_strength"(
jbe@427 4996 "matrix_a"["i"]["j"],
jbe@427 4997 "matrix_a"["j"]["i"],
jbe@426 4998 "policy_row"."defeat_strength"
jbe@426 4999 ),
jbe@426 5000 "secondary_link_strength"(
jbe@426 5001 "i",
jbe@426 5002 "j",
jbe@426 5003 "policy_row"."tie_breaking"
jbe@426 5004 )
jbe@426 5005 )::"link_strength";
jbe@0 5006 END IF;
jbe@170 5007 EXIT WHEN "j" = "dimension_v";
jbe@170 5008 "j" := "j" + 1;
jbe@0 5009 END LOOP;
jbe@170 5010 EXIT WHEN "i" = "dimension_v";
jbe@170 5011 "i" := "i" + 1;
jbe@170 5012 END LOOP;
jbe@428 5013 -- find best paths:
jbe@427 5014 "matrix_p" := "find_best_paths"("matrix_d");
jbe@428 5015 -- create partial order:
jbe@427 5016 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
jbe@170 5017 "i" := 1;
jbe@170 5018 LOOP
jbe@427 5019 "j" := "i" + 1;
jbe@170 5020 LOOP
jbe@170 5021 IF "i" != "j" THEN
jbe@427 5022 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
jbe@427 5023 "matrix_b"["i"]["j"] := TRUE;
jbe@427 5024 "matrix_b"["j"]["i"] := FALSE;
jbe@427 5025 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
jbe@427 5026 "matrix_b"["i"]["j"] := FALSE;
jbe@427 5027 "matrix_b"["j"]["i"] := TRUE;
jbe@427 5028 END IF;
jbe@170 5029 END IF;
jbe@170 5030 EXIT WHEN "j" = "dimension_v";
jbe@170 5031 "j" := "j" + 1;
jbe@170 5032 END LOOP;
jbe@427 5033 EXIT WHEN "i" = "dimension_v" - 1;
jbe@170 5034 "i" := "i" + 1;
jbe@170 5035 END LOOP;
jbe@428 5036 -- tie-breaking by forbidding shared weakest links in beat-paths
jbe@428 5037 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
jbe@428 5038 -- is performed later by initiative id):
jbe@427 5039 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
jbe@427 5040 "m" := 1;
jbe@427 5041 LOOP
jbe@427 5042 "n" := "m" + 1;
jbe@427 5043 LOOP
jbe@428 5044 -- only process those candidates m and n, which are tied:
jbe@427 5045 IF "matrix_b"["m"]["n"] ISNULL THEN
jbe@428 5046 -- start with beat-paths prior tie-breaking:
jbe@427 5047 "matrix_t" := "matrix_p";
jbe@428 5048 -- start with all links allowed:
jbe@427 5049 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
jbe@427 5050 LOOP
jbe@428 5051 -- determine (and forbid) that link that is the weakest link
jbe@428 5052 -- in both the best path from candidate m to candidate n and
jbe@428 5053 -- from candidate n to candidate m:
jbe@427 5054 "i" := 1;
jbe@427 5055 <<forbid_one_link>>
jbe@427 5056 LOOP
jbe@427 5057 "j" := 1;
jbe@427 5058 LOOP
jbe@427 5059 IF "i" != "j" THEN
jbe@427 5060 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
jbe@427 5061 "matrix_f"["i"]["j"] := TRUE;
jbe@427 5062 -- exit for performance reasons,
jbe@428 5063 -- as exactly one link will be found:
jbe@427 5064 EXIT forbid_one_link;
jbe@427 5065 END IF;
jbe@427 5066 END IF;
jbe@427 5067 EXIT WHEN "j" = "dimension_v";
jbe@427 5068 "j" := "j" + 1;
jbe@427 5069 END LOOP;
jbe@427 5070 IF "i" = "dimension_v" THEN
jbe@428 5071 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
jbe@427 5072 END IF;
jbe@427 5073 "i" := "i" + 1;
jbe@427 5074 END LOOP;
jbe@428 5075 -- calculate best beat-paths while ignoring forbidden links:
jbe@427 5076 "i" := 1;
jbe@427 5077 LOOP
jbe@427 5078 "j" := 1;
jbe@427 5079 LOOP
jbe@427 5080 IF "i" != "j" THEN
jbe@427 5081 "matrix_t"["i"]["j"] := CASE
jbe@427 5082 WHEN "matrix_f"["i"]["j"]
jbe@431 5083 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
jbe@427 5084 ELSE "matrix_d"["i"]["j"] END;
jbe@427 5085 END IF;
jbe@427 5086 EXIT WHEN "j" = "dimension_v";
jbe@427 5087 "j" := "j" + 1;
jbe@427 5088 END LOOP;
jbe@427 5089 EXIT WHEN "i" = "dimension_v";
jbe@427 5090 "i" := "i" + 1;
jbe@427 5091 END LOOP;
jbe@427 5092 "matrix_t" := "find_best_paths"("matrix_t");
jbe@428 5093 -- extend partial order, if tie-breaking was successful:
jbe@427 5094 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
jbe@427 5095 "matrix_b"["m"]["n"] := TRUE;
jbe@427 5096 "matrix_b"["n"]["m"] := FALSE;
jbe@427 5097 EXIT;
jbe@427 5098 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
jbe@427 5099 "matrix_b"["m"]["n"] := FALSE;
jbe@427 5100 "matrix_b"["n"]["m"] := TRUE;
jbe@427 5101 EXIT;
jbe@427 5102 END IF;
jbe@427 5103 END LOOP;
jbe@427 5104 END IF;
jbe@427 5105 EXIT WHEN "n" = "dimension_v";
jbe@427 5106 "n" := "n" + 1;
jbe@427 5107 END LOOP;
jbe@427 5108 EXIT WHEN "m" = "dimension_v" - 1;
jbe@427 5109 "m" := "m" + 1;
jbe@427 5110 END LOOP;
jbe@427 5111 END IF;
jbe@428 5112 -- store a unique ranking in "rank_ary":
jbe@170 5113 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
jbe@170 5114 "rank_v" := 1;
jbe@170 5115 LOOP
jbe@0 5116 "i" := 1;
jbe@428 5117 <<assign_next_rank>>
jbe@0 5118 LOOP
jbe@170 5119 IF "rank_ary"["i"] ISNULL THEN
jbe@170 5120 "j" := 1;
jbe@170 5121 LOOP
jbe@170 5122 IF
jbe@170 5123 "i" != "j" AND
jbe@170 5124 "rank_ary"["j"] ISNULL AND
jbe@427 5125 ( "matrix_b"["j"]["i"] OR
jbe@411 5126 -- tie-breaking by "id"
jbe@427 5127 ( "matrix_b"["j"]["i"] ISNULL AND
jbe@411 5128 "j" < "i" ) )
jbe@170 5129 THEN
jbe@170 5130 -- someone else is better
jbe@170 5131 EXIT;
jbe@170 5132 END IF;
jbe@428 5133 IF "j" = "dimension_v" THEN
jbe@170 5134 -- noone is better
jbe@411 5135 "rank_ary"["i"] := "rank_v";
jbe@428 5136 EXIT assign_next_rank;
jbe@170 5137 END IF;
jbe@428 5138 "j" := "j" + 1;
jbe@170 5139 END LOOP;
jbe@170 5140 END IF;
jbe@0 5141 "i" := "i" + 1;
jbe@411 5142 IF "i" > "dimension_v" THEN
jbe@411 5143 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
jbe@411 5144 END IF;
jbe@0 5145 END LOOP;
jbe@411 5146 EXIT WHEN "rank_v" = "dimension_v";
jbe@170 5147 "rank_v" := "rank_v" + 1;
jbe@170 5148 END LOOP;
jbe@170 5149 -- write preliminary results:
jbe@411 5150 "i" := 2; -- omit status quo with "i" = 1
jbe@170 5151 FOR "initiative_id_v" IN
jbe@170 5152 SELECT "id" FROM "initiative"
jbe@170 5153 WHERE "issue_id" = "issue_id_p" AND "admitted"
jbe@170 5154 ORDER BY "id"
jbe@170 5155 LOOP
jbe@170 5156 UPDATE "initiative" SET
jbe@170 5157 "direct_majority" =
jbe@170 5158 CASE WHEN "policy_row"."direct_majority_strict" THEN
jbe@170 5159 "positive_votes" * "policy_row"."direct_majority_den" >
jbe@170 5160 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 5161 ELSE
jbe@170 5162 "positive_votes" * "policy_row"."direct_majority_den" >=
jbe@170 5163 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 5164 END
jbe@170 5165 AND "positive_votes" >= "policy_row"."direct_majority_positive"
jbe@170 5166 AND "issue_row"."voter_count"-"negative_votes" >=
jbe@170 5167 "policy_row"."direct_majority_non_negative",
jbe@170 5168 "indirect_majority" =
jbe@170 5169 CASE WHEN "policy_row"."indirect_majority_strict" THEN
jbe@170 5170 "positive_votes" * "policy_row"."indirect_majority_den" >
jbe@170 5171 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 5172 ELSE
jbe@170 5173 "positive_votes" * "policy_row"."indirect_majority_den" >=
jbe@170 5174 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 5175 END
jbe@170 5176 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
jbe@170 5177 AND "issue_row"."voter_count"-"negative_votes" >=
jbe@170 5178 "policy_row"."indirect_majority_non_negative",
jbe@171 5179 "schulze_rank" = "rank_ary"["i"],
jbe@411 5180 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
jbe@411 5181 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
jbe@411 5182 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
jbe@429 5183 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
jbe@429 5184 THEN NULL
jbe@429 5185 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
jbe@216 5186 "eligible" = FALSE,
jbe@250 5187 "winner" = FALSE,
jbe@250 5188 "rank" = NULL -- NOTE: in cases of manual reset of issue state
jbe@170 5189 WHERE "id" = "initiative_id_v";
jbe@170 5190 "i" := "i" + 1;
jbe@170 5191 END LOOP;
jbe@411 5192 IF "i" != "dimension_v" + 1 THEN
jbe@170 5193 RAISE EXCEPTION 'Wrong winner count (should not happen)';
jbe@0 5194 END IF;
jbe@170 5195 -- take indirect majorities into account:
jbe@170 5196 LOOP
jbe@170 5197 UPDATE "initiative" SET "indirect_majority" = TRUE
jbe@139 5198 FROM (
jbe@170 5199 SELECT "new_initiative"."id" AS "initiative_id"
jbe@170 5200 FROM "initiative" "old_initiative"
jbe@170 5201 JOIN "initiative" "new_initiative"
jbe@170 5202 ON "new_initiative"."issue_id" = "issue_id_p"
jbe@170 5203 AND "new_initiative"."indirect_majority" = FALSE
jbe@139 5204 JOIN "battle" "battle_win"
jbe@139 5205 ON "battle_win"."issue_id" = "issue_id_p"
jbe@170 5206 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
jbe@170 5207 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
jbe@139 5208 JOIN "battle" "battle_lose"
jbe@139 5209 ON "battle_lose"."issue_id" = "issue_id_p"
jbe@170 5210 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
jbe@170 5211 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
jbe@170 5212 WHERE "old_initiative"."issue_id" = "issue_id_p"
jbe@170 5213 AND "old_initiative"."indirect_majority" = TRUE
jbe@170 5214 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
jbe@170 5215 "battle_win"."count" * "policy_row"."indirect_majority_den" >
jbe@170 5216 "policy_row"."indirect_majority_num" *
jbe@170 5217 ("battle_win"."count"+"battle_lose"."count")
jbe@170 5218 ELSE
jbe@170 5219 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
jbe@170 5220 "policy_row"."indirect_majority_num" *
jbe@170 5221 ("battle_win"."count"+"battle_lose"."count")
jbe@170 5222 END
jbe@170 5223 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
jbe@170 5224 AND "issue_row"."voter_count"-"battle_lose"."count" >=
jbe@170 5225 "policy_row"."indirect_majority_non_negative"
jbe@139 5226 ) AS "subquery"
jbe@139 5227 WHERE "id" = "subquery"."initiative_id";
jbe@170 5228 EXIT WHEN NOT FOUND;
jbe@170 5229 END LOOP;
jbe@170 5230 -- set "multistage_majority" for remaining matching initiatives:
jbe@216 5231 UPDATE "initiative" SET "multistage_majority" = TRUE
jbe@170 5232 FROM (
jbe@170 5233 SELECT "losing_initiative"."id" AS "initiative_id"
jbe@170 5234 FROM "initiative" "losing_initiative"
jbe@170 5235 JOIN "initiative" "winning_initiative"
jbe@170 5236 ON "winning_initiative"."issue_id" = "issue_id_p"
jbe@170 5237 AND "winning_initiative"."admitted"
jbe@170 5238 JOIN "battle" "battle_win"
jbe@170 5239 ON "battle_win"."issue_id" = "issue_id_p"
jbe@170 5240 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
jbe@170 5241 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
jbe@170 5242 JOIN "battle" "battle_lose"
jbe@170 5243 ON "battle_lose"."issue_id" = "issue_id_p"
jbe@170 5244 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
jbe@170 5245 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
jbe@170 5246 WHERE "losing_initiative"."issue_id" = "issue_id_p"
jbe@170 5247 AND "losing_initiative"."admitted"
jbe@170 5248 AND "winning_initiative"."schulze_rank" <
jbe@170 5249 "losing_initiative"."schulze_rank"
jbe@170 5250 AND "battle_win"."count" > "battle_lose"."count"
jbe@170 5251 AND (
jbe@170 5252 "battle_win"."count" > "winning_initiative"."positive_votes" OR
jbe@170 5253 "battle_lose"."count" < "losing_initiative"."negative_votes" )
jbe@170 5254 ) AS "subquery"
jbe@170 5255 WHERE "id" = "subquery"."initiative_id";
jbe@170 5256 -- mark eligible initiatives:
jbe@170 5257 UPDATE "initiative" SET "eligible" = TRUE
jbe@171 5258 WHERE "issue_id" = "issue_id_p"
jbe@171 5259 AND "initiative"."direct_majority"
jbe@171 5260 AND "initiative"."indirect_majority"
jbe@171 5261 AND "initiative"."better_than_status_quo"
jbe@171 5262 AND (
jbe@171 5263 "policy_row"."no_multistage_majority" = FALSE OR
jbe@429 5264 "initiative"."multistage_majority" = FALSE )
jbe@429 5265 AND (
jbe@429 5266 "policy_row"."no_reverse_beat_path" = FALSE OR
jbe@429 5267 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
jbe@170 5268 -- mark final winner:
jbe@170 5269 UPDATE "initiative" SET "winner" = TRUE
jbe@170 5270 FROM (
jbe@170 5271 SELECT "id" AS "initiative_id"
jbe@170 5272 FROM "initiative"
jbe@170 5273 WHERE "issue_id" = "issue_id_p" AND "eligible"
jbe@217 5274 ORDER BY
jbe@217 5275 "schulze_rank",
jbe@217 5276 "id"
jbe@170 5277 LIMIT 1
jbe@170 5278 ) AS "subquery"
jbe@170 5279 WHERE "id" = "subquery"."initiative_id";
jbe@173 5280 -- write (final) ranks:
jbe@173 5281 "rank_v" := 1;
jbe@173 5282 FOR "initiative_id_v" IN
jbe@173 5283 SELECT "id"
jbe@173 5284 FROM "initiative"
jbe@173 5285 WHERE "issue_id" = "issue_id_p" AND "admitted"
jbe@174 5286 ORDER BY
jbe@174 5287 "winner" DESC,
jbe@217 5288 "eligible" DESC,
jbe@174 5289 "schulze_rank",
jbe@174 5290 "id"
jbe@173 5291 LOOP
jbe@173 5292 UPDATE "initiative" SET "rank" = "rank_v"
jbe@173 5293 WHERE "id" = "initiative_id_v";
jbe@173 5294 "rank_v" := "rank_v" + 1;
jbe@173 5295 END LOOP;
jbe@170 5296 -- set schulze rank of status quo and mark issue as finished:
jbe@111 5297 UPDATE "issue" SET
jbe@411 5298 "status_quo_schulze_rank" = "rank_ary"[1],
jbe@111 5299 "state" =
jbe@139 5300 CASE WHEN EXISTS (
jbe@139 5301 SELECT NULL FROM "initiative"
jbe@139 5302 WHERE "issue_id" = "issue_id_p" AND "winner"
jbe@139 5303 ) THEN
jbe@139 5304 'finished_with_winner'::"issue_state"
jbe@139 5305 ELSE
jbe@121 5306 'finished_without_winner'::"issue_state"
jbe@111 5307 END,
jbe@331 5308 "closed" = "phase_finished",
jbe@331 5309 "phase_finished" = NULL
jbe@0 5310 WHERE "id" = "issue_id_p";
jbe@0 5311 RETURN;
jbe@0 5312 END;
jbe@0 5313 $$;
jbe@0 5314
jbe@0 5315 COMMENT ON FUNCTION "calculate_ranks"
jbe@0 5316 ( "issue"."id"%TYPE )
jbe@0 5317 IS 'Determine ranking (Votes have to be counted first)';
jbe@0 5318
jbe@0 5319
jbe@0 5320
jbe@0 5321 -----------------------------
jbe@0 5322 -- Automatic state changes --
jbe@0 5323 -----------------------------
jbe@0 5324
jbe@0 5325
jbe@528 5326 CREATE FUNCTION "issue_admission"()
jbe@528 5327 RETURNS BOOLEAN
jbe@528 5328 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@528 5329 DECLARE
jbe@528 5330 "issue_id_v" "issue"."id"%TYPE;
jbe@528 5331 BEGIN
jbe@528 5332 PERFORM "dont_require_transaction_isolation"();
jbe@528 5333 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
jbe@528 5334 SELECT "id" INTO "issue_id_v" FROM "issue_for_admission" LIMIT 1;
jbe@528 5335 IF "issue_id_v" ISNULL THEN RETURN FALSE; END IF;
jbe@528 5336 UPDATE "issue" SET
jbe@528 5337 "admission_snapshot_id" = "latest_snapshot_id",
jbe@528 5338 "state" = 'discussion',
jbe@528 5339 "accepted" = now(),
jbe@528 5340 "phase_finished" = NULL
jbe@528 5341 WHERE "id" = "issue_id_v";
jbe@528 5342 RETURN TRUE;
jbe@528 5343 END;
jbe@528 5344 $$;
jbe@528 5345
jbe@528 5346 COMMENT ON FUNCTION "issue_admission"() IS 'Checks if an issue can be admitted for further discussion; returns TRUE on success in which case the function must be called again until it returns FALSE';
jbe@528 5347
jbe@528 5348
jbe@331 5349 CREATE TYPE "check_issue_persistence" AS (
jbe@331 5350 "state" "issue_state",
jbe@331 5351 "phase_finished" BOOLEAN,
jbe@331 5352 "issue_revoked" BOOLEAN,
jbe@331 5353 "snapshot_created" BOOLEAN,
jbe@331 5354 "harmonic_weights_set" BOOLEAN,
jbe@331 5355 "closed_voting" BOOLEAN );
jbe@331 5356
jbe@336 5357 COMMENT ON TYPE "check_issue_persistence" IS 'Type of data returned by "check_issue" function, to be passed to subsequent calls of the same function';
jbe@336 5358
jbe@336 5359
jbe@0 5360 CREATE FUNCTION "check_issue"
jbe@331 5361 ( "issue_id_p" "issue"."id"%TYPE,
jbe@331 5362 "persist" "check_issue_persistence" )
jbe@331 5363 RETURNS "check_issue_persistence"
jbe@0 5364 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 5365 DECLARE
jbe@528 5366 "issue_row" "issue"%ROWTYPE;
jbe@528 5367 "last_calculated_v" "snapshot"."calculated"%TYPE;
jbe@528 5368 "policy_row" "policy"%ROWTYPE;
jbe@528 5369 "initiative_row" "initiative"%ROWTYPE;
jbe@528 5370 "state_v" "issue_state";
jbe@0 5371 BEGIN
jbe@333 5372 PERFORM "require_transaction_isolation"();
jbe@331 5373 IF "persist" ISNULL THEN
jbe@331 5374 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
jbe@331 5375 FOR UPDATE;
jbe@528 5376 SELECT "calculated" INTO "last_calculated_v"
jbe@528 5377 FROM "snapshot" JOIN "snapshot_issue"
jbe@528 5378 ON "snapshot"."id" = "snapshot_issue"."snapshot_id"
jbe@528 5379 WHERE "snapshot_issue"."issue_id" = "issue_id_p";
jbe@331 5380 IF "issue_row"."closed" NOTNULL THEN
jbe@331 5381 RETURN NULL;
jbe@0 5382 END IF;
jbe@331 5383 "persist"."state" := "issue_row"."state";
jbe@331 5384 IF
jbe@528 5385 ( "issue_row"."state" = 'admission' AND "last_calculated_v" >=
jbe@447 5386 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
jbe@331 5387 ( "issue_row"."state" = 'discussion' AND now() >=
jbe@331 5388 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
jbe@331 5389 ( "issue_row"."state" = 'verification' AND now() >=
jbe@331 5390 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
jbe@331 5391 ( "issue_row"."state" = 'voting' AND now() >=
jbe@331 5392 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
jbe@331 5393 THEN
jbe@331 5394 "persist"."phase_finished" := TRUE;
jbe@331 5395 ELSE
jbe@331 5396 "persist"."phase_finished" := FALSE;
jbe@0 5397 END IF;
jbe@0 5398 IF
jbe@24 5399 NOT EXISTS (
jbe@24 5400 -- all initiatives are revoked
jbe@24 5401 SELECT NULL FROM "initiative"
jbe@24 5402 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@24 5403 ) AND (
jbe@111 5404 -- and issue has not been accepted yet
jbe@331 5405 "persist"."state" = 'admission' OR
jbe@331 5406 -- or verification time has elapsed
jbe@331 5407 ( "persist"."state" = 'verification' AND
jbe@331 5408 "persist"."phase_finished" ) OR
jbe@331 5409 -- or no initiatives have been revoked lately
jbe@24 5410 NOT EXISTS (
jbe@24 5411 SELECT NULL FROM "initiative"
jbe@24 5412 WHERE "issue_id" = "issue_id_p"
jbe@24 5413 AND now() < "revoked" + "issue_row"."verification_time"
jbe@24 5414 )
jbe@24 5415 )
jbe@24 5416 THEN
jbe@331 5417 "persist"."issue_revoked" := TRUE;
jbe@331 5418 ELSE
jbe@331 5419 "persist"."issue_revoked" := FALSE;
jbe@24 5420 END IF;
jbe@331 5421 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
jbe@331 5422 UPDATE "issue" SET "phase_finished" = now()
jbe@331 5423 WHERE "id" = "issue_row"."id";
jbe@331 5424 RETURN "persist";
jbe@331 5425 ELSIF
jbe@331 5426 "persist"."state" IN ('admission', 'discussion', 'verification')
jbe@3 5427 THEN
jbe@331 5428 RETURN "persist";
jbe@331 5429 ELSE
jbe@331 5430 RETURN NULL;
jbe@322 5431 END IF;
jbe@0 5432 END IF;
jbe@331 5433 IF
jbe@331 5434 "persist"."state" IN ('admission', 'discussion', 'verification') AND
jbe@331 5435 coalesce("persist"."snapshot_created", FALSE) = FALSE
jbe@331 5436 THEN
jbe@528 5437 IF "persist"."state" != 'admission' THEN
jbe@528 5438 PERFORM "take_snapshot"("issue_id_p");
jbe@528 5439 PERFORM "finish_snapshot"("issue_id_p");
jbe@528 5440 END IF;
jbe@331 5441 "persist"."snapshot_created" = TRUE;
jbe@331 5442 IF "persist"."phase_finished" THEN
jbe@331 5443 IF "persist"."state" = 'admission' THEN
jbe@528 5444 UPDATE "issue" SET "admission_snapshot_id" = "latest_snapshot_id";
jbe@331 5445 ELSIF "persist"."state" = 'discussion' THEN
jbe@528 5446 UPDATE "issue" SET "half_freeze_snapshot_id" = "latest_snapshot_id";
jbe@331 5447 ELSIF "persist"."state" = 'verification' THEN
jbe@528 5448 UPDATE "issue" SET "full_freeze_snapshot_id" = "latest_snapshot_id";
jbe@336 5449 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@336 5450 SELECT * INTO "policy_row" FROM "policy"
jbe@336 5451 WHERE "id" = "issue_row"."policy_id";
jbe@336 5452 FOR "initiative_row" IN
jbe@336 5453 SELECT * FROM "initiative"
jbe@336 5454 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@336 5455 FOR UPDATE
jbe@336 5456 LOOP
jbe@336 5457 IF
jbe@336 5458 "initiative_row"."polling" OR (
jbe@336 5459 "initiative_row"."satisfied_supporter_count" > 0 AND
jbe@336 5460 "initiative_row"."satisfied_supporter_count" *
jbe@336 5461 "policy_row"."initiative_quorum_den" >=
jbe@336 5462 "issue_row"."population" * "policy_row"."initiative_quorum_num"
jbe@336 5463 )
jbe@336 5464 THEN
jbe@336 5465 UPDATE "initiative" SET "admitted" = TRUE
jbe@336 5466 WHERE "id" = "initiative_row"."id";
jbe@336 5467 ELSE
jbe@336 5468 UPDATE "initiative" SET "admitted" = FALSE
jbe@336 5469 WHERE "id" = "initiative_row"."id";
jbe@336 5470 END IF;
jbe@336 5471 END LOOP;
jbe@331 5472 END IF;
jbe@331 5473 END IF;
jbe@331 5474 RETURN "persist";
jbe@331 5475 END IF;
jbe@331 5476 IF
jbe@331 5477 "persist"."state" IN ('admission', 'discussion', 'verification') AND
jbe@331 5478 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
jbe@331 5479 THEN
jbe@331 5480 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
jbe@331 5481 "persist"."harmonic_weights_set" = TRUE;
jbe@332 5482 IF
jbe@332 5483 "persist"."phase_finished" OR
jbe@332 5484 "persist"."issue_revoked" OR
jbe@332 5485 "persist"."state" = 'admission'
jbe@332 5486 THEN
jbe@331 5487 RETURN "persist";
jbe@331 5488 ELSE
jbe@331 5489 RETURN NULL;
jbe@331 5490 END IF;
jbe@331 5491 END IF;
jbe@331 5492 IF "persist"."issue_revoked" THEN
jbe@331 5493 IF "persist"."state" = 'admission' THEN
jbe@331 5494 "state_v" := 'canceled_revoked_before_accepted';
jbe@331 5495 ELSIF "persist"."state" = 'discussion' THEN
jbe@331 5496 "state_v" := 'canceled_after_revocation_during_discussion';
jbe@331 5497 ELSIF "persist"."state" = 'verification' THEN
jbe@331 5498 "state_v" := 'canceled_after_revocation_during_verification';
jbe@331 5499 END IF;
jbe@331 5500 UPDATE "issue" SET
jbe@331 5501 "state" = "state_v",
jbe@331 5502 "closed" = "phase_finished",
jbe@331 5503 "phase_finished" = NULL
jbe@332 5504 WHERE "id" = "issue_id_p";
jbe@331 5505 RETURN NULL;
jbe@331 5506 END IF;
jbe@331 5507 IF "persist"."state" = 'admission' THEN
jbe@336 5508 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
jbe@336 5509 FOR UPDATE;
jbe@528 5510 IF "issue_row"."phase_finished" NOTNULL THEN
jbe@336 5511 UPDATE "issue" SET
jbe@336 5512 "state" = 'canceled_issue_not_accepted',
jbe@336 5513 "closed" = "phase_finished",
jbe@336 5514 "phase_finished" = NULL
jbe@336 5515 WHERE "id" = "issue_id_p";
jbe@336 5516 END IF;
jbe@331 5517 RETURN NULL;
jbe@331 5518 END IF;
jbe@332 5519 IF "persist"."phase_finished" THEN
jbe@443 5520 IF "persist"."state" = 'discussion' THEN
jbe@332 5521 UPDATE "issue" SET
jbe@332 5522 "state" = 'verification',
jbe@332 5523 "half_frozen" = "phase_finished",
jbe@332 5524 "phase_finished" = NULL
jbe@332 5525 WHERE "id" = "issue_id_p";
jbe@332 5526 RETURN NULL;
jbe@332 5527 END IF;
jbe@332 5528 IF "persist"."state" = 'verification' THEN
jbe@336 5529 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
jbe@336 5530 FOR UPDATE;
jbe@336 5531 SELECT * INTO "policy_row" FROM "policy"
jbe@336 5532 WHERE "id" = "issue_row"."policy_id";
jbe@336 5533 IF EXISTS (
jbe@336 5534 SELECT NULL FROM "initiative"
jbe@336 5535 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
jbe@336 5536 ) THEN
jbe@336 5537 UPDATE "issue" SET
jbe@343 5538 "state" = 'voting',
jbe@343 5539 "fully_frozen" = "phase_finished",
jbe@336 5540 "phase_finished" = NULL
jbe@336 5541 WHERE "id" = "issue_id_p";
jbe@336 5542 ELSE
jbe@336 5543 UPDATE "issue" SET
jbe@343 5544 "state" = 'canceled_no_initiative_admitted',
jbe@343 5545 "fully_frozen" = "phase_finished",
jbe@343 5546 "closed" = "phase_finished",
jbe@343 5547 "phase_finished" = NULL
jbe@336 5548 WHERE "id" = "issue_id_p";
jbe@336 5549 -- NOTE: The following DELETE statements have effect only when
jbe@336 5550 -- issue state has been manipulated
jbe@336 5551 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
jbe@336 5552 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
jbe@336 5553 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@336 5554 END IF;
jbe@332 5555 RETURN NULL;
jbe@332 5556 END IF;
jbe@332 5557 IF "persist"."state" = 'voting' THEN
jbe@332 5558 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
jbe@332 5559 PERFORM "close_voting"("issue_id_p");
jbe@332 5560 "persist"."closed_voting" = TRUE;
jbe@332 5561 RETURN "persist";
jbe@332 5562 END IF;
jbe@332 5563 PERFORM "calculate_ranks"("issue_id_p");
jbe@332 5564 RETURN NULL;
jbe@332 5565 END IF;
jbe@331 5566 END IF;
jbe@331 5567 RAISE WARNING 'should not happen';
jbe@331 5568 RETURN NULL;
jbe@0 5569 END;
jbe@0 5570 $$;
jbe@0 5571
jbe@0 5572 COMMENT ON FUNCTION "check_issue"
jbe@331 5573 ( "issue"."id"%TYPE,
jbe@331 5574 "check_issue_persistence" )
jbe@336 5575 IS 'Precalculate supporter counts etc. for a given issue, and check, if status change is required, and perform the status change when necessary; Function must be called multiple times with the previous result as second parameter, until the result is NULL (see source code of function "check_everything")';
jbe@0 5576
jbe@0 5577
jbe@0 5578 CREATE FUNCTION "check_everything"()
jbe@0 5579 RETURNS VOID
jbe@0 5580 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 5581 DECLARE
jbe@528 5582 "snapshot_id_v" "snapshot"."id"%TYPE;
jbe@528 5583 "issue_id_v" "issue"."id"%TYPE;
jbe@528 5584 "persist_v" "check_issue_persistence";
jbe@0 5585 BEGIN
jbe@333 5586 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
jbe@235 5587 DELETE FROM "expired_session";
jbe@184 5588 PERFORM "check_activity"();
jbe@4 5589 PERFORM "calculate_member_counts"();
jbe@528 5590 SELECT "take_snapshot"(NULL) INTO "snapshot_id_v";
jbe@528 5591 PERFORM "finish_snapshot"("issue_id") FROM "snapshot_issue"
jbe@528 5592 WHERE "snapshot_id" = "snapshot_id_v";
jbe@528 5593 LOOP
jbe@528 5594 EXIT WHEN "issue_admission"() = FALSE;
jbe@528 5595 END LOOP;
jbe@4 5596 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
jbe@331 5597 "persist_v" := NULL;
jbe@331 5598 LOOP
jbe@331 5599 "persist_v" := "check_issue"("issue_id_v", "persist_v");
jbe@331 5600 EXIT WHEN "persist_v" ISNULL;
jbe@331 5601 END LOOP;
jbe@0 5602 END LOOP;
jbe@0 5603 RETURN;
jbe@0 5604 END;
jbe@0 5605 $$;
jbe@0 5606
jbe@528 5607 COMMENT ON FUNCTION "check_everything"() IS 'Amongst other regular tasks, this function performs "check_issue" for every open issue. Use this function only for development and debugging purposes, as you may run into locking and/or serialization problems in productive environments.';
jbe@0 5608
jbe@0 5609
jbe@0 5610
jbe@59 5611 ----------------------
jbe@59 5612 -- Deletion of data --
jbe@59 5613 ----------------------
jbe@59 5614
jbe@59 5615
jbe@59 5616 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
jbe@59 5617 RETURNS VOID
jbe@59 5618 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@59 5619 BEGIN
jbe@385 5620 IF EXISTS (
jbe@385 5621 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
jbe@385 5622 ) THEN
jbe@385 5623 -- override protection triggers:
jbe@385 5624 INSERT INTO "temporary_transaction_data" ("key", "value")
jbe@385 5625 VALUES ('override_protection_triggers', TRUE::TEXT);
jbe@385 5626 -- clean data:
jbe@59 5627 DELETE FROM "delegating_voter"
jbe@59 5628 WHERE "issue_id" = "issue_id_p";
jbe@59 5629 DELETE FROM "direct_voter"
jbe@59 5630 WHERE "issue_id" = "issue_id_p";
jbe@59 5631 DELETE FROM "delegating_interest_snapshot"
jbe@59 5632 WHERE "issue_id" = "issue_id_p";
jbe@59 5633 DELETE FROM "direct_interest_snapshot"
jbe@59 5634 WHERE "issue_id" = "issue_id_p";
jbe@59 5635 DELETE FROM "delegating_population_snapshot"
jbe@59 5636 WHERE "issue_id" = "issue_id_p";
jbe@59 5637 DELETE FROM "direct_population_snapshot"
jbe@59 5638 WHERE "issue_id" = "issue_id_p";
jbe@113 5639 DELETE FROM "non_voter"
jbe@94 5640 WHERE "issue_id" = "issue_id_p";
jbe@59 5641 DELETE FROM "delegation"
jbe@59 5642 WHERE "issue_id" = "issue_id_p";
jbe@59 5643 DELETE FROM "supporter"
jbe@329 5644 USING "initiative" -- NOTE: due to missing index on issue_id
jbe@325 5645 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@325 5646 AND "supporter"."initiative_id" = "initiative_id";
jbe@385 5647 -- mark issue as cleaned:
jbe@385 5648 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
jbe@385 5649 -- finish overriding protection triggers (avoids garbage):
jbe@385 5650 DELETE FROM "temporary_transaction_data"
jbe@385 5651 WHERE "key" = 'override_protection_triggers';
jbe@59 5652 END IF;
jbe@59 5653 RETURN;
jbe@59 5654 END;
jbe@59 5655 $$;
jbe@59 5656
jbe@59 5657 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
jbe@8 5658
jbe@8 5659
jbe@54 5660 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
jbe@8 5661 RETURNS VOID
jbe@8 5662 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@8 5663 BEGIN
jbe@9 5664 UPDATE "member" SET
jbe@57 5665 "last_login" = NULL,
jbe@387 5666 "last_delegation_check" = NULL,
jbe@45 5667 "login" = NULL,
jbe@11 5668 "password" = NULL,
jbe@441 5669 "authority" = NULL,
jbe@441 5670 "authority_uid" = NULL,
jbe@441 5671 "authority_login" = NULL,
jbe@101 5672 "locked" = TRUE,
jbe@54 5673 "active" = FALSE,
jbe@11 5674 "notify_email" = NULL,
jbe@11 5675 "notify_email_unconfirmed" = NULL,
jbe@11 5676 "notify_email_secret" = NULL,
jbe@11 5677 "notify_email_secret_expiry" = NULL,
jbe@57 5678 "notify_email_lock_expiry" = NULL,
jbe@522 5679 "disable_notifications" = TRUE,
jbe@522 5680 "notification_counter" = DEFAULT,
jbe@522 5681 "notification_sample_size" = 0,
jbe@499 5682 "notification_dow" = NULL,
jbe@499 5683 "notification_hour" = NULL,
jbe@387 5684 "login_recovery_expiry" = NULL,
jbe@11 5685 "password_reset_secret" = NULL,
jbe@11 5686 "password_reset_secret_expiry" = NULL,
jbe@11 5687 "organizational_unit" = NULL,
jbe@11 5688 "internal_posts" = NULL,
jbe@11 5689 "realname" = NULL,
jbe@11 5690 "birthday" = NULL,
jbe@11 5691 "address" = NULL,
jbe@11 5692 "email" = NULL,
jbe@11 5693 "xmpp_address" = NULL,
jbe@11 5694 "website" = NULL,
jbe@11 5695 "phone" = NULL,
jbe@11 5696 "mobile_phone" = NULL,
jbe@11 5697 "profession" = NULL,
jbe@11 5698 "external_memberships" = NULL,
jbe@11 5699 "external_posts" = NULL,
jbe@45 5700 "statement" = NULL
jbe@45 5701 WHERE "id" = "member_id_p";
jbe@11 5702 -- "text_search_data" is updated by triggers
jbe@45 5703 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
jbe@45 5704 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
jbe@45 5705 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
jbe@45 5706 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
jbe@45 5707 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
jbe@113 5708 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
jbe@235 5709 DELETE FROM "session" WHERE "member_id" = "member_id_p";
jbe@45 5710 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
jbe@45 5711 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
jbe@113 5712 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
jbe@45 5713 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
jbe@45 5714 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
jbe@54 5715 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
jbe@54 5716 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
jbe@113 5717 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
jbe@57 5718 DELETE FROM "direct_voter" USING "issue"
jbe@57 5719 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@57 5720 AND "issue"."closed" ISNULL
jbe@57 5721 AND "member_id" = "member_id_p";
jbe@45 5722 RETURN;
jbe@45 5723 END;
jbe@45 5724 $$;
jbe@45 5725
jbe@57 5726 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 5727
jbe@45 5728
jbe@45 5729 CREATE FUNCTION "delete_private_data"()
jbe@45 5730 RETURNS VOID
jbe@45 5731 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@45 5732 BEGIN
jbe@385 5733 DELETE FROM "temporary_transaction_data";
jbe@226 5734 DELETE FROM "member" WHERE "activated" ISNULL;
jbe@50 5735 UPDATE "member" SET
jbe@206 5736 "invite_code" = NULL,
jbe@232 5737 "invite_code_expiry" = NULL,
jbe@228 5738 "admin_comment" = NULL,
jbe@57 5739 "last_login" = NULL,
jbe@387 5740 "last_delegation_check" = NULL,
jbe@50 5741 "login" = NULL,
jbe@50 5742 "password" = NULL,
jbe@441 5743 "authority" = NULL,
jbe@441 5744 "authority_uid" = NULL,
jbe@441 5745 "authority_login" = NULL,
jbe@238 5746 "lang" = NULL,
jbe@50 5747 "notify_email" = NULL,
jbe@50 5748 "notify_email_unconfirmed" = NULL,
jbe@50 5749 "notify_email_secret" = NULL,
jbe@50 5750 "notify_email_secret_expiry" = NULL,
jbe@57 5751 "notify_email_lock_expiry" = NULL,
jbe@522 5752 "disable_notifications" = TRUE,
jbe@522 5753 "notification_counter" = DEFAULT,
jbe@522 5754 "notification_sample_size" = 0,
jbe@499 5755 "notification_dow" = NULL,
jbe@499 5756 "notification_hour" = NULL,
jbe@387 5757 "login_recovery_expiry" = NULL,
jbe@50 5758 "password_reset_secret" = NULL,
jbe@50 5759 "password_reset_secret_expiry" = NULL,
jbe@50 5760 "organizational_unit" = NULL,
jbe@50 5761 "internal_posts" = NULL,
jbe@50 5762 "realname" = NULL,
jbe@50 5763 "birthday" = NULL,
jbe@50 5764 "address" = NULL,
jbe@50 5765 "email" = NULL,
jbe@50 5766 "xmpp_address" = NULL,
jbe@50 5767 "website" = NULL,
jbe@50 5768 "phone" = NULL,
jbe@50 5769 "mobile_phone" = NULL,
jbe@50 5770 "profession" = NULL,
jbe@50 5771 "external_memberships" = NULL,
jbe@50 5772 "external_posts" = NULL,
jbe@238 5773 "formatting_engine" = NULL,
jbe@50 5774 "statement" = NULL;
jbe@50 5775 -- "text_search_data" is updated by triggers
jbe@50 5776 DELETE FROM "setting";
jbe@50 5777 DELETE FROM "setting_map";
jbe@50 5778 DELETE FROM "member_relation_setting";
jbe@50 5779 DELETE FROM "member_image";
jbe@50 5780 DELETE FROM "contact";
jbe@113 5781 DELETE FROM "ignored_member";
jbe@235 5782 DELETE FROM "session";
jbe@50 5783 DELETE FROM "area_setting";
jbe@50 5784 DELETE FROM "issue_setting";
jbe@113 5785 DELETE FROM "ignored_initiative";
jbe@50 5786 DELETE FROM "initiative_setting";
jbe@50 5787 DELETE FROM "suggestion_setting";
jbe@113 5788 DELETE FROM "non_voter";
jbe@8 5789 DELETE FROM "direct_voter" USING "issue"
jbe@8 5790 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@8 5791 AND "issue"."closed" ISNULL;
jbe@8 5792 RETURN;
jbe@8 5793 END;
jbe@8 5794 $$;
jbe@8 5795
jbe@273 5796 COMMENT ON FUNCTION "delete_private_data"() IS 'Used by lf_export script. DO NOT USE on productive database, but only on a copy! This function deletes all data which should not be publicly available, and can be used to create a database dump for publication. See source code to see which data is deleted. If you need a different behaviour, copy this function and modify lf_export accordingly, to avoid data-leaks after updating.';
jbe@8 5797
jbe@8 5798
jbe@8 5799
jbe@0 5800 COMMIT;

Impressum / About Us