Skip to content

Commit f7c07a7

Browse files
authored
feat(schema-compiler): Support date_bin function in Cube Store queries (#8684)
* feat(schema-compiler): implement dateBin() in CubeStoreQuery * Add tests for dateBin in CubeStoreQuery * add e2e tests for custom granularities with preaggregations * Remove console.log
1 parent 678a13a commit f7c07a7

File tree

4 files changed

+147
-10
lines changed

4 files changed

+147
-10
lines changed

packages/cubejs-schema-compiler/src/adapter/CubeStoreQuery.ts

Lines changed: 66 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,5 @@
11
import moment from 'moment-timezone';
2+
import { parseSqlInterval } from '@cubejs-backend/shared';
23
import { BaseQuery } from './BaseQuery';
34
import { BaseFilter } from './BaseFilter';
45
import { BaseMeasure } from './BaseMeasure';
@@ -42,7 +43,7 @@ export class CubeStoreQuery extends BaseQuery {
4243
}
4344

4445
public timeStampCast(value) {
45-
return `CAST(${value} as TIMESTAMP)`; // TODO
46+
return `CAST(${value} as TIMESTAMP)`;
4647
}
4748

4849
public timestampFormat() {
@@ -53,18 +54,77 @@ export class CubeStoreQuery extends BaseQuery {
5354
return `to_timestamp(${value})`;
5455
}
5556

56-
public subtractInterval(date, interval) {
57-
return `DATE_SUB(${date}, INTERVAL '${interval}')`;
57+
public subtractInterval(date: string, interval: string) {
58+
return `DATE_SUB(${date}, INTERVAL ${this.formatInterval(interval)})`;
5859
}
5960

60-
public addInterval(date, interval) {
61-
return `DATE_ADD(${date}, INTERVAL '${interval}')`;
61+
public addInterval(date: string, interval: string) {
62+
return `DATE_ADD(${date}, INTERVAL ${this.formatInterval(interval)})`;
6263
}
6364

64-
public timeGroupedColumn(granularity, dimension) {
65+
public timeGroupedColumn(granularity: string, dimension: string) {
6566
return `date_trunc('${GRANULARITY_TO_INTERVAL[granularity]}', ${dimension})`;
6667
}
6768

69+
/**
70+
* Returns sql for source expression floored to timestamps aligned with
71+
* intervals relative to origin timestamp point.
72+
*/
73+
public dateBin(interval: string, source: string, origin: string): string {
74+
return `DATE_BIN(INTERVAL ${this.formatInterval(interval)}, ${this.timeStampCast(source)}, ${this.timeStampCast(`'${origin}'`)})`;
75+
}
76+
77+
/**
78+
* The input interval with (possible) plural units, like "2 years", "3 months", "4 weeks", "5 days"...
79+
* will be converted to CubeStore (DataFusion) dialect.
80+
*/
81+
private formatInterval(interval: string): string {
82+
const intervalParsed = parseSqlInterval(interval);
83+
const intKeys = Object.keys(intervalParsed).length;
84+
85+
if (intervalParsed.year && intKeys === 1) {
86+
return `'${intervalParsed.year} YEAR'`;
87+
} else if (intervalParsed.year && intervalParsed.month && intKeys === 2) {
88+
return `'${intervalParsed.year} YEAR ${intervalParsed.month} MONTH'`;
89+
} else if (intervalParsed.year && intervalParsed.month && intervalParsed.quarter && intKeys === 3) {
90+
return `'${intervalParsed.year} YEAR ${intervalParsed.quarter} QUARTER ${intervalParsed.month} MONTH'`;
91+
} else if (intervalParsed.quarter && intKeys === 1) {
92+
return `'${intervalParsed.quarter} QUARTER'`;
93+
} else if (intervalParsed.quarter && intervalParsed.month && intKeys === 2) {
94+
return `'${intervalParsed.quarter} QUARTER ${intervalParsed.month} MONTH'`;
95+
} else if (intervalParsed.month && intKeys === 1) {
96+
return `'${intervalParsed.month} MONTH'`;
97+
} else if (intervalParsed.week && intKeys === 1) {
98+
return `'${intervalParsed.week} WEEK'`;
99+
} else if (intervalParsed.week && intervalParsed.day && intKeys === 2) {
100+
return `'${intervalParsed.week} WEEK ${intervalParsed.day} DAY'`;
101+
} else if (intervalParsed.week && intervalParsed.day && intervalParsed.hour && intKeys === 3) {
102+
return `'${intervalParsed.week} WEEK ${intervalParsed.day} DAY ${intervalParsed.hour} HOUR'`;
103+
} else if (intervalParsed.week && intervalParsed.day && intervalParsed.hour && intervalParsed.minute && intKeys === 4) {
104+
return `'${intervalParsed.week} WEEK ${intervalParsed.day} DAY ${intervalParsed.hour} HOUR ${intervalParsed.minute} MINUTE'`;
105+
} else if (intervalParsed.week && intervalParsed.day && intervalParsed.hour && intervalParsed.minute && intervalParsed.second && intKeys === 5) {
106+
return `'${intervalParsed.week} WEEK ${intervalParsed.day} DAY ${intervalParsed.hour} HOUR ${intervalParsed.minute} MINUTE ${intervalParsed.second} SECOND'`;
107+
} else if (intervalParsed.day && intKeys === 1) {
108+
return `'${intervalParsed.day} DAY'`;
109+
} else if (intervalParsed.day && intervalParsed.hour && intKeys === 2) {
110+
return `'${intervalParsed.day} DAY ${intervalParsed.hour} HOUR'`;
111+
} else if (intervalParsed.day && intervalParsed.hour && intervalParsed.minute && intKeys === 3) {
112+
return `'${intervalParsed.day} DAY ${intervalParsed.hour} HOUR ${intervalParsed.minute} MINUTE'`;
113+
} else if (intervalParsed.day && intervalParsed.hour && intervalParsed.minute && intervalParsed.second && intKeys === 4) {
114+
return `'${intervalParsed.day} DAY ${intervalParsed.hour} HOUR ${intervalParsed.minute} MINUTE ${intervalParsed.second} SECOND'`;
115+
} else if (intervalParsed.hour && intervalParsed.minute && intKeys === 2) {
116+
return `'${intervalParsed.hour} HOUR ${intervalParsed.minute} MINUTE'`;
117+
} else if (intervalParsed.hour && intervalParsed.minute && intervalParsed.second && intKeys === 3) {
118+
return `'${intervalParsed.hour} HOUR ${intervalParsed.minute} MINUTE ${intervalParsed.second} SECOND'`;
119+
} else if (intervalParsed.minute && intervalParsed.second && intKeys === 2) {
120+
return `'${intervalParsed.minute} MINUTE ${intervalParsed.second} SECOND'`;
121+
}
122+
123+
// No need to support microseconds.
124+
125+
throw new Error(`Cannot transform interval expression "${interval}" to CubeStore dialect`);
126+
}
127+
68128
public escapeColumnName(name) {
69129
return `\`${name}\``;
70130
}

packages/cubejs-schema-compiler/test/unit/base-query.test.ts

Lines changed: 26 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,5 @@
11
import moment from 'moment-timezone';
2-
import { BaseQuery, PostgresQuery, MssqlQuery, UserError } from '../../src';
2+
import { BaseQuery, PostgresQuery, MssqlQuery, UserError, CubeStoreQuery } from '../../src';
33
import { prepareCompiler, prepareYamlCompiler } from './PrepareCompiler';
44
import {
55
createCubeSchema,
@@ -295,7 +295,6 @@ describe('SQL Generation', () => {
295295
const query = new PostgresQuery(compilers, q);
296296
const queryAndParams = query.buildSqlAndParams();
297297
const queryString = queryAndParams[0];
298-
console.log('Generated query: ', queryString);
299298

300299
if (q.measures[0].includes('count')) {
301300
expect(queryString.includes('INTERVAL \'6 months\'')).toBeTruthy();
@@ -307,6 +306,31 @@ describe('SQL Generation', () => {
307306
});
308307
});
309308
});
309+
310+
describe('via CubeStoreQuery', () => {
311+
beforeAll(async () => {
312+
await compilers.compiler.compile();
313+
});
314+
315+
queries.forEach(q => {
316+
it(`measure "${q.measures[0]}" + granularity "${q.timeDimensions[0].granularity}"`, () => {
317+
const query = new CubeStoreQuery(compilers, q);
318+
const queryAndParams = query.buildSqlAndParams();
319+
const queryString = queryAndParams[0];
320+
321+
if (q.measures[0].includes('count')) {
322+
expect(queryString.includes('DATE_BIN(INTERVAL')).toBeTruthy();
323+
expect(queryString.includes('INTERVAL \'6 MONTH\'')).toBeTruthy();
324+
} else if (q.measures[0].includes('rollingCountByTrailing2Day')) {
325+
expect(queryString.includes('date_trunc(\'day\'')).toBeTruthy();
326+
expect(queryString.includes('INTERVAL \'2 DAY\'')).toBeTruthy();
327+
} else if (q.measures[0].includes('rollingCountByLeading2Day')) {
328+
expect(queryString.includes('date_trunc(\'day\'')).toBeTruthy();
329+
expect(queryString.includes('INTERVAL \'3 DAY\'')).toBeTruthy();
330+
}
331+
});
332+
});
333+
});
310334
});
311335

312336
describe('Common - JS', () => {
@@ -1141,7 +1165,6 @@ describe('SQL Generation', () => {
11411165
],
11421166
});
11431167
const cubeSQL = query.cubeSql('Order');
1144-
console.log('TEST: ', cubeSQL);
11451168
expect(cubeSQL).toContain('select * from order where ((type = $0$))');
11461169
});
11471170
});

packages/cubejs-testing-drivers/fixtures/_schemas.json

Lines changed: 22 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -88,7 +88,28 @@
8888
{
8989
"name": "orderDate",
9090
"sql": "order_date",
91-
"type": "time"
91+
"type": "time",
92+
"granularities": [
93+
{
94+
"name": "half_year",
95+
"interval": "6 months"
96+
},
97+
{
98+
"name": "half_year_by_1st_april",
99+
"interval": "6 months",
100+
"offset": "3 months"
101+
},
102+
{
103+
"name": "two_mo_by_feb",
104+
"interval": "2 months",
105+
"origin": "2020-02-01 00:00:00"
106+
},
107+
{
108+
"name": "three_months_by_march",
109+
"interval": "3 month 3 days 3 hours",
110+
"origin": "2020-03-15"
111+
}
112+
]
92113
},
93114
{
94115
"name": "customOrderDateNoPreAgg",

packages/cubejs-testing-drivers/src/tests/testQueries.ts

Lines changed: 33 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1750,6 +1750,39 @@ export function testQueries(type: string, { includeIncrementalSchemaSuite, exten
17501750
expect(response.rawData()).toMatchSnapshot();
17511751
});
17521752

1753+
execute('querying custom granularities (with preaggregation) ECommerce: totalQuantity by half_year + no dimension', async () => {
1754+
const response = await client.load({
1755+
measures: [
1756+
'ECommerce.totalQuantity',
1757+
],
1758+
timeDimensions: [{
1759+
dimension: 'ECommerce.orderDate',
1760+
granularity: 'half_year',
1761+
dateRange: ['2020-01-01', '2020-12-31'],
1762+
}],
1763+
});
1764+
expect(response.rawData()).toMatchSnapshot();
1765+
});
1766+
1767+
execute('querying custom granularities (with preaggregation) ECommerce: totalQuantity by half_year + dimension', async () => {
1768+
const response = await client.load({
1769+
measures: [
1770+
'ECommerce.totalQuantity',
1771+
],
1772+
timeDimensions: [{
1773+
dimension: 'ECommerce.orderDate',
1774+
granularity: 'half_year',
1775+
dateRange: ['2020-01-01', '2020-12-31'],
1776+
}],
1777+
dimensions: ['ECommerce.productName'],
1778+
order: [
1779+
['ECommerce.orderDate', 'asc'],
1780+
['ECommerce.productName', 'asc']
1781+
],
1782+
});
1783+
expect(response.rawData()).toMatchSnapshot();
1784+
});
1785+
17531786
if (includeIncrementalSchemaSuite) {
17541787
incrementalSchemaLoadingSuite(execute, () => driver, tables);
17551788
}

0 commit comments

Comments
 (0)