query-generator.test.js
9.61 KB
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
'use strict';
const Support = require(__dirname + '/../../support');
const expectsql = Support.expectsql;
const current = Support.sequelize;
const QueryGenerator = require('../../../../lib/dialects/mssql/query-generator');
const _ = require('lodash');
if (current.dialect.name === 'mssql') {
suite('[MSSQL Specific] QueryGenerator', () => {
// Dialect would normally be set by the query interface that instantiates the query-generator, but here we specify it explicitly
QueryGenerator._dialect = current.dialect;
test('getDefaultConstraintQuery', () => {
expectsql(QueryGenerator.getDefaultConstraintQuery({tableName: 'myTable', schema: 'mySchema'}, 'myColumn'), {
mssql: "SELECT name FROM SYS.DEFAULT_CONSTRAINTS WHERE PARENT_OBJECT_ID = OBJECT_ID('[mySchema].[myTable]', 'U') AND PARENT_COLUMN_ID = (SELECT column_id FROM sys.columns WHERE NAME = ('myColumn') AND object_id = OBJECT_ID('[mySchema].[myTable]', 'U'));"
});
});
test('dropConstraintQuery', () => {
expectsql(QueryGenerator.dropConstraintQuery({tableName: 'myTable', schema: 'mySchema'}, 'myConstraint'), {
mssql: 'ALTER TABLE [mySchema].[myTable] DROP CONSTRAINT [myConstraint];'
});
});
test('bulkInsertQuery', () => {
//normal cases
expectsql(QueryGenerator.bulkInsertQuery('myTable', [{ name: 'foo' }, {name: 'bar'}]), {
mssql: "INSERT INTO [myTable] ([name]) VALUES (N'foo'),(N'bar');"
});
expectsql(QueryGenerator.bulkInsertQuery('myTable', [{ username: 'username', firstName: 'firstName', lastName: 'lastName' }, { firstName: 'user1FirstName', lastName: 'user1LastName'}]), {
mssql: "INSERT INTO [myTable] ([username],[firstName],[lastName]) VALUES (N'username',N'firstName',N'lastName'),(NULL,N'user1FirstName',N'user1LastName');"
});
expectsql(QueryGenerator.bulkInsertQuery('myTable', [{ firstName: 'firstName', lastName: 'lastName' }, { firstName: 'user1FirstName', lastName: 'user1LastName'}]), {
mssql: "INSERT INTO [myTable] ([firstName],[lastName]) VALUES (N'firstName',N'lastName'),(N'user1FirstName',N'user1LastName');"
});
//Bulk Insert With autogenerated primary key
const attributes = { id: { autoIncrement: true }};
expectsql(QueryGenerator.bulkInsertQuery('myTable', [{ id: null }], {}, attributes), {
mssql: 'INSERT INTO [myTable] DEFAULT VALUES'
});
});
test('selectFromTableFragment', () => {
const modifiedGen = _.clone(QueryGenerator);
// Test newer versions first
// Should be all the same since handling is done in addLimitAndOffset
// for SQL Server 2012 and higher (>= v11.0.0)
modifiedGen.sequelize = {
options: {
databaseVersion: '11.0.0'
}
};
// Base case
expectsql(modifiedGen.selectFromTableFragment({}, { primaryKeyField: 'id' }, ['id', 'name'], 'myTable', 'myOtherName', 'WHERE id=1'), {
mssql: 'SELECT id, name FROM myTable AS myOtherName'
});
// With limit
expectsql(modifiedGen.selectFromTableFragment({ limit: 10 }, { primaryKeyField: 'id' }, ['id', 'name'], 'myTable', 'myOtherName'), {
mssql: 'SELECT id, name FROM myTable AS myOtherName'
});
// With offset
expectsql(modifiedGen.selectFromTableFragment({ offset: 10 }, { primaryKeyField: 'id' }, ['id', 'name'], 'myTable', 'myOtherName'), {
mssql: 'SELECT id, name FROM myTable AS myOtherName'
});
// With both limit and offset
expectsql(modifiedGen.selectFromTableFragment({ limit: 10, offset: 10 }, { primaryKeyField: 'id' }, ['id', 'name'], 'myTable', 'myOtherName'), {
mssql: 'SELECT id, name FROM myTable AS myOtherName'
});
// Test older version (< v11.0.0)
modifiedGen.sequelize.options.databaseVersion = '10.0.0';
// Base case
expectsql(modifiedGen.selectFromTableFragment({}, { primaryKeyField: 'id' }, ['id', 'name'], 'myTable', 'myOtherName', 'WHERE id=1'), {
mssql: 'SELECT id, name FROM myTable AS myOtherName'
});
// With limit
expectsql(modifiedGen.selectFromTableFragment({ limit: 10 }, { primaryKeyField: 'id' }, ['id', 'name'], 'myTable', 'myOtherName'), {
mssql: 'SELECT TOP 10 id, name FROM myTable AS myOtherName'
});
// With offset
expectsql(modifiedGen.selectFromTableFragment({ offset: 10 }, { primaryKeyField: 'id' }, ['id', 'name'], 'myTable', 'myOtherName'), {
mssql: 'SELECT TOP 100 PERCENT id, name FROM (SELECT * FROM (SELECT ROW_NUMBER() OVER (ORDER BY [id]) as row_num, * FROM myTable AS myOtherName) AS myOtherName WHERE row_num > 10) AS myOtherName'
});
// With both limit and offset
expectsql(modifiedGen.selectFromTableFragment({ limit: 10, offset: 10 }, { primaryKeyField: 'id' }, ['id', 'name'], 'myTable', 'myOtherName'), {
mssql: 'SELECT TOP 100 PERCENT id, name FROM (SELECT TOP 10 * FROM (SELECT ROW_NUMBER() OVER (ORDER BY [id]) as row_num, * FROM myTable AS myOtherName) AS myOtherName WHERE row_num > 10) AS myOtherName'
});
});
test('getPrimaryKeyConstraintQuery', () => {
expectsql(QueryGenerator.getPrimaryKeyConstraintQuery('myTable', 'myColumnName'), {
mssql: 'SELECT K.TABLE_NAME AS tableName, K.COLUMN_NAME AS columnName, K.CONSTRAINT_NAME AS constraintName FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS AS C JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE AS K ON C.TABLE_NAME = K.TABLE_NAME AND C.CONSTRAINT_CATALOG = K.CONSTRAINT_CATALOG AND C.CONSTRAINT_SCHEMA = K.CONSTRAINT_SCHEMA AND C.CONSTRAINT_NAME = K.CONSTRAINT_NAME WHERE C.CONSTRAINT_TYPE = \'PRIMARY KEY\' AND K.COLUMN_NAME = \'myColumnName\' AND K.TABLE_NAME = \'myTable\';'
});
});
test('createSchema', () => {
expectsql(QueryGenerator.createSchema('mySchema'), {
mssql: 'IF NOT EXISTS (SELECT schema_name FROM information_schema.schemata WHERE schema_name = \'mySchema\' ) BEGIN EXEC sp_executesql N\'CREATE SCHEMA [mySchema] ;\' END;'
});
});
test('showSchemasQuery', () => {
expectsql(QueryGenerator.showSchemasQuery(), {
mssql: 'SELECT "name" as "schema_name" FROM sys.schemas as s WHERE "s"."name" NOT IN ( \'INFORMATION_SCHEMA\', \'dbo\', \'guest\', \'sys\', \'archive\' ) AND "s"."name" NOT LIKE \'db_%\''
});
});
test('versionQuery', () => {
expectsql(QueryGenerator.versionQuery(), {
mssql: "DECLARE @ms_ver NVARCHAR(20); SET @ms_ver = REVERSE(CONVERT(NVARCHAR(20), SERVERPROPERTY('ProductVersion'))); SELECT REVERSE(SUBSTRING(@ms_ver, CHARINDEX('.', @ms_ver)+1, 20)) AS 'version'"
});
});
test('renameTableQuery', () => {
expectsql(QueryGenerator.renameTableQuery('oldTableName', 'newTableName'), {
mssql: 'EXEC sp_rename [oldTableName], [newTableName];'
});
});
test('showTablesQuery', () => {
expectsql(QueryGenerator.showTablesQuery(), {
mssql: 'SELECT TABLE_NAME, TABLE_SCHEMA FROM INFORMATION_SCHEMA.TABLES;'
});
});
test('dropTableQuery', () => {
expectsql(QueryGenerator.dropTableQuery('dirtyTable'), {
mssql: "IF OBJECT_ID('[dirtyTable]', 'U') IS NOT NULL DROP TABLE [dirtyTable];"
});
});
test('removeColumnQuery', () => {
expectsql(QueryGenerator.removeColumnQuery('myTable', 'myColumn'), {
mssql: 'ALTER TABLE [myTable] DROP COLUMN [myColumn];'
});
});
test('quoteIdentifier', () => {
expectsql(QueryGenerator.quoteIdentifier("'myTable'.'Test'"), {
mssql: '[myTable.Test]'
});
});
test('getForeignKeysQuery', () => {
expectsql(QueryGenerator.getForeignKeysQuery('myTable'), {
mssql: "SELECT constraint_name = C.CONSTRAINT_NAME FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS C WHERE C.CONSTRAINT_TYPE = 'FOREIGN KEY' AND C.TABLE_NAME = 'myTable'"
});
});
test('getForeignKeyQuery', () => {
expectsql(QueryGenerator.getForeignKeyQuery('myTable', 'myColumn'), {
mssql: "SELECT constraint_name = TC.CONSTRAINT_NAME FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS TC JOIN INFORMATION_SCHEMA.CONSTRAINT_COLUMN_USAGE CCU ON TC.CONSTRAINT_NAME = CCU.CONSTRAINT_NAME WHERE TC.CONSTRAINT_TYPE = 'FOREIGN KEY' AND TC.TABLE_NAME = 'myTable' AND CCU.COLUMN_NAME = 'myColumn'"
});
});
test('dropForeignKeyQuery', () => {
expectsql(QueryGenerator.dropForeignKeyQuery('myTable', 'myColumnKey'), {
mssql: 'ALTER TABLE [myTable] DROP [myColumnKey]'
});
});
test('arithmeticQuery', () => {
[{
title:'Should use the plus operator',
arguments: ['+', 'myTable', { foo: 'bar' }, {}, {}],
expectation: 'UPDATE myTable SET foo=foo+ \'bar\' '
},
{
title:'Should use the plus operator with where clause',
arguments: ['+', 'myTable', { foo: 'bar' }, { bar: 'biz'}, {}],
expectation: 'UPDATE myTable SET foo=foo+ \'bar\' WHERE bar = \'biz\''
},
{
title:'Should use the minus operator',
arguments: ['-', 'myTable', { foo: 'bar' }, {}, {}],
expectation: 'UPDATE myTable SET foo=foo- \'bar\' '
},
{
title:'Should use the minus operator with negative value',
arguments: ['-', 'myTable', { foo: -1 }, {}, {}],
expectation: 'UPDATE myTable SET foo=foo- -1 '
},
{
title:'Should use the minus operator with where clause',
arguments: ['-', 'myTable', { foo: 'bar' }, { bar: 'biz'}, {}],
expectation: 'UPDATE myTable SET foo=foo- \'bar\' WHERE bar = \'biz\''
}].forEach(test => {
it(test.title, () => {
expectsql(QueryGenerator.arithmeticQuery.call(QueryGenerator, test.arguments), {
mssql: test.expectation
});
});
});
});
});
}