package main import ( "database/sql" "github.com/jmoiron/sqlx" "time" ) type sqlKey int const ( sqlLoadDecisions sqlKey = iota sqlLoadUnvotedDecisions sqlLoadDecisionByTag sqlLoadDecisionById sqlLoadVoteCountsForDecision sqlLoadVotesForDecision sqlLoadEnabledVoterByEmail sqlCountOlderThanDecision sqlCountOlderThanUnvotedDecision sqlCreateDecision ) 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`, 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') ) )`, } var db *sqlx.DB func init() { for _, sqlStatement := range sqlStatements { var stmt *sqlx.Stmt stmt, err := db.Preparex(sqlStatement) if err != nil { logger.Fatalf("ERROR parsing statement %s: %s", sqlStatement, err) } stmt.Close() } } type VoteType uint8 type VoteStatus int8 type Decision struct { Id int Proposed time.Time ProponentId int `db:"proponent"` Title string Content string Quorum int Majority int Status VoteStatus Due time.Time Modified time.Time Tag string VoteType VoteType } type Email struct { VoterId int `db:"voter"` Address string } type Voter struct { Id int Name string Enabled bool Reminder string // reminder email address } type VoteChoice int type Vote struct { DecisionId int `db:"decision"` VoterId int `db:"voter"` Vote VoteChoice Voted time.Time Notes string } 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" } } 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 VoteSums struct { Ayes int Nayes int Abstains int } func (v *VoteSums) VoteCount() int { return v.Ayes + v.Nayes + v.Abstains } 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, err := db.Preparex(sqlStatements[sqlLoadDecisionByTag]) if err != nil { logger.Println("Error preparing statement:", err) return } defer decisionStmt.Close() decision = &DecisionForDisplay{} if err = decisionStmt.Get(decision, tag); err != nil { if err == sql.ErrNoRows { decision = nil err = nil } else { logger.Printf("Error getting motion %s: %v\n", tag, err) } } 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, err = db.Preparex(sqlStatements[sqlLoadUnvotedDecisions]) } else { decisionsStmt, err = db.Preparex(sqlStatements[sqlLoadDecisions]) } if err != nil { logger.Println("Error preparing statement:", err) return } defer 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 { logger.Printf("Error loading motions for page %d: %v\n", page, err) return } defer rows.Close() for rows.Next() { var d DecisionForDisplay if err = rows.StructScan(&d); err != nil { logger.Printf("Error loading motions for page %d: %v\n", 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, err := db.Preparex(sqlStatements[sqlLoadVoteCountsForDecision]) if err != nil { logger.Println("Error preparing statement:", err) return } defer votesStmt.Close() voteRows, err := votesStmt.Queryx(d.Id) if err != nil { logger.Printf("Error fetching vote sums for motion %s: %v\n", d.Tag, err) return } defer voteRows.Close() sums = &VoteSums{} for voteRows.Next() { var vote VoteChoice var count int if err = voteRows.Scan(&vote, &count); err != nil { logger.Printf("Error fetching vote sums for motion %s: %v\n", 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, err := db.Preparex(sqlStatements[sqlLoadVotesForDecision]) if err != nil { logger.Println("Error preparing statement:", err) return } defer votesStmt.Close() err = votesStmt.Select(&d.Votes, d.Id) if err != nil { logger.Printf("Error selecting votes for motion %s: %v\n", d.Tag, err) } return } func (d *Decision) OlderExists(unvoted bool, voter *Voter) (result bool, err error) { var olderStmt *sqlx.Stmt if unvoted && voter != nil { olderStmt, err = db.Preparex(sqlStatements[sqlCountOlderThanUnvotedDecision]) } else { olderStmt, err = db.Preparex(sqlStatements[sqlCountOlderThanDecision]) } if err != nil { logger.Println("Error preparing statement:", err) return } defer olderStmt.Close() if unvoted && voter != nil { if err = olderStmt.Get(&result, d.Proposed, voter.Id); err != nil { logger.Printf("Error finding older motions than %s: %v\n", d.Tag, err) } } else { if err = olderStmt.Get(&result, d.Proposed); err != nil { logger.Printf("Error finding older motions than %s: %v\n", d.Tag, err) } } return } func (d *Decision) Save() (err error) { insertDecisionStmt, err := db.PrepareNamed(sqlStatements[sqlCreateDecision]) if err != nil { logger.Println("Error preparing statement:", err) return } defer insertDecisionStmt.Close() result, err := insertDecisionStmt.Exec(d) if err != nil { logger.Println("Error creating motion:", err) return } lastInsertId, err := result.LastInsertId() if err != nil { logger.Println("Error getting id of inserted motion:", err) } logger.Println("DEBUG new motion has id", lastInsertId) getDecisionStmt, err := db.Preparex(sqlStatements[sqlLoadDecisionById]) if err != nil { logger.Println("Error preparing statement:", err) return } defer getDecisionStmt.Close() err = getDecisionStmt.Get(d, lastInsertId) if err != nil { logger.Println("Error getting inserted motion:", err) } return } func FindVoterByAddress(emailAddress string) (voter *Voter, err error) { findVoterStmt, err := db.Preparex(sqlStatements[sqlLoadEnabledVoterByEmail]) if err != nil { logger.Println("Error preparing statement:", err) return } defer findVoterStmt.Close() voter = &Voter{} if err = findVoterStmt.Get(voter, emailAddress); err != nil { if err != sql.ErrNoRows { logger.Printf("Error getting voter for address %s: %v\n", emailAddress, err) } else { err = nil voter = nil } } return }