common/dal/db_query/queries.sql

1493 lines
55 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

-- 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,
session,
auditory
)
VALUES ($1,$2,$3,$4,$5,$6,$7,$8,$9,$10,$11)
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, 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, 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,
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 :one
INSERT INTO account (id, user_id, created_at, deleted) VALUES ($1, $2, $3, $4) RETURNING *;
-- 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' OR status = 'ai') AND
qid = $1;
-- name: GetQuestionTitle :one
SELECT title, questiontype,page 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: 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 :many
SELECT
a.id,
a.user_id,
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: GetExpiredDayPrivilege :many
SELECT p.id, p.privilegeID, p.privilege_name, p.amount, p.created_at, a.user_id
FROM privileges p
JOIN account a ON p.account_id = a.id
WHERE p.created_at + p.amount * interval '1 day' < NOW()
AND p.privilegeID = $1;
-- name: GetExpiredCountPrivilege :many
SELECT p.id, p.privilegeID, p.privilege_name, p.amount, p.created_at, a.user_id
FROM privileges p
JOIN account a ON p.account_id = a.id
WHERE p.amount = 0
AND p.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 (a.question_id)
a.content, a.created_at, a.question_id, a.id,a.version, q.questiontype::Text as 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 :one
INSERT INTO answer(
content,
quiz_id,
question_id,
fingerprint,
session,
result,
email,
device_type,
device,
os,
browser,
ip,
start,
utm,
version
) VALUES ($1,$2,$3,$4,$5,$6,$7,$8,$9,$10,$11,$12,$13,$14,$15)
RETURNING *;
-- name: GetResultAnswers :many
SELECT DISTINCT on (question_id) id, content, quiz_id, question_id, fingerprint, session,created_at, result, new,deleted, device_type,device,os,browser,ip,version FROM answer WHERE session = (
SELECT session FROM answer WHERE answer.id = $1) 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,auditory FROM question WHERE quiz_id = $1 AND deleted = FALSE ORDER BY page ASC;
-- 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
date_trunc('hour', timestamp_bucket)::TIMESTAMP AS time_interval_start,
COALESCE(LEAD(
date_trunc('hour', timestamp_bucket)::TIMESTAMP
) OVER (ORDER BY timestamp_bucket), NOW()) AS time_interval_end
FROM
generate_series(TO_TIMESTAMP($1), TO_TIMESTAMP($2), CASE
WHEN EXTRACT(epoch FROM TO_TIMESTAMP($2)) - EXTRACT(epoch FROM TO_TIMESTAMP($1)) > 172800 THEN '1 day'::interval
ELSE '1 hour'::interval
END) 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 >= TO_TIMESTAMP($1)
AND created_at <= TO_TIMESTAMP($2)
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 >= TO_TIMESTAMP($1)
AND created_at <= TO_TIMESTAMP($2)
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)) - EXTRACT(epoch FROM (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 >= TO_TIMESTAMP($1)
AND a.created_at <= TO_TIMESTAMP($2)
AND b.created_at >= TO_TIMESTAMP($1)
AND b.created_at <= TO_TIMESTAMP($2)
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)::float / COALESCE(os.open_count, 0)::float
ELSE 0
END::float 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 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
FROM
QuizAnswers a
LEFT JOIN (
SELECT DISTINCT a.session, q.id AS qid_true_result
FROM QuizAnswers a
JOIN question q ON a.question_id = q.id
WHERE a.result = TRUE AND a.quiz_id = $1
) AS q ON a.session = q.session
),
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
),
LastContent AS (
SELECT
a.question_id,
a.content AS last_answer_content,
a.result,
a.start
FROM
QuizAnswers a
LEFT JOIN (
SELECT
session,
question_id,
MAX(created_at) AS last_created_at
FROM
QuizAnswers
WHERE
quiz_id = $1
AND start != true
AND created_at >= TO_TIMESTAMP($2)
AND created_at <= TO_TIMESTAMP($3)
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
),
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
Funnel.count_start_false,
Funnel.count_start_true,
Funnel.count_f_result_with_t_question,
Funnel.count_t_result,
COALESCE(Results.question_title, '') AS results_title,
COALESCE(Results.percentage, 0) AS results_percentage,
COALESCE(Questions.question_title, '') AS questions_title,
COALESCE(Questions.question_page, 0) AS questions_page,
COALESCE(Questions.answer_content, '') AS answer_content,
COALESCE(Questions.percentage, 0) AS questions_percentage
FROM
Funnel
LEFT JOIN Results ON true
LEFT JOIN Questions ON 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;
-- name: GetListStartQuiz :many
SELECT id FROM quiz WHERE accountid = $1 AND status = 'start';
-- name: GetListCreatedQuizzes :many
SELECT id
FROM quiz
WHERE accountid = $1;
-- name: TemplateCopy :one
WITH copied_quiz AS (
INSERT INTO quiz (accountid, name,fingerprinting,repeatable,note_prevented,mail_notifications,unique_answers,super,group_id, description, config, status,limit_answers,due_to,time_of_passing,pausable,version,version_comment, parent_ids)
SELECT $1 AS accountid,name,fingerprinting,repeatable,note_prevented,mail_notifications,unique_answers,super,group_id, description, config, 'stop' AS status,limit_answers,due_to,time_of_passing,pausable,version,version_comment, parent_ids
FROM quiz
WHERE qid = $2 and status = 'template'
RETURNING id
)
INSERT INTO question (quiz_id, title, description, questiontype, required, deleted, page, content, version, parent_ids)
SELECT cq.id AS quiz_id, q.title, q.description, q.questiontype, q.required, q.deleted, q.page, q.content, q.version, q.parent_ids
FROM question q
JOIN quiz old ON q.quiz_id = old.id
JOIN copied_quiz cq ON old.qid = $2
RETURNING quiz_id;
-- amo methods:
-- name: CreateAmoAccount :exec
INSERT INTO accountsAmo (AccountID, AmoID,Name, Subdomain, Country,DriveURL)
VALUES ($1, $2, $3, $4, $5, $6);
-- name: CreateWebHook :exec
INSERT INTO tokens (AccountID, RefreshToken, AccessToken, AuthCode, Expiration, CreatedAt)
VALUES ($1, $2, $3, $4, $5, $6);
-- name: WebhookUpdate :exec
UPDATE tokens SET AccessToken = $1,RefreshToken = $2,Expiration = to_timestamp(($3)::bigint) AT TIME ZONE 'UTC' + INTERVAL '3 hours',CreatedAt = to_timestamp(($4)::bigint) AT TIME ZONE 'UTC' + INTERVAL '3 hours'
WHERE accountID = $5;
-- name: GetAllTokens :many
SELECT * FROM tokens;
-- name: CheckExpiredToken :one
SELECT * FROM tokens WHERE AccountID = $1 AND Expiration <= NOW();
-- name: UpdateAmoAccount :exec
UPDATE accountsAmo SET Name = $2, Subdomain = $3, Country = $4, DriveURL = $5 WHERE AccountID = $1 AND Deleted = false;
-- name: WebhookDelete :exec
WITH companyDel AS (
UPDATE accountsAmo SET Deleted = true WHERE accountsAmo.AmoID = $1 RETURNING AccountID
),
userDel AS (
UPDATE usersAmo SET Deleted = true WHERE AmoID = $1
)
DELETE FROM tokens WHERE AccountID IN (SELECT AccountID FROM companyDel);
-- name: SoftDeleteAccount :exec
WITH amoCompany AS (
SELECT AmoID FROM accountsAmo WHERE accountsAmo.AccountID = $1 AND deleted = false
),usersDel AS (
UPDATE usersAmo SET Deleted = true WHERE AmoID = (SELECT AmoID FROM amoCompany)
),
companyDel AS ( UPDATE accountsAmo SET Deleted = true WHERE AmoID = (SELECT AmoID FROM amoCompany)
)
DELETE FROM tokens WHERE tokens.AccountID = $1;
-- name: GetCurrentCompany :one
SELECT * FROM accountsAmo WHERE AccountID = $1 AND Deleted = false;
-- name: GetAllCompanyUsers :many
SELECT * FROM usersamo WHERE amoid = $1 AND deleted = false;
-- name: GetUsersWithPagination :many
WITH user_data AS (
SELECT AmoID FROM accountsAmo WHERE accountsAmo.AccountID = $1 AND accountsAmo.Deleted = false
)
SELECT u.*
FROM usersAmo u
JOIN user_data a ON u.AmoID = a.AmoID
WHERE u.Deleted = false
ORDER BY u.ID OFFSET ($2 - 1) * $3 LIMIT $3;
-- name: GetUsersCount :one
WITH user_data AS (
SELECT AmoID FROM accountsAmo WHERE accountsAmo.AccountID = $1 AND accountsAmo.Deleted = false
)
SELECT COUNT(*) FROM usersAmo u JOIN user_data a ON u.AmoID = a.AmoID WHERE u.Deleted = false;
-- name: GetTagsWithPagination :many
WITH user_data AS (
SELECT AmoID FROM accountsAmo WHERE accountsAmo.AccountID = $1 AND accountsAmo.Deleted = false
)
SELECT t.*
FROM tags t JOIN user_data u ON t.AccountID = u.AmoID
WHERE t.Deleted = false
ORDER BY t.ID OFFSET ($2 - 1) * $3 LIMIT $3;
-- name: GetTagsCount :one
WITH user_data AS (
SELECT AmoID FROM accountsAmo WHERE accountsAmo.AccountID = $1 AND accountsAmo.Deleted = false
)
SELECT COUNT(*) FROM tags t JOIN user_data u ON t.AccountID = u.AmoID WHERE t.Deleted = false;
-- name: GetStepsWithPagination :many
WITH user_data AS (
SELECT AmoID FROM accountsAmo WHERE accountsAmo.AccountID = $1 AND accountsAmo.Deleted = false
)
SELECT s.*
FROM steps s JOIN user_data u ON s.AccountID = u.AmoID
WHERE s.Deleted = false AND s.PipelineID = $4
ORDER BY s.ID OFFSET ($2 - 1) * $3 LIMIT $3;
-- name: GetStepsCount :one
WITH user_data AS (
SELECT AmoID FROM accountsAmo WHERE accountsAmo.AccountID = $1 AND accountsAmo.Deleted = false
)
SELECT COUNT(*) FROM steps s JOIN user_data u ON s.AccountID = u.AmoID WHERE s.Deleted = false AND s.PipelineID = $2;
-- name: GetPipelinesWithPagination :many
WITH user_data AS (
SELECT AmoID FROM accountsAmo WHERE accountsAmo.AccountID = $1 AND accountsAmo.Deleted = false
)
SELECT p.*
FROM pipelines p JOIN user_data u ON p.AccountID = u.AmoID
WHERE p.Deleted = false
ORDER BY p.ID OFFSET ($2 - 1) * $3 LIMIT $3;
-- name: GetPipelinesCount :one
WITH user_data AS (
SELECT AmoID FROM accountsAmo WHERE accountsAmo.AccountID = $1 AND accountsAmo.Deleted = false
)
SELECT COUNT(*) FROM pipelines p JOIN user_data u ON p.AccountID = u.AmoID WHERE p.Deleted = false;
-- name: GetFieldsWithPagination :many
WITH user_data AS (
SELECT AmoID FROM accountsAmo WHERE accountsAmo.AccountID = $1 AND accountsAmo.Deleted = false
)
SELECT f.*
FROM fields f JOIN user_data u ON f.AccountID = u.AmoID
WHERE f.Deleted = false
ORDER BY f.ID OFFSET ($2 - 1) * $3 LIMIT $3;
-- name: GetFieldsCount :one
WITH user_data AS (
SELECT AmoID FROM accountsAmo WHERE accountsAmo.AccountID = $1 AND accountsAmo.Deleted = false
)
SELECT COUNT(*) FROM fields f JOIN user_data u ON f.AccountID = u.AmoID WHERE f.Deleted = false;
-- name: UpdateTags :exec
UPDATE tags AS t
SET name = (update_data ->> 'Name')::varchar(512),
color = (update_data ->> 'Color')::varchar(50)
FROM json_array_elements($1::json) AS update_data
WHERE t.amoID = (update_data ->> 'AmoID')::INT
AND t.accountID = (update_data ->> 'AccountID')::INT
AND t.Entity = (update_data ->> 'Entity')::entitytype;
-- name: UpdatePipelines :exec
UPDATE pipelines AS p
SET name = (update_data ->> 'Name')::varchar(512),
isArchive = CASE WHEN (update_data ->> 'IsArchive') = 'true' THEN TRUE ELSE FALSE END
FROM json_array_elements($1::json) AS update_data
WHERE p.amoID = (update_data ->> 'AmoID')::INT
AND p.accountID = (update_data ->> 'AccountID')::INT;
-- name: UpdateSteps :exec
UPDATE steps AS s
SET name = (update_data ->> 'Name')::varchar(512),
color = (update_data ->> 'Color')::varchar(50)
FROM json_array_elements($1::json) AS update_data
WHERE s.amoID = (update_data ->> 'AmoID')::INT
AND s.accountID = (update_data ->> 'AccountID')::INT
AND s.pipelineID = (update_data ->> 'PipelineID')::INT;
-- name: UpdateFields :exec
UPDATE fields AS f
SET name = (update_data ->> 'Name')::varchar(512),
code = (update_data ->> 'Code')::varchar(255),
type = (update_data ->> 'Type')::fieldtype
FROM json_array_elements($1::json) AS update_data
WHERE f.amoID = (update_data ->> 'AmoID')::INT
AND f.accountID = (update_data ->> 'AccountID')::INT
AND f.Entity = (update_data ->> 'Entity')::entitytype;
-- name: CheckTags :many
WITH user_data AS (
SELECT AmoID FROM accountsAmo WHERE accountsAmo.AccountID = $1 AND accountsAmo.Deleted = false
), new_tags AS (
SELECT (tag->>'AmoID')::INT AS amoID,
(tag->>'Entity')::entitytype AS Entity,
COALESCE(tag->>'Name', '')::VARCHAR(512) AS name,
COALESCE(tag->>'Color', '')::VARCHAR(50) AS color
FROM json_array_elements($2::json) AS tag
), inserted_tags AS (
INSERT INTO tags (amoID, accountID, Entity, name, color, createdAt)
SELECT nt.amoID,
ud.AmoID,
nt.Entity,
nt.name,
nt.color,
CURRENT_TIMESTAMP
FROM new_tags nt
JOIN user_data ud ON true
ON CONFLICT (amoID, accountID, Entity) DO UPDATE SET Deleted = false
RETURNING *
)
SELECT nt.*,ud.AmoID
FROM new_tags nt
JOIN user_data ud ON true
WHERE NOT EXISTS (
SELECT *
FROM inserted_tags ins
JOIN user_data ud ON true
WHERE ins.amoID = nt.amoID AND ins.accountID = ud.amoid AND ins.Entity = nt.Entity
);
-- name: CheckPipelines :many
WITH new_pipelines AS (
SELECT (pipeline->>'AmoID')::INT AS amoID,
(pipeline->>'AccountID')::INT AS accountID,
COALESCE(pipeline->>'Name', '')::varchar(512) AS name,
CASE WHEN (pipeline->>'IsArchive') = 'true' THEN TRUE ELSE FALSE END AS isArchive,
CURRENT_TIMESTAMP AS createdAt
FROM json_array_elements($1::json) AS pipeline
), inserted_pipelines AS(
INSERT INTO pipelines (amoID, accountID, name, isArchive, createdAt)
SELECT np.amoID,
np.accountID,
np.name,
np.isArchive,
np.createdAt
FROM new_pipelines np
ON CONFLICT (amoID, accountID) DO NOTHING
RETURNING *
)
SELECT np.*
FROM new_pipelines np
WHERE NOT EXISTS (
SELECT *
FROM inserted_pipelines ins
WHERE ins.amoID = np.amoID AND ins.accountID = np.accountID
);
-- name: CheckFields :many
WITH user_data AS (
SELECT AmoID FROM accountsAmo WHERE accountsAmo.AccountID = $1 AND accountsAmo.Deleted = false
), new_fields AS (
SELECT (field->>'AmoID')::INT AS amoID,
COALESCE(field->>'Code', '')::varchar(255) AS code,
COALESCE(field->>'Name', '')::varchar(512) AS name,
CAST(field->>'Entity' AS entitytype) AS Entity,
COALESCE(field->>'Type', '')::fieldtype AS type,
CURRENT_TIMESTAMP AS createdAt
FROM json_array_elements($2::json) AS field
), inserted_fields AS(
INSERT INTO fields (amoID, code, accountID, name, Entity, type, createdAt)
SELECT nf.amoID,
nf.code,
ud.AmoID,
nf.name,
nf.Entity,
nf.type,
nf.createdAt
FROM new_fields nf
JOIN user_data ud ON true
ON CONFLICT (amoID, accountID, entity) DO UPDATE SET Deleted=false
RETURNING *
)
SELECT nf.*,ud.AmoID
FROM new_fields nf
JOIN user_data ud ON true
WHERE NOT EXISTS (
SELECT *
FROM inserted_fields ins
JOIN user_data ud ON true
WHERE ins.amoID = nf.amoID AND ins.accountID = ud.amoid AND ins.Entity = nf.Entity
);
-- name: CheckSteps :many
WITH new_steps AS (
SELECT (step->>'AmoID')::INT AS amoID,
(step->>'PipelineID')::INT AS pipelineID,
(step->>'AccountID')::INT AS accountID,
COALESCE(step->>'Name', '')::varchar(512) AS name,
COALESCE(step->>'Color', '')::varchar(50) AS color,
CURRENT_TIMESTAMP AS createdAt
FROM json_array_elements($1::json) AS step
), inserted_steps AS (
INSERT INTO steps (amoID, pipelineID, accountID, name, color, createdAt)
SELECT ns.amoID,
ns.pipelineID,
ns.accountID,
ns.name,
ns.color,
ns.createdAt
FROM new_steps ns
ON CONFLICT (amoID, accountID, PipelineID) DO NOTHING
RETURNING *
)
SELECT ns.*
FROM new_steps ns
WHERE NOT EXISTS (
SELECT *
FROM inserted_steps ins
WHERE ins.amoID = ns.amoID AND ins.accountID = ns.accountID AND ins.pipelineID = ns.pipelineID
);
-- name: GetTokenById :one
SELECT * FROM tokens WHERE accountID = $1;
-- name: GetQuizRule :one
SELECT * FROM rules WHERE QuizID = $1 AND AccountID = (SELECT AmoID FROM accountsAmo WHERE accountsAmo.AccountID = $2 AND accountsAmo.Deleted = false) AND Deleted = false;
-- name: SetQuizSettings :one
INSERT INTO rules (AccountID, QuizID, PerformerID, PipelineID, StepID, FieldsRule,TagsToAdd)
SELECT u.AmoID AS AccountID,$1 AS QuizID,$2 AS PerformerID,$3 AS PipelineID,
$4 AS StepID,$5 AS FieldsRule,$6 AS TagsToAdd FROM accountsamo u WHERE u.AccountID = $7 AND u.Deleted = false
RETURNING id;
-- name: ChangeQuizSettings :one
UPDATE rules
SET PerformerID = $1,PipelineID = $2,StepID = $3,FieldsRule = $4, TagsToAdd=$5, Deleted = false
WHERE AccountID = (SELECT AmoID FROM accountsAmo WHERE accountsAmo.AccountID = $6 AND accountsAmo.Deleted = false) AND QuizID = $7
RETURNING id;
-- name: GetQuestionListByIDs :many
SELECT * FROM question WHERE id = ANY($1::int[]) AND deleted = FALSE;
-- name: UpdateFieldRules :exec
UPDATE rules SET FieldsRule = $1
WHERE AccountID = (SELECT AmoID FROM accountsAmo WHERE accountsAmo.AccountID = $2 AND accountsAmo.Deleted = false) AND QuizID = $3 AND Deleted = false;
-- name: UpdateAmoAccountUser :exec
UPDATE usersAmo SET Name = $3, Email = $4, Role = $5, "Group" = $6
WHERE AmoID = $1 AND AmoUserID = $2 AND deleted = false;
-- name: AddAmoAccountUser :exec
INSERT INTO usersAmo (AmoID, AmoUserID, Name, Email, Role, "Group")
VALUES ($1, $2, $3, $4, $5, $6);
-- name: GettingAmoUsersTrueResults :many
SELECT a.quiz_id,a.id,a.result,a.question_id,a.content,a.session,
COALESCE((SELECT a2.utm
FROM answer a2
WHERE a2.start = true AND a2.session = a.session
LIMIT 1), '{}'::jsonb) AS utm
,t.accesstoken,r.accountid,r.fieldsrule,r.tagstoadd,r.performerid,r.stepid,r.pipelineid,(SELECT u.name FROM usersAmo u WHERE u.AmoUserID = r.performerid AND u.amoid = r.accountid AND u.deleted = false) AS performer_name,u.subdomain,u.accountid,u.driveurl
FROM answer a
INNER JOIN quiz q ON a.quiz_id = q.id
LEFT JOIN amoCRMStatuses s ON a.id = s.AnswerID
INNER JOIN rules r ON q.id = r.QuizID
INNER JOIN tokens t ON q.accountid = t.AccountID
INNER JOIN accountsAmo u ON q.accountid = u.accountid AND u.amoid = r.accountid
WHERE a.result = true
AND s.id IS NULL
AND a.deleted = false
AND r.deleted = false
AND q.deleted = false
AND u.deleted = false;
-- name: SettingDealAmoStatus :exec
INSERT INTO amoCRMStatuses (AccountID, DealID, AnswerID, Status)
SELECT u.AmoID, $1, $2, $3
FROM tokens AS t
JOIN accountsAmo AS u ON t.AccountID = u.AccountID
WHERE t.AccessToken = $4 AND u.Deleted = false;
-- name: UpdatingDealAmoStatus :exec
UPDATE amoCRMStatuses SET Status = $1
WHERE DealID = $2 AND AccountID = (SELECT u.AmoID FROM tokens AS t JOIN accountsAmo AS u ON t.AccountID = u.AccountID WHERE t.AccessToken = $3 AND u.Deleted = false);
-- name: DeleteFields :exec
UPDATE fields SET Deleted = true WHERE ID = ANY($1::bigint[]);
-- name: DeleteTags :exec
UPDATE tags SET Deleted = true WHERE ID = ANY($1::bigint[]);
-- name: DeleteSteps :exec
UPDATE steps SET Deleted = true WHERE ID = ANY($1::bigint[]);
-- name: DeletePipelines :exec
UPDATE pipelines SET Deleted = true WHERE ID = ANY($1::bigint[]);
-- name: DeleteUsers :exec
UPDATE usersAmo SET Deleted = true WHERE ID = ANY($1::bigint[]);
-- name: GetUserTagsByID :many
SELECT ID,AmoID,AccountID,Name,Entity,Color
FROM tags
WHERE AccountID = $1 AND Deleted = false;
-- name: GetUserStepsByID :many
SELECT ID,AmoID,PipelineID,AccountID,Name,Color
FROM steps
WHERE AccountID = $1 AND Deleted = false;
-- name: GetUserPipelinesByID :many
SELECT ID,AmoID,AccountID,Name,IsArchive
FROM pipelines
WHERE AccountID = $1 AND Deleted = false;
-- name: GetUserUsersByID :many
SELECT * FROM usersAmo WHERE amoid = $1 AND Deleted = false;
-- name: GetFieldByAmoID :one
SELECT * FROM fields WHERE AmoID = $1 AND Deleted = false;
-- name: GetUserFieldsByID :many
SELECT ID,AmoID,Code,AccountID,Name,Entity,Type
FROM fields
WHERE AccountID = $1 AND Deleted = false;
-- name: DecrementManual :one
UPDATE privileges p SET amount = amount - 1 FROM account a
WHERE p.account_id = a.id AND a.user_id = $1 AND p.privilegeID = $2 AND p.amount > 0
RETURNING p.id, p.privilegeID, p.account_id, p.privilege_name, p.amount, p.created_at;
-- name: GetExistingContactAmo :many
WITH getAmoID AS (
SELECT AmoID FROM amoContact WHERE amoContact.AccountID = $1 AND amoContact.Field = ANY($2::text[])
) SELECT * FROM amoContact
WHERE amoContact.AccountID = $1 AND amoContact.AmoID IN (SELECT AmoID FROM getAmoID);
-- name: InsertContactAmo :one
INSERT INTO amoContact (AccountID, AmoID, Field) VALUES ($1, $2, $3) RETURNING AmoID;
-- name: UpdateAmoContact :exec
UPDATE amoContact SET Field = $1,AmoID=$3 WHERE ID = $2;
-- name: GetQuestionsAI :many
SELECT q.id, q.quiz_id, q.title, q.description, q.questiontype, q.required, q.deleted, q.page, q.content, q.version, q.parent_ids, q.created_at, q.updated_at, q.session,q.auditory FROM question q
WHERE q.quiz_id = $1 AND q.auditory = $2 AND (q.session = $3 OR q.session = '') AND q.deleted = FALSE
ORDER BY (q.session != '') ASC, --без сессии первые потом с сессией
q.page, --по возрастанию страницы
q.created_at --по времени создания
LIMIT $4 OFFSET $5;
-- name: GetQuestionsAICount :one
SELECT COUNT(*) AS count FROM question WHERE quiz_id = $1 AND (session = $2 OR session = '') AND deleted = FALSE;
-- name: CreateQuizAudience :one
INSERT INTO gigachatAudience (QuizID, Sex, Age) VALUES ($1, $2, $3) RETURNING ID;
-- name: GetQuizAudience :many
SELECT * FROM gigachatAudience WHERE QuizID = $1 AND Deleted = FALSE;
-- name: DeleteQuizAudience :exec
UPDATE gigachatAudience set Deleted = TRUE WHERE QuizID = $1 and ID = $2;
-- name: CheckIsOwnerAudience :one
SELECT EXISTS ( SELECT 1 FROM gigachatAudience ga JOIN quiz q ON ga.QuizID = q.id
WHERE ga.QuizID = $1 AND ga.ID = $2 AND q.accountid = $3 AND ga.Deleted = FALSE
) AS is_owner;
-- name: CreateLeadTarget :one
INSERT INTO leadtarget (accountID,type,quizID,target,InviteLink) VALUES ($1,$2,$3,$4,$5) RETURNING *;
-- name: DeleteLeadTarget :exec
UPDATE leadtarget SET deleted = true WHERE id = $1;
-- name: UpdateLeadTarget :one
UPDATE leadtarget SET target = $1,InviteLink = $2 WHERE id = $3 AND deleted=false RETURNING *;
-- name: GetLeadTarget :many
SELECT * FROM leadtarget WHERE accountID = $1 AND quizID = $2 AND deleted=false;
-- name: CreateTgAccount :one
INSERT INTO tgAccounts (ApiID, ApiHash, PhoneNumber,Password, Status)
VALUES ($1, $2, $3, $4, $5) RETURNING id;
-- name: GetAllTgAccounts :many
SELECT * FROM tgAccounts WHERE Deleted = false;
-- name: UpdateStatusTg :exec
UPDATE tgAccounts SET Status = $1 WHERE id = $2;
-- name: SoftDeleteTgAccount :exec
UPDATE tgAccounts SET Deleted = true WHERE id = $1;
-- name: SearchIDByAppIDanAppHash :one
SELECT * FROM tgAccounts WHERE ApiID = $1 and ApiHash=$2 and Deleted = false;
-- name: CheckQuestionOwner :one
SELECT qz.accountid FROM question q
JOIN quiz qz ON q.quiz_id = qz.id WHERE q.id = $1 AND qz.accountid = $2;
-- name: CheckQuizOwner :one
SELECT accountid FROM quiz WHERE id = $1 AND accountid = $2;
-- name: CheckLeadTargetOwner :one
SELECT accountid FROM leadtarget WHERE id = $1 AND accountid = $2;
-- BITRIX
-- name: GetUsersBitrixWithPagination :many
WITH user_data AS (
SELECT BitrixID FROM BitrixAccounts WHERE BitrixAccounts.AccountID = $1 AND BitrixAccounts.Deleted = false
)
SELECT u.*, COUNT(*) OVER() as total_count
FROM BitrixAccountUsers u
JOIN user_data a ON u.BitrixID = a.BitrixID
WHERE u.Deleted = false
ORDER BY u.ID OFFSET ($2 - 1) * $3 LIMIT $3;
-- name: SoftDeleteBitrixAccount :exec
WITH bitrixCompany AS (
SELECT BitrixID FROM BitrixAccounts WHERE BitrixAccounts.AccountID = $1 AND deleted = false
),usersDel AS (
UPDATE BitrixAccountUsers SET Deleted = true WHERE BitrixID = (SELECT BitrixID FROM bitrixCompany)
),
companyDel AS ( UPDATE BitrixAccounts SET Deleted = true WHERE BitrixID = (SELECT BitrixID FROM bitrixCompany)
)
DELETE FROM BitrixTokens WHERE BitrixTokens.AccountID = $1;
-- name: GetCurrentBitrixCompany :one
SELECT * FROM BitrixAccounts WHERE AccountID = $1 AND Deleted = false;
-- name: CheckExpiredBitrixToken :one
SELECT * FROM BitrixTokens WHERE AccountID = $1 AND Expiration <= NOW();
-- name: CreateBitrixAccount :exec
INSERT INTO BitrixAccounts (AccountID, BitrixID, Subdomain)
VALUES ($1, $2, $3);
-- name: AddBitrixAccountUser :exec
INSERT INTO BitrixAccountUsers (AccountID, BitrixIDUserID, Name, LastName, SecondName, Title,Email,UFDepartment,WorkPosition)
VALUES ($1, $2, $3, $4, $5, $6,$7,$8,$9);
-- name: UpdateBitrixAccountUser :exec
UPDATE BitrixAccountUsers SET Name = $3, LastName = $4, SecondName = $5, Title= $6, Email = $7,UFDepartment = $8,WorkPosition=$9
WHERE AccountID = $1 AND BitrixIDUserID = $2 AND deleted = false;
-- name: UpdateBitrixAccount :exec
UPDATE BitrixAccounts SET Subdomain = $2 WHERE AccountID = $1 AND Deleted = false;
-- name: GetBitrixTokenById :one
SELECT * FROM BitrixTokens WHERE accountID = $1;
-- name: DeleteBitrixUsers :exec
UPDATE BitrixAccountUsers SET Deleted = true WHERE ID = ANY($1::bigint[]);
-- name: GetUserUsersByIDBitrix :many
SELECT * FROM BitrixAccountUsers WHERE accountID = $1 AND Deleted = false;
-- name: CreateBitrixWebHook :exec
INSERT INTO BitrixTokens (AccountID, RefreshToken, AccessToken, AuthCode, Expiration, CreatedAt)
VALUES ($1, $2, $3, $4, $5, $6);
-- name: WebhookBitrixUpdate :exec
UPDATE BitrixTokens SET AccessToken = $1,RefreshToken = $2,Expiration = to_timestamp(($3)::bigint) AT TIME ZONE 'UTC' + INTERVAL '3 hours',CreatedAt = to_timestamp(($4)::bigint) AT TIME ZONE 'UTC' + INTERVAL '3 hours'
WHERE accountID = $5;
-- name: GetAllBitrixTokens :many
SELECT * FROM BitrixTokens;
-- name: WebhookBitrixDelete :exec
WITH companyDel AS (
UPDATE BitrixAccounts SET Deleted = true WHERE BitrixAccounts.BitrixID = $1 RETURNING AccountID
),
userDel AS (
UPDATE BitrixAccountUsers SET Deleted = true WHERE AccountID = $1
)
DELETE FROM BitrixTokens WHERE AccountID IN (SELECT AccountID FROM companyDel);
-- name: GetBitrixPipelinesWithPagination :many
WITH user_data AS (
SELECT BitrixID FROM BitrixAccounts WHERE BitrixAccounts.AccountID = $1 AND BitrixAccounts.Deleted = false
)
SELECT p.*, COUNT(*) OVER() as total_count
FROM PipelineBitrix p JOIN user_data u ON p.AccountID = u.BitrixID
WHERE p.Deleted = false
ORDER BY p.ID OFFSET ($2 - 1) * $3 LIMIT $3;
-- name: DeleteBitrixPipelines :exec
UPDATE PipelineBitrix SET Deleted = true WHERE ID = ANY($1::bigint[]);
-- name: GetUserBitrixPipelinesByID :many
SELECT * FROM PipelineBitrix WHERE AccountID = $1 AND Deleted = false;
-- name: CheckBitrixPipelines :many
WITH new_pipelines AS (
SELECT (pipeline->>'bitrixID')::INT AS BitrixID,
(pipeline->>'accountID')::varchar(255) AS AccountID,
COALESCE(pipeline->>'name', '')::varchar(255) AS Name,
(pipeline->>'entityTypeId')::INT as EntityTypeId,
CURRENT_TIMESTAMP AS createdAt
FROM json_array_elements($1::json) AS pipeline
), inserted_pipelines AS(
INSERT INTO PipelineBitrix (BitrixID, AccountID, Name, EntityTypeId, createdAt)
SELECT np.BitrixID,
np.AccountID,
np.Name,
np.EntityTypeId,
np.createdAt
FROM new_pipelines np
ON CONFLICT (BitrixID, AccountID) WHERE Deleted = false DO NOTHING
RETURNING *
)
SELECT np.*
FROM new_pipelines np
WHERE NOT EXISTS (
SELECT *
FROM inserted_pipelines ins
WHERE ins.BitrixID = np.BitrixID AND ins.AccountID = np.AccountID
);
-- name: UpdateBitrixPipelines :exec
UPDATE PipelineBitrix AS p
SET Name = (update_data ->> 'name')::varchar(255),EntityTypeId = (update_data ->> 'entityTypeId')::INT
FROM json_array_elements($1::json) AS update_data
WHERE p.BitrixID = (update_data ->> 'BitrixID')::INT
AND p.AccountID = (update_data ->> 'AccountID')::varchar(255);
-- name: GetBitrixStepsWithPagination :many
WITH user_data AS (
SELECT BitrixID FROM BitrixAccounts WHERE BitrixAccounts.AccountID = $1 AND BitrixAccounts.Deleted = false
)
SELECT s.*, COUNT(*) OVER() as total_count
FROM StepBitrix s JOIN user_data u ON s.AccountID = u.BitrixID
WHERE s.Deleted = false ORDER BY s.ID OFFSET ($2 - 1) * $3 LIMIT $3;
-- name: DeleteBitrixSteps :exec
UPDATE StepBitrix SET Deleted = true WHERE ID = ANY($1::bigint[]);
-- name: GetUserBitrixStepsByID :many
SELECT * FROM StepBitrix WHERE AccountID = $1 AND Deleted = false;
-- name: CheckBitrixSteps :many
WITH new_steps AS (
SELECT (step->>'bitrixID')::VARCHAR(255) AS BitrixID,
(step->>'pipelineID')::INT AS PipelineID,
(step->>'accountID')::VARCHAR(255) AS AccountID,
(step->>'entityID')::VARCHAR(255) AS EntityID,
(step->>'statusID')::VARCHAR(255) AS StatusID,
COALESCE(step->>'name', '')::VARCHAR(255) AS Name,
COALESCE(step->>'nameInit', '')::VARCHAR(255) AS NameInit,
COALESCE(step->>'color', '')::VARCHAR(50) AS Color,
CURRENT_TIMESTAMP AS CreatedAt
FROM json_array_elements($1::json) AS step
), inserted_steps AS (
INSERT INTO StepBitrix (BitrixID, PipelineID, AccountID,EntityID, StatusID, Name,NameInit, Color, CreatedAt)
SELECT ns.BitrixID,
ns.PipelineID,
ns.AccountID,
ns.EntityID,
ns.StatusID,
ns.Name,
ns.NameInit,
ns.Color,
ns.CreatedAt
FROM new_steps ns
ON CONFLICT (BitrixID, AccountID) WHERE Deleted = false DO NOTHING
RETURNING *
)
SELECT ns.*
FROM new_steps ns
WHERE NOT EXISTS (
SELECT *
FROM inserted_steps ins
WHERE ins.BitrixID = ns.BitrixID AND ins.AccountID = ns.AccountID
);
-- name: UpdateBitrixSteps :exec
UPDATE StepBitrix AS s SET
Name = (update_data ->> 'name')::varchar(255),
NameInit = (update_data ->> 'nameInit')::varchar(255),
Color = (update_data ->> 'color')::varchar(50),
EntityID = (update_data ->> 'entityID')::varchar(255),
StatusID = (update_data ->> 'statusID')::varchar(255),
PipelineID = (update_data ->> 'pipelineID')::INT
FROM json_array_elements($1::json) AS update_data
WHERE s.BitrixID = (update_data ->> 'bitrixID')::VARCHAR(255)
AND s.AccountID = (update_data ->> 'accountID')::VARCHAR(255);
-- name: GetBitrixFieldsWithPagination :many
WITH user_data AS (
SELECT BitrixID FROM BitrixAccounts WHERE BitrixAccounts.AccountID = $1 AND BitrixAccounts.Deleted = false
)
SELECT f.*, COUNT(*) OVER() as total_count
FROM BitrixFields f JOIN user_data u ON f.AccountID = u.BitrixID
WHERE f.Deleted = false
ORDER BY f.ID OFFSET ($2 - 1) * $3 LIMIT $3;
-- name: GetUserBitrixFieldsByID :many
SELECT * FROM BitrixFields WHERE AccountID = $1 AND Deleted = false;
-- name: DeleteBitrixFields :exec
UPDATE BitrixFields SET Deleted = true WHERE ID = ANY($1::bigint[]);
-- name: GetBitrixFieldByID :one
SELECT * FROM BitrixFields WHERE BitrixID = $1 AND Deleted = false;
-- name: CheckBitrixFields :many
WITH user_data AS (
SELECT BitrixID FROM BitrixAccounts WHERE BitrixAccounts.AccountID = $1 AND BitrixAccounts.Deleted = false
), new_fields AS (
SELECT
(field->>'bitrixID')::VARCHAR(255) AS BitrixID,
(field->>'accountID')::VARCHAR(255) AS AccountID,
CAST(field->>'entityID' AS FieldsType) AS EntityID,
COALESCE(field->>'fieldName', '')::VARCHAR(255) AS FieldName,
COALESCE(field->>'editFromLabel', '')::VARCHAR(255) AS EditFromLabel,
CAST(field->>'fieldType' AS CustomFieldsType) AS FieldType,
CURRENT_TIMESTAMP AS CreatedAt
FROM json_array_elements($2::json) AS field
), inserted_fields AS (
INSERT INTO BitrixFields (BitrixID, AccountID, EntityID, FieldName, EditFromLabel, FieldType, CreatedAt)
SELECT
nf.BitrixID,
ud.BitrixID AS AccountID,
nf.EntityID,
nf.FieldName,
nf.EditFromLabel,
nf.FieldType,
nf.CreatedAt
FROM new_fields nf
JOIN user_data ud ON true
ON CONFLICT (BitrixID, AccountID, EntityID) DO NOTHING
RETURNING *
)
SELECT nf.*, ud.BitrixID AS AccountID
FROM new_fields nf
JOIN user_data ud ON true
WHERE NOT EXISTS (
SELECT *
FROM inserted_fields ins
JOIN user_data ud ON true
WHERE ins.BitrixID = nf.BitrixID AND ins.AccountID = ud.BitrixID AND ins.EntityID = nf.EntityID
);
-- name: UpdateBitrixFields :exec
UPDATE BitrixFields AS f SET
FieldName = (update_data ->> 'fieldName')::varchar(255),
EditFromLabel = (update_data ->> 'editFromLabel')::varchar(255),
FieldType = (update_data ->> 'fieldType')::CustomFieldsType
FROM json_array_elements($1::json) AS update_data
WHERE f.BitrixID = (update_data ->> 'bitrixID')::VARCHAR(255)
AND f.AccountID = (update_data ->> 'accountID')::VARCHAR(255)
AND f.EntityID = (update_data ->> 'entityID')::FieldsType;
-- name: ChangeBitrixQuizSettings :one
UPDATE BitrixRule
SET PerformerID = $1,PipelineID = $2,TypeID = $3,StageID= $4,SourceID = $5,StatusID = $6,FieldsRule = $7, TagsToAdd=$8, LeadFlag = $9
WHERE AccountID = (SELECT BitrixID FROM bitrixaccounts WHERE bitrixaccounts.AccountID = $10 AND bitrixaccounts.Deleted = false) AND QuizID = $11 AND Deleted = false
RETURNING id;
-- name: SetBitrixQuizSettings :one
INSERT INTO BitrixRule (AccountID, QuizID, PerformerID, PipelineID, TypeID,StageID,SourceID,StatusID, FieldsRule,TagsToAdd,LeadFlag)
SELECT u.bitrixid AS AccountID,$1 AS QuizID,$2 AS PerformerID,$3 AS PipelineID,
$4 AS TypeID,$5 AS StageID,$6 AS SourceID,$7 AS StatusID,$8 AS FieldsRule,$9 AS TagsToAdd, $10 AS LeadFlag FROM bitrixaccounts u WHERE u.AccountID = $11 AND u.Deleted = false
RETURNING id;
-- name: GetBitrixQuizRule :one
SELECT * FROM BitrixRule WHERE QuizID = $1 AND Deleted = false;
-- name: UpdateBitrixFieldRules :exec
UPDATE BitrixRule SET FieldsRule = $1
WHERE AccountID = (SELECT BitrixID FROM bitrixaccounts WHERE bitrixaccounts.AccountID = $2 AND bitrixaccounts.Deleted = false) AND QuizID = $3 AND Deleted = false;
-- name: GettingBitrixUsersTrueResults :many
SELECT a.quiz_id,a.id,a.result,a.question_id,a.content,a.session,
COALESCE((SELECT a2.utm
FROM answer a2
WHERE a2.start = true AND a2.session = a.session
LIMIT 1), '{}'::jsonb) AS utm
,t.accesstoken,r.accountid,r.fieldsrule,r.tagstoadd,r.performerid,r.TypeID,r.StageID,r.SourceID,r.StatusID,r.pipelineid,(SELECT u.name FROM BitrixAccountUsers u WHERE u.bitrixiduserid = r.performerid AND u.deleted = false) AS performer_name,u.subdomain,u.accountid,r.leadflag
FROM answer a
INNER JOIN quiz q ON a.quiz_id = q.id
LEFT JOIN bitrixcrmstatuses s ON a.id = s.AnswerID
INNER JOIN bitrixrule r ON q.id = r.QuizID
INNER JOIN bitrixtokens t ON q.accountid = t.AccountID
INNER JOIN bitrixaccounts u ON q.accountid = u.accountid AND u.bitrixid = r.accountid
WHERE a.result = true
AND s.id IS NULL
AND a.deleted = false
AND r.deleted = false
AND q.deleted = false
AND u.deleted = false;
-- name: SettingDealBitrixStatus :exec
INSERT INTO bitrixCRMStatuses (AccountID, DealID, AnswerID, Status)
SELECT u.BitrixID, $1, $2, $3
FROM BitrixTokens AS t
JOIN BitrixAccounts AS u ON t.AccountID = u.AccountID
WHERE t.AccessToken = $4 AND u.Deleted = false;
-- name: GetExistingContactBitrix :many
WITH getBitrixID AS (
SELECT BitrixID FROM bitrixContact WHERE bitrixContact.AccountID = $1 AND bitrixContact.Field = ANY($2::text[])
) SELECT * FROM bitrixContact
WHERE bitrixContact.AccountID = $1 AND bitrixContact.BitrixID IN (SELECT BitrixID FROM getBitrixID);
-- name: InsertContactBitrix :one
INSERT INTO bitrixContact (AccountID, BitrixID, Field) VALUES ($1, $2, $3) RETURNING BitrixID;
-- name: UpdateBitrixContact :exec
UPDATE bitrixContact SET Field = $1,BitrixID=$3 WHERE ID = $2;
-- name: UpdateGigaChatQuizFlag :exec
UPDATE quiz SET gigachat = true where id = $1 AND accountid = $2 AND deleted = false;
-- name: GetAllQuizUtms :many
SELECT * from quiz_utm where quizID = $1 and deleted=false;
-- name: CreateQuizUtm :one
INSERT into quiz_utm (quizID,utm) values ($1,$2) RETURNING *;
-- name: SoftDeleteQuizUtm :exec
UPDATE quiz_utm set deleted = true where id = $1;
-- name: GetQuizPrivilegeUsage :one
SELECT * FROM quiz_privilege_usage
WHERE quiz_id = $1 AND privilege_id = $2 AND privilege_id_str = $3 LIMIT 1;
-- name: InsertQuizPrivilegeUsage :one
INSERT INTO quiz_privilege_usage (quiz_id, privilege_id, privilege_id_str, used_count)
VALUES ($1, $2, $3, 1) RETURNING *;
-- name: IncrementQuizPrivilegeUsage :exec
UPDATE quiz_privilege_usage SET used_count = used_count + 1, updated_at = CURRENT_TIMESTAMP
WHERE quiz_id = $1 AND privilege_id = $2 AND privilege_id_str = $3;
-- name: ResetQuizPrivilegeUsageCount :exec
UPDATE quiz_privilege_usage SET used_count = 0, updated_at = CURRENT_TIMESTAMP
WHERE quiz_id = $1 AND privilege_id = $2 AND privilege_id_str = $3;