Skip to content

Commit

Permalink
feat: Odata built-in query functions (#558)
Browse files Browse the repository at this point in the history
- added tests for all built-in query functions
- added functions: `totaloffsetminutes` (should be fixed in `cds` as well), `now`, `second`, `fractionalseconds`, `maxdatetime`, `mindatetime`, `date`, `time`

---------

Co-authored-by: D070615 <[email protected]>
  • Loading branch information
etimr and OlenaTi authored Apr 10, 2024
1 parent 37a7a0d commit 6e63367
Show file tree
Hide file tree
Showing 5 changed files with 140 additions and 33 deletions.
21 changes: 14 additions & 7 deletions db-service/lib/cql-functions.js
Original file line number Diff line number Diff line change
Expand Up @@ -152,6 +152,13 @@ const StandardFunctions = {
current_time: p => (p ? `current_time(${p})` : 'current_time'),
current_timestamp: p => (p ? `current_timestamp(${p})` : 'current_timestamp'),

/**
* Generates SQL statement that produces current point in time (date and time with time zone)
* @returns {string}
*/
now: function() {
return this.session_context({val: '$now'})
},
/**
* Generates SQL statement that produces the year of a given timestamp
* @param {string} x
Expand Down Expand Up @@ -189,37 +196,37 @@ const StandardFunctions = {
* /
second: x => `cast( strftime('%S',${x}) as Integer )`,
// REVISIT: make precision configurable
/**
* Generates SQL statement that produces the fractional seconds of a given timestamp
* @param {string} x
* @returns {string}
*/
fractionalseconds: x => `cast( strftime('%f0000',${x}) as Integer )`,
fractionalseconds: x => `cast( substr( strftime('%f', ${x}), length(strftime('%f', ${x})) - 3) as REAL)`,

/**
* maximum date time value
* @returns {string}
*/
maxdatetime: () => '9999-12-31 23:59:59.999',
maxdatetime: () => "'9999-12-31T23:59:59.999Z'",
/**
* minimum date time value
* @returns {string}
*/
mindatetime: () => '0001-01-01 00:00:00.000',
mindatetime: () => "'0001-01-01T00:00:00.000Z'",

// odata spec defines the date time offset type as a normal ISO time stamp
// Where the timezone can either be 'Z' (for UTC) or [+|-]xx:xx for the time offset
// sqlite understands this so by splitting the timezone from the actual date
// prefixing it with 1970 it allows sqlite to give back the number of seconds
// which can be divided by 60 back to minutes
/**
* Generates SQL statement that produces the offset in minutes of a given date time offset string
* @param {string} x
* @returns {string}
*/
totaloffsetminutes: x => `case
when substr(${x}, length(${x})) = 'z' then 0
else strftime('%s', '1970-01-01T00:00:00' || substr(${x}, length(${x}) - 5)) / 60
else sign( cast( substr(${x}, length(${x}) - 5) as Integer )) *
( cast( strftime('%H', substr(${x}, length(${x}) - 4 )) as Integer ) * 60 +
cast( strftime('%M', substr(${x},length(${x}) - 4 )) as Integer ))
end`,

// odata spec defines the value format for totalseconds as a duration like: P12DT23H59M59.999999999999S
Expand Down
8 changes: 7 additions & 1 deletion hana/lib/cql-functions.js
Original file line number Diff line number Diff line change
Expand Up @@ -34,7 +34,13 @@ const StandardFunctions = {
day: x => `DAYOFMONTH(${x})`,
hour: x => `HOUR(${getTimeCast(x)})`,
minute: x => `MINUTE(${getTimeCast(x)})`,
second: x => `SECOND(${getTimeCast(x)})`
second: x => `TO_INTEGER(SECOND(${getTimeCast(x)}))`,
date: x => `TO_DATE(${x})`,
time: x => `TO_TIME(${x})`,
maxdatetime: () => "'9999-12-31T23:59:59.999Z'",
mindatetime: () => "'0001-01-01T00:00:00.000Z'",
now: () => `session_context('$now')`,
fractionalseconds: x => `(TO_DECIMAL(SECOND(${x}),5,3) - TO_INTEGER(SECOND(${x})))`
}

module.exports = StandardFunctions
7 changes: 6 additions & 1 deletion postgres/lib/func.js
Original file line number Diff line number Diff line change
Expand Up @@ -18,9 +18,14 @@ const StandardFunctions = {
year: x => `date_part('year', ${castVal(x)})`,
month: x => `date_part('month', ${castVal(x)})`,
day: x => `date_part('day', ${castVal(x)})`,
time: x => `to_char(${castVal(x)}, 'HH24:MI:SS')`,
hour: x => `date_part('hour', ${castVal(x)})`,
minute: x => `date_part('minute', ${castVal(x)})`,
second: x => `date_part('second', ${castVal(x)})`,
second: x => `floor(date_part('second', ${castVal(x)}))`,
fractionalseconds: x => `CAST(date_part('second', ${castVal(x)}) - floor(date_part('second', ${castVal(x)})) AS DECIMAL)`,
now: function() {
return this.session_context({val: '$now'})
}
}

const isTime = /^\d{1,2}:\d{1,2}:\d{1,2}$/
Expand Down
128 changes: 104 additions & 24 deletions test/scenarios/bookshop/funcs.test.js
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
const cds = require('../../cds.js')
const bookshop = require('path').resolve(__dirname, '../../bookshop')
cds.env.features.odata_new_adapter = true

describe('Bookshop - Functions', () => {
const { expect, GET } = cds.test(bookshop)
Expand Down Expand Up @@ -135,8 +136,26 @@ describe('Bookshop - Functions', () => {
})

describe('Collection Functions', () => {
test.skip('hassubset', () => { })
test.skip('hassubsequence', () => { })
test.skip('hassubset', async () => {
// okra error: 400 - Property 'hassubset' does not exist in type 'CatalogService.Books'
// new adapter error: 400 - Function 'hassubset' is not supported
const { Books } = cds.entities('sap.capire.bookshop')
await cds.run(INSERT.into(Books).columns(['ID', 'footnotes']).rows([123, ['1','2','3']]))
await cds.run(INSERT.into(Books).columns(['ID', 'footnotes']).rows([124, ['2','5','6']]))
const res = await GET(`/browse/Books?$filter=hassubset(footnotes, ['3','1'])`)
expect(res.status).to.be.eq(200)
expect(res.data.value.length).to.be.eq(1)
})
test.skip('hassubsequence', async () => {
// okra error: 400 - Property 'hassubset' does not exist in type 'CatalogService.Books'
// new adapter error: 400 - Function 'hassubsequence' is not supported
const { Books } = cds.entities('sap.capire.bookshop')
await cds.run(INSERT.into(Books).columns(['ID', 'footnotes']).rows([123, ['1','2','3']]))
await cds.run(INSERT.into(Books).columns(['ID', 'footnotes']).rows([124, ['2','5','6']]))
const res = await GET(`/browse/Books?$filter=hassubset(footnotes, ['1','3'])`)
expect(res.status).to.be.eq(200)
expect(res.data.value.length).to.be.eq(1)
})
})

describe('Arithmetic Functions', () => {
Expand Down Expand Up @@ -217,94 +236,133 @@ describe('Bookshop - Functions', () => {
})
})

// REVISIT: does not seem database relevant
test.skip('date', () => { })
test('date', async () => {
const res = await GET(`/browse/Books?$select=ID,createdAt&$filter=date(2023-03-29T15:44:58.999Z) eq 2023-03-29&$top=1`)

expect(res.status).to.be.eq(200)
expect(res.data.value.length).to.be.eq(1)
})

test('day', async () => {
const res = await GET(`/browse/Books?$select=ID&$filter=day(1970-01-31T00:00:00.000Z) eq 31&$top=1`)

expect(res.status).to.be.eq(200)
expect(res.data.value.length).to.be.eq(1)
})

test('date function with null value', async () => {
test('day function with null value', async () => {
const { result } = await SELECT.one(`day(null) as result`)
.from('sap.capire.bookshop.Books')

expect(result).to.be.null
})

test.skip('fractionalseconds', async () => {
// REVISIT: ERROR: Feature is not supported: Method "fractionalseconds" in $filter or $orderby query options
test('fractionalseconds', async () => {
// okra error: Feature is not supported: Method "fractionalseconds" in $filter or $orderby query options
const res = await GET(
`/browse/Books?$select=ID&$filter=fractionalseconds(1970-01-01T00:00:00.321Z) eq 321&$top=1`,
`/browse/Books?$select=ID&$filter=fractionalseconds(1970-01-01T00:00:01.321Z) eq 0.321&$top=1`,
)

expect(res.status).to.be.eq(200)
expect(res.data.value.length).to.be.eq(1)
})

test('hour', async () => {
const res = await GET(`/browse/Books?$select=ID&$filter=hour(1970-01-01T07:00:00.000Z) eq 7&$top=1`)

expect(res.status).to.be.eq(200)
expect(res.data.value.length).to.be.eq(1)
})
test.skip('maxdatetime', async () => {
// REVISIT: ERROR: Feature is not supported: Method "maxdatetime" in $filter or $orderby query options

test('maxdatetime', async () => {
// okra error: Feature is not supported: Method "maxdatetime" in $filter or $orderby query options
const res = await GET(`/browse/Books?$select=ID&$filter=maxdatetime() eq 9999-12-31T23:59:59.999Z&$top=1`)

expect(res.status).to.be.eq(200)
expect(res.data.value.length).to.be.eq(1)
})
test.skip('mindatetime', async () => {
// REVISIT: ERROR: Feature is not supported: Method "mindatetime" in $filter or $orderby query options

test('mindatetime', async () => {
// okra error: Feature is not supported: Method "mindatetime" in $filter or $orderby query options
const res = await GET(`/browse/Books?$select=ID&$filter=mindatetime() eq 0001-01-01T00:00:00.000Z&$top=1`)

expect(res.status).to.be.eq(200)
expect(res.data.value.length).to.be.eq(1)
})

test('minute', async () => {
const res = await GET(`/browse/Books?$select=ID&$filter=minute(1970-01-01T00:32:00.000Z) eq 32&$top=1`)
const res = await GET(`/browse/Books?$select=ID&$filter=minute(1970-01-01T00:32:10.000Z) eq 32&$top=1`)

expect(res.status).to.be.eq(200)
expect(res.data.value.length).to.be.eq(1)
})

test('month', async () => {
const res = await GET(`/browse/Books?$select=ID&$filter=month(1970-03-01T00:00:00.000Z) eq 3&$top=1`)

expect(res.status).to.be.eq(200)
expect(res.data.value.length).to.be.eq(1)
})

test('now', async () => {
// REVISIT: this test does not really proof much
const res = await GET(`/browse/Books?$select=ID&$filter=now() gt 1970-03-01T00:00:00.000Z&$top=1`)
const db = await cds.connect.to('db')
return db.run(async tx => {
Object.defineProperty(cds.context, 'timestamp', {value: new Date('1972-09-15T21:36:51.123Z')})
const cqn = {
SELECT: {
from: { ref: ['localized.CatalogService.Books'], as: 'Books' },
columns: [{ ref: ['Books', 'ID'] }],
where: [
{
func: 'now',
args: [],
},
'=',
{
val: '1972-09-15T21:36:51.123Z',
},
],
},
}
const res = await tx.run(cqn)
expect(res.length).to.be.eq(5)
})
})

test('second', async () => {
const res = await GET(`/browse/Books?$select=ID&$filter=second(1970-01-01T00:00:45.123Z) eq 45&$top=1`)

expect(res.status).to.be.eq(200)
expect(res.data.value.length).to.be.eq(1)
})
test('second', async () => {
const res = await GET(`/browse/Books?$select=ID&$filter=second(1970-01-01T00:00:45.000Z) eq 45&$top=1`)

test('time', async () => {
const res = await GET(`/browse/Books?$select=ID,createdAt&$filter=time(2023-03-29T15:44:58.999Z) eq 15:44:58&$top=1`)

expect(res.status).to.be.eq(200)
expect(res.data.value.length).to.be.eq(1)
})
// REVISIT: does not seem database relevant
test.skip('time', () => { })

test.skip('totaloffsetminutes', async () => {
// REVISIT: ERROR: Feature is not supported: Method "totaloffsetminutes" in $filter or $orderby query options
// okra error: Feature is not supported: Method "totaloffsetminutes" in $filter or $orderby query options
// new adapter: REVISIT: getting transformed date without timeoffset from service layer
const res = await GET(
`/browse/Books?$select=ID&$filter=totaloffsetminutes(2000-01-01T23:45:13+10:30) eq -630&$top=1`,
`/browse/Books?$select=ID&$filter=totaloffsetminutes('2000-01-01T23:45:13-10:30') eq -630&$top=1`,
)

expect(res.status).to.be.eq(200)
expect(res.data.value.length).to.be.eq(1)
})

test.skip('totalseconds', async () => {
// REVISIT: ERROR: Feature is not supported: Method "totalseconds" in $filter or $orderby query options
// okra error: Feature is not supported: Method "totalseconds" in $filter or $orderby query options
// new adapter error: 400 - Property 'duration' does not exist in 'CatalogService.Books'
const res = await GET(`/browse/Books?$select=ID&$filter=totalseconds(duration'P1DT06H32M45.000S') gt 0&$top=1`)

expect(res.status).to.be.eq(200)
expect(res.data.value.length).to.be.eq(1)
})

test('year', async () => {
const res = await GET(`/browse/Books?$select=ID&$filter=year(1971-01-01T00:00:00.000Z) eq 1971&$top=1`)

Expand All @@ -314,13 +372,35 @@ describe('Bookshop - Functions', () => {
})

describe('Type Functions', () => {
test.skip('cast', async () => {
// okra error: 501 - Feature is not supported: Expression "5" in $filter or $orderby query options
// new adapter error: 400 - Function 'cast' is not supported
const res = await GET(`/browse/Books?$filter=cast(price,Edm.Int32) eq 13`)

expect(res.status).to.be.eq(200)
expect(res.data.value.length).to.be.eq(1)
})
test.skip('isOf', async () => {
// REVISIT: ERROR: Feature is not supported: Expression "false" in $filter or $orderby query options
// ??? "false"
// okra error: Feature is not supported: Expression "false" in $filter or $orderby query options
// "false" comes from expression.getKind() in ExpressionToCQN.js
// new adapter error: 400 - Function 'isof' is not supported
const res = await GET(`/browse/Books?$filter=isof(createdAt,Edm.Date)`)

expect(res.status).to.be.eq(200)
expect(res.data.value.length).to.be.eq(1)
})
})

describe('Geo Functions', () => {
test.skip('geo.distance', async () => {
// okra error: 400 - Property 'geography' does not exist in type 'CatalogService.Books'
// new adapter error: 400 - Parsing URL failed at position 34: Expected "/" or a whitespace but "(" found.
const res = await GET(`/browse/Books?$filter=geo.distance(geography'POINT(-122.131577 47.678581)', geography'POINT(-122.374722,37.618888)') lt 900.0`)

expect(res.status).to.be.eq(200)
expect(res.data.value.length).to.be.eq(1)
})
test.skip('geo.intersects', () => { })
test.skip('geo.length', () => { })
})
})
9 changes: 9 additions & 0 deletions test/scenarios/bookshop/genres.test.js
Original file line number Diff line number Diff line change
Expand Up @@ -87,6 +87,15 @@ describe('Bookshop - Genres', () => {
res = await PUT(`/test/Genres(${body.ID})`, { name: 'no more children', children: [] }, admin)
expect(res.status).to.be.eq(200)
delete res.data['@odata.context']
// REVISIT children: null for odata_new_adapter
cds.env.features.odata_new_adapter ?
assert.deepEqual(res.data, {
name: 'no more children',
descr: null,
ID: 100,
parent_ID: null,
children: null, // all children have been removed
}) :
assert.deepEqual(res.data, {
name: 'no more children',
descr: null,
Expand Down

0 comments on commit 6e63367

Please sign in to comment.