From f80cf299f4b9f50e179be37dfbff2283357ca992 Mon Sep 17 00:00:00 2001 From: Pranav C Balan Date: Mon, 9 Aug 2021 16:44:03 +0530 Subject: [PATCH] feat: Add SEARCH, INT, LEFT, RIGHT functions Signed-off-by: Pranav C --- .../components/editColumn/formulaOptions.vue | 6 +- .../lib/sql/formulaQueryBuilderFromString.ts | 2 +- .../lib/sql/functionMappings/mssql.ts | 54 +++++++++++ .../lib/sql/functionMappings/mysql.ts | 27 ++++++ .../dataMapper/lib/sql/functionMappings/pg.ts | 21 +++++ .../lib/sql/functionMappings/sqlite.ts | 30 ++++++ .../lib/dataMapper/lib/sql/mapFunctionName.ts | 92 +++---------------- 7 files changed, 149 insertions(+), 83 deletions(-) create mode 100644 packages/nocodb/src/lib/dataMapper/lib/sql/functionMappings/mssql.ts create mode 100644 packages/nocodb/src/lib/dataMapper/lib/sql/functionMappings/mysql.ts create mode 100644 packages/nocodb/src/lib/dataMapper/lib/sql/functionMappings/pg.ts create mode 100644 packages/nocodb/src/lib/dataMapper/lib/sql/functionMappings/sqlite.ts diff --git a/packages/nc-gui/components/project/spreadsheet/components/editColumn/formulaOptions.vue b/packages/nc-gui/components/project/spreadsheet/components/editColumn/formulaOptions.vue index e63d6711f5..bc6858bae7 100644 --- a/packages/nc-gui/components/project/spreadsheet/components/editColumn/formulaOptions.vue +++ b/packages/nc-gui/components/project/spreadsheet/components/editColumn/formulaOptions.vue @@ -83,7 +83,11 @@ export default { 'LOG', 'EXP', 'POWER', 'SQRT', // todo: remove in sqlite 'ABS', 'NOW', - 'REPLACE' + 'REPLACE', + 'SEARCH', + 'INT', + 'RIGHT', + 'LEFT' ], availableBinOps: ['+', '-', '*', '/'], autocomplete: false, diff --git a/packages/nocodb/src/lib/dataMapper/lib/sql/formulaQueryBuilderFromString.ts b/packages/nocodb/src/lib/dataMapper/lib/sql/formulaQueryBuilderFromString.ts index 25615eb00a..c4199322b8 100644 --- a/packages/nocodb/src/lib/dataMapper/lib/sql/formulaQueryBuilderFromString.ts +++ b/packages/nocodb/src/lib/dataMapper/lib/sql/formulaQueryBuilderFromString.ts @@ -54,7 +54,7 @@ export default function formulaQueryBuilder(tree, alias, knex, aliasToColumn = { } break; default: { - const res = mapFunctionName({pt, knex, alias, aliasToCol: aliasToColumn, fn}) + const res = mapFunctionName({pt, knex, alias, aliasToCol: aliasToColumn, fn, colAlias}) if (res) return res; } break diff --git a/packages/nocodb/src/lib/dataMapper/lib/sql/functionMappings/mssql.ts b/packages/nocodb/src/lib/dataMapper/lib/sql/functionMappings/mssql.ts new file mode 100644 index 0000000000..758408a376 --- /dev/null +++ b/packages/nocodb/src/lib/dataMapper/lib/sql/functionMappings/mssql.ts @@ -0,0 +1,54 @@ +import {MapFnArgs} from "../mapFunctionName"; + +const mssql = { + MIN: (args: MapFnArgs) => { + if (args.pt.arguments.length === 1) { + return args.fn(args.pt.arguments[0]) + } + let query = ''; + for (const [i, arg] of Object.entries(args.pt.arguments)) { + if (+i === args.pt.arguments.length - 1) { + query += args.knex.raw(`\n\tElse ${args.fn(arg).toQuery()}`).toQuery() + } else { + query += args.knex.raw(`\n\tWhen ${args.pt.arguments.filter((_, j) => +i !== j).map(arg1 => `${args.fn(arg).toQuery()} < ${args.fn(arg1).toQuery()}`).join(' And ')} Then ${args.fn(arg).toQuery()}`).toQuery() + } + } + return args.knex.raw(`Case ${query}\n End${args.colAlias}`) + }, + MAX: (args: MapFnArgs) => { + if (args.pt.arguments.length === 1) { + return args.fn(args.pt.arguments[0]) + } + let query = ''; + for (const [i, arg] of Object.entries(args.pt.arguments)) { + if (+i === args.pt.arguments.length - 1) { + query += args.knex.raw(`\nElse ${args.fn(arg).toQuery()}`).toQuery() + } else { + query += args.knex.raw(`\nWhen ${args.pt.arguments.filter((_, j) => +i !== j).map(arg1 => `${args.fn(arg).toQuery()} > ${args.fn(arg1).toQuery()}`).join(' And ')} Then ${args.fn(arg).toQuery()}`).toQuery() + } + } + + return args.knex.raw(`Case ${query}\n End${args.colAlias}`) + }, + MOD: (pt) => { + Object.assign(pt, { + type: 'BinaryExpression', + operator: '%', + left: pt.arguments[0], + right: pt.arguments[1] + }) + }, + REPEAT: 'REPLICATE', + NOW: 'getdate', + SEARCH: (args: MapFnArgs) => { + args.pt.callee.name = 'CHARINDEX'; + const temp = args.pt.arguments[0] + args.pt.arguments[0] = args.pt.arguments[1] + args.pt.arguments[1] = temp; + }, + INT: (args: MapFnArgs) => { + return args.knex.raw(`CASE WHEN ISNUMERIC(${args.fn(args.pt.arguments[0]).toQuery()}) = 1 THEN FLOOR(${args.fn(args.pt.arguments[0]).toQuery()}) ELSE 0 END${args.colAlias}`) + } +} + +export default mssql; diff --git a/packages/nocodb/src/lib/dataMapper/lib/sql/functionMappings/mysql.ts b/packages/nocodb/src/lib/dataMapper/lib/sql/functionMappings/mysql.ts new file mode 100644 index 0000000000..9c7f02f201 --- /dev/null +++ b/packages/nocodb/src/lib/dataMapper/lib/sql/functionMappings/mysql.ts @@ -0,0 +1,27 @@ +import {MapFnArgs} from "../mapFunctionName"; + + +const mysql2 = { + LEN: 'CHAR_LENGTH', + MIN: 'LEAST', + MAX: 'GREATEST', + SEARCH: (args: MapFnArgs) => { + args.pt.callee.name = 'LOCATE'; + const temp = args.pt.arguments[0] + args.pt.arguments[0] = args.pt.arguments[1] + args.pt.arguments[1] = temp; + }, + INT:(args: MapFnArgs) =>{ + return args.knex.raw(`CAST(${args.fn(args.pt.arguments[0])} as SIGNED)${args.colAlias}`) + }, + LEFT:(args: MapFnArgs)=> { + return args.knex.raw(`SUBSTR(${args.fn(args.pt.arguments[0])},1,${args.fn(args.pt.arguments[1])})${args.colAlias}`) + }, + RIGHT:(args: MapFnArgs)=> { + return args.knex.raw(`SUBSTR(${args.fn(args.pt.arguments[0])},-${args.fn(args.pt.arguments[1])})${args.colAlias}`) + } +} + + +export default mysql2; + diff --git a/packages/nocodb/src/lib/dataMapper/lib/sql/functionMappings/pg.ts b/packages/nocodb/src/lib/dataMapper/lib/sql/functionMappings/pg.ts new file mode 100644 index 0000000000..c49c70964a --- /dev/null +++ b/packages/nocodb/src/lib/dataMapper/lib/sql/functionMappings/pg.ts @@ -0,0 +1,21 @@ +import {MapFnArgs} from "../mapFunctionName"; + +const pg = { + LEN: 'length', + MIN: 'least', + MAX: 'greatest', + CEILING: 'ceil', + ROUND: 'round', + POWER: 'pow', + SQRT: 'sqrt', + SEARCH: (args: MapFnArgs) => { + return args.knex.raw(`POSITION(${args.knex.raw(args.fn(args.pt.arguments[1]).toQuery())} in ${args.knex.raw(args.fn(args.pt.arguments[0]).toQuery())})${args.colAlias}`) + }, + INT(args: MapFnArgs) { + // todo: correction + return args.knex.raw(`REGEXP_REPLACE(COALESCE(${args.fn(args.pt.arguments[0])}::character varying, '0'), '[^0-9]+|\\.[0-9]+' ,'')${args.colAlias}`) + } +} + + +export default pg; diff --git a/packages/nocodb/src/lib/dataMapper/lib/sql/functionMappings/sqlite.ts b/packages/nocodb/src/lib/dataMapper/lib/sql/functionMappings/sqlite.ts new file mode 100644 index 0000000000..a23a776208 --- /dev/null +++ b/packages/nocodb/src/lib/dataMapper/lib/sql/functionMappings/sqlite.ts @@ -0,0 +1,30 @@ +import {MapFnArgs} from "../mapFunctionName"; + + +const sqlite3 = { + LEN: 'LENGTH', + CEILING(_pt) { + // todo: + }, FLOOR(_pt) { + // todo: + }, + MOD:(pt) => { + Object.assign(pt, { + type: 'BinaryExpression', + operator: '%', + left: pt.arguments[0], + right: pt.arguments[1] + }) + }, + REPEAT(args: MapFnArgs) { + return args.knex.raw(`replace(printf('%.' || ${args.fn(args.pt.arguments[1])} || 'c', '/'),'/',${args.fn(args.pt.arguments[0])})${args.colAlias}`) + }, + NOW: 'DATE', + SEARCH:'INSTR', + INT(args: MapFnArgs) { + return args.knex.raw(`CAST(${args.fn(args.pt.arguments[0])} as INTEGER)${args.colAlias}`) + } +} + + +export default sqlite3; diff --git a/packages/nocodb/src/lib/dataMapper/lib/sql/mapFunctionName.ts b/packages/nocodb/src/lib/dataMapper/lib/sql/mapFunctionName.ts index 3c5a04ad2e..be13e998bf 100644 --- a/packages/nocodb/src/lib/dataMapper/lib/sql/mapFunctionName.ts +++ b/packages/nocodb/src/lib/dataMapper/lib/sql/mapFunctionName.ts @@ -1,96 +1,26 @@ import {XKnex} from "../../index"; +import mssql from "./functionMappings/mssql"; +import mysql from "./functionMappings/mysql"; +import pg from "./functionMappings/pg"; +import sqlite from "./functionMappings/sqlite"; +import {QueryBuilder} from "knex"; -interface MapFnArgs { +export interface MapFnArgs { pt: any, aliasToCol: { [alias: string]: string }, knex: XKnex, alias: string, - fn: (...args: any) => any + fn: (...args: any) => QueryBuilder, + colAlias:string } -const MOD = (pt) => { - Object.assign(pt, { - type: 'BinaryExpression', - operator: '%', - left: pt.arguments[0], - right: pt.arguments[1] - }) -} -const mysql2 = { - LEN: 'CHAR_LENGTH', - MIN: 'LEAST', - MAX: 'GREATEST', -} - -const pg = { - LEN: 'length', - MIN: 'least', - MAX: 'greatest', - CEILING: 'ceil', - ROUND: 'round', - POWER: 'pow', - SQRT: 'sqrt' -} - -const mssql = { - MIN: (args: MapFnArgs) => { - if (args.pt.arguments.length === 1) { - return args.fn(args.pt.arguments[0]) - } - let query = ''; - for (const [i, arg] of Object.entries(args.pt.arguments)) { - if (+i === args.pt.arguments.length - 1) { - query += args.knex.raw(`\n\tElse ${args.fn(arg).toQuery()}`).toQuery() - } else { - query += args.knex.raw(`\n\tWhen ${args.pt.arguments.filter((_, j) => +i !== j).map(arg1 => `${args.fn(arg).toQuery()} < ${args.fn(arg1).toQuery()}`).join(' And ')} Then ${args.fn(arg).toQuery()}`).toQuery() - } - } - - return args.knex.raw(`Case ${query}\n End as ${args.alias}`) - }, - MAX: (args: MapFnArgs) => { - if (args.pt.arguments.length === 1) { - return args.fn(args.pt.arguments[0]) - } - let query = ''; - for (const [i, arg] of Object.entries(args.pt.arguments)) { - if (+i === args.pt.arguments.length - 1) { - query += args.knex.raw(`\nElse ${args.fn(arg).toQuery()}`).toQuery() - } else { - query += args.knex.raw(`\nWhen ${args.pt.arguments.filter((_, j) => +i !== j).map(arg1 => `${args.fn(arg).toQuery()} > ${args.fn(arg1).toQuery()}`).join(' And ')} Then ${args.fn(arg).toQuery()}`).toQuery() - } - } - - return args.knex.raw(`Case ${query}\n End as ${args.alias}`) - }, - MOD, - REPEAT: 'REPLICATE', - NOW: 'getdate' -} - - -const sqlite3 = { - LEN: 'LENGTH', - CEILING(_pt) { - // todo: - }, FLOOR(_pt) { - // todo: - }, - MOD, - REPEAT(args: MapFnArgs) { - return args.knex.raw(`replace(printf('%.' || ${args.fn(args.pt.arguments[1])} || 'c', '/'),'/',${args.fn(args.pt.arguments[0])}) ${args.alias}`) - }, - NOW: 'DATE' -} - - const mapFunctionName = (args: MapFnArgs): any => { const name = args.pt.callee.name; let val; switch (args.knex.clientType()) { case 'mysql': case 'mysql2': - val = mysql2[name] || name; + val = mysql[name] || name; break; case 'pg': case 'postgre': @@ -101,7 +31,7 @@ const mapFunctionName = (args: MapFnArgs): any => { break; case 'sqlite': case 'sqlite3': - val = sqlite3[name] || name; + val = sqlite[name] || name; break; } @@ -113,4 +43,4 @@ const mapFunctionName = (args: MapFnArgs): any => { } -export default mapFunctionName; \ No newline at end of file +export default mapFunctionName;