Merge pull request #6931 from Budibase/feature/multiselect-filters

Multi-select dropdown filters
This commit is contained in:
melohagan 2022-08-15 14:41:11 +01:00 committed by GitHub
commit 9fdd353331
9 changed files with 279 additions and 48 deletions

View File

@ -23,7 +23,7 @@
$: toggleOption = makeToggleOption(selectedLookupMap, value)
const getFieldText = (value, map, placeholder) => {
if (value?.length) {
if (Array.isArray(value) && value.length > 0) {
if (!map) {
return ""
}
@ -36,7 +36,7 @@
const getSelectedLookupMap = value => {
let map = {}
if (value?.length) {
if (Array.isArray(value) && value.length > 0) {
value.forEach(option => {
if (option) {
map[option] = true

View File

@ -3,6 +3,7 @@
Body,
Button,
Combobox,
Multiselect,
DatePicker,
DrawerContent,
Icon,
@ -97,6 +98,16 @@
if (expression.noValue) {
expression.value = null
}
if (
operator === Constants.OperatorOptions.In.value &&
!Array.isArray(expression.value)
) {
if (expression.value) {
expression.value = [expression.value]
} else {
expression.value = []
}
}
}
const getFieldOptions = field => {
@ -169,7 +180,13 @@
/>
{:else if ["string", "longform", "number", "formula"].includes(filter.type)}
<Input disabled={filter.noValue} bind:value={filter.value} />
{:else if ["options", "array"].includes(filter.type)}
{:else if filter.type === "array" || (filter.type === "options" && filter.operator === "oneOf")}
<Multiselect
disabled={filter.noValue}
options={getFieldOptions(filter.field)}
bind:value={filter.value}
/>
{:else if filter.type === "options"}
<Combobox
disabled={filter.noValue}
options={getFieldOptions(filter.field)}

View File

@ -39,13 +39,17 @@ export const OperatorOptions = {
label: "Contains",
},
NotContains: {
value: "notEqual",
value: "notContains",
label: "Does Not Contain",
},
In: {
value: "oneOf",
label: "Is in",
},
ContainsAny: {
value: "containsAny",
label: "Has any",
},
}
// Cookie names

View File

@ -32,9 +32,9 @@ export const getValidOperatorsForType = type => {
} else if (type === "number") {
return numOps
} else if (type === "options") {
return [Op.Equals, Op.NotEquals, Op.Empty, Op.NotEmpty]
return [Op.Equals, Op.NotEquals, Op.Empty, Op.NotEmpty, Op.In]
} else if (type === "array") {
return [Op.Contains, Op.NotContains, Op.Empty, Op.NotEmpty]
return [Op.Contains, Op.NotContains, Op.Empty, Op.NotEmpty, Op.ContainsAny]
} else if (type === "boolean") {
return [Op.Equals, Op.NotEquals, Op.Empty, Op.NotEmpty]
} else if (type === "longform") {
@ -96,6 +96,7 @@ export const buildLuceneQuery = filter => {
contains: {},
notContains: {},
oneOf: {},
containsAny: {},
}
if (Array.isArray(filter)) {
filter.forEach(expression => {
@ -128,6 +129,13 @@ export const buildLuceneQuery = filter => {
if (type === "boolean") {
value = `${value}`?.toLowerCase() === "true"
}
if (
["contains", "notContains", "containsAny"].includes(operator) &&
type === "array" &&
typeof value === "string"
) {
value = value.split(",")
}
if (operator.startsWith("range")) {
const minint =
SqlNumberTypeRangeMap[externalType]?.min || Number.MIN_SAFE_INTEGER
@ -244,6 +252,18 @@ export const runLuceneQuery = (docs, query) => {
return !testValue?.includes(docValue)
})
const containsAny = match("containsAny", (docValue, testValue) => {
return !docValue?.includes(...testValue)
})
const contains = match("contains", (docValue, testValue) => {
return !testValue?.every(item => docValue?.includes(item))
})
const notContains = match("notContains", (docValue, testValue) => {
return testValue?.every(item => docValue?.includes(item))
})
// Match a document against all criteria
const docMatch = doc => {
return (
@ -254,7 +274,10 @@ export const runLuceneQuery = (docs, query) => {
notEqualMatch(doc) &&
emptyMatch(doc) &&
notEmptyMatch(doc) &&
oneOf(doc)
oneOf(doc) &&
contains(doc) &&
containsAny(doc) &&
notContains(doc)
)
}

View File

@ -21,6 +21,8 @@ class QueryBuilder {
notEmpty: {},
oneOf: {},
contains: {},
notContains: {},
containsAny: {},
...base,
}
this.limit = 50
@ -126,6 +128,16 @@ class QueryBuilder {
return this
}
addNotContains(key, value) {
this.query.notContains[key] = value
return this
}
addContainsAny(key, value) {
this.query.containsAny[key] = value
return this
}
/**
* Preprocesses a value before going into a lucene search.
* Transforms strings to lowercase and wraps strings and bools in quotes.
@ -171,11 +183,29 @@ class QueryBuilder {
return `${key}:${builder.preprocess(value, allPreProcessingOpts)}`
}
const contains = (key, value) => {
if (!value && value !== 0) {
const contains = (key, value, mode = "AND") => {
if (Array.isArray(value) && value.length === 0) {
return null
}
return `${key}:${builder.preprocess(value, { escape: true })}`
if (!Array.isArray(value)) {
return `${key}:${value}`
}
let statement = `${builder.preprocess(value[0], { escape: true })}`
for (let i = 1; i < value.length; i++) {
statement += ` ${mode} ${builder.preprocess(value[i], {
escape: true,
})}`
}
return `${key}:(${statement})`
}
const notContains = (key, value) => {
const allPrefix = allOr === "" ? "*:* AND" : ""
return allPrefix + "NOT " + contains(key, value)
}
const containsAny = (key, value) => {
return contains(key, value, "OR")
}
const oneOf = (key, value) => {
@ -278,6 +308,12 @@ class QueryBuilder {
if (this.query.contains) {
build(this.query.contains, contains)
}
if (this.query.notContains) {
build(this.query.notContains, notContains)
}
if (this.query.containsAny) {
build(this.query.containsAny, containsAny)
}
// make sure table ID is always added as an AND
if (tableId) {
query = `(${query})`

View File

@ -129,9 +129,10 @@ describe("internal search", () => {
const response = await search.paginatedSearch({
contains: {
"column": "a",
"colArr": [1, 2, 3],
},
}, PARAMS)
checkLucene(response, `*:* AND column:a`, PARAMS)
checkLucene(response, `*:* AND column:a AND colArr:(1 AND 2 AND 3)`, PARAMS)
})
it("test multiple of same column", async () => {
@ -154,4 +155,22 @@ describe("internal search", () => {
}, PARAMS)
checkLucene(response, `*:* AND 1\\:column:"a"`, PARAMS)
})
it("test containsAny query", async () => {
const response = await search.paginatedSearch({
containsAny: {
"column": ["a", "b", "c"]
},
}, PARAMS)
checkLucene(response, `*:* AND column:(a OR b OR c)`, PARAMS)
})
it("test notContains query", async () => {
const response = await search.paginatedSearch({
notContains: {
"column": ["a", "b", "c"]
},
}, PARAMS)
checkLucene(response, `*:* AND NOT column:(a AND b AND c)`, PARAMS)
})
})

View File

@ -159,6 +159,61 @@ class InternalBuilder {
}
}
const contains = (mode: object, any: boolean = false) => {
const fnc = allOr ? "orWhere" : "where"
const rawFnc = `${fnc}Raw`
const not = mode === filters?.notContains ? "NOT " : ""
function stringifyArray(value: Array<any>, quoteStyle = '"'): string {
for (let i in value) {
if (typeof value[i] === "string") {
value[i] = `${quoteStyle}${value[i]}${quoteStyle}`
}
}
return `[${value.join(",")}]`
}
if (this.client === SqlClient.POSTGRES) {
iterate(mode, (key: string, value: Array<any>) => {
const wrap = any ? "" : "'"
const containsOp = any ? "\\?| array" : "@>"
const fieldNames = key.split(/\./g)
const tableName = fieldNames[0]
const columnName = fieldNames[1]
// @ts-ignore
query = query[rawFnc](
`${not}"${tableName}"."${columnName}"::jsonb ${containsOp} ${wrap}${stringifyArray(
value,
any ? "'" : '"'
)}${wrap}`
)
})
} else if (this.client === SqlClient.MY_SQL) {
const jsonFnc = any ? "JSON_OVERLAPS" : "JSON_CONTAINS"
iterate(mode, (key: string, value: Array<any>) => {
// @ts-ignore
query = query[rawFnc](
`${not}${jsonFnc}(${key}, '${stringifyArray(value)}')`
)
})
} else {
const andOr = mode === filters?.containsAny ? " OR " : " AND "
iterate(mode, (key: string, value: Array<any>) => {
let statement = ""
for (let i in value) {
if (typeof value[i] === "string") {
value[i] = `%"${value[i]}"%`
} else {
value[i] = `%${value[i]}%`
}
statement +=
(statement ? andOr : "") +
`LOWER(${likeKey(this.client, key)}) LIKE ?`
}
// @ts-ignore
query = query[rawFnc](`${not}(${statement})`, value)
})
}
}
if (!filters) {
return query
}
@ -229,32 +284,13 @@ class InternalBuilder {
})
}
if (filters.contains) {
const fnc = allOr ? "orWhere" : "where"
const rawFnc = `${fnc}Raw`
if (this.client === SqlClient.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 === SqlClient.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)
}
contains(filters.contains)
}
if (filters.notContains) {
contains(filters.notContains)
}
if (filters.containsAny) {
contains(filters.containsAny, true)
}
return query
}

View File

@ -240,18 +240,18 @@ describe("SQL query builder", () => {
})
})
it("should use like expression for MS-SQL when filter is contains", () => {
it("should use AND like expression for MS-SQL when filter is contains", () => {
const query = new Sql(SqlClient.MS_SQL, 10)._query(generateReadJson({
filters: {
contains: {
age: 20,
name: "John"
age: [20, 25],
name: ["John", "Mary"]
}
}
}))
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}]`
bindings: [10, "%20%", "%25%", `%"John"%`, `%"Mary"%`],
sql: `select * from (select top (@p0) * from [${TABLE_NAME}] where (LOWER(${TABLE_NAME}.age) LIKE @p1 AND LOWER(${TABLE_NAME}.age) LIKE @p2) and (LOWER(${TABLE_NAME}.name) LIKE @p3 AND LOWER(${TABLE_NAME}.name) LIKE @p4)) as [${TABLE_NAME}]`
})
})
@ -259,14 +259,14 @@ describe("SQL query builder", () => {
const query = new Sql(SqlClient.MY_SQL, 10)._query(generateReadJson({
filters: {
contains: {
age: 20,
name: "John"
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}\``
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}\``
})
})
@ -274,8 +274,8 @@ describe("SQL query builder", () => {
const query = new Sql(SqlClient.POSTGRES, 10)._query(generateReadJson({
filters: {
contains: {
age: 20,
name: "John"
age: [20],
name: ["John"]
}
}
}))
@ -284,4 +284,94 @@ describe("SQL query builder", () => {
sql: `select * from (select * from \"${TABLE_NAME}\" where \"${TABLE_NAME}\".\"age\"::jsonb @> '[20]' and \"${TABLE_NAME}\".\"name\"::jsonb @> '["John"]' limit $1) as \"${TABLE_NAME}\"`
})
})
it("should use NOT like expression for MS-SQL when filter is notContains", () => {
const query = new Sql(SqlClient.MS_SQL, 10)._query(generateReadJson({
filters: {
notContains: {
age: [20],
name: ["John"]
}
}
}))
expect(query).toEqual({
bindings: [10, "%20%", `%"John"%`],
sql: `select * from (select top (@p0) * from [${TABLE_NAME}] where NOT (LOWER(${TABLE_NAME}.age) LIKE @p1) and NOT (LOWER(${TABLE_NAME}.name) LIKE @p2)) as [${TABLE_NAME}]`
})
})
it("should use NOT JSON_CONTAINS expression for MySQL when filter is notContains", () => {
const query = new Sql(SqlClient.MY_SQL, 10)._query(generateReadJson({
filters: {
notContains: {
age: [20],
name: ["John"]
}
}
}))
expect(query).toEqual({
bindings: [10],
sql: `select * from (select * from \`${TABLE_NAME}\` where NOT JSON_CONTAINS(${TABLE_NAME}.age, '[20]') and NOT JSON_CONTAINS(${TABLE_NAME}.name, '["John"]') limit ?) as \`${TABLE_NAME}\``
})
})
it("should use jsonb operator NOT expression for PostgreSQL when filter is notContains", () => {
const query = new Sql(SqlClient.POSTGRES, 10)._query(generateReadJson({
filters: {
notContains: {
age: [20],
name: ["John"]
}
}
}))
expect(query).toEqual({
bindings: [10],
sql: `select * from (select * from \"${TABLE_NAME}\" where NOT \"${TABLE_NAME}\".\"age\"::jsonb @> '[20]' and NOT \"${TABLE_NAME}\".\"name\"::jsonb @> '["John"]' limit $1) as \"${TABLE_NAME}\"`
})
})
it("should use OR like expression for MS-SQL when filter is containsAny", () => {
const query = new Sql(SqlClient.MS_SQL, 10)._query(generateReadJson({
filters: {
containsAny: {
age: [20, 25],
name: ["John", "Mary"]
}
}
}))
expect(query).toEqual({
bindings: [10, "%20%", "%25%", `%"John"%`, `%"Mary"%`],
sql: `select * from (select top (@p0) * from [${TABLE_NAME}] where (LOWER(${TABLE_NAME}.age) LIKE @p1 OR LOWER(${TABLE_NAME}.age) LIKE @p2) and (LOWER(${TABLE_NAME}.name) LIKE @p3 OR LOWER(${TABLE_NAME}.name) LIKE @p4)) as [${TABLE_NAME}]`
})
})
it("should use JSON_OVERLAPS expression for MySQL when filter is containsAny", () => {
const query = new Sql(SqlClient.MY_SQL, 10)._query(generateReadJson({
filters: {
containsAny: {
age: [20, 25],
name: ["John", "Mary"]
}
}
}))
expect(query).toEqual({
bindings: [10],
sql: `select * from (select * from \`${TABLE_NAME}\` where JSON_OVERLAPS(${TABLE_NAME}.age, '[20,25]') and JSON_OVERLAPS(${TABLE_NAME}.name, '["John","Mary"]') limit ?) as \`${TABLE_NAME}\``
})
})
it("should use ?| operator expression for PostgreSQL when filter is containsAny", () => {
const query = new Sql(SqlClient.POSTGRES, 10)._query(generateReadJson({
filters: {
containsAny: {
age: [20, 25],
name: ["John", "Mary"]
}
}
}))
expect(query).toEqual({
bindings: [10],
sql: `select * from (select * from \"${TABLE_NAME}\" where \"${TABLE_NAME}\".\"age\"::jsonb ?| array [20,25] and \"${TABLE_NAME}\".\"name\"::jsonb ?| array ['John','Mary'] limit $1) as \"${TABLE_NAME}\"`
})
})
})

View File

@ -31,7 +31,13 @@ export interface SearchFilters {
[key: string]: any[]
}
contains?: {
[key: string]: any
[key: string]: any[]
}
notContains?: {
[key: string]: any[]
}
containsAny?: {
[key: string]: any[]
}
}