/* Copyright 2017-2019 Jan Dittberner Licensed under the Apache License, Version 2.0 (the "License"); you may not use this program except in compliance with the License. You may obtain a copy of the License at http://www.apache.org/licenses/LICENSE-2.0 Unless required by applicable law or agreed to in writing, software distributed under the License is distributed on an "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. See the License for the specific language governing permissions and limitations under the License. */ package main import ( "database/sql" "fmt" "github.com/jmoiron/sqlx" "github.com/rubenv/sql-migrate" "time" migrations "git.cacert.org/cacert-boardvoting/db" log "github.com/sirupsen/logrus" ) type sqlKey int const ( sqlLoadDecisions sqlKey = iota sqlLoadUnvotedDecisions sqlLoadDecisionByTag sqlLoadDecisionById sqlLoadVoteCountsForDecision sqlLoadVotesForDecision sqlLoadEnabledVoterByEmail sqlCountOlderThanDecision sqlCountOlderThanUnvotedDecision sqlCreateDecision sqlUpdateDecision sqlUpdateDecisionStatus sqlSelectClosableDecisions sqlGetNextPendingDecisionDue sqlGetReminderVoters sqlFindUnvotedDecisionsForVoter sqlGetEnabledVoterById sqlCreateVote sqlLoadVote sqlGetVotersForProxy ) var sqlStatements = map[sqlKey]string{ sqlLoadDecisions: ` SELECT decisions.id, decisions.tag, decisions.proponent, voters.name AS proposer, decisions.proposed, decisions.title, decisions.content, decisions.votetype, decisions.status, decisions.due, decisions.modified FROM decisions JOIN voters ON decisions.proponent=voters.id ORDER BY proposed DESC LIMIT 10 OFFSET 10 * $1`, sqlLoadUnvotedDecisions: ` SELECT decisions.id, decisions.tag, decisions.proponent, voters.name AS proposer, decisions.proposed, decisions.title, decisions.content, decisions.votetype, decisions.status, decisions.due, decisions.modified FROM decisions JOIN voters ON decisions.proponent=voters.id WHERE decisions.status = 0 AND decisions.id NOT IN (SELECT votes.decision FROM votes WHERE votes.voter = $1) ORDER BY proposed DESC LIMIT 10 OFFSET 10 * $2;`, sqlLoadDecisionByTag: ` SELECT decisions.id, decisions.tag, decisions.proponent, voters.name AS proposer, decisions.proposed, decisions.title, decisions.content, decisions.votetype, decisions.status, decisions.due, decisions.modified FROM decisions JOIN voters ON decisions.proponent=voters.id WHERE decisions.tag=$1;`, sqlLoadDecisionById: ` SELECT decisions.id, decisions.tag, decisions.proponent, decisions.proposed, decisions.title, decisions.content, decisions.votetype, decisions.status, decisions.due, decisions.modified FROM decisions WHERE decisions.id=$1;`, sqlLoadVoteCountsForDecision: ` SELECT vote, COUNT(vote) FROM votes WHERE decision=$1 GROUP BY vote`, sqlLoadVotesForDecision: ` SELECT votes.decision, votes.voter, voters.name, votes.vote, votes.voted, votes.notes FROM votes JOIN voters ON votes.voter=voters.id WHERE decision=$1`, sqlLoadEnabledVoterByEmail: ` SELECT voters.id, voters.name, voters.enabled, voters.reminder FROM voters JOIN emails ON voters.id=emails.voter WHERE emails.address=$1 AND voters.enabled=1`, sqlGetEnabledVoterById: ` SELECT id, name, enabled, reminder FROM voters WHERE enabled=1 AND id=$1`, sqlCountOlderThanDecision: ` SELECT COUNT(*) > 0 FROM decisions WHERE proposed < $1`, sqlCountOlderThanUnvotedDecision: ` SELECT COUNT(*) > 0 FROM decisions WHERE proposed < $1 AND status=0 AND id NOT IN (SELECT decision FROM votes WHERE votes.voter=$2)`, sqlCreateDecision: ` INSERT INTO decisions (proposed, proponent, title, content, votetype, status, due, modified,tag) VALUES ( :proposed, :proponent, :title, :content, :votetype, 0, :due, :proposed, 'm' || strftime('%Y%m%d', :proposed) || '.' || ( SELECT COUNT(*)+1 AS num FROM decisions WHERE proposed BETWEEN date(:proposed) AND date(:proposed, '1 day') ) )`, sqlUpdateDecision: ` UPDATE decisions SET proponent=:proponent, title=:title, content=:content, votetype=:votetype, due=:due, modified=:modified WHERE id=:id`, sqlUpdateDecisionStatus: ` UPDATE decisions SET status=:status, modified=:modified WHERE id=:id`, sqlSelectClosableDecisions: ` SELECT decisions.id, decisions.tag, decisions.proponent, decisions.proposed, decisions.title, decisions.content, decisions.votetype, decisions.status, decisions.due, decisions.modified FROM decisions WHERE decisions.status=0 AND :now > due`, sqlGetNextPendingDecisionDue: ` SELECT due FROM decisions WHERE status=0 ORDER BY due LIMIT 1`, sqlGetVotersForProxy: ` SELECT id, name, reminder FROM voters WHERE enabled=1 AND id != $1`, sqlGetReminderVoters: ` SELECT id, name, reminder FROM voters WHERE enabled=1 AND reminder!='' AND reminder IS NOT NULL`, sqlFindUnvotedDecisionsForVoter: ` SELECT tag, title, votetype, due FROM decisions WHERE status = 0 AND id NOT IN (SELECT decision FROM votes WHERE voter = $1) ORDER BY due ASC`, sqlCreateVote: ` INSERT OR REPLACE INTO votes (decision, voter, vote, voted, notes) VALUES (:decision, :voter, :vote, :voted, :notes)`, sqlLoadVote: ` SELECT decision, voter, vote, voted, notes FROM votes WHERE decision=$1 AND voter=$2`, } type VoteType uint8 type VoteStatus int8 type Decision struct { Id int64 Proposed time.Time ProponentId int64 `db:"proponent"` Title string Content string Quorum int Majority int Status VoteStatus Due time.Time Modified time.Time Tag string VoteType VoteType } type Voter struct { Id int64 Name string Enabled bool Reminder string // reminder email address } type VoteChoice int const ( voteAye = 1 voteNaye = -1 voteAbstain = 0 ) const ( voteTypeMotion = 0 voteTypeVeto = 1 ) func (v VoteType) String() string { switch v { case voteTypeMotion: return "motion" case voteTypeVeto: return "veto" default: return "unknown" } } func (v VoteType) QuorumAndMajority() (int, int) { switch v { case voteTypeMotion: return 3, 50 default: return 1, 99 } } func (v VoteChoice) String() string { switch v { case voteAye: return "aye" case voteNaye: return "naye" case voteAbstain: return "abstain" default: return "unknown" } } var VoteValues = map[string]VoteChoice{ "aye": voteAye, "naye": voteNaye, "abstain": voteAbstain, } var VoteChoices = map[int64]VoteChoice{ 1: voteAye, 0: voteAbstain, -1: voteNaye, } const ( voteStatusDeclined = -1 voteStatusPending = 0 voteStatusApproved = 1 voteStatusWithdrawn = -2 ) func (v VoteStatus) String() string { switch v { case voteStatusDeclined: return "declined" case voteStatusPending: return "pending" case voteStatusApproved: return "approved" case voteStatusWithdrawn: return "withdrawn" default: return "unknown" } } type Vote struct { DecisionId int64 `db:"decision"` VoterId int64 `db:"voter"` Vote VoteChoice Voted time.Time Notes string } type dbHandler struct { db *sqlx.DB } var db *dbHandler func NewDB(database *sql.DB) *dbHandler { handler := &dbHandler{db: sqlx.NewDb(database, "sqlite3")} _, err := migrate.Exec(database, "sqlite3", migrations.Migrations(), migrate.Up) if err != nil { log.Panicf("running database migration failed: %v", err) } failedStatements := make([]string, 0) for _, sqlStatement := range sqlStatements { var stmt *sqlx.Stmt stmt, err := handler.db.Preparex(sqlStatement) if err != nil { log.Errorf("error parsing statement %s: %s", sqlStatement, err) failedStatements = append(failedStatements, sqlStatement) } _ = stmt.Close() } if len(failedStatements) > 0 { log.Panicf("%d statements failed to prepare", len(failedStatements)) } return handler } func (d *dbHandler) Close() error { return d.db.Close() } func (d *dbHandler) getPreparedNamedStatement(statementKey sqlKey) *sqlx.NamedStmt { statement, err := d.db.PrepareNamed(sqlStatements[statementKey]) if err != nil { log.Panicf("Preparing statement failed: %v", err) } return statement } func (d *dbHandler) getPreparedStatement(statementKey sqlKey) *sqlx.Stmt { statement, err := d.db.Preparex(sqlStatements[statementKey]) if err != nil { log.Panicf("Preparing statement failed: %v", err) } return statement } func (v *Vote) Save() (err error) { insertVoteStmt := db.getPreparedNamedStatement(sqlCreateVote) defer func() { _ = insertVoteStmt.Close() }() if _, err = insertVoteStmt.Exec(v); err != nil { log.Errorf("saving vote failed: %v", err) return } getVoteStmt := db.getPreparedStatement(sqlLoadVote) defer func() { _ = getVoteStmt.Close() }() if err = getVoteStmt.Get(v, v.DecisionId, v.VoterId); err != nil { log.Errorf("getting inserted vote failed: %v", err) return } return } type VoteSums struct { Ayes int Nayes int Abstains int } func (v *VoteSums) VoteCount() int { return v.Ayes + v.Nayes + v.Abstains } func (v *VoteSums) TotalVotes() int { return v.Ayes + v.Nayes } func (v *VoteSums) Percent() int { totalVotes := v.TotalVotes() if totalVotes == 0 { return 0 } return v.Ayes * 100 / totalVotes } func (v *VoteSums) CalculateResult(quorum int, majority int) (status VoteStatus, reasoning string) { if v.VoteCount() < quorum { status, reasoning = voteStatusDeclined, fmt.Sprintf("Needed quorum of %d has not been reached.", quorum) } else if (v.Ayes / v.TotalVotes()) < (majority / 100) { status, reasoning = voteStatusDeclined, fmt.Sprintf("Needed majority of %d%% has not been reached.", majority) } else { status, reasoning = voteStatusApproved, "Quorum and majority have been reached" } return } type VoteForDisplay struct { Vote Name string } type DecisionForDisplay struct { Decision Proposer string `db:"proposer"` *VoteSums Votes []VoteForDisplay } func FindDecisionForDisplayByTag(tag string) (decision *DecisionForDisplay, err error) { decisionStmt := db.getPreparedStatement(sqlLoadDecisionByTag) defer func() { _ = decisionStmt.Close() }() decision = &DecisionForDisplay{} if err = decisionStmt.Get(decision, tag); err != nil { if err == sql.ErrNoRows { decision = nil err = nil return } else { log.Errorf("getting motion %s failed: %v", tag, err) return } } decision.VoteSums, err = decision.Decision.VoteSums() return } // FindDecisionsForDisplayOnPage loads a set of decisions from the database. // // This function uses OFFSET for pagination which is not a good idea for larger data sets. // // TODO: migrate to timestamp base pagination func FindDecisionsForDisplayOnPage(page int64, unvoted bool, voter *Voter) (decisions []*DecisionForDisplay, err error) { var decisionsStmt *sqlx.Stmt if unvoted && voter != nil { decisionsStmt = db.getPreparedStatement(sqlLoadUnvotedDecisions) } else { decisionsStmt = db.getPreparedStatement(sqlLoadDecisions) } defer func() { _ = decisionsStmt.Close() }() var rows *sqlx.Rows if unvoted && voter != nil { rows, err = decisionsStmt.Queryx(voter.Id, page-1) } else { rows, err = decisionsStmt.Queryx(page - 1) } if err != nil { log.Errorf("loading motions for page %d failed: %v", page, err) return } defer func() { _ = rows.Close() }() for rows.Next() { var d DecisionForDisplay if err = rows.StructScan(&d); err != nil { log.Errorf("loading motions for page %d failed: %v", page, err) return } d.VoteSums, err = d.Decision.VoteSums() if err != nil { return } decisions = append(decisions, &d) } return } func (d *Decision) VoteSums() (sums *VoteSums, err error) { votesStmt := db.getPreparedStatement(sqlLoadVoteCountsForDecision) defer func() { _ = votesStmt.Close() }() voteRows, err := votesStmt.Queryx(d.Id) if err != nil { log.Errorf("fetching vote sums for motion %s failed: %v", d.Tag, err) return } defer func() { _ = voteRows.Close() }() sums = &VoteSums{} for voteRows.Next() { var vote VoteChoice var count int if err = voteRows.Scan(&vote, &count); err != nil { log.Errorf("fetching vote sums for motion %s failed: %v", d.Tag, err) return } switch vote { case voteAye: sums.Ayes = count case voteNaye: sums.Nayes = count case voteAbstain: sums.Abstains = count } } return } func (d *DecisionForDisplay) LoadVotes() (err error) { votesStmt := db.getPreparedStatement(sqlLoadVotesForDecision) defer func() { _ = votesStmt.Close() }() err = votesStmt.Select(&d.Votes, d.Id) if err != nil { log.Errorf("selecting votes for motion %s failed: %v", d.Tag, err) return } return } func (d *Decision) OlderExists(unvoted bool, voter *Voter) (result bool, err error) { if unvoted && voter != nil { olderStmt := db.getPreparedStatement(sqlCountOlderThanUnvotedDecision) defer func() { _ = olderStmt.Close() }() if err = olderStmt.Get(&result, d.Proposed, voter.Id); err != nil { log.Errorf("finding older motions than %s failed: %v", d.Tag, err) return } } else { olderStmt := db.getPreparedStatement(sqlCountOlderThanDecision) defer func() { _ = olderStmt.Close() }() if err = olderStmt.Get(&result, d.Proposed); err != nil { log.Errorf("finding older motions than %s failed: %v", d.Tag, err) return } } return } func (d *Decision) Create() (err error) { insertDecisionStmt := db.getPreparedNamedStatement(sqlCreateDecision) defer func() { _ = insertDecisionStmt.Close() }() result, err := insertDecisionStmt.Exec(d) if err != nil { log.Errorf("creating motion failed: %v", err) return } lastInsertId, err := result.LastInsertId() if err != nil { log.Errorf("getting id of inserted motion failed: %v", err) return } rescheduleChannel <- JobIdCloseDecisions getDecisionStmt := db.getPreparedStatement(sqlLoadDecisionById) defer func() { _ = getDecisionStmt.Close() }() err = getDecisionStmt.Get(d, lastInsertId) if err != nil { log.Errorf("getting inserted motion failed: %v", err) return } return } func (d *Decision) LoadWithId() (err error) { getDecisionStmt := db.getPreparedStatement(sqlLoadDecisionById) defer func() { _ = getDecisionStmt.Close() }() err = getDecisionStmt.Get(d, d.Id) if err != nil { log.Errorf("loading updated motion failed: %v", err) return } return } func (d *Decision) Update() (err error) { updateDecisionStmt := db.getPreparedNamedStatement(sqlUpdateDecision) defer func() { _ = updateDecisionStmt.Close() }() result, err := updateDecisionStmt.Exec(d) if err != nil { log.Errorf("updating motion failed: %v", err) return } affectedRows, err := result.RowsAffected() if err != nil { log.Error("Problem determining the affected rows") return } else if affectedRows != 1 { log.Warningf("wrong number of affected rows: %d (1 expected)", affectedRows) } rescheduleChannel <- JobIdCloseDecisions err = d.LoadWithId() return } func (d *Decision) UpdateStatus() (err error) { updateStatusStmt := db.getPreparedNamedStatement(sqlUpdateDecisionStatus) defer func() { _ = updateStatusStmt.Close() }() result, err := updateStatusStmt.Exec(d) if err != nil { log.Errorf("setting motion status failed: %v", err) return } affectedRows, err := result.RowsAffected() if err != nil { log.Errorf("determining the affected rows failed: %v", err) return } else if affectedRows != 1 { log.Warningf("wrong number of affected rows: %d (1 expected)", affectedRows) } rescheduleChannel <- JobIdCloseDecisions err = d.LoadWithId() return } func (d *Decision) String() string { return fmt.Sprintf("%s %s (Id %d)", d.Tag, d.Title, d.Id) } func FindVoterByAddress(emailAddress string) (voter *Voter, err error) { findVoterStmt := db.getPreparedStatement(sqlLoadEnabledVoterByEmail) defer func() { _ = findVoterStmt.Close() }() voter = &Voter{} if err = findVoterStmt.Get(voter, emailAddress); err != nil { if err != sql.ErrNoRows { log.Errorf("getting voter for address %s failed: %v", emailAddress, err) } else { err = nil voter = nil } } return } func (d *Decision) Close() error { quorum, majority := d.VoteType.QuorumAndMajority() var voteSums *VoteSums var err error if voteSums, err = d.VoteSums(); err != nil { log.Errorf("getting vote sums failed: %v", err) return err } var reasoning string d.Status, reasoning = voteSums.CalculateResult(quorum, majority) closeDecisionStmt := db.getPreparedNamedStatement(sqlUpdateDecisionStatus) defer func() { _ = closeDecisionStmt.Close() }() result, err := closeDecisionStmt.Exec(d) if err != nil { log.Errorf("closing vote failed: %v", err) return err } if affectedRows, err := result.RowsAffected(); err != nil { log.Errorf("getting affected rows failed: %v", err) return err } else if affectedRows != 1 { log.Warningf("wrong number of affected rows: %d (1 expected)", affectedRows) } NotifyMailChannel <- NewNotificationClosedDecision(d, voteSums, reasoning) log.Infof("decision %s closed with result %s: reasoning %s", d.Tag, d.Status, reasoning) return nil } func CloseDecisions() (err error) { getClosableDecisionsStmt := db.getPreparedNamedStatement(sqlSelectClosableDecisions) defer func() { _ = getClosableDecisionsStmt.Close() }() decisions := make([]*Decision, 0) rows, err := getClosableDecisionsStmt.Queryx(struct{ Now time.Time }{time.Now().UTC()}) if err != nil { log.Errorf("fetching closable decisions failed: %v", err) return } defer func() { _ = rows.Close() }() for rows.Next() { decision := &Decision{} if err = rows.StructScan(decision); err != nil { log.Errorf("scanning row failed: %v", err) return } decisions = append(decisions, decision) } defer func() { _ = rows.Close() }() for _, decision := range decisions { log.Infof("found closable decision %s", decision.Tag) if err = decision.Close(); err != nil { log.Errorf("closing decision %s failed: %s", decision.Tag, err) return } } return } func GetNextPendingDecisionDue() (due *time.Time, err error) { getNextPendingDecisionDueStmt := db.getPreparedStatement(sqlGetNextPendingDecisionDue) defer func() { _ = getNextPendingDecisionDueStmt.Close() }() row := getNextPendingDecisionDueStmt.QueryRow() due = &time.Time{} if err = row.Scan(due); err != nil { if err == sql.ErrNoRows { log.Debug("No pending decisions") return nil, nil } log.Errorf("parsing result failed: %v", err) return nil, err } return } func GetReminderVoters() (voters *[]Voter, err error) { getReminderVotersStmt := db.getPreparedStatement(sqlGetReminderVoters) defer func() { _ = getReminderVotersStmt.Close() }() voterSlice := make([]Voter, 0) if err = getReminderVotersStmt.Select(&voterSlice); err != nil { log.Errorf("getting voters failed: %v", err) return } voters = &voterSlice return } func FindUnvotedDecisionsForVoter(voter *Voter) (decisions *[]Decision, err error) { findUnvotedDecisionsForVoterStmt := db.getPreparedStatement(sqlFindUnvotedDecisionsForVoter) defer func() { _ = findUnvotedDecisionsForVoterStmt.Close() }() decisionsSlice := make([]Decision, 0) if err = findUnvotedDecisionsForVoterStmt.Select(&decisionsSlice, voter.Id); err != nil { log.Errorf("getting unvoted decisions failed: %v", err) return } decisions = &decisionsSlice return } func GetVoterById(id int64) (voter *Voter, err error) { getVoterByIdStmt := db.getPreparedStatement(sqlGetEnabledVoterById) defer func() { _ = getVoterByIdStmt.Close() }() voter = &Voter{} if err = getVoterByIdStmt.Get(voter, id); err != nil { log.Errorf("getting voter failed: %v", err) return } return } func GetVotersForProxy(proxy *Voter) (voters *[]Voter, err error) { getVotersForProxyStmt := db.getPreparedStatement(sqlGetVotersForProxy) defer func() { _ = getVotersForProxyStmt.Close() }() votersSlice := make([]Voter, 0) if err = getVotersForProxyStmt.Select(&votersSlice, proxy.Id); err != nil { log.Errorf("Error getting voters for proxy failed: %v", err) return } voters = &votersSlice return }