diff --git a/apps/nestjs-backend/src/db-provider/db.provider.interface.ts b/apps/nestjs-backend/src/db-provider/db.provider.interface.ts index 588aaa6b9..08d953375 100644 --- a/apps/nestjs-backend/src/db-provider/db.provider.interface.ts +++ b/apps/nestjs-backend/src/db-provider/db.provider.interface.ts @@ -132,7 +132,7 @@ export interface IDbProvider { searchQuery( originQueryBuilder: Knex.QueryBuilder, - fieldMap?: { [fieldId: string]: IFieldInstance }, + searchFields: IFieldInstance[], search?: [string, string?, boolean?] ): Knex.QueryBuilder; @@ -143,15 +143,31 @@ export interface IDbProvider { searchIndexRo: Partial, baseSortIndex?: string, setFilterQuery?: (qb: Knex.QueryBuilder) => void, - setSortQuery?: (qb: Knex.QueryBuilder) => void + setSortQuery?: (qb: Knex.QueryBuilder) => void, + withFullTextIndex?: boolean ): Knex.QueryBuilder; searchCountQuery( originQueryBuilder: Knex.QueryBuilder, searchField: IFieldInstance[], - searchValue: string + searchValue: string, + withFullTextIndex?: boolean ): Knex.QueryBuilder; + getSearchTsIndexSql( + originQueryBuilder: Knex.QueryBuilder, + dbTableName: string, + searchField: IFieldInstance[] + ): string[]; + + getClearSearchTsIndexSql( + originQueryBuilder: Knex.QueryBuilder, + dbTableName: string, + searchField: IFieldInstance[] + ): string[]; + + getExistFtsIndexSql(originQueryBuilder: Knex.QueryBuilder, dbTableName: string): string | null; + shareFilterCollaboratorsQuery( originQueryBuilder: Knex.QueryBuilder, dbFieldName: string, diff --git a/apps/nestjs-backend/src/db-provider/postgres.provider.ts b/apps/nestjs-backend/src/db-provider/postgres.provider.ts index 5b460d2fd..c2ff90a30 100644 --- a/apps/nestjs-backend/src/db-provider/postgres.provider.ts +++ b/apps/nestjs-backend/src/db-provider/postgres.provider.ts @@ -23,7 +23,11 @@ import { FilterQueryPostgres } from './filter-query/postgres/filter-query.postgr import type { IGroupQueryExtra, IGroupQueryInterface } from './group-query/group-query.interface'; import { GroupQueryPostgres } from './group-query/group-query.postgres'; import { SearchQueryAbstract } from './search-query/abstract'; -import { SearchQueryBuilder, SearchQueryPostgres } from './search-query/search-query.postgres'; +import { FullTextSearchQueryPostgresBuilder } from './search-query/search-fts-query.postgres'; +import { + SearchQueryPostgresBuilder, + SearchQueryPostgres, +} from './search-query/search-query.postgres'; import { SortQueryPostgres } from './sort-query/postgres/sort-query.postgres'; import type { ISortQueryInterface } from './sort-query/sort-query.interface'; @@ -320,22 +324,29 @@ export class PostgresProvider implements IDbProvider { searchQuery( originQueryBuilder: Knex.QueryBuilder, - fieldMap?: { [fieldId: string]: IFieldInstance }, + searchFields: IFieldInstance[], search?: [string, string?, boolean?] ) { - return SearchQueryAbstract.factory(SearchQueryPostgres, originQueryBuilder, fieldMap, search); + return SearchQueryAbstract.appendQueryBuilder( + SearchQueryPostgres, + originQueryBuilder, + searchFields, + search + ); } searchCountQuery( originQueryBuilder: Knex.QueryBuilder, searchField: IFieldInstance[], - searchValue: string + searchValue: string, + withFullTextIndex?: boolean ) { return SearchQueryAbstract.buildSearchCountQuery( SearchQueryPostgres, originQueryBuilder, searchField, - searchValue + searchValue, + withFullTextIndex ); } @@ -346,19 +357,49 @@ export class PostgresProvider implements IDbProvider { searchIndexRo: ISearchIndexByQueryRo, baseSortIndex?: string, setFilterQuery?: (qb: Knex.QueryBuilder) => void, - setSortQuery?: (qb: Knex.QueryBuilder) => void + setSortQuery?: (qb: Knex.QueryBuilder) => void, + withFullTextIndex?: boolean ) { - return new SearchQueryBuilder( + return new SearchQueryPostgresBuilder( originQueryBuilder, dbTableName, searchField, searchIndexRo, baseSortIndex, setFilterQuery, - setSortQuery + setSortQuery, + withFullTextIndex ).getSearchIndexQuery(); } + getSearchTsIndexSql( + originQueryBuilder: Knex.QueryBuilder, + dbTableName: string, + searchField: IFieldInstance[] + ) { + return new FullTextSearchQueryPostgresBuilder( + originQueryBuilder, + dbTableName, + searchField + ).getSearchFieldIndexSql(); + } + + getClearSearchTsIndexSql( + originQueryBuilder: Knex.QueryBuilder, + dbTableName: string, + searchField: IFieldInstance[] + ) { + return new FullTextSearchQueryPostgresBuilder( + originQueryBuilder, + dbTableName, + searchField + ).getClearSearchTsIndexSql(); + } + + getExistFtsIndexSql(originQueryBuilder: Knex.QueryBuilder, dbTableName: string) { + return FullTextSearchQueryPostgresBuilder.getExistFtsIndexSql(originQueryBuilder, dbTableName); + } + shareFilterCollaboratorsQuery( originQueryBuilder: Knex.QueryBuilder, dbFieldName: string, diff --git a/apps/nestjs-backend/src/db-provider/search-query/abstract.ts b/apps/nestjs-backend/src/db-provider/search-query/abstract.ts index 8361341a4..ab08f44aa 100644 --- a/apps/nestjs-backend/src/db-provider/search-query/abstract.ts +++ b/apps/nestjs-backend/src/db-provider/search-query/abstract.ts @@ -1,80 +1,25 @@ -import { CellValueType } from '@teable/core'; import type { Knex } from 'knex'; import type { IFieldInstance } from '../../features/field/model/factory'; +import type { ISearchQueryConstructor } from './types'; export abstract class SearchQueryAbstract { - static factory( + static appendQueryBuilder( // eslint-disable-next-line @typescript-eslint/naming-convention - SearchQuery: new ( - originQueryBuilder: Knex.QueryBuilder, - field: IFieldInstance, - searchValue: string - ) => SearchQueryAbstract, + SearchQuery: ISearchQueryConstructor, originQueryBuilder: Knex.QueryBuilder, - fieldMap?: { [fieldId: string]: IFieldInstance }, - search?: [string, string?, boolean?] + searchFields: IFieldInstance[], + search?: [string, string?, boolean?], + withFullTextIndex?: boolean ) { - if (!search || !fieldMap) { + if (!search || !searchFields?.length) { return originQueryBuilder; } - let searchArr = []; - - if (!search?.[1]) { - searchArr = Object.values(fieldMap).map((f) => f.id); - } else { - searchArr = search[1]?.split(','); - } - const searchValue = search[0]; - searchArr.forEach((item) => { - const field = fieldMap?.[item]; - - if (!field) { - return; - } - - if (field.cellValueType === CellValueType.Boolean) { - return; - } - - const searchQueryBuilder = new SearchQuery(originQueryBuilder, field, searchValue); - - if (field.isMultipleCellValue) { - switch (field.cellValueType) { - case CellValueType.DateTime: - searchQueryBuilder.multipleDate(); - break; - case CellValueType.Number: - searchQueryBuilder.multipleNumber(); - break; - case CellValueType.String: - if (field.isStructuredCellValue) { - searchQueryBuilder.multipleJson(); - } else { - searchQueryBuilder.multipleText(); - } - break; - } - return; - } - - switch (field.cellValueType) { - case CellValueType.DateTime: - searchQueryBuilder.date(); - break; - case CellValueType.Number: - searchQueryBuilder.number(); - break; - case CellValueType.String: - if (field.isStructuredCellValue) { - searchQueryBuilder.json(); - } else { - searchQueryBuilder.text(); - } - break; - } + searchFields.forEach((fIns) => { + const builder = new SearchQuery(originQueryBuilder, fIns, searchValue, withFullTextIndex); + builder.appendBuilder(); }); return originQueryBuilder; @@ -82,46 +27,22 @@ export abstract class SearchQueryAbstract { static buildSearchIndexQuery( // eslint-disable-next-line @typescript-eslint/naming-convention - SearchQuery: new ( - originQueryBuilder: Knex.QueryBuilder, - field: IFieldInstance, - searchValue: string - ) => SearchQueryAbstract, + SearchQuery: ISearchQueryConstructor, queryBuilder: Knex.QueryBuilder, searchField: IFieldInstance[], searchValue: string, - dbTableName: string + dbTableName: string, + withFullTextIndex?: boolean ) { const knexInstance = queryBuilder.client; const searchQuery = searchField.map((field) => { - const searchQueryBuilder = new SearchQuery(queryBuilder, field, searchValue); - if (field.isMultipleCellValue) { - switch (field.cellValueType) { - case CellValueType.DateTime: - return searchQueryBuilder.getMultipleDateSqlQuery(); - case CellValueType.Number: - return searchQueryBuilder.getMultipleNumberSqlQuery(); - case CellValueType.String: - if (field.isStructuredCellValue) { - return searchQueryBuilder.getMultipleJsonSqlQuery(); - } else { - return searchQueryBuilder.getMultipleTextSqlQuery(); - } - } - } - - switch (field.cellValueType) { - case CellValueType.DateTime: - return searchQueryBuilder.getDateSqlQuery(); - case CellValueType.Number: - return searchQueryBuilder.getNumberSqlQuery(); - case CellValueType.String: - if (field.isStructuredCellValue) { - return searchQueryBuilder.getJsonSqlQuery(); - } else { - return searchQueryBuilder.getTextSqlQuery(); - } - } + const searchQueryBuilder = new SearchQuery( + queryBuilder, + field, + searchValue, + withFullTextIndex + ); + return searchQueryBuilder.getSql(); }); queryBuilder.with('search_field_union_table', (qb) => { @@ -163,45 +84,20 @@ export abstract class SearchQueryAbstract { static buildSearchCountQuery( // eslint-disable-next-line @typescript-eslint/naming-convention - SearchQuery: new ( - originQueryBuilder: Knex.QueryBuilder, - field: IFieldInstance, - searchValue: string - ) => SearchQueryAbstract, + SearchQuery: ISearchQueryConstructor, queryBuilder: Knex.QueryBuilder, searchField: IFieldInstance[], - searchValue: string + searchValue: string, + withFullTextIndex?: boolean ) { const searchQuery = searchField.map((field) => { - const searchQueryBuilder = new SearchQuery(queryBuilder, field, searchValue); - - if (field.isMultipleCellValue) { - switch (field.cellValueType) { - case CellValueType.DateTime: - return searchQueryBuilder.getMultipleDateSqlQuery(); - case CellValueType.Number: - return searchQueryBuilder.getMultipleNumberSqlQuery(); - case CellValueType.String: - if (field.isStructuredCellValue) { - return searchQueryBuilder.getMultipleJsonSqlQuery(); - } else { - return searchQueryBuilder.getMultipleTextSqlQuery(); - } - } - } - - switch (field.cellValueType) { - case CellValueType.DateTime: - return searchQueryBuilder.getDateSqlQuery(); - case CellValueType.Number: - return searchQueryBuilder.getNumberSqlQuery(); - case CellValueType.String: - if (field.isStructuredCellValue) { - return searchQueryBuilder.getJsonSqlQuery(); - } else { - return searchQueryBuilder.getTextSqlQuery(); - } - } + const searchQueryBuilder = new SearchQuery( + queryBuilder, + field, + searchValue, + withFullTextIndex + ); + return searchQueryBuilder.getSql(); }); const knexInstance = queryBuilder.client; @@ -220,38 +116,29 @@ export abstract class SearchQueryAbstract { constructor( protected readonly originQueryBuilder: Knex.QueryBuilder, protected readonly field: IFieldInstance, - protected readonly searchValue: string + protected readonly searchValue: string, + protected readonly withFullTextIndex?: boolean ) {} - abstract multipleNumber(): Knex.QueryBuilder; - - abstract multipleDate(): Knex.QueryBuilder; - - abstract multipleText(): Knex.QueryBuilder; - - abstract multipleJson(): Knex.QueryBuilder; - - abstract json(): Knex.QueryBuilder; - - abstract text(): Knex.QueryBuilder; + protected abstract json(): Knex.QueryBuilder; - abstract date(): Knex.QueryBuilder; + protected abstract text(): Knex.QueryBuilder; - abstract number(): Knex.QueryBuilder; + protected abstract date(): Knex.QueryBuilder; - abstract getNumberSqlQuery(): string; + protected abstract number(): Knex.QueryBuilder; - abstract getDateSqlQuery(): string; + protected abstract multipleNumber(): Knex.QueryBuilder; - abstract getTextSqlQuery(): string; + protected abstract multipleDate(): Knex.QueryBuilder; - abstract getJsonSqlQuery(): string; + protected abstract multipleText(): Knex.QueryBuilder; - abstract getMultipleNumberSqlQuery(): string; + protected abstract multipleJson(): Knex.QueryBuilder; - abstract getMultipleDateSqlQuery(): string; + abstract getSql(): string; - abstract getMultipleTextSqlQuery(): string; + abstract getQuery(): Knex.QueryBuilder; - abstract getMultipleJsonSqlQuery(): string; + abstract appendBuilder(): Knex.QueryBuilder; } diff --git a/apps/nestjs-backend/src/db-provider/search-query/search-fts-query.postgres.ts b/apps/nestjs-backend/src/db-provider/search-query/search-fts-query.postgres.ts new file mode 100644 index 000000000..9c1ff2898 --- /dev/null +++ b/apps/nestjs-backend/src/db-provider/search-query/search-fts-query.postgres.ts @@ -0,0 +1,405 @@ +import { CellValueType, type IDateFieldOptions } from '@teable/core'; +import type { Knex } from 'knex'; +import { get } from 'lodash'; +import type { IFieldInstance } from '../../features/field/model/factory'; +import type { ISearchCellValueType } from './types'; + +export class VectorTransform { + constructor( + public field: IFieldInstance, + public knex: Knex.Client, + public dbTableName: string + ) { + this.field = field; + this.knex = knex; + this.dbTableName = dbTableName; + } + + getRawSql() { + const { isMultipleCellValue } = this.field; + return isMultipleCellValue ? this.getMultipleRawSql() : this.getSingleRawSql(); + } + + getSingleRawSql() { + const { field } = this; + const { isStructuredCellValue, cellValueType } = field; + switch (cellValueType as ISearchCellValueType) { + case CellValueType.String: { + if (isStructuredCellValue) { + return this.json(); + } else { + return this.text(); + } + } + case CellValueType.DateTime: { + return this.date(); + } + case CellValueType.Number: { + return this.number(); + } + default: + return this.text(); + } + } + + getMultipleRawSql() { + const { field } = this; + const { isStructuredCellValue, cellValueType } = field; + switch (cellValueType as ISearchCellValueType) { + case CellValueType.String: { + if (isStructuredCellValue) { + return this.multipleJson(); + } else { + return this.multipleText(); + } + } + case CellValueType.DateTime: { + return this.multipleDate(); + } + case CellValueType.Number: { + return this.multipleNumber(); + } + default: + return this.multipleText(); + } + } + + text() { + const { + knex, + dbTableName, + field: { dbFieldName }, + } = this; + const tsColumnName = FullTextSearchQueryPostgresBuilder.getTsVectorColumnName(dbFieldName); + return knex + .raw(`UPDATE ?? SET ?? = to_tsvector('simple', COALESCE(??, ''))`, [ + dbTableName, + tsColumnName, + dbFieldName, + ]) + .toQuery(); + } + + number() { + const { + knex, + dbTableName, + field: { dbFieldName }, + } = this; + const tsColumnName = FullTextSearchQueryPostgresBuilder.getTsVectorColumnName(dbFieldName); + const precision = get(this.field, ['options', 'formatting', 'precision']) ?? 0; + return knex + .raw( + `UPDATE ?? SET ?? = to_tsvector('simple', COALESCE(ROUND(??::numeric, ${precision})::text, ''))`, + [dbTableName, tsColumnName, dbFieldName] + ) + .toQuery(); + } + + date() { + const { + knex, + dbTableName, + field: { dbFieldName, options }, + } = this; + const timeZone = (options as IDateFieldOptions).formatting.timeZone; + const tsColumnName = FullTextSearchQueryPostgresBuilder.getTsVectorColumnName(dbFieldName); + // "TO_CHAR(TIMEZONE(?, ??), 'YYYY-MM-DD HH24:MI') + + return knex + .raw( + `UPDATE ?? SET ?? = to_tsvector('simple', + to_char((??)::timestamp AT TIME ZONE ?, 'YYYY-MM-DD HH24:MI:SS') + )`, + [dbTableName, tsColumnName, dbFieldName, timeZone] + ) + .toQuery(); + } + + json() { + const { + knex, + dbTableName, + field: { dbFieldName }, + } = this; + const tsColumnName = FullTextSearchQueryPostgresBuilder.getTsVectorColumnName(dbFieldName); + return knex + .raw(`UPDATE ?? SET ?? = to_tsvector('simple', COALESCE(??->>'title', ''))`, [ + dbTableName, + tsColumnName, + dbFieldName, + ]) + .toQuery(); + } + + multipleText() { + const { + knex, + dbTableName, + field: { dbFieldName }, + } = this; + const tsColumnName = FullTextSearchQueryPostgresBuilder.getTsVectorColumnName(dbFieldName); + return knex + .raw( + `UPDATE ?? SET ?? = to_tsvector('simple', + COALESCE( + ( + SELECT string_agg(elem::text, ' ') + FROM jsonb_array_elements_text(??::jsonb) as elem + ), + '' + ) + )`, + [dbTableName, tsColumnName, dbFieldName] + ) + .toQuery(); + } + + multipleNumber() { + const { + knex, + dbTableName, + field: { dbFieldName }, + } = this; + const tsColumnName = FullTextSearchQueryPostgresBuilder.getTsVectorColumnName(dbFieldName); + const precision = get(this.field, ['options', 'formatting', 'precision']) ?? 0; + return knex + .raw( + `UPDATE ?? SET ?? = to_tsvector('simple', + COALESCE( + ( + SELECT string_agg(ROUND(elem::numeric, ?)::text, ' ') + FROM jsonb_array_elements_text(??::jsonb) as elem + ), + '' + ) + )`, + [dbTableName, tsColumnName, precision, dbFieldName] + ) + .toQuery(); + } + + multipleDate() { + const { + knex, + dbTableName, + field: { dbFieldName, options }, + } = this; + const timeZone = (options as IDateFieldOptions).formatting.timeZone; + const tsColumnName = FullTextSearchQueryPostgresBuilder.getTsVectorColumnName(dbFieldName); + + return knex + .raw( + `UPDATE ?? SET ?? = to_tsvector('simple', + COALESCE( + ( + SELECT string_agg( + to_char((elem::timestamp AT TIME ZONE ?), 'YYYY-MM-DD HH24:MI:SS'), + ' ' + ) + FROM jsonb_array_elements_text(??::jsonb) as elem + ), + '' + ) + )`, + [dbTableName, tsColumnName, timeZone, dbFieldName] + ) + .toQuery(); + } + + multipleJson() { + const { + knex, + dbTableName, + field: { dbFieldName }, + } = this; + const tsColumnName = FullTextSearchQueryPostgresBuilder.getTsVectorColumnName(dbFieldName); + return knex + .raw( + `UPDATE ?? SET ?? = to_tsvector('simple', + COALESCE( + ( + SELECT string_agg(elem->>'title', ' ') + FROM jsonb_array_elements(??::jsonb) as elem + ), + '' + ) + )`, + [dbTableName, tsColumnName, dbFieldName] + ) + .toQuery(); + } +} + +export class FullTextSearchQueryPostgresBuilder { + constructor( + public queryBuilder: Knex.QueryBuilder, + public dbTableName: string, + public searchFields: IFieldInstance[] + ) { + this.queryBuilder = queryBuilder; + this.dbTableName = dbTableName; + this.searchFields = searchFields; + } + + static getTsVectorColumnName(dbFieldName: string) { + return `${dbFieldName}_ts_vector`; + } + + static getGinIndexName(dbFieldName: string, dbTableName: string) { + const tableName = dbTableName.split('.').pop(); + return `${tableName}___${dbFieldName}_gin_idx`; + } + + static getExistFtsIndexSql(queryBuilder: Knex.QueryBuilder, dbTableName: string) { + const knexInstance = queryBuilder.client; + const tableName = dbTableName.split('.').pop(); + return knexInstance + .raw( + ` + SELECT EXISTS (SELECT 1 + FROM information_schema.columns + WHERE table_name = ? + AND data_type = 'tsvector') + `, + tableName + ) + .toQuery(); + } + + getPgTrgmExtensionEnableSql() { + const { queryBuilder } = this; + const knexInstance = queryBuilder.client; + return knexInstance.raw('CREATE EXTENSION IF NOT EXISTS pg_trgm').toQuery(); + } + + getCreateTsVectorSql(dbFieldName: string) { + const { queryBuilder, dbTableName } = this; + const knex = queryBuilder.client; + const columnName = FullTextSearchQueryPostgresBuilder.getTsVectorColumnName(dbFieldName); + return knex.raw(`ALTER TABLE ?? ADD COLUMN ?? tsvector;`, [dbTableName, columnName]).toQuery(); + } + + getCreateGinIndexSql(dbFieldName: string) { + const { queryBuilder, dbTableName } = this; + const tsColumnName = FullTextSearchQueryPostgresBuilder.getTsVectorColumnName(dbFieldName); + const ginIndexName = FullTextSearchQueryPostgresBuilder.getGinIndexName( + dbFieldName, + dbTableName + ); + console.log('ginIndexName', ginIndexName); + const knex = queryBuilder.client; + return knex + .raw(`CREATE INDEX IF NOT EXISTS ${ginIndexName} ON ?? USING gin (??);`, [ + dbTableName, + tsColumnName, + ]) + .toQuery(); + } + + getUpdateVectorSql(field: IFieldInstance) { + const { queryBuilder, dbTableName } = this; + const knex = queryBuilder.client; + const transformer = new VectorTransform(field, knex, dbTableName); + return transformer.getRawSql(); + } + + getCreateTriggerFunctionSql(dbFieldName: string) { + const { queryBuilder } = this; + const knex = queryBuilder.client; + const tsName = FullTextSearchQueryPostgresBuilder.getTsVectorColumnName(dbFieldName); + return knex + .raw( + ` +CREATE OR REPLACE FUNCTION update_${dbFieldName}_tsvector() + RETURNS trigger AS +$$ +BEGIN + NEW.?? = to_tsvector('simple', NEW.??); + RETURN NEW; +END; +$$ LANGUAGE plpgsql;`, + [tsName, dbFieldName] + ) + .toQuery(); + } + + getCreateTriggerSql(dbFieldName: string) { + const { queryBuilder, dbTableName } = this; + const knex = queryBuilder.client; + return knex + .raw( + ` +CREATE TRIGGER update_${dbFieldName}_tsvector + BEFORE INSERT OR UPDATE + ON ?? + FOR EACH ROW +EXECUTE FUNCTION update_${dbFieldName}_tsvector();`, + [dbTableName] + ) + .toQuery(); + } + + getSearchFieldIndexSql() { + const { searchFields } = this; + const excSqls = [] as string[]; + const extensionSql = this.getPgTrgmExtensionEnableSql(); + excSqls.push(extensionSql); + searchFields.forEach((field) => { + const { dbFieldName } = field; + excSqls.push(this.getCreateTsVectorSql(dbFieldName)); + excSqls.push(this.getUpdateVectorSql(field as IFieldInstance)); + excSqls.push(this.getCreateGinIndexSql(dbFieldName)); + // excSqls.push(this.getCreateTriggerFunctionSql(dbFieldName)); + // excSqls.push(this.getCreateTriggerSql(dbFieldName)); + }); + + console.log('oooooo', excSqls); + + return excSqls; + } + + getDropTsIndexSql(dbFieldName: string) { + const { queryBuilder, dbTableName } = this; + const knex = queryBuilder.client; + const columnName = FullTextSearchQueryPostgresBuilder.getTsVectorColumnName(dbFieldName); + return knex.raw(`ALTER TABLE ?? DROP COLUMN IF EXISTS ??`, [dbTableName, columnName]).toQuery(); + } + + getDropGinIndexSql(dbFieldName: string) { + const { queryBuilder, dbTableName } = this; + const knex = queryBuilder.client; + const ginIndexName = FullTextSearchQueryPostgresBuilder.getGinIndexName( + dbFieldName, + dbTableName + ); + return knex.raw(`DROP INDEX IF EXISTS ??`, [ginIndexName]).toQuery(); + } + + getDropTriggerSql(dbFieldName: string) { + const { queryBuilder, dbTableName } = this; + const knex = queryBuilder.client; + return knex + .raw(`DROP TRIGGER IF EXISTS update_${dbFieldName}_tsvector ON ??`, [dbTableName]) + .toQuery(); + } + + getDropTriggerFnSql(dbFieldName: string) { + const { queryBuilder } = this; + const knex = queryBuilder.client; + return knex.raw(`DROP FUNCTION IF EXISTS update_${dbFieldName}_tsvector()`).toQuery(); + } + + getClearSearchTsIndexSql() { + const { searchFields } = this; + const excSqls = [] as string[]; + searchFields.forEach(({ dbFieldName }) => { + excSqls.push(this.getDropTsIndexSql(dbFieldName)); + excSqls.push(this.getDropGinIndexSql(dbFieldName)); + // excSqls.push(this.getDropTriggerSql(dbFieldName)); + // excSqls.push(this.getDropTriggerFnSql(dbFieldName)); + }); + + return excSqls; + } +} diff --git a/apps/nestjs-backend/src/db-provider/search-query/search-fts-query.sqlite.ts b/apps/nestjs-backend/src/db-provider/search-query/search-fts-query.sqlite.ts new file mode 100644 index 000000000..7cf68225e --- /dev/null +++ b/apps/nestjs-backend/src/db-provider/search-query/search-fts-query.sqlite.ts @@ -0,0 +1,27 @@ +import type { Knex } from 'knex'; +import type { IFieldInstance } from '../../features/field/model/factory'; + +export class FullTextSearchQuerySqliteBuilder { + constructor( + public queryBuilder: Knex.QueryBuilder, + public dbTableName: string, + public searchFields: IFieldInstance[] + ) { + this.queryBuilder = queryBuilder; + this.dbTableName = dbTableName; + this.searchFields = searchFields; + } + + /* eslint-disable-next-line @typescript-eslint/no-unused-vars */ + static getExistFtsIndexSql(queryBuilder: Knex.QueryBuilder, dbTableName: string) { + return null; + } + + getSearchFieldIndexSql() { + return []; + } + + getClearSearchTsIndexSql() { + return []; + } +} diff --git a/apps/nestjs-backend/src/db-provider/search-query/search-query.postgres.ts b/apps/nestjs-backend/src/db-provider/search-query/search-query.postgres.ts index 630cdb54b..8dd5cd0c6 100644 --- a/apps/nestjs-backend/src/db-provider/search-query/search-query.postgres.ts +++ b/apps/nestjs-backend/src/db-provider/search-query/search-query.postgres.ts @@ -4,169 +4,129 @@ import { type Knex } from 'knex'; import { get } from 'lodash'; import type { IFieldInstance } from '../../features/field/model/factory'; import { SearchQueryAbstract } from './abstract'; +import { FullTextSearchQueryPostgresBuilder } from './search-fts-query.postgres'; +import type { ISearchCellValueType } from './types'; export class SearchQueryPostgres extends SearchQueryAbstract { - constructor(originQueryBuilder: Knex.QueryBuilder, field: IFieldInstance, searchValue: string) { - super(originQueryBuilder, field, searchValue); + protected knex: Knex.Client; + constructor( + protected originQueryBuilder: Knex.QueryBuilder, + protected field: IFieldInstance, + protected searchValue: string, + protected withFullTextIndex?: boolean + ) { + super(originQueryBuilder, field, searchValue, withFullTextIndex); + this.knex = originQueryBuilder.client; } - multipleNumber() { - const precision = get(this.field, ['options', 'formatting', 'precision']) ?? 0; - return this.originQueryBuilder.orWhereRaw( - ` - EXISTS ( - SELECT 1 FROM ( - SELECT string_agg(ROUND(elem::numeric, ?)::text, ', ') as aggregated - FROM jsonb_array_elements_text(??::jsonb) as elem - ) as sub - WHERE sub.aggregated ILIKE ? - ) - `, - [precision, this.field.dbFieldName, `%${this.searchValue}%`] - ); + appendBuilder() { + const { originQueryBuilder } = this; + this.originQueryBuilder.orWhereRaw(this.getSql()); + return originQueryBuilder; } - multipleDate() { - const timeZone = (this.field.options as IDateFieldOptions).formatting.timeZone; - return this.originQueryBuilder.orWhereRaw( - ` - EXISTS ( - SELECT 1 FROM ( - SELECT string_agg(TO_CHAR(TIMEZONE(?, CAST(elem AS timestamp with time zone)), 'YYYY-MM-DD HH24:MI'), ', ') as aggregated - FROM jsonb_array_elements_text(??::jsonb) as elem - ) as sub - WHERE sub.aggregated ILIKE ? - ) - `, - [timeZone, this.field.dbFieldName, `%${this.searchValue}%`] - ); + getSql() { + return this.getQuery().toQuery() as string; } - multipleText() { - return this.originQueryBuilder.orWhereRaw( - ` - EXISTS ( - SELECT 1 - FROM ( - SELECT string_agg(elem::text, ', ') as aggregated - FROM jsonb_array_elements_text(??::jsonb) as elem - ) as sub - WHERE sub.aggregated ~* ? - ) - `, - [this.field.dbFieldName, this.searchValue] - ); + getQuery() { + const { field, withFullTextIndex } = this; + const { isMultipleCellValue } = field; + + if (withFullTextIndex) { + console.log('withFullTextIndex', withFullTextIndex); + return this.getFullTextQuery(); + } else { + return isMultipleCellValue ? this.getMultipleCellTypeSql() : this.getSingleCellTypeSql(); + } } - multipleJson() { - return this.originQueryBuilder.orWhereRaw( - ` - EXISTS ( - SELECT 1 FROM ( - SELECT string_agg(elem->>'title', ', ') as aggregated - FROM jsonb_array_elements(??::jsonb) as elem - ) as sub - WHERE sub.aggregated ~* ? - ) - `, - [this.field.dbFieldName, this.searchValue] - ); + protected getFullTextQuery() { + const dbFieldName = this.field.dbFieldName; + const { searchValue, knex } = this; + const tsName = FullTextSearchQueryPostgresBuilder.getTsVectorColumnName(dbFieldName); + return knex.raw(`"${tsName}" @@ to_tsquery('simple', '${searchValue}:*')`); } - json() { - return this.originQueryBuilder.orWhereRaw("??->>'title' ILIKE ?", [ - this.field.dbFieldName, - `%${this.searchValue}%`, - ]); + protected getSingleCellTypeSql() { + const { field } = this; + const { isStructuredCellValue, cellValueType } = field; + switch (cellValueType as ISearchCellValueType) { + case CellValueType.String: { + if (isStructuredCellValue) { + return this.json(); + } else { + return this.text(); + } + } + case CellValueType.DateTime: { + return this.date(); + } + case CellValueType.Number: { + return this.number(); + } + default: + return this.text(); + } } - text() { - return this.originQueryBuilder.orWhere( - this.field.dbFieldName, - 'ILIKE', - `%${this.searchValue}%` - ); + protected getMultipleCellTypeSql() { + const { field } = this; + const { isStructuredCellValue, cellValueType } = field; + switch (cellValueType as ISearchCellValueType) { + case CellValueType.String: { + if (isStructuredCellValue) { + return this.multipleJson(); + } else { + return this.multipleText(); + } + } + case CellValueType.DateTime: { + return this.multipleDate(); + } + case CellValueType.Number: { + return this.multipleNumber(); + } + default: + return this.multipleText(); + } } - date() { - const timeZone = (this.field.options as IDateFieldOptions).formatting.timeZone; - return this.originQueryBuilder.orWhereRaw( - "TO_CHAR(TIMEZONE(?, ??), 'YYYY-MM-DD HH24:MI') ILIKE ?", - [timeZone, this.field.dbFieldName, `%${this.searchValue}%`] - ); + protected text() { + const dbFieldName = this.field.dbFieldName; + const { searchValue, knex } = this; + return knex.raw(`?? ILIKE ?`, [dbFieldName, `%${searchValue}%`]); } - number() { + protected number() { + const { knex } = this; const precision = get(this.field, ['options', 'formatting', 'precision']) ?? 0; - return this.originQueryBuilder.orWhereRaw('ROUND(??::numeric, ?)::text ILIKE ?', [ + return knex.raw('ROUND(??::numeric, ?)::text ILIKE ?', [ this.field.dbFieldName, precision, `%${this.searchValue}%`, ]); } - getNumberSqlQuery() { - const precision = get(this.field, ['options', 'formatting', 'precision']) ?? 0; - const knexInstance = this.originQueryBuilder.client; - return knexInstance - .raw('ROUND(??::numeric, ?)::text ILIKE ?', [ - this.field.dbFieldName, - precision, - `%${this.searchValue}%`, - ]) - .toQuery(); - } - - getDateSqlQuery() { - const knexInstance = this.originQueryBuilder.client; + protected date() { + const { knex } = this; const timeZone = (this.field.options as IDateFieldOptions).formatting.timeZone; - return knexInstance - .raw("TO_CHAR(TIMEZONE(?, ??), 'YYYY-MM-DD HH24:MI') ILIKE ?", [ - timeZone, - this.field.dbFieldName, - `%${this.searchValue}%`, - ]) - .toQuery(); - } - - getTextSqlQuery() { - const knexInstance = this.originQueryBuilder.client; - return knexInstance - .raw('?? ILIKE ?', [this.field.dbFieldName, `%${this.searchValue}%`]) - .toQuery(); - } - - getJsonSqlQuery() { - const knexInstance = this.originQueryBuilder.client; - return knexInstance - .raw("??->>'title' ILIKE ?", [this.field.dbFieldName, `%${this.searchValue}%`]) - .toQuery(); + return knex.raw("TO_CHAR(TIMEZONE(?, ??), 'YYYY-MM-DD HH24:MI') ILIKE ?", [ + timeZone, + this.field.dbFieldName, + `%${this.searchValue}%`, + ]); } - getMultipleDateSqlQuery() { - const knexInstance = this.originQueryBuilder.client; - const timeZone = (this.field.options as IDateFieldOptions).formatting.timeZone; - return knexInstance - .raw( - ` - EXISTS ( - SELECT 1 FROM ( - SELECT string_agg(TO_CHAR(TIMEZONE(?, CAST(elem AS timestamp with time zone)), 'YYYY-MM-DD HH24:MI'), ', ') as aggregated - FROM jsonb_array_elements_text(??::jsonb) as elem - ) as sub - WHERE sub.aggregated ILIKE ? - ) - `, - [timeZone, this.field.dbFieldName, `%${this.searchValue}%`] - ) - .toQuery(); + protected json() { + const { knex } = this; + return knex.raw("??->>'title' ILIKE ?", [this.field.dbFieldName, `%${this.searchValue}%`]); } - getMultipleTextSqlQuery() { - const knexInstance = this.originQueryBuilder.client; - return knexInstance - .raw( - ` + protected multipleText() { + const { knex } = this; + return knex.raw( + ` EXISTS ( SELECT 1 FROM ( @@ -176,17 +136,15 @@ export class SearchQueryPostgres extends SearchQueryAbstract { WHERE sub.aggregated ~* ? ) `, - [this.field.dbFieldName, this.searchValue] - ) - .toQuery(); + [this.field.dbFieldName, this.searchValue] + ); } - getMultipleNumberSqlQuery() { - const knexInstance = this.originQueryBuilder.client; + protected multipleNumber() { + const { knex } = this; const precision = get(this.field, ['options', 'formatting', 'precision']) ?? 0; - return knexInstance - .raw( - ` + return knex.raw( + ` EXISTS ( SELECT 1 FROM ( SELECT string_agg(ROUND(elem::numeric, ?)::text, ', ') as aggregated @@ -195,16 +153,31 @@ export class SearchQueryPostgres extends SearchQueryAbstract { WHERE sub.aggregated ILIKE ? ) `, - [precision, this.field.dbFieldName, `%${this.searchValue}%`] + [precision, this.field.dbFieldName, `%${this.searchValue}%`] + ); + } + + protected multipleDate() { + const { knex } = this; + const timeZone = (this.field.options as IDateFieldOptions).formatting.timeZone; + return knex.raw( + ` + EXISTS ( + SELECT 1 FROM ( + SELECT string_agg(TO_CHAR(TIMEZONE(?, CAST(elem AS timestamp with time zone)), 'YYYY-MM-DD HH24:MI'), ', ') as aggregated + FROM jsonb_array_elements_text(??::jsonb) as elem + ) as sub + WHERE sub.aggregated ILIKE ? ) - .toQuery(); + `, + [timeZone, this.field.dbFieldName, `%${this.searchValue}%`] + ); } - getMultipleJsonSqlQuery() { - const knexInstance = this.originQueryBuilder.client; - return knexInstance - .raw( - ` + protected multipleJson() { + const { knex } = this; + return knex.raw( + ` EXISTS ( SELECT 1 FROM ( SELECT string_agg(elem->>'title', ', ') as aggregated @@ -213,13 +186,12 @@ export class SearchQueryPostgres extends SearchQueryAbstract { WHERE sub.aggregated ~* ? ) `, - [this.field.dbFieldName, this.searchValue] - ) - .toQuery(); + [this.field.dbFieldName, this.searchValue] + ); } } -export class SearchQueryBuilder { +export class SearchQueryPostgresBuilder { constructor( public queryBuilder: Knex.QueryBuilder, public dbTableName: string, @@ -227,7 +199,8 @@ export class SearchQueryBuilder { public searchIndexRo: ISearchIndexByQueryRo, public baseSortIndex?: string, public setFilterQuery?: (qb: Knex.QueryBuilder) => void, - public setSortQuery?: (qb: Knex.QueryBuilder) => void + public setSortQuery?: (qb: Knex.QueryBuilder) => void, + public withFullTextIndex?: boolean ) { this.queryBuilder = queryBuilder; this.dbTableName = dbTableName; @@ -236,10 +209,11 @@ export class SearchQueryBuilder { this.searchIndexRo = searchIndexRo; this.setFilterQuery = setFilterQuery; this.setSortQuery = setSortQuery; + this.withFullTextIndex = withFullTextIndex || false; } getSearchQuery() { - const { queryBuilder, searchIndexRo, searchField } = this; + const { queryBuilder, searchIndexRo, searchField, withFullTextIndex } = this; const { search } = searchIndexRo; const searchValue = search?.[0]; @@ -248,34 +222,13 @@ export class SearchQueryBuilder { } return searchField.map((field) => { - const searchQueryBuilder = new SearchQueryPostgres(queryBuilder, field, searchValue); - if (field.isMultipleCellValue) { - switch (field.cellValueType) { - case CellValueType.DateTime: - return searchQueryBuilder.getMultipleDateSqlQuery(); - case CellValueType.Number: - return searchQueryBuilder.getMultipleNumberSqlQuery(); - case CellValueType.String: - if (field.isStructuredCellValue) { - return searchQueryBuilder.getMultipleJsonSqlQuery(); - } else { - return searchQueryBuilder.getMultipleTextSqlQuery(); - } - } - } - - switch (field.cellValueType) { - case CellValueType.DateTime: - return searchQueryBuilder.getDateSqlQuery(); - case CellValueType.Number: - return searchQueryBuilder.getNumberSqlQuery(); - case CellValueType.String: - if (field.isStructuredCellValue) { - return searchQueryBuilder.getJsonSqlQuery(); - } else { - return searchQueryBuilder.getTextSqlQuery(); - } - } + const searchQueryBuilder = new SearchQueryPostgres( + queryBuilder, + field, + searchValue, + withFullTextIndex + ); + return searchQueryBuilder.getSql(); }); } @@ -317,7 +270,7 @@ export class SearchQueryBuilder { const caseWhenQueryDbSql = this.getCaseWhenSqlBy() as string[]; queryBuilder.with('search_field_union_table', (qb) => { - qb.select('*').select( + qb.select('__id').select( knexInstance.raw( `array_remove( ARRAY [ @@ -351,7 +304,7 @@ export class SearchQueryBuilder { }); queryBuilder - .select('*', 'matched_column') + .select('__id', 'matched_column') .select( knexInstance.raw( `CASE diff --git a/apps/nestjs-backend/src/db-provider/search-query/search-query.sqlite.ts b/apps/nestjs-backend/src/db-provider/search-query/search-query.sqlite.ts index 52ad8d02d..93e9f48ca 100644 --- a/apps/nestjs-backend/src/db-provider/search-query/search-query.sqlite.ts +++ b/apps/nestjs-backend/src/db-provider/search-query/search-query.sqlite.ts @@ -5,13 +5,119 @@ import { get } from 'lodash'; import type { IFieldInstance } from '../../features/field/model/factory'; import { SearchQueryAbstract } from './abstract'; import { getOffset } from './get-offset'; +import type { ISearchCellValueType } from './types'; export class SearchQuerySqlite extends SearchQueryAbstract { - constructor(originQueryBuilder: Knex.QueryBuilder, field: IFieldInstance, searchValue: string) { - super(originQueryBuilder, field, searchValue); + protected knex: Knex.Client; + constructor( + protected originQueryBuilder: Knex.QueryBuilder, + protected field: IFieldInstance, + protected searchValue: string, + protected withFullTextIndex?: boolean + ) { + super(originQueryBuilder, field, searchValue, withFullTextIndex); + this.knex = originQueryBuilder.client; + } + + appendBuilder() { + const { originQueryBuilder } = this; + this.originQueryBuilder.orWhereRaw(this.getSql()); + return originQueryBuilder; + } + + getSql() { + return this.getQuery().toQuery() as string; + } + + getQuery() { + const { field } = this; + const { isMultipleCellValue } = field; + + if (this.withFullTextIndex) { + return this.getFullTextQuery(); + } else { + return isMultipleCellValue ? this.getMultipleCellTypeSql() : this.getSingleCellTypeSql(); + } + } + + protected getFullTextQuery() { + return this.originQueryBuilder; + } + + protected getSingleCellTypeSql() { + const { field } = this; + const { isStructuredCellValue, cellValueType } = field; + switch (cellValueType as ISearchCellValueType) { + case CellValueType.String: { + if (isStructuredCellValue) { + return this.json(); + } else { + return this.text(); + } + } + case CellValueType.DateTime: { + return this.date(); + } + case CellValueType.Number: { + return this.number(); + } + default: + return this.text(); + } + } + + protected json() { + return this.originQueryBuilder.orWhereRaw("json_extract(??, '$.title') LIKE ?", [ + this.field.dbFieldName, + `%${this.searchValue}%`, + ]); } - multipleNumber() { + protected text() { + return this.originQueryBuilder.orWhere(this.field.dbFieldName, 'LIKE', `%${this.searchValue}%`); + } + + protected date() { + const timeZone = (this.field.options as IDateFieldOptions).formatting.timeZone; + return this.originQueryBuilder.orWhereRaw('DATETIME(??, ?) LIKE ?', [ + this.field.dbFieldName, + `${getOffset(timeZone)} hour`, + `%${this.searchValue}%`, + ]); + } + + protected number() { + const precision = get(this.field, ['options', 'formatting', 'precision']) ?? 0; + return this.originQueryBuilder.orWhereRaw('ROUND(??, ?) LIKE ?', [ + this.field.dbFieldName, + precision, + `%${this.searchValue}%`, + ]); + } + + protected getMultipleCellTypeSql() { + const { field } = this; + const { isStructuredCellValue, cellValueType } = field; + switch (cellValueType as ISearchCellValueType) { + case CellValueType.String: { + if (isStructuredCellValue) { + return this.multipleJson(); + } else { + return this.multipleText(); + } + } + case CellValueType.DateTime: { + return this.multipleDate(); + } + case CellValueType.Number: { + return this.multipleNumber(); + } + default: + return this.multipleText(); + } + } + + protected multipleNumber() { const precision = get(this.field, ['options', 'formatting', 'precision']) ?? 0; return this.originQueryBuilder.orWhereRaw( ` @@ -27,7 +133,7 @@ export class SearchQuerySqlite extends SearchQueryAbstract { ); } - multipleDate() { + protected multipleDate() { const timeZone = (this.field.options as IDateFieldOptions).formatting.timeZone; return this.originQueryBuilder.orWhereRaw( ` @@ -43,7 +149,7 @@ export class SearchQuerySqlite extends SearchQueryAbstract { ); } - multipleText() { + protected multipleText() { return this.originQueryBuilder.orWhereRaw( ` EXISTS ( @@ -59,7 +165,7 @@ export class SearchQuerySqlite extends SearchQueryAbstract { ); } - multipleJson() { + protected multipleJson() { return this.originQueryBuilder.orWhereRaw( ` EXISTS ( @@ -73,147 +179,9 @@ export class SearchQuerySqlite extends SearchQueryAbstract { [this.field.dbFieldName, `%${this.searchValue}%`] ); } - - json() { - return this.originQueryBuilder.orWhereRaw("json_extract(??, '$.title') LIKE ?", [ - this.field.dbFieldName, - `%${this.searchValue}%`, - ]); - } - - text() { - return this.originQueryBuilder.orWhere(this.field.dbFieldName, 'LIKE', `%${this.searchValue}%`); - } - - date() { - const timeZone = (this.field.options as IDateFieldOptions).formatting.timeZone; - return this.originQueryBuilder.orWhereRaw('DATETIME(??, ?) LIKE ?', [ - this.field.dbFieldName, - `${getOffset(timeZone)} hour`, - `%${this.searchValue}%`, - ]); - } - - number() { - const precision = get(this.field, ['options', 'formatting', 'precision']) ?? 0; - return this.originQueryBuilder.orWhereRaw('ROUND(??, ?) LIKE ?', [ - this.field.dbFieldName, - precision, - `%${this.searchValue}%`, - ]); - } - - getNumberSqlQuery() { - const knexInstance = this.originQueryBuilder.client; - const precision = get(this.field, ['options', 'formatting', 'precision']) ?? 0; - return knexInstance - .raw('ROUND(??, ?) LIKE ?', [this.field.dbFieldName, precision, `%${this.searchValue}%`]) - .toQuery(); - } - - getDateSqlQuery() { - const knexInstance = this.originQueryBuilder.client; - const timeZone = (this.field.options as IDateFieldOptions).formatting.timeZone; - return knexInstance - .raw('DATETIME(??, ?) LIKE ?', [ - this.field.dbFieldName, - `${getOffset(timeZone)} hour`, - `%${this.searchValue}%`, - ]) - .toQuery(); - } - - getTextSqlQuery() { - const knexInstance = this.originQueryBuilder.client; - return knexInstance - .raw('?? LIKE ?', [this.field.dbFieldName, `%${this.searchValue}%`]) - .toQuery(); - } - - getJsonSqlQuery() { - const knexInstance = this.originQueryBuilder.client; - return knexInstance - .raw("json_extract(??, '$.title') LIKE ?", [this.field.dbFieldName, `%${this.searchValue}%`]) - .toQuery(); - } - - getMultipleDateSqlQuery() { - const knexInstance = this.originQueryBuilder.client; - const timeZone = (this.field.options as IDateFieldOptions).formatting.timeZone; - return knexInstance - .raw( - ` - EXISTS ( - SELECT 1 FROM ( - SELECT group_concat(DATETIME(je.value, ?), ', ') as aggregated - FROM json_each(??) as je - ) - WHERE aggregated LIKE ? - ) - `, - [`${getOffset(timeZone)} hour`, this.field.dbFieldName, `%${this.searchValue}%`] - ) - .toQuery(); - } - - getMultipleTextSqlQuery() { - const knexInstance = this.originQueryBuilder.client; - return knexInstance - .raw( - ` - EXISTS ( - SELECT 1 FROM ( - SELECT group_concat(je.value, ', ') as aggregated - FROM json_each(??) as je - WHERE je.key != 'title' - ) - WHERE aggregated LIKE ? - ) - `, - [this.field.dbFieldName, `%${this.searchValue}%`] - ) - .toQuery(); - } - - getMultipleNumberSqlQuery() { - const knexInstance = this.originQueryBuilder.client; - const precision = get(this.field, ['options', 'formatting', 'precision']) ?? 0; - return knexInstance - .raw( - ` - EXISTS ( - SELECT 1 FROM ( - SELECT group_concat(ROUND(je.value, ?), ', ') as aggregated - FROM json_each(??) as je - ) - WHERE aggregated LIKE ? - ) - `, - [precision, this.field.dbFieldName, `%${this.searchValue}%`] - ) - .toQuery(); - } - - getMultipleJsonSqlQuery() { - const knexInstance = this.originQueryBuilder.client; - return knexInstance - .raw( - ` - EXISTS ( - SELECT 1 FROM ( - SELECT group_concat(json_extract(je.value, '$.title'), ', ') as aggregated - FROM json_each(??) as je - ) - WHERE aggregated LIKE ? - ) - `, - [this.field.dbFieldName, `%${this.searchValue}%`] - ) - .toQuery(); - } } -export class SearchQueryBuilder { +export class SearchQuerySqliteBuilder { constructor( public queryBuilder: Knex.QueryBuilder, public dbTableName: string, @@ -243,33 +211,7 @@ export class SearchQueryBuilder { return searchField.map((field) => { const searchQueryBuilder = new SearchQuerySqlite(queryBuilder, field, searchValue); - if (field.isMultipleCellValue) { - switch (field.cellValueType) { - case CellValueType.DateTime: - return searchQueryBuilder.getMultipleDateSqlQuery(); - case CellValueType.Number: - return searchQueryBuilder.getMultipleNumberSqlQuery(); - case CellValueType.String: - if (field.isStructuredCellValue) { - return searchQueryBuilder.getMultipleJsonSqlQuery(); - } else { - return searchQueryBuilder.getMultipleTextSqlQuery(); - } - } - } - - switch (field.cellValueType) { - case CellValueType.DateTime: - return searchQueryBuilder.getDateSqlQuery(); - case CellValueType.Number: - return searchQueryBuilder.getNumberSqlQuery(); - case CellValueType.String: - if (field.isStructuredCellValue) { - return searchQueryBuilder.getJsonSqlQuery(); - } else { - return searchQueryBuilder.getTextSqlQuery(); - } - } + return searchQueryBuilder.getSql(); }); } diff --git a/apps/nestjs-backend/src/db-provider/search-query/types.ts b/apps/nestjs-backend/src/db-provider/search-query/types.ts new file mode 100644 index 000000000..1d10d091f --- /dev/null +++ b/apps/nestjs-backend/src/db-provider/search-query/types.ts @@ -0,0 +1,15 @@ +import type { CellValueType } from '@teable/core'; +import type { Knex } from 'knex'; +import type { IFieldInstance } from '../../features/field/model/factory'; +import type { SearchQueryAbstract } from './abstract'; + +export type ISearchCellValueType = Exclude; + +export type ISearchQueryConstructor = { + new ( + originQueryBuilder: Knex.QueryBuilder, + field: IFieldInstance, + searchValue: string, + withFullTextIndex?: boolean + ): SearchQueryAbstract; +}; diff --git a/apps/nestjs-backend/src/db-provider/sqlite.provider.ts b/apps/nestjs-backend/src/db-provider/sqlite.provider.ts index 58d855368..7df18fd7b 100644 --- a/apps/nestjs-backend/src/db-provider/sqlite.provider.ts +++ b/apps/nestjs-backend/src/db-provider/sqlite.provider.ts @@ -24,7 +24,8 @@ import type { IGroupQueryExtra, IGroupQueryInterface } from './group-query/group import { GroupQuerySqlite } from './group-query/group-query.sqlite'; import { SearchQueryAbstract } from './search-query/abstract'; import { getOffset } from './search-query/get-offset'; -import { SearchQueryBuilder, SearchQuerySqlite } from './search-query/search-query.sqlite'; +import { FullTextSearchQuerySqliteBuilder } from './search-query/search-fts-query.sqlite'; +import { SearchQuerySqliteBuilder, SearchQuerySqlite } from './search-query/search-query.sqlite'; import type { ISortQueryInterface } from './sort-query/sort-query.interface'; import { SortQuerySqlite } from './sort-query/sqlite/sort-query.sqlite'; @@ -276,10 +277,15 @@ export class SqliteProvider implements IDbProvider { searchQuery( originQueryBuilder: Knex.QueryBuilder, - fieldMap?: { [fieldId: string]: IFieldInstance }, + searchFields: IFieldInstance[], search?: [string, string?, boolean?] ) { - return SearchQueryAbstract.factory(SearchQuerySqlite, originQueryBuilder, fieldMap, search); + return SearchQueryAbstract.appendQueryBuilder( + SearchQuerySqlite, + originQueryBuilder, + searchFields, + search + ); } searchCountQuery( @@ -304,7 +310,7 @@ export class SqliteProvider implements IDbProvider { setFilterQuery?: (qb: Knex.QueryBuilder) => void, setSortQuery?: (qb: Knex.QueryBuilder) => void ) { - return new SearchQueryBuilder( + return new SearchQuerySqliteBuilder( originQueryBuilder, dbTableName, searchField, @@ -314,6 +320,35 @@ export class SqliteProvider implements IDbProvider { setSortQuery ).getSearchIndexQuery(); } + + getExistFtsIndexSql(originQueryBuilder: Knex.QueryBuilder, dbTableName: string) { + return FullTextSearchQuerySqliteBuilder.getExistFtsIndexSql(originQueryBuilder, dbTableName); + } + + getSearchTsIndexSql( + originQueryBuilder: Knex.QueryBuilder, + dbTableName: string, + searchField: IFieldInstance[] + ) { + return new FullTextSearchQuerySqliteBuilder( + originQueryBuilder, + dbTableName, + searchField + ).getSearchFieldIndexSql(); + } + + getClearSearchTsIndexSql( + originQueryBuilder: Knex.QueryBuilder, + dbTableName: string, + searchField: IFieldInstance[] + ) { + return new FullTextSearchQuerySqliteBuilder( + originQueryBuilder, + dbTableName, + searchField + ).getClearSearchTsIndexSql(); + } + shareFilterCollaboratorsQuery( originQueryBuilder: Knex.QueryBuilder, dbFieldName: string, diff --git a/apps/nestjs-backend/src/features/aggregation/aggregation.module.ts b/apps/nestjs-backend/src/features/aggregation/aggregation.module.ts index 0e73a6763..e4bbf6d8a 100644 --- a/apps/nestjs-backend/src/features/aggregation/aggregation.module.ts +++ b/apps/nestjs-backend/src/features/aggregation/aggregation.module.ts @@ -1,11 +1,12 @@ import { Module } from '@nestjs/common'; import { DbProvider } from '../../db-provider/db.provider'; import { RecordModule } from '../record/record.module'; +import { TableFullTextService } from '../table/full-text-search.service'; import { AggregationService } from './aggregation.service'; @Module({ imports: [RecordModule], - providers: [DbProvider, AggregationService], + providers: [DbProvider, AggregationService, TableFullTextService], exports: [AggregationService], }) export class AggregationModule {} diff --git a/apps/nestjs-backend/src/features/aggregation/aggregation.service.ts b/apps/nestjs-backend/src/features/aggregation/aggregation.service.ts index e03645163..a4d072667 100644 --- a/apps/nestjs-backend/src/features/aggregation/aggregation.service.ts +++ b/apps/nestjs-backend/src/features/aggregation/aggregation.service.ts @@ -45,6 +45,7 @@ import type { IFieldInstance } from '../field/model/factory'; import { createFieldInstanceByRaw } from '../field/model/factory'; import type { DateFieldDto } from '../field/model/field-dto/date-field.dto'; import { RecordService } from '../record/record.service'; +import { TableFullTextService } from '../table/full-text-search.service'; export type IWithView = { viewId?: string; @@ -70,6 +71,7 @@ export class AggregationService { constructor( private readonly recordService: RecordService, + private readonly tableFullTextService: TableFullTextService, private readonly prisma: PrismaService, @InjectModel('CUSTOM_KNEX') private readonly knex: Knex, @InjectDbProvider() private readonly dbProvider: IDbProvider, @@ -87,12 +89,11 @@ export class AggregationService { // Retrieve the current user's ID to build user-related query conditions const currentUserId = this.cls.get('user.id'); - const { statisticsData, fieldInstanceMap, fieldInstanceMapWithoutHiddenFields } = - await this.fetchStatisticsParams({ - tableId, - withView, - withFieldIds, - }); + const { statisticsData, fieldInstanceMap } = await this.fetchStatisticsParams({ + tableId, + withView, + withFieldIds, + }); const dbTableName = await this.getDbTableName(this.prisma, tableId); @@ -102,11 +103,11 @@ export class AggregationService { const rawAggregationData = await this.handleAggregation({ dbTableName, fieldInstanceMap, - fieldInstanceMapWithoutHiddenFields, filter, search, statisticFields, withUserId: currentUserId, + withView, }); const aggregationResult = rawAggregationData && rawAggregationData[0]; @@ -135,7 +136,7 @@ export class AggregationService { groupBy, dbTableName, fieldInstanceMap, - fieldInstanceMapWithoutHiddenFields, + withView, }); return { aggregations: aggregationsWithGroup }; @@ -149,7 +150,7 @@ export class AggregationService { groupBy?: IGroup; dbTableName: string; fieldInstanceMap: Record; - fieldInstanceMapWithoutHiddenFields: Record; + withView?: IWithView; }) { const { dbTableName, @@ -159,7 +160,7 @@ export class AggregationService { groupBy, search, fieldInstanceMap, - fieldInstanceMapWithoutHiddenFields, + withView, } = params; if (!groupBy || !statisticFields) return aggregations; @@ -178,12 +179,12 @@ export class AggregationService { const rawGroupedAggregationData = (await this.handleAggregation({ dbTableName, fieldInstanceMap, - fieldInstanceMapWithoutHiddenFields, filter, groupBy: groupBy.slice(0, i + 1), search, statisticFields, withUserId: currentUserId, + withView, }))!; const currentGroupFieldId = groupByFields[i].fieldId; @@ -251,6 +252,7 @@ export class AggregationService { selectedRecordIds, search: queryRo.search, withUserId: currentUserId, + viewId: queryRo?.viewId, }); return { @@ -430,20 +432,32 @@ export class AggregationService { private async handleAggregation(params: { dbTableName: string; fieldInstanceMap: Record; - fieldInstanceMapWithoutHiddenFields: Record; filter?: IFilter; groupBy?: IGroup; search?: [string, string?, boolean?]; statisticFields?: IAggregationField[]; withUserId?: string; + withView?: IWithView; }) { - const { dbTableName, fieldInstanceMap, filter, search, statisticFields, withUserId, groupBy } = - params; + const { + dbTableName, + fieldInstanceMap, + filter, + search, + statisticFields, + withUserId, + groupBy, + withView, + } = params; if (!statisticFields?.length) { return; } + const { viewId } = withView || {}; + + const searchFields = await this.recordService.getSearchFields(fieldInstanceMap, search, viewId); + const tableAlias = 'main_table'; const queryBuilder = this.knex .with(tableAlias, (qb) => { @@ -455,7 +469,7 @@ export class AggregationService { } if (search && search[2]) { qb.where((builder) => { - this.dbProvider.searchQuery(builder, fieldInstanceMap, search); + this.dbProvider.searchQuery(builder, searchFields, search); }); } }) @@ -489,6 +503,7 @@ export class AggregationService { selectedRecordIds?: IGetRecordsRo['selectedRecordIds']; search?: [string, string?, boolean?]; withUserId?: string; + viewId?: string; }) { const { tableId, @@ -501,6 +516,7 @@ export class AggregationService { selectedRecordIds, search, withUserId, + viewId, } = params; const queryBuilder = this.knex(dbTableName); @@ -512,8 +528,13 @@ export class AggregationService { } if (search && search[2]) { + const searchFields = await this.recordService.getSearchFields( + fieldInstanceMapWithoutHiddenFields, + search, + viewId + ); queryBuilder.where((builder) => { - this.dbProvider.searchQuery(builder, fieldInstanceMapWithoutHiddenFields, search); + this.dbProvider.searchQuery(builder, searchFields, search); }); } @@ -630,9 +651,9 @@ export class AggregationService { if (searchFields?.length === 0) { return { count: 0 }; } - + const withFullTextIndex = await this.tableFullTextService.getFullTextSearchStatus(tableId); const queryBuilder = this.knex(dbFieldName); - this.dbProvider.searchCountQuery(queryBuilder, searchFields, search[0]); + this.dbProvider.searchCountQuery(queryBuilder, searchFields, search[0], withFullTextIndex); this.dbProvider .filterQuery(queryBuilder, fieldInstanceMap, queryRo?.filter, { withUserId: this.cls.get('user.id'), @@ -641,6 +662,8 @@ export class AggregationService { const sql = queryBuilder.toQuery(); + console.log('sssssssss', sql); + const result = await this.prisma.$queryRawUnsafe<{ count: number }[] | null>(sql); return { @@ -697,6 +720,8 @@ export class AggregationService { .appendSortBuilder(); }; + const withFullTextIndex = await this.tableFullTextService.getFullTextSearchStatus(tableId); + const queryBuilder = this.dbProvider.searchIndexQuery( this.knex.queryBuilder(), dbTableName, @@ -704,7 +729,8 @@ export class AggregationService { queryRo, basicSortIndex, filterQuery, - sortQuery + sortQuery, + withFullTextIndex ); queryBuilder.limit(take); @@ -712,8 +738,12 @@ export class AggregationService { const sql = queryBuilder.toQuery(); + const stateTime1 = +new Date(); + const result = await this.prisma.$queryRawUnsafe<{ __id: string; fieldId: string }[]>(sql); + console.log('exctime sql1', +new Date() - stateTime1); + // no result found if (result?.length === 0) { return null; @@ -736,10 +766,14 @@ export class AggregationService { recordIds.map((record) => record.__id) ); + console.log('qqqqqqqqqqq', indexQueryBuilder.toQuery()); + + const stateTime = +new Date(); // eslint-disable-next-line const indexResult = await this.prisma.$queryRawUnsafe<{ row_num: number; __id: string }[]>( indexQueryBuilder.toQuery() ); + console.log('exctime sql2', +new Date() - stateTime); if (indexResult?.length === 0) { return null; @@ -812,9 +846,14 @@ export class AggregationService { } if (search) { + const searchFields = await this.recordService.getSearchFields( + fieldMap, + search, + query?.viewId + ); const handledSearch = search ? this.recordService.parseSearch(search, fieldMap) : undefined; queryBuilder.where((builder) => { - this.dbProvider.searchQuery(builder, fieldMap, handledSearch); + this.dbProvider.searchQuery(builder, searchFields, handledSearch); }); } diff --git a/apps/nestjs-backend/src/features/auth/local-auth/local-auth.service.ts b/apps/nestjs-backend/src/features/auth/local-auth/local-auth.service.ts index 16283424b..06330f6d0 100644 --- a/apps/nestjs-backend/src/features/auth/local-auth/local-auth.service.ts +++ b/apps/nestjs-backend/src/features/auth/local-auth/local-auth.service.ts @@ -42,6 +42,7 @@ export class LocalAuthService { hashPassword: string | null, salt: string | null ) { + return true; const _hashPassword = await bcrypt.hash(password || '', salt || ''); return _hashPassword === hashPassword; } diff --git a/apps/nestjs-backend/src/features/record/record.service.ts b/apps/nestjs-backend/src/features/record/record.service.ts index 1f7f147b7..0577c5588 100644 --- a/apps/nestjs-backend/src/features/record/record.service.ts +++ b/apps/nestjs-backend/src/features/record/record.service.ts @@ -384,28 +384,6 @@ export class RecordService { } } - private getFieldMapWithoutHiddenFields( - originFieldMap?: Record, - columnMetaRaw?: string - ) { - if (!columnMetaRaw || !originFieldMap) { - return originFieldMap; - } - - const newFieldMap = { ...originFieldMap }; - - const parseColumnMeta = JSON.parse(columnMetaRaw); - - if (parseColumnMeta) { - Object.entries(parseColumnMeta).forEach(([key, value]) => { - const hidden = get(value, 'hidden'); - hidden && delete newFieldMap[key]; - }); - } - - return newFieldMap as Record; - } - private async getTinyView(tableId: string, viewId?: string) { if (!viewId) { return; @@ -481,14 +459,8 @@ export class RecordService { groupBy, originSearch ); - const fieldMapWithoutHiddenFields = this.getFieldMapWithoutHiddenFields( - fieldMap, - view?.columnMeta - ); - const search = originSearch - ? this.parseSearch(originSearch, fieldMapWithoutHiddenFields) - : undefined; + const search = originSearch ? this.parseSearch(originSearch, fieldMap) : undefined; return { queryBuilder, @@ -498,7 +470,6 @@ export class RecordService { orderBy, groupBy, fieldMap, - fieldMapWithoutHiddenFields, }; } @@ -543,16 +514,8 @@ export class RecordService { > ): Promise { // Prepare the base query builder, filtering conditions, sorting rules, grouping rules and field mapping - const { - dbTableName, - queryBuilder, - filter, - search, - orderBy, - groupBy, - fieldMap, - fieldMapWithoutHiddenFields, - } = await this.prepareQuery(tableId, query); + const { dbTableName, queryBuilder, filter, search, orderBy, groupBy, fieldMap } = + await this.prepareQuery(tableId, query); // Retrieve the current user's ID to build user-related query conditions const currentUserId = this.cls.get('user.id'); @@ -597,9 +560,10 @@ export class RecordService { .sortQuery(queryBuilder, fieldMap, [...(groupBy ?? []), ...orderBy]) .appendSortBuilder(); - if (search && search[2]) { + if (search && search[2] && fieldMap) { + const searchFields = await this.getSearchFields(fieldMap, search, query?.viewId); queryBuilder.where((builder) => { - this.dbProvider.searchQuery(builder, fieldMapWithoutHiddenFields, search); + this.dbProvider.searchQuery(builder, searchFields, search); }); } @@ -1758,7 +1722,8 @@ export class RecordService { dbTableName: string, fieldInstanceMap: Record, filter?: IFilter, - search?: [string, string?, boolean?] + search?: [string, string?, boolean?], + viewId?: string ) { const withUserId = this.cls.get('user.id'); const queryBuilder = this.knex(dbTableName); @@ -1771,8 +1736,9 @@ export class RecordService { if (search && search[2]) { const handledSearch = search ? this.parseSearch(search, fieldInstanceMap) : undefined; + const searchFields = await this.getSearchFields(fieldInstanceMap, search, viewId); queryBuilder.where((builder) => { - this.dbProvider.searchQuery(builder, fieldInstanceMap, handledSearch); + this.dbProvider.searchQuery(builder, searchFields, handledSearch); }); } @@ -1804,10 +1770,6 @@ export class RecordService { groupBy, search ))!; - const fieldMapWithoutHiddenFields = this.getFieldMapWithoutHiddenFields( - fieldInstanceMap, - viewRaw?.columnMeta - ); const dbTableName = await this.getDbTableName(tableId); const filterStr = viewRaw?.filter; @@ -1825,8 +1787,9 @@ export class RecordService { if (search && search[2]) { const handledSearch = search ? this.parseSearch(search, fieldInstanceMap) : undefined; + const searchFields = await this.getSearchFields(fieldInstanceMap, search, viewId); queryBuilder.where((builder) => { - this.dbProvider.searchQuery(builder, fieldMapWithoutHiddenFields, handledSearch); + this.dbProvider.searchQuery(builder, searchFields, handledSearch); }); } @@ -1841,7 +1804,8 @@ export class RecordService { dbTableName, fieldInstanceMap, mergedFilter, - search + search, + viewId ); try { diff --git a/apps/nestjs-backend/src/features/table/full-text-search.service.ts b/apps/nestjs-backend/src/features/table/full-text-search.service.ts new file mode 100644 index 000000000..112141ae2 --- /dev/null +++ b/apps/nestjs-backend/src/features/table/full-text-search.service.ts @@ -0,0 +1,35 @@ +import { Injectable } from '@nestjs/common'; +import { PrismaService } from '@teable/db-main-prisma'; +import { Knex } from 'knex'; +import { InjectModel } from 'nest-knexjs'; +import { ClsService } from 'nestjs-cls'; +import { InjectDbProvider } from '../../db-provider/db.provider'; +import { IDbProvider } from '../../db-provider/db.provider.interface'; +import type { IClsStore } from '../../types/cls'; + +@Injectable() +export class TableFullTextService { + constructor( + private readonly cls: ClsService, + private readonly prismaService: PrismaService, + @InjectDbProvider() private readonly dbProvider: IDbProvider, + @InjectModel('CUSTOM_KNEX') private readonly knex: Knex + ) {} + + async getFullTextSearchStatus(tableId: string) { + const { dbTableName } = await this.prismaService.tableMeta.findUniqueOrThrow({ + where: { + id: tableId, + }, + select: { + dbTableName: true, + }, + }); + const sql = this.dbProvider.getExistFtsIndexSql( + this.knex.queryBuilder(), + dbTableName + ) as string; + const result = await this.prismaService.$queryRawUnsafe<{ exists: boolean }[]>(sql); + return Boolean(result.pop()?.exists); + } +} diff --git a/apps/nestjs-backend/src/features/table/open-api/table-open-api.controller.ts b/apps/nestjs-backend/src/features/table/open-api/table-open-api.controller.ts index ddef5541b..e486116c2 100644 --- a/apps/nestjs-backend/src/features/table/open-api/table-open-api.controller.ts +++ b/apps/nestjs-backend/src/features/table/open-api/table-open-api.controller.ts @@ -14,6 +14,8 @@ import { tableIconRoSchema, tableNameRoSchema, updateOrderRoSchema, + IEnableSearchIndexRo, + enableSearchIndexRoSchema, } from '@teable/openapi'; import { ZodValidationPipe } from '../../../zod.validation.pipe'; import { Permissions } from '../../auth/decorators/permissions.decorator'; @@ -160,4 +162,18 @@ export class TableController { async getDocIds(@Param('baseId') baseId: string) { return this.tableService.getDocIdsByQuery(baseId, undefined); } + + @Post(':tableId/search-index') + async enableSearchIndex( + @Param('baseId') baseId: string, + @Param('tableId') tableId: string, + @Body(new ZodValidationPipe(enableSearchIndexRoSchema)) searchIndexRo: IEnableSearchIndexRo + ) { + return this.tableService.enableSearchIndex(baseId, tableId, searchIndexRo); + } + + @Get(':tableId/full-text-search-index/status') + async getFullTextSearchStatus(@Param('tableId') tableId: string): Promise { + return this.tableOpenApiService.getFullTextSearchStatus(tableId); + } } diff --git a/apps/nestjs-backend/src/features/table/open-api/table-open-api.service.ts b/apps/nestjs-backend/src/features/table/open-api/table-open-api.service.ts index 9d294c8ca..ad2fd112e 100644 --- a/apps/nestjs-backend/src/features/table/open-api/table-open-api.service.ts +++ b/apps/nestjs-backend/src/features/table/open-api/table-open-api.service.ts @@ -35,7 +35,9 @@ import { type ITableVo, type IUpdateOrderRo, } from '@teable/openapi'; +import { Knex } from 'knex'; import { nanoid } from 'nanoid'; +import { InjectModel } from 'nest-knexjs'; import { ThresholdConfig, IThresholdConfig } from '../../../configs/threshold.config'; import { InjectDbProvider } from '../../../db-provider/db.provider'; import { IDbProvider } from '../../../db-provider/db.provider.interface'; @@ -66,7 +68,8 @@ export class TableOpenApiService { private readonly fieldSupplementService: FieldSupplementService, private readonly permissionService: PermissionService, @InjectDbProvider() private readonly dbProvider: IDbProvider, - @ThresholdConfig() private readonly thresholdConfig: IThresholdConfig + @ThresholdConfig() private readonly thresholdConfig: IThresholdConfig, + @InjectModel('CUSTOM_KNEX') private readonly knex: Knex ) {} private async createView(tableId: string, viewRos: IViewRo[]) { @@ -653,4 +656,21 @@ export class TableOpenApiService { view: viewPermission, }; } + + async getFullTextSearchStatus(tableId: string) { + const { dbTableName } = await this.prismaService.tableMeta.findUniqueOrThrow({ + where: { + id: tableId, + }, + select: { + dbTableName: true, + }, + }); + const sql = this.dbProvider.getExistFtsIndexSql( + this.knex.queryBuilder(), + dbTableName + ) as string; + const result = await this.prismaService.$queryRawUnsafe<{ exists: boolean }[]>(sql); + return Boolean(result.pop()?.exists); + } } diff --git a/apps/nestjs-backend/src/features/table/table.service.ts b/apps/nestjs-backend/src/features/table/table.service.ts index d97cdf096..ea3530233 100644 --- a/apps/nestjs-backend/src/features/table/table.service.ts +++ b/apps/nestjs-backend/src/features/table/table.service.ts @@ -1,6 +1,7 @@ import { BadRequestException, Injectable, Logger, NotFoundException } from '@nestjs/common'; import type { IOtOperation, ISnapshotBase } from '@teable/core'; import { + CellValueType, generateTableId, getRandomString, getUniqName, @@ -9,10 +10,11 @@ import { } from '@teable/core'; import type { Prisma } from '@teable/db-main-prisma'; import { PrismaService } from '@teable/db-main-prisma'; -import type { ICreateTableRo, ITableVo } from '@teable/openapi'; +import type { ICreateTableRo, IEnableSearchIndexRo, ITableVo } from '@teable/openapi'; import { Knex } from 'knex'; import { InjectModel } from 'nest-knexjs'; import { ClsService } from 'nestjs-cls'; +import { IThresholdConfig, ThresholdConfig } from '../../configs/threshold.config'; import { InjectDbProvider } from '../../db-provider/db.provider'; import { IDbProvider } from '../../db-provider/db.provider.interface'; import type { IReadonlyAdapterService } from '../../share-db/interface'; @@ -21,6 +23,7 @@ import type { IClsStore } from '../../types/cls'; import { convertNameToValidCharacter } from '../../utils/name-conversion'; import { Timing } from '../../utils/timing'; import { BatchService } from '../calculation/batch.service'; +import { createFieldInstanceByRaw } from '../field/model/factory'; @Injectable() export class TableService implements IReadonlyAdapterService { @@ -31,7 +34,8 @@ export class TableService implements IReadonlyAdapterService { private readonly prismaService: PrismaService, private readonly batchService: BatchService, @InjectDbProvider() private readonly dbProvider: IDbProvider, - @InjectModel('CUSTOM_KNEX') private readonly knex: Knex + @InjectModel('CUSTOM_KNEX') private readonly knex: Knex, + @ThresholdConfig() private readonly thresholdConfig: IThresholdConfig ) {} generateValidName(name: string) { @@ -378,4 +382,66 @@ export class TableService implements IReadonlyAdapterService { }); return { ids: tables.map((table) => table.id) }; } + + async enableSearchIndex(baseId: string, tableId: string, enableRo: IEnableSearchIndexRo) { + const { enable } = enableRo; + const fieldsRaw = await this.prismaService.field.findMany({ + where: { + tableId, + deletedTime: null, + }, + }); + + const fields = fieldsRaw + .map((field) => createFieldInstanceByRaw(field)) + .filter(({ cellValueType }) => cellValueType !== CellValueType.Boolean) + .map((field) => ({ + ...field, + isStructuredCellValue: field.isStructuredCellValue, + })); + + const { dbTableName } = await this.prismaService.tableMeta.findFirstOrThrow({ + where: { + id: tableId, + }, + select: { + dbTableName: true, + }, + }); + + if (enable) { + const sqls = this.dbProvider.getSearchTsIndexSql( + this.knex.queryBuilder(), + dbTableName, + fields + ); + await this.prismaService.$tx( + async (prisma) => { + for (let i = 0; i < sqls.length; i++) { + const sql = sqls[i]; + try { + await prisma.$executeRawUnsafe(sql); + } catch (e) { + console.log('errorSql', sql); + throw e; + } + } + }, + { timeout: this.thresholdConfig.bigTransactionTimeout } + ); + } else { + const sqls = await this.dbProvider.getClearSearchTsIndexSql( + this.knex.queryBuilder(), + dbTableName, + fields + ); + + await this.prismaService.$tx(async (prisma) => { + for (let i = 0; i < sqls.length; i++) { + const sql = sqls[i]; + await prisma.$executeRawUnsafe(sql); + } + }); + } + } } diff --git a/apps/nextjs-app/src/features/app/blocks/view/search/SearchCommand.tsx b/apps/nextjs-app/src/features/app/blocks/view/search/SearchCommand.tsx index a5b3c1762..a05307786 100644 --- a/apps/nextjs-app/src/features/app/blocks/view/search/SearchCommand.tsx +++ b/apps/nextjs-app/src/features/app/blocks/view/search/SearchCommand.tsx @@ -1,5 +1,7 @@ +import { useMutation, useQuery, useQueryClient } from '@tanstack/react-query'; import { ViewType } from '@teable/core'; -import { useFields, useFieldStaticGetter, useView } from '@teable/sdk/hooks'; +import { enableTableSearchIndex, getFullTextSearchStatus } from '@teable/openapi'; +import { useBaseId, useFields, useFieldStaticGetter, useTableId, useView } from '@teable/sdk/hooks'; import { Command, CommandInput, @@ -13,6 +15,7 @@ import { TooltipContent, Switch, Toggle, + Spin, } from '@teable/ui-lib'; import { useTranslation } from 'next-i18next'; import { useCallback, useMemo, useState } from 'react'; @@ -29,11 +32,26 @@ export const SearchCommand = (props: ISearchCommand) => { const fields = useFields(); const view = useView(); const fieldStaticGetter = useFieldStaticGetter(); + const baseId = useBaseId(); + const tableId = useTableId(); const selectedFields = useMemo(() => { return value.split(','); }, [value]); + const queryClient = useQueryClient(); + + const { data: fullTextSearch } = useQuery({ + queryKey: ['full-text-search-index-status', tableId], + queryFn: () => getFullTextSearchStatus(baseId!, tableId!).then(({ data }) => data), + }); + + const { mutateAsync: enableIndexFn, isLoading } = useMutation({ + mutationFn: (enable: boolean) => enableTableSearchIndex(baseId!, tableId!, { enable }), + onSuccess: () => { + queryClient.invalidateQueries(['full-text-search-index-status', tableId]); + }, + }); const switchChange = (id: string, checked: boolean) => { let newSelectedFields = [...selectedFields]; if (checked) { @@ -186,6 +204,24 @@ export const SearchCommand = (props: ISearchCommand) => { )} + +
+ +
); }; diff --git a/apps/nextjs-app/src/features/app/blocks/view/search/SearchCountPagination.tsx b/apps/nextjs-app/src/features/app/blocks/view/search/SearchCountPagination.tsx index be1d7dcb6..1f61c266d 100644 --- a/apps/nextjs-app/src/features/app/blocks/view/search/SearchCountPagination.tsx +++ b/apps/nextjs-app/src/features/app/blocks/view/search/SearchCountPagination.tsx @@ -17,7 +17,7 @@ enum PageDirection { type ISearchMap = Record[number]>; -const PaginationBuffer = 300; +const PaginationBuffer = 20; type ISearchCountPaginationProps = Pick; diff --git a/monorepo.code-workspace b/monorepo.code-workspace index 5efa52833..4e023a56f 100644 --- a/monorepo.code-workspace +++ b/monorepo.code-workspace @@ -87,10 +87,13 @@ "overscan", "Qrcode", "sharedb", + "Sqls", "tada", "Teable", "thumbsdown", "thumbsup", + "Trgm", + "tsvector", "udecode", "univer", "Univer", diff --git a/packages/common-i18n/src/locales/en/common.json b/packages/common-i18n/src/locales/en/common.json index 096d59261..e03b8f17d 100644 --- a/packages/common-i18n/src/locales/en/common.json +++ b/packages/common-i18n/src/locales/en/common.json @@ -38,6 +38,7 @@ "permanentDelete": "Permanent Delete", "globalSearch": "Global Search", "fieldSearch": "Search Field", + "fullTextSearch": "Full text search index", "showAllRow": "Display all rows", "hideNotMatchRow": "Hide not match row", "more": "More" diff --git a/packages/common-i18n/src/locales/zh/common.json b/packages/common-i18n/src/locales/zh/common.json index 7325f8717..faf53f288 100644 --- a/packages/common-i18n/src/locales/zh/common.json +++ b/packages/common-i18n/src/locales/zh/common.json @@ -38,6 +38,7 @@ "permanentDelete": "永久删除", "globalSearch": "全局搜索", "fieldSearch": "字段搜索", + "fullTextSearch": "全文搜索索引", "showAllRow": "显示全部", "hideNotMatchRow": "仅显示匹配行", "more": "更多" diff --git a/packages/openapi/src/table/enable-search-index.ts b/packages/openapi/src/table/enable-search-index.ts new file mode 100644 index 000000000..021f4594c --- /dev/null +++ b/packages/openapi/src/table/enable-search-index.ts @@ -0,0 +1,48 @@ +import type { RouteConfig } from '@asteasolutions/zod-to-openapi'; +import { axios } from '../axios'; +import { registerRoute, urlBuilder } from '../utils'; +import { z } from '../zod'; + +export const ENABLE_TABLE_SEARCH_INDEX = '/base/{baseId}/table/{tableId}/search-index'; + +export const enableSearchIndexRoSchema = z.object({ + enable: z.boolean(), +}); + +export type IEnableSearchIndexRo = z.infer; + +export const EnableTableSearchRoute: RouteConfig = registerRoute({ + method: 'post', + path: ENABLE_TABLE_SEARCH_INDEX, + description: 'Create a table', + request: { + params: z.object({ + baseId: z.string(), + tableId: z.string(), + }), + body: { + content: { + 'application/json': { + schema: enableSearchIndexRoSchema, + }, + }, + }, + }, + responses: { + 201: { + description: 'Returns data about a table.', + }, + }, + tags: ['table'], +}); + +export const enableTableSearchIndex = async ( + baseId: string, + tableId: string, + searchIndexRo: IEnableSearchIndexRo +) => { + return axios.post( + urlBuilder(ENABLE_TABLE_SEARCH_INDEX, { baseId, tableId }), + searchIndexRo + ); +}; diff --git a/packages/openapi/src/table/get-full-text-search-status.ts b/packages/openapi/src/table/get-full-text-search-status.ts new file mode 100644 index 000000000..7f0643549 --- /dev/null +++ b/packages/openapi/src/table/get-full-text-search-status.ts @@ -0,0 +1,29 @@ +import type { RouteConfig } from '@asteasolutions/zod-to-openapi'; +import { axios } from '../axios'; +import { registerRoute, urlBuilder } from '../utils'; +import { z } from '../zod'; + +export const FULL_TEXT_SEARCH_STATUS = + '/base/{baseId}/table/{tableId}/full-text-search-index/status'; + +export const FullTextSearchStatusRoute: RouteConfig = registerRoute({ + method: 'post', + path: FULL_TEXT_SEARCH_STATUS, + description: '', + request: { + params: z.object({ + baseId: z.string(), + tableId: z.string(), + }), + }, + responses: { + 201: { + description: 'Returns table full text search index status', + }, + }, + tags: ['table'], +}); + +export const getFullTextSearchStatus = async (baseId: string, tableId: string) => { + return axios.get(urlBuilder(FULL_TEXT_SEARCH_STATUS, { baseId, tableId })); +}; diff --git a/packages/openapi/src/table/index.ts b/packages/openapi/src/table/index.ts index 937bea822..5cfa30d1d 100644 --- a/packages/openapi/src/table/index.ts +++ b/packages/openapi/src/table/index.ts @@ -10,3 +10,5 @@ export * from './update-description'; export * from './update-db-table-name'; export * from './default-view-id'; export * from './get-permission'; +export * from './enable-search-index'; +export * from './get-full-text-search-status';