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
30 changes: 30 additions & 0 deletions hana/cds-plugin.js
Original file line number Diff line number Diff line change
Expand Up @@ -7,3 +7,33 @@ if (!cds.env.fiori.lean_draft) {
if (cds.requires.db?.impl === '@cap-js/hana') {
cds.env.sql.dialect = 'hana'
}

// monkey patch as not extendable as class
const compiler_to_hdi = cds.compiler.to.hdi
cds.compiler.to.hdi = function capjs_compile_hdi(...args) {
const artifacts = compiler_to_hdi(...args)
artifacts['ISO.hdbfunction'] =
`CREATE OR REPLACE 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;`

return artifacts
}

// TODO: we can override cds.compile.to.sql/.delta in a similar fashion for our tests
33 changes: 20 additions & 13 deletions hana/lib/HANAService.js
Original file line number Diff line number Diff line change
Expand Up @@ -900,7 +900,7 @@ class HANAService extends SQLService {
? []
: 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 @@ -918,7 +918,7 @@ class HANAService extends SQLService {
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 @@ -979,6 +979,10 @@ class HANAService extends SQLService {
array: () => `NVARCHAR(2147483647)`,
Vector: () => `NVARCHAR(2147483647)`,

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

// JavaScript types
string: () => `NVARCHAR(2147483647)`,
number: () => `DOUBLE`
Expand All @@ -990,10 +994,14 @@ class HANAService extends SQLService {
// 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})`,
}

static OutputConverters = {
Expand Down Expand Up @@ -1043,10 +1051,10 @@ class HANAService extends SQLService {
return super.dispatch(req)
}

async onCall({ query, data }, name, schema) {
const outParameters = await this._getProcedureMetadata(name, schema)
const ps = await this.prepare(query)
return ps.proc(data, outParameters)
async onCall({ query, data }, name, schema) {
const outParameters = await this._getProcedureMetadata(name, schema)
const ps = await this.prepare(query)
return ps.proc(data, outParameters)
}

async onPlainSQL(req, next) {
Expand All @@ -1062,7 +1070,7 @@ class HANAService extends SQLService {
throw err
}
}

const proc = this._getProcedureNameAndSchema(req.query)
if (proc && proc.name) return this.onCall(req, proc.name, proc.schema)

Expand Down Expand Up @@ -1169,15 +1177,14 @@ class HANAService extends SQLService {
}

async _getProcedureMetadata(name, schema) {
const query = `SELECT PARAMETER_NAME FROM SYS.PROCEDURE_PARAMETERS WHERE SCHEMA_NAME = ${
schema?.toUpperCase?.() === 'SYS' ? `'SYS'` : 'CURRENT_SCHEMA'
const query = `SELECT PARAMETER_NAME FROM SYS.PROCEDURE_PARAMETERS WHERE SCHEMA_NAME = ${schema?.toUpperCase?.() === 'SYS' ? `'SYS'` : 'CURRENT_SCHEMA'
} AND PROCEDURE_NAME = '${name}' AND PARAMETER_TYPE IN ('OUT', 'INOUT') ORDER BY POSITION`
return await super.onPlainSQL({ query, data: [] })
return await super.onPlainSQL({ query, data: [] })
}

_getProcedureNameAndSchema(sql) {
// name delimited with "" allows any character
const match = sql
const match = sql
.match(
/^\s*call \s*(("(?<schema_delimited>\w+)"\.)?("(?<delimited>.+)")|(?<schema_undelimited>\w+\.)?(?<undelimited>\w+))\s*\(/i
)
Expand Down
49 changes: 39 additions & 10 deletions hana/lib/drivers/base.js
Original file line number Diff line number Diff line change
Expand Up @@ -126,17 +126,46 @@ 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],
}

// Consider that '-' is only allowed as timezone after ':' or 'T'
await prom(this._native, 'exec')(`
CREATE OR REPLACE FUNCTION ISO(RAW NVARCHAR(36))
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I have moved the function to the plugin now for hdi artifacts. I think we should enrich the compile.to.sql commands for our tests that are used under the hood. the function creation should rather be part of deployment.

I was also wondering whether we should add a prefix to ensure uniqueness also for the future.

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;
`)
}

/**
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