mirror of
https://github.com/knex/knex.git
synced 2025-12-28 07:29:16 +00:00
parent
e469766689
commit
40576ce430
@ -31,6 +31,30 @@ class QueryCompiler_MSSQL extends QueryCompiler {
|
||||
this._emptyInsertValue = 'default values';
|
||||
}
|
||||
|
||||
with() {
|
||||
// WITH RECURSIVE is a syntax error:
|
||||
// SQL Server does not syntactically distinguish recursive and non-recursive CTEs.
|
||||
// So mark all statements as non-recursive, generate the SQL, then restore.
|
||||
// This approach ensures any changes in base class with() get propagated here.
|
||||
const undoList = [];
|
||||
if (this.grouped.with) {
|
||||
for (const stmt of this.grouped.with) {
|
||||
if (stmt.recursive) {
|
||||
undoList.push(stmt);
|
||||
stmt.recursive = false;
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
const result = super.with();
|
||||
|
||||
// Restore the recursive markings, in case this same query gets cloned and passed to other drivers.
|
||||
for (const stmt of undoList) {
|
||||
stmt.recursive = true;
|
||||
}
|
||||
return result;
|
||||
}
|
||||
|
||||
select() {
|
||||
const sql = this.with();
|
||||
const statements = components.map((component) => this[component](this));
|
||||
|
||||
@ -1214,6 +1214,44 @@ module.exports = function (knex) {
|
||||
.select('first_name', 'last_name');
|
||||
});
|
||||
|
||||
describe('recursive CTE support', function () {
|
||||
before(async function() {
|
||||
await knex.schema.dropTableIfExists('rcte')
|
||||
await knex.schema.createTable('rcte', (table) => {
|
||||
table.string('name')
|
||||
table.string('parentName').nullable()
|
||||
})
|
||||
|
||||
// We will check later that this name was found by chaining up parentId using an rCTE.
|
||||
await knex('rcte').insert({name: 'parent'})
|
||||
let parentName = 'parent'
|
||||
for (const name of ['child', 'grandchild']) {
|
||||
await knex('rcte').insert({name, parentName})
|
||||
parentName = name
|
||||
}
|
||||
|
||||
// We will check later that this name is not returned.
|
||||
await knex('rcte').insert({name: 'nope'})
|
||||
})
|
||||
it('supports recursive CTEs', async function () {
|
||||
// FIXME: Oracle requires to omit RECURSIVE. [#4514]
|
||||
if (isOracle(knex)) {
|
||||
return this.skip()
|
||||
}
|
||||
|
||||
const results = await knex.withRecursive('family', (qb) => {
|
||||
qb.select('name', 'parentName').from('rcte').where({name: 'grandchild'}).unionAll(
|
||||
(qb) => qb.select('rcte.name', 'rcte.parentName').from('rcte').join('family', knex.ref('family.parentName'), knex.ref('rcte.name'))
|
||||
)
|
||||
}).select('name').from('family')
|
||||
const names = results.map(({name}) => name)
|
||||
|
||||
expect(names).to.have.length('parent child grandchild'.split(' ').length)
|
||||
expect(names).to.contain('parent')
|
||||
expect(names).not.to.contain('nope')
|
||||
})
|
||||
})
|
||||
|
||||
it('supports the <> operator', function () {
|
||||
return knex('accounts').where('id', '<>', 2).select('email', 'logins');
|
||||
});
|
||||
|
||||
@ -9367,13 +9367,16 @@ describe('QueryBuilder', () => {
|
||||
.select('*')
|
||||
.from('secondWithClause'),
|
||||
{
|
||||
// mssql does not allow the RECURSIVE keyword.
|
||||
mssql:
|
||||
'with recursive [firstWithClause] as (with recursive [firstWithSubClause] as ((select [foo] from [users]) as [foz]) select * from [firstWithSubClause]), [secondWithClause] as (with recursive [secondWithSubClause] as ((select [bar] from [users]) as [baz]) select * from [secondWithSubClause]) select * from [secondWithClause]',
|
||||
'with [firstWithClause] as (with [firstWithSubClause] as ((select [foo] from [users]) as [foz]) select * from [firstWithSubClause]), [secondWithClause] as (with [secondWithSubClause] as ((select [bar] from [users]) as [baz]) select * from [secondWithSubClause]) select * from [secondWithClause]',
|
||||
sqlite3:
|
||||
'with recursive `firstWithClause` as (with recursive `firstWithSubClause` as ((select `foo` from `users`) as `foz`) select * from `firstWithSubClause`), `secondWithClause` as (with recursive `secondWithSubClause` as ((select `bar` from `users`) as `baz`) select * from `secondWithSubClause`) select * from `secondWithClause`',
|
||||
pg: 'with recursive "firstWithClause" as (with recursive "firstWithSubClause" as ((select "foo" from "users") as "foz") select * from "firstWithSubClause"), "secondWithClause" as (with recursive "secondWithSubClause" as ((select "bar" from "users") as "baz") select * from "secondWithSubClause") select * from "secondWithClause"',
|
||||
'pg-redshift':
|
||||
'with recursive "firstWithClause" as (with recursive "firstWithSubClause" as ((select "foo" from "users") as "foz") select * from "firstWithSubClause"), "secondWithClause" as (with recursive "secondWithSubClause" as ((select "bar" from "users") as "baz") select * from "secondWithSubClause") select * from "secondWithClause"',
|
||||
// FIXME: oracledb does not allow the RECURSIVE keyword, but does require a list of column aliases for a recursive query. [#4514]
|
||||
// https://github.com/knex/knex/issues/4514#issuecomment-903727391
|
||||
oracledb:
|
||||
'with recursive "firstWithClause" as (with recursive "firstWithSubClause" as ((select "foo" from "users") "foz") select * from "firstWithSubClause"), "secondWithClause" as (with recursive "secondWithSubClause" as ((select "bar" from "users") "baz") select * from "secondWithSubClause") select * from "secondWithClause"',
|
||||
}
|
||||
|
||||
Loading…
x
Reference in New Issue
Block a user