diff --git a/prisma/mysql-migrations/20250918183910_add_kafka_integration/migration.sql b/prisma/mysql-migrations/20250918183910_add_kafka_integration/migration.sql index c3a089bd0..7db06e1ae 100644 --- a/prisma/mysql-migrations/20250918183910_add_kafka_integration/migration.sql +++ b/prisma/mysql-migrations/20250918183910_add_kafka_integration/migration.sql @@ -131,8 +131,7 @@ ALTER TABLE `IntegrationSession` MODIFY `createdAt` TIMESTAMP NULL DEFAULT CURRE MODIFY `updatedAt` TIMESTAMP NOT NULL; -- AlterTable -ALTER TABLE `IsOnWhatsapp` DROP COLUMN `lid`, - MODIFY `createdAt` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, +ALTER TABLE `IsOnWhatsapp` MODIFY `createdAt` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, MODIFY `updatedAt` TIMESTAMP NOT NULL; -- AlterTable diff --git a/prisma/mysql-migrations/20251223093839_re_add_lid_to_is_onwhatsapp/migration.sql b/prisma/mysql-migrations/20251223093839_re_add_lid_to_is_onwhatsapp/migration.sql new file mode 100644 index 000000000..1a6046d67 --- /dev/null +++ b/prisma/mysql-migrations/20251223093839_re_add_lid_to_is_onwhatsapp/migration.sql @@ -0,0 +1,21 @@ +-- Re-add lid column that was incorrectly dropped by previous migration +-- This migration ensures backward compatibility for existing installations + +-- Check if column exists before adding +SET @dbname = DATABASE(); +SET @tablename = 'IsOnWhatsapp'; +SET @columnname = 'lid'; +SET @preparedStatement = (SELECT IF( + ( + SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS + WHERE + (table_name = @tablename) + AND (table_schema = @dbname) + AND (column_name = @columnname) + ) > 0, + 'SELECT 1', + CONCAT('ALTER TABLE `', @tablename, '` ADD COLUMN `', @columnname, '` VARCHAR(100);') +)); +PREPARE alterIfNotExists FROM @preparedStatement; +EXECUTE alterIfNotExists; +DEALLOCATE PREPARE alterIfNotExists; diff --git a/prisma/mysql-schema.prisma b/prisma/mysql-schema.prisma index 71b5a743f..63ef9377d 100644 --- a/prisma/mysql-schema.prisma +++ b/prisma/mysql-schema.prisma @@ -655,6 +655,7 @@ model IsOnWhatsapp { id String @id @default(cuid()) remoteJid String @unique @db.VarChar(100) jidOptions String + lid String? @db.VarChar(100) createdAt DateTime @default(dbgenerated("CURRENT_TIMESTAMP")) @db.Timestamp updatedAt DateTime @updatedAt @db.Timestamp } diff --git a/src/api/integrations/channel/whatsapp/whatsapp.baileys.service.ts b/src/api/integrations/channel/whatsapp/whatsapp.baileys.service.ts index 60e857fcc..089d4ca7b 100644 --- a/src/api/integrations/channel/whatsapp/whatsapp.baileys.service.ts +++ b/src/api/integrations/channel/whatsapp/whatsapp.baileys.service.ts @@ -522,12 +522,27 @@ export class BaileysStartupService extends ChannelStartupService { private async getMessage(key: proto.IMessageKey, full = false) { try { - // Use raw SQL to avoid JSON path issues - const webMessageInfo = (await this.prismaRepository.$queryRaw` - SELECT * FROM "Message" - WHERE "instanceId" = ${this.instanceId} - AND "key"->>'id' = ${key.id} - `) as proto.IWebMessageInfo[]; + const provider = this.configService.get('DATABASE').PROVIDER; + + let webMessageInfo: proto.IWebMessageInfo[]; + + if (provider === 'mysql') { + // MySQL version + webMessageInfo = (await this.prismaRepository.$queryRaw` + SELECT * FROM Message + WHERE instanceId = ${this.instanceId} + AND JSON_UNQUOTE(JSON_EXTRACT(\`key\`, '$.id')) = ${key.id} + LIMIT 1 + `) as proto.IWebMessageInfo[]; + } else { + // PostgreSQL version + webMessageInfo = (await this.prismaRepository.$queryRaw` + SELECT * FROM "Message" + WHERE "instanceId" = ${this.instanceId} + AND "key"->>'id' = ${key.id} + LIMIT 1 + `) as proto.IWebMessageInfo[]; + } if (full) { return webMessageInfo[0]; @@ -1636,13 +1651,24 @@ export class BaileysStartupService extends ChannelStartupService { } const searchId = originalMessageId || key.id; - - const messages = (await this.prismaRepository.$queryRaw` - SELECT * FROM "Message" - WHERE "instanceId" = ${this.instanceId} - AND "key"->>'id' = ${searchId} - LIMIT 1 - `) as any[]; + const dbProvider = this.configService.get('DATABASE').PROVIDER; + + let messages: any[]; + if (dbProvider === 'mysql') { + messages = (await this.prismaRepository.$queryRaw` + SELECT * FROM Message + WHERE instanceId = ${this.instanceId} + AND JSON_UNQUOTE(JSON_EXTRACT(\`key\`, '$.id')) = ${searchId} + LIMIT 1 + `) as any[]; + } else { + messages = (await this.prismaRepository.$queryRaw` + SELECT * FROM "Message" + WHERE "instanceId" = ${this.instanceId} + AND "key"->>'id' = ${searchId} + LIMIT 1 + `) as any[]; + } findMessage = messages[0] || null; if (!findMessage?.id) { @@ -4734,16 +4760,32 @@ export class BaileysStartupService extends ChannelStartupService { private async updateMessagesReadedByTimestamp(remoteJid: string, timestamp?: number): Promise { if (timestamp === undefined || timestamp === null) return 0; - // Use raw SQL to avoid JSON path issues - const result = await this.prismaRepository.$executeRaw` - UPDATE "Message" - SET "status" = ${status[4]} - WHERE "instanceId" = ${this.instanceId} - AND "key"->>'remoteJid' = ${remoteJid} - AND ("key"->>'fromMe')::boolean = false - AND "messageTimestamp" <= ${timestamp} - AND ("status" IS NULL OR "status" = ${status[3]}) - `; + const provider = this.configService.get('DATABASE').PROVIDER; + let result: number; + + if (provider === 'mysql') { + // MySQL version + result = await this.prismaRepository.$executeRaw` + UPDATE Message + SET status = ${status[4]} + WHERE instanceId = ${this.instanceId} + AND JSON_UNQUOTE(JSON_EXTRACT(\`key\`, '$.remoteJid')) = ${remoteJid} + AND JSON_UNQUOTE(JSON_EXTRACT(\`key\`, '$.fromMe')) = 'false' + AND messageTimestamp <= ${timestamp} + AND (status IS NULL OR status = ${status[3]}) + `; + } else { + // PostgreSQL version + result = await this.prismaRepository.$executeRaw` + UPDATE "Message" + SET "status" = ${status[4]} + WHERE "instanceId" = ${this.instanceId} + AND "key"->>'remoteJid' = ${remoteJid} + AND ("key"->>'fromMe')::boolean = false + AND "messageTimestamp" <= ${timestamp} + AND ("status" IS NULL OR "status" = ${status[3]}) + `; + } if (result) { if (result > 0) { @@ -4757,16 +4799,33 @@ export class BaileysStartupService extends ChannelStartupService { } private async updateChatUnreadMessages(remoteJid: string): Promise { - const [chat, unreadMessages] = await Promise.all([ - this.prismaRepository.chat.findFirst({ where: { remoteJid } }), - // Use raw SQL to avoid JSON path issues - this.prismaRepository.$queryRaw` + const provider = this.configService.get('DATABASE').PROVIDER; + + let unreadMessagesPromise: Promise; + + if (provider === 'mysql') { + // MySQL version + unreadMessagesPromise = this.prismaRepository.$queryRaw` + SELECT COUNT(*) as count FROM Message + WHERE instanceId = ${this.instanceId} + AND JSON_UNQUOTE(JSON_EXTRACT(\`key\`, '$.remoteJid')) = ${remoteJid} + AND JSON_UNQUOTE(JSON_EXTRACT(\`key\`, '$.fromMe')) = 'false' + AND status = ${status[3]} + `.then((result: any[]) => Number(result[0]?.count) || 0); + } else { + // PostgreSQL version + unreadMessagesPromise = this.prismaRepository.$queryRaw` SELECT COUNT(*)::int as count FROM "Message" WHERE "instanceId" = ${this.instanceId} AND "key"->>'remoteJid' = ${remoteJid} AND ("key"->>'fromMe')::boolean = false AND "status" = ${status[3]} - `.then((result: any[]) => result[0]?.count || 0), + `.then((result: any[]) => result[0]?.count || 0); + } + + const [chat, unreadMessages] = await Promise.all([ + this.prismaRepository.chat.findFirst({ where: { remoteJid } }), + unreadMessagesPromise, ]); if (chat && chat.unreadMessages !== unreadMessages) { @@ -4778,50 +4837,95 @@ export class BaileysStartupService extends ChannelStartupService { private async addLabel(labelId: string, instanceId: string, chatId: string) { const id = cuid(); - - await this.prismaRepository.$executeRawUnsafe( - `INSERT INTO "Chat" ("id", "instanceId", "remoteJid", "labels", "createdAt", "updatedAt") - VALUES ($4, $2, $3, to_jsonb(ARRAY[$1]::text[]), NOW(), NOW()) ON CONFLICT ("instanceId", "remoteJid") - DO - UPDATE - SET "labels" = ( - SELECT to_jsonb(array_agg(DISTINCT elem)) - FROM ( - SELECT jsonb_array_elements_text("Chat"."labels") AS elem - UNION - SELECT $1::text AS elem - ) sub - ), - "updatedAt" = NOW();`, - labelId, - instanceId, - chatId, - id, - ); + const provider = this.configService.get('DATABASE').PROVIDER; + + if (provider === 'mysql') { + // MySQL version - use INSERT ... ON DUPLICATE KEY UPDATE + await this.prismaRepository.$executeRawUnsafe( + `INSERT INTO Chat (id, instanceId, remoteJid, labels, createdAt, updatedAt) + VALUES (?, ?, ?, JSON_ARRAY(?), NOW(), NOW()) + ON DUPLICATE KEY UPDATE + labels = JSON_ARRAY_APPEND( + COALESCE(labels, JSON_ARRAY()), + '$', + ? + ), + updatedAt = NOW()`, + id, + instanceId, + chatId, + labelId, + labelId, + ); + } else { + // PostgreSQL version + await this.prismaRepository.$executeRawUnsafe( + `INSERT INTO "Chat" ("id", "instanceId", "remoteJid", "labels", "createdAt", "updatedAt") + VALUES ($4, $2, $3, to_jsonb(ARRAY[$1]::text[]), NOW(), NOW()) ON CONFLICT ("instanceId", "remoteJid") + DO + UPDATE + SET "labels" = ( + SELECT to_jsonb(array_agg(DISTINCT elem)) + FROM ( + SELECT jsonb_array_elements_text("Chat"."labels") AS elem + UNION + SELECT $1::text AS elem + ) sub + ), + "updatedAt" = NOW();`, + labelId, + instanceId, + chatId, + id, + ); + } } private async removeLabel(labelId: string, instanceId: string, chatId: string) { const id = cuid(); - - await this.prismaRepository.$executeRawUnsafe( - `INSERT INTO "Chat" ("id", "instanceId", "remoteJid", "labels", "createdAt", "updatedAt") - VALUES ($4, $2, $3, '[]'::jsonb, NOW(), NOW()) ON CONFLICT ("instanceId", "remoteJid") - DO - UPDATE - SET "labels" = COALESCE ( - ( - SELECT jsonb_agg(elem) - FROM jsonb_array_elements_text("Chat"."labels") AS elem - WHERE elem <> $1 - ), - '[]'::jsonb - ), - "updatedAt" = NOW();`, - labelId, - instanceId, - chatId, - id, - ); + const provider = this.configService.get('DATABASE').PROVIDER; + + if (provider === 'mysql') { + // MySQL version - use INSERT ... ON DUPLICATE KEY UPDATE + await this.prismaRepository.$executeRawUnsafe( + `INSERT INTO Chat (id, instanceId, remoteJid, labels, createdAt, updatedAt) + VALUES (?, ?, ?, JSON_ARRAY(), NOW(), NOW()) + ON DUPLICATE KEY UPDATE + labels = COALESCE( + JSON_REMOVE( + labels, + JSON_UNQUOTE(JSON_SEARCH(labels, 'one', ?)) + ), + JSON_ARRAY() + ), + updatedAt = NOW()`, + id, + instanceId, + chatId, + labelId, + ); + } else { + // PostgreSQL version + await this.prismaRepository.$executeRawUnsafe( + `INSERT INTO "Chat" ("id", "instanceId", "remoteJid", "labels", "createdAt", "updatedAt") + VALUES ($4, $2, $3, '[]'::jsonb, NOW(), NOW()) ON CONFLICT ("instanceId", "remoteJid") + DO + UPDATE + SET "labels" = COALESCE ( + ( + SELECT jsonb_agg(elem) + FROM jsonb_array_elements_text("Chat"."labels") AS elem + WHERE elem <> $1 + ), + '[]'::jsonb + ), + "updatedAt" = NOW();`, + labelId, + instanceId, + chatId, + id, + ); + } } public async baileysOnWhatsapp(jid: string) { diff --git a/src/api/integrations/chatbot/chatwoot/services/chatwoot.service.ts b/src/api/integrations/chatbot/chatwoot/services/chatwoot.service.ts index 906fff188..d15b19804 100644 --- a/src/api/integrations/chatbot/chatwoot/services/chatwoot.service.ts +++ b/src/api/integrations/chatbot/chatwoot/services/chatwoot.service.ts @@ -1617,18 +1617,36 @@ export class ChatwootService { return; } - // Use raw SQL to avoid JSON path issues - const result = await this.prismaRepository.$executeRaw` - UPDATE "Message" - SET - "chatwootMessageId" = ${chatwootMessageIds.messageId}, - "chatwootConversationId" = ${chatwootMessageIds.conversationId}, - "chatwootInboxId" = ${chatwootMessageIds.inboxId}, - "chatwootContactInboxSourceId" = ${chatwootMessageIds.contactInboxSourceId}, - "chatwootIsRead" = ${chatwootMessageIds.isRead || false} - WHERE "instanceId" = ${instance.instanceId} - AND "key"->>'id' = ${key.id} - `; + const provider = this.configService.get('DATABASE').PROVIDER; + let result: number; + + if (provider === 'mysql') { + // MySQL version + result = await this.prismaRepository.$executeRaw` + UPDATE Message + SET + chatwootMessageId = ${chatwootMessageIds.messageId}, + chatwootConversationId = ${chatwootMessageIds.conversationId}, + chatwootInboxId = ${chatwootMessageIds.inboxId}, + chatwootContactInboxSourceId = ${chatwootMessageIds.contactInboxSourceId}, + chatwootIsRead = ${chatwootMessageIds.isRead || false} + WHERE instanceId = ${instance.instanceId} + AND JSON_UNQUOTE(JSON_EXTRACT(\`key\`, '$.id')) = ${key.id} + `; + } else { + // PostgreSQL version + result = await this.prismaRepository.$executeRaw` + UPDATE "Message" + SET + "chatwootMessageId" = ${chatwootMessageIds.messageId}, + "chatwootConversationId" = ${chatwootMessageIds.conversationId}, + "chatwootInboxId" = ${chatwootMessageIds.inboxId}, + "chatwootContactInboxSourceId" = ${chatwootMessageIds.contactInboxSourceId}, + "chatwootIsRead" = ${chatwootMessageIds.isRead || false} + WHERE "instanceId" = ${instance.instanceId} + AND "key"->>'id' = ${key.id} + `; + } this.logger.verbose(`Update result: ${result} rows affected`); @@ -1642,15 +1660,28 @@ export class ChatwootService { } private async getMessageByKeyId(instance: InstanceDto, keyId: string): Promise { - // Use raw SQL query to avoid JSON path issues with Prisma - const messages = await this.prismaRepository.$queryRaw` - SELECT * FROM "Message" - WHERE "instanceId" = ${instance.instanceId} - AND "key"->>'id' = ${keyId} - LIMIT 1 - `; - - return (messages as MessageModel[])[0] || null; + const provider = this.configService.get('DATABASE').PROVIDER; + let messages: MessageModel[]; + + if (provider === 'mysql') { + // MySQL version + messages = await this.prismaRepository.$queryRaw` + SELECT * FROM Message + WHERE instanceId = ${instance.instanceId} + AND JSON_UNQUOTE(JSON_EXTRACT(\`key\`, '$.id')) = ${keyId} + LIMIT 1 + `; + } else { + // PostgreSQL version + messages = await this.prismaRepository.$queryRaw` + SELECT * FROM "Message" + WHERE "instanceId" = ${instance.instanceId} + AND "key"->>'id' = ${keyId} + LIMIT 1 + `; + } + + return messages[0] || null; } private async getReplyToIds( diff --git a/src/api/services/channel.service.ts b/src/api/services/channel.service.ts index 56bec0802..2d7ec8c60 100644 --- a/src/api/services/channel.service.ts +++ b/src/api/services/channel.service.ts @@ -9,7 +9,7 @@ import { TypebotService } from '@api/integrations/chatbot/typebot/services/typeb import { PrismaRepository, Query } from '@api/repository/repository.service'; import { eventManager, waMonitor } from '@api/server.module'; import { Events, wa } from '@api/types/wa.types'; -import { Auth, Chatwoot, ConfigService, HttpServer, Proxy } from '@config/env.config'; +import { Auth, Chatwoot, ConfigService, Database, HttpServer, Proxy } from '@config/env.config'; import { Logger } from '@config/logger.config'; import { NotFoundException } from '@exceptions'; import { Contact, Message, Prisma } from '@prisma/client'; @@ -731,63 +731,127 @@ export class ChannelStartupService { where['remoteJid'] = remoteJid; } - const timestampFilter = - query?.where?.messageTimestamp?.gte && query?.where?.messageTimestamp?.lte - ? Prisma.sql` - AND "Message"."messageTimestamp" >= ${Math.floor(new Date(query.where.messageTimestamp.gte).getTime() / 1000)} - AND "Message"."messageTimestamp" <= ${Math.floor(new Date(query.where.messageTimestamp.lte).getTime() / 1000)}` - : Prisma.sql``; - + const provider = this.configService.get('DATABASE').PROVIDER; const limit = query?.take ? Prisma.sql`LIMIT ${query.take}` : Prisma.sql``; const offset = query?.skip ? Prisma.sql`OFFSET ${query.skip}` : Prisma.sql``; - const results = await this.prismaRepository.$queryRaw` - WITH rankedMessages AS ( - SELECT DISTINCT ON ("Message"."key"->>'remoteJid') - "Contact"."id" as "contactId", - "Message"."key"->>'remoteJid' as "remoteJid", - CASE - WHEN "Message"."key"->>'remoteJid' LIKE '%@g.us' THEN COALESCE("Chat"."name", "Contact"."pushName") - ELSE COALESCE("Contact"."pushName", "Message"."pushName") - END as "pushName", - "Contact"."profilePicUrl", + let results: any[]; + + if (provider === 'mysql') { + // MySQL version + const timestampFilterMysql = + query?.where?.messageTimestamp?.gte && query?.where?.messageTimestamp?.lte + ? Prisma.sql` + AND Message.messageTimestamp >= ${Math.floor(new Date(query.where.messageTimestamp.gte).getTime() / 1000)} + AND Message.messageTimestamp <= ${Math.floor(new Date(query.where.messageTimestamp.lte).getTime() / 1000)}` + : Prisma.sql``; + + results = await this.prismaRepository.$queryRaw` + SELECT + Contact.id as contactId, + JSON_UNQUOTE(JSON_EXTRACT(Message.key, '$.remoteJid')) as remoteJid, + CASE + WHEN JSON_UNQUOTE(JSON_EXTRACT(Message.key, '$.remoteJid')) LIKE '%@g.us' THEN COALESCE(Chat.name, Contact.pushName) + ELSE COALESCE(Contact.pushName, Message.pushName) + END as pushName, + Contact.profilePicUrl, COALESCE( - to_timestamp("Message"."messageTimestamp"::double precision), - "Contact"."updatedAt" - ) as "updatedAt", - "Chat"."name" as "pushName", - "Chat"."createdAt" as "windowStart", - "Chat"."createdAt" + INTERVAL '24 hours' as "windowExpires", - "Chat"."unreadMessages" as "unreadMessages", - CASE WHEN "Chat"."createdAt" + INTERVAL '24 hours' > NOW() THEN true ELSE false END as "windowActive", - "Message"."id" AS "lastMessageId", - "Message"."key" AS "lastMessage_key", + FROM_UNIXTIME(Message.messageTimestamp), + Contact.updatedAt + ) as updatedAt, + Chat.name as chatName, + Chat.createdAt as windowStart, + DATE_ADD(Chat.createdAt, INTERVAL 24 HOUR) as windowExpires, + Chat.unreadMessages as unreadMessages, + CASE WHEN DATE_ADD(Chat.createdAt, INTERVAL 24 HOUR) > NOW() THEN 1 ELSE 0 END as windowActive, + Message.id AS lastMessageId, + Message.key AS lastMessage_key, CASE - WHEN "Message"."key"->>'fromMe' = 'true' THEN 'Você' - ELSE "Message"."pushName" - END AS "lastMessagePushName", - "Message"."participant" AS "lastMessageParticipant", - "Message"."messageType" AS "lastMessageMessageType", - "Message"."message" AS "lastMessageMessage", - "Message"."contextInfo" AS "lastMessageContextInfo", - "Message"."source" AS "lastMessageSource", - "Message"."messageTimestamp" AS "lastMessageMessageTimestamp", - "Message"."instanceId" AS "lastMessageInstanceId", - "Message"."sessionId" AS "lastMessageSessionId", - "Message"."status" AS "lastMessageStatus" - FROM "Message" - LEFT JOIN "Contact" ON "Contact"."remoteJid" = "Message"."key"->>'remoteJid' AND "Contact"."instanceId" = "Message"."instanceId" - LEFT JOIN "Chat" ON "Chat"."remoteJid" = "Message"."key"->>'remoteJid' AND "Chat"."instanceId" = "Message"."instanceId" - WHERE "Message"."instanceId" = ${this.instanceId} - ${remoteJid ? Prisma.sql`AND "Message"."key"->>'remoteJid' = ${remoteJid}` : Prisma.sql``} - ${timestampFilter} - ORDER BY "Message"."key"->>'remoteJid', "Message"."messageTimestamp" DESC - ) - SELECT * FROM rankedMessages - ORDER BY "updatedAt" DESC NULLS LAST - ${limit} - ${offset}; - `; + WHEN JSON_UNQUOTE(JSON_EXTRACT(Message.key, '$.fromMe')) = 'true' THEN 'Você' + ELSE Message.pushName + END AS lastMessagePushName, + Message.participant AS lastMessageParticipant, + Message.messageType AS lastMessageMessageType, + Message.message AS lastMessageMessage, + Message.contextInfo AS lastMessageContextInfo, + Message.source AS lastMessageSource, + Message.messageTimestamp AS lastMessageMessageTimestamp, + Message.instanceId AS lastMessageInstanceId, + Message.sessionId AS lastMessageSessionId, + Message.status AS lastMessageStatus + FROM Message + LEFT JOIN Contact ON Contact.remoteJid = JSON_UNQUOTE(JSON_EXTRACT(Message.key, '$.remoteJid')) AND Contact.instanceId = Message.instanceId + LEFT JOIN Chat ON Chat.remoteJid = JSON_UNQUOTE(JSON_EXTRACT(Message.key, '$.remoteJid')) AND Chat.instanceId = Message.instanceId + WHERE Message.instanceId = ${this.instanceId} + ${remoteJid ? Prisma.sql`AND JSON_UNQUOTE(JSON_EXTRACT(Message.key, '$.remoteJid')) = ${remoteJid}` : Prisma.sql``} + ${timestampFilterMysql} + AND Message.messageTimestamp = ( + SELECT MAX(m2.messageTimestamp) + FROM Message m2 + WHERE JSON_UNQUOTE(JSON_EXTRACT(m2.key, '$.remoteJid')) = JSON_UNQUOTE(JSON_EXTRACT(Message.key, '$.remoteJid')) + AND m2.instanceId = Message.instanceId + ) + ORDER BY updatedAt DESC + ${limit} + ${offset}; + `; + } else { + // PostgreSQL version + const timestampFilter = + query?.where?.messageTimestamp?.gte && query?.where?.messageTimestamp?.lte + ? Prisma.sql` + AND "Message"."messageTimestamp" >= ${Math.floor(new Date(query.where.messageTimestamp.gte).getTime() / 1000)} + AND "Message"."messageTimestamp" <= ${Math.floor(new Date(query.where.messageTimestamp.lte).getTime() / 1000)}` + : Prisma.sql``; + + results = await this.prismaRepository.$queryRaw` + WITH rankedMessages AS ( + SELECT DISTINCT ON ("Message"."key"->>'remoteJid') + "Contact"."id" as "contactId", + "Message"."key"->>'remoteJid' as "remoteJid", + CASE + WHEN "Message"."key"->>'remoteJid' LIKE '%@g.us' THEN COALESCE("Chat"."name", "Contact"."pushName") + ELSE COALESCE("Contact"."pushName", "Message"."pushName") + END as "pushName", + "Contact"."profilePicUrl", + COALESCE( + to_timestamp("Message"."messageTimestamp"::double precision), + "Contact"."updatedAt" + ) as "updatedAt", + "Chat"."name" as "pushName", + "Chat"."createdAt" as "windowStart", + "Chat"."createdAt" + INTERVAL '24 hours' as "windowExpires", + "Chat"."unreadMessages" as "unreadMessages", + CASE WHEN "Chat"."createdAt" + INTERVAL '24 hours' > NOW() THEN true ELSE false END as "windowActive", + "Message"."id" AS "lastMessageId", + "Message"."key" AS "lastMessage_key", + CASE + WHEN "Message"."key"->>'fromMe' = 'true' THEN 'Você' + ELSE "Message"."pushName" + END AS "lastMessagePushName", + "Message"."participant" AS "lastMessageParticipant", + "Message"."messageType" AS "lastMessageMessageType", + "Message"."message" AS "lastMessageMessage", + "Message"."contextInfo" AS "lastMessageContextInfo", + "Message"."source" AS "lastMessageSource", + "Message"."messageTimestamp" AS "lastMessageMessageTimestamp", + "Message"."instanceId" AS "lastMessageInstanceId", + "Message"."sessionId" AS "lastMessageSessionId", + "Message"."status" AS "lastMessageStatus" + FROM "Message" + LEFT JOIN "Contact" ON "Contact"."remoteJid" = "Message"."key"->>'remoteJid' AND "Contact"."instanceId" = "Message"."instanceId" + LEFT JOIN "Chat" ON "Chat"."remoteJid" = "Message"."key"->>'remoteJid' AND "Chat"."instanceId" = "Message"."instanceId" + WHERE "Message"."instanceId" = ${this.instanceId} + ${remoteJid ? Prisma.sql`AND "Message"."key"->>'remoteJid' = ${remoteJid}` : Prisma.sql``} + ${timestampFilter} + ORDER BY "Message"."key"->>'remoteJid', "Message"."messageTimestamp" DESC + ) + SELECT * FROM rankedMessages + ORDER BY "updatedAt" DESC NULLS LAST + ${limit} + ${offset}; + `; + } if (results && isArray(results) && results.length > 0) { const mappedResults = results.map((contact) => {