Skip to content

Commit

Permalink
Update
Browse files Browse the repository at this point in the history
  • Loading branch information
varmoh authored Jan 6, 2025

Verified

This commit was created on GitHub.com and signed with GitHub’s verified signature. The key has expired.
1 parent c856fc9 commit 144bdb0
Showing 27 changed files with 599 additions and 78 deletions.
8 changes: 4 additions & 4 deletions .env.img
Original file line number Diff line number Diff line change
@@ -1,19 +1,19 @@
RELEASE=backoffice-module-test
VERSION=1
BUILD=2
FIX=222-service
FIX=223-service

RELEASE=analytics-module-test
VERSION=1
BUILD=2
FIX=16
FIX=17

RELEASE=training-module-test
VERSION=1
BUILD=2
FIX=30
FIX=31

RELEASE=service-module-test
VERSION=1
BUILD=2
FIX=30
FIX=31
Original file line number Diff line number Diff line change
@@ -0,0 +1,24 @@
<?xml version="1.0" encoding="UTF-8"?>
<databaseChangeLog xmlns="http://www.liquibase.org/xml/ns/dbchangelog"
xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance"
xsi:schemaLocation="http://www.liquibase.org/xml/ns/dbchangelog
http://www.liquibase.org/xml/ns/dbchangelog/dbchangelog-4.1.xsd">

<changeSet id="20241227154101" author="vassilim">
<createTable tableName="user_page_preferences">
<column name="id" type="bigint" autoIncrement="true">
<constraints primaryKey="true" nullable="false"/>
</column>
<column name="user_id" type="varchar(50)">
<constraints nullable="false"/>
</column>
<column name="page_name" type="varchar(50)">
<constraints nullable="false"/>
</column>
<column name="page_results" type="int">
<constraints nullable="false"/>
</column>
<column name="created" type="timestamp with time zone"/>
</createTable>
</changeSet>
</databaseChangeLog>
9 changes: 7 additions & 2 deletions Resql/analytics/POST/csa-avg-chat-time.sql
Original file line number Diff line number Diff line change
@@ -15,9 +15,14 @@ chat_lengths AS (
WHERE chat.base_id IN (SELECT base_id FROM chats)
GROUP BY chat.base_id
)
SELECT date_time, max("user".display_name) AS customer_support_display_name, max("user".id_code) AS customer_support_id, ROUND(EXTRACT(epoch FROM COALESCE(AVG(chat_length), '0 seconds'::interval)) / 60) AS avg_min
SELECT
date_time,
max("user".display_name) AS customer_support_display_name,
max(CONCAT("user".first_name, ' ', "user".last_name)) AS customer_support_full_name,
max("user".id_code) AS customer_support_id,
ROUND(EXTRACT(epoch FROM COALESCE(AVG(chat_length), '0 seconds'::interval)) / 60) AS avg_min
FROM chats
LEFT JOIN chat_lengths ON chats.base_id = chat_lengths.base_id
LEFT JOIN "user" ON "user".id_code = chats.author_id
WHERE "user".id_code NOT IN (:excluded_csas)
GROUP BY date_time, author_id;
GROUP BY date_time, author_id;
3 changes: 2 additions & 1 deletion Resql/analytics/POST/csa-chats-count.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,7 @@
SELECT date_trunc(:metric, chat.created) AS date_time,
max("user".display_name) AS customer_support_display_name,
max("user".id_code) AS customer_support_id,
max(CONCAT("user".first_name, ' ', "user".last_name)) AS customer_support_full_name,
COUNT(DISTINCT chat.base_id)
FROM chat
JOIN message ON message.chat_base_id = chat.base_id
@@ -12,4 +13,4 @@ WHERE message.author_role IN ('backoffice-user', 'end-user')
AND message.author_id <> 'null'
AND "user".id_code NOT IN (:excluded_csas)
AND chat.created::date BETWEEN :start::date AND :end::date
GROUP BY date_time, message.author_id;
GROUP BY date_time, message.author_id;
91 changes: 56 additions & 35 deletions Resql/analytics/POST/feedback-chats-with-negative-feedback.sql
Original file line number Diff line number Diff line change
@@ -1,41 +1,62 @@
WITH n_chats AS (
SELECT
SELECT
base_id,
MAX(created) AS created
FROM chat
WHERE STATUS = 'ENDED'
AND created::date BETWEEN :start::date AND :end::date
AND feedback_rating IS NOT NULL
AND feedback_rating <= 5
GROUP BY base_id
),
c_chat AS (
SELECT
base_id,
MAX(created) AS created
FROM chat
WHERE STATUS = 'ENDED'
AND created::date BETWEEN :start::date AND :end::date
AND feedback_rating IS NOT NULL
AND feedback_rating <= 5
GROUP BY base_id
),
c_chat AS (
SELECT base_id,
MIN(created) AS created,
MAX(ended) AS ended
FROM chat
GROUP BY base_id
)
SELECT n_chats.base_id,
c_chat.created,
c_chat.ended,
chat.feedback_rating AS rating,
chat.feedback_text AS feedback,
CEIL(COUNT(*) OVER() / :page_size::DECIMAL) AS total_pages
FROM chat
GROUP BY base_id
),
deduplicated_users AS (
SELECT
id_code,
first_name,
last_name
FROM (
SELECT
id_code,
first_name,
last_name,
ROW_NUMBER() OVER (PARTITION BY id_code ORDER BY first_name, last_name) AS row_num
FROM "user"
) AS ranked_users
WHERE row_num = 1
)
SELECT
n_chats.base_id,
c_chat.created,
c_chat.ended,
chat.feedback_rating AS rating,
chat.feedback_text AS feedback,
deduplicated_users.first_name AS first_name,
deduplicated_users.last_name AS last_name,
CEIL(COUNT(*) OVER() / :page_size::DECIMAL) AS total_pages
FROM n_chats
LEFT JOIN chat ON n_chats.base_id = chat.base_id
JOIN c_chat ON c_chat.base_id = chat.base_id AND n_chats.created = chat.created
LEFT JOIN chat ON n_chats.base_id = chat.base_id
LEFT JOIN c_chat ON c_chat.base_id = chat.base_id AND n_chats.created = chat.created
LEFT JOIN deduplicated_users ON chat.customer_support_id = deduplicated_users.id_code
WHERE chat.feedback_rating IS NOT NULL
AND chat.ended IS NOT NULL
ORDER BY
CASE WHEN :sorting = 'created desc' THEN n_chats.created END DESC,
CASE WHEN :sorting = 'created asc' THEN n_chats.created END ASC,
CASE WHEN :sorting = 'ended desc' THEN n_chats.created END DESC,
CASE WHEN :sorting = 'ended asc' THEN n_chats.created END ASC,
CASE WHEN :sorting = 'base_id desc' THEN n_chats.base_id END DESC,
CASE WHEN :sorting = 'base_id asc' THEN n_chats.base_id END ASC,
CASE WHEN :sorting = 'feedback desc' THEN feedback_text END DESC,
CASE WHEN :sorting = 'feedback asc' THEN feedback_text END ASC,
CASE WHEN :sorting = 'rating desc' THEN feedback_rating END DESC,
CASE WHEN :sorting = 'rating asc' THEN feedback_rating END ASC
OFFSET ((GREATEST(:page, 1) - 1) * :page_size) LIMIT :page_size;
AND chat.ended IS NOT NULL
ORDER BY
CASE WHEN :sorting = 'created desc' THEN n_chats.created END DESC,
CASE WHEN :sorting = 'created asc' THEN n_chats.created END ASC,
CASE WHEN :sorting = 'ended desc' THEN n_chats.created END DESC,
CASE WHEN :sorting = 'ended asc' THEN n_chats.created END ASC,
CASE WHEN :sorting = 'base_id desc' THEN n_chats.base_id END DESC,
CASE WHEN :sorting = 'base_id asc' THEN n_chats.base_id END ASC,
CASE WHEN :sorting = 'feedback desc' THEN feedback_text END DESC,
CASE WHEN :sorting = 'feedback asc' THEN feedback_text END ASC,
CASE WHEN :sorting = 'rating desc' THEN feedback_rating END DESC,
CASE WHEN :sorting = 'rating asc' THEN feedback_rating END ASC
OFFSET ((GREATEST(:page, 1) - 1) * :page_size)
LIMIT :page_size;
62 changes: 32 additions & 30 deletions Resql/analytics/POST/feedback-selected-csa-feedback-nps.sql
Original file line number Diff line number Diff line change
@@ -1,47 +1,49 @@
WITH chat_csas AS (
SELECT DISTINCT base_id,
first_value(created) over (
first_value(created) over (
PARTITION by base_id
ORDER BY updated
) AS created,
last_value(customer_support_id) over (
last_value(customer_support_id) over (
PARTITION by base_id
ORDER BY updated
) AS customer_support_id,
first_value(customer_support_display_name) over (
first_value(customer_support_display_name) over (
PARTITION by customer_support_id
ORDER BY updated DESC
) AS customer_support_display_name,
last_value(feedback_rating) over (
last_value(feedback_rating) over (
PARTITION by base_id
ORDER BY updated
) AS feedback_rating
FROM chat
WHERE customer_support_id <> ''
AND EXISTS (
SELECT 1
FROM message
WHERE message.chat_base_id = chat.base_id
AND message.author_role = 'backoffice-user'
)
AND EXISTS (
SELECT 1
FROM message
WHERE message.chat_base_id = chat.base_id
AND message.author_role = 'end-user'
)
AND STATUS = 'ENDED'
AND feedback_rating IS NOT NULL
AND created::date BETWEEN :start::date AND :end::date
AND customer_support_id NOT IN (:excluded_csas)
)
SELECT date_trunc(:metric, created) AS date_time,
customer_support_id,
TRIM(customer_support_display_name) AS customer_support_display_name,
coalesce(CAST(((
SUM(CASE WHEN feedback_rating BETWEEN 9 AND 10 THEN 1 ELSE 0 END) * 1.0 -
SUM(CASE WHEN feedback_rating BETWEEN 0 AND 6 THEN 1 ELSE 0 END)
) / COUNT(base_id) * 100) AS int), 0) AS nps
AND EXISTS (
SELECT 1
FROM message
WHERE message.chat_base_id = chat.base_id
AND message.author_role = 'backoffice-user'
)
AND EXISTS (
SELECT 1
FROM message
WHERE message.chat_base_id = chat.base_id
AND message.author_role = 'end-user'
)
AND STATUS = 'ENDED'
AND feedback_rating IS NOT NULL
AND created::date BETWEEN :start::date AND :end::date
AND customer_support_id NOT IN (:excluded_csas)
)
SELECT date_trunc(:metric, chat_csas.created) AS date_time,
customer_support_id,
TRIM(customer_support_display_name) AS customer_support_display_name,
max(CONCAT("user".first_name, ' ', "user".last_name)) AS customer_support_full_name,
coalesce(CAST(((
SUM(CASE WHEN feedback_rating BETWEEN 9 AND 10 THEN 1 ELSE 0 END) * 1.0 -
SUM(CASE WHEN feedback_rating BETWEEN 0 AND 6 THEN 1 ELSE 0 END)
) / COUNT(base_id) * 100) AS int), 0) AS nps
FROM chat_csas
GROUP BY date_time, customer_support_id, customer_support_display_name
ORDER BY date_time
LEFT JOIN "user" ON "user".id_code = chat_csas.customer_support_id
GROUP BY date_time, customer_support_id, customer_support_display_name
ORDER BY date_time
57 changes: 57 additions & 0 deletions Resql/analytics/POST/get-chat-by-id.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,57 @@
SELECT c.base_id AS id,
c.customer_support_id,
c.customer_support_display_name,
c.end_user_id,
c.end_user_first_name,
c.end_user_last_name,
c.status,
c.feedback_text,
c.feedback_rating,
c.end_user_email,
c.end_user_phone,
c.end_user_os,
c.end_user_url,
c.created,
c.updated,
c.ended,
c.external_id,
c.received_from,
c.received_from_name,
c.forwarded_to_name,
c.forwarded_to,
(CASE WHEN (SELECT value FROM configuration WHERE key = 'is_csa_title_visible' AND configuration.id IN (SELECT max(id) from configuration GROUP BY key) AND deleted = false) = 'true'
THEN c.csa_title ELSE '' END) AS csa_title,
m.content AS last_message,
m.updated AS last_message_timestamp
FROM (
SELECT
base_id,
customer_support_id,
customer_support_display_name,
end_user_id,
end_user_first_name,
end_user_last_name,
status,
feedback_text,
feedback_rating,
end_user_email,
end_user_phone,
end_user_os,
end_user_url,
created,
updated,
ended,
external_id,
received_from,
received_from_name,
forwarded_to_name,
forwarded_to,
csa_title
FROM chat
WHERE base_id = :id
ORDER BY updated DESC
LIMIT 1
) AS c
JOIN message AS m ON c.base_id = m.chat_base_id
ORDER BY m.updated DESC
LIMIT 1;
39 changes: 39 additions & 0 deletions Resql/analytics/POST/get-chat-messages.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,39 @@
WITH MaxMessages AS (
SELECT max(id) AS maxId
FROM message
WHERE chat_base_id = :chatId
GROUP BY base_id
),
LatestActiveUser AS (
SELECT
u.id_code, u.created, u.csa_title
FROM
"user" u INNER JOIN (
SELECT iu.id_code, max(created) AS MaxCreated
FROM "user" iu
WHERE iu.status = 'active'
GROUP BY iu.id_code
) iju ON iju.id_code = u.id_code AND iju.MaxCreated = u.created
)
SELECT m.base_id AS id,
m.chat_base_id AS chat_id,
m.content,
m.buttons,
m.options,
m.event,
m.author_id,
m.author_timestamp,
m.author_first_name,
m.author_last_name,
m.author_role,
m.forwarded_by_user,
m.forwarded_from_csa,
m.forwarded_to_csa,
rating,
m.created,
updated,
u.csa_title
FROM message m
LEFT JOIN LatestActiveUser u ON m.author_id = u.id_code
JOIN MaxMessages ON m.id = maxId
ORDER BY created ASC;
4 changes: 4 additions & 0 deletions Resql/analytics/POST/get-user-page-preferences.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
SELECT * FROM user_page_preferences
WHERE user_id = :user_id
AND page_name = :page_name
ORDER BY created DESC LIMIT 1;
2 changes: 2 additions & 0 deletions Resql/analytics/POST/update-user-page-preferences.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,2 @@
INSERT INTO user_page_preferences (user_id, page_name, page_results,created)
VALUES (:user_id, :page_name, :page_results,:created::timestamp with time zone);
Loading

0 comments on commit 144bdb0

Please sign in to comment.