Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

feat(model): add options.include[].right option #11537

Merged
merged 1 commit into from
Oct 18, 2019
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
46 changes: 46 additions & 0 deletions docs/manual/models-usage.md
Original file line number Diff line number Diff line change
Expand Up @@ -759,3 +759,49 @@ Include all also supports nested loading:
```js
User.findAll({ include: [{ all: true, nested: true }]});
```

### Use right join for association

By default, associations are loaded using a left join, that is to say it only includes records from the parent table. You can change this behavior to a right join by passing the `right` property, if the dialect you are using supports it. Currenly, `sqlite` *does not* support [right joins](https://www.sqlite.org/omitted.html).

*Note:* `right` is only respected if `required` is false.

```js
User.findAll({
include: [{
model: Tool // will create a left join
}]
});

User.findAll({
include: [{
model: Tool,
right: true // will create a right join
}]
});

User.findAll({
include: [{
model: Tool,
required: true,
right: true // has no effect, will create an inner join
}]
});

User.findAll({
include: [{
model: Tool,
where: { name: { [Op.like]: '%ooth%' } },
right: true // has no effect, will create an inner join
}]
});

User.findAll({
include: [{
model: Tool,
where: { name: { [Op.like]: '%ooth%' } },
required: false
right: true // because we set `required` to false, this will create a right join
}]
});
```
1 change: 1 addition & 0 deletions lib/dialects/abstract/index.js
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,7 @@ AbstractDialect.prototype.supports = {
'ORDER NULLS': false,
'UNION': true,
'UNION ALL': true,
'RIGHT JOIN': true,

/* does the dialect support returning values for inserted/updated fields */
returnValues: false,
Expand Down
4 changes: 2 additions & 2 deletions lib/dialects/abstract/query-generator.js
Original file line number Diff line number Diff line change
Expand Up @@ -1716,7 +1716,7 @@ class QueryGenerator {
}

return {
join: include.required ? 'INNER JOIN' : 'LEFT OUTER JOIN',
join: include.required ? 'INNER JOIN' : include.right && this._dialect.supports['RIGHT JOIN'] ? 'RIGHT OUTER JOIN' : 'LEFT OUTER JOIN',
body: this.quoteTable(tableRight, asRight),
condition: joinOn,
attributes: {
Expand Down Expand Up @@ -1750,7 +1750,7 @@ class QueryGenerator {
const identTarget = association.foreignIdentifierField;
const attrTarget = association.targetKeyField;

const joinType = include.required ? 'INNER JOIN' : 'LEFT OUTER JOIN';
const joinType = include.required ? 'INNER JOIN' : include.right && this._dialect.supports['RIGHT JOIN'] ? 'RIGHT OUTER JOIN' : 'LEFT OUTER JOIN';
let joinBody;
let joinCondition;
const attributes = {
Expand Down
1 change: 1 addition & 0 deletions lib/dialects/sqlite/index.js
Original file line number Diff line number Diff line change
Expand Up @@ -23,6 +23,7 @@ SqliteDialect.prototype.supports = _.merge(_.cloneDeep(AbstractDialect.prototype
'DEFAULT': false,
'DEFAULT VALUES': true,
'UNION ALL': false,
'RIGHT JOIN': false,
inserts: {
ignoreDuplicates: ' OR IGNORE',
updateOnDuplicate: ' ON CONFLICT DO UPDATE SET'
Expand Down
1 change: 1 addition & 0 deletions lib/model.js
Original file line number Diff line number Diff line change
Expand Up @@ -1653,6 +1653,7 @@ class Model {
* @param {Object} [options.include[].on] Supply your own ON condition for the join.
* @param {Array<string>} [options.include[].attributes] A list of attributes to select from the child model
* @param {boolean} [options.include[].required] If true, converts to an inner join, which means that the parent model will only be loaded if it has any matching children. True if `include.where` is set, false otherwise.
* @param {boolean} [options.include[].right] If true, converts to a right join if dialect support it. Ignored if `include.required` is true.
* @param {boolean} [options.include[].separate] If true, runs a separate query to fetch the associated instances, only supported for hasMany associations
* @param {number} [options.include[].limit] Limit the joined rows, only supported with include.separate=true
* @param {Object} [options.include[].through.where] Filter on the join model for belongsToMany relations
Expand Down
101 changes: 100 additions & 1 deletion test/integration/include.test.js
Original file line number Diff line number Diff line change
Expand Up @@ -7,7 +7,8 @@ const chai = require('chai'),
Support = require('./support'),
DataTypes = require('../../lib/data-types'),
_ = require('lodash'),
dialect = Support.getTestDialect();
dialect = Support.getTestDialect(),
current = Support.sequelize;

const sortById = function(a, b) {
return a.id < b.id ? -1 : 1;
Expand Down Expand Up @@ -911,6 +912,104 @@ describe(Support.getTestDialectTeaser('Include'), () => {
});
});

describe('right join', () => {
it('should support getting an include with a right join', function() {
const User = this.sequelize.define('user', {
name: DataTypes.STRING
}),
Group = this.sequelize.define('group', {
name: DataTypes.STRING
});

User.hasMany(Group);
Group.belongsTo(User);

return this.sequelize.sync({ force: true }).then(() => {
return Promise.all([
User.create({ name: 'User 1' }),
User.create({ name: 'User 2' }),
User.create({ name: 'User 3' }),
Group.create({ name: 'A Group' })
]);
}).then(() => {
return Group.findAll({
include: [{
model: User,
right: true
}]
});
}).then(groups => {
if (current.dialect.supports['RIGHT JOIN']) {
expect(groups.length).to.equal(3);
} else {
expect(groups.length).to.equal(1);
}
});
});

it('should support getting an include through with a right join', function() {
const User = this.sequelize.define('user', {
name: DataTypes.STRING
}),
Group = this.sequelize.define('group', {
name: DataTypes.STRING
}),
UserGroup = this.sequelize.define('user_group', {
vip: DataTypes.INTEGER
});

User.hasMany(Group);
Group.belongsTo(User);
User.belongsToMany(Group, {
through: UserGroup,
as: 'Clubs',
constraints: false
});
Group.belongsToMany(User, {
through: UserGroup,
as: 'Members',
constraints: false
});

const ctx = {};
return this.sequelize.sync({ force: true }).then(() => {
return Promise.all([
User.create({ name: 'Member 1' }),
User.create({ name: 'Member 2' }),
Group.create({ name: 'Group 1' }),
Group.create({ name: 'Group 2' })
]);
}).then(([member1, member2, group1, group2]) => {
ctx.member1 = member1;
ctx.member2 = member2;
ctx.group1 = group1;
ctx.group2 = group2;
}).then(() => {
return Promise.all([
ctx.group1.addMember(ctx.member1),
ctx.group1.addMember(ctx.member2),
ctx.group2.addMember(ctx.member1)
]);
}).then(() => {
return ctx.group2.destroy();
}).then(() => {
return Group.findAll({
include: [{
model: User,
as: 'Members',
right: true
}]
});
}).then(groups => {
if (current.dialect.supports['RIGHT JOIN']) {
expect(groups.length).to.equal(2);
} else {
expect(groups.length).to.equal(1);
}
});
});
});

describe('nested includes', () => {
beforeEach(function() {
const Employee = this.sequelize.define('Employee', { 'name': DataTypes.STRING });
Expand Down
2 changes: 1 addition & 1 deletion test/integration/model/count.test.js
Original file line number Diff line number Diff line change
Expand Up @@ -53,7 +53,7 @@ describe(Support.getTestDialectTeaser('Model'), () => {
{ username: 'bar' },
{
username: 'valak',
createdAt: (new Date()).setFullYear(2015)
createdAt: new Date().setFullYear(2015)
}
]).then(() => this.User.count({
attributes: ['createdAt'],
Expand Down
16 changes: 16 additions & 0 deletions test/unit/sql/generateJoin.test.js
Original file line number Diff line number Diff line change
Expand Up @@ -172,6 +172,22 @@ describe(Support.getTestDialectTeaser('SQL'), () => {
}
);

testsql(
'include[0]',
{
model: User,
subQuery: true,
include: [
{
association: User.Company, right: true
}
]
},
{
default: `${current.dialect.supports['RIGHT JOIN'] ? 'RIGHT' : 'LEFT'} OUTER JOIN [company] AS [Company] ON [User].[companyId] = [Company].[id]`
}
);

testsql(
'include[0].include[0]',
{
Expand Down
77 changes: 76 additions & 1 deletion test/unit/sql/select.test.js
Original file line number Diff line number Diff line change
Expand Up @@ -159,7 +159,6 @@ describe(Support.getTestDialectTeaser('SQL'), () => {
}) AS [user] ORDER BY [subquery_order_0] ASC;`
});


testsql({
table: User.getTableName(),
model: User,
Expand Down Expand Up @@ -374,6 +373,82 @@ describe(Support.getTestDialectTeaser('SQL'), () => {
});
});

it('include (right outer join)', () => {
const User = Support.sequelize.define('User', {
name: DataTypes.STRING,
age: DataTypes.INTEGER
},
{
freezeTableName: true
});
const Post = Support.sequelize.define('Post', {
title: DataTypes.STRING
},
{
freezeTableName: true
});

User.Posts = User.hasMany(Post, { foreignKey: 'user_id' });

expectsql(sql.selectQuery('User', {
attributes: ['name', 'age'],
include: Model._validateIncludedElements({
include: [{
attributes: ['title'],
association: User.Posts,
right: true
}],
model: User
}).include,
model: User
}, User), {
default: `SELECT [User].[name], [User].[age], [Posts].[id] AS [Posts.id], [Posts].[title] AS [Posts.title] FROM [User] AS [User] ${current.dialect.supports['RIGHT JOIN'] ? 'RIGHT' : 'LEFT'} OUTER JOIN [Post] AS [Posts] ON [User].[id] = [Posts].[user_id];`
});
});

it('include through (right outer join)', () => {
const User = Support.sequelize.define('user', {
id: {
type: DataTypes.INTEGER,
primaryKey: true,
autoIncrement: true,
field: 'id_user'
}
});
const Project = Support.sequelize.define('project', {
title: DataTypes.STRING
});

const ProjectUser = Support.sequelize.define('project_user', {
userId: {
type: DataTypes.INTEGER,
field: 'user_id'
},
projectId: {
type: DataTypes.INTEGER,
field: 'project_id'
}
}, { timestamps: false });

User.Projects = User.belongsToMany(Project, { through: ProjectUser });
Project.belongsToMany(User, { through: ProjectUser });

expectsql(sql.selectQuery('User', {
attributes: ['id_user', 'id'],
include: Model._validateIncludedElements({
include: [{
model: Project,
right: true
}],
model: User
}).include,
model: User
}, User), {
default: `SELECT [user].[id_user], [user].[id], [projects].[id] AS [projects.id], [projects].[title] AS [projects.title], [projects].[createdAt] AS [projects.createdAt], [projects].[updatedAt] AS [projects.updatedAt], [projects->project_user].[user_id] AS [projects.project_user.userId], [projects->project_user].[project_id] AS [projects.project_user.projectId] FROM [User] AS [user] ${current.dialect.supports['RIGHT JOIN'] ? 'RIGHT' : 'LEFT'} OUTER JOIN ( [project_users] AS [projects->project_user] INNER JOIN [projects] AS [projects] ON [projects].[id] = [projects->project_user].[project_id]) ON [user].[id_user] = [projects->project_user].[user_id];`,
sqlite: `SELECT \`user\`.\`id_user\`, \`user\`.\`id\`, \`projects\`.\`id\` AS \`projects.id\`, \`projects\`.\`title\` AS \`projects.title\`, \`projects\`.\`createdAt\` AS \`projects.createdAt\`, \`projects\`.\`updatedAt\` AS \`projects.updatedAt\`, \`projects->project_user\`.\`user_id\` AS \`projects.project_user.userId\`, \`projects->project_user\`.\`project_id\` AS \`projects.project_user.projectId\` FROM \`User\` AS \`user\` ${current.dialect.supports['RIGHT JOIN'] ? 'RIGHT' : 'LEFT'} OUTER JOIN \`project_users\` AS \`projects->project_user\` ON \`user\`.\`id_user\` = \`projects->project_user\`.\`user_id\` LEFT OUTER JOIN \`projects\` AS \`projects\` ON \`projects\`.\`id\` = \`projects->project_user\`.\`project_id\`;`
});
});

it('include (subQuery alias)', () => {
const User = Support.sequelize.define('User', {
name: DataTypes.STRING,
Expand Down
5 changes: 5 additions & 0 deletions types/lib/model.d.ts
Original file line number Diff line number Diff line change
Expand Up @@ -419,6 +419,11 @@ export interface IncludeOptions extends Filterable, Projectable, Paranoid {
*/
required?: boolean;

/**
* If true, converts to a right join if dialect support it. Ignored if `include.required` is true.
*/
right?: boolean;

/**
* Limit include. Only available when setting `separate` to true.
*/
Expand Down