@@ -1518,29 +1518,49 @@ class OrganizationRepository {
1518
1518
const segmentIds = SequelizeRepository . getSegmentIds ( options )
1519
1519
1520
1520
const orgs = await options . database . sequelize . query (
1521
- `SELECT
1522
- "organizationsToMerge".id,
1523
- "organizationsToMerge"."toMergeId",
1524
- "organizationsToMerge"."total_count",
1525
- "organizationsToMerge"."similarity"
1526
- FROM
1527
- (
1528
- SELECT DISTINCT ON (Greatest(Hashtext(Concat(org.id, otm."toMergeId")), Hashtext(Concat(otm."toMergeId", org.id))))
1529
- org.id,
1530
- otm."toMergeId",
1531
- org."createdAt",
1532
- COUNT(*) OVER() AS total_count,
1521
+ `WITH
1522
+ cte AS (
1523
+ SELECT
1524
+ Greatest(Hashtext(Concat(org.id, otm."toMergeId")), Hashtext(Concat(otm."toMergeId", org.id))) as hash,
1525
+ org.id,
1526
+ otm."toMergeId",
1527
+ org."createdAt",
1533
1528
otm."similarity"
1534
1529
FROM organizations org
1535
- INNER JOIN "organizationToMerge" otm ON org.id = otm."organizationId"
1530
+ JOIN "organizationToMerge" otm ON org.id = otm."organizationId"
1536
1531
JOIN "organizationSegments" os ON os."organizationId" = org.id
1532
+ JOIN "organizationSegments" to_merge_segments on to_merge_segments."organizationId" = otm."toMergeId"
1537
1533
WHERE org."tenantId" = :tenantId
1538
1534
AND os."segmentId" IN (:segmentIds)
1539
- ORDER BY Greatest(Hashtext(Concat(org.id, otm."toMergeId")), Hashtext(Concat(otm."toMergeId", org.id))), org.id
1540
- ) AS "organizationsToMerge"
1541
- ORDER BY
1542
- "organizationsToMerge"."similarity" DESC, "organizationsToMerge".id
1543
- LIMIT :limit OFFSET :offset
1535
+ AND to_merge_segments."segmentId" IN (:segmentIds)
1536
+ ),
1537
+
1538
+ count_cte AS (
1539
+ SELECT COUNT(DISTINCT hash) AS total_count
1540
+ FROM cte
1541
+ ),
1542
+
1543
+ final_select AS (
1544
+ SELECT DISTINCT ON (hash)
1545
+ id,
1546
+ "toMergeId",
1547
+ "createdAt",
1548
+ "similarity"
1549
+ FROM cte
1550
+ ORDER BY hash, id
1551
+ )
1552
+
1553
+ SELECT
1554
+ "organizationsToMerge".id,
1555
+ "organizationsToMerge"."toMergeId",
1556
+ count_cte."total_count",
1557
+ "organizationsToMerge"."similarity"
1558
+ FROM
1559
+ final_select AS "organizationsToMerge",
1560
+ count_cte
1561
+ ORDER BY
1562
+ "organizationsToMerge"."similarity" DESC, "organizationsToMerge".id
1563
+ LIMIT :limit OFFSET :offset
1544
1564
` ,
1545
1565
{
1546
1566
replacements : {
0 commit comments