This commit is contained in:
skeris 2024-09-12 17:24:42 +03:00
parent fad3296f33
commit 58e924bf7e
2 changed files with 124 additions and 134 deletions

@ -511,87 +511,82 @@ FROM
AND tb.time_interval_end = at.time_interval_end;
-- name: QuestionsStatistics :many
WITH Funnel AS (
WITH QuizAnswers AS (
SELECT
session, start, result, question_id, created_at, content, quiz_id
FROM answer
WHERE answer.quiz_id = $1 AND created_at between TO_TIMESTAMP($2)::timestamp and TO_TIMESTAMP($3)::timestamp
), QuizQuestions AS (SELECT title, page, id from question where quiz_id = $1), 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
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
QuizAnswers a
LEFT JOIN (
SELECT DISTINCT a.session, q.id AS qid_true_result
FROM answer a
FROM QuizAnswers a
JOIN question q ON a.question_id = q.id
WHERE a.result = TRUE AND q.quiz_id = $1
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
COALESCE(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
),
SELECT
COALESCE(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
LEFT JOIN QuizAnswers a ON q.id = a.question_id
WHERE
a.result = TRUE
GROUP BY
q.title, a.result, a.quiz_id
HAVING
COUNT(*) >= 1
),
LastContent AS (
SELECT
a.question_id,
a.content AS last_answer_content
a.content AS last_answer_content,
a.result,
a.start
FROM
answer a
JOIN (
QuizAnswers a
LEFT JOIN (
SELECT
session,
question_id,
MAX(created_at) AS last_created_at
FROM
answer
QuizAnswers
WHERE
quiz_id = $1
AND start != true
AND created_at >= TO_TIMESTAMP($2)
AND created_at <= TO_TIMESTAMP($3)
start != true
GROUP BY
question_id, session
) AS last_created_at_one_session ON a.session = last_created_at_one_session.session AND a.question_id = last_created_at_one_session.question_id AND a.created_at = last_created_at_one_session.last_created_at
question_id, session
) AS last_created_at_one_session ON a.session = last_created_at_one_session.session
AND a.question_id = last_created_at_one_session.question_id
AND a.created_at = last_created_at_one_session.last_created_at
),
Questions AS (
SELECT
q.title AS question_title,
q.page AS question_page,
lc.last_answer_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 LastContent lc ON q.id = lc.question_id
JOIN answer a ON q.id = a.question_id
WHERE
a.quiz_id = $1
AND a.start != true
AND a.created_at >= TO_TIMESTAMP($2)
AND a.created_at <= TO_TIMESTAMP($3)
GROUP BY
q.id, q.title, lc.last_answer_content
HAVING
COUNT(*) >= 1
)
SELECT
q.title AS question_title,
MAX(q.page) AS question_page,
lc.last_answer_content AS answer_content,
CAST(
COUNT(CASE WHEN lc.result = FALSE THEN 1 END) * 100.0 / NULLIF(SUM(COUNT(CASE WHEN lc.result = FALSE THEN 1 END)) OVER (PARTITION BY q.id), 0) AS FLOAT8
) AS percentage
FROM
LastContent lc
JOIN QuizQuestions q ON q.id = lc.question_id
WHERE
lc.start != true
GROUP BY
q.id, q.title, lc.last_answer_content
HAVING
COUNT(*) >= 1
)
SELECT
Funnel.count_start_false,
Funnel.count_start_true,
@ -605,8 +600,8 @@ SELECT
COALESCE(Questions.percentage, 0) AS questions_percentage
FROM
Funnel
LEFT JOIN Results ON true
LEFT JOIN Questions ON Questions.percentage >= 1;
LEFT JOIN Results ON true
LEFT JOIN Questions ON Questions.percentage >= 1;
-- name: QuizCopyQid :one
INSERT INTO quiz (

@ -3164,87 +3164,82 @@ func (q *Queries) MoveToHistoryQuiz(ctx context.Context, arg MoveToHistoryQuizPa
}
const questionsStatistics = `-- name: QuestionsStatistics :many
WITH Funnel AS (
WITH QuizAnswers AS (
SELECT
session, start, result, question_id, created_at, content, quiz_id
FROM answer
WHERE answer.quiz_id = $1 AND created_at between TO_TIMESTAMP($2)::timestamp and TO_TIMESTAMP($3)::timestamp
), QuizQuestions AS (SELECT title, page, id from question where quiz_id = $1), 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
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
QuizAnswers a
LEFT JOIN (
SELECT DISTINCT a.session, q.id AS qid_true_result
FROM answer a
FROM QuizAnswers a
JOIN question q ON a.question_id = q.id
WHERE a.result = TRUE AND q.quiz_id = $1
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
COALESCE(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
),
SELECT
COALESCE(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
LEFT JOIN QuizAnswers a ON q.id = a.question_id
WHERE
a.result = TRUE
GROUP BY
q.title, a.result, a.quiz_id
HAVING
COUNT(*) >= 1
),
LastContent AS (
SELECT
a.question_id,
a.content AS last_answer_content
a.content AS last_answer_content,
a.result,
a.start
FROM
answer a
JOIN (
QuizAnswers a
LEFT JOIN (
SELECT
session,
question_id,
MAX(created_at) AS last_created_at
FROM
answer
QuizAnswers
WHERE
quiz_id = $1
AND start != true
AND created_at >= TO_TIMESTAMP($2)
AND created_at <= TO_TIMESTAMP($3)
start != true
GROUP BY
question_id, session
) AS last_created_at_one_session ON a.session = last_created_at_one_session.session AND a.question_id = last_created_at_one_session.question_id AND a.created_at = last_created_at_one_session.last_created_at
question_id, session
) AS last_created_at_one_session ON a.session = last_created_at_one_session.session
AND a.question_id = last_created_at_one_session.question_id
AND a.created_at = last_created_at_one_session.last_created_at
),
Questions AS (
SELECT
q.title AS question_title,
q.page AS question_page,
lc.last_answer_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 LastContent lc ON q.id = lc.question_id
JOIN answer a ON q.id = a.question_id
WHERE
a.quiz_id = $1
AND a.start != true
AND a.created_at >= TO_TIMESTAMP($2)
AND a.created_at <= TO_TIMESTAMP($3)
GROUP BY
q.id, q.title, lc.last_answer_content
HAVING
COUNT(*) >= 1
)
SELECT
q.title AS question_title,
MAX(q.page) AS question_page,
lc.last_answer_content AS answer_content,
CAST(
COUNT(CASE WHEN lc.result = FALSE THEN 1 END) * 100.0 / NULLIF(SUM(COUNT(CASE WHEN lc.result = FALSE THEN 1 END)) OVER (PARTITION BY q.id), 0) AS FLOAT8
) AS percentage
FROM
LastContent lc
JOIN QuizQuestions q ON q.id = lc.question_id
WHERE
lc.start != true
GROUP BY
q.id, q.title, lc.last_answer_content
HAVING
COUNT(*) >= 1
)
SELECT
Funnel.count_start_false,
Funnel.count_start_true,
@ -3258,8 +3253,8 @@ SELECT
COALESCE(Questions.percentage, 0) AS questions_percentage
FROM
Funnel
LEFT JOIN Results ON true
LEFT JOIN Questions ON Questions.percentage >= 1
LEFT JOIN Results ON true
LEFT JOIN Questions ON Questions.percentage >= 1
`
type QuestionsStatisticsParams struct {
@ -3269,16 +3264,16 @@ type QuestionsStatisticsParams struct {
}
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"`
QuestionsPage int16 `db:"questions_page" json:"questions_page"`
AnswerContent string `db:"answer_content" json:"answer_content"`
QuestionsPercentage float64 `db:"questions_percentage" json:"questions_percentage"`
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"`
QuestionsPage interface{} `db:"questions_page" json:"questions_page"`
AnswerContent string `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) {