/* Copyright 2017-2022 CAcert Inc. SPDX-License-Identifier: Apache-2.0 Licensed under the Apache License, Version 2.0 (the "License"); you may not use this file 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 models import ( "context" "database/sql" "database/sql/driver" "errors" "fmt" "strings" "time" "github.com/jmoiron/sqlx" ) type VoteType struct { label string id uint8 } var ( VoteTypeMotion = &VoteType{label: "motion", id: 0} VoteTypeVeto = &VoteType{label: "veto", id: 1} ) func (v *VoteType) String() string { return v.label } func VoteTypeFromString(label string) (*VoteType, error) { for _, vt := range []*VoteType{VoteTypeMotion, VoteTypeVeto} { if strings.EqualFold(vt.label, label) { return vt, nil } } return nil, fmt.Errorf("unknown vote type %s", label) } func VoteTypeFromInt(id int64) (*VoteType, error) { for _, vt := range []*VoteType{VoteTypeMotion, VoteTypeVeto} { if int64(vt.id) == id { return vt, nil } } return nil, fmt.Errorf("unknown vote type id %d", id) } func (v *VoteType) Scan(src any) error { value, ok := src.(int64) if !ok { return fmt.Errorf("could not cast %v of %T to uint8", src, src) } vt, err := VoteTypeFromInt(value) if err != nil { return err } *v = *vt return nil } func (v *VoteType) Value() (driver.Value, error) { return int64(v.id), nil } func (v *VoteType) QuorumAndMajority() (int, float32) { const ( majorityDefault = 0.99 majorityMotion = 0.50 quorumDefault = 1 quorumMotion = 3 ) if v == VoteTypeMotion { return quorumMotion, majorityMotion } return quorumDefault, majorityDefault } type VoteStatus struct { Label string ID int8 } var ( voteStatusDeclined = &VoteStatus{Label: "declined", ID: -1} voteStatusPending = &VoteStatus{Label: "pending", ID: 0} voteStatusApproved = &VoteStatus{Label: "approved", ID: 1} voteStatusWithdrawn = &VoteStatus{Label: "withdrawn", ID: -2} ) func VoteStatusFromInt(id int64) (*VoteStatus, error) { for _, vs := range []*VoteStatus{voteStatusPending, voteStatusApproved, voteStatusWithdrawn, voteStatusDeclined} { if int64(vs.ID) == id { return vs, nil } } return nil, fmt.Errorf("unknown vote status id %d", id) } func (v *VoteStatus) String() string { return v.Label } func (v *VoteStatus) Scan(src any) error { value, ok := src.(int64) if !ok { return fmt.Errorf("could not cast %v of %T to uint8", src, src) } vs, err := VoteStatusFromInt(value) if err != nil { return err } *v = *vs return nil } func (v *VoteStatus) Value() (driver.Value, error) { return int64(v.ID), nil } type VoteChoice struct { Label string ID int8 } var ( VoteAye = &VoteChoice{Label: "aye", ID: 1} VoteNaye = &VoteChoice{Label: "naye", ID: -1} VoteAbstain = &VoteChoice{Label: "abstain", ID: 0} ) func VoteChoiceFromString(label string) (*VoteChoice, error) { for _, vc := range []*VoteChoice{VoteAye, VoteNaye, VoteAbstain} { if strings.EqualFold(vc.Label, label) { return vc, nil } } return nil, fmt.Errorf("unknown vote choice %s", label) } func VoteChoiceFromInt(id int64) (*VoteChoice, error) { for _, vc := range []*VoteChoice{VoteAye, VoteNaye, VoteAbstain} { if int64(vc.ID) == id { return vc, nil } } return nil, fmt.Errorf("unknown vote type id %d", id) } func (v *VoteChoice) String() string { return v.Label } func (v *VoteChoice) Scan(src any) error { value, ok := src.(int64) if !ok { return fmt.Errorf("could not cast %v of %T to uint8", src, src) } vc, err := VoteChoiceFromInt(value) if err != nil { return err } *v = *vc return nil } func (v *VoteChoice) Value() (driver.Value, error) { return int64(v.ID), nil } func (v *VoteChoice) Equal(other *VoteChoice) bool { return v.ID == other.ID } type VoteSums struct { Ayes, Nayes, 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 float32) (*VoteStatus, string) { if v.VoteCount() < quorum { return voteStatusDeclined, fmt.Sprintf("Needed quorum of %d has not been reached.", quorum) } if (float32(v.Ayes) / float32(v.TotalVotes())) < majority { return voteStatusDeclined, fmt.Sprintf("Needed majority of %0.2f%% has not been reached.", majority) } return voteStatusApproved, "Quorum and majority have been reached" } type Motion struct { ID int64 `db:"id"` Proposed time.Time `db:"proposed"` Proponent int64 `db:"proponent"` Proposer string `db:"proposer"` Title string `db:"title"` Content string `db:"content"` Status *VoteStatus `db:"status"` Due time.Time `db:"due"` Modified time.Time `db:"modified"` Tag string `db:"tag"` Type *VoteType `db:"votetype"` Sums *VoteSums `db:"-"` Votes []*Vote `db:"-"` Reasoning string `db:"-"` } type MotionModel struct { DB *sqlx.DB } // Create a new decision. func (m *MotionModel) Create( ctx context.Context, proponent *User, voteType *VoteType, title, content string, proposed, due time.Time, ) (int64, error) { d := &Motion{ Proposed: proposed.UTC(), Proponent: proponent.ID, Title: title, Content: content, Due: due.UTC(), Type: voteType, Status: voteStatusPending, } result, err := m.DB.NamedExecContext( ctx, `INSERT INTO decisions (proposed, proponent, title, content, votetype, status, due, modified, tag) VALUES (:proposed, :proponent, :title, :content, :votetype, :status, :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') ))`, d, ) if err != nil { return 0, fmt.Errorf("creating motion failed: %w", err) } id, err := result.LastInsertId() if err != nil { return 0, fmt.Errorf("could not get inserted decision id: %w", err) } return id, nil } func (m *MotionModel) CloseDecisions(ctx context.Context) ([]*Motion, error) { tx, err := m.DB.BeginTxx(ctx, nil) if err != nil { return nil, fmt.Errorf(errCouldNotStartTransaction, err) } defer func(tx *sqlx.Tx) { _ = tx.Rollback() }(tx) rows, err := tx.NamedQuery(` 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`, struct{ Now time.Time }{Now: time.Now().UTC()}) if err != nil { return nil, fmt.Errorf("fetching closable decisions failed: %w", err) } defer func(rows *sqlx.Rows) { _ = rows.Close() }(rows) decisions := make([]*Motion, 0) for rows.Next() { decision := &Motion{} if err = rows.StructScan(decision); err != nil { return nil, fmt.Errorf(errCouldNotScanResult, err) } if rows.Err() != nil { return nil, fmt.Errorf("row error: %w", err) } decisions = append(decisions, decision) } results := make([]*Motion, 0, len(decisions)) var decisionResult *Motion for _, decision := range decisions { if decisionResult, err = closeDecision(ctx, tx, decision); err != nil { return nil, fmt.Errorf("closing decision %s failed: %w", decision.Tag, err) } results = append(results, decisionResult) } if err = tx.Commit(); err != nil { return nil, fmt.Errorf(errCouldNotCommitTransaction, err) } return results, nil } func closeDecision(ctx context.Context, tx *sqlx.Tx, d *Motion) (*Motion, error) { quorum, majority := d.Type.QuorumAndMajority() var ( voteSums *VoteSums err error reasoning string ) // TODO: implement prefetching in CloseDecisions if voteSums, err = sumsForDecision(ctx, tx, d); err != nil { return nil, fmt.Errorf("getting vote sums failed: %w", err) } d.Status, reasoning = voteSums.CalculateResult(quorum, majority) result, err := tx.NamedExecContext( ctx, `UPDATE decisions SET status=:status, modified=CURRENT_TIMESTAMP WHERE id=:id`, d, ) if err != nil { return nil, fmt.Errorf(errCouldNotExecuteQuery, err) } affectedRows, err := result.RowsAffected() if err != nil { return nil, fmt.Errorf("could not get affected rows count: %w", err) } if affectedRows != 1 { return nil, fmt.Errorf("unexpected number of rows %d instead of 1", affectedRows) } d.Sums = voteSums d.Reasoning = reasoning return d, nil } func (m *MotionModel) UnvotedForVoter(ctx context.Context, voter *User) ([]*Motion, error) { // TODO: implement more efficient variant that fetches unvoted votes for a slice of voters rows, err := m.DB.QueryxContext( ctx, `SELECT decisions.* FROM decisions WHERE due < ? AND status=? AND NOT EXISTS(SELECT * FROM votes WHERE decision = decisions.id AND voter = ?)`, time.Now().UTC(), voteStatusPending, voter.ID) if err != nil { return nil, fmt.Errorf(errCouldNotExecuteQuery, err) } defer func(rows *sqlx.Rows) { _ = rows.Close() }(rows) result := make([]*Motion, 0) for rows.Next() { if err := rows.Err(); err != nil { return nil, fmt.Errorf(errCouldNotFetchRow, err) } var motion Motion if err := rows.StructScan(&motion); err != nil { return nil, fmt.Errorf(errCouldNotScanResult, err) } result = append(result, &motion) } return result, nil } func sumsForDecision(ctx context.Context, tx *sqlx.Tx, d *Motion) (*VoteSums, error) { voteRows, err := tx.QueryxContext( ctx, `SELECT vote, COUNT(vote) FROM votes WHERE decision=$1 GROUP BY vote`, d.ID, ) if err != nil { return nil, fmt.Errorf("fetching vote sums for motion %s failed: %w", d.Tag, err) } defer func(voteRows *sqlx.Rows) { _ = voteRows.Close() }(voteRows) sums := &VoteSums{} for voteRows.Next() { var ( vote *VoteChoice count int ) if err = voteRows.Err(); err != nil { return nil, fmt.Errorf("could not fetch vote sums for motion %s: %w", d.Tag, err) } if err = voteRows.Scan(&vote, &count); err != nil { return nil, fmt.Errorf("could not parse row for vote sums of motion %s: %w", d.Tag, err) } switch vote { case VoteAye: sums.Ayes = count case VoteNaye: sums.Nayes = count case VoteAbstain: sums.Abstains = count } } return sums, nil } func (m *MotionModel) NextPendingDue(ctx context.Context) (*time.Time, error) { row := m.DB.QueryRowContext( ctx, `SELECT due FROM decisions WHERE status=0 ORDER BY due LIMIT 1`, nil, ) if row == nil { return nil, errors.New("no row returned") } if err := row.Err(); err != nil { return nil, fmt.Errorf("could not retrieve row for next pending decision: %w", err) } var due time.Time if err := row.Scan(&due); err != nil { if errors.Is(err, sql.ErrNoRows) { return nil, nil } return nil, fmt.Errorf("parsing result failed: %w", err) } return &due, nil } type MotionListOptions struct { Limit int UnvotedOnly bool Before, After *time.Time VoterID int64 } func (m *MotionModel) TimestampRange(ctx context.Context, options *MotionListOptions) (*time.Time, *time.Time, error) { var row *sqlx.Row if options.UnvotedOnly { row = m.DB.QueryRowxContext( ctx, `SELECT MIN(proposed), MAX(proposed) FROM decisions WHERE due >= ? AND NOT EXISTS(SELECT * FROM votes WHERE decision = decisions.id AND voter = ?)`, time.Now().UTC(), options.VoterID, ) } else { row = m.DB.QueryRowxContext( ctx, `SELECT MIN(proposed), MAX(proposed) FROM decisions`, ) } if err := row.Err(); err != nil { return nil, nil, fmt.Errorf("could not query for motion timestamps: %w", err) } var ( first, last sql.NullString firstTs, lastTs *time.Time err error ) if err := row.Scan(&first, &last); err != nil { return nil, nil, fmt.Errorf("could not scan timestamps: %w", err) } if !first.Valid || !last.Valid { return nil, nil, nil } if firstTs, err = parseSqlite3TimeStamp(first.String); err != nil { return nil, nil, err } if lastTs, err = parseSqlite3TimeStamp(last.String); err != nil { return nil, nil, err } return firstTs, lastTs, nil } func (m *MotionModel) List(ctx context.Context, options *MotionListOptions) ([]*Motion, error) { var ( rows *sqlx.Rows err error ) switch { case options.Before != nil: rows, err = m.rowsBefore(ctx, options) case options.After != nil: rows, err = m.rowsAfter(ctx, options) default: rows, err = m.rowsFirst(ctx, options) } if err != nil { return nil, err } defer func(rows *sqlx.Rows) { _ = rows.Close() }(rows) motions := make([]*Motion, 0, options.Limit) for rows.Next() { var decision Motion if err = rows.Err(); err != nil { return nil, fmt.Errorf(errCouldNotFetchRow, err) } if err = rows.StructScan(&decision); err != nil { return nil, fmt.Errorf(errCouldNotScanResult, err) } motions = append(motions, &decision) } if len(motions) > 0 { err = m.FillVoteSums(ctx, motions) if err != nil { return nil, err } } return motions, nil } func (m *MotionModel) FillVoteSums(ctx context.Context, decisions []*Motion) error { decisionIds := make([]int64, len(decisions)) decisionMap := make(map[int64]*Motion, len(decisions)) for idx, decision := range decisions { decision.Sums = &VoteSums{} decisionIds[idx] = decision.ID decisionMap[decision.ID] = decision } query, args, err := sqlx.In( `SELECT v.decision, v.vote, COUNT(*) FROM votes v WHERE v.decision IN (?) GROUP BY v.decision, v.vote`, decisionIds, ) if err != nil { return fmt.Errorf("could not create IN query: %w", err) } rows, err := m.DB.QueryContext(ctx, query, args...) if err != nil { return fmt.Errorf(errCouldNotExecuteQuery, err) } defer func(rows *sql.Rows) { _ = rows.Close() }(rows) for rows.Next() { if err = rows.Err(); err != nil { return fmt.Errorf(errCouldNotFetchRow, err) } var ( decisionID int64 vote *VoteChoice count int ) err = rows.Scan(&decisionID, &vote, &count) if err != nil { return fmt.Errorf(errCouldNotScanResult, err) } switch { case vote.Equal(VoteAye): decisionMap[decisionID].Sums.Ayes = count case vote.Equal(VoteNaye): decisionMap[decisionID].Sums.Nayes = count case vote.Equal(VoteAbstain): decisionMap[decisionID].Sums.Abstains = count } } return nil } func (m *MotionModel) rowsBefore(ctx context.Context, options *MotionListOptions) (*sqlx.Rows, error) { // TODO: implement variant for options.UnvotedOnly rows, err := m.DB.QueryxContext( ctx, `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.proposed < $1 ORDER BY proposed DESC LIMIT $2`, options.Before, options.Limit, ) if err != nil { return nil, fmt.Errorf("could not query motions before %s: %w", options.Before, err) } return rows, nil } func (m *MotionModel) rowsAfter(ctx context.Context, options *MotionListOptions) (*sqlx.Rows, error) { // TODO: implement variant for options.UnvotedOnly rows, err := m.DB.QueryxContext( ctx, `WITH display_decision AS (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.proposed > $1 ORDER BY proposed LIMIT $2) SELECT * FROM display_decision ORDER BY proposed DESC`, options.After, options.Limit, ) if err != nil { return nil, fmt.Errorf("could not query motions after %s: %w", options.After, err) } return rows, nil } func (m *MotionModel) rowsFirst(ctx context.Context, options *MotionListOptions) (*sqlx.Rows, error) { var ( rows *sqlx.Rows err error ) if options.UnvotedOnly { rows, err = m.DB.QueryxContext( ctx, `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 status=? AND due >= ? AND NOT EXISTS(SELECT * FROM votes WHERE decision = decisions.id AND voter = ?) ORDER BY decisions.proposed DESC LIMIT ?`, voteStatusPending, time.Now().UTC(), options.VoterID, options.Limit, ) } else { rows, err = m.DB.QueryxContext( ctx, `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 ?`, options.Limit, ) } if err != nil { return nil, fmt.Errorf("could not query motions: %w", err) } return rows, nil } func (m *MotionModel) ByTag(ctx context.Context, tag string, withVotes bool) (*Motion, error) { row := m.DB.QueryRowxContext( ctx, `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 = ?`, tag, ) if err := row.Err(); err != nil { return nil, fmt.Errorf("could not query motion: %w", err) } var result Motion if err := row.StructScan(&result); err != nil { return nil, fmt.Errorf("could not fill motion from query result: %w", err) } if err := m.FillVoteSums(ctx, []*Motion{&result}); err != nil { return nil, fmt.Errorf("could not get vote sums: %w", err) } if result.ID != 0 && withVotes { if err := m.FillVotes(ctx, &result); err != nil { return nil, fmt.Errorf("could not get votes for %s: %w", result.Tag, err) } } return &result, nil } func (m *MotionModel) FillVotes(ctx context.Context, md *Motion) error { rows, err := m.DB.QueryxContext(ctx, `SELECT voters.name, votes.vote FROM voters JOIN votes ON votes.voter = voters.id WHERE votes.decision = ? ORDER BY voters.name`, md.ID) if err != nil { if errors.Is(err, sql.ErrNoRows) { return nil } return fmt.Errorf("could not fetch rows: %w", err) } defer func(rows *sqlx.Rows) { _ = rows.Close() }(rows) for rows.Next() { if err := rows.Err(); err != nil { return fmt.Errorf("could not get row: %w", err) } var vote Vote if err := rows.StructScan(&vote); err != nil { return fmt.Errorf(errCouldNotScanResult, err) } md.Votes = append(md.Votes, &vote) } return nil } func (m *MotionModel) ByID(ctx context.Context, id int64) (*Motion, error) { row := m.DB.QueryRowxContext(ctx, `SELECT * FROM decisions WHERE id=?`, id) if err := row.Err(); err != nil { return nil, fmt.Errorf("could not fetch tag for id %d: %w", id, err) } var motion Motion if err := row.StructScan(&motion); err != nil { return nil, fmt.Errorf("could not get tag from row: %w", err) } return &motion, nil } func (m *MotionModel) Update( ctx context.Context, id int64, updateFn func(*Motion), ) error { tx, err := m.DB.BeginTxx(ctx, nil) if err != nil { return fmt.Errorf(errCouldNotStartTransaction, err) } defer func(tx *sqlx.Tx) { _ = tx.Rollback() }(tx) row := tx.QueryRowxContext(ctx, `SELECT * FROM decisions WHERE id=?`, id) if err := row.Err(); err != nil { return fmt.Errorf("could not select motion: %w", err) } var motion Motion if err := row.StructScan(&motion); err != nil { return fmt.Errorf(errCouldNotScanResult, err) } updateFn(&motion) motion.Modified = time.Now().UTC() _, err = tx.NamedExecContext( ctx, `UPDATE decisions SET title=:title, content=:content, votetype=:votetype, due=:due, modified=:modified, status=:status WHERE id = :id`, motion, ) if err != nil { return fmt.Errorf("could not update decision: %w", err) } if err := tx.Commit(); err != nil { return fmt.Errorf(errCouldNotCommitTransaction, err) } return nil } type Vote struct { UserID int64 `db:"voter"` MotionID int64 `db:"decision"` Vote *VoteChoice `db:"vote"` Voted time.Time `db:"voted"` Notes string `db:"notes"` Name string `db:"name"` } func (m *MotionModel) UpdateVote(ctx context.Context, userID, motionID int64, performVoteFn func(v *Vote)) error { tx, err := m.DB.BeginTxx(ctx, nil) if err != nil { return fmt.Errorf(errCouldNotStartTransaction, err) } defer func(tx *sqlx.Tx) { _ = tx.Rollback() }(tx) row := tx.QueryRowxContext(ctx, `SELECT * FROM votes WHERE voter=? AND decision=?`, userID, motionID) if err := row.Err(); err != nil { return fmt.Errorf(errCouldNotExecuteQuery, err) } vote := Vote{UserID: userID, MotionID: motionID} if err := row.StructScan(&vote); err != nil && !errors.Is(err, sql.ErrNoRows) { return fmt.Errorf("could not scan vote structure: %w", err) } performVoteFn(&vote) if _, err := tx.NamedExecContext( ctx, `INSERT INTO votes (decision, voter, vote, voted, notes) VALUES (:decision, :voter, :vote, :voted, :notes) ON CONFLICT (decision, voter) DO UPDATE SET vote=:vote, voted=:voted, notes=:notes WHERE decision = :decision AND voter = :voter`, vote, ); err != nil { return fmt.Errorf("could not insert or update vote: %w", err) } if err := tx.Commit(); err != nil { return fmt.Errorf(errCouldNotCommitTransaction, err) } return nil } func (m *MotionModel) Withdraw(ctx context.Context, id int64) error { return m.Update(ctx, id, func(m *Motion) { m.Status = voteStatusWithdrawn }) }