From a5aef361a768082630992b77623f88da5c33270c Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?F=C3=A9lix=20Desmaretz?= Date: Fri, 5 Jul 2024 22:55:03 +0200 Subject: [PATCH] Add swing circo --- README.md | 15 +++++ analyse-duckdb.sql | 151 +++++++++++++++++++++++++++++++++++---------- 2 files changed, 132 insertions(+), 34 deletions(-) create mode 100644 README.md diff --git a/README.md b/README.md new file mode 100644 index 0000000..1715e12 --- /dev/null +++ b/README.md @@ -0,0 +1,15 @@ + +* 1. [TOC](#TOC) +* 2. [Introduction](#Introduction) + + +# Analyse Legislatives 2024 + +## 1. TOC + + + +## 2. Introduction \ No newline at end of file diff --git a/analyse-duckdb.sql b/analyse-duckdb.sql index 8456242..6ec0b7a 100644 --- a/analyse-duckdb.sql +++ b/analyse-duckdb.sql @@ -134,7 +134,11 @@ 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 + 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 ( @@ -155,6 +159,23 @@ SELECT projection / SUM(projection) OVER (PARTITION BY region, circo) AS projection FROM agg_projection +CREATE OR REPLACE TEMP TABLE projection_voix AS +SELECT + dc.region, + dc.circo, + rvd."to" AS orientation, + SUM(dc.voix * 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 +GROUP BY + dc.region, + dc.circo, + rvd."to" + ----- -- Circonscriptions dans lesquelles il y a 2 candidats de même orientation @@ -192,37 +213,32 @@ 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 + p.region, + p.circo, + FIRST(p.orientation) OVER (PARTITION BY p.region, p.circo ORDER BY p.projection DESC) AS elu, + ABS(p.projection - lag(p.projection) OVER (PARTITION BY p.region, p.circo)) AS diff, + ABS(pv.projection - lag(pv.projection) OVER (PARTITION BY p.region, p.circo)) AS diff_voix + FROM projection AS p + JOIN projection_voix AS pv + ON p.region = pv.region + AND p.circo = pv.circo + AND p.orientation = pv.orientation + ORDER BY p.region, p.circo +), 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 dc.*, d.elu, d.diff, d.diff_voix +FROM duels_circo AS dc +JOIN diff_null AS d +ON d.region = dc.region + AND d.circo = dc.circo +WHERE d.diff IS NOT NULL; + + +-- Nombre de duels avec un écart entre les candidats de 1, 2, 5, 10, 20 et 50 pourcents +WITH bucket_diff_orientation AS ( SELECT orientation_candidat_1 || ' v ' || orientation_candidat_2 AS duel, elu AS "projection élu", @@ -233,7 +249,7 @@ WITH duels_circo AS ( 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 + FROM difference GROUP BY orientation_candidat_1, orientation_candidat_2, @@ -241,10 +257,10 @@ WITH duels_circo AS ( ), ordered_bucket_diff_orientation AS ( SELECT *, - ROW_NUMBER() OVER (ORDER BY duel ASC, "projection élu" ASC) AS r + ROW_NUMBER() OVER (ORDER BY duel DESC, "projection élu" DESC) AS r FROM bucket_diff_orientation ), res AS ( - SELECT * + SELECT * FROM ordered_bucket_diff_orientation UNION ALL SELECT @@ -262,4 +278,71 @@ WITH duels_circo AS ( ) SELECT * EXCLUDE (r) FROM res -ORDER BY r DESC \ No newline at end of file +ORDER BY r DESC; + + +-- Pour les ecarts de moins de 5%, à combien de voix cela se joue ? +SELECT + orientation_candidat_1 || ' v ' || orientation_candidat_2 AS duel, + elu AS "projection élu", + round(min(diff_voix)) AS "min", + round(max(diff_voix)) AS "max", + round(mean(diff_voix)) AS "moyenne", + round(quantile_disc(diff_voix, 0.25)) AS "1er Quartile", + round(median(diff_voix)) AS "médianne", + round(quantile_disc(diff_voix, 0.75)) AS "3e Quartile", +FROM difference +WHERE diff < 0.05 +GROUP BY + orientation_candidat_1, + orientation_candidat_2, + elu +ORDER BY + duel, + "projection élu" + + +-- Les "swing" circos où la gauche est présente +SELECT * +FROM difference +WHERE orientation_candidat_1 = 'Gauche' + OR orientation_candidat_2 = 'Gauche' +ORDER BY diff + +-- Rank des "swing" circos analysés par Averroès +SELECT + circo_code AS 'Code Circo', + region AS 'Région', + circo AS 'Circo', + CASE WHEN diff < 0.01 THEN TRUE ELSE FALSE END AS '<1%', + CASE WHEN diff < 0.02 THEN TRUE ELSE FALSE END AS '<2%', + CASE WHEN diff < 0.05 THEN TRUE ELSE FALSE END AS '<5%', + CASE WHEN elu = 'Gauche' THEN TRUE ELSE FALSE END AS 'Gauche favorite ?' +FROM difference +WHERE circo_code IN ( + '0502', + '0703', + '1202', + '1601', + '2103', + '2404', + '3103', + '3704', + '3809', + '6302', + '6303', + '6406', + '6912', + '7701', + '7708', + '8002', + '8401', + '8602', + '8703', + '9404', + '9407', + '0402' +) +ORDER BY circo_code + +