Skip to content

Commit

Permalink
feat(sequelize): custom query support
Browse files Browse the repository at this point in the history
implemented execute method on datasource with similar interface as juggler

Signed-off-by: Shubham P <shubham.prajapat@sourcefuse.com>
  • Loading branch information
shubhamp-sf authored and samarpanB committed Jun 1, 2023
1 parent f90cf7f commit a30ecc8
Show file tree
Hide file tree
Showing 4 changed files with 275 additions and 15 deletions.
Expand Up @@ -153,6 +153,6 @@ export class TodoListController extends TestControllerBase {
@get('/todo-lists/sync-sequelize-model')
@response(200)
async syncSequelizeModel(): Promise<void> {
await this.beforeEach();
await this.beforeEach({syncAll: true});
}
}
Expand Up @@ -10,9 +10,9 @@ import {
import {resolve} from 'path';
import {SequelizeSandboxApplication} from '../fixtures/application';
import {config as primaryDataSourceConfig} from '../fixtures/datasources/primary.datasource';

import {config as secondaryDataSourceConfig} from '../fixtures/datasources/secondary.datasource';
import {TableInSecondaryDB} from '../fixtures/models';
import {UserRepository} from '../fixtures/repositories';

type Entities =
| 'users'
Expand All @@ -27,6 +27,7 @@ describe('Sequelize CRUD Repository (integration)', () => {
const sandbox = new TestSandbox(resolve(__dirname, '../../.sandbox'));

let app: SequelizeSandboxApplication;
let userRepo: UserRepository;
let client: Client;

beforeEach('reset sandbox', () => sandbox.reset());
Expand Down Expand Up @@ -86,6 +87,136 @@ describe('Sequelize CRUD Repository (integration)', () => {
expect(patchResponse.body).to.have.property('count', 1);
});

it('can execute raw sql command without parameters', async function () {
await client.post('/users').send(getDummyUser({name: 'Foo'}));

const queryResult = await userRepo.execute('SELECT * from "user"');

expect(queryResult).to.have.length(1);
expect(queryResult[0]).property('name').to.be.eql('Foo');
});

it('can execute raw sql command (select) using named parameters', async function () {
await client.post('/users').send(getDummyUser({name: 'Foo'}));
const bar = getDummyUser({name: 'Bar'});
await client.post('/users').send(bar);

const queryResult = await userRepo.execute(
'SELECT * from "user" where name = $name',
{
name: 'Bar',
},
);

expect(queryResult).to.have.length(1);
expect(queryResult[0]).property('name').to.be.eql(bar.name);
expect(queryResult[0]).property('email').to.be.eql(bar.email);
});

it('can execute raw sql command (select) using positional parameters', async () => {
await client.post('/users').send(getDummyUser({name: 'Foo'}));
const bar = getDummyUser({name: 'Bar'});
await client.post('/users').send(bar);

const queryResult = await userRepo.execute(
'SELECT * from "user" where name = $1',
['Bar'],
);

expect(queryResult).to.have.length(1);
expect(queryResult[0]).property('name').to.be.eql(bar.name);
expect(queryResult[0]).property('email').to.be.eql(bar.email);
});

it('can execute raw sql command (insert) using positional parameters', async () => {
const user = getDummyUser({name: 'Foo', active: true});
if (primaryDataSourceConfig.connector === 'sqlite3') {
// sqlite handles object and dates differently
// it requires format like 2007-01-01 10:00:00 (https://stackoverflow.com/a/1933735/14200863)
// and sequelize's sqlite dialect parses object returned from db so below reassignments are required here
user.dob = '2023-05-23T04:12:22.234Z';
user.address = JSON.stringify(user.address);
}

// since the model mapping is not performed when executing raw queries
// any column renaming need to be changed manually
user.is_active = user.active;
delete user.active;

await userRepo.execute(
'INSERT INTO "user" (name, email, is_active, address, dob) VALUES ($1, $2, $3, $4, $5)',
[user.name, user.email, user.is_active, user.address, user.dob],
);

const users = await userRepo.execute('SELECT * from "user"');

expect(users).to.have.length(1);
expect(users[0]).property('name').to.be.eql(user.name);
expect(users[0]).property('email').to.be.eql(user.email);
expect(users[0]).property('address').to.be.eql(user.address);
expect(new Date(users[0].dob)).to.be.eql(new Date(user.dob!));
expect(users[0]).property('is_active').to.be.ok();
});

it('can execute raw sql command (insert) using named parameters', async () => {
const user = getDummyUser({name: 'Foo', active: true});
if (primaryDataSourceConfig.connector === 'sqlite3') {
user.dob = '2023-05-23T04:12:22.234Z';
user.address = JSON.stringify(user.address);
}

// since the model mapping is not performed when executing raw queries
// any column renaming need to be changed manually
user.is_active = user.active;
delete user.active;

await userRepo.execute(
'INSERT INTO "user" (name, email, is_active, address, dob) VALUES ($name, $email, $is_active, $address, $dob)',
user,
);

const users = await userRepo.execute('SELECT * from "user"');

expect(users).to.have.length(1);
expect(users[0]).property('name').to.be.eql(user.name);
expect(users[0]).property('email').to.be.eql(user.email);
expect(users[0]).property('address').to.be.eql(user.address);
expect(new Date(users[0].dob)).to.be.eql(new Date(user.dob!));
expect(users[0]).property('is_active').to.be.ok();
});

it('can execute raw sql command (insert) using question mark replacement', async () => {
const user = getDummyUser({name: 'Foo', active: true});
if (primaryDataSourceConfig.connector === 'sqlite3') {
user.dob = '2023-05-23T04:12:22.234Z';
}

// when using replacements (using "?" mark)
// sequelize when escaping those values needs them as string (See: https://github.com/sequelize/sequelize/blob/v6/src/sql-string.js#L65-L77)
user.address = JSON.stringify(user.address);

// since the model mapping is not performed when executing raw queries
// any column renaming need to be changed manually
user.is_active = user.active;
delete user.active;

await userRepo.execute(
'INSERT INTO "user" (name, email, is_active, address, dob) VALUES (?, ?, ?, ?, ?)',
[user.name, user.email, user.is_active, user.address, user.dob],
);

const users = await userRepo.execute('SELECT * from "user"');

expect(users).to.have.length(1);
expect(users[0]).property('name').to.be.eql(user.name);
expect(users[0]).property('email').to.be.eql(user.email);
expect(users[0])
.property('address')
.to.be.oneOf(JSON.parse(user.address as string), user.address);
expect(new Date(users[0].dob)).to.be.eql(new Date(user.dob!));
expect(users[0]).property('is_active').to.be.ok();
});

it('supports `fields` filter', async () => {
const user = getDummyUser();
const createResponse = await client.post('/users').send(user);
Expand Down Expand Up @@ -342,7 +473,7 @@ describe('Sequelize CRUD Repository (integration)', () => {
it('can work with two datasources together', async () => {
await migrateSchema(['todo-lists', 'products']);

// products model uses primary datasource
// todo-lists model uses primary datasource
const todoList = getDummyTodoList();
const todoListCreateRes = await client.post('/todo-lists').send(todoList);

Expand Down Expand Up @@ -523,14 +654,23 @@ describe('Sequelize CRUD Repository (integration)', () => {
await app.boot();
await app.start();

userRepo = await app.getRepository(UserRepository);
client = createRestAppClient(app as RestApplication);
}

function getDummyUser(overwrite = {}) {
const date = new Date();
const timestamp = date.toISOString();

const user = {
type DummyUser = {
name: string;
email: string;
active?: boolean;
address: AnyObject | string;
dob: Date | string;
} & AnyObject;

const user: DummyUser = {
name: 'Foo',
email: 'email@example.com',
active: true,
Expand Down
88 changes: 87 additions & 1 deletion extensions/sequelize/src/sequelize/sequelize.datasource.base.ts
@@ -1,8 +1,15 @@
import {LifeCycleObserver} from '@loopback/core';
import {AnyObject} from '@loopback/repository';
import {
AnyObject,
Command,
NamedParameters,
Options,
PositionalParameters,
} from '@loopback/repository';
import debugFactory from 'debug';
import {
PoolOptions,
QueryOptions,
Sequelize,
Options as SequelizeOptions,
Transaction,
Expand Down Expand Up @@ -131,6 +138,85 @@ export class SequelizeDataSource implements LifeCycleObserver {
return this.sequelize!.transaction(options);
}

/**
* Execute a SQL command.
*
* **WARNING:** In general, it is always better to perform database actions
* through repository methods. Directly executing SQL may lead to unexpected
* results, corrupted data, security vulnerabilities and other issues.
*
* @example
*
* ```ts
* // MySQL
* const result = await db.execute(
* 'SELECT * FROM Products WHERE size > ?',
* [42]
* );
*
* // PostgreSQL
* const result = await db.execute(
* 'SELECT * FROM Products WHERE size > $1',
* [42]
* );
* ```
*
* @param command A parameterized SQL command or query.
* @param parameters List of parameter values to use.
* @param options Additional options, for example `transaction`.
* @returns A promise which resolves to the command output. The output type (data structure) is database specific and
* often depends on the command executed.
*/
async execute(
command: Command,
parameters?: NamedParameters | PositionalParameters,
options?: Options,
): Promise<AnyObject> {
if (!this.sequelize) {
throw Error(
`The datasource "${this.name}" doesn't have sequelize instance bound to it.`,
);
}

if (typeof command !== 'string') {
command = JSON.stringify(command);
}

options = options ?? {};

const queryOptions: QueryOptions = {};
if (options?.transaction) {
queryOptions.transaction = options.transaction;
}

let targetReplacementKey: 'replacements' | 'bind';

// By default, we'll use 'bind'
targetReplacementKey = 'bind';

if (command.includes('?')) {
// If command has '?', use 'replacements'
targetReplacementKey = 'replacements';
} else if (/\$\w/g.test(command)) {
// If command has parameters starting with a dollar sign ($param or $1, $2), use 'bind'
targetReplacementKey = 'bind';
}

if (parameters) {
queryOptions[targetReplacementKey] = parameters;
}
const result = await this.sequelize.query(command, queryOptions);

// Sequelize returns the select query result in an array at index 0 and at index 1 is the actual Result instance
// Whereas in juggler it is returned directly as plain array.
// Below condition maps that 0th index to final result to match juggler's behaviour
if (command.match(/^select/i) && result.length >= 1) {
return result[0];
}

return result;
}

getPoolOptions(): PoolOptions | undefined {
const config: SequelizeDataSourceConfig = this.config;
const specifiedPoolOptions = Object.keys(config).some(key =>
Expand Down
54 changes: 44 additions & 10 deletions extensions/sequelize/src/sequelize/sequelize.repository.base.ts
Expand Up @@ -7,12 +7,8 @@ import {
AnyObject,
BelongsToAccessor,
BelongsToDefinition,
Command,
Count,
createBelongsToAccessor,
createHasManyRepositoryFactory,
createHasManyThroughRepositoryFactory,
createHasOneRepositoryFactory,
createReferencesManyAccessor,
DataObject,
Entity,
EntityCrudRepository,
Expand All @@ -29,12 +25,19 @@ import {
Inclusion,
InclusionFilter,
InclusionResolver,
RelationType as LoopbackRelationType,
NamedParameters,
Options,
PositionalParameters,
PropertyDefinition,
ReferencesManyAccessor,
ReferencesManyDefinition,
RelationType as LoopbackRelationType,
Where,
createBelongsToAccessor,
createHasManyRepositoryFactory,
createHasManyThroughRepositoryFactory,
createHasOneRepositoryFactory,
createReferencesManyAccessor,
} from '@loopback/repository';
import debugFactory from 'debug';
import {
Expand Down Expand Up @@ -347,10 +350,41 @@ export class SequelizeCrudRepository<
return {count};
}

async execute(..._args: PositionalParameters): Promise<AnyObject> {
throw new Error(
'RAW Query execution is currently NOT supported for Sequelize CRUD Repository.',
);
/**
* Execute a SQL command.
*
* **WARNING:** In general, it is always better to perform database actions
* through repository methods. Directly executing SQL may lead to unexpected
* results, corrupted data, security vulnerabilities and other issues.
*
* @example
*
* ```ts
* // MySQL
* const result = await repo.execute(
* 'SELECT * FROM Products WHERE size > ?',
* [42]
* );
*
* // PostgreSQL
* const result = await repo.execute(
* 'SELECT * FROM Products WHERE size > $1',
* [42]
* );
* ```
*
* @param command A parameterized SQL command or query.
* @param parameters List of parameter values to use.
* @param options Additional options, for example `transaction`.
* @returns A promise which resolves to the command output. The output type (data structure) is database specific and
* often depends on the command executed.
*/
async execute(
command: Command,
parameters?: NamedParameters | PositionalParameters,
options?: Options,
): Promise<AnyObject> {
return this.dataSource.execute(command, parameters, options);
}

protected toEntities(models: Model<T, T>[]): T[] {
Expand Down

0 comments on commit a30ecc8

Please sign in to comment.