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

Fix for createViewOrReplace and its support for sqlite3 #4856

Merged
merged 3 commits into from Jan 14, 2022
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
2 changes: 2 additions & 0 deletions .gitignore
Expand Up @@ -28,3 +28,5 @@ test/coverage/*
#VsCode workspace
.vscode
/coverage/

test/integration/migrate/migration/
33 changes: 31 additions & 2 deletions lib/dialects/sqlite3/schema/sqlite-viewcompiler.js
@@ -1,11 +1,40 @@
/* eslint max-len: 0 */

const ViewCompiler = require('../../../schema/viewcompiler.js');
const {
columnize: columnize_,
} = require('../../../formatter/wrappingFormatter');

class ViewCompiler_PG extends ViewCompiler {
class ViewCompiler_SQLite3 extends ViewCompiler {
constructor(client, viewCompiler) {
super(client, viewCompiler);
}
createOrReplace() {
const columns = this.columns;
const selectQuery = this.selectQuery.toString();
const viewName = this.viewName();

const columnList = columns
? ' (' +
columnize_(
columns,
this.viewBuilder,
this.client,
this.bindingsHolder
) +
')'
: '';

const dropSql = `drop view if exists ${viewName}`;
const createSql = `create view ${viewName}${columnList} as ${selectQuery}`;

this.pushQuery({
sql: dropSql,
});
this.pushQuery({
sql: createSql,
});
}
}

module.exports = ViewCompiler_PG;
module.exports = ViewCompiler_SQLite3;
4 changes: 2 additions & 2 deletions lib/schema/viewcompiler.js
Expand Up @@ -52,8 +52,8 @@ class ViewCompiler {
const createStatement =
'create ' +
(materialized ? 'materialized ' : '') +
'view ' +
(replace ? 'or replace ' : '');
(replace ? 'or replace ' : '') +
'view ';
const columnList = columns
? ' (' +
columnize_(
Expand Down
124 changes: 124 additions & 0 deletions test/integration2/schema/views.spec.js
Expand Up @@ -122,6 +122,130 @@ describe('Views', () => {
});
});

it('create or replace view', async () => {
// We create the view and test if all is ok
await knex.schema.createView('view_test', (view) => {
view.as(knex('table_view').select('a', 'b'));
});
await knex
.select(['a', 'b'])
.from('view_test')
.then(function (results) {
expect(results.length).to.equal(3);
expect(results[0].a).to.be.equal('test');
expect(results[1].a).to.be.equal('test2');
expect(results[2].a).to.be.equal('test3');
assertNumber(knex, results[0].b, 5);
assertNumber(knex, results[1].b, 12);
assertNumber(knex, results[2].b, 45);
});
// Now we test that the new view is replaced
await knex.schema
OlivierCavadenti marked this conversation as resolved.
Show resolved Hide resolved
.createViewOrReplace('view_test', function (view) {
view.columns(['a', 'b']);
view.as(
knex('table_view').select('a', 'b').where('b', '>', '10')
);
})
.testSql((tester) => {
tester(
['pg', 'pg-redshift', 'cockroachdb', 'oracledb'],
[
'create or replace view "view_test" ("a", "b") as select "a", "b" from "table_view" where "b" > \'10\'',
]
);
tester(
['mysql'],
[
"create or replace view `view_test` (`a`, `b`) as select `a`, `b` from `table_view` where `b` > '10'",
]
);
tester(
['sqlite3'],
[
'drop view if exists `view_test`',
"create view `view_test` (`a`, `b`) as select `a`, `b` from `table_view` where `b` > '10'",
]
);
tester('mssql', [
"CREATE OR ALTER VIEW [view_test] ([a], [b]) AS select [a], [b] from [table_view] where [b] > '10'",
]);
});

// We test if the select on the view works and if results are good
await knex
.select(['a', 'b'])
.from('view_test')
.then(function (results) {
expect(results.length).to.equal(2);
assertNumber(knex, results[0].b, 12);
assertNumber(knex, results[1].b, 45);
expect(results[0].a).to.be.equal('test2');
expect(results[1].a).to.be.equal('test3');
});
});

it('create or replace view without columns', async () => {
// We create the view and test if all is ok
await knex.schema.createView('view_test', (view) => {
view.as(knex('table_view').select('a', 'b'));
});
await knex
.select(['a', 'b'])
.from('view_test')
.then(function (results) {
expect(results.length).to.equal(3);
expect(results[0].a).to.be.equal('test');
expect(results[1].a).to.be.equal('test2');
expect(results[2].a).to.be.equal('test3');
assertNumber(knex, results[0].b, 5);
assertNumber(knex, results[1].b, 12);
assertNumber(knex, results[2].b, 45);
});
// Now we test that the new view is replaced
await knex.schema
.createViewOrReplace('view_test', function (view) {
view.as(
knex('table_view').select('a', 'b').where('b', '>', '10')
);
})
.testSql((tester) => {
tester(
['pg', 'pg-redshift', 'cockroachdb', 'oracledb'],
[
'create or replace view "view_test" as select "a", "b" from "table_view" where "b" > \'10\'',
]
);
tester(
['mysql'],
[
"create or replace view `view_test` as select `a`, `b` from `table_view` where `b` > '10'",
]
);
tester(
['sqlite3'],
[
'drop view if exists `view_test`',
"create view `view_test` as select `a`, `b` from `table_view` where `b` > '10'",
]
);
tester('mssql', [
"CREATE OR ALTER VIEW [view_test] AS select [a], [b] from [table_view] where [b] > '10'",
]);
});

// We test if the select on the view works and if results are good
await knex
.select(['a', 'b'])
.from('view_test')
.then(function (results) {
assertNumber(knex, results[0].b, 12);
assertNumber(knex, results[1].b, 45);
expect(results[0].a).to.be.equal('test2');
expect(results[1].a).to.be.equal('test3');
});
});

it('create materialized view', async function () {
if (isMssql(knex) || isSQLite(knex) || isMysql(knex)) {
return this.skip();
Expand Down
13 changes: 13 additions & 0 deletions test/unit/schema-builder/mssql.js
Expand Up @@ -118,6 +118,19 @@ describe('MSSQL SchemaBuilder', function () {
);
});

it('create view or replace without columns', async function () {
const viewSql = client
.schemaBuilder()
.createViewOrReplace('adults', function (view) {
view.as(knexMssql('users').select('name').where('age', '>', '18'));
})
.toSQL();
equal(1, viewSql.length);
expect(viewSql[0].sql).to.equal(
"CREATE OR ALTER VIEW [adults] AS select [name] from [users] where [age] > '18'"
);
});

it('create view with check options', async function () {
expect(() => {
client
Expand Down
17 changes: 15 additions & 2 deletions test/unit/schema-builder/mysql.js
Expand Up @@ -155,9 +155,22 @@ module.exports = function (dialect) {
view.as(knexMysql('users').select('name').where('age', '>', '18'));
})
.toSQL();
equal(1, viewSql.length);
expect(viewSql.length).to.equal(1);
expect(viewSql[0].sql).to.equal(
"create or replace view `adults` (`name`) as select `name` from `users` where `age` > '18'"
);
});

it('create view or replace without columns', async function () {
const viewSql = client
.schemaBuilder()
.createViewOrReplace('adults', function (view) {
view.as(knexMysql('users').select('name').where('age', '>', '18'));
})
.toSQL();
expect(viewSql.length).to.equal(1);
expect(viewSql[0].sql).to.equal(
"create view or replace `adults` (`name`) as select `name` from `users` where `age` > '18'"
"create or replace view `adults` as select `name` from `users` where `age` > '18'"
);
});

Expand Down
19 changes: 16 additions & 3 deletions test/unit/schema-builder/oracledb.js
Expand Up @@ -97,9 +97,22 @@ describe('OracleDb SchemaBuilder', function () {
view.as(knexOracleDb('users').select('name').where('age', '>', '18'));
})
.toSQL();
equal(1, viewSql.length);
expect(viewSql.length).to.equal(1);
expect(viewSql[0].sql).to.equal(
'create or replace view "adults" ("name") as select "name" from "users" where "age" > \'18\''
);
});

it('create view or replace without columns', async function () {
const viewSql = client
.schemaBuilder()
.createViewOrReplace('adults', function (view) {
view.as(knexOracleDb('users').select('name').where('age', '>', '18'));
})
.toSQL();
expect(viewSql.length).to.equal(1);
expect(viewSql[0].sql).to.equal(
'create view or replace "adults" ("name") as select "name" from "users" where "age" > \'18\''
'create or replace view "adults" as select "name" from "users" where "age" > \'18\''
);
});

Expand All @@ -112,7 +125,7 @@ describe('OracleDb SchemaBuilder', function () {
view.checkOption();
})
.toSQL();
equal(1, tableSql.length);
expect(tableSql.length).to.equal(1);
expect(tableSql[0].sql).to.equal(
'create view "adults" ("name") as select "name" from "users" where "age" > \'18\' with check option'
);
Expand Down
15 changes: 14 additions & 1 deletion test/unit/schema-builder/postgres.js
Expand Up @@ -255,9 +255,22 @@ describe('PostgreSQL SchemaBuilder', function () {
view.as(knexPg('users').select('name').where('age', '>', '18'));
})
.toSQL();
expect(viewSql.length).to.equal(1);
expect(viewSql[0].sql).to.equal(
'create or replace view "adults" ("name") as select "name" from "users" where "age" > \'18\''
);
});

it('create view or replace without columns', async function () {
const viewSql = client
.schemaBuilder()
.createViewOrReplace('adults', function (view) {
view.as(knexPg('users').select('name').where('age', '>', '18'));
})
.toSQL();
equal(1, viewSql.length);
expect(viewSql[0].sql).to.equal(
'create view or replace "adults" ("name") as select "name" from "users" where "age" > \'18\''
'create or replace view "adults" as select "name" from "users" where "age" > \'18\''
);
});

Expand Down
25 changes: 19 additions & 6 deletions test/unit/schema-builder/redshift.js
Expand Up @@ -93,7 +93,7 @@ describe('Redshift SchemaBuilder', function () {
view.as(knexRedShift('users').select('name').where('age', '>', '18'));
})
.toSQL();
equal(1, viewSql.length);
expect(viewSql.length).to.equal(1);
expect(viewSql[0].sql).to.equal(
'create view "adults" ("name") as select "name" from "users" where "age" > \'18\''
);
Expand All @@ -106,7 +106,7 @@ describe('Redshift SchemaBuilder', function () {
view.as(knexRedShift('users').select('name').where('age', '>', '18'));
})
.toSQL();
equal(1, viewSql.length);
expect(viewSql.length).to.equal(1);
expect(viewSql[0].sql).to.equal(
'create view "adults" as select "name" from "users" where "age" > \'18\''
);
Expand All @@ -120,9 +120,22 @@ describe('Redshift SchemaBuilder', function () {
view.as(knexRedShift('users').select('name').where('age', '>', '18'));
})
.toSQL();
equal(1, viewSql.length);
expect(viewSql.length).to.equal(1);
expect(viewSql[0].sql).to.equal(
'create view or replace "adults" ("name") as select "name" from "users" where "age" > \'18\''
'create or replace view "adults" ("name") as select "name" from "users" where "age" > \'18\''
);
});

it('create view or replace without columns', async function () {
const viewSql = client
.schemaBuilder()
.createViewOrReplace('adults', function (view) {
view.as(knexRedShift('users').select('name').where('age', '>', '18'));
})
.toSQL();
expect(viewSql.length).to.equal(1);
expect(viewSql[0].sql).to.equal(
'create or replace view "adults" as select "name" from "users" where "age" > \'18\''
);
});

Expand All @@ -135,7 +148,7 @@ describe('Redshift SchemaBuilder', function () {
view.localCheckOption();
})
.toSQL();
equal(1, viewSqlLocalCheck.length);
expect(viewSqlLocalCheck.length).to.equal(1);
expect(viewSqlLocalCheck[0].sql).to.equal(
'create view "adults" ("name") as select "name" from "users" where "age" > \'18\' with local check option'
);
Expand All @@ -148,7 +161,7 @@ describe('Redshift SchemaBuilder', function () {
view.cascadedCheckOption();
})
.toSQL();
equal(1, viewSqlCascadedCheck.length);
expect(viewSqlCascadedCheck.length).to.equal(1);
expect(viewSqlCascadedCheck[0].sql).to.equal(
'create view "adults" ("name") as select "name" from "users" where "age" > \'18\' with cascaded check option'
);
Expand Down
34 changes: 26 additions & 8 deletions test/unit/schema-builder/sqlite3.js
Expand Up @@ -110,14 +110,32 @@ describe('SQLite SchemaBuilder', function () {
});

it('create view or replace', async function () {
expect(() => {
tableSql = client
.schemaBuilder()
.view('users', function (view) {
view.column('oldName').rename('newName').defaultTo('10');
})
.toSQL();
}).to.throw('rename column of views is not supported by this dialect.');
const viewSql = client
.schemaBuilder()
.createViewOrReplace('adults', function (view) {
view.columns(['name']);
view.as(knexSqlite3('users').select('name').where('age', '>', '18'));
})
.toSQL();
expect(viewSql.length).to.equal(2);
expect(viewSql[0].sql).to.equal('drop view if exists `adults`');
expect(viewSql[1].sql).to.equal(
"create view `adults` (`name`) as select `name` from `users` where `age` > '18'"
);
});

it('create view or replace without columns', async function () {
const viewSql = client
.schemaBuilder()
.createViewOrReplace('adults', function (view) {
view.as(knexSqlite3('users').select('name').where('age', '>', '18'));
})
.toSQL();
expect(viewSql.length).to.equal(2);
expect(viewSql[0].sql).to.equal('drop view if exists `adults`');
expect(viewSql[1].sql).to.equal(
"create view `adults` as select `name` from `users` where `age` > '18'"
);
});

it('create view with check options', async function () {
Expand Down