Skip to content

Commit 6916535

Browse files
committed
- Support for "left join lateral" in Postgres which converts to "outer apply" in Microsoft SQL Server and Oracle.
1 parent 95d775a commit 6916535

File tree

6 files changed

+87
-0
lines changed

6 files changed

+87
-0
lines changed

lib/dialect/mssql.js

+10
Original file line numberDiff line numberDiff line change
@@ -274,6 +274,16 @@ Mssql.prototype.visitFunctionCall = function(functionCall) {
274274
return [txt];
275275
};
276276

277+
Mssql.prototype.visitJoin = function(join) {
278+
if (join.subType !== 'LEFT LATERAL') return Mssql.super_.prototype.visitJoin.call(this, join);
279+
var result = [];
280+
this._visitingJoin = true;
281+
result = result.concat(this.visit(join.from));
282+
result = result.concat('OUTER APPLY');
283+
result = result.concat(this.visit(join.to));
284+
return result;
285+
};
286+
277287
Mssql.prototype.visitOrderBy = function(orderBy) {
278288
var result=Mssql.super_.prototype.visitOrderBy.call(this, orderBy);
279289
var offsetNode=orderBy.msSQLOffsetNode;

lib/dialect/oracle.js

+5
Original file line numberDiff line numberDiff line change
@@ -278,6 +278,11 @@ Oracle.prototype.visitCase = function(caseExp) {
278278
return Mssql.prototype.visitCase.call(this, caseExp);
279279
};
280280

281+
// Using same JOIN implementation as MSSQL
282+
Oracle.prototype.visitJoin = function(joinExp) {
283+
return Mssql.prototype.visitJoin.call(this, joinExp);
284+
};
285+
281286
Oracle.prototype.visitOnConflict = function(onConflict) {
282287
throw new Error('Oracle does not allow onConflict clause.');
283288
};

lib/dialect/postgres.js

+11
Original file line numberDiff line numberDiff line change
@@ -1022,6 +1022,7 @@ Postgres.prototype.visitForShare = function() {
10221022
};
10231023

10241024
Postgres.prototype.visitJoin = function(join) {
1025+
if (join.subType === 'LEFT LATERAL') return this.visitLeftJoinLateral(join)
10251026
var result = [];
10261027
this._visitingJoin = true;
10271028
result = result.concat(this.visit(join.from));
@@ -1032,6 +1033,16 @@ Postgres.prototype.visitJoin = function(join) {
10321033
return result;
10331034
};
10341035

1036+
Postgres.prototype.visitLeftJoinLateral = function(join) {
1037+
var result = [];
1038+
this._visitingJoin = true;
1039+
result = result.concat(this.visit(join.from));
1040+
result = result.concat('LEFT JOIN LATERAL');
1041+
result = result.concat(this.visit(join.to));
1042+
result = result.concat('ON true');
1043+
return result;
1044+
};
1045+
10351046
Postgres.prototype.visitLiteral = function(node) {
10361047
var txt = [node.literal];
10371048
if(node.alias) {

lib/node/join.js

+3
Original file line numberDiff line numberDiff line change
@@ -19,5 +19,8 @@ var JoinNode = module.exports = Node.define({
1919
},
2020
leftJoin: function(other) {
2121
return new JoinNode('LEFT', this, other);
22+
},
23+
leftJoinLateral: function(other) {
24+
return new JoinNode('LEFT LATERAL', this, other);
2225
}
2326
});

lib/table.js

+4
Original file line numberDiff line numberDiff line change
@@ -237,6 +237,10 @@ Table.prototype.leftJoin = function(other) {
237237
return new JoinNode('LEFT', this.toNode(), other.toNode());
238238
};
239239

240+
Table.prototype.leftJoinLateral = function(other) {
241+
return new JoinNode('LEFT LATERAL', this.toNode(), other.toNode());
242+
};
243+
240244
// auto-join tables based on column intropsection
241245
Table.prototype.joinTo = function(other) {
242246
return Joiner.leftJoin(this, other);

test/dialects/join-tests.js

+54
Original file line numberDiff line numberDiff line change
@@ -174,3 +174,57 @@ Harness.test({
174174
},
175175
params: []
176176
});
177+
178+
Harness.test({
179+
query: user.select().from(user.leftJoinLateral(post.subQuery().select(post.userId))),
180+
pg: {
181+
text : 'SELECT "user".* FROM "user" LEFT JOIN LATERAL (SELECT "post"."userId" FROM "post") ON true',
182+
string: 'SELECT "user".* FROM "user" LEFT JOIN LATERAL (SELECT "post"."userId" FROM "post") ON true'
183+
},
184+
mssql: {
185+
text : 'SELECT [user].* FROM [user] OUTER APPLY (SELECT [post].[userId] FROM [post])',
186+
string: 'SELECT [user].* FROM [user] OUTER APPLY (SELECT [post].[userId] FROM [post])'
187+
},
188+
oracle: {
189+
text : 'SELECT "user".* FROM "user" OUTER APPLY (SELECT "post"."userId" FROM "post")',
190+
string: 'SELECT "user".* FROM "user" OUTER APPLY (SELECT "post"."userId" FROM "post")'
191+
},
192+
params: []
193+
});
194+
195+
Harness.test({
196+
query: user.select().from(user.leftJoinLateral(post.subQuery().select(post.userId).where(user.id.equals(post.userId)))),
197+
pg: {
198+
text : 'SELECT "user".* FROM "user" LEFT JOIN LATERAL (SELECT "post"."userId" FROM "post" WHERE ("user"."id" = "post"."userId")) ON true',
199+
string: 'SELECT "user".* FROM "user" LEFT JOIN LATERAL (SELECT "post"."userId" FROM "post" WHERE ("user"."id" = "post"."userId")) ON true'
200+
},
201+
mssql: {
202+
text : 'SELECT [user].* FROM [user] OUTER APPLY (SELECT [post].[userId] FROM [post] WHERE ([user].[id] = [post].[userId]))',
203+
string: 'SELECT [user].* FROM [user] OUTER APPLY (SELECT [post].[userId] FROM [post] WHERE ([user].[id] = [post].[userId]))'
204+
},
205+
oracle: {
206+
text : 'SELECT "user".* FROM "user" OUTER APPLY (SELECT "post"."userId" FROM "post" WHERE ("user"."id" = "post"."userId"))',
207+
string: 'SELECT "user".* FROM "user" OUTER APPLY (SELECT "post"."userId" FROM "post" WHERE ("user"."id" = "post"."userId"))'
208+
},
209+
params: []
210+
});
211+
212+
Harness.test({
213+
query: user.select().from(user
214+
.leftJoinLateral(post.subQuery().select(post.userId))
215+
.leftJoinLateral(comment.subQuery().select(comment.postId))),
216+
pg: {
217+
text : 'SELECT "user".* FROM "user" LEFT JOIN LATERAL (SELECT "post"."userId" FROM "post") ON true LEFT JOIN LATERAL (SELECT "comment"."postId" FROM "comment") ON true',
218+
string: 'SELECT "user".* FROM "user" LEFT JOIN LATERAL (SELECT "post"."userId" FROM "post") ON true LEFT JOIN LATERAL (SELECT "comment"."postId" FROM "comment") ON true'
219+
},
220+
mssql: {
221+
text : 'SELECT [user].* FROM [user] OUTER APPLY (SELECT [post].[userId] FROM [post]) OUTER APPLY (SELECT [comment].[postId] FROM [comment])',
222+
string: 'SELECT [user].* FROM [user] OUTER APPLY (SELECT [post].[userId] FROM [post]) OUTER APPLY (SELECT [comment].[postId] FROM [comment])'
223+
},
224+
oracle: {
225+
text : 'SELECT "user".* FROM "user" OUTER APPLY (SELECT "post"."userId" FROM "post") OUTER APPLY (SELECT "comment"."postId" FROM "comment")',
226+
string: 'SELECT "user".* FROM "user" OUTER APPLY (SELECT "post"."userId" FROM "post") OUTER APPLY (SELECT "comment"."postId" FROM "comment")'
227+
},
228+
params: []
229+
});
230+

0 commit comments

Comments
 (0)