refactor: use trigram search index instead of full text search (#3900)
Co-authored-by: Balu Babu <balub997@gmail.com>
This commit is contained in:
@@ -1,17 +1,22 @@
|
|||||||
-- AlterTable
|
-- This is a custom migration file which is not generated by Prisma.
|
||||||
ALTER TABLE
|
-- The aim of this migration is to add text search indices to the TeamCollection and TeamRequest tables.
|
||||||
|
|
||||||
|
-- Create Extension
|
||||||
|
CREATE EXTENSION IF NOT EXISTS pg_trgm;
|
||||||
|
|
||||||
|
-- Create GIN Trigram Index for Team Collection title
|
||||||
|
CREATE INDEX
|
||||||
|
"TeamCollection_title_trgm_idx"
|
||||||
|
ON
|
||||||
"TeamCollection"
|
"TeamCollection"
|
||||||
ADD
|
USING
|
||||||
titleSearch tsvector GENERATED ALWAYS AS (to_tsvector('english', title)) STORED;
|
GIN (title gin_trgm_ops);
|
||||||
|
|
||||||
-- AlterTable
|
-- Create GIN Trigram Index for Team Collection title
|
||||||
ALTER TABLE
|
CREATE INDEX
|
||||||
|
"TeamRequest_title_trgm_idx"
|
||||||
|
ON
|
||||||
"TeamRequest"
|
"TeamRequest"
|
||||||
ADD
|
USING
|
||||||
titleSearch tsvector GENERATED ALWAYS AS (to_tsvector('english', title)) STORED;
|
GIN (title gin_trgm_ops);
|
||||||
|
|
||||||
-- CreateIndex
|
|
||||||
CREATE INDEX "TeamCollection_textSearch_idx" ON "TeamCollection" USING GIN (titleSearch);
|
|
||||||
|
|
||||||
-- CreateIndex
|
|
||||||
CREATE INDEX "TeamRequest_textSearch_idx" ON "TeamRequest" USING GIN (titleSearch);
|
|
||||||
|
|||||||
@@ -20,7 +20,7 @@ import {
|
|||||||
TEAM_COLL_PARENT_TREE_GEN_FAILED,
|
TEAM_COLL_PARENT_TREE_GEN_FAILED,
|
||||||
} from '../errors';
|
} from '../errors';
|
||||||
import { PubSubService } from '../pubsub/pubsub.service';
|
import { PubSubService } from '../pubsub/pubsub.service';
|
||||||
import { isValidLength } from 'src/utils';
|
import { escapeSqlLikeString, isValidLength } from 'src/utils';
|
||||||
import * as E from 'fp-ts/Either';
|
import * as E from 'fp-ts/Either';
|
||||||
import * as O from 'fp-ts/Option';
|
import * as O from 'fp-ts/Option';
|
||||||
import { Prisma, TeamCollection as DBTeamCollection } from '@prisma/client';
|
import { Prisma, TeamCollection as DBTeamCollection } from '@prisma/client';
|
||||||
@@ -1125,7 +1125,7 @@ export class TeamCollectionService {
|
|||||||
id: searchResults[i].id,
|
id: searchResults[i].id,
|
||||||
path: !fetchedParentTree
|
path: !fetchedParentTree
|
||||||
? []
|
? []
|
||||||
: ([fetchedParentTree.right] as CollectionSearchNode[]),
|
: (fetchedParentTree.right as CollectionSearchNode[]),
|
||||||
});
|
});
|
||||||
}
|
}
|
||||||
|
|
||||||
@@ -1148,14 +1148,20 @@ export class TeamCollectionService {
|
|||||||
skip: number,
|
skip: number,
|
||||||
) {
|
) {
|
||||||
const query = Prisma.sql`
|
const query = Prisma.sql`
|
||||||
select id,title,'collection' AS type
|
SELECT
|
||||||
from "TeamCollection"
|
id,title,'collection' AS type
|
||||||
where "TeamCollection"."teamID"=${teamID}
|
FROM
|
||||||
and titlesearch @@ to_tsquery(${searchQuery})
|
"TeamCollection"
|
||||||
order by ts_rank(titlesearch,to_tsquery(${searchQuery}))
|
WHERE
|
||||||
limit ${take}
|
"TeamCollection"."teamID"=${teamID}
|
||||||
|
AND
|
||||||
|
title ILIKE ${`%${escapeSqlLikeString(searchQuery)}%`}
|
||||||
|
ORDER BY
|
||||||
|
similarity(title, ${searchQuery})
|
||||||
|
LIMIT ${take}
|
||||||
OFFSET ${skip === 0 ? 0 : (skip - 1) * take};
|
OFFSET ${skip === 0 ? 0 : (skip - 1) * take};
|
||||||
`;
|
`;
|
||||||
|
|
||||||
try {
|
try {
|
||||||
const res = await this.prisma.$queryRaw<SearchQueryReturnType[]>(query);
|
const res = await this.prisma.$queryRaw<SearchQueryReturnType[]>(query);
|
||||||
return E.right(res);
|
return E.right(res);
|
||||||
@@ -1180,12 +1186,17 @@ export class TeamCollectionService {
|
|||||||
skip: number,
|
skip: number,
|
||||||
) {
|
) {
|
||||||
const query = Prisma.sql`
|
const query = Prisma.sql`
|
||||||
select id,title,request->>'method' as method,'request' AS type
|
SELECT
|
||||||
from "TeamRequest"
|
id,title,request->>'method' as method,'request' AS type
|
||||||
where "TeamRequest"."teamID"=${teamID}
|
FROM
|
||||||
and titlesearch @@ to_tsquery(${searchQuery})
|
"TeamRequest"
|
||||||
order by ts_rank(titlesearch,to_tsquery(${searchQuery}))
|
WHERE
|
||||||
limit ${take}
|
"TeamRequest"."teamID"=${teamID}
|
||||||
|
AND
|
||||||
|
title ILIKE ${`%${escapeSqlLikeString(searchQuery)}%`}
|
||||||
|
ORDER BY
|
||||||
|
similarity(title, ${searchQuery})
|
||||||
|
LIMIT ${take}
|
||||||
OFFSET ${skip === 0 ? 0 : (skip - 1) * take};
|
OFFSET ${skip === 0 ? 0 : (skip - 1) * take};
|
||||||
`;
|
`;
|
||||||
|
|
||||||
@@ -1250,45 +1261,53 @@ export class TeamCollectionService {
|
|||||||
* @returns The parent tree of the parent collections
|
* @returns The parent tree of the parent collections
|
||||||
*/
|
*/
|
||||||
private generateParentTree(parentCollections: ParentTreeQueryReturnType[]) {
|
private generateParentTree(parentCollections: ParentTreeQueryReturnType[]) {
|
||||||
function findChildren(id) {
|
function findChildren(id: string): CollectionSearchNode[] {
|
||||||
const collection = parentCollections.filter((item) => item.id === id)[0];
|
const collection = parentCollections.filter((item) => item.id === id)[0];
|
||||||
if (collection.parentID == null) {
|
if (collection.parentID == null) {
|
||||||
return {
|
return <CollectionSearchNode[]>[
|
||||||
id: collection.id,
|
{
|
||||||
title: collection.title,
|
id: collection.id,
|
||||||
type: 'collection',
|
title: collection.title,
|
||||||
path: [],
|
type: 'collection' as const,
|
||||||
};
|
path: [],
|
||||||
|
},
|
||||||
|
];
|
||||||
}
|
}
|
||||||
|
|
||||||
const res = {
|
const res = <CollectionSearchNode[]>[
|
||||||
id: collection.id,
|
{
|
||||||
title: collection.title,
|
id: collection.id,
|
||||||
type: 'collection',
|
title: collection.title,
|
||||||
path: findChildren(collection.parentID),
|
type: 'collection' as const,
|
||||||
};
|
path: findChildren(collection.parentID),
|
||||||
|
},
|
||||||
|
];
|
||||||
return res;
|
return res;
|
||||||
}
|
}
|
||||||
|
|
||||||
if (parentCollections.length > 0) {
|
if (parentCollections.length > 0) {
|
||||||
if (parentCollections[0].parentID == null) {
|
if (parentCollections[0].parentID == null) {
|
||||||
return {
|
return <CollectionSearchNode[]>[
|
||||||
|
{
|
||||||
|
id: parentCollections[0].id,
|
||||||
|
title: parentCollections[0].title,
|
||||||
|
type: 'collection',
|
||||||
|
path: [],
|
||||||
|
},
|
||||||
|
];
|
||||||
|
}
|
||||||
|
|
||||||
|
return <CollectionSearchNode[]>[
|
||||||
|
{
|
||||||
id: parentCollections[0].id,
|
id: parentCollections[0].id,
|
||||||
title: parentCollections[0].title,
|
title: parentCollections[0].title,
|
||||||
type: 'collection',
|
type: 'collection',
|
||||||
path: [],
|
path: findChildren(parentCollections[0].parentID),
|
||||||
};
|
},
|
||||||
}
|
];
|
||||||
|
|
||||||
return {
|
|
||||||
id: parentCollections[0].id,
|
|
||||||
title: parentCollections[0].title,
|
|
||||||
type: 'collection',
|
|
||||||
path: findChildren(parentCollections[0].parentID),
|
|
||||||
};
|
|
||||||
}
|
}
|
||||||
|
|
||||||
return null;
|
return <CollectionSearchNode[]>[];
|
||||||
}
|
}
|
||||||
|
|
||||||
/**
|
/**
|
||||||
|
|||||||
@@ -250,3 +250,40 @@ export function checkEnvironmentAuthProvider(
|
|||||||
}
|
}
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
|
/**
|
||||||
|
* Adds escape backslashes to the input so that it can be used inside
|
||||||
|
* SQL LIKE/ILIKE queries. Inspired by PHP's `mysql_real_escape_string`
|
||||||
|
* function.
|
||||||
|
*
|
||||||
|
* Eg. "100%" -> "100\\%"
|
||||||
|
*
|
||||||
|
* Source: https://stackoverflow.com/a/32648526
|
||||||
|
*/
|
||||||
|
export function escapeSqlLikeString(str: string) {
|
||||||
|
if (typeof str != 'string')
|
||||||
|
return str;
|
||||||
|
|
||||||
|
return str.replace(/[\0\x08\x09\x1a\n\r"'\\\%]/g, function (char) {
|
||||||
|
switch (char) {
|
||||||
|
case "\0":
|
||||||
|
return "\\0";
|
||||||
|
case "\x08":
|
||||||
|
return "\\b";
|
||||||
|
case "\x09":
|
||||||
|
return "\\t";
|
||||||
|
case "\x1a":
|
||||||
|
return "\\z";
|
||||||
|
case "\n":
|
||||||
|
return "\\n";
|
||||||
|
case "\r":
|
||||||
|
return "\\r";
|
||||||
|
case "\"":
|
||||||
|
case "'":
|
||||||
|
case "\\":
|
||||||
|
case "%":
|
||||||
|
return "\\"+char; // prepends a backslash to backslash, percent,
|
||||||
|
// and double/single quotes
|
||||||
|
}
|
||||||
|
});
|
||||||
|
}
|
||||||
|
|||||||
Reference in New Issue
Block a user