|
| 1 | +import { parseSqlInterval } from '@cubejs-backend/shared'; |
1 | 2 | import { BaseQuery } from './BaseQuery'; |
2 | 3 | import { BaseFilter } from './BaseFilter'; |
3 | 4 | import { UserError } from '../compiler/UserError'; |
4 | | -import { BaseDimension } from './BaseDimension'; |
| 5 | +import type { BaseDimension } from './BaseDimension'; |
5 | 6 |
|
6 | 7 | const GRANULARITY_VALUE = { |
7 | 8 | day: 'DD', |
@@ -55,7 +56,11 @@ export class OracleQuery extends BaseQuery { |
55 | 56 | * using forSelect dimensions for grouping |
56 | 57 | */ |
57 | 58 | public groupByClause() { |
58 | | - const dimensions = this.forSelect().filter((item: any) => !!item.dimension) as BaseDimension[]; |
| 59 | + // Only include dimensions that have select columns |
| 60 | + // Time dimensions without granularity return null from selectColumns() |
| 61 | + const dimensions = this.forSelect().filter((item: any) => ( |
| 62 | + !!item.dimension && item.selectColumns && item.selectColumns() |
| 63 | + )) as BaseDimension[]; |
59 | 64 | if (!dimensions.length) { |
60 | 65 | return ''; |
61 | 66 | } |
@@ -92,6 +97,88 @@ export class OracleQuery extends BaseQuery { |
92 | 97 | return `TRUNC(${dimension}, '${GRANULARITY_VALUE[granularity]}')`; |
93 | 98 | } |
94 | 99 |
|
| 100 | + /** |
| 101 | + * Oracle uses ADD_MONTHS for year/month/quarter intervals |
| 102 | + * and NUMTODSINTERVAL for day/hour/minute/second intervals |
| 103 | + */ |
| 104 | + public addInterval(date: string, interval: string): string { |
| 105 | + const intervalParsed = parseSqlInterval(interval); |
| 106 | + let res = date; |
| 107 | + |
| 108 | + // Handle year/month/quarter using ADD_MONTHS |
| 109 | + let totalMonths = 0; |
| 110 | + if (intervalParsed.year) { |
| 111 | + totalMonths += intervalParsed.year * 12; |
| 112 | + } |
| 113 | + if (intervalParsed.quarter) { |
| 114 | + totalMonths += intervalParsed.quarter * 3; |
| 115 | + } |
| 116 | + if (intervalParsed.month) { |
| 117 | + totalMonths += intervalParsed.month; |
| 118 | + } |
| 119 | + |
| 120 | + if (totalMonths !== 0) { |
| 121 | + res = `ADD_MONTHS(${res}, ${totalMonths})`; |
| 122 | + } |
| 123 | + |
| 124 | + // Handle day/hour/minute/second using NUMTODSINTERVAL |
| 125 | + if (intervalParsed.day) { |
| 126 | + res = `${res} + NUMTODSINTERVAL(${intervalParsed.day}, 'DAY')`; |
| 127 | + } |
| 128 | + if (intervalParsed.hour) { |
| 129 | + res = `${res} + NUMTODSINTERVAL(${intervalParsed.hour}, 'HOUR')`; |
| 130 | + } |
| 131 | + if (intervalParsed.minute) { |
| 132 | + res = `${res} + NUMTODSINTERVAL(${intervalParsed.minute}, 'MINUTE')`; |
| 133 | + } |
| 134 | + if (intervalParsed.second) { |
| 135 | + res = `${res} + NUMTODSINTERVAL(${intervalParsed.second}, 'SECOND')`; |
| 136 | + } |
| 137 | + |
| 138 | + return res; |
| 139 | + } |
| 140 | + |
| 141 | + /** |
| 142 | + * Oracle subtraction uses ADD_MONTHS with negative values |
| 143 | + * and subtracts NUMTODSINTERVAL for time units |
| 144 | + */ |
| 145 | + public subtractInterval(date: string, interval: string): string { |
| 146 | + const intervalParsed = parseSqlInterval(interval); |
| 147 | + let res = date; |
| 148 | + |
| 149 | + // Handle year/month/quarter using ADD_MONTHS with negative values |
| 150 | + let totalMonths = 0; |
| 151 | + if (intervalParsed.year) { |
| 152 | + totalMonths += intervalParsed.year * 12; |
| 153 | + } |
| 154 | + if (intervalParsed.quarter) { |
| 155 | + totalMonths += intervalParsed.quarter * 3; |
| 156 | + } |
| 157 | + if (intervalParsed.month) { |
| 158 | + totalMonths += intervalParsed.month; |
| 159 | + } |
| 160 | + |
| 161 | + if (totalMonths !== 0) { |
| 162 | + res = `ADD_MONTHS(${res}, -${totalMonths})`; |
| 163 | + } |
| 164 | + |
| 165 | + // Handle day/hour/minute/second using NUMTODSINTERVAL with subtraction |
| 166 | + if (intervalParsed.day) { |
| 167 | + res = `${res} - NUMTODSINTERVAL(${intervalParsed.day}, 'DAY')`; |
| 168 | + } |
| 169 | + if (intervalParsed.hour) { |
| 170 | + res = `${res} - NUMTODSINTERVAL(${intervalParsed.hour}, 'HOUR')`; |
| 171 | + } |
| 172 | + if (intervalParsed.minute) { |
| 173 | + res = `${res} - NUMTODSINTERVAL(${intervalParsed.minute}, 'MINUTE')`; |
| 174 | + } |
| 175 | + if (intervalParsed.second) { |
| 176 | + res = `${res} - NUMTODSINTERVAL(${intervalParsed.second}, 'SECOND')`; |
| 177 | + } |
| 178 | + |
| 179 | + return res; |
| 180 | + } |
| 181 | + |
95 | 182 | public newFilter(filter) { |
96 | 183 | return new OracleFilter(this, filter); |
97 | 184 | } |
|
0 commit comments