diff --git a/packages/cubejs-schema-compiler/src/adapter/BaseQuery.js b/packages/cubejs-schema-compiler/src/adapter/BaseQuery.js index 53b3295d798c3..c47b0cee83fec 100644 --- a/packages/cubejs-schema-compiler/src/adapter/BaseQuery.js +++ b/packages/cubejs-schema-compiler/src/adapter/BaseQuery.js @@ -1380,8 +1380,8 @@ export class BaseQuery { const join = R.drop(1, toJoin) .map( (q, i) => (this.dimensionAliasNames().length ? - `INNER JOIN ${this.wrapInParenthesis((q))} as q_${i + 1} ON ${this.dimensionsJoinCondition(`q_${i}`, `q_${i + 1}`)}` : - `, ${this.wrapInParenthesis(q)} as q_${i + 1}`), + `INNER JOIN ${this.wrapInParenthesis((q))} ${this.asSyntaxJoin} q_${i + 1} ON ${this.dimensionsJoinCondition(`q_${i}`, `q_${i + 1}`)}` : + `, ${this.wrapInParenthesis(q)} ${this.asSyntaxJoin} q_${i + 1}`), ).join('\n'); const columnsToSelect = this.evaluateSymbolSqlWithContext( @@ -1410,7 +1410,7 @@ export class BaseQuery { return `${toJoin[0].replace(/^SELECT/, `SELECT ${this.topLimit()}`)} ${this.orderBy()}${this.groupByDimensionLimit()}`; } - return `SELECT ${this.topLimit()}${columnsToSelect} FROM ${this.wrapInParenthesis(toJoin[0])} as q_0 ${join}${havingFilters}${this.orderBy()}${this.groupByDimensionLimit()}`; + return `SELECT ${this.topLimit()}${columnsToSelect} FROM ${this.wrapInParenthesis(toJoin[0])} ${this.asSyntaxJoin} q_0 ${join}${havingFilters}${this.orderBy()}${this.groupByDimensionLimit()}`; } wrapInParenthesis(select) { diff --git a/packages/cubejs-schema-compiler/src/adapter/OracleQuery.ts b/packages/cubejs-schema-compiler/src/adapter/OracleQuery.ts index 46fdfaa0e7ed7..d0417847fe8f2 100644 --- a/packages/cubejs-schema-compiler/src/adapter/OracleQuery.ts +++ b/packages/cubejs-schema-compiler/src/adapter/OracleQuery.ts @@ -1,7 +1,8 @@ +import { parseSqlInterval } from '@cubejs-backend/shared'; import { BaseQuery } from './BaseQuery'; import { BaseFilter } from './BaseFilter'; import { UserError } from '../compiler/UserError'; -import { BaseDimension } from './BaseDimension'; +import type { BaseDimension } from './BaseDimension'; const GRANULARITY_VALUE = { day: 'DD', @@ -55,7 +56,11 @@ export class OracleQuery extends BaseQuery { * using forSelect dimensions for grouping */ public groupByClause() { - const dimensions = this.forSelect().filter((item: any) => !!item.dimension) as BaseDimension[]; + // Only include dimensions that have select columns + // Time dimensions without granularity return null from selectColumns() + const dimensions = this.forSelect().filter((item: any) => ( + !!item.dimension && item.selectColumns && item.selectColumns() + )) as BaseDimension[]; if (!dimensions.length) { return ''; } @@ -92,6 +97,88 @@ export class OracleQuery extends BaseQuery { return `TRUNC(${dimension}, '${GRANULARITY_VALUE[granularity]}')`; } + /** + * Oracle uses ADD_MONTHS for year/month/quarter intervals + * and NUMTODSINTERVAL for day/hour/minute/second intervals + */ + public addInterval(date: string, interval: string): string { + const intervalParsed = parseSqlInterval(interval); + let res = date; + + // Handle year/month/quarter using ADD_MONTHS + let totalMonths = 0; + if (intervalParsed.year) { + totalMonths += intervalParsed.year * 12; + } + if (intervalParsed.quarter) { + totalMonths += intervalParsed.quarter * 3; + } + if (intervalParsed.month) { + totalMonths += intervalParsed.month; + } + + if (totalMonths !== 0) { + res = `ADD_MONTHS(${res}, ${totalMonths})`; + } + + // Handle day/hour/minute/second using NUMTODSINTERVAL + if (intervalParsed.day) { + res = `${res} + NUMTODSINTERVAL(${intervalParsed.day}, 'DAY')`; + } + if (intervalParsed.hour) { + res = `${res} + NUMTODSINTERVAL(${intervalParsed.hour}, 'HOUR')`; + } + if (intervalParsed.minute) { + res = `${res} + NUMTODSINTERVAL(${intervalParsed.minute}, 'MINUTE')`; + } + if (intervalParsed.second) { + res = `${res} + NUMTODSINTERVAL(${intervalParsed.second}, 'SECOND')`; + } + + return res; + } + + /** + * Oracle subtraction uses ADD_MONTHS with negative values + * and subtracts NUMTODSINTERVAL for time units + */ + public subtractInterval(date: string, interval: string): string { + const intervalParsed = parseSqlInterval(interval); + let res = date; + + // Handle year/month/quarter using ADD_MONTHS with negative values + let totalMonths = 0; + if (intervalParsed.year) { + totalMonths += intervalParsed.year * 12; + } + if (intervalParsed.quarter) { + totalMonths += intervalParsed.quarter * 3; + } + if (intervalParsed.month) { + totalMonths += intervalParsed.month; + } + + if (totalMonths !== 0) { + res = `ADD_MONTHS(${res}, -${totalMonths})`; + } + + // Handle day/hour/minute/second using NUMTODSINTERVAL with subtraction + if (intervalParsed.day) { + res = `${res} - NUMTODSINTERVAL(${intervalParsed.day}, 'DAY')`; + } + if (intervalParsed.hour) { + res = `${res} - NUMTODSINTERVAL(${intervalParsed.hour}, 'HOUR')`; + } + if (intervalParsed.minute) { + res = `${res} - NUMTODSINTERVAL(${intervalParsed.minute}, 'MINUTE')`; + } + if (intervalParsed.second) { + res = `${res} - NUMTODSINTERVAL(${intervalParsed.second}, 'SECOND')`; + } + + return res; + } + public newFilter(filter) { return new OracleFilter(this, filter); } diff --git a/packages/cubejs-schema-compiler/test/unit/oracle-query.test.ts b/packages/cubejs-schema-compiler/test/unit/oracle-query.test.ts index c3680d796f384..307a5cc5400e5 100644 --- a/packages/cubejs-schema-compiler/test/unit/oracle-query.test.ts +++ b/packages/cubejs-schema-compiler/test/unit/oracle-query.test.ts @@ -1,3 +1,4 @@ +/* eslint-disable no-restricted-syntax */ import { OracleQuery } from '../../src/adapter/OracleQuery'; import { prepareJsCompiler } from './PrepareCompiler'; @@ -11,6 +12,31 @@ describe('OracleQuery', () => { measures: { count: { type: 'count' + }, + + unboundedCount: { + type: 'count', + rollingWindow: { + trailing: 'unbounded' + } + }, + + thisPeriod: { + sql: 'amount', + type: 'sum', + rollingWindow: { + trailing: '1 year', + offset: 'end' + } + }, + + priorPeriod: { + sql: 'amount', + type: 'sum', + rollingWindow: { + trailing: '1 year', + offset: 'start' + } } }, @@ -20,14 +46,784 @@ describe('OracleQuery', () => { type: 'number', primaryKey: true }, + createdAt: { type: 'time', sql: 'created_at' + }, + + source: { + type: 'string', + sql: 'source' } } }) + + cube(\`Deals\`, { + sql: \`select * from deals\`, + + measures: { + amount: { + sql: \`amount\`, + type: \`sum\` + } + }, + + dimensions: { + salesManagerId: { + sql: \`sales_manager_id\`, + type: 'string', + primaryKey: true + } + } + }) + + cube(\`SalesManagers\`, { + sql: \`select * from sales_managers\`, + + joins: { + Deals: { + relationship: \`hasMany\`, + sql: \`\${SalesManagers}.id = \${Deals}.sales_manager_id\` + } + }, + + measures: { + averageDealAmount: { + sql: \`\${dealsAmount}\`, + type: \`avg\` + } + }, + + dimensions: { + id: { + sql: \`id\`, + type: \`string\`, + primaryKey: true + }, + + dealsAmount: { + sql: \`\${Deals.amount}\`, + type: \`number\`, + subQuery: true + } + } + }); `, { adapter: 'oracle' }); + it('basic query without subqueries', async () => { + await compiler.compile(); + + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: [ + 'visitors.count' + ], + timeDimensions: [], + timezone: 'UTC' + }); + + const queryAndParams = query.buildSqlAndParams(); + const sql = queryAndParams[0]; + + // Basic query should work + expect(sql).toContain('SELECT'); + expect(sql).toMatch(/FROM\s+visitors/i); + // Should not have subquery aliases in simple query + expect(sql).not.toMatch(/\bq_\d+\b/); + // Should use Oracle FETCH NEXT + expect(sql).toContain('FETCH NEXT'); + }); + + it('does not use AS keyword in subquery aliases with single rolling window', async () => { + await compiler.compile(); + + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: [ + 'visitors.count', + 'visitors.unboundedCount' + ], + timeDimensions: [{ + dimension: 'visitors.createdAt', + granularity: 'day', + dateRange: ['2020-01-01', '2020-01-31'] + }], + timezone: 'UTC' + }); + + const queryAndParams = query.buildSqlAndParams(); + const sql = queryAndParams[0]; + + // Oracle should NOT have AS keyword before subquery aliases + expect(sql).not.toMatch(/\bAS\s+q_\d+/i); + expect(sql).not.toMatch(/\bas\s+q_\d+/); + + // Should have q_0 alias (with space around it, indicating no AS) + expect(sql).toMatch(/\)\s+q_0\s+/); + }); + + it('does not use AS keyword with multiple rolling window measures (YoY scenario)', async () => { + await compiler.compile(); + + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: [ + 'visitors.thisPeriod', + 'visitors.priorPeriod' + ], + timeDimensions: [{ + dimension: 'visitors.createdAt', + granularity: 'year', + dateRange: ['2020-01-01', '2022-12-31'] + }], + timezone: 'UTC' + }); + + const queryAndParams = query.buildSqlAndParams(); + const sql = queryAndParams[0]; + + // Should have multiple subquery aliases (q_0, q_1, q_2, etc.) + expect(sql).toMatch(/\bq_0\b/); + expect(sql).toMatch(/\bq_1\b/); + + // Oracle should NOT have AS keyword anywhere before q_ aliases + expect(sql).not.toMatch(/\bAS\s+q_\d+/i); + expect(sql).not.toMatch(/\bas\s+q_\d+/); + + // Verify pattern is ) q_X not ) AS q_X + expect(sql).toMatch(/\)\s+q_\d+/); + }); + + it('does not use AS keyword in INNER JOIN subqueries', async () => { + await compiler.compile(); + + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + dimensions: [ + 'SalesManagers.id', + 'SalesManagers.dealsAmount' + ] + }); + + const queryAndParams = query.buildSqlAndParams(); + const sql = queryAndParams[0]; + + // Should have INNER JOIN for subquery dimension + if (sql.includes('INNER JOIN')) { + // Oracle should NOT have AS keyword in INNER JOIN + expect(sql).not.toMatch(/INNER\s+JOIN\s+\([^)]+\)\s+AS\s+/i); + expect(sql).not.toMatch(/INNER\s+JOIN\s+\([^)]+\)\s+as\s+/); + } + }); + + it('uses FETCH NEXT syntax instead of LIMIT', async () => { + await compiler.compile(); + + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: [ + 'visitors.count' + ], + timezone: 'UTC', + limit: 100 + }); + + const queryAndParams = query.buildSqlAndParams(); + const sql = queryAndParams[0]; + + // Oracle should use FETCH NEXT instead of LIMIT + expect(sql).toContain('FETCH NEXT'); + expect(sql).toContain('ROWS ONLY'); + expect(sql).not.toContain('LIMIT'); + }); + + it('uses FETCH NEXT syntax with subqueries and rolling windows', async () => { + await compiler.compile(); + + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: [ + 'visitors.thisPeriod', + 'visitors.priorPeriod' + ], + timeDimensions: [{ + dimension: 'visitors.createdAt', + granularity: 'month', + dateRange: ['2020-01-01', '2020-12-31'] + }], + timezone: 'UTC', + limit: 50 + }); + + const queryAndParams = query.buildSqlAndParams(); + const sql = queryAndParams[0]; + + // Should have subqueries without AS + expect(sql).not.toMatch(/\bAS\s+q_\d+/i); + + // Should use Oracle-specific FETCH NEXT + expect(sql).toContain('FETCH NEXT'); + expect(sql).toContain('ROWS ONLY'); + expect(sql).not.toContain('LIMIT'); + }); + + it('does not use AS keyword with comma-separated subqueries', async () => { + await compiler.compile(); + + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: [ + 'visitors.thisPeriod', + 'visitors.priorPeriod' + ], + timezone: 'UTC' + }); + + const queryAndParams = query.buildSqlAndParams(); + const sql = queryAndParams[0]; + + // Should have multiple subquery aliases + expect(sql).toMatch(/\)\s+q_0\s+,/); + expect(sql).toMatch(/\)\s+q_1\s+/); + + // Should NOT have AS before q_ aliases + expect(sql).not.toMatch(/\bAS\s+q_\d+/i); + expect(sql).not.toMatch(/\bas\s+q_\d+/); + }); + + it('group by dimensions not indexes', async () => { + await compiler.compile(); + + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: [ + 'visitors.count' + ], + dimensions: [ + 'visitors.source' + ], + timezone: 'UTC' + }); + + const queryAndParams = query.buildSqlAndParams(); + const sql = queryAndParams[0]; + + // Oracle should group by actual dimension SQL, not by index + expect(sql).toMatch(/GROUP BY.*"visitors"\.source/i); + expect(sql).not.toMatch(/GROUP BY\s+\d+/); + }); + + it('handles time dimension without granularity in filter', async () => { + await compiler.compile(); + + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: [ + 'visitors.count' + ], + timeDimensions: [{ + dimension: 'visitors.createdAt', + dateRange: ['2020-01-01', '2020-12-31'] + // No granularity specified - used only for filtering + }], + timezone: 'UTC' + }); + + const queryAndParams = query.buildSqlAndParams(); + const sql = queryAndParams[0]; + + // Time dimensions without granularity should not appear in GROUP BY + expect(sql).not.toMatch(/GROUP BY.*created_at/i); + }); + + it('handles time dimension with granularity in SELECT and GROUP BY', async () => { + await compiler.compile(); + + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: [ + 'visitors.count' + ], + timeDimensions: [{ + dimension: 'visitors.createdAt', + granularity: 'day', + dateRange: ['2020-01-01', '2020-12-31'] + }], + timezone: 'UTC' + }); + + const queryAndParams = query.buildSqlAndParams(); + const sql = queryAndParams[0]; + + // Time dimension with granularity should appear in SELECT with TRUNC + expect(sql).toMatch(/TRUNC\(.*created_at/i); + + // Time dimension with granularity should appear in GROUP BY + expect(sql).toMatch(/GROUP BY.*created_at/i); + + // Should still have WHERE clause for filtering + expect(sql).toMatch(/WHERE/i); + }); + + it('uses Oracle-specific interval arithmetic', async () => { + await compiler.compile(); + + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: [ + 'visitors.thisPeriod', + 'visitors.priorPeriod' + ], + timeDimensions: [{ + dimension: 'visitors.createdAt', + granularity: 'year', + dateRange: ['2020-01-01', '2022-12-31'] + }], + timezone: 'UTC' + }); + + const queryAndParams = query.buildSqlAndParams(); + const sql = queryAndParams[0]; + + // Key test: Oracle uses ADD_MONTHS, not PostgreSQL interval syntax + expect(sql).toMatch(/ADD_MONTHS/i); + expect(sql).not.toMatch(/interval '1 year'/i); + }); + + describe('addInterval', () => { + it('adds year interval using ADD_MONTHS', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '1 year'); + expect(result).toBe('ADD_MONTHS(my_date, 12)'); + }); + + it('adds multiple years using ADD_MONTHS', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '3 year'); + expect(result).toBe('ADD_MONTHS(my_date, 36)'); + }); + + it('adds month interval using ADD_MONTHS', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '1 month'); + expect(result).toBe('ADD_MONTHS(my_date, 1)'); + }); + + it('adds multiple months using ADD_MONTHS', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '6 month'); + expect(result).toBe('ADD_MONTHS(my_date, 6)'); + }); + + it('adds quarter interval using ADD_MONTHS', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '1 quarter'); + expect(result).toBe('ADD_MONTHS(my_date, 3)'); + }); + + it('adds multiple quarters using ADD_MONTHS', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '4 quarter'); + expect(result).toBe('ADD_MONTHS(my_date, 12)'); + }); + + it('adds day interval using NUMTODSINTERVAL', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '1 day'); + expect(result).toBe('my_date + NUMTODSINTERVAL(1, \'DAY\')'); + }); + + it('adds multiple days using NUMTODSINTERVAL', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '7 day'); + expect(result).toBe('my_date + NUMTODSINTERVAL(7, \'DAY\')'); + }); + + it('adds hour interval using NUMTODSINTERVAL', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '1 hour'); + expect(result).toBe('my_date + NUMTODSINTERVAL(1, \'HOUR\')'); + }); + + it('adds multiple hours using NUMTODSINTERVAL', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '24 hour'); + expect(result).toBe('my_date + NUMTODSINTERVAL(24, \'HOUR\')'); + }); + + it('adds minute interval using NUMTODSINTERVAL', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '1 minute'); + expect(result).toBe('my_date + NUMTODSINTERVAL(1, \'MINUTE\')'); + }); + + it('adds multiple minutes using NUMTODSINTERVAL', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '30 minute'); + expect(result).toBe('my_date + NUMTODSINTERVAL(30, \'MINUTE\')'); + }); + + it('adds second interval using NUMTODSINTERVAL', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '1 second'); + expect(result).toBe('my_date + NUMTODSINTERVAL(1, \'SECOND\')'); + }); + + it('adds multiple seconds using NUMTODSINTERVAL', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '45 second'); + expect(result).toBe('my_date + NUMTODSINTERVAL(45, \'SECOND\')'); + }); + + it('combines year and month into single ADD_MONTHS', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '1 year 6 month'); + expect(result).toBe('ADD_MONTHS(my_date, 18)'); + }); + + it('combines quarter and month into single ADD_MONTHS', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '2 quarter 3 month'); + expect(result).toBe('ADD_MONTHS(my_date, 9)'); + }); + + it('combines year, quarter, and month into single ADD_MONTHS', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '2 year 1 quarter 2 month'); + expect(result).toBe('ADD_MONTHS(my_date, 29)'); + }); + + it('combines day and hour intervals', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '1 day 2 hour'); + expect(result).toBe('my_date + NUMTODSINTERVAL(1, \'DAY\') + NUMTODSINTERVAL(2, \'HOUR\')'); + }); + + it('combines hour, minute, and second intervals', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '1 hour 30 minute 45 second'); + expect(result).toBe('my_date + NUMTODSINTERVAL(1, \'HOUR\') + NUMTODSINTERVAL(30, \'MINUTE\') + NUMTODSINTERVAL(45, \'SECOND\')'); + }); + + it('combines month-based and day-based intervals', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '1 year 2 day 3 hour'); + expect(result).toBe('ADD_MONTHS(my_date, 12) + NUMTODSINTERVAL(2, \'DAY\') + NUMTODSINTERVAL(3, \'HOUR\')'); + }); + + it('combines all interval types', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('my_date', '1 year 2 quarter 3 month 4 day 5 hour 6 minute 7 second'); + expect(result).toBe('ADD_MONTHS(my_date, 21) + NUMTODSINTERVAL(4, \'DAY\') + NUMTODSINTERVAL(5, \'HOUR\') + NUMTODSINTERVAL(6, \'MINUTE\') + NUMTODSINTERVAL(7, \'SECOND\')'); + }); + + it('handles complex date expressions', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.addInterval('TRUNC(my_date)', '1 month'); + expect(result).toBe('ADD_MONTHS(TRUNC(my_date), 1)'); + }); + }); + + describe('subtractInterval', () => { + it('subtracts year interval using ADD_MONTHS with negative value', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '1 year'); + expect(result).toBe('ADD_MONTHS(my_date, -12)'); + }); + + it('subtracts multiple years using ADD_MONTHS with negative value', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '3 year'); + expect(result).toBe('ADD_MONTHS(my_date, -36)'); + }); + + it('subtracts month interval using ADD_MONTHS with negative value', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '1 month'); + expect(result).toBe('ADD_MONTHS(my_date, -1)'); + }); + + it('subtracts multiple months using ADD_MONTHS with negative value', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '6 month'); + expect(result).toBe('ADD_MONTHS(my_date, -6)'); + }); + + it('subtracts quarter interval using ADD_MONTHS with negative value', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '1 quarter'); + expect(result).toBe('ADD_MONTHS(my_date, -3)'); + }); + + it('subtracts multiple quarters using ADD_MONTHS with negative value', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '4 quarter'); + expect(result).toBe('ADD_MONTHS(my_date, -12)'); + }); + + it('subtracts day interval using NUMTODSINTERVAL subtraction', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '1 day'); + expect(result).toBe('my_date - NUMTODSINTERVAL(1, \'DAY\')'); + }); + + it('subtracts multiple days using NUMTODSINTERVAL subtraction', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '7 day'); + expect(result).toBe('my_date - NUMTODSINTERVAL(7, \'DAY\')'); + }); + + it('subtracts hour interval using NUMTODSINTERVAL subtraction', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '1 hour'); + expect(result).toBe('my_date - NUMTODSINTERVAL(1, \'HOUR\')'); + }); + + it('subtracts multiple hours using NUMTODSINTERVAL subtraction', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '24 hour'); + expect(result).toBe('my_date - NUMTODSINTERVAL(24, \'HOUR\')'); + }); + + it('subtracts minute interval using NUMTODSINTERVAL subtraction', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '1 minute'); + expect(result).toBe('my_date - NUMTODSINTERVAL(1, \'MINUTE\')'); + }); + + it('subtracts multiple minutes using NUMTODSINTERVAL subtraction', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '30 minute'); + expect(result).toBe('my_date - NUMTODSINTERVAL(30, \'MINUTE\')'); + }); + + it('subtracts second interval using NUMTODSINTERVAL subtraction', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '1 second'); + expect(result).toBe('my_date - NUMTODSINTERVAL(1, \'SECOND\')'); + }); + + it('subtracts multiple seconds using NUMTODSINTERVAL subtraction', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '45 second'); + expect(result).toBe('my_date - NUMTODSINTERVAL(45, \'SECOND\')'); + }); + + it('combines year and month into single ADD_MONTHS with negative value', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '1 year 6 month'); + expect(result).toBe('ADD_MONTHS(my_date, -18)'); + }); + + it('combines quarter and month into single ADD_MONTHS with negative value', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '2 quarter 3 month'); + expect(result).toBe('ADD_MONTHS(my_date, -9)'); + }); + + it('combines year, quarter, and month into single ADD_MONTHS with negative value', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '2 year 1 quarter 2 month'); + expect(result).toBe('ADD_MONTHS(my_date, -29)'); + }); + + it('combines day and hour intervals with subtraction', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '1 day 2 hour'); + expect(result).toBe('my_date - NUMTODSINTERVAL(1, \'DAY\') - NUMTODSINTERVAL(2, \'HOUR\')'); + }); + + it('combines hour, minute, and second intervals with subtraction', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '1 hour 30 minute 45 second'); + expect(result).toBe('my_date - NUMTODSINTERVAL(1, \'HOUR\') - NUMTODSINTERVAL(30, \'MINUTE\') - NUMTODSINTERVAL(45, \'SECOND\')'); + }); + + it('combines month-based and day-based intervals with subtraction', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '1 year 2 day 3 hour'); + expect(result).toBe('ADD_MONTHS(my_date, -12) - NUMTODSINTERVAL(2, \'DAY\') - NUMTODSINTERVAL(3, \'HOUR\')'); + }); + + it('combines all interval types with subtraction', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('my_date', '1 year 2 quarter 3 month 4 day 5 hour 6 minute 7 second'); + expect(result).toBe('ADD_MONTHS(my_date, -21) - NUMTODSINTERVAL(4, \'DAY\') - NUMTODSINTERVAL(5, \'HOUR\') - NUMTODSINTERVAL(6, \'MINUTE\') - NUMTODSINTERVAL(7, \'SECOND\')'); + }); + + it('handles complex date expressions', async () => { + await compiler.compile(); + const query = new OracleQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: ['visitors.count'], + timezone: 'UTC' + }); + const result = query.subtractInterval('TRUNC(my_date)', '1 month'); + expect(result).toBe('ADD_MONTHS(TRUNC(my_date), -1)'); + }); + }); + it('generates TO_TIMESTAMP_TZ with millisecond precision for date range filters', async () => { await compiler.compile(); diff --git a/packages/cubejs-schema-compiler/test/unit/postgres-query.test.ts b/packages/cubejs-schema-compiler/test/unit/postgres-query.test.ts index b72c0b4d97311..f2a609b743781 100644 --- a/packages/cubejs-schema-compiler/test/unit/postgres-query.test.ts +++ b/packages/cubejs-schema-compiler/test/unit/postgres-query.test.ts @@ -328,4 +328,80 @@ describe('PostgresQuery', () => { expect(queryAndParams[0]).toContain('ORDER BY 3 ASC'); }); }); + + it('handles time dimension without granularity in filter', async () => { + await compiler.compile(); + + const query = new PostgresQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: [ + 'visitors.count' + ], + timeDimensions: [{ + dimension: 'visitors.createdAt', + dateRange: ['2020-01-01', '2020-12-31'] + // No granularity specified - used only for filtering + }], + timezone: 'UTC' + }); + + const queryAndParams = query.buildSqlAndParams(); + const sql = queryAndParams[0]; + + // Time dimensions without granularity should not appear in GROUP BY + expect(sql).not.toMatch(/GROUP BY.*created_at/i); + + // Time dimension should still be used in WHERE clause for filtering + expect(sql).toMatch(/WHERE/i); + }); + + it('handles time dimension with granularity in SELECT and GROUP BY', async () => { + await compiler.compile(); + + const query = new PostgresQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: [ + 'visitors.count' + ], + timeDimensions: [{ + dimension: 'visitors.createdAt', + granularity: 'day', + dateRange: ['2020-01-01', '2020-12-31'] + }], + timezone: 'UTC' + }); + + const queryAndParams = query.buildSqlAndParams(); + const sql = queryAndParams[0]; + + // Time dimension with granularity should appear in SELECT + expect(sql).toMatch(/date_trunc\('day',.*created_at/i); + + // Time dimension with granularity should appear in GROUP BY + expect(sql).toMatch(/GROUP BY/i); + + // Should still have WHERE clause for filtering + expect(sql).toMatch(/WHERE/i); + }); + + it('uses AS keyword in subquery aliases (regression test)', async () => { + await compiler.compile(); + + const query = new PostgresQuery({ joinGraph, cubeEvaluator, compiler }, { + measures: [ + 'visitors.count', + 'visitors.unboundedCount' + ], + timeDimensions: [{ + dimension: 'visitors.createdAt', + granularity: 'day', + dateRange: ['2020-01-01', '2020-01-31'] + }], + timezone: 'UTC' + }); + + const queryAndParams = query.buildSqlAndParams(); + const sql = queryAndParams[0]; + + // PostgreSQL should use AS keyword for subquery aliases + expect(sql).toMatch(/\s+AS\s+q_0\s+/); + }); });