Skip to content
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
Original file line number Diff line number Diff line change
@@ -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;
1 change: 1 addition & 0 deletions prisma/mysql-schema.prisma
Original file line number Diff line number Diff line change
Expand Up @@ -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
}
Expand Down
240 changes: 172 additions & 68 deletions src/api/integrations/channel/whatsapp/whatsapp.baileys.service.ts
Original file line number Diff line number Diff line change
Expand Up @@ -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>('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
Comment on lines +529 to +538
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

issue (bug_risk): MySQL label insertion does not deduplicate labels like the PostgreSQL version does.

In Postgres, labels is built with array_agg(DISTINCT elem), so each label appears at most once per chat. In MySQL, JSON_ARRAY_APPEND(COALESCE(labels, JSON_ARRAY()), '$', ?) can add the same labelId multiple times, changing the semantics from a set to a multiset across providers. This mismatch can cause subtle bugs if callers assume uniqueness. Please add a deduplication step for MySQL (e.g., via JSON_TABLE or a normalization function) so both backends behave consistently.

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];
Expand Down Expand Up @@ -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>('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) {
Expand Down Expand Up @@ -4734,16 +4760,32 @@ export class BaileysStartupService extends ChannelStartupService {
private async updateMessagesReadedByTimestamp(remoteJid: string, timestamp?: number): Promise<number> {
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>('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) {
Comment on lines +4782 to 4791
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

issue (bug_risk): MySQL label removal can wipe the entire labels array when the label is not present.

In the MySQL branch, if JSON_SEARCH doesn’t find the label, it returns NULL. JSON_REMOVE(labels, NULL) then evaluates to NULL, so COALESCE(NULL, JSON_ARRAY()) resets labels to an empty array. This turns a no-op removal into data loss.

Consider restructuring so JSON_REMOVE is only called when JSON_SEARCH finds a match (e.g., via a CASE or subquery), and otherwise labels is left unchanged.

Expand All @@ -4757,16 +4799,33 @@ export class BaileysStartupService extends ChannelStartupService {
}

private async updateChatUnreadMessages(remoteJid: string): Promise<number> {
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>('DATABASE').PROVIDER;

let unreadMessagesPromise: Promise<number>;

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) {
Expand All @@ -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>('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>('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) {
Expand Down
Loading