From 6b259fa87b1d197395351ae4b010cea752ecf1ab Mon Sep 17 00:00:00 2001 From: Wing-Kam Wong Date: Wed, 7 Dec 2022 18:40:51 +0800 Subject: [PATCH 01/15] feat(nc-gui): add DATETIME_DIFF validation --- .../smartsheet/column/FormulaOptions.vue | 57 +++++++++++++++++++ 1 file changed, 57 insertions(+) diff --git a/packages/nc-gui/components/smartsheet/column/FormulaOptions.vue b/packages/nc-gui/components/smartsheet/column/FormulaOptions.vue index c55bc8ec85..2721028f22 100644 --- a/packages/nc-gui/components/smartsheet/column/FormulaOptions.vue +++ b/packages/nc-gui/components/smartsheet/column/FormulaOptions.vue @@ -235,6 +235,63 @@ function validateAgainstMeta(parsedTree: any, errors = new Set(), typeErrors = n }, typeErrors, ) + } else if (parsedTree.callee.name === 'DATETIME_DIFF') { + // parsedTree.arguments[0] = date + validateAgainstType( + parsedTree.arguments[0], + formulaTypes.DATE, + (v: any) => { + if (!validateDateWithUnknownFormat(v)) { + typeErrors.add('The first parameter of DATETIME_DIFF() should have date value') + } + }, + typeErrors, + ) + // parsedTree.arguments[1] = date + validateAgainstType( + parsedTree.arguments[1], + formulaTypes.DATE, + (v: any) => { + if (!validateDateWithUnknownFormat(v)) { + typeErrors.add('The second parameter of DATETIME_DIFF() should have date value') + } + }, + typeErrors, + ) + // parsedTree.arguments[2] = ["milliseconds" | "ms" | "seconds" | "s" | "minutes" | "m" | "hours" | "h" | "days" | "d" | "weeks" | "w" | "months" | "M" | "quarters" | "Q" | "years" | "y"] + validateAgainstType( + parsedTree.arguments[2], + formulaTypes.STRING, + (v: any) => { + if ( + ![ + 'milliseconds', + 'ms', + 'seconds', + 's', + 'minutes', + 'm', + 'hours', + 'h', + 'days', + 'd', + 'weeks', + 'w', + 'months', + 'M', + 'quarters', + 'Q', + 'years', + 'y', + ].includes(v) + ) { + typeErrors.add( + 'The third parameter of DATETIME_DIFF() should have value either "milliseconds", "ms", "seconds", "s", "minutes", "m", "hours", "h", "days", "d", "weeks", "w", "months", "M", "quarters", "Q", "years", or "y"', + ) + } + }, + typeErrors, + ) } } } From 5f64da2f3713a93f207473759c1ad6ad39aee778 Mon Sep 17 00:00:00 2001 From: Wing-Kam Wong Date: Wed, 7 Dec 2022 18:41:14 +0800 Subject: [PATCH 02/15] feat(nc-gui): add DATETIME_DIFF hint --- packages/nc-gui/utils/formulaUtils.ts | 23 +++++++++++++++++++++++ 1 file changed, 23 insertions(+) diff --git a/packages/nc-gui/utils/formulaUtils.ts b/packages/nc-gui/utils/formulaUtils.ts index e49655338f..5c1cdf99be 100644 --- a/packages/nc-gui/utils/formulaUtils.ts +++ b/packages/nc-gui/utils/formulaUtils.ts @@ -51,6 +51,29 @@ const formulas: Record = { 'DATEADD({column1}, -2, "year")', ], }, + DATETIME_DIFF: { + type: formulaTypes.DATE, + validation: { + args: { + min: 2, + max: 3, + }, + }, + description: 'Calculate the difference of two given date / datetime in specified units.', + syntax: + 'DATETIME_DIFF(date | datetime, date | datetime, ["milliseconds" | "ms" | "seconds" | "s" | "minutes" | "m" | "hours" | "h" | "days" | "d" | "weeks" | "w" | "months" | "M" | "quarters" | "Q" | "years" | "y"])', + examples: [ + 'DATEDIFF({column1}, {column2})', + 'DATEDIFF({column1}, {column2}, "seconds")', + 'DATEDIFF({column1}, {column2}, "s")', + 'DATEDIFF({column1}, {column2}, "years")', + 'DATEDIFF({column1}, {column2}, "y")', + 'DATEDIFF({column1}, {column2}, "minutes")', + 'DATEDIFF({column1}, {column2}, "m")', + 'DATEDIFF({column1}, {column2}, "days")', + 'DATEDIFF({column1}, {column2}, "d")', + ], + }, AND: { type: formulaTypes.COND_EXP, validation: { From f10cf40ee224aec34970dec39694e2e44a51c79a Mon Sep 17 00:00:00 2001 From: Wing-Kam Wong Date: Wed, 7 Dec 2022 18:41:42 +0800 Subject: [PATCH 03/15] feat(nocodb-sdk): add DATETIME_DIFF to formula list --- packages/nocodb-sdk/src/lib/formulaHelpers.ts | 1 + 1 file changed, 1 insertion(+) diff --git a/packages/nocodb-sdk/src/lib/formulaHelpers.ts b/packages/nocodb-sdk/src/lib/formulaHelpers.ts index 94f22b79b5..ffa7964488 100644 --- a/packages/nocodb-sdk/src/lib/formulaHelpers.ts +++ b/packages/nocodb-sdk/src/lib/formulaHelpers.ts @@ -132,6 +132,7 @@ export function jsepTreeToFormula(node) { 'AVG', 'ADD', 'DATEADD', + 'DATETIME_DIFF', 'WEEKDAY', 'AND', 'OR', From 7fbacb6023c7a05136cab44a3200c59506566e25 Mon Sep 17 00:00:00 2001 From: Wing-Kam Wong Date: Wed, 7 Dec 2022 18:41:58 +0800 Subject: [PATCH 04/15] feat(docs): add DATETIME_DIFF usage --- packages/noco-docs/content/en/setup-and-usages/formulas.md | 2 ++ 1 file changed, 2 insertions(+) diff --git a/packages/noco-docs/content/en/setup-and-usages/formulas.md b/packages/noco-docs/content/en/setup-and-usages/formulas.md index 6d39cb250d..5a1d7c3a1c 100644 --- a/packages/noco-docs/content/en/setup-and-usages/formulas.md +++ b/packages/noco-docs/content/en/setup-and-usages/formulas.md @@ -97,6 +97,8 @@ Example: ({Column1} + ({Column2} * {Column3}) / (3 - $Column4$ )) | | | `DATEADD(date, 1, 'year')` | Supposing {DATE_COL} is 2022-03-14 03:14. The result is 2023-03-14 03:14. | DateTime columns and negative values are supported. Example: `DATEADD(DATE_TIME_COL, -1, 'year')` | | | | `IF(NOW() < DATEADD(date,10,'day'), "true", "false")` | If the current date is less than {DATE_COL} plus 10 days, it returns true. Otherwise, it returns false. | DateTime columns and negative values are supported. | | | | `IF(NOW() < DATEADD(date,10,'day'), "true", "false")` | If the current date is less than {DATE_COL} plus 10 days, it returns true. Otherwise, it returns false. | DateTime columns and negative values are supported. | +| **DATETIME_DIFF** | `DATETIME_DIFF(date, date, ["milliseconds" \| "ms" \| "seconds" \| "s" \| "minutes" \| "m" \| "hours" \| "h" \| "days" \| "d" \| "weeks" \| "w" \| "months" \| "M" \| "quarters" \| "Q" \| "years" \| "y"])` | `DATETIME_DIFF("2022/10/14", "2022/10/15", "second")` | Supposing {DATE_COL_1} is 2017-08-25 and {DATE_COL_2} is 2011-08-25. The result is 86400. | Compares two dates and returns the difference in the unit specified. Positive integers indicate the second date being in the past compared to the first and vice versa for negative ones. | +| | | `WEEKDAY(NOW(), "sunday")` | If today is Monday, it returns 1 | Get the week day of NOW() with the first day set as sunday | | **WEEKDAY** | `WEEKDAY(date, [startDayOfWeek])` | `WEEKDAY(NOW())` | If today is Monday, it returns 0 | Returns the day of the week as an integer between 0 and 6 inclusive starting from Monday by default. You can optionally change the start day of the week by specifying in the second argument | | | | `WEEKDAY(NOW(), "sunday")` | If today is Monday, it returns 1 | Get the week day of NOW() with the first day set as sunday | From 961247f4e5038b5f492971e8800ddb96e8f610ca Mon Sep 17 00:00:00 2001 From: Wing-Kam Wong Date: Wed, 7 Dec 2022 19:48:58 +0800 Subject: [PATCH 05/15] feat(nocodb): covertUnits --- .../lib/sql/helpers/convertUnits.ts | 155 ++++++++++++++++++ 1 file changed, 155 insertions(+) create mode 100644 packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/helpers/convertUnits.ts diff --git a/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/helpers/convertUnits.ts b/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/helpers/convertUnits.ts new file mode 100644 index 0000000000..22daefe71c --- /dev/null +++ b/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/helpers/convertUnits.ts @@ -0,0 +1,155 @@ +export function convertUnits( + unit: string, + type: 'mysql' | 'mssql' | 'pg' | 'sqlite' +) { + switch (unit) { + case 'milliseconds': + case 'ms': { + if (type === 'mssql') { + return 'millisecond'; + } + + if (type === 'mysql') { + // MySQL doesn't support millisecond + // hence change from MICROSECOND to millisecond manually + return 'MICROSECOND'; + } + + if (type === 'pg' || type === 'sqlite') { + return 'milliseconds'; + } + + return unit; + } + case 'seconds': + case 's': { + if (type === 'mssql' || type === 'pg') { + return 'second'; + } + + if (type === 'mysql') { + return 'SECOND'; + } + + if (type === 'sqlite') { + return 'seconds'; + } + + return unit; + } + case 'minutes': + case 'm': { + if (type === 'mssql' || type === 'pg') { + return 'minute'; + } + + if (type === 'mysql') { + return 'MINUTE'; + } + + if (type === 'sqlite') { + return 'minutes'; + } + + return unit; + } + case 'hours': + case 'h': { + if (type === 'mssql' || type === 'pg') { + return 'hour'; + } + + if (type === 'mysql') { + return 'HOUR'; + } + + if (type === 'sqlite') { + return 'hours'; + } + + return unit; + } + case 'days': + case 'd': { + if (type === 'mssql' || type === 'pg') { + return 'day'; + } + + if (type === 'mysql') { + return 'DAY'; + } + + if (type === 'sqlite') { + return 'days'; + } + + return unit; + } + case 'weeks': + case 'w': { + if (type === 'mssql' || type === 'pg') { + return 'week'; + } + + if (type === 'mysql') { + return 'WEEK'; + } + + if (type === 'sqlite') { + return 'weeks'; + } + + return unit; + } + case 'months': + case 'M': { + if (type === 'mssql' || type === 'pg') { + return 'month'; + } + + if (type === 'mysql') { + return 'MONTH'; + } + + if (type === 'sqlite') { + return 'months'; + } + + return unit; + } + case 'quarters': + case 'Q': { + if (type === 'mssql' || type === 'pg') { + return 'quarter'; + } + + if (type === 'mysql') { + return 'QUARTER'; + } + + if (type === 'sqlite') { + return 'quarters'; + } + + return unit; + } + case 'years': + case 'y': { + if (type === 'mssql' || type === 'pg') { + return 'year'; + } + + if (type === 'mysql') { + return 'YEAR'; + } + + if (type === 'sqlite') { + return 'years'; + } + + return unit; + } + default: + return unit; + } +} From 9d104016bdda3f1f1905b133293d1ca5e7307632 Mon Sep 17 00:00:00 2001 From: Wing-Kam Wong Date: Wed, 7 Dec 2022 19:56:36 +0800 Subject: [PATCH 06/15] feat(nocodb): add DATETIME_DIFF logic for mysql --- .../lib/sql/functionMappings/mysql.ts | 21 +++++++++++++++++++ 1 file changed, 21 insertions(+) diff --git a/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/mysql.ts b/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/mysql.ts index ab1acb763b..2512437c17 100644 --- a/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/mysql.ts +++ b/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/mysql.ts @@ -1,6 +1,7 @@ import dayjs from 'dayjs'; import { MapFnArgs } from '../mapFunctionName'; import commonFns from './commonFns'; +import { convertUnits } from '../helpers/convertUnits'; import { getWeekdayByText } from '../helpers/formulaFnHelper'; const mysql2 = { @@ -61,6 +62,26 @@ const mysql2 = { END${colAlias}` ); }, + DATETIME_DIFF: ({ fn, knex, pt, colAlias }: MapFnArgs) => { + const datetime_expr1 = fn(pt.arguments[0]); + const datetime_expr2 = fn(pt.arguments[1]); + + const unit = convertUnits( + pt.arguments[2] ? fn(pt.arguments[2]).bindings[0] : 'seconds', + 'mysql' + ); + + if (unit === 'MICROSECOND') { + // MySQL doesn't support millisecond + // hence change from MICROSECOND to millisecond manually + return knex.raw( + `TIMESTAMPDIFF(${unit}, ${datetime_expr2}, ${datetime_expr1}) div 1000 ${colAlias}` + ); + } + return knex.raw( + `TIMESTAMPDIFF(${unit}, ${datetime_expr2}, ${datetime_expr1}) ${colAlias}` + ); + }, WEEKDAY: ({ fn, knex, pt, colAlias }: MapFnArgs) => { // WEEKDAY() returns an index from 0 to 6 for Monday to Sunday return knex.raw( From 5ad979b66b974f6079e13ab688a547f4e264aaa6 Mon Sep 17 00:00:00 2001 From: Wing-Kam Wong Date: Thu, 8 Dec 2022 16:37:26 +0800 Subject: [PATCH 07/15] feat(nocodb): add DATETIME_DIFF logic for pg --- .../lib/sql/functionMappings/pg.ts | 48 +++++++++++++++++++ 1 file changed, 48 insertions(+) diff --git a/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/pg.ts b/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/pg.ts index f24ec33598..60c0e122c4 100644 --- a/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/pg.ts +++ b/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/pg.ts @@ -1,6 +1,7 @@ import dayjs from 'dayjs'; import { MapFnArgs } from '../mapFunctionName'; import commonFns from './commonFns'; +import { convertUnits } from '../helpers/convertUnits'; import { getWeekdayByText } from '../helpers/formulaFnHelper'; const pg = { @@ -50,6 +51,53 @@ const pg = { )}')::interval${colAlias}` ); }, + DATETIME_DIFF: ({ fn, knex, pt, colAlias }: MapFnArgs) => { + const datetime_expr1 = fn(pt.arguments[0]); + const datetime_expr2 = fn(pt.arguments[1]); + const rawUnit = pt.arguments[2] + ? fn(pt.arguments[2]).bindings[0] + : 'seconds'; + let sql; + const unit = convertUnits(rawUnit, 'pg'); + switch (unit) { + case 'second': + sql = `EXTRACT(EPOCH from (${datetime_expr1}::TIMESTAMP - ${datetime_expr2}::TIMESTAMP))::INTEGER`; + break; + case 'minute': + sql = `EXTRACT(EPOCH from (${datetime_expr1}::TIMESTAMP - ${datetime_expr2}::TIMESTAMP))::INTEGER / 60`; + break; + case 'milliseconds': + sql = `EXTRACT(EPOCH from (${datetime_expr1}::TIMESTAMP - ${datetime_expr2}::TIMESTAMP))::INTEGER / 3600`; + break; + case 'week': + sql = `TRUNC(DATE_PART('day', ${datetime_expr1}::TIMESTAMP - ${datetime_expr2}::TIMESTAMP) / 7)`; + break; + case 'month': + sql = `( + DATE_PART('year', ${datetime_expr1}::TIMESTAMP) - + DATE_PART('year', ${datetime_expr2}::TIMESTAMP) + ) * 12 + ( + DATE_PART('month', ${datetime_expr1}::TIMESTAMP) - + DATE_PART('month', ${datetime_expr2}::TIMESTAMP) + )`; + break; + case 'quarter': + sql = `((EXTRACT(QUARTER FROM ${datetime_expr1}::TIMESTAMP) + + DATE_PART('year', AGE(${datetime_expr1},'1900/01/01')) * 4) - 1) - + ((EXTRACT(QUARTER FROM ${datetime_expr2}::TIMESTAMP) + + DATE_PART('year', AGE(${datetime_expr2},'1900/01/01')) * 4) - 1)`; + break; + case 'year': + sql = `DATE_PART('year', ${datetime_expr1}::TIMESTAMP) - DATE_PART('year', ${datetime_expr2}::TIMESTAMP)`; + break; + case 'day': + sql = `DATE_PART('day', ${datetime_expr1}::TIMESTAMP - ${datetime_expr2}::TIMESTAMP)`; + break; + default: + sql = ''; + } + return knex.raw(`${sql} ${colAlias}`); + }, WEEKDAY: ({ fn, knex, pt, colAlias }: MapFnArgs) => { // isodow: the day of the week as Monday (1) to Sunday (7) // WEEKDAY() returns an index from 0 to 6 for Monday to Sunday From b5b7ce0ef9a6ff45fc5a06fb763360cfeca7281c Mon Sep 17 00:00:00 2001 From: Wing-Kam Wong Date: Thu, 8 Dec 2022 18:31:49 +0800 Subject: [PATCH 08/15] feat(nocodb): add dateTimeUtils --- .../nocodb/src/lib/utils/dateTimeUtils.ts | 75 +++++++++++++++++++ 1 file changed, 75 insertions(+) create mode 100644 packages/nocodb/src/lib/utils/dateTimeUtils.ts diff --git a/packages/nocodb/src/lib/utils/dateTimeUtils.ts b/packages/nocodb/src/lib/utils/dateTimeUtils.ts new file mode 100644 index 0000000000..19c058df34 --- /dev/null +++ b/packages/nocodb/src/lib/utils/dateTimeUtils.ts @@ -0,0 +1,75 @@ +import dayjs from 'dayjs'; + +export const dateFormats = [ + 'DD-MM-YYYY', + 'MM-DD-YYYY', + 'YYYY-MM-DD', + 'DD/MM/YYYY', + 'MM/DD/YYYY', + 'YYYY/MM/DD', + 'DD MM YYYY', + 'MM DD YYYY', + 'YYYY MM DD', +]; + +export function validateDateFormat(v: string) { + return dateFormats.includes(v); +} + +export function validateDateWithUnknownFormat(v: string) { + for (const format of dateFormats) { + if (dayjs(v, format, true).isValid() as any) { + return true; + } + for (const timeFormat of ['HH:mm', 'HH:mm:ss', 'HH:mm:ss.SSS']) { + if (dayjs(v, `${format} ${timeFormat}`, true).isValid() as any) { + return true; + } + } + } + return false; +} + +export function getDateFormat(v: string) { + for (const format of dateFormats) { + if (dayjs(v, format, true).isValid()) { + return format; + } + } + return 'YYYY/MM/DD'; +} + +export function getDateTimeFormat(v: string) { + for (const format of dateFormats) { + for (const timeFormat of ['HH:mm', 'HH:mm:ss', 'HH:mm:ss.SSS']) { + const dateTimeFormat = `${format} ${timeFormat}`; + if (dayjs(v, dateTimeFormat, true).isValid() as any) { + return dateTimeFormat; + } + } + } + return 'YYYY/MM/DD'; +} + +export function parseStringDate(v: string, dateFormat: string) { + const dayjsObj = dayjs(v); + if (dayjsObj.isValid()) { + v = dayjsObj.format('YYYY-MM-DD'); + } else { + v = dayjs(v, dateFormat).format('YYYY-MM-DD'); + } + return v; +} + +export function convertToTargetFormat( + v: string, + oldDataFormat, + newDateFormat: string +) { + if ( + !dateFormats.includes(oldDataFormat) || + !dateFormats.includes(newDateFormat) + ) + return v; + return dayjs(v, oldDataFormat).format(newDateFormat); +} From 82462d2085d93520a7a5aaa675922a768a46995d Mon Sep 17 00:00:00 2001 From: Wing-Kam Wong Date: Thu, 8 Dec 2022 18:32:18 +0800 Subject: [PATCH 09/15] feat(nocodb): add DATETIME_DIFF logic for sqlite --- .../lib/sql/functionMappings/sqlite.ts | 63 ++++++++++++++++++- 1 file changed, 62 insertions(+), 1 deletion(-) diff --git a/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/sqlite.ts b/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/sqlite.ts index be33bb7606..94817b79ce 100644 --- a/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/sqlite.ts +++ b/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/sqlite.ts @@ -1,7 +1,12 @@ import dayjs from 'dayjs'; import { MapFnArgs } from '../mapFunctionName'; import commonFns from './commonFns'; +import { convertUnits } from '../helpers/convertUnits'; import { getWeekdayByText } from '../helpers/formulaFnHelper'; +import { + convertToTargetFormat, + getDateFormat, +} from '../../../../../utils/dateTimeUtils'; const sqlite3 = { ...commonFns, @@ -77,7 +82,63 @@ const sqlite3 = { END${colAlias}` ); }, - + DATETIME_DIFF: ({ fn, knex, pt, colAlias }: MapFnArgs) => { + let datetime_expr1 = fn(pt.arguments[0]); + let datetime_expr2 = fn(pt.arguments[1]); + // JULIANDAY takes YYYY-MM-DD + datetime_expr1 = convertToTargetFormat( + datetime_expr1, + getDateFormat(datetime_expr1), + 'YYYY-MM-DD' + ); + datetime_expr2 = convertToTargetFormat( + datetime_expr2, + getDateFormat(datetime_expr2), + 'YYYY-MM-DD' + ); + const rawUnit = pt.arguments[2] + ? fn(pt.arguments[2]).bindings[0] + : 'seconds'; + let sql; + const unit = convertUnits(rawUnit, 'sqlite'); + switch (unit) { + case 'seconds': + sql = `ROUND((JULIANDAY('${datetime_expr1}') - JULIANDAY('${datetime_expr2}')) * 86400)`; + break; + case 'minutes': + sql = `ROUND((JULIANDAY('${datetime_expr1}') - JULIANDAY('${datetime_expr2}')) * 1440)`; + break; + case 'hours': + sql = `ROUND((JULIANDAY('${datetime_expr1}') - JULIANDAY('${datetime_expr2}')) * 24)`; + break; + case 'milliseconds': + sql = `ROUND((JULIANDAY('${datetime_expr1}') - JULIANDAY('${datetime_expr2}')) * 86400000)`; + break; + case 'weeks': + sql = `ROUND((JULIANDAY('${datetime_expr1}') - JULIANDAY('${datetime_expr2}')) / 7)`; + break; + case 'months': + sql = `(ROUND((JULIANDAY('${datetime_expr1}') - JULIANDAY('${datetime_expr2}')) / 365)) + * 12 + (ROUND((JULIANDAY('${datetime_expr1}') - JULIANDAY('${datetime_expr2}')) / 365 / 12))`; + break; + case 'quarters': + sql = ` + ROUND((JULIANDAY('${datetime_expr1}')) / 365 / 4) - + ROUND((JULIANDAY('${datetime_expr2}')) / 365 / 4) + + (ROUND((JULIANDAY('${datetime_expr1}') - JULIANDAY('${datetime_expr2}')) / 365)) * 4 + `; + break; + case 'years': + sql = `ROUND((JULIANDAY('${datetime_expr1}') - JULIANDAY('${datetime_expr2}')) / 365)`; + break; + case 'days': + sql = `JULIANDAY('${datetime_expr1}') - JULIANDAY('${datetime_expr2}')`; + break; + default: + sql = ''; + } + return knex.raw(`${sql} ${colAlias}`); + }, WEEKDAY: ({ fn, knex, pt, colAlias }: MapFnArgs) => { // strftime('%w', date) - day of week 0 - 6 with Sunday == 0 // WEEKDAY() returns an index from 0 to 6 for Monday to Sunday From ac0c78b78365f572f61a855d73ee9f888a961015 Mon Sep 17 00:00:00 2001 From: Wing-Kam Wong Date: Thu, 8 Dec 2022 18:36:50 +0800 Subject: [PATCH 10/15] feat(nocodb): add missing hour logic and correct milliseconds sql --- .../lib/db/sql-data-mapper/lib/sql/functionMappings/pg.ts | 7 +++++-- 1 file changed, 5 insertions(+), 2 deletions(-) diff --git a/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/pg.ts b/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/pg.ts index 60c0e122c4..72ee49bcfa 100644 --- a/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/pg.ts +++ b/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/pg.ts @@ -67,6 +67,9 @@ const pg = { sql = `EXTRACT(EPOCH from (${datetime_expr1}::TIMESTAMP - ${datetime_expr2}::TIMESTAMP))::INTEGER / 60`; break; case 'milliseconds': + sql = `EXTRACT(EPOCH from (${datetime_expr1}::TIMESTAMP - ${datetime_expr2}::TIMESTAMP))::INTEGER * 1000`; + break; + case 'hour': sql = `EXTRACT(EPOCH from (${datetime_expr1}::TIMESTAMP - ${datetime_expr2}::TIMESTAMP))::INTEGER / 3600`; break; case 'week': @@ -83,9 +86,9 @@ const pg = { break; case 'quarter': sql = `((EXTRACT(QUARTER FROM ${datetime_expr1}::TIMESTAMP) + - DATE_PART('year', AGE(${datetime_expr1},'1900/01/01')) * 4) - 1) - + DATE_PART('year', AGE(${datetime_expr1}, '1900/01/01')) * 4) - 1) - ((EXTRACT(QUARTER FROM ${datetime_expr2}::TIMESTAMP) + - DATE_PART('year', AGE(${datetime_expr2},'1900/01/01')) * 4) - 1)`; + DATE_PART('year', AGE(${datetime_expr2}, '1900/01/01')) * 4) - 1)`; break; case 'year': sql = `DATE_PART('year', ${datetime_expr1}::TIMESTAMP) - DATE_PART('year', ${datetime_expr2}::TIMESTAMP)`; From c758cd16c20da128026f40245ca6371836ec3c44 Mon Sep 17 00:00:00 2001 From: Wing-Kam Wong Date: Fri, 9 Dec 2022 14:08:13 +0800 Subject: [PATCH 11/15] feat(nocodb): feat(nocodb): add DATETIME_DIFF logic for mssql --- .../lib/sql/functionMappings/mssql.ts | 12 ++++++++++++ 1 file changed, 12 insertions(+) diff --git a/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/mssql.ts b/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/mssql.ts index 1358a87411..b666957176 100644 --- a/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/mssql.ts +++ b/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/mssql.ts @@ -1,6 +1,7 @@ import dayjs from 'dayjs'; import { MapFnArgs } from '../mapFunctionName'; import commonFns from './commonFns'; +import { convertUnits } from '../helpers/convertUnits'; import { getWeekdayByText } from '../helpers/formulaFnHelper'; const mssql = { @@ -110,6 +111,17 @@ const mssql = { END${colAlias}` ); }, + DATETIME_DIFF: ({ fn, knex, pt, colAlias }: MapFnArgs) => { + const datetime_expr1 = fn(pt.arguments[0]); + const datetime_expr2 = fn(pt.arguments[1]); + const rawUnit = pt.arguments[2] + ? fn(pt.arguments[2]).bindings[0] + : 'seconds'; + const unit = convertUnits(rawUnit, 'mssql'); + return knex.raw( + `DATEDIFF(${unit}, ${datetime_expr2}, ${datetime_expr1}) ${colAlias}` + ); + }, WEEKDAY: ({ fn, knex, pt, colAlias }: MapFnArgs) => { // DATEPART(WEEKDAY, DATE): sunday = 1, monday = 2, ..., saturday = 7 // WEEKDAY() returns an index from 0 to 6 for Monday to Sunday From 40c2aada155f1c4302ac26034443acea82760f29 Mon Sep 17 00:00:00 2001 From: Wing-Kam Wong Date: Fri, 9 Dec 2022 14:15:55 +0800 Subject: [PATCH 12/15] feat(playwright): formula DATETIME_DIFF tests --- tests/playwright/tests/columnFormula.spec.ts | 40 ++++++++++++++++++++ 1 file changed, 40 insertions(+) diff --git a/tests/playwright/tests/columnFormula.spec.ts b/tests/playwright/tests/columnFormula.spec.ts index d9a1ed5763..b8c5fdcc8a 100644 --- a/tests/playwright/tests/columnFormula.spec.ts +++ b/tests/playwright/tests/columnFormula.spec.ts @@ -30,6 +30,46 @@ const formulaDataByDbType = (context: NcContext) => [ formula: `WEEKDAY("2022-07-19", "sunday")`, result: ['2', '2', '2', '2', '2'], }, + { + formula: `DATETIME_DIFF("2022/10/14", "2022/10/15")`, + result: ['-86400', '-86400', '-86400', '-86400', '-86400'], + }, + { + formula: `DATETIME_DIFF("2022/10/14", "2022/10/15", "minutes")`, + result: ['-1440', '-1440', '-1440', '-1440', '-1440'], + }, + { + formula: `DATETIME_DIFF("2022/10/14", "2022/10/15", "seconds")`, + result: ['-86400', '-86400', '-86400', '-86400', '-86400'], + }, + { + formula: `DATETIME_DIFF("2022/10/14", "2022/10/15", "milliseconds")`, + result: ['-86400000', '-86400000', '-86400000', '-86400000', '-86400000'], + }, + { + formula: `DATETIME_DIFF("2022/10/14", "2022/10/15", "hours")`, + result: ['-24', '-24', '-24', '-24', '-24'], + }, + { + formula: `DATETIME_DIFF("2022/10/14", "2022/10/15", "weeks")`, + result: ['-52', '-52', '-52', '-52', '-52'], + }, + { + formula: `DATETIME_DIFF("2022/10/14", "2022/10/15", "months")`, + result: ['-12', '-12', '-12', '-12', '-12'], + }, + { + formula: `DATETIME_DIFF("2022/10/14", "2022/10/15", "Q")`, + result: ['-4', '-4', '-4', '-4', '-4'], + }, + { + formula: `DATETIME_DIFF("2022/10/14", "2022/10/15", "y")`, + result: ['-1', '-1', '-1', '-1', '-1'], + }, + { + formula: `DATETIME_DIFF("2022/10/14", "2022/10/15", "d")`, + result: ['-365', '-365', '-365', '-365', '-365'], + }, { formula: `CONCAT(UPPER({City}), LOWER({City}), TRIM(' trimmed '))`, result: [ From 94b607c3b2f5f85c54f2b9d97c5c8bb2fcd7e6b1 Mon Sep 17 00:00:00 2001 From: Wing-Kam Wong Date: Sat, 10 Dec 2022 00:24:39 +0800 Subject: [PATCH 13/15] fix(playwright): incorrect formula --- tests/playwright/tests/columnFormula.spec.ts | 10 +++++----- 1 file changed, 5 insertions(+), 5 deletions(-) diff --git a/tests/playwright/tests/columnFormula.spec.ts b/tests/playwright/tests/columnFormula.spec.ts index b8c5fdcc8a..bc08da00ba 100644 --- a/tests/playwright/tests/columnFormula.spec.ts +++ b/tests/playwright/tests/columnFormula.spec.ts @@ -51,23 +51,23 @@ const formulaDataByDbType = (context: NcContext) => [ result: ['-24', '-24', '-24', '-24', '-24'], }, { - formula: `DATETIME_DIFF("2022/10/14", "2022/10/15", "weeks")`, + formula: `DATETIME_DIFF("2022/10/14", "2023/10/14", "w")`, result: ['-52', '-52', '-52', '-52', '-52'], }, { - formula: `DATETIME_DIFF("2022/10/14", "2022/10/15", "months")`, + formula: `DATETIME_DIFF("2022/10/14", "2023/10/14", "M")`, result: ['-12', '-12', '-12', '-12', '-12'], }, { - formula: `DATETIME_DIFF("2022/10/14", "2022/10/15", "Q")`, + formula: `DATETIME_DIFF("2022/10/14", "2023/10/14", "Q")`, result: ['-4', '-4', '-4', '-4', '-4'], }, { - formula: `DATETIME_DIFF("2022/10/14", "2022/10/15", "y")`, + formula: `DATETIME_DIFF("2022/10/14", "2023/10/14", "y")`, result: ['-1', '-1', '-1', '-1', '-1'], }, { - formula: `DATETIME_DIFF("2022/10/14", "2022/10/15", "d")`, + formula: `DATETIME_DIFF("2022/10/14", "2023/10/14", "d")`, result: ['-365', '-365', '-365', '-365', '-365'], }, { From 7c0e24ad85dbc823ee98064286f0c526f6700bf0 Mon Sep 17 00:00:00 2001 From: Wing-Kam Wong Date: Sat, 10 Dec 2022 15:19:49 +0800 Subject: [PATCH 14/15] fix(nocodb): add missing bindings --- .../lib/db/sql-data-mapper/lib/sql/functionMappings/sqlite.ts | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/sqlite.ts b/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/sqlite.ts index 94817b79ce..ad384aeedf 100644 --- a/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/sqlite.ts +++ b/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/functionMappings/sqlite.ts @@ -83,8 +83,8 @@ const sqlite3 = { ); }, DATETIME_DIFF: ({ fn, knex, pt, colAlias }: MapFnArgs) => { - let datetime_expr1 = fn(pt.arguments[0]); - let datetime_expr2 = fn(pt.arguments[1]); + let datetime_expr1 = fn(pt.arguments[0]).bindings[0]; + let datetime_expr2 = fn(pt.arguments[1]).bindings[0]; // JULIANDAY takes YYYY-MM-DD datetime_expr1 = convertToTargetFormat( datetime_expr1, From 9105cd8cd910ed703f98642f20dbe6b1e4b26c0f Mon Sep 17 00:00:00 2001 From: Wing-Kam Wong Date: Wed, 21 Dec 2022 21:51:08 +0800 Subject: [PATCH 15/15] refactor(nocodb): move the logic to switch --- .../lib/sql/helpers/convertUnits.ts | 202 ++++++++---------- 1 file changed, 92 insertions(+), 110 deletions(-) diff --git a/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/helpers/convertUnits.ts b/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/helpers/convertUnits.ts index 22daefe71c..961a9d26d3 100644 --- a/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/helpers/convertUnits.ts +++ b/packages/nocodb/src/lib/db/sql-data-mapper/lib/sql/helpers/convertUnits.ts @@ -5,149 +5,131 @@ export function convertUnits( switch (unit) { case 'milliseconds': case 'ms': { - if (type === 'mssql') { - return 'millisecond'; + switch (type) { + case 'mssql': + return 'millisecond'; + case 'mysql': + // MySQL doesn't support millisecond + // hence change from MICROSECOND to millisecond manually + return 'MICROSECOND'; + case 'pg': + case 'sqlite': + return 'milliseconds'; + default: + return unit; } - - if (type === 'mysql') { - // MySQL doesn't support millisecond - // hence change from MICROSECOND to millisecond manually - return 'MICROSECOND'; - } - - if (type === 'pg' || type === 'sqlite') { - return 'milliseconds'; - } - - return unit; } case 'seconds': case 's': { - if (type === 'mssql' || type === 'pg') { - return 'second'; - } - - if (type === 'mysql') { - return 'SECOND'; + switch (type) { + case 'mssql': + case 'pg': + return 'second'; + case 'mysql': + return 'SECOND'; + case 'sqlite': + return 'seconds'; + default: + return unit; } - - if (type === 'sqlite') { - return 'seconds'; - } - - return unit; } case 'minutes': case 'm': { - if (type === 'mssql' || type === 'pg') { - return 'minute'; - } - - if (type === 'mysql') { - return 'MINUTE'; + switch (type) { + case 'mssql': + case 'pg': + return 'minute'; + case 'mysql': + return 'MINUTE'; + case 'sqlite': + return 'minutes'; + default: + return unit; } - - if (type === 'sqlite') { - return 'minutes'; - } - - return unit; } case 'hours': case 'h': { - if (type === 'mssql' || type === 'pg') { - return 'hour'; - } - - if (type === 'mysql') { - return 'HOUR'; - } - - if (type === 'sqlite') { - return 'hours'; + switch (type) { + case 'mssql': + case 'pg': + return 'hour'; + case 'mysql': + return 'HOUR'; + case 'sqlite': + return 'hours'; + default: + return unit; } - - return unit; } case 'days': case 'd': { - if (type === 'mssql' || type === 'pg') { - return 'day'; - } - - if (type === 'mysql') { - return 'DAY'; - } - - if (type === 'sqlite') { - return 'days'; + switch (type) { + case 'mssql': + case 'pg': + return 'day'; + case 'mysql': + return 'DAY'; + case 'sqlite': + return 'days'; + default: + return unit; } - - return unit; } case 'weeks': case 'w': { - if (type === 'mssql' || type === 'pg') { - return 'week'; - } - - if (type === 'mysql') { - return 'WEEK'; + switch (type) { + case 'mssql': + case 'pg': + return 'week'; + case 'mysql': + return 'WEEK'; + case 'sqlite': + return 'weeks'; + default: + return unit; } - - if (type === 'sqlite') { - return 'weeks'; - } - - return unit; } case 'months': case 'M': { - if (type === 'mssql' || type === 'pg') { - return 'month'; + switch (type) { + case 'mssql': + case 'pg': + return 'month'; + case 'mysql': + return 'MONTH'; + case 'sqlite': + return 'months'; + default: + return unit; } - - if (type === 'mysql') { - return 'MONTH'; - } - - if (type === 'sqlite') { - return 'months'; - } - - return unit; } case 'quarters': case 'Q': { - if (type === 'mssql' || type === 'pg') { - return 'quarter'; + switch (type) { + case 'mssql': + case 'pg': + return 'quarter'; + case 'mysql': + return 'QUARTER'; + case 'sqlite': + return 'quarters'; + default: + return unit; } - - if (type === 'mysql') { - return 'QUARTER'; - } - - if (type === 'sqlite') { - return 'quarters'; - } - - return unit; } case 'years': case 'y': { - if (type === 'mssql' || type === 'pg') { - return 'year'; + switch (type) { + case 'mssql': + case 'pg': + return 'year'; + case 'mysql': + return 'YEAR'; + case 'sqlite': + return 'years'; + default: + return unit; } - - if (type === 'mysql') { - return 'YEAR'; - } - - if (type === 'sqlite') { - return 'years'; - } - - return unit; } default: return unit;