Merge pull request #6815 from Budibase/feature/contains-filter

Contains filter for Multi-select types
This commit is contained in:
melohagan 2022-07-21 10:47:23 +01:00 committed by GitHub
commit 059cd6d378
5 changed files with 133 additions and 38 deletions

View File

@ -35,7 +35,7 @@ export const OperatorOptions = {
label: "Less than",
},
Contains: {
value: "equal",
value: "contains",
label: "Contains",
},
NotContains: {

View File

@ -19,6 +19,7 @@ class QueryBuilder {
empty: {},
notEmpty: {},
oneOf: {},
contains: {},
...base,
}
this.limit = 50
@ -119,6 +120,11 @@ class QueryBuilder {
return this
}
addContains(key, value) {
this.query.contains[key] = value
return this
}
/**
* Preprocesses a value before going into a lucene search.
* Transforms strings to lowercase and wraps strings and bools in quotes.
@ -164,6 +170,31 @@ class QueryBuilder {
return `${key}:${builder.preprocess(value, allPreProcessingOpts)}`
}
const contains = (key, value) => {
if (!value && value !== 0) {
return null
}
return `${key}:${builder.preprocess(value, { escape: true })}`
}
const oneOf = (key, value) => {
if (!Array.isArray(value)) {
if (typeof value === "string") {
value = value.split(",")
} else {
return ""
}
}
let orStatement = `${builder.preprocess(value[0], allPreProcessingOpts)}`
for (let i = 1; i < value.length; i++) {
orStatement += ` OR ${builder.preprocess(
value[i],
allPreProcessingOpts
)}`
}
return `${key}:(${orStatement})`
}
function build(structure, queryFn) {
for (let [key, value] of Object.entries(structure)) {
key = builder.preprocess(key.replace(/ /g, "_"), {
@ -239,26 +270,10 @@ class QueryBuilder {
build(this.query.notEmpty, key => `${key}:["" TO *]`)
}
if (this.query.oneOf) {
build(this.query.oneOf, (key, value) => {
if (!Array.isArray(value)) {
if (typeof value === "string") {
value = value.split(",")
} else {
return ""
}
}
let orStatement = `${builder.preprocess(
value[0],
allPreProcessingOpts
)}`
for (let i = 1; i < value.length; i++) {
orStatement += ` OR ${builder.preprocess(
value[i],
allPreProcessingOpts
)}`
}
return `${key}:(${orStatement})`
})
build(this.query.oneOf, oneOf)
}
if (this.query.contains) {
build(this.query.contains, contains)
}
// make sure table ID is always added as an AND
if (tableId) {

View File

@ -131,6 +131,9 @@ export interface SearchFilters {
oneOf?: {
[key: string]: any[]
}
contains?: {
[key: string]: any
}
}
export interface SortJson {

View File

@ -142,6 +142,21 @@ class InternalBuilder {
}
}
}
const like = (key: string, value: any) => {
const fnc = allOr ? "orWhere" : "where"
// postgres supports ilike, nothing else does
if (this.client === SqlClients.POSTGRES) {
query = query[fnc](key, "ilike", `%${value}%`)
} else {
const rawFnc = `${fnc}Raw`
// @ts-ignore
query = query[rawFnc](`LOWER(${likeKey(this.client, key)}) LIKE ?`, [
`%${value}%`,
])
}
}
if (!filters) {
return query
}
@ -168,19 +183,7 @@ class InternalBuilder {
})
}
if (filters.fuzzy) {
iterate(filters.fuzzy, (key, value) => {
const fnc = allOr ? "orWhere" : "where"
// postgres supports ilike, nothing else does
if (this.client === SqlClients.POSTGRES) {
query = query[fnc](key, "ilike", `%${value}%`)
} else {
const rawFnc = `${fnc}Raw`
// @ts-ignore
query = query[rawFnc](`LOWER(${likeKey(this.client, key)}) LIKE ?`, [
`%${value}%`,
])
}
})
iterate(filters.fuzzy, like)
}
if (filters.range) {
iterate(filters.range, (key, value) => {
@ -223,6 +226,34 @@ class InternalBuilder {
query = query[fnc](key)
})
}
if (filters.contains) {
const fnc = allOr ? "orWhere" : "where"
const rawFnc = `${fnc}Raw`
if (this.client === SqlClients.POSTGRES) {
iterate(filters.contains, (key: string, value: any) => {
const fieldNames = key.split(/\./g)
const tableName = fieldNames[0]
const columnName = fieldNames[1]
if (typeof value === "string") {
value = `"${value}"`
}
// @ts-ignore
query = query[rawFnc](
`"${tableName}"."${columnName}"::jsonb @> '[${value}]'`
)
})
} else if (this.client === SqlClients.MY_SQL) {
iterate(filters.contains, (key: string, value: any) => {
if (typeof value === "string") {
value = `"${value}"`
}
// @ts-ignore
query = query[rawFnc](`JSON_CONTAINS(${key}, '${value}')`)
})
} else {
iterate(filters.contains, like)
}
}
return query
}

View File

@ -1,4 +1,5 @@
const Sql = require("../base/sql")
const { SqlClients } = require("../utils")
const TABLE_NAME = "test"
@ -46,7 +47,7 @@ function generateDeleteJson(table = TABLE_NAME, filters = {}) {
describe("SQL query builder", () => {
const limit = 500
const client = "pg"
const client = SqlClients.POSTGRES
let sql
beforeEach(() => {
@ -173,15 +174,15 @@ describe("SQL query builder", () => {
})
it("should work with MS-SQL", () => {
const query = new Sql("mssql", 10)._query(generateReadJson())
const query = new Sql(SqlClients.MS_SQL, 10)._query(generateReadJson())
expect(query).toEqual({
bindings: [10],
sql: `select * from (select top (@p0) * from [${TABLE_NAME}]) as [${TABLE_NAME}]`
})
})
it("should work with mySQL", () => {
const query = new Sql("mysql", 10)._query(generateReadJson())
it("should work with MySQL", () => {
const query = new Sql(SqlClients.MY_SQL, 10)._query(generateReadJson())
expect(query).toEqual({
bindings: [10],
sql: `select * from (select * from \`${TABLE_NAME}\` limit ?) as \`${TABLE_NAME}\``
@ -238,4 +239,49 @@ describe("SQL query builder", () => {
sql: `select * from (select * from "${TABLE_NAME}" where "${TABLE_NAME}"."property" > $1 limit $2) as "${TABLE_NAME}"`
})
})
it("should use like expression for MS-SQL when filter is contains", () => {
const query = new Sql(SqlClients.MS_SQL, 10)._query(generateReadJson({
filters: {
contains: {
age: 20,
name: "John"
}
}
}))
expect(query).toEqual({
bindings: [10, "%20%", "%John%"],
sql: `select * from (select top (@p0) * from [${TABLE_NAME}] where LOWER(${TABLE_NAME}.age) LIKE @p1 and LOWER(${TABLE_NAME}.name) LIKE @p2) as [${TABLE_NAME}]`
})
})
it("should use JSON_CONTAINS expression for MySQL when filter is contains", () => {
const query = new Sql(SqlClients.MY_SQL, 10)._query(generateReadJson({
filters: {
contains: {
age: 20,
name: "John"
}
}
}))
expect(query).toEqual({
bindings: [10],
sql: `select * from (select * from \`${TABLE_NAME}\` where JSON_CONTAINS(${TABLE_NAME}.age, '20') and JSON_CONTAINS(${TABLE_NAME}.name, '"John"') limit ?) as \`${TABLE_NAME}\``
})
})
it("should use jsonb operator expression for PostgreSQL when filter is contains", () => {
const query = new Sql(SqlClients.POSTGRES, 10)._query(generateReadJson({
filters: {
contains: {
age: 20,
name: "John"
}
}
}))
expect(query).toEqual({
bindings: [10],
sql: `select * from (select * from \"${TABLE_NAME}\" where \"${TABLE_NAME}\".\"age\"::jsonb @> '[20]' and \"${TABLE_NAME}\".\"name\"::jsonb @> '["John"]' limit $1) as \"${TABLE_NAME}\"`
})
})
})