Add bucketing des duels par différence de part de voix
parent
a9c3619988
commit
07b655fb54
|
|
@ -132,6 +132,29 @@ FROM cleaned_undecided AS cu
|
||||||
JOIN duels AS d
|
JOIN duels AS d
|
||||||
ON d.circo_code = cu.circo_code;
|
ON d.circo_code = cu.circo_code;
|
||||||
|
|
||||||
|
CREATE OR REPLACE TEMP TABLE projection AS
|
||||||
|
WITH report AS (
|
||||||
|
SELECT dc.region, dc.circo, rvd."to" AS orientation, dc.exprimes * rvd.quantity AS projection
|
||||||
|
FROM tour_2 AS dc
|
||||||
|
JOIN report_voix_duel AS rvd
|
||||||
|
ON (
|
||||||
|
dc.orientation_candidat_1 = rvd.candidat_1 AND dc.orientation_candidat_2 = rvd.candidat_2
|
||||||
|
OR dc.orientation_candidat_1 = rvd.candidat_2 AND dc.orientation_candidat_2 = rvd.candidat_1
|
||||||
|
) AND rvd."from" = dc.orientation
|
||||||
|
ORDER BY circo_code
|
||||||
|
), agg_projection AS (
|
||||||
|
SELECT region, circo, orientation, SUM(projection) AS projection
|
||||||
|
FROM report
|
||||||
|
GROUP BY region, circo, orientation
|
||||||
|
ORDER BY region, circo, orientation
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
region,
|
||||||
|
circo,
|
||||||
|
orientation,
|
||||||
|
projection / SUM(projection) OVER (PARTITION BY region, circo) AS projection
|
||||||
|
FROM agg_projection
|
||||||
|
|
||||||
-----
|
-----
|
||||||
|
|
||||||
-- Circonscriptions dans lesquelles il y a 2 candidats de même orientation
|
-- Circonscriptions dans lesquelles il y a 2 candidats de même orientation
|
||||||
|
|
@ -153,28 +176,90 @@ GROUP BY orientation_candidat_1, orientation_candidat_2
|
||||||
ORDER BY n DESC;
|
ORDER BY n DESC;
|
||||||
|
|
||||||
-- Après report de voix
|
-- Après report de voix
|
||||||
WITH report AS (
|
WITH ordered_projection AS (
|
||||||
SELECT dc.region, dc.circo, rvd."to" AS orientation, dc.exprimes * rvd.quantity AS projection
|
|
||||||
FROM tour_2 AS dc
|
|
||||||
JOIN report_voix_duel AS rvd
|
|
||||||
ON (
|
|
||||||
dc.orientation_candidat_1 = rvd.candidat_1 AND dc.orientation_candidat_2 = rvd.candidat_2
|
|
||||||
OR dc.orientation_candidat_1 = rvd.candidat_2 AND dc.orientation_candidat_2 = rvd.candidat_1
|
|
||||||
) AND rvd."from" = dc.orientation
|
|
||||||
ORDER BY circo_code
|
|
||||||
), agg_projection AS (
|
|
||||||
SELECT region, circo, orientation, sum(projection) AS projection
|
|
||||||
FROM report
|
|
||||||
GROUP BY region, circo, orientation
|
|
||||||
ORDER BY region, circo, orientation
|
|
||||||
), ordered_projection AS (
|
|
||||||
SELECT
|
SELECT
|
||||||
*,
|
*,
|
||||||
ROW_NUMBER() OVER (PARTITION BY region, circo ORDER BY projection DESC) AS pos
|
ROW_NUMBER() OVER (PARTITION BY region, circo ORDER BY projection DESC) AS pos
|
||||||
FROM agg_projection
|
FROM projection
|
||||||
)
|
)
|
||||||
SELECT orientation, count(*) AS n
|
SELECT orientation, count(*) AS n
|
||||||
FROM ordered_projection
|
FROM ordered_projection
|
||||||
WHERE pos = 1
|
WHERE pos = 1
|
||||||
GROUP BY orientation
|
GROUP BY orientation
|
||||||
ORDER BY n DESC;
|
ORDER BY n DESC;
|
||||||
|
|
||||||
|
|
||||||
|
-- Projection avec faible écart
|
||||||
|
CREATE OR REPLACE TEMP TABLE difference AS
|
||||||
|
WITH diff_null AS (
|
||||||
|
SELECT region, circo, ABS(projection - lag(projection) OVER (PARTITION BY region, circo)) AS diff
|
||||||
|
FROM projection
|
||||||
|
ORDER BY region, circo
|
||||||
|
)
|
||||||
|
SELECT *
|
||||||
|
FROM diff_null
|
||||||
|
WHERE diff IS NOT NULL;
|
||||||
|
|
||||||
|
|
||||||
|
WITH duels_circo AS (
|
||||||
|
SELECT DISTINCT circo_code, region, circo, orientation_candidat_1, orientation_candidat_2
|
||||||
|
FROM tour_2
|
||||||
|
), diff_null AS (
|
||||||
|
SELECT
|
||||||
|
region,
|
||||||
|
circo,
|
||||||
|
ABS(projection - lag(projection) OVER (PARTITION BY region, circo)) AS diff,
|
||||||
|
FIRST(orientation) OVER (PARTITION BY region, circo ORDER BY projection DESC) AS elu
|
||||||
|
FROM projection
|
||||||
|
ORDER BY region, circo
|
||||||
|
), diff AS (
|
||||||
|
SELECT *
|
||||||
|
FROM diff_null
|
||||||
|
WHERE diff IS NOT NULL
|
||||||
|
), diff_orientation AS (
|
||||||
|
SELECT dc.*, d.diff, d.elu
|
||||||
|
FROM duels_circo AS dc
|
||||||
|
JOIN diff AS d
|
||||||
|
ON d.region = dc.region
|
||||||
|
AND d.circo = dc.circo
|
||||||
|
), bucket_diff_orientation AS (
|
||||||
|
SELECT
|
||||||
|
orientation_candidat_1 || ' v ' || orientation_candidat_2 AS duel,
|
||||||
|
elu AS "projection élu",
|
||||||
|
SUM(CASE WHEN diff < 0.01 THEN 1 ELSE 0 END) AS "1%",
|
||||||
|
SUM(CASE WHEN diff < 0.02 THEN 1 ELSE 0 END) AS "2%",
|
||||||
|
SUM(CASE WHEN diff < 0.05 THEN 1 ELSE 0 END) AS "5%",
|
||||||
|
SUM(CASE WHEN diff < 0.10 THEN 1 ELSE 0 END) AS "10%",
|
||||||
|
SUM(CASE WHEN diff < 0.20 THEN 1 ELSE 0 END) AS "20%",
|
||||||
|
SUM(CASE WHEN diff < 0.50 THEN 1 ELSE 0 END) AS "50%",
|
||||||
|
COUNT(*) AS total
|
||||||
|
FROM diff_orientation
|
||||||
|
GROUP BY
|
||||||
|
orientation_candidat_1,
|
||||||
|
orientation_candidat_2,
|
||||||
|
elu
|
||||||
|
), ordered_bucket_diff_orientation AS (
|
||||||
|
SELECT
|
||||||
|
*,
|
||||||
|
ROW_NUMBER() OVER (ORDER BY duel ASC, "projection élu" ASC) AS r
|
||||||
|
FROM bucket_diff_orientation
|
||||||
|
), res AS (
|
||||||
|
SELECT *
|
||||||
|
FROM ordered_bucket_diff_orientation
|
||||||
|
UNION ALL
|
||||||
|
SELECT
|
||||||
|
'TOTAL' AS duel,
|
||||||
|
'' AS "projection élu",
|
||||||
|
SUM("1%") AS "1%",
|
||||||
|
SUM("2%") AS "3%",
|
||||||
|
SUM("5%") AS "5%",
|
||||||
|
SUM("10%") AS "10%",
|
||||||
|
SUM("20%") AS "30%",
|
||||||
|
SUM("50%") AS "50%",
|
||||||
|
SUM(total) AS total,
|
||||||
|
0 AS r
|
||||||
|
FROM ordered_bucket_diff_orientation
|
||||||
|
)
|
||||||
|
SELECT * EXCLUDE (r)
|
||||||
|
FROM res
|
||||||
|
ORDER BY r DESC
|
||||||
Loading…
Reference in New Issue