Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

fix(hana): Apply time zones when inserting timestamps and datetimes #606

Open
wants to merge 10 commits into
base: main
Choose a base branch
from
34 changes: 34 additions & 0 deletions hana/cds-plugin.js
Original file line number Diff line number Diff line change
Expand Up @@ -7,3 +7,37 @@ if (!cds.env.fiori.lean_draft) {
if (cds.requires.db?.impl === '@cap-js/hana') {
cds.env.sql.dialect = 'hana'
}

// Consider that '-' is only allowed as timezone after ':' or 'T'
const ISO = `FUNCTION ISO(RAW NVARCHAR(36))
RETURNS RET TIMESTAMP LANGUAGE SQLSCRIPT AS
BEGIN
DECLARE REGEXP NVARCHAR(255);
DECLARE TIMEZONE NVARCHAR(36);
DECLARE MULTIPLIER INTEGER;
DECLARE HOURS INTEGER;
DECLARE MINUTES INTEGER;
REGEXP := '(([-+])([[:digit:]]{2}):?([[:digit:]]{2})?|Z)$';
TIMEZONE := SUBSTR_REGEXPR(:REGEXP IN RAW GROUP 1);
RET := TO_TIMESTAMP(RAW);
IF :TIMEZONE = 'Z' OR :TIMEZONE IS NULL THEN
RETURN;
END IF;
MULTIPLIER := TO_INTEGER(SUBSTR_REGEXPR(:REGEXP IN TIMEZONE GROUP 2) || '1');
HOURS := TO_INTEGER(SUBSTR_REGEXPR(:REGEXP IN TIMEZONE GROUP 3));
MINUTES := COALESCE(TO_INTEGER(SUBSTR_REGEXPR(:REGEXP IN TIMEZONE GROUP 4)),0);
RET := ADD_SECONDS(:RET, (HOURS * 60 + MINUTES) * 60 * MULTIPLIER * -1);
END;`

// monkey patch as not extendable as class
const compiler_to_hdi = cds.compiler.to.hdi
cds.compiler.to.hdi = Object.assign(function capjs_compile_hdi(...args) {
const artifacts = compiler_to_hdi(...args)
artifacts['ISO.hdbfunction'] = ISO
return artifacts
},
{...compiler_to_hdi} // take over other stuff like keywords
)

// TODO: we can override cds.compile.to.sql/.delta in a similar fashion for our tests
module.exports.ISO = ISO
37 changes: 30 additions & 7 deletions hana/lib/HANAService.js
Original file line number Diff line number Diff line change
Expand Up @@ -60,6 +60,23 @@
const dbc = new driver(credentials)
await dbc.connect()
HANAVERSION = dbc.server.major

// Check whether the ISO function is available in the current deployment
if (!service.hasIsoFunction) {
service.hasIsoFunction = dbc.exec(`SELECT ISO('') FROM DUMMY`).catch(() => {
if (!service.class.CQN2SQL.InputConverters.Timestamp) {
service.class.CQN2SQL.InputConverters = service.class.CQN2SQL.InputConverters.__proto__
}
}, () => {
service.class.CQN2SQL.InputConverters = {
__proto__: service.class.CQN2SQL.InputConverters,
DateTime: undefined,
Timestamp: undefined
}
})
}
await service.hasIsoFunction

return dbc
} catch (err) {
if (isMultitenant) {
Expand Down Expand Up @@ -117,7 +134,7 @@
const { query, data } = req

if (!query.target) {
try { this.infer(query) } catch (e) { /**/ }

Check warning on line 137 in hana/lib/HANAService.js

View workflow job for this annotation

GitHub Actions / Node.js 18

'e' is defined but never used

Check warning on line 137 in hana/lib/HANAService.js

View workflow job for this annotation

GitHub Actions / HANA Node.js 18

'e' is defined but never used
}
if (!query.target || query.target._unresolved) {
return super.onSELECT(req)
Expand All @@ -137,7 +154,7 @@

// REVISIT: add prepare options when param:true is used
const sqlScript = isLockQuery || isSimple ? sql : this.wrapTemporary(temporary, withclause, blobs)
let rows
let rows
if (values?.length || blobs.length > 0) {
const ps = await this.prepare(sqlScript, blobs.length)
rows = this.ensureDBC() && await ps.all(values || [])
Expand Down Expand Up @@ -973,7 +990,7 @@
? []
: Object.keys(elements)
.filter(e => {
if (elements[e]?.virtual) return false
if (elements[e]?.virtual || elements[e]?.isAssociation) return false
if (columns.find(c => c.name === e)) return false
if (elements[e]?.[annotation]) return true
if (!isUpdate && elements[e]?.default) return true
Expand All @@ -991,7 +1008,7 @@
return [...columns, ...requiredColumns].map(({ name, sql }) => {
const element = elements?.[name] || {}
// Don't apply input converters for place holders
const converter = (sql !== '?' && element[inputConverterKey]) || (e => e)
const converter = element[inputConverterKey] || (e => e)
const val = _managed[element[annotation]?.['=']]
let managed
if (val) managed = this.func({ func: 'session_context', args: [{ val, param: false }] })
Expand Down Expand Up @@ -1055,6 +1072,10 @@
array: () => `NVARCHAR(2147483647) FORMAT JSON`,
Vector: () => `NVARCHAR(2147483647)`,

// Keep as nvarchar until ISO transformation
DateTime: () => `NVARCHAR(32)`,
Timestamp: () => `NVARCHAR(32)`,

// JavaScript types
string: () => `NVARCHAR(2147483647)`,
number: () => `DOUBLE`,
Expand All @@ -1073,14 +1094,16 @@
// REVISIT: BASE64_DECODE has stopped working
// Unable to convert NVARCHAR to UTF8
// Not encoded string with CESU-8 or some UTF-8 except a surrogate pair at "base64_decode" function
Binary: e => `HEXTOBIN(${e})`,
Boolean: e => `CASE WHEN ${e} = 'true' THEN TRUE WHEN ${e} = 'false' THEN FALSE END`,
Binary: e => e === '?' ? e : `HEXTOBIN(${e})`,
Boolean: e => e === '?' ? e : `CASE WHEN ${e} = 'true' THEN TRUE WHEN ${e} = 'false' THEN FALSE END`,
Vector: e => `TO_REAL_VECTOR(${e})`,
// TODO: Decimal: (expr, element) => element.precision ? `TO_DECIMAL(${expr},${element.precision},${element.scale})` : expr

// Custom ISO function applies timezone when inserting
DateTime: e => `ISO(${e})`,
Timestamp: e => `ISO(${e})`,
// HANA types
'cds.hana.ST_POINT': e => `CASE WHEN ${e} IS NOT NULL THEN NEW ST_POINT(TO_DOUBLE(JSON_VALUE(${e}, '$.x')), TO_DOUBLE(JSON_VALUE(${e}, '$.y'))) END`,
'cds.hana.ST_GEOMETRY': e => `TO_GEOMETRY(${e})`,
'cds.hana.ST_GEOMETRY': e => `TO_GEOMETRY(${e})`
}

static OutputConverters = {
Expand Down
23 changes: 13 additions & 10 deletions hana/lib/drivers/base.js
Original file line number Diff line number Diff line change
Expand Up @@ -120,17 +120,20 @@ class HANADriver {
* Connects the driver using the provided credentials
* @returns {Promise<any>}
*/
async connect() {
async connect(sqls = []) {
this.connected = prom(this._native, 'connect')(this._creds)
return this.connected.then(async () => {
const version = await prom(this._native, 'exec')('SELECT VERSION FROM "SYS"."M_DATABASE"')
const split = version[0].VERSION.split('.')
this.server = {
major: split[0],
minor: split[2],
patch: split[3],
}
})
await this.connected
for (const sql of sqls) {
await prom(this._native, 'exec')(sql)
}

const version = await prom(this._native, 'exec')('SELECT VERSION FROM "SYS"."M_DATABASE"')
const split = version[0].VERSION.split('.')
this.server = {
major: split[0],
minor: split[2],
patch: split[3],
}
}

/**
Expand Down
20 changes: 4 additions & 16 deletions hana/lib/drivers/hdb.js
Original file line number Diff line number Diff line change
Expand Up @@ -55,19 +55,7 @@ class HDBDriver extends driver {
* @returns {Promise<any>}
*/
async connect() {
this.connected = prom(this._native, 'connect')(this._creds)
return this.connected.then(async () => {
const [version] = await Promise.all([
prom(this._native, 'exec')('SELECT VERSION FROM "SYS"."M_DATABASE"'),
this._creds.schema && prom(this._native, 'exec')(`SET SCHEMA ${this._creds.schema}`),
])
const split = version[0].VERSION.split('.')
this.server = {
major: split[0],
minor: split[2],
patch: split[3],
}
})
return super.connect(this._creds.schema ? [`SET SCHEMA ${this._creds.schema}`] : [])
}

async prepare(sql, hasBlobs) {
Expand Down Expand Up @@ -135,8 +123,8 @@ class HDBDriver extends driver {

_getResultForProcedure(rows, outParameters) {
// on hdb, rows already contains results for scalar params
const isArray = Array.isArray(rows)
const result = isArray ? {...rows[0]} : {...rows}
const isArray = Array.isArray(rows)
const result = isArray ? { ...rows[0] } : { ...rows }

// merge table output params into scalar params
const args = isArray ? rows.slice(1) : []
Expand All @@ -146,7 +134,7 @@ class HDBDriver extends driver {
result[params[i].PARAMETER_NAME] = args[i]
}
}

return result
}

Expand Down
4 changes: 2 additions & 2 deletions postgres/lib/PostgresService.js
Original file line number Diff line number Diff line change
Expand Up @@ -500,8 +500,8 @@
Int64: e => `CAST(${e} as bigint)`,
Date: e => `CAST(${e} as DATE)`,
Time: e => `CAST(${e} as TIME)`,
DateTime: e => `CAST(${e} as TIMESTAMP)`,
Timestamp: e => `CAST(${e} as TIMESTAMP)`,
DateTime: e => `CAST(${e} as TIMESTAMP WITH TIME ZONE)`,
Timestamp: e => `CAST(${e} as TIMESTAMP WITH TIME ZONE)`,
// REVISIT: Remove that with upcomming fixes in cds.linked
Double: (e, t) => `CAST(${e} as decimal${t.precision && t.scale ? `(${t.precision},${t.scale})` : ''})`,
DecimalFloat: (e, t) => `CAST(${e} as decimal${t.precision && t.scale ? `(${t.precision},${t.scale})` : ''})`,
Expand Down Expand Up @@ -566,7 +566,7 @@
GRANT "${creds.usergroup}" TO "${creds.user}" WITH ADMIN OPTION;
`)
await this.exec(`CREATE DATABASE "${creds.database}" OWNER="${creds.user}" TEMPLATE=template0`)
} catch (e) {

Check warning on line 569 in postgres/lib/PostgresService.js

View workflow job for this annotation

GitHub Actions / Node.js 18

'e' is defined but never used

Check warning on line 569 in postgres/lib/PostgresService.js

View workflow job for this annotation

GitHub Actions / HANA Node.js 18

'e' is defined but never used
// Failed to reset database
} finally {
await this.dbc.end()
Expand Down
2 changes: 1 addition & 1 deletion sqlite/lib/SQLiteService.js
Original file line number Diff line number Diff line change
Expand Up @@ -27,7 +27,7 @@ class SQLiteService extends SQLService {
const deterministic = { deterministic: true }
dbc.function('session_context', key => dbc[$session][key])
dbc.function('regexp', deterministic, (re, x) => (RegExp(re).test(x) ? 1 : 0))
dbc.function('ISO', deterministic, d => d && new Date(d).toISOString())
dbc.function('ISO', deterministic, d => d && new Date(/([+-]\d{2}:?(\d{2})?|Z)$/.test(d) ? d : `${d}Z`).toISOString())

// define date and time functions in js to allow for throwing errors
const isTime = /^\d{1,2}:\d{1,2}:\d{1,2}$/
Expand Down
5 changes: 5 additions & 0 deletions test/cds.js
Original file line number Diff line number Diff line change
Expand Up @@ -112,6 +112,11 @@ cds.test = Object.setPrototypeOf(function () {
ret.data.autoIsolation(true)

global.beforeAll(async () => {
if (cds.db.options.impl === '@cap-js/hana') {
await cds.run(`CREATE OR REPLACE ${require('../hana/cds-plugin.js').ISO}`)
await cds.disconnect() // Reset database connection to retrigger ISO detection
}

if (ret.data._autoIsolation && !ret.data._deployed) {
ret.data._deployed = cds.deploy(cds.options.from[0])
await ret.data._deployed
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -4,32 +4,37 @@ module.exports = [
},
{
timestamp: '1970-01-01T00:00:00.000Z',
'=timestamp': '1970-01-01T00:00:00.000Z',
'=timestamp': /1970-01-01T00:00:00.0000{0,6}Z/,
},
{
timestamp: new Date('1970-01-01Z'),
'=timestamp': '1970-01-01T00:00:00.000Z',
'=timestamp': /1970-01-01T00:00:00.0000{0,6}Z/,
},
{
timestamp: '1970-01-01T00:00:00.000Z',
'=timestamp': /1970-01-01T00:00:00.0000{0,6}Z/
},
/* Ignoring transformations
{
timestamp: '2020-01-01T10:00:00.000+10:00',
'=timestamp': /2020-01-01T00:00:00.0000{0,6}Z/
},
/*
{
timestamp: '1970-01-01',
'=timestamp': '1970-01-01 00:00:00.0000000'
'=timestamp': /1970-01-01T00:00:00.0000{0,6}Z/
},
{
timestamp: '1970-1-1',
'=timestamp': '1970-01-01 00:00:00.0000000'
'=timestamp': /1970-01-01T00:00:00.0000{0,6}Z/
},
{
timestamp: '2',
'=timestamp': '0002-01-01 00:00:00.0000000'
'=timestamp': /0002-01-01T00:00:00.0000{0,6}Z/
},
{
// HANA supports left trim
timestamp: ' 2',
'=timestamp': '0002-01-01 00:00:00.0000000'
'=timestamp': /0002-01-01T00:00:00.0000{0,6}Z/
},
{
// HANA does not support right trim
Expand All @@ -43,15 +48,15 @@ module.exports = [
},
{
timestamp: '2-2',
'=timestamp': '0002-02-01 00:00:00.0000000'
'=timestamp': /0002-02-01T00:00:00.0000{0,6}Z/
},
{
timestamp: '2-2-2',
'=timestamp': '0002-02-02 00:00:00.0000000'
'=timestamp': /0002-02-02T00:00:00.0000{0,6}Z/
},
{
timestamp: () => new Date('1970-01-01Z'),
'=timestamp': '1970-01-01 00:00:00.0000000'
'=timestamp': /1970-01-01T00:00:00.0000{0,6}Z/
},
{
// Z+2359 adds 23 hour and 59 minutes to the UTC time
Expand All @@ -68,26 +73,28 @@ module.exports = [
timestamp: '1970-01-01+2359',
'!': 'Invalid cds.Timestamp "1970-01-01+2359"'
},
*/
{
timestamp: '1970-01-01T01:10:59',
'=timestamp': '1970-01-01 01:10:59.0000000'
'=timestamp': /1970-01-01T01:10:59.0000{0,6}Z/
},
{
timestamp: '1970-01-01T00:00:00-2359',
'=timestamp': '1970-01-01 23:59:00.0000000'
timestamp: '1970-01-01T00:00:00-11:59',
'=timestamp': /1970-01-01T11:59:00.0000{0,6}Z/
},
{
timestamp: '1970-01-01T00:00:00.999',
'=timestamp': '1970-01-01 00:00:00.9990000'
'=timestamp': /1970-01-01T00:00:00.9990{0,6}Z/
},
{
timestamp: '1970-01-01T00:00:00.1234567',
'=timestamp': '1970-01-01 00:00:00.1234567'
'=timestamp': /1970-01-01T00:00:00.1234?5?6?7?0{0,2}Z/
},
{
timestamp: '1970-01-01T00:00:00.123456789',
'=timestamp': '1970-01-01 00:00:00.1234567'
'=timestamp': /1970-01-01T00:00:00.1234?5?6?7?8?9?Z/
},
/*
{
// HANA SECONDDATE does not support year 0 or lower
timestamp: '0000-01-01',
Expand Down
Loading