diff --git a/dal/dal.go b/dal/dal.go index 3adc580..7b4cdde 100644 --- a/dal/dal.go +++ b/dal/dal.go @@ -9,12 +9,14 @@ import ( "github.com/golang-migrate/migrate/v4/database/postgres" _ "github.com/golang-migrate/migrate/v4/source/file" _ "github.com/lib/pq" + "github.com/minio/minio-go/v7" "penahub.gitlab.yandexcloud.net/backend/quiz/common.git/dal/sqlcgen" "penahub.gitlab.yandexcloud.net/backend/quiz/common.git/repository/account" "penahub.gitlab.yandexcloud.net/backend/quiz/common.git/repository/answer" "penahub.gitlab.yandexcloud.net/backend/quiz/common.git/repository/question" "penahub.gitlab.yandexcloud.net/backend/quiz/common.git/repository/quiz" "penahub.gitlab.yandexcloud.net/backend/quiz/common.git/repository/result" + "penahub.gitlab.yandexcloud.net/backend/quiz/common.git/repository/statistics" "penahub.gitlab.yandexcloud.net/backend/quiz/common.git/repository/workers" "penahub.gitlab.yandexcloud.net/backend/quiz/core.git/clients/auth" "time" @@ -23,18 +25,19 @@ import ( var errNextDeclined = errors.New("next is declined") type DAL struct { - conn *sql.DB - authClient *auth.AuthClient - queries *sqlcgen.Queries - AccountRepo *account.AccountRepository - AnswerRepo *answer.AnswerRepository - QuestionRepo *question.QuestionRepository - QuizRepo *quiz.QuizRepository - ResultRepo *result.ResultRepository - WorkerRepo *workers.WorkerRepository + conn *sql.DB + authClient *auth.AuthClient + queries *sqlcgen.Queries + AccountRepo *account.AccountRepository + AnswerRepo *answer.AnswerRepository + QuestionRepo *question.QuestionRepository + QuizRepo *quiz.QuizRepository + ResultRepo *result.ResultRepository + WorkerRepo *workers.WorkerRepository + StatisticsRepo *statistics.StatisticsRepository } -func New(ctx context.Context, cred string, authClient *auth.AuthClient) (*DAL, error) { +func New(ctx context.Context, cred string, authClient *auth.AuthClient, minioClient *minio.Client) (*DAL, error) { pool, err := sql.Open("postgres", cred) if err != nil { return nil, err @@ -55,9 +58,19 @@ func New(ctx context.Context, cred string, authClient *auth.AuthClient) (*DAL, e Pool: pool, }) + storerAnswer := &answer.StorerAnswer{} + + if minioClient != nil { + storerAnswer, err = answer.NewAnswerMinio(ctx, minioClient) + if err != nil { + return nil, err + } + } + answerRepo := answer.NewAnswerRepository(answer.Deps{ - Queries: queries, - Pool: pool, + Queries: queries, + Pool: pool, + AnswerMinio: storerAnswer, }) questionRepo := question.NewQuestionRepository(question.Deps{ @@ -79,16 +92,22 @@ func New(ctx context.Context, cred string, authClient *auth.AuthClient) (*DAL, e Queries: queries, }) + statisticsRepo := statistics.NewStatisticsRepo(statistics.Deps{ + Queries: queries, + Pool: pool, + }) + return &DAL{ - conn: pool, - authClient: authClient, - queries: queries, - AccountRepo: accountRepo, - AnswerRepo: answerRepo, - QuestionRepo: questionRepo, - QuizRepo: quizRepo, - ResultRepo: resultRepo, - WorkerRepo: workerRepo, + conn: pool, + authClient: authClient, + queries: queries, + AccountRepo: accountRepo, + AnswerRepo: answerRepo, + QuestionRepo: questionRepo, + QuizRepo: quizRepo, + ResultRepo: resultRepo, + WorkerRepo: workerRepo, + StatisticsRepo: statisticsRepo, }, nil } diff --git a/dal/db_query/queries.sql b/dal/db_query/queries.sql index 257d9ca..edcfb42 100644 --- a/dal/db_query/queries.sql +++ b/dal/db_query/queries.sql @@ -282,8 +282,18 @@ WHERE privilege_name = $2 AND (amount < $3 OR created_at <= NOW() - INTERVAL '1 month'); -- name: GetAllAnswersByQuizID :many -SELECT DISTINCT ON(question_id) content, created_at, question_id, id FROM answer WHERE session = $1 ORDER BY question_id ASC, created_at DESC; - +SELECT DISTINCT ON (a.question_id) + a.content, a.created_at, a.question_id, a.id, q.questiontype, quiz.qid +FROM + answer a + JOIN + question q ON a.question_id = q.id + JOIN + quiz ON q.quiz_id = quiz.id +WHERE + a.session = $1 AND a.start = false AND a.deleted = false +ORDER BY + a.question_id ASC, a.created_at DESC; -- name: InsertAnswers :exec INSERT INTO answer( content, @@ -297,12 +307,13 @@ INSERT INTO answer( device, os, browser, - ip -) VALUES ($1,$2,$3,$4,$5,$6,$7,$8,$9,$10,$11,$12); + ip, + start +) VALUES ($1,$2,$3,$4,$5,$6,$7,$8,$9,$10,$11,$12,$13); -- name: GetResultAnswers :many SELECT DISTINCT on (question_id) id, content, quiz_id, question_id, fingerprint, session,created_at, result, new,deleted FROM answer WHERE session = ( - SELECT session FROM answer WHERE answer.id = $1) ORDER BY question_id, created_at DESC; + SELECT session FROM answer WHERE answer.id = $1) AND start = false ORDER BY question_id, created_at DESC; -- name: GetQuestions :many SELECT id, quiz_id, title, description, questiontype, required, deleted, page, content, version, parent_ids, created_at, updated_at FROM question WHERE quiz_id = $1 AND deleted = FALSE; @@ -314,7 +325,308 @@ UPDATE answer SET deleted = TRUE WHERE id = $1 AND deleted = FALSE; SELECT a.id FROM answer a JOIN quiz q ON a.quiz_id = q.id -WHERE a.id = ANY($1::bigint[]) AND a.deleted = FALSE AND q.accountid = $2; +WHERE a.id = ANY($1::bigint[]) AND a.deleted = FALSE AND q.accountid = $2 AND a.start = false; -- name: CheckResultOwner :one -SELECT q.accountid FROM answer a JOIN quiz q ON a.quiz_id = q.id WHERE a.id = $1 AND a.deleted = FALSE; +SELECT q.accountid FROM answer a JOIN quiz q ON a.quiz_id = q.id WHERE a.id = $1 AND a.deleted = FALSE AND a.start = false; + +-- name: DeviceStatistics :many +WITH DeviceStats AS ( + SELECT + device_type, + COUNT(*) AS device_count + FROM + answer + WHERE + answer.quiz_id = $1 + AND created_at >= to_timestamp($2) + AND created_at <= to_timestamp($3) + AND result = TRUE + GROUP BY + device_type +), + OSStats AS ( + SELECT + os, + COUNT(*) AS os_count + FROM + answer + WHERE + answer.quiz_id = $1 + AND created_at >= to_timestamp($2) + AND created_at <= to_timestamp($3) + AND result = TRUE + GROUP BY + os + ), + BrowserStats AS ( + SELECT + browser, + COUNT(*) AS browser_count + FROM + answer + WHERE + answer.quiz_id = $1 + AND created_at >= to_timestamp($2) + AND created_at <= to_timestamp($3) + AND result = TRUE + GROUP BY + browser + ), + TotalStats AS ( + SELECT + COUNT(*) AS total_count + FROM + answer + WHERE + answer.quiz_id = $1 + AND created_at >= to_timestamp($2) + AND created_at <= to_timestamp($3) + AND result = TRUE + ) +SELECT + DeviceStats.device_type, + CAST((DeviceStats.device_count::FLOAT / TotalStats.total_count) * 100.0 AS FLOAT8) AS device_percentage, + OSStats.os, + CAST((OSStats.os_count::FLOAT / TotalStats.total_count) * 100.0 AS FLOAT8) AS os_percentage, + BrowserStats.browser, + CAST((BrowserStats.browser_count::FLOAT / TotalStats.total_count) * 100.0 AS FLOAT8) AS browser_percentage +FROM + DeviceStats, + OSStats, + BrowserStats, + TotalStats; + +-- name: GeneralStatistics :many +WITH TimeBucket AS ( + SELECT + CASE + WHEN EXTRACT(epoch FROM $2::timestamp) - EXTRACT(epoch FROM $1::timestamp) > 172800 THEN date_trunc('day', timestamp_bucket) + ELSE date_trunc('hour', timestamp_bucket) + END::TIMESTAMP AS time_interval_start, + LEAD( + CASE + WHEN EXTRACT(epoch FROM $2::timestamp) - EXTRACT(epoch FROM $1::timestamp) > 172800 THEN date_trunc('day', timestamp_bucket) + ELSE date_trunc('hour', timestamp_bucket) + END::TIMESTAMP + ) OVER (ORDER BY timestamp_bucket) AS time_interval_end + FROM + generate_series($1::timestamp with time zone, $2::timestamp with time zone, '1 hour'::interval) AS timestamp_bucket +), + OpenStats AS ( + SELECT + tb.time_interval_start, + tb.time_interval_end, + COUNT(DISTINCT session) AS open_count + FROM + ( + SELECT + session, + MIN(created_at) AS first_start_time + FROM + answer + WHERE + answer.quiz_id = $3 + AND start = TRUE + AND created_at >= $1::timestamp + AND created_at <= $2::timestamp + GROUP BY + session + ) AS first_starts + JOIN TimeBucket tb ON date_trunc('hour', first_starts.first_start_time) >= tb.time_interval_start + AND date_trunc('hour', first_starts.first_start_time) < tb.time_interval_end + GROUP BY + tb.time_interval_start, tb.time_interval_end + ), + ResultStats AS ( + SELECT + tb.time_interval_start, + tb.time_interval_end, + COUNT(DISTINCT session) AS true_result_count + FROM + ( + SELECT + session, + MIN(created_at) AS first_result_time + FROM + answer + WHERE + answer.quiz_id = $3 + AND result = TRUE + AND created_at >= $1::timestamp + AND created_at <= $2::timestamp + GROUP BY + session + ) AS first_results + JOIN TimeBucket tb ON date_trunc('hour', first_results.first_result_time) >= tb.time_interval_start + AND date_trunc('hour', first_results.first_result_time) < tb.time_interval_end + GROUP BY + tb.time_interval_start, tb.time_interval_end + ), + AvTimeStats AS ( + SELECT + tb.time_interval_start, + tb.time_interval_end, + AVG(EXTRACT(epoch FROM (a.created_at - b.created_at))) AS avg_time + FROM + answer a + JOIN answer b ON a.session = b.session + JOIN TimeBucket tb ON date_trunc('hour', a.created_at) >= tb.time_interval_start + AND date_trunc('hour', a.created_at) < tb.time_interval_end + WHERE + a.quiz_id = $3 + AND a.result = TRUE + AND b.start = TRUE + AND b.quiz_id = $3 + AND a.created_at >= $1::timestamp + AND a.created_at <= $2::timestamp + AND b.created_at >= $1::timestamp + AND b.created_at <= $2::timestamp + GROUP BY + tb.time_interval_start, tb.time_interval_end + ) +SELECT + tb.time_interval_start AS time_bucket, + COALESCE(os.open_count, 0) AS open_count, + COALESCE(rs.true_result_count, 0) AS true_result_count, + CASE + WHEN COALESCE(os.open_count, 0) > 0 THEN COALESCE(rs.true_result_count, 0) / COALESCE(os.open_count, 0) + ELSE 0 + END AS conversion, + COALESCE(at.avg_time, 0) AS avg_time +FROM + TimeBucket tb + LEFT JOIN + OpenStats os ON tb.time_interval_start = os.time_interval_start + AND tb.time_interval_end = os.time_interval_end + LEFT JOIN + ResultStats rs ON tb.time_interval_start = rs.time_interval_start + AND tb.time_interval_end = rs.time_interval_end + LEFT JOIN + AvTimeStats at ON tb.time_interval_start = at.time_interval_start + AND tb.time_interval_end = at.time_interval_end; + +-- name: QuestionsStatistics :many +WITH Funnel AS ( + SELECT + COUNT(DISTINCT a.session) FILTER (WHERE a.start = FALSE) AS count_start_false, + COUNT(DISTINCT a.session) FILTER (WHERE a.start = TRUE) AS count_start_true, + COUNT(DISTINCT CASE WHEN a.result = FALSE AND qid_true_result IS NOT NULL THEN a.session END) AS count_f_result_with_t_question, + COUNT(DISTINCT a.session) FILTER (WHERE a.result = TRUE) AS count_t_result + FROM + answer a + LEFT JOIN ( + SELECT DISTINCT a.session, q.id AS qid_true_result + FROM answer a + JOIN question q ON a.question_id = q.id + WHERE a.result = TRUE + ) AS q ON a.session = q.session + WHERE + a.quiz_id = $1 + AND a.created_at >= TO_TIMESTAMP($2) + AND a.created_at <= TO_TIMESTAMP($3) +), + Results AS ( + SELECT + q.title AS question_title, + COUNT(*) AS total_answers, + CAST(COUNT(*) * 100.0 / NULLIF(SUM(COUNT(*)) FILTER (WHERE a.result = TRUE) OVER (PARTITION BY a.quiz_id), 0) AS FLOAT8) AS percentage + FROM + question q + JOIN answer a ON q.id = a.question_id + WHERE + a.quiz_id = $1 + AND a.created_at >= TO_TIMESTAMP($2) + AND a.created_at <= TO_TIMESTAMP($3) + AND a.result = TRUE + GROUP BY + q.title, a.quiz_id, a.result + HAVING + COUNT(*) >= 1 + ), + Questions AS ( + SELECT + q.title AS question_title, + a.content AS answer_content, + CAST( + COUNT(CASE WHEN a.result = FALSE THEN 1 END) * 100.0 / NULLIF(SUM(COUNT(CASE WHEN a.result = FALSE THEN 1 END)) OVER (PARTITION BY q.id), 0) AS FLOAT8 + ) AS percentage + FROM + question q + JOIN answer a ON q.id = a.question_id + WHERE + a.quiz_id = $1 + AND a.created_at >= TO_TIMESTAMP($2) + AND a.created_at <= TO_TIMESTAMP($3) + GROUP BY + q.id, q.title, a.content + HAVING + COUNT(*) >= 1 +) +SELECT + Funnel.count_start_false, + Funnel.count_start_true, + Funnel.count_f_result_with_t_question, + Funnel.count_t_result, + Results.question_title AS results_title, + Results.percentage AS results_percentage, + Questions.question_title AS questions_title, + Questions.answer_content AS answer_content, + Questions.percentage AS questions_percentage +FROM + Funnel, + Results, + Questions +WHERE + Questions.percentage >= 1; + +-- name: QuizCopyQid :one + INSERT INTO quiz ( + accountid, archived, fingerprinting, repeatable, note_prevented, mail_notifications, unique_answers, name, description, config, + status, limit_answers, due_to, time_of_passing, pausable, version, version_comment, parent_ids, questions_count, answers_count, average_time_passing, super, group_id + ) + SELECT + $2, archived, fingerprinting, repeatable, note_prevented, mail_notifications, unique_answers, name, description, config, + status, limit_answers, due_to, time_of_passing, pausable, version, version_comment, parent_ids, questions_count, answers_count, average_time_passing, super, group_id + FROM + quiz as q + WHERE + q.qid = $1 + RETURNING (select id from quiz where qid = $1),id, qid; + +-- name: CopyQuestionQuizID :exec +INSERT INTO question ( + quiz_id, title, description, questiontype, required, + page, content, version, parent_ids, created_at, updated_at +) +SELECT + $2, title, description, questiontype, required, + page, content, version, parent_ids, created_at, updated_at +FROM + question +WHERE + question.quiz_id = $1 AND deleted = false; + +-- name: GetQidOwner :one +SELECT accountid FROM quiz where qid=$1; + +-- name: AllServiceStatistics :one +WITH Registrations AS ( + SELECT COUNT(*) AS registration_count + FROM account + WHERE created_at >= to_timestamp($1) AND created_at <= to_timestamp($2) +), + Quizes AS ( + SELECT COUNT(*) AS quiz_count + FROM quiz + WHERE deleted = false AND created_at >= to_timestamp($1) AND created_at <= to_timestamp($2) + ), + Results AS ( + SELECT COUNT(*) AS result_count + FROM answer + WHERE result = true AND created_at >= to_timestamp($1) AND created_at <= to_timestamp($2) + ) +SELECT + (SELECT registration_count FROM Registrations) AS registrations, + (SELECT quiz_count FROM Quizes) AS quizes, + (SELECT result_count FROM Results) AS results; diff --git a/dal/schema/000007_init.down.sql b/dal/schema/000007_init.down.sql new file mode 100644 index 0000000..374c55d --- /dev/null +++ b/dal/schema/000007_init.down.sql @@ -0,0 +1,2 @@ +ALTER TABLE answer +DROP COLUMN start; \ No newline at end of file diff --git a/dal/schema/000007_init.up.sql b/dal/schema/000007_init.up.sql new file mode 100644 index 0000000..6b41425 --- /dev/null +++ b/dal/schema/000007_init.up.sql @@ -0,0 +1,2 @@ +ALTER TABLE answer +ADD COLUMN start BOOLEAN NOT NULL DEFAULT FALSE; \ No newline at end of file diff --git a/dal/sqlcgen/models.go b/dal/sqlcgen/models.go index 2a6da31..5a42d12 100644 --- a/dal/sqlcgen/models.go +++ b/dal/sqlcgen/models.go @@ -35,6 +35,7 @@ type Answer struct { Os string `db:"os" json:"os"` Browser string `db:"browser" json:"browser"` Ip string `db:"ip" json:"ip"` + Start bool `db:"start" json:"start"` } type Privilege struct { diff --git a/dal/sqlcgen/queries.sql.go b/dal/sqlcgen/queries.sql.go index 3a98c1e..a058104 100644 --- a/dal/sqlcgen/queries.sql.go +++ b/dal/sqlcgen/queries.sql.go @@ -8,6 +8,7 @@ package sqlcgen import ( "context" "database/sql" + "time" "github.com/google/uuid" "github.com/lib/pq" @@ -58,6 +59,46 @@ func (q *Queries) AccountPagination(ctx context.Context, arg AccountPaginationPa return items, nil } +const allServiceStatistics = `-- name: AllServiceStatistics :one +WITH Registrations AS ( + SELECT COUNT(*) AS registration_count + FROM account + WHERE created_at >= to_timestamp($1) AND created_at <= to_timestamp($2) +), + Quizes AS ( + SELECT COUNT(*) AS quiz_count + FROM quiz + WHERE deleted = false AND created_at >= to_timestamp($1) AND created_at <= to_timestamp($2) + ), + Results AS ( + SELECT COUNT(*) AS result_count + FROM answer + WHERE result = true AND created_at >= to_timestamp($1) AND created_at <= to_timestamp($2) + ) +SELECT + (SELECT registration_count FROM Registrations) AS registrations, + (SELECT quiz_count FROM Quizes) AS quizes, + (SELECT result_count FROM Results) AS results +` + +type AllServiceStatisticsParams struct { + ToTimestamp float64 `db:"to_timestamp" json:"to_timestamp"` + ToTimestamp_2 float64 `db:"to_timestamp_2" json:"to_timestamp_2"` +} + +type AllServiceStatisticsRow struct { + Registrations int64 `db:"registrations" json:"registrations"` + Quizes int64 `db:"quizes" json:"quizes"` + Results int64 `db:"results" json:"results"` +} + +func (q *Queries) AllServiceStatistics(ctx context.Context, arg AllServiceStatisticsParams) (AllServiceStatisticsRow, error) { + row := q.db.QueryRowContext(ctx, allServiceStatistics, arg.ToTimestamp, arg.ToTimestamp_2) + var i AllServiceStatisticsRow + err := row.Scan(&i.Registrations, &i.Quizes, &i.Results) + return i, err +} + const archiveQuiz = `-- name: ArchiveQuiz :exec UPDATE quiz SET archived = true WHERE id=$1 AND accountId=$2 ` @@ -91,7 +132,7 @@ func (q *Queries) CheckAndAddDefault(ctx context.Context, arg CheckAndAddDefault } const checkResultOwner = `-- name: CheckResultOwner :one -SELECT q.accountid FROM answer a JOIN quiz q ON a.quiz_id = q.id WHERE a.id = $1 AND a.deleted = FALSE +SELECT q.accountid FROM answer a JOIN quiz q ON a.quiz_id = q.id WHERE a.id = $1 AND a.deleted = FALSE AND a.start = false ` func (q *Queries) CheckResultOwner(ctx context.Context, id int64) (string, error) { @@ -105,7 +146,7 @@ const checkResultsOwner = `-- name: CheckResultsOwner :many SELECT a.id FROM answer a JOIN quiz q ON a.quiz_id = q.id -WHERE a.id = ANY($1::bigint[]) AND a.deleted = FALSE AND q.accountid = $2 +WHERE a.id = ANY($1::bigint[]) AND a.deleted = FALSE AND q.accountid = $2 AND a.start = false ` type CheckResultsOwnerParams struct { @@ -171,6 +212,30 @@ func (q *Queries) CopyQuestion(ctx context.Context, arg CopyQuestionParams) (Cop return i, err } +const copyQuestionQuizID = `-- name: CopyQuestionQuizID :exec +INSERT INTO question ( + quiz_id, title, description, questiontype, required, + page, content, version, parent_ids, created_at, updated_at +) +SELECT + $2, title, description, questiontype, required, + page, content, version, parent_ids, created_at, updated_at +FROM + question +WHERE + question.quiz_id = $1 AND deleted = false +` + +type CopyQuestionQuizIDParams struct { + QuizID int64 `db:"quiz_id" json:"quiz_id"` + QuizID_2 int64 `db:"quiz_id_2" json:"quiz_id_2"` +} + +func (q *Queries) CopyQuestionQuizID(ctx context.Context, arg CopyQuestionQuizIDParams) error { + _, err := q.db.ExecContext(ctx, copyQuestionQuizID, arg.QuizID, arg.QuizID_2) + return err +} + const copyQuiz = `-- name: CopyQuiz :one INSERT INTO quiz( accountid, archived,fingerprinting,repeatable,note_prevented,mail_notifications,unique_answers,name,description,config, @@ -345,6 +410,119 @@ func (q *Queries) DeleteQuizByID(ctx context.Context, arg DeleteQuizByIDParams) return i, err } +const deviceStatistics = `-- name: DeviceStatistics :many +WITH DeviceStats AS ( + SELECT + device_type, + COUNT(*) AS device_count + FROM + answer + WHERE + answer.quiz_id = $1 + AND created_at >= to_timestamp($2) + AND created_at <= to_timestamp($3) + AND result = TRUE + GROUP BY + device_type +), + OSStats AS ( + SELECT + os, + COUNT(*) AS os_count + FROM + answer + WHERE + answer.quiz_id = $1 + AND created_at >= to_timestamp($2) + AND created_at <= to_timestamp($3) + AND result = TRUE + GROUP BY + os + ), + BrowserStats AS ( + SELECT + browser, + COUNT(*) AS browser_count + FROM + answer + WHERE + answer.quiz_id = $1 + AND created_at >= to_timestamp($2) + AND created_at <= to_timestamp($3) + AND result = TRUE + GROUP BY + browser + ), + TotalStats AS ( + SELECT + COUNT(*) AS total_count + FROM + answer + WHERE + answer.quiz_id = $1 + AND created_at >= to_timestamp($2) + AND created_at <= to_timestamp($3) + AND result = TRUE + ) +SELECT + DeviceStats.device_type, + CAST((DeviceStats.device_count::FLOAT / TotalStats.total_count) * 100.0 AS FLOAT8) AS device_percentage, + OSStats.os, + CAST((OSStats.os_count::FLOAT / TotalStats.total_count) * 100.0 AS FLOAT8) AS os_percentage, + BrowserStats.browser, + CAST((BrowserStats.browser_count::FLOAT / TotalStats.total_count) * 100.0 AS FLOAT8) AS browser_percentage +FROM + DeviceStats, + OSStats, + BrowserStats, + TotalStats +` + +type DeviceStatisticsParams struct { + QuizID int64 `db:"quiz_id" json:"quiz_id"` + ToTimestamp float64 `db:"to_timestamp" json:"to_timestamp"` + ToTimestamp_2 float64 `db:"to_timestamp_2" json:"to_timestamp_2"` +} + +type DeviceStatisticsRow struct { + DeviceType string `db:"device_type" json:"device_type"` + DevicePercentage float64 `db:"device_percentage" json:"device_percentage"` + Os string `db:"os" json:"os"` + OsPercentage float64 `db:"os_percentage" json:"os_percentage"` + Browser string `db:"browser" json:"browser"` + BrowserPercentage float64 `db:"browser_percentage" json:"browser_percentage"` +} + +func (q *Queries) DeviceStatistics(ctx context.Context, arg DeviceStatisticsParams) ([]DeviceStatisticsRow, error) { + rows, err := q.db.QueryContext(ctx, deviceStatistics, arg.QuizID, arg.ToTimestamp, arg.ToTimestamp_2) + if err != nil { + return nil, err + } + defer rows.Close() + var items []DeviceStatisticsRow + for rows.Next() { + var i DeviceStatisticsRow + if err := rows.Scan( + &i.DeviceType, + &i.DevicePercentage, + &i.Os, + &i.OsPercentage, + &i.Browser, + &i.BrowserPercentage, + ); err != nil { + return nil, err + } + items = append(items, i) + } + if err := rows.Close(); err != nil { + return nil, err + } + if err := rows.Err(); err != nil { + return nil, err + } + return items, nil +} + const duplicateQuestion = `-- name: DuplicateQuestion :one INSERT INTO question( quiz_id, title, description, questiontype, required, @@ -375,6 +553,159 @@ func (q *Queries) DuplicateQuestion(ctx context.Context, id int64) (DuplicateQue return i, err } +const generalStatistics = `-- name: GeneralStatistics :many +WITH TimeBucket AS ( + SELECT + CASE + WHEN EXTRACT(epoch FROM $2::timestamp) - EXTRACT(epoch FROM $1::timestamp) > 172800 THEN date_trunc('day', timestamp_bucket) + ELSE date_trunc('hour', timestamp_bucket) + END::TIMESTAMP AS time_interval_start, + LEAD( + CASE + WHEN EXTRACT(epoch FROM $2::timestamp) - EXTRACT(epoch FROM $1::timestamp) > 172800 THEN date_trunc('day', timestamp_bucket) + ELSE date_trunc('hour', timestamp_bucket) + END::TIMESTAMP + ) OVER (ORDER BY timestamp_bucket) AS time_interval_end + FROM + generate_series($1::timestamp with time zone, $2::timestamp with time zone, '1 hour'::interval) AS timestamp_bucket +), + OpenStats AS ( + SELECT + tb.time_interval_start, + tb.time_interval_end, + COUNT(DISTINCT session) AS open_count + FROM + ( + SELECT + session, + MIN(created_at) AS first_start_time + FROM + answer + WHERE + answer.quiz_id = $3 + AND start = TRUE + AND created_at >= $1::timestamp + AND created_at <= $2::timestamp + GROUP BY + session + ) AS first_starts + JOIN TimeBucket tb ON date_trunc('hour', first_starts.first_start_time) >= tb.time_interval_start + AND date_trunc('hour', first_starts.first_start_time) < tb.time_interval_end + GROUP BY + tb.time_interval_start, tb.time_interval_end + ), + ResultStats AS ( + SELECT + tb.time_interval_start, + tb.time_interval_end, + COUNT(DISTINCT session) AS true_result_count + FROM + ( + SELECT + session, + MIN(created_at) AS first_result_time + FROM + answer + WHERE + answer.quiz_id = $3 + AND result = TRUE + AND created_at >= $1::timestamp + AND created_at <= $2::timestamp + GROUP BY + session + ) AS first_results + JOIN TimeBucket tb ON date_trunc('hour', first_results.first_result_time) >= tb.time_interval_start + AND date_trunc('hour', first_results.first_result_time) < tb.time_interval_end + GROUP BY + tb.time_interval_start, tb.time_interval_end + ), + AvTimeStats AS ( + SELECT + tb.time_interval_start, + tb.time_interval_end, + AVG(EXTRACT(epoch FROM (a.created_at - b.created_at))) AS avg_time + FROM + answer a + JOIN answer b ON a.session = b.session + JOIN TimeBucket tb ON date_trunc('hour', a.created_at) >= tb.time_interval_start + AND date_trunc('hour', a.created_at) < tb.time_interval_end + WHERE + a.quiz_id = $3 + AND a.result = TRUE + AND b.start = TRUE + AND b.quiz_id = $3 + AND a.created_at >= $1::timestamp + AND a.created_at <= $2::timestamp + AND b.created_at >= $1::timestamp + AND b.created_at <= $2::timestamp + GROUP BY + tb.time_interval_start, tb.time_interval_end + ) +SELECT + tb.time_interval_start AS time_bucket, + COALESCE(os.open_count, 0) AS open_count, + COALESCE(rs.true_result_count, 0) AS true_result_count, + CASE + WHEN COALESCE(os.open_count, 0) > 0 THEN COALESCE(rs.true_result_count, 0) / COALESCE(os.open_count, 0) + ELSE 0 + END AS conversion, + COALESCE(at.avg_time, 0) AS avg_time +FROM + TimeBucket tb + LEFT JOIN + OpenStats os ON tb.time_interval_start = os.time_interval_start + AND tb.time_interval_end = os.time_interval_end + LEFT JOIN + ResultStats rs ON tb.time_interval_start = rs.time_interval_start + AND tb.time_interval_end = rs.time_interval_end + LEFT JOIN + AvTimeStats at ON tb.time_interval_start = at.time_interval_start + AND tb.time_interval_end = at.time_interval_end +` + +type GeneralStatisticsParams struct { + Column1 time.Time `db:"column_1" json:"column_1"` + Column2 time.Time `db:"column_2" json:"column_2"` + QuizID int64 `db:"quiz_id" json:"quiz_id"` +} + +type GeneralStatisticsRow struct { + TimeBucket time.Time `db:"time_bucket" json:"time_bucket"` + OpenCount int64 `db:"open_count" json:"open_count"` + TrueResultCount int64 `db:"true_result_count" json:"true_result_count"` + Conversion int32 `db:"conversion" json:"conversion"` + AvgTime float64 `db:"avg_time" json:"avg_time"` +} + +func (q *Queries) GeneralStatistics(ctx context.Context, arg GeneralStatisticsParams) ([]GeneralStatisticsRow, error) { + rows, err := q.db.QueryContext(ctx, generalStatistics, arg.Column1, arg.Column2, arg.QuizID) + if err != nil { + return nil, err + } + defer rows.Close() + var items []GeneralStatisticsRow + for rows.Next() { + var i GeneralStatisticsRow + if err := rows.Scan( + &i.TimeBucket, + &i.OpenCount, + &i.TrueResultCount, + &i.Conversion, + &i.AvgTime, + ); err != nil { + return nil, err + } + items = append(items, i) + } + if err := rows.Close(); err != nil { + return nil, err + } + if err := rows.Err(); err != nil { + return nil, err + } + return items, nil +} + const getAccAndPrivilegeByEmail = `-- name: GetAccAndPrivilegeByEmail :one SELECT a.id, @@ -476,14 +807,27 @@ func (q *Queries) GetAccountWithPrivileges(ctx context.Context, userID sql.NullS } const getAllAnswersByQuizID = `-- name: GetAllAnswersByQuizID :many -SELECT DISTINCT ON(question_id) content, created_at, question_id, id FROM answer WHERE session = $1 ORDER BY question_id ASC, created_at DESC +SELECT DISTINCT ON (a.question_id) + a.content, a.created_at, a.question_id, a.id, q.questiontype, quiz.qid +FROM + answer a + JOIN + question q ON a.question_id = q.id + JOIN + quiz ON q.quiz_id = quiz.id +WHERE + a.session = $1 AND a.start = false AND a.deleted = false +ORDER BY + a.question_id ASC, a.created_at DESC ` type GetAllAnswersByQuizIDRow struct { - Content sql.NullString `db:"content" json:"content"` - CreatedAt sql.NullTime `db:"created_at" json:"created_at"` - QuestionID int64 `db:"question_id" json:"question_id"` - ID int64 `db:"id" json:"id"` + Content sql.NullString `db:"content" json:"content"` + CreatedAt sql.NullTime `db:"created_at" json:"created_at"` + QuestionID int64 `db:"question_id" json:"question_id"` + ID int64 `db:"id" json:"id"` + Questiontype interface{} `db:"questiontype" json:"questiontype"` + Qid uuid.NullUUID `db:"qid" json:"qid"` } func (q *Queries) GetAllAnswersByQuizID(ctx context.Context, session sql.NullString) ([]GetAllAnswersByQuizIDRow, error) { @@ -500,6 +844,8 @@ func (q *Queries) GetAllAnswersByQuizID(ctx context.Context, session sql.NullStr &i.CreatedAt, &i.QuestionID, &i.ID, + &i.Questiontype, + &i.Qid, ); err != nil { return nil, err } @@ -698,6 +1044,17 @@ func (q *Queries) GetPrivilegesQuizAccount(ctx context.Context, id int64) ([]Get return items, nil } +const getQidOwner = `-- name: GetQidOwner :one +SELECT accountid FROM quiz where qid=$1 +` + +func (q *Queries) GetQidOwner(ctx context.Context, qid uuid.NullUUID) (string, error) { + row := q.db.QueryRowContext(ctx, getQidOwner, qid) + var accountid string + err := row.Scan(&accountid) + return accountid, err +} + const getQuestionHistory = `-- name: GetQuestionHistory :many SELECT id, quiz_id, title, description, questiontype, required, deleted, page, content, version, parent_ids, created_at, updated_at FROM question WHERE question.id = $1 OR question.id = ANY( SELECT unnest(parent_ids) FROM question WHERE id = $1 @@ -985,7 +1342,7 @@ func (q *Queries) GetQuizHistory(ctx context.Context, arg GetQuizHistoryParams) const getResultAnswers = `-- name: GetResultAnswers :many SELECT DISTINCT on (question_id) id, content, quiz_id, question_id, fingerprint, session,created_at, result, new,deleted FROM answer WHERE session = ( - SELECT session FROM answer WHERE answer.id = $1) ORDER BY question_id, created_at DESC + SELECT session FROM answer WHERE answer.id = $1) AND start = false ORDER BY question_id, created_at DESC ` type GetResultAnswersRow struct { @@ -1048,8 +1405,9 @@ INSERT INTO answer( device, os, browser, - ip -) VALUES ($1,$2,$3,$4,$5,$6,$7,$8,$9,$10,$11,$12) + ip, + start +) VALUES ($1,$2,$3,$4,$5,$6,$7,$8,$9,$10,$11,$12,$13) ` type InsertAnswersParams struct { @@ -1065,6 +1423,7 @@ type InsertAnswersParams struct { Os string `db:"os" json:"os"` Browser string `db:"browser" json:"browser"` Ip string `db:"ip" json:"ip"` + Start bool `db:"start" json:"start"` } func (q *Queries) InsertAnswers(ctx context.Context, arg InsertAnswersParams) error { @@ -1081,6 +1440,7 @@ func (q *Queries) InsertAnswers(ctx context.Context, arg InsertAnswersParams) er arg.Os, arg.Browser, arg.Ip, + arg.Start, ) return err } @@ -1319,6 +1679,165 @@ func (q *Queries) MoveToHistoryQuiz(ctx context.Context, arg MoveToHistoryQuizPa return i, err } +const questionsStatistics = `-- name: QuestionsStatistics :many +WITH Funnel AS ( + SELECT + COUNT(DISTINCT a.session) FILTER (WHERE a.start = FALSE) AS count_start_false, + COUNT(DISTINCT a.session) FILTER (WHERE a.start = TRUE) AS count_start_true, + COUNT(DISTINCT CASE WHEN a.result = FALSE AND qid_true_result IS NOT NULL THEN a.session END) AS count_f_result_with_t_question, + COUNT(DISTINCT a.session) FILTER (WHERE a.result = TRUE) AS count_t_result + FROM + answer a + LEFT JOIN ( + SELECT DISTINCT a.session, q.id AS qid_true_result + FROM answer a + JOIN question q ON a.question_id = q.id + WHERE a.result = TRUE + ) AS q ON a.session = q.session + WHERE + a.quiz_id = $1 + AND a.created_at >= TO_TIMESTAMP($2) + AND a.created_at <= TO_TIMESTAMP($3) +), + Results AS ( + SELECT + q.title AS question_title, + COUNT(*) AS total_answers, + CAST(COUNT(*) * 100.0 / NULLIF(SUM(COUNT(*)) FILTER (WHERE a.result = TRUE) OVER (PARTITION BY a.quiz_id), 0) AS FLOAT8) AS percentage + FROM + question q + JOIN answer a ON q.id = a.question_id + WHERE + a.quiz_id = $1 + AND a.created_at >= TO_TIMESTAMP($2) + AND a.created_at <= TO_TIMESTAMP($3) + AND a.result = TRUE + GROUP BY + q.title, a.quiz_id, a.result + HAVING + COUNT(*) >= 1 + ), + Questions AS ( + SELECT + q.title AS question_title, + a.content AS answer_content, + CAST( + COUNT(CASE WHEN a.result = FALSE THEN 1 END) * 100.0 / NULLIF(SUM(COUNT(CASE WHEN a.result = FALSE THEN 1 END)) OVER (PARTITION BY q.id), 0) AS FLOAT8 + ) AS percentage + FROM + question q + JOIN answer a ON q.id = a.question_id + WHERE + a.quiz_id = $1 + AND a.created_at >= TO_TIMESTAMP($2) + AND a.created_at <= TO_TIMESTAMP($3) + GROUP BY + q.id, q.title, a.content + HAVING + COUNT(*) >= 1 +) +SELECT + Funnel.count_start_false, + Funnel.count_start_true, + Funnel.count_f_result_with_t_question, + Funnel.count_t_result, + Results.question_title AS results_title, + Results.percentage AS results_percentage, + Questions.question_title AS questions_title, + Questions.answer_content AS answer_content, + Questions.percentage AS questions_percentage +FROM + Funnel, + Results, + Questions +WHERE + Questions.percentage >= 1 +` + +type QuestionsStatisticsParams struct { + QuizID int64 `db:"quiz_id" json:"quiz_id"` + ToTimestamp float64 `db:"to_timestamp" json:"to_timestamp"` + ToTimestamp_2 float64 `db:"to_timestamp_2" json:"to_timestamp_2"` +} + +type QuestionsStatisticsRow struct { + CountStartFalse int64 `db:"count_start_false" json:"count_start_false"` + CountStartTrue int64 `db:"count_start_true" json:"count_start_true"` + CountFResultWithTQuestion int64 `db:"count_f_result_with_t_question" json:"count_f_result_with_t_question"` + CountTResult int64 `db:"count_t_result" json:"count_t_result"` + ResultsTitle string `db:"results_title" json:"results_title"` + ResultsPercentage float64 `db:"results_percentage" json:"results_percentage"` + QuestionsTitle string `db:"questions_title" json:"questions_title"` + AnswerContent sql.NullString `db:"answer_content" json:"answer_content"` + QuestionsPercentage float64 `db:"questions_percentage" json:"questions_percentage"` +} + +func (q *Queries) QuestionsStatistics(ctx context.Context, arg QuestionsStatisticsParams) ([]QuestionsStatisticsRow, error) { + rows, err := q.db.QueryContext(ctx, questionsStatistics, arg.QuizID, arg.ToTimestamp, arg.ToTimestamp_2) + if err != nil { + return nil, err + } + defer rows.Close() + var items []QuestionsStatisticsRow + for rows.Next() { + var i QuestionsStatisticsRow + if err := rows.Scan( + &i.CountStartFalse, + &i.CountStartTrue, + &i.CountFResultWithTQuestion, + &i.CountTResult, + &i.ResultsTitle, + &i.ResultsPercentage, + &i.QuestionsTitle, + &i.AnswerContent, + &i.QuestionsPercentage, + ); err != nil { + return nil, err + } + items = append(items, i) + } + if err := rows.Close(); err != nil { + return nil, err + } + if err := rows.Err(); err != nil { + return nil, err + } + return items, nil +} + +const quizCopyQid = `-- name: QuizCopyQid :one + INSERT INTO quiz ( + accountid, archived, fingerprinting, repeatable, note_prevented, mail_notifications, unique_answers, name, description, config, + status, limit_answers, due_to, time_of_passing, pausable, version, version_comment, parent_ids, questions_count, answers_count, average_time_passing, super, group_id + ) + SELECT + $2, archived, fingerprinting, repeatable, note_prevented, mail_notifications, unique_answers, name, description, config, + status, limit_answers, due_to, time_of_passing, pausable, version, version_comment, parent_ids, questions_count, answers_count, average_time_passing, super, group_id + FROM + quiz as q + WHERE + q.qid = $1 + RETURNING (select id from quiz where qid = $1),id, qid +` + +type QuizCopyQidParams struct { + Qid uuid.NullUUID `db:"qid" json:"qid"` + Accountid string `db:"accountid" json:"accountid"` +} + +type QuizCopyQidRow struct { + ID int64 `db:"id" json:"id"` + ID_2 int64 `db:"id_2" json:"id_2"` + Qid uuid.NullUUID `db:"qid" json:"qid"` +} + +func (q *Queries) QuizCopyQid(ctx context.Context, arg QuizCopyQidParams) (QuizCopyQidRow, error) { + row := q.db.QueryRowContext(ctx, quizCopyQid, arg.Qid, arg.Accountid) + var i QuizCopyQidRow + err := row.Scan(&i.ID, &i.ID_2, &i.Qid) + return i, err +} + const softDeleteResultByID = `-- name: SoftDeleteResultByID :exec UPDATE answer SET deleted = TRUE WHERE id = $1 AND deleted = FALSE ` diff --git a/go.mod b/go.mod index fc2ebef..2f74b5c 100644 --- a/go.mod +++ b/go.mod @@ -17,17 +17,29 @@ require ( require ( github.com/andybalholm/brotli v1.0.5 // indirect + github.com/dustin/go-humanize v1.0.1 // indirect github.com/google/go-cmp v0.5.9 // indirect github.com/hashicorp/errwrap v1.1.0 // indirect github.com/hashicorp/go-multierror v1.1.1 // indirect - github.com/klauspost/compress v1.17.0 // indirect + github.com/json-iterator/go v1.1.12 // indirect + github.com/klauspost/compress v1.17.6 // indirect + github.com/klauspost/cpuid/v2 v2.2.6 // indirect github.com/mattn/go-colorable v0.1.13 // indirect github.com/mattn/go-isatty v0.0.20 // indirect github.com/mattn/go-runewidth v0.0.15 // indirect + github.com/minio/md5-simd v1.1.2 // indirect + github.com/minio/minio-go/v7 v7.0.69 // indirect + github.com/minio/sha256-simd v1.0.1 // indirect + github.com/modern-go/concurrent v0.0.0-20180306012644-bacd9c7ef1dd // indirect + github.com/modern-go/reflect2 v1.0.2 // indirect github.com/rivo/uniseg v0.2.0 // indirect github.com/valyala/bytebufferpool v1.0.0 // indirect github.com/valyala/fasthttp v1.51.0 // indirect github.com/valyala/tcplisten v1.0.0 // indirect go.uber.org/atomic v1.7.0 // indirect - golang.org/x/sys v0.15.0 // indirect + golang.org/x/crypto v0.19.0 // indirect + golang.org/x/net v0.21.0 // indirect + golang.org/x/sys v0.17.0 // indirect + golang.org/x/text v0.14.0 // indirect + gopkg.in/ini.v1 v1.67.0 // indirect ) diff --git a/go.sum b/go.sum index a3ed716..12c0db5 100644 --- a/go.sum +++ b/go.sum @@ -17,6 +17,8 @@ github.com/docker/go-connections v0.4.0 h1:El9xVISelRB7BuFusrZozjnkIM5YnzCViNKoh github.com/docker/go-connections v0.4.0/go.mod h1:Gbd7IOopHjR8Iph03tsViu4nIes5XhDvyHbTtUxmeec= github.com/docker/go-units v0.5.0 h1:69rxXcBk27SvSaaxTtLh/8llcHD8vYHT7WSdRZ/jvr4= github.com/docker/go-units v0.5.0/go.mod h1:fgPhTUdO+D/Jk86RDLlptpiXQzgHJF7gydDDbaIK4Dk= +github.com/dustin/go-humanize v1.0.1 h1:GzkhY7T5VNhEkwH0PVJgjz+fX1rhBrR7pRT3mDkpeCY= +github.com/dustin/go-humanize v1.0.1/go.mod h1:Mu1zIs6XwVuF/gI1OepvI0qD18qycQx+mFykh5fBlto= github.com/gofiber/fiber/v2 v2.52.0 h1:S+qXi7y+/Pgvqq4DrSmREGiFwtB7Bu6+QFLuIHYw/UE= github.com/gofiber/fiber/v2 v2.52.0/go.mod h1:KEOE+cXMhXG0zHc9d8+E38hoX+ZN7bhOtgeF2oT6jrQ= github.com/gogo/protobuf v1.3.2 h1:Ov1cvc58UF3b5XjBnZv7+opcTcQFZebYjWzi34vdm4Q= @@ -31,6 +33,7 @@ github.com/golang/protobuf v1.5.3/go.mod h1:XVQd3VNwM+JqD3oG2Ue2ip4fOMUkwXdXDdiu github.com/google/go-cmp v0.5.5/go.mod h1:v8dTdLbMG2kIc/vJvl+f65V22dbkXbowE6jgT/gNBxE= github.com/google/go-cmp v0.5.9 h1:O2Tfq5qg4qc4AmwVlvv0oLiVAGB7enBSJ2x2DqQFi38= github.com/google/go-cmp v0.5.9/go.mod h1:17dUlkBOakJ0+DkrSSNjCkIjxS6bF9zb3elmeNGIjoY= +github.com/google/gofuzz v1.0.0/go.mod h1:dBl0BpW6vV/+mYPU4Po3pmUjxk6FQPldtuIdl/M65Eg= github.com/google/uuid v1.6.0 h1:NIvaJDMOsjHA8n1jAhLSgzrAzy1Hgr+hNrb57e+94F0= github.com/google/uuid v1.6.0/go.mod h1:TIyPZe4MgqvfeYDBFedMoGGpEw/LqOeaOT+nhxU+yHo= github.com/hashicorp/errwrap v1.0.0/go.mod h1:YH+1FKiLXxHSkmPseP+kNlulaMuP3n2brvKWEqk/Jc4= @@ -38,8 +41,15 @@ github.com/hashicorp/errwrap v1.1.0 h1:OxrOeh75EUXMY8TBjag2fzXGZ40LB6IKw45YeGUDY github.com/hashicorp/errwrap v1.1.0/go.mod h1:YH+1FKiLXxHSkmPseP+kNlulaMuP3n2brvKWEqk/Jc4= github.com/hashicorp/go-multierror v1.1.1 h1:H5DkEtf6CXdFp0N0Em5UCwQpXMWke8IA0+lD48awMYo= github.com/hashicorp/go-multierror v1.1.1/go.mod h1:iw975J/qwKPdAO1clOe2L8331t/9/fmwbPZ6JB6eMoM= +github.com/json-iterator/go v1.1.12 h1:PV8peI4a0ysnczrg+LtxykD8LfKY9ML6u2jnxaEnrnM= +github.com/json-iterator/go v1.1.12/go.mod h1:e30LSqwooZae/UwlEbR2852Gd8hjQvJoHmT4TnhNGBo= github.com/klauspost/compress v1.17.0 h1:Rnbp4K9EjcDuVuHtd0dgA4qNuv9yKDYKK1ulpJwgrqM= github.com/klauspost/compress v1.17.0/go.mod h1:ntbaceVETuRiXiv4DpjP66DpAtAGkEQskQzEyD//IeE= +github.com/klauspost/compress v1.17.6 h1:60eq2E/jlfwQXtvZEeBUYADs+BwKBWURIY+Gj2eRGjI= +github.com/klauspost/compress v1.17.6/go.mod h1:/dCuZOvVtNoHsyb+cuJD3itjs3NbnF6KH9zAO4BDxPM= +github.com/klauspost/cpuid/v2 v2.0.1/go.mod h1:FInQzS24/EEf25PyTYn52gqo7WaD8xa0213Md/qVLRg= +github.com/klauspost/cpuid/v2 v2.2.6 h1:ndNyv040zDGIDh8thGkXYjnFtiN02M1PVVF+JE/48xc= +github.com/klauspost/cpuid/v2 v2.2.6/go.mod h1:Lcz8mBdAVJIBVzewtcLocK12l3Y+JytZYpaMropDUws= github.com/lib/pq v1.10.9 h1:YXG7RB+JIjhP29X+OtkiDnYaXQwpS4JEWq7dtCCRUEw= github.com/lib/pq v1.10.9/go.mod h1:AlVN5x4E4T544tWzH6hKfbfQvm3HdbOxrmggDNAPY9o= github.com/mattn/go-colorable v0.1.13 h1:fFA4WZxdEF4tXPZVKMLwD8oUnCTTo08duU7wxecdEvA= @@ -49,8 +59,19 @@ github.com/mattn/go-isatty v0.0.20 h1:xfD0iDuEKnDkl03q4limB+vH+GxLEtL/jb4xVJSWWE github.com/mattn/go-isatty v0.0.20/go.mod h1:W+V8PltTTMOvKvAeJH7IuucS94S2C6jfK/D7dTCTo3Y= github.com/mattn/go-runewidth v0.0.15 h1:UNAjwbU9l54TA3KzvqLGxwWjHmMgBUVhBiTjelZgg3U= github.com/mattn/go-runewidth v0.0.15/go.mod h1:Jdepj2loyihRzMpdS35Xk/zdY8IAYHsh153qUoGf23w= +github.com/minio/md5-simd v1.1.2 h1:Gdi1DZK69+ZVMoNHRXJyNcxrMA4dSxoYHZSQbirFg34= +github.com/minio/md5-simd v1.1.2/go.mod h1:MzdKDxYpY2BT9XQFocsiZf/NKVtR7nkE4RoEpN+20RM= +github.com/minio/minio-go/v7 v7.0.69 h1:l8AnsQFyY1xiwa/DaQskY4NXSLA2yrGsW5iD9nRPVS0= +github.com/minio/minio-go/v7 v7.0.69/go.mod h1:XAvOPJQ5Xlzk5o3o/ArO2NMbhSGkimC+bpW/ngRKDmQ= +github.com/minio/sha256-simd v1.0.1 h1:6kaan5IFmwTNynnKKpDHe6FWHohJOHhCPchzK49dzMM= +github.com/minio/sha256-simd v1.0.1/go.mod h1:Pz6AKMiUdngCLpeTL/RJY1M9rUuPMYujV5xJjtbRSN8= github.com/moby/term v0.5.0 h1:xt8Q1nalod/v7BqbG21f8mQPqH+xAaC9C3N3wfWbVP0= github.com/moby/term v0.5.0/go.mod h1:8FzsFHVUBGZdbDsJw/ot+X+d5HLUbvklYLJ9uGfcI3Y= +github.com/modern-go/concurrent v0.0.0-20180228061459-e0a39a4cb421/go.mod h1:6dJC0mAP4ikYIbvyc7fijjWJddQyLn8Ig3JB5CqoB9Q= +github.com/modern-go/concurrent v0.0.0-20180306012644-bacd9c7ef1dd h1:TRLaZ9cD/w8PVh93nsPXa1VrQ6jlwL5oN8l14QlcNfg= +github.com/modern-go/concurrent v0.0.0-20180306012644-bacd9c7ef1dd/go.mod h1:6dJC0mAP4ikYIbvyc7fijjWJddQyLn8Ig3JB5CqoB9Q= +github.com/modern-go/reflect2 v1.0.2 h1:xBagoLtFs94CBntxluKeaWgTMpvLxC4ur3nMaC9Gz0M= +github.com/modern-go/reflect2 v1.0.2/go.mod h1:yWuevngMOJpCy52FWWMvUC8ws7m/LJsjYzDa0/r8luk= github.com/morikuni/aec v1.0.0 h1:nP9CBfwrvYnBRgY6qfDQkygYDmYwOilePFkwzv4dU8A= github.com/morikuni/aec v1.0.0/go.mod h1:BbKIizmSmc5MMPqRYbxO4ZU0S0+P200+tUnFx7PXmsc= github.com/opencontainers/go-digest v1.0.0 h1:apOUWs51W5PlhuyGyz9FCeeBIOUDA/6nW8Oi/yOhh5U= @@ -77,14 +98,23 @@ github.com/valyala/tcplisten v1.0.0 h1:rBHj/Xf+E1tRGZyWIWwJDiRY0zc1Js+CV5DqwacVS github.com/valyala/tcplisten v1.0.0/go.mod h1:T0xQ8SeCZGxckz9qRXTfG43PvQ/mcWh7FwZEA7Ioqkc= go.uber.org/atomic v1.7.0 h1:ADUqmZGgLDDfbSL9ZmPxKTybcoEYHgpYfELNoN+7hsw= go.uber.org/atomic v1.7.0/go.mod h1:fEN4uk6kAWBTFdckzkM89CLk9XfWZrxpCo0nPH17wJc= +golang.org/x/crypto v0.19.0 h1:ENy+Az/9Y1vSrlrvBSyna3PITt4tiZLf7sgCjZBX7Wo= +golang.org/x/crypto v0.19.0/go.mod h1:Iy9bg/ha4yyC70EfRS8jz+B6ybOBKMaSxLj6P6oBDfU= golang.org/x/mod v0.11.0 h1:bUO06HqtnRcc/7l71XBe4WcqTZ+3AH1J59zWDDwLKgU= golang.org/x/mod v0.11.0/go.mod h1:iBbtSCu2XBx23ZKBPSOrRkjjQPZFPuis4dIYUhu/chs= golang.org/x/net v0.18.0 h1:mIYleuAkSbHh0tCv7RvjL3F6ZVbLjq4+R7zbOn3Kokg= golang.org/x/net v0.18.0/go.mod h1:/czyP5RqHAH4odGYxBJ1qz0+CE5WZ+2j1YgoEo8F2jQ= +golang.org/x/net v0.21.0 h1:AQyQV4dYCvJ7vGmJyKki9+PBdyvhkSd8EIx/qb0AYv4= +golang.org/x/net v0.21.0/go.mod h1:bIjVDfnllIU7BJ2DNgfnXvpSvtn8VRwhlsaeUTyUS44= golang.org/x/sys v0.0.0-20220811171246-fbc7d0a398ab/go.mod h1:oPkhp1MJrh7nUepCBck5+mAzfO9JrbApNNgaTdGDITg= +golang.org/x/sys v0.5.0/go.mod h1:oPkhp1MJrh7nUepCBck5+mAzfO9JrbApNNgaTdGDITg= golang.org/x/sys v0.6.0/go.mod h1:oPkhp1MJrh7nUepCBck5+mAzfO9JrbApNNgaTdGDITg= golang.org/x/sys v0.15.0 h1:h48lPFYpsTvQJZF4EKyI4aLHaev3CxivZmv7yZig9pc= golang.org/x/sys v0.15.0/go.mod h1:/VUhepiaJMQUp4+oa/7Zr1D23ma6VTLIYjOOTFZPUcA= +golang.org/x/sys v0.17.0 h1:25cE3gD+tdBA7lp7QfhuV+rJiE9YXTcS3VG1SqssI/Y= +golang.org/x/sys v0.17.0/go.mod h1:/VUhepiaJMQUp4+oa/7Zr1D23ma6VTLIYjOOTFZPUcA= +golang.org/x/text v0.14.0 h1:ScX5w1eTa3QqT8oi6+ziP7dTV1S2+ALU0bI+0zXKWiQ= +golang.org/x/text v0.14.0/go.mod h1:18ZOQIKpY8NJVqYksKHtTdi31H5itFRjB5/qKTNYzSU= golang.org/x/tools v0.10.0 h1:tvDr/iQoUqNdohiYm0LmmKcBk+q86lb9EprIUFhHHGg= golang.org/x/tools v0.10.0/go.mod h1:UJwyiVBsOA2uwvK/e5OY3GTpDUJriEd+/YlqAwLPmyM= golang.org/x/xerrors v0.0.0-20191204190536-9bdfabe68543/go.mod h1:I/5z698sn9Ka8TeJc9MKroUUfqBBauWjQqLJ2OPfmY0= @@ -92,6 +122,8 @@ google.golang.org/protobuf v1.26.0-rc.1/go.mod h1:jlhhOSvTdKEhbULTjvd4ARK9grFBp0 google.golang.org/protobuf v1.26.0/go.mod h1:9q0QmTI4eRPtz6boOQmLYwt+qCgq0jsYwAQnmE0givc= google.golang.org/protobuf v1.32.0 h1:pPC6BG5ex8PDFnkbrGU3EixyhKcQ2aDuBS36lqK/C7I= google.golang.org/protobuf v1.32.0/go.mod h1:c6P6GXX6sHbq/GpV6MGZEdwhWPcYBgnhAHhKbcUYpos= +gopkg.in/ini.v1 v1.67.0 h1:Dgnx+6+nfE+IfzjUEISNeydPJh9AXNNsWbGP9KzCsOA= +gopkg.in/ini.v1 v1.67.0/go.mod h1:pNLf8WUiyNEtQjuu5G5vTm06TEv9tsIgeAvK8hOrP4k= gopkg.in/yaml.v3 v3.0.1 h1:fxVm/GzAzEWqLHuvctI91KS9hhNmmWOoWu0XTYJS7CA= gopkg.in/yaml.v3 v3.0.1/go.mod h1:K4uyk7z7BCEPqu6E+C64Yfv1cQ7kz7rIZviUmN+EgEM= penahub.gitlab.yandexcloud.net/backend/penahub_common v0.0.0-20240202120244-c4ef330cfe5d h1:gbaDt35HMDqOK84WYmDIlXMI7rstUcRqNttaT6Kx1do= diff --git a/model/model.go b/model/model.go index cfb3689..e5fcaea 100644 --- a/model/model.go +++ b/model/model.go @@ -147,6 +147,12 @@ type ResultContent struct { Messenger string `json:"messenger"` Custom map[string]string `json:"customs"` Start bool `json:"start"` + //IMGContent ImageContent `json:"imagecontent"` +} + +type ImageContent struct { + Description string + Image string } type ResultAnswer struct { diff --git a/repository/account/account.go b/repository/account/account.go index 1d93013..9150d27 100644 --- a/repository/account/account.go +++ b/repository/account/account.go @@ -307,3 +307,19 @@ func (r *AccountRepository) GetAccAndPrivilegeByEmail(ctx context.Context, email return account, privileges, nil } + +func (r *AccountRepository) GetQidOwner(ctx context.Context, qId string) (string, error) { + qUUID, err := uuid.Parse(qId) + if err != nil { + return "", err + } + + qNullUUID := uuid.NullUUID{UUID: qUUID, Valid: true} + + userID, err := r.queries.GetQidOwner(ctx, qNullUUID) + if err != nil { + return "", err + } + + return userID, nil +} diff --git a/repository/answer/answer.go b/repository/answer/answer.go index 6ced475..0b943df 100644 --- a/repository/answer/answer.go +++ b/repository/answer/answer.go @@ -3,24 +3,28 @@ package answer import ( "context" "database/sql" + "fmt" "penahub.gitlab.yandexcloud.net/backend/quiz/common.git/dal/sqlcgen" "penahub.gitlab.yandexcloud.net/backend/quiz/common.git/model" ) type Deps struct { - Queries *sqlcgen.Queries - Pool *sql.DB + Queries *sqlcgen.Queries + Pool *sql.DB + AnswerMinio *StorerAnswer } type AnswerRepository struct { - queries *sqlcgen.Queries - pool *sql.DB + queries *sqlcgen.Queries + pool *sql.DB + answerMinio *StorerAnswer } func NewAnswerRepository(deps Deps) *AnswerRepository { return &AnswerRepository{ - queries: deps.Queries, - pool: deps.Pool, + queries: deps.Queries, + pool: deps.Pool, + answerMinio: deps.AnswerMinio, } } @@ -50,6 +54,7 @@ func (r *AnswerRepository) CreateAnswers(ctx context.Context, answers []model.An Ip: ans.IP, Browser: ans.Browser, Os: ans.OS, + Start: ans.Start, } err := r.queries.InsertAnswers(ctx, params) @@ -80,6 +85,15 @@ func (r *AnswerRepository) GetAllAnswersByQuizID(ctx context.Context, session st for _, row := range rows { + if row.Questiontype.(string) == model.TypeFile { + fileURL, err := r.answerMinio.GetAnswerURL(ctx, row.Qid.UUID.String(), row.QuestionID, row.Content.String) + if err != nil { + fmt.Println("GetAnswerURL dal answer minio answer", err) + return nil, err + } + row.Content = sql.NullString{String: fmt.Sprintf("%s|%s", fileURL, row.Content.String), Valid: true} + } + resultAnswer := model.ResultAnswer{ Content: row.Content.String, CreatedAt: row.CreatedAt.Time, diff --git a/repository/answer/dal_minio.go b/repository/answer/dal_minio.go new file mode 100644 index 0000000..73276a8 --- /dev/null +++ b/repository/answer/dal_minio.go @@ -0,0 +1,44 @@ +package answer + +import ( + "context" + "fmt" + "github.com/minio/minio-go/v7" + "net/url" + "time" +) + +const ( + bucketAnswers = "squizanswer" +) + +type StorerAnswer struct { + client *minio.Client +} + +func NewAnswerMinio(ctx context.Context, minioClient *minio.Client) (*StorerAnswer, error) { + if ok, err := minioClient.BucketExists(ctx, bucketAnswers); !ok { + if err := minioClient.MakeBucket(ctx, bucketAnswers, minio.MakeBucketOptions{}); err != nil { + return nil, err + } + } else if err != nil { + return nil, err + } + + return &StorerAnswer{ + client: minioClient, + }, nil +} + +func (s *StorerAnswer) GetAnswerURL(ctx context.Context, quizID string, questionID int64, filename string) (string, error) { + objectName := fmt.Sprintf("%s/%d/%s", quizID, questionID, filename) + + reqParams := make(url.Values) + reqParams.Set("response-content-disposition", "attachment") + url, err := s.client.PresignedGetObject(ctx, bucketAnswers, objectName, time.Hour*1, reqParams) + if err != nil { + return "", err + } + + return url.String(), nil +} diff --git a/repository/quiz/quiz.go b/repository/quiz/quiz.go index 9df6892..0061bc6 100644 --- a/repository/quiz/quiz.go +++ b/repository/quiz/quiz.go @@ -578,3 +578,31 @@ func (r *QuizRepository) GetQuizConfig(ctx context.Context, quizID uint64) (mode return config, row.Accountid, nil } + +func (r *QuizRepository) QuizMove(ctx context.Context, qID, accountID string) (string, error) { + qUUID, err := uuid.Parse(qID) + if err != nil { + return "", err + } + qNullUUID := uuid.NullUUID{UUID: qUUID, Valid: true} + + data, err := r.queries.QuizCopyQid(ctx, sqlcgen.QuizCopyQidParams{ + Qid: qNullUUID, + Accountid: accountID, + }) + + if err != nil { + return "", err + } + + err = r.queries.CopyQuestionQuizID(ctx, sqlcgen.CopyQuestionQuizIDParams{ + QuizID: data.ID, + QuizID_2: data.ID_2, + }) + + if err != nil { + return "", err + } + + return data.Qid.UUID.String(), err +} diff --git a/repository/statistics/statistics.go b/repository/statistics/statistics.go new file mode 100644 index 0000000..2ae9789 --- /dev/null +++ b/repository/statistics/statistics.go @@ -0,0 +1,173 @@ +package statistics + +import ( + "context" + "database/sql" + "penahub.gitlab.yandexcloud.net/backend/quiz/common.git/dal/sqlcgen" + "time" +) + +type Deps struct { + Queries *sqlcgen.Queries + Pool *sql.DB +} + +type StatisticsRepository struct { + queries *sqlcgen.Queries + pool *sql.DB +} + +func NewStatisticsRepo(deps Deps) *StatisticsRepository { + return &StatisticsRepository{ + queries: deps.Queries, + pool: deps.Pool, + } +} + +type DeviceStatReq struct { + QuizId int64 + From uint64 + To uint64 +} + +type DeviceStatResp struct { + //ключ DeviceType значение процент + Device map[string]float64 // процентное соотношение DeviceType по всем ответам на опроc c res==true + // тоже самое тут только по OS и BROWSER + OS map[string]float64 + Browser map[string]float64 +} + +func (r *StatisticsRepository) GetDeviceStatistics(ctx context.Context, req DeviceStatReq) (DeviceStatResp, error) { + resp := DeviceStatResp{ + Device: make(map[string]float64), + OS: make(map[string]float64), + Browser: make(map[string]float64), + } + + allStatistics, err := r.queries.DeviceStatistics(ctx, sqlcgen.DeviceStatisticsParams{ + QuizID: req.QuizId, + ToTimestamp: float64(req.From), + ToTimestamp_2: float64(req.To), + }) + if err != nil { + return resp, err + } + + for _, stat := range allStatistics { + resp.Device[stat.DeviceType] = stat.DevicePercentage + resp.OS[stat.Os] = stat.OsPercentage + resp.Browser[stat.Browser] = stat.BrowserPercentage + } + + return resp, nil +} + +type GeneralStatsResp struct { + Open map[int64]int64 // количество ответов с полем start == true за период от одного пункта разбиения и до другого + Result map[int64]int64 // количество ответов с полем result == true за период от одного пункта разбиения и до другого + AvTime map[int64]uint64 // среднее время между ответом с полем result == true и start == true. в рамках сессии + Conversion map[int64]int32 // Result/Open за период от одного пункта разбиения и до другого +} + +func (r *StatisticsRepository) GetGeneralStatistics(ctx context.Context, req DeviceStatReq) (GeneralStatsResp, error) { + resp := GeneralStatsResp{ + Open: make(map[int64]int64), + Result: make(map[int64]int64), + AvTime: make(map[int64]uint64), + Conversion: make(map[int64]int32), + } + // todo затестить запрос нужно, когда на один тру ответ приходится один тру старт апдейтнуть запрос + allStatistics, err := r.queries.GeneralStatistics(ctx, sqlcgen.GeneralStatisticsParams{ + QuizID: req.QuizId, + Column1: time.Unix(int64(req.From), 0), + Column2: time.Unix(int64(req.To), 0), + }) + if err != nil { + return resp, err + } + + for _, stat := range allStatistics { + resp.Open[stat.TimeBucket.Unix()] = stat.OpenCount + resp.Result[stat.TimeBucket.Unix()] = stat.TrueResultCount + resp.AvTime[stat.TimeBucket.Unix()] = uint64(stat.AvgTime) + resp.Conversion[stat.TimeBucket.Unix()] = stat.Conversion + } + + return resp, nil +} + +type QuestionsStatsResp struct { + // PS это / не или а делить а то я спустя пару часов только догнал + //Funnel 3 отдельных метрики + // 0 - количество сессий с любым ответом кроме start == true / количество сессий с ответом start == true + // 1 - количество сессий с result == false, но тип вопроса, на который ответ == result / количество сессий с ответом start == true + // 2 - количество сессий с ответом result == true / количество сессий с ответом start == true + Funnel [3]float64 + // ключ - заголовок вопроса найденного по айдишнику вопроса в ответе result == true, + // значение - процент ответов с result == true и таким айдишником вопроса + Results map[string]float64 + // ключ - заголовок вопроса, а значение - map, где ключ - вариант ответа на этот вопрос, + // т.е. группировка по полю Контент, а значение - процент таких ответов + Questions map[string]map[string]float64 +} + +func (r *StatisticsRepository) GetQuestionsStatistics(ctx context.Context, req DeviceStatReq) (QuestionsStatsResp, error) { + resp := QuestionsStatsResp{ + Funnel: [3]float64{}, + Results: make(map[string]float64), + Questions: make(map[string]map[string]float64), + } + + queStatistics, err := r.queries.QuestionsStatistics(ctx, sqlcgen.QuestionsStatisticsParams{ + QuizID: req.QuizId, + ToTimestamp: float64(req.From), + ToTimestamp_2: float64(req.To), + }) + if err != nil { + return resp, err + } + + for _, row := range queStatistics { + if row.CountStartTrue != 0 { + resp.Funnel[0] = float64(row.CountStartFalse) / float64(row.CountStartTrue) + resp.Funnel[1] = float64(row.CountFResultWithTQuestion) / float64(row.CountStartTrue) + resp.Funnel[2] = float64(row.CountTResult) / float64(row.CountStartTrue) + } + + resp.Results[row.ResultsTitle] = row.ResultsPercentage + + if resp.Questions[row.QuestionsTitle] == nil { + resp.Questions[row.QuestionsTitle] = make(map[string]float64) + } + resp.Questions[row.QuestionsTitle][row.AnswerContent.String] = row.QuestionsPercentage + } + + return resp, nil +} + +type StatisticResp struct { + // от from до to + Registrations int64 // количество зарегестрированных аккаунтов + Quizes int64 // количество созданных не удаленных квизов + Results int64 // количество ответов с result = true +} + +func (r *StatisticsRepository) AllServiceStatistics(ctx context.Context, from, to uint64) (StatisticResp, error) { + allSvcStats, err := r.queries.AllServiceStatistics(ctx, sqlcgen.AllServiceStatisticsParams{ + ToTimestamp: float64(from), + ToTimestamp_2: float64(to), + }) + + if err != nil { + return StatisticResp{}, err + } + + resp := StatisticResp{ + Registrations: allSvcStats.Registrations, + Quizes: allSvcStats.Quizes, + Results: allSvcStats.Results, + } + + return resp, nil +} diff --git a/sqlc.yaml b/sqlc.yaml index 31e8f53..625e6c4 100644 --- a/sqlc.yaml +++ b/sqlc.yaml @@ -16,6 +16,8 @@ packages: - "./dal/schema/000005_init.down.sql" - "./dal/schema/000006_init.up.sql" - "./dal/schema/000006_init.down.sql" + - "./dal/schema/000007_init.up.sql" + - "./dal/schema/000007_init.down.sql" engine: "postgresql" emit_json_tags: true emit_db_tags: true diff --git a/utils/encrypted.go b/utils/encrypted.go new file mode 100644 index 0000000..24034eb --- /dev/null +++ b/utils/encrypted.go @@ -0,0 +1,57 @@ +package utils + +import ( + "crypto/rand" + "crypto/rsa" + "crypto/x509" + "encoding/pem" + "errors" +) + +type Encrypt struct { + pubKey string + privKey string +} + +func NewEncrypt(pubKey, privKey string) *Encrypt { + return &Encrypt{pubKey: pubKey, privKey: privKey} +} + +func (e *Encrypt) EncryptStr(str string) ([]byte, error) { + block, _ := pem.Decode([]byte(e.pubKey)) + if block == nil { + return nil, errors.New("failed to parse PEM block containing the public key") + } + pub, err := x509.ParsePKIXPublicKey(block.Bytes) + if err != nil { + return nil, err + } + rsaPubKey, ok := pub.(*rsa.PublicKey) + if !ok { + return nil, errors.New("failed to parse RSA public key") + } + + shifr, err := rsa.EncryptPKCS1v15(rand.Reader, rsaPubKey, []byte(str)) + if err != nil { + return nil, err + } + return shifr, nil +} + +func (e *Encrypt) DecryptStr(shifr []byte) (string, error) { + block, _ := pem.Decode([]byte(e.privKey)) + if block == nil { + return "", errors.New("failed to parse PEM block containing the private key") + } + + priv, err := x509.ParsePKCS1PrivateKey(block.Bytes) + if err != nil { + return "", err + } + + res, err := rsa.DecryptPKCS1v15(rand.Reader, priv, shifr) + if err != nil { + return "", err + } + return string(res), nil +} diff --git a/utils/excel.go b/utils/excel.go new file mode 100644 index 0000000..a69d5cc --- /dev/null +++ b/utils/excel.go @@ -0,0 +1,33 @@ +package utils + +import ( + "bytes" + "github.com/tealeg/xlsx" +) + +func CreateExcel(headers []string, data map[int]string) (*bytes.Buffer, error) { + file := xlsx.NewFile() + sheet, err := file.AddSheet("sheet1") + if err != nil { + return nil, err + } + + headerRow := sheet.AddRow() + for _, header := range headers { + cell := headerRow.AddCell() + cell.Value = header + } + + dataRow := sheet.AddRow() + for i := 0; i < len(headers); i++ { + cell := dataRow.AddCell() + cell.Value = data[i] + } + + buffer := new(bytes.Buffer) + if err := file.Write(buffer); err != nil { + return nil, err + } + + return buffer, nil +}