package repository import ( "context" "fmt" "git.sch9.ru/new_gate/ms-tester/internal/models" "github.com/jmoiron/sqlx" "strings" ) type ContestRepository struct { db *sqlx.DB } func NewContestRepository(db *sqlx.DB) *ContestRepository { return &ContestRepository{ db: db, } } const createContestQuery = "INSERT INTO contests (title) VALUES (?) RETURNING id" func (r *ContestRepository) CreateContest(ctx context.Context, title string) (int32, error) { const op = "ContestRepository.CreateContest" query := r.db.Rebind(createContestQuery) rows, err := r.db.QueryxContext(ctx, query, title) if err != nil { return 0, handlePgErr(err, op) } defer rows.Close() var id int32 rows.Next() err = rows.Scan(&id) if err != nil { return 0, handlePgErr(err, op) } return id, nil } const readContestByIdQuery = "SELECT * from contests WHERE id=? LIMIT 1" func (r *ContestRepository) ReadContestById(ctx context.Context, id int32) (*models.Contest, error) { const op = "ContestRepository.ReadContestById" var contest models.Contest query := r.db.Rebind(readContestByIdQuery) err := r.db.GetContext(ctx, &contest, query, id) if err != nil { return nil, handlePgErr(err, op) } return &contest, nil } const deleteContestQuery = "DELETE FROM contests WHERE id=?" func (r *ContestRepository) DeleteContest(ctx context.Context, id int32) error { const op = "ContestRepository.DeleteContest" query := r.db.Rebind(deleteContestQuery) _, err := r.db.ExecContext(ctx, query, id) if err != nil { return handlePgErr(err, op) } return nil } const addTaskQuery = `INSERT INTO tasks (problem_id, contest_id, position) VALUES (?, ?, COALESCE((SELECT MAX(position) FROM tasks WHERE contest_id = ?), 0) + 1) RETURNING id ` func (r *ContestRepository) AddTask(ctx context.Context, contestId int32, problemId int32) (int32, error) { const op = "ContestRepository.AddTask" query := r.db.Rebind(addTaskQuery) rows, err := r.db.QueryxContext(ctx, query, problemId, contestId, contestId) if err != nil { return 0, handlePgErr(err, op) } defer rows.Close() var id int32 rows.Next() err = rows.Scan(&id) if err != nil { return 0, handlePgErr(err, op) } return id, nil } const deleteTaskQuery = "DELETE FROM tasks WHERE id=?" func (r *ContestRepository) DeleteTask(ctx context.Context, taskId int32) error { const op = "ContestRepository.DeleteTask" query := r.db.Rebind(deleteTaskQuery) _, err := r.db.ExecContext(ctx, query, taskId) if err != nil { return handlePgErr(err, op) } return nil } const addParticipantQuery = "INSERT INTO participants (user_id ,contest_id, name) VALUES (?, ?, ?) RETURNING id" func (r *ContestRepository) AddParticipant(ctx context.Context, contestId int32, userId int32) (int32, error) { const op = "ContestRepository.AddParticipant" query := r.db.Rebind(addParticipantQuery) name := "" rows, err := r.db.QueryxContext(ctx, query, contestId, userId, name) if err != nil { return 0, handlePgErr(err, op) } defer rows.Close() var id int32 rows.Next() err = rows.Scan(&id) if err != nil { return 0, err } return id, nil } const deleteParticipantQuery = "DELETE FROM participants WHERE id=?" func (r *ContestRepository) DeleteParticipant(ctx context.Context, participantId int32) error { const op = "ContestRepository.DeleteParticipant" query := r.db.Rebind(deleteParticipantQuery) _, err := r.db.ExecContext(ctx, query, participantId) if err != nil { return handlePgErr(err, op) } return nil } const readTasksQuery = `SELECT tasks.id, problem_id, contest_id, position, title, memory_limit, time_limit, tasks.created_at, tasks.updated_at FROM tasks INNER JOIN problems ON tasks.problem_id = problems.id WHERE contest_id = ? ORDER BY position` func (r *ContestRepository) ReadTasks(ctx context.Context, contestId int32) ([]*models.TasksListItem, error) { const op = "ContestRepository.ReadTasks" var tasks []*models.TasksListItem query := r.db.Rebind(readTasksQuery) err := r.db.SelectContext(ctx, &tasks, query, contestId) if err != nil { return nil, handlePgErr(err, op) } return tasks, nil } const ( readContestsListQuery = `SELECT id, title, created_at, updated_at FROM contests LIMIT ? OFFSET ?` countContestsQuery = "SELECT COUNT(*) FROM contests" ) func (r *ContestRepository) ListContests(ctx context.Context, filter models.ContestsFilter) (*models.ContestsList, error) { const op = "ContestRepository.ReadTasks" var contests []*models.ContestsListItem query := r.db.Rebind(readContestsListQuery) err := r.db.SelectContext(ctx, &contests, query, filter.PageSize, filter.Offset()) if err != nil { return nil, handlePgErr(err, op) } query = r.db.Rebind(countContestsQuery) var count int32 err = r.db.GetContext(ctx, &count, query) if err != nil { return nil, handlePgErr(err, op) } return &models.ContestsList{ Contests: contests, Pagination: models.Pagination{ Total: models.Total(count, filter.PageSize), Page: filter.Page, }, }, nil } const ( readParticipantsListQuery = `SELECT id, user_id, name, created_at, updated_at FROM participants WHERE contest_id = ? LIMIT ? OFFSET ?` countParticipantsQuery = "SELECT COUNT(*) FROM participants WHERE contest_id = ?" ) func (r *ContestRepository) ListParticipants(ctx context.Context, filter models.ParticipantsFilter) (*models.ParticipantsList, error) { const op = "ContestRepository.ReadParticipants" if filter.PageSize > 20 { filter.PageSize = 1 } var participants []*models.ParticipantsListItem query := r.db.Rebind(readParticipantsListQuery) err := r.db.SelectContext(ctx, &participants, query, filter.ContestId, filter.PageSize, filter.Offset()) if err != nil { return nil, handlePgErr(err, op) } query = r.db.Rebind(countParticipantsQuery) var count int32 err = r.db.GetContext(ctx, &count, query, filter.ContestId) if err != nil { return nil, handlePgErr(err, op) } return &models.ParticipantsList{ Participants: participants, Pagination: models.Pagination{ Total: models.Total(count, filter.PageSize), Page: filter.Page, }, }, nil } const ( updateContestQuery = "UPDATE contests SET title = COALESCE(?, title) WHERE id = ?" ) func (r *ContestRepository) UpdateContest(ctx context.Context, id int32, contestUpdate models.ContestUpdate) error { const op = "ContestRepository.UpdateContest" query := r.db.Rebind(updateContestQuery) _, err := r.db.ExecContext(ctx, query, contestUpdate.Title, id) if err != nil { return handlePgErr(err, op) } return nil } const ( updateParticipantQuery = "UPDATE participants SET name = COALESCE(?, name) WHERE id = ?" ) func (r *ContestRepository) UpdateParticipant(ctx context.Context, id int32, participantUpdate models.ParticipantUpdate) error { const op = "ContestRepository.UpdateParticipant" query := r.db.Rebind(updateParticipantQuery) _, err := r.db.ExecContext(ctx, query, participantUpdate.Name, id) if err != nil { return handlePgErr(err, op) } return nil } const ( readSolutionQuery = "SELECT * FROM solutions WHERE id = ?" ) func (r *ContestRepository) ReadSolution(ctx context.Context, id int32) (*models.Solution, error) { const op = "ContestRepository.ReadSolution" query := r.db.Rebind(readSolutionQuery) var solution models.Solution err := r.db.GetContext(ctx, &solution, query, id) if err != nil { return nil, handlePgErr(err, op) } return &solution, nil } const ( createSolutionQuery = `INSERT INTO solutions (task_id, participant_id, language, penalty, solution) VALUES (?, ?, ?, ?, ?) RETURNING id` ) func (r *ContestRepository) CreateSolution(ctx context.Context, creation *models.SolutionCreation) (int32, error) { const op = "ContestRepository.CreateSolution" query := r.db.Rebind(createSolutionQuery) rows, err := r.db.QueryxContext(ctx, query, creation.TaskId, creation.ParticipantId, creation.Language, creation.Penalty, creation.Solution, ) if err != nil { return 0, handlePgErr(err, op) } defer rows.Close() var id int32 rows.Next() err = rows.Scan(&id) if err != nil { return 0, handlePgErr(err, op) } return id, nil } func (r *ContestRepository) ListSolutions(ctx context.Context, filter models.SolutionsFilter) (*models.SolutionsList, error) { const op = "ContestRepository.ListSolutions" baseQuery := ` SELECT s.id, s.participant_id, p2.name as participant_name, s.state, s.score, s.penalty, s.time_stat, s.memory_stat, s.language, s.task_id, t.position as task_position, p.title as task_title, t.contest_id, c.title, s.updated_at, s.created_at FROM solutions s LEFT JOIN tasks t ON s.task_id = t.id LEFT JOIN problems p ON t.problem_id = p.id LEFT JOIN contests c ON t.contest_id = c.id LEFT JOIN participants p2 on s.participant_id = p2.id WHERE 1=1 ` var conditions []string var args []interface{} if filter.ContestId != nil { conditions = append(conditions, "s.contest_id = ?") args = append(args, *filter.ContestId) } if filter.ParticipantId != nil { conditions = append(conditions, "s.participant_id = ?") args = append(args, *filter.ParticipantId) } if filter.TaskId != nil { conditions = append(conditions, "s.task_id = ?") args = append(args, *filter.TaskId) } if filter.Language != nil { conditions = append(conditions, "s.language = ?") args = append(args, *filter.Language) } if filter.State != nil { conditions = append(conditions, "s.state = ?") args = append(args, *filter.State) } if len(conditions) > 0 { baseQuery += " AND " + strings.Join(conditions, " AND ") } if filter.Order != nil { orderDirection := "ASC" if *filter.Order < 0 { orderDirection = "DESC" } baseQuery += fmt.Sprintf(" ORDER BY s.id %s", orderDirection) } countQuery := "SELECT COUNT(*) FROM (" + baseQuery + ") as count_table" var totalCount int32 err := r.db.QueryRowxContext(ctx, r.db.Rebind(countQuery), args...).Scan(&totalCount) if err != nil { return nil, handlePgErr(err, op) } offset := (filter.Page - 1) * filter.PageSize baseQuery += " LIMIT ? OFFSET ?" args = append(args, filter.PageSize, offset) rows, err := r.db.QueryxContext(ctx, r.db.Rebind(baseQuery), args...) if err != nil { return nil, handlePgErr(err, op) } defer rows.Close() var solutions []*models.SolutionsListItem for rows.Next() { var solution models.SolutionsListItem err = rows.StructScan(&solution) if err != nil { return nil, handlePgErr(err, op) } solutions = append(solutions, &solution) } if err = rows.Err(); err != nil { return nil, handlePgErr(err, op) } return &models.SolutionsList{ Solutions: solutions, Pagination: models.Pagination{ Total: models.Total(totalCount, filter.PageSize), Page: filter.Page, }, }, nil } const ( readTaskQuery = ` SELECT t.id, t.position, p.title, p.time_limit, p.memory_limit, t.problem_id, t.contest_id, p.legend_html, p.input_format_html, p.output_format_html, p.notes_html, p.scoring_html, t.created_at, t.updated_at FROM tasks t LEFT JOIN problems p ON t.problem_id = p.id WHERE t.id = ? ` ) func (r *ContestRepository) ReadTask(ctx context.Context, id int32) (*models.Task, error) { const op = "ContestRepository.ReadTask" query := r.db.Rebind(readTaskQuery) var task models.Task err := r.db.GetContext(ctx, &task, query, id) if err != nil { return nil, handlePgErr(err, op) } return &task, nil } const ( // state=5 - AC readStatisticsQuery = ` SELECT t.id as task_id, t.position, COUNT(*) as total, COUNT(CASE WHEN s.state = 5 THEN 1 END) as success FROM tasks t LEFT JOIN solutions s ON t.id = s.task_id WHERE t.contest_id = ? GROUP BY t.id, t.position ORDER BY t.position; ` solutionsQuery = ` WITH RankedSolutions AS ( SELECT s.id, s.participant_id, p2.name as participant_name, s.state, s.score, s.penalty, s.time_stat, s.memory_stat, s.language, s.task_id, t.position as task_position, p.title as task_title, t.contest_id, c.title as contest_title, s.updated_at, s.created_at, ROW_NUMBER() OVER ( PARTITION BY s.participant_id, s.task_id ORDER BY CASE WHEN s.state = 5 THEN 0 ELSE 1 END, s.created_at ) as rn FROM solutions s LEFT JOIN tasks t ON s.task_id = t.id LEFT JOIN problems p ON t.problem_id = p.id LEFT JOIN contests c ON t.contest_id = c.id LEFT JOIN participants p2 on s.participant_id = p2.id WHERE t.contest_id = ? ) SELECT rs.id, rs.participant_id, rs.participant_name, rs.state, rs.score, rs.penalty, rs.time_stat, rs.memory_stat, rs.language, rs.task_id, rs.task_position, rs.task_title, rs.contest_id, rs.contest_title, rs.updated_at, rs.created_at FROM RankedSolutions rs WHERE rs.rn = 1; ` participantsQuery = ` WITH Attempts AS ( SELECT s.participant_id, s.task_id, COUNT(*) FILTER (WHERE s.state != 5 AND s.created_at < ( SELECT MIN(s2.created_at) FROM solutions s2 WHERE s2.participant_id = s.participant_id AND s2.task_id = s.task_id AND s2.state = 5 )) as failed_attempts, MIN(CASE WHEN s.state = 5 THEN s.penalty END) as success_penalty FROM solutions s JOIN tasks t ON t.id = s.task_id WHERE t.contest_id = :contest_id GROUP BY s.participant_id, s.task_id ) SELECT p.id, p.name, COUNT(DISTINCT CASE WHEN a.success_penalty IS NOT NULL THEN a.task_id END) as solved_in_total, COALESCE(SUM(CASE WHEN a.success_penalty IS NOT NULL THEN a.failed_attempts * :penalty + a.success_penalty ELSE 0 END), 0) as penalty_in_total FROM participants p LEFT JOIN Attempts a ON a.participant_id = p.id WHERE p.contest_id = :contest_id GROUP BY p.id, p.name ` ) func (r *ContestRepository) ReadMonitor(ctx context.Context, contestId int32) (*models.Monitor, error) { const op = "ContestRepository.ReadMonitor" query := r.db.Rebind(readStatisticsQuery) rows, err := r.db.QueryxContext(ctx, query, contestId) if err != nil { return nil, handlePgErr(err, op) } defer rows.Close() var monitor models.Monitor for rows.Next() { var stat models.ProblemStatSummary err = rows.StructScan(&stat) if err != nil { return nil, handlePgErr(err, op) } monitor.Summary = append(monitor.Summary, &stat) } var solutions []*models.SolutionsListItem err = r.db.SelectContext(ctx, &solutions, r.db.Rebind(solutionsQuery), contestId) if err != nil { return nil, handlePgErr(err, op) } penalty := int32(20) // FIXME namedQuery := r.db.Rebind(participantsQuery) rows3, err := r.db.NamedQueryContext(ctx, namedQuery, map[string]interface{}{ "contest_id": contestId, "penalty": penalty, }) if err != nil { return nil, handlePgErr(err, op) } defer rows3.Close() solutionsMap := make(map[int32][]*models.SolutionsListItem) for _, solution := range solutions { solutionsMap[solution.ParticipantId] = append(solutionsMap[solution.ParticipantId], solution) } for rows3.Next() { var stat models.ParticipantsStat err = rows3.StructScan(&stat) if err != nil { return nil, handlePgErr(err, op) } if sols, ok := solutionsMap[stat.Id]; ok { stat.Solutions = sols } monitor.Participants = append(monitor.Participants, &stat) } return &monitor, nil }