|
| 1 | +CREATE TABLE IF NOT EXISTS ext_pe2020_dashboard_increment ( |
| 2 | + id INT AUTO_INCREMENT NOT NULL, |
| 3 | + PRIMARY KEY(id) |
| 4 | +) ENGINE=INNODB; |
| 5 | + |
| 6 | +CREATE TABLE IF NOT EXISTS ext_pe2020_dashboard_tally_sheet_status ( |
| 7 | + id INT AUTO_INCREMENT, |
| 8 | + incrementId INT NOT NULL, |
| 9 | + electionId INT NOT NULL, |
| 10 | + electoralDistrictId INT NOT NULL, |
| 11 | + pollingDivisionId INT, |
| 12 | + countingCentreId INT NOT NULL, |
| 13 | + templateName VARCHAR(20) NOT NULL, |
| 14 | + voteType VARCHAR(20) NOT NULL, |
| 15 | + partyId INT, |
| 16 | + verifiedTallySheetCount INT NOT NULL, |
| 17 | + emptyTallySheetCount INT NOT NULL, |
| 18 | + savedTallySheetCount INT NOT NULL, |
| 19 | + totalTallySheetCount INT NOT NULL, |
| 20 | + PRIMARY KEY(id) |
| 21 | +) ENGINE=INNODB; |
| 22 | + |
| 23 | +INSERT INTO ext_pe2020_dashboard_increment () VALUES(); |
| 24 | + |
| 25 | +SET @lastIncrementId = LAST_INSERT_ID(); |
| 26 | + |
| 27 | +INSERT INTO ext_pe2020_dashboard_tally_sheet_status (incrementId, electionId, electoralDistrictId, pollingDivisionId, |
| 28 | + countingCentreId, templateName, voteType, partyId, verifiedTallySheetCount,emptyTallySheetCount, |
| 29 | + savedTallySheetCount, totalTallySheetCount) |
| 30 | +SELECT |
| 31 | + @lastIncrementId, |
| 32 | + election.rootElectionId as electionId, |
| 33 | + areaMap.electoralDistrictId, |
| 34 | + areaMap.pollingDivisionId, |
| 35 | + areaMap.countingCentreId, |
| 36 | + template.templateName, |
| 37 | + election.voteType, |
| 38 | + metaData.metaDataValue as "partyId", |
| 39 | + COUNT(IF(workflowInstance.status = "Verified", tallySheet.tallySheetId, NULL)) AS verifiedTallySheetCount, |
| 40 | + COUNT(IF(workflowInstance.status = "Empty", tallySheet.tallySheetId, NULL)) AS emptyTallySheetCount, |
| 41 | + COUNT(IF(workflowInstance.status = "Saved", tallySheet.tallySheetId, NULL)) AS savedTallySheetCount, |
| 42 | + COUNT(tallySheet.tallySheetId) AS totalTallySheetCount |
| 43 | +FROM |
| 44 | + (SELECT |
| 45 | + country.areaId as countryId, |
| 46 | + electoralDistrict.areaId as electoralDistrictId, |
| 47 | + pollingDivision.areaId as pollingDivisionId, |
| 48 | + countingCentre.areaId as countingCentreId, |
| 49 | + "NonPostal" as voteType |
| 50 | + FROM |
| 51 | + area country, area electoralDistrict, area pollingDivision, area pollingDistrict, area pollingStation, |
| 52 | + area electionCommission, area districtCentre, area countingCentre, |
| 53 | + |
| 54 | + area_area country_electoralDistrict, |
| 55 | + area_area electoralDistrict_pollingDivision, |
| 56 | + area_area pollingDivision_pollingDistrict, |
| 57 | + area_area pollingDistrict_pollingStation, |
| 58 | + |
| 59 | + area_area electionCommission_districtCentre, |
| 60 | + area_area districtCentre_countingCentre, |
| 61 | + area_area countingCentre_pollingStation |
| 62 | + WHERE |
| 63 | + country_electoralDistrict.parentAreaId = country.areaId |
| 64 | + and country_electoralDistrict.childAreaId = electoralDistrict.areaId |
| 65 | + |
| 66 | + and electoralDistrict_pollingDivision.parentAreaId = electoralDistrict.areaId |
| 67 | + and electoralDistrict_pollingDivision.childAreaId = pollingDivision.areaId |
| 68 | + |
| 69 | + and pollingDivision_pollingDistrict.parentAreaId = pollingDivision.areaId |
| 70 | + and pollingDivision_pollingDistrict.childAreaId = pollingDistrict.areaId |
| 71 | + |
| 72 | + and pollingDistrict_pollingStation.parentAreaId = pollingDistrict.areaId |
| 73 | + and pollingDistrict_pollingStation.childAreaId = pollingStation.areaId |
| 74 | + |
| 75 | + and electionCommission_districtCentre.parentAreaId = electionCommission.areaId |
| 76 | + and electionCommission_districtCentre.childAreaId = districtCentre.areaId |
| 77 | + |
| 78 | + and districtCentre_countingCentre.parentAreaId = districtCentre.areaId |
| 79 | + and districtCentre_countingCentre.childAreaId = countingCentre.areaId |
| 80 | + |
| 81 | + and countingCentre_pollingStation.parentAreaId = countingCentre.areaId |
| 82 | + and countingCentre_pollingStation.childAreaId = pollingStation.areaId |
| 83 | + |
| 84 | + and country.areaType = "Country" and electoralDistrict.areaType = "ElectoralDistrict" |
| 85 | + and pollingDivision.areaType = "PollingDivision" and pollingDistrict.areaType = "PollingDistrict" |
| 86 | + and pollingStation.areaType = "PollingStation" and countingCentre.areaType = "CountingCentre" |
| 87 | + and districtCentre.areaType = "DistrictCentre" and electionCommission.areaType = "ElectionCommission" |
| 88 | + GROUP BY |
| 89 | + country.areaId, |
| 90 | + electoralDistrict.areaId, |
| 91 | + pollingDivision.areaId, |
| 92 | + countingCentre.areaId |
| 93 | + UNION SELECT |
| 94 | + country.areaId as countryId, |
| 95 | + electoralDistrict.areaId as electoralDistrictId, |
| 96 | + electoralDistrict.areaId as pollingDivisionId, |
| 97 | + countingCentre.areaId as countingCentreId, |
| 98 | + "Postal" AS voteType |
| 99 | + FROM |
| 100 | + area country, area electoralDistrict, |
| 101 | + area electionCommission, area districtCentre, area countingCentre, |
| 102 | + |
| 103 | + area_area country_electoralDistrict, |
| 104 | + area_area electoralDistrict_countingCentre, |
| 105 | + |
| 106 | + area_area electionCommission_districtCentre, |
| 107 | + area_area districtCentre_countingCentre |
| 108 | + WHERE |
| 109 | + country_electoralDistrict.parentAreaId = country.areaId |
| 110 | + and country_electoralDistrict.childAreaId = electoralDistrict.areaId |
| 111 | + |
| 112 | + and electoralDistrict_countingCentre.parentAreaId = electoralDistrict.areaId |
| 113 | + and electoralDistrict_countingCentre.childAreaId = countingCentre.areaId |
| 114 | + |
| 115 | + and electionCommission_districtCentre.parentAreaId = electionCommission.areaId |
| 116 | + and electionCommission_districtCentre.childAreaId = districtCentre.areaId |
| 117 | + |
| 118 | + and districtCentre_countingCentre.parentAreaId = districtCentre.areaId |
| 119 | + and districtCentre_countingCentre.childAreaId = countingCentre.areaId |
| 120 | + |
| 121 | + and country.areaType = "Country" and electoralDistrict.areaType = "ElectoralDistrict" |
| 122 | + and countingCentre.areaType = "CountingCentre" and districtCentre.areaType = "DistrictCentre" |
| 123 | + and electionCommission.areaType = "ElectionCommission" |
| 124 | + GROUP BY |
| 125 | + country.areaId, |
| 126 | + electoralDistrict.areaId, |
| 127 | + countingCentre.areaId |
| 128 | + ) AS areaMap, |
| 129 | + submission, election, template, workflowInstance, |
| 130 | + tallySheet left join metaData |
| 131 | + on metaData.metaId = tallySheet.metaId and metaData.metaDataKey = "partyId" |
| 132 | +WHERE |
| 133 | + submission.areaId = areaMap.countingCentreId |
| 134 | + and tallySheet.tallySheetId = submission.submissionId |
| 135 | + and election.electionId = submission.electionId |
| 136 | + and template.templateId = tallySheet.templateId |
| 137 | + and workflowInstance.workflowInstanceId = tallySheet.workflowInstanceId |
| 138 | +GROUP BY |
| 139 | + election.rootElectionId, |
| 140 | + areaMap.electoralDistrictId, |
| 141 | + areaMap.pollingDivisionId, |
| 142 | + areaMap.countingCentreId, |
| 143 | + template.templateName, |
| 144 | + election.voteType, |
| 145 | + metaData.metaDataValue; |
0 commit comments