common/dal/db_query/queries.sql
2024-03-22 14:31:37 +03:00

613 lines
21 KiB
SQL

-- name: InsertQuiz :one
INSERT INTO quiz (accountid,
fingerprinting,
repeatable,
note_prevented,
mail_notifications,
unique_answers,
super,
group_id,
name,
description,
config,
status,
limit_answers,
due_to,
time_of_passing,
pausable,
parent_ids,
questions_count,
qid
)
VALUES ($1,$2,$3,$4,$5,$6,$7,$8,$9,$10,$11,$12,$13,$14,$15,$16,$17,$18,$19)
RETURNING id, created_at, updated_at, qid;
-- name: InsertQuestion :one
INSERT INTO question (
quiz_id,
title,
description,
questiontype,
required,
page,
content,
parent_ids,
updated_at
)
VALUES ($1,$2,$3,$4,$5,$6,$7,$8,$9)
RETURNING id, created_at, updated_at;
-- name: DeleteQuestion :one
UPDATE question SET deleted=true WHERE id=$1 RETURNING question.*;
-- name: DeleteQuizByID :one
UPDATE quiz SET deleted=true WHERE quiz.id=$1 AND accountid=$2 RETURNING quiz.*;
-- name: CopyQuestion :one
INSERT INTO question(
quiz_id, title, description, questiontype, required,
page, content, version, parent_ids
)
SELECT $1, title, description, questiontype, required,
page, content, version, parent_ids
FROM question WHERE question.id=$2
RETURNING question.id, quiz_id, created_at, updated_at;
-- name: DuplicateQuestion :one
INSERT INTO question(
quiz_id, title, description, questiontype, required,
page, content, version, parent_ids
)
SELECT quiz_id, title, description, questiontype, required,
page, content, version, parent_ids
FROM question WHERE question.id=$1
RETURNING question.id, quiz_id, created_at, updated_at;
-- name: MoveToHistory :one
INSERT INTO question(
quiz_id, title, description, questiontype, required,
page, content, version, parent_ids, deleted
)
SELECT quiz_id, title, description, questiontype, required,
page, content, version, parent_ids, true as deleted
FROM question WHERE question.id=$1
RETURNING question.id, quiz_id, parent_ids;
-- name: MoveToHistoryQuiz :one
INSERT INTO quiz(deleted,
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 true as deleted, 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
FROM quiz WHERE quiz.id=$1 AND quiz.accountid=$2
RETURNING quiz.id, qid, parent_ids;
-- name: CopyQuiz :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 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
FROM quiz WHERE quiz.id=$1 AND quiz.accountId=$2
RETURNING id, qid,created_at, updated_at;
-- name: CopyQuizQuestions :exec
INSERT INTO question(
quiz_id, title, description, questiontype, required, page, content, version, parent_ids
)
SELECT $2, title, description, questiontype, required, page, content, version, parent_ids
FROM question WHERE question.quiz_id=$1 AND deleted=false;
-- name: GetQuizHistory :many
SELECT * FROM quiz WHERE quiz.id = $1 AND quiz.accountId = $4 OR quiz.id = ANY(
SELECT unnest(parent_ids) FROM quiz WHERE id = $1
) ORDER BY quiz.id DESC LIMIT $2 OFFSET $3;
-- name: GetQuestionHistory :many
SELECT * FROM question WHERE question.id = $1 OR question.id = ANY(
SELECT unnest(parent_ids) FROM question WHERE id = $1
) ORDER BY question.id DESC LIMIT $2 OFFSET $3;
-- name: ArchiveQuiz :exec
UPDATE quiz SET archived = true WHERE id=$1 AND accountId=$2;
-- name: GetPrivilegesByAccountID :many
SELECT id,privilegeID,privilege_name,amount, created_at FROM privileges WHERE account_id = $1;
-- name: GetAccountWithPrivileges :many
SELECT a.id, a.user_id, a.created_at, a.deleted,
coalesce(p.id,0) AS privilege_id,
coalesce(p.privilegeID,''),
coalesce(p.privilege_name,''),
coalesce(p.amount,0), coalesce(p.created_at,Now()) AS privilege_created_at
FROM account a
LEFT JOIN privileges AS p ON a.id = p.account_id
WHERE a.user_id = $1;
-- name: GetPrivilegesQuizAccount :many
SELECT
p.privilegeID,
p.privilege_name,
p.amount,
p.created_at,
a.id,
a.email,
qz.config
FROM
privileges AS p
INNER JOIN account AS a ON p.account_id = a.id
INNER JOIN quiz AS qz ON qz.accountid = a.user_id
WHERE
qz.id = $1;
-- name: CreateAccount :exec
INSERT INTO account (id, user_id, email, created_at, deleted) VALUES ($1, $2, $3, $4, $5);
-- name: DeletePrivilegeByAccID :exec
DELETE FROM privileges WHERE account_id = $1;
-- name: DeleteAccountById :exec
DELETE FROM account WHERE id = $1;
-- name: AccountPagination :many
SELECT a.id, a.user_id, a.created_at, a.deleted
FROM account a ORDER BY a.created_at DESC LIMIT $1 OFFSET $2;
-- name: UpdatePrivilege :exec
UPDATE privileges SET amount = $1, created_at = $2 WHERE account_id = $3 AND privilegeID = $4;
-- name: InsertPrivilege :exec
INSERT INTO privileges (privilegeID, account_id, privilege_name, amount, created_at) VALUES ($1, $2, $3, $4, $5);
-- name: GetQuizByQid :one
SELECT * FROM quiz
WHERE
deleted = false AND
archived = false AND
status = 'start' AND
qid = $1;
-- name: GetQuestionTitle :one
SELECT title, questiontype FROM question WHERE id = $1;
-- name: WorkerTimeoutProcess :exec
UPDATE quiz SET status = 'timeout' WHERE deleted = false AND due_to <> 0 AND due_to < EXTRACT(epoch FROM CURRENT_TIMESTAMP);
-- name: GetQuizById :one
SELECT * FROM quiz WHERE id=$1 AND accountId=$2;
-- name: InsertPrivilegeWC :exec
UPDATE privileges SET amount = $1, created_at = $2 WHERE account_id = $3 AND privilegeID = $4;
-- name: GetPrivilegesByAccountIDWC :many
SELECT p.id,p.privilegeID,p.privilege_name,p.amount, p.created_at FROM privileges as p JOIN account as a on p.account_id = a.id WHERE a.user_id = $1;
-- name: WorkerStatProcess :exec
WITH answer_aggregates AS (
SELECT
quiz_id,
COUNT(DISTINCT session) AS unique_true_answers_count
FROM
answer
WHERE
result = TRUE
GROUP BY
quiz_id
),
question_aggregates AS (
SELECT
q.id AS quiz_id,
COUNT(qs.id) AS total_questions
FROM
quiz q
INNER JOIN
question qs ON q.id = qs.quiz_id
WHERE
q.deleted = false
AND q.archived = false
AND qs.deleted = false
GROUP BY
q.id
),
session_times_aggregates AS (
SELECT
quiz_id, COUNT(session) as sess,
AVG(extract(epoch FROM session_time)) AS average_session_time
FROM (
SELECT
quiz_id,
session,
(MAX(created_at) - MIN(created_at)) AS session_time
FROM
answer
GROUP BY
quiz_id,
session
) AS all_sessions
GROUP BY
quiz_id
)
UPDATE quiz q
SET
questions_count = COALESCE(qa.total_questions, 0),
answers_count = COALESCE(aa.unique_true_answers_count, 0),
average_time_passing = COALESCE(sta.average_session_time, 0),
sessions_count = COALESCE(sta.sess,0)
FROM
(SELECT * FROM quiz WHERE deleted = FALSE AND archived = FALSE) q_sub
LEFT JOIN answer_aggregates aa ON q_sub.id = aa.quiz_id
LEFT JOIN question_aggregates qa ON q_sub.id = qa.quiz_id
LEFT JOIN session_times_aggregates sta ON q_sub.id = sta.quiz_id
WHERE
q.id = q_sub.id;
-- name: UpdatePrivilegeAmount :exec
UPDATE privileges SET amount = $1 WHERE id = $2;
-- name: GetAccAndPrivilegeByEmail :one
SELECT
a.id,
a.user_id,
a.email,
a.created_at,
COALESCE(p.ID,0),
coalesce(p.privilegeid,''),
coalesce(p.amount,0),
coalesce(p.created_at,Now())
FROM
account AS a
LEFT JOIN privileges AS p ON a.id = p.account_id
WHERE
a.user_id = $1;
-- name: DeletePrivilegeByID :exec
DELETE FROM privileges WHERE id = $1;
-- name: GetQuizConfig :one
SELECT config, accountid FROM quiz WHERE id = $1 AND deleted = false;
-- name: GetExpiredPrivilege :many
SELECT id, privilegeID, privilege_name, amount, created_at
FROM privileges
WHERE created_at + amount * interval '1 day' < NOW()
AND privilegeid = $1;
-- name: CheckAndAddDefault :exec
UPDATE privileges
SET amount = $1, created_at = NOW()
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 AND start = false ORDER BY question_id ASC, created_at DESC;
-- name: InsertAnswers :exec
INSERT INTO answer(
content,
quiz_id,
question_id,
fingerprint,
session,
result,
email,
device_type,
device,
os,
browser,
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) 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;
-- name: SoftDeleteResultByID :exec
UPDATE answer SET deleted = TRUE WHERE id = $1 AND deleted = FALSE;
-- 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 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 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
WITH original_quiz AS (
SELECT id
FROM quiz
WHERE quiz.qid = $1 AND quiz.accountId = $2
),
new_quiz AS (
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
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
FROM
quiz
WHERE
qid = $1 AND accountId = $2
RETURNING id,qid
)
SELECT
original_quiz.id AS original_quiz_id,
new_quiz.id AS new_quiz_id,
new_quiz.qid AS original_qid
FROM
original_quiz, new_quiz;
-- 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;