├── .gitignore ├── .npmignore ├── README.md ├── SECURITY.md ├── package.json ├── src ├── ExpressionVisitor.js ├── booleanize.js ├── convertTypes.js ├── expressions.js ├── format.js ├── helpers.js ├── index.js ├── parseOData.js └── utilities │ ├── assert.js │ ├── errors.js │ ├── strings.js │ └── types.js └── test ├── expressions.tests.js ├── mssql.tests.js ├── parseOData.tests.js └── sqlite.tests.js /.gitignore: -------------------------------------------------------------------------------- 1 | # VS / NTVS stuff 2 | *.dat 3 | *.suo 4 | bin 5 | obj 6 | 7 | 8 | # Logs 9 | logs 10 | *.log 11 | 12 | # Runtime data 13 | pids 14 | *.pid 15 | *.seed 16 | 17 | # Directory for instrumented libs generated by jscoverage/JSCover 18 | lib-cov 19 | 20 | # Coverage directory used by tools like istanbul 21 | coverage 22 | 23 | # Grunt intermediate storage (http://gruntjs.com/creating-plugins#storing-task-files) 24 | .grunt 25 | 26 | # node-waf configuration 27 | .lock-wscript 28 | 29 | # Compiled binary addons (http://nodejs.org/api/addons.html) 30 | build/Release 31 | 32 | # Dependency directory 33 | # https://www.npmjs.org/doc/misc/npm-faq.html#should-i-check-my-node_modules-folder-into-git 34 | node_modules 35 | 36 | azureMobile.js 37 | -------------------------------------------------------------------------------- /.npmignore: -------------------------------------------------------------------------------- 1 | test 2 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # azure-odata-sql 2 | 3 | This library contains functionality to convert OData queries into SQL 4 | statements. 5 | 6 | The library uses types from the `mssql` npm package to represent parameter types. 7 | The query object is in the format produced by 8 | [azure-query-js](https://github.com/Azure/queryjs). 9 | 10 | ## Installation 11 | 12 | npm i azure-odata-sql 13 | 14 | ## Usage 15 | 16 | The library currently exports a single function: 17 | 18 | require('azure-odata-sql').format(query, tableConfig) 19 | 20 | The query parameter is an object with any of the following properties: 21 | 22 | |Property|Description| 23 | |--------|-----------| 24 | |skip|Number of rows to skip| 25 | |take|Number of rows to take| 26 | |inlineCount|Set to `allpages` to include a total count query| 27 | |resultLimit|Number of rows to limit the query to| 28 | |selections|Columns to select| 29 | |filters|Filters to apply| 30 | |ordering|Columns to sort by| 31 | |id|Record identifier| 32 | |includeDeleted|Include soft deleted columns| 33 | 34 | The tableConfig is an object with any of the following properties: 35 | 36 | |Property|Description| 37 | |--------|-----------| 38 | |name|The name of the table being queried| 39 | |schema|The database schema name for the table| 40 | |flavor|Either `mssql` or `sqlite`| 41 | |softDelete|True if the table supports soft delete with a column called `deleted`| 42 | -------------------------------------------------------------------------------- /SECURITY.md: -------------------------------------------------------------------------------- 1 | 2 | 3 | ## Security 4 | 5 | Microsoft takes the security of our software products and services seriously, which includes all source code repositories managed through our GitHub organizations, which include [Microsoft](https://github.com/microsoft), [Azure](https://github.com/Azure), [DotNet](https://github.com/dotnet), [AspNet](https://github.com/aspnet), [Xamarin](https://github.com/xamarin), and [our GitHub organizations](https://opensource.microsoft.com/). 6 | 7 | If you believe you have found a security vulnerability in any Microsoft-owned repository that meets [Microsoft's definition of a security vulnerability](https://aka.ms/opensource/security/definition), please report it to us as described below. 8 | 9 | ## Reporting Security Issues 10 | 11 | **Please do not report security vulnerabilities through public GitHub issues.** 12 | 13 | Instead, please report them to the Microsoft Security Response Center (MSRC) at [https://msrc.microsoft.com/create-report](https://aka.ms/opensource/security/create-report). 14 | 15 | If you prefer to submit without logging in, send email to [secure@microsoft.com](mailto:secure@microsoft.com). If possible, encrypt your message with our PGP key; please download it from the [Microsoft Security Response Center PGP Key page](https://aka.ms/opensource/security/pgpkey). 16 | 17 | You should receive a response within 24 hours. If for some reason you do not, please follow up via email to ensure we received your original message. Additional information can be found at [microsoft.com/msrc](https://aka.ms/opensource/security/msrc). 18 | 19 | Please include the requested information listed below (as much as you can provide) to help us better understand the nature and scope of the possible issue: 20 | 21 | * Type of issue (e.g. buffer overflow, SQL injection, cross-site scripting, etc.) 22 | * Full paths of source file(s) related to the manifestation of the issue 23 | * The location of the affected source code (tag/branch/commit or direct URL) 24 | * Any special configuration required to reproduce the issue 25 | * Step-by-step instructions to reproduce the issue 26 | * Proof-of-concept or exploit code (if possible) 27 | * Impact of the issue, including how an attacker might exploit the issue 28 | 29 | This information will help us triage your report more quickly. 30 | 31 | If you are reporting for a bug bounty, more complete reports can contribute to a higher bounty award. Please visit our [Microsoft Bug Bounty Program](https://aka.ms/opensource/security/bounty) page for more details about our active programs. 32 | 33 | ## Preferred Languages 34 | 35 | We prefer all communications to be in English. 36 | 37 | ## Policy 38 | 39 | Microsoft follows the principle of [Coordinated Vulnerability Disclosure](https://aka.ms/opensource/security/cvd). 40 | 41 | 42 | -------------------------------------------------------------------------------- /package.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "azure-odata-sql", 3 | "version": "0.2.0", 4 | "description": "Convert OData queries into SQL statements", 5 | "main": "src/index.js", 6 | "author": "Microsoft", 7 | "repository": "Azure/azure-odata-sql-js", 8 | "license": "MIT", 9 | "scripts": { 10 | "test": "npm run lint & mocha", 11 | "lint": "jshint src" 12 | }, 13 | "dependencies": { 14 | }, 15 | "devDependencies": { 16 | "chai": "^3.0.0", 17 | "jshint": "^2.9.1", 18 | "mocha": "^2.2.5" 19 | } 20 | } 21 | -------------------------------------------------------------------------------- /src/ExpressionVisitor.js: -------------------------------------------------------------------------------- 1 | // ---------------------------------------------------------------------------- 2 | // Copyright (c) Microsoft Corporation. All rights reserved. 3 | // ---------------------------------------------------------------------------- 4 | 5 | var types = require('./utilities/types'), 6 | expressions = require('./expressions'); 7 | 8 | module.exports = types.defineClass(null, { 9 | visit: function (expr) { 10 | return expr.accept(this); 11 | }, 12 | 13 | visitConstant: function (expr) { 14 | return expr; 15 | }, 16 | 17 | visitFloatConstant: function (expr) { 18 | return expr; 19 | }, 20 | 21 | visitBinary: function (expr) { 22 | var left = null; 23 | var right = null; 24 | 25 | if (expr.left !== null) { 26 | left = this.visit(expr.left); 27 | } 28 | if (expr.right !== null) { 29 | right = this.visit(expr.right); 30 | } 31 | if (left != expr.left || right != expr.right) { 32 | return new expressions.Binary(left, right, expr.expressionType); 33 | } 34 | 35 | return expr; 36 | }, 37 | 38 | visitUnary: function (expr) { 39 | var operand = this.visit(expr.operand); 40 | if (operand != expr.operand) { 41 | return new expressions.Unary(operand, expr.expressionType); 42 | } 43 | return expr; 44 | }, 45 | 46 | visitMember: function (expr) { 47 | return expr; 48 | }, 49 | 50 | visitParameter: function (expr) { 51 | return expr; 52 | }, 53 | 54 | visitFunction: function (expr) { 55 | var updated = false; 56 | 57 | var instance = expr.instance; 58 | if (expr.instance) { 59 | instance = this.visit(expr.instance); 60 | if (instance != expr.instance) { 61 | updated = true; 62 | } 63 | } 64 | 65 | var args = [expr.args.length], 66 | i = 0, 67 | self = this; 68 | expr.args.forEach(function (arg) { 69 | var newArg = self.visit(arg); 70 | args[i++] = arg; 71 | if (newArg != arg) { 72 | updated = true; 73 | } 74 | }); 75 | 76 | if (updated) { 77 | return new expressions.FunctionCall(instance, expr.memberInfo, args); 78 | } 79 | return expr; 80 | } 81 | }); 82 | -------------------------------------------------------------------------------- /src/booleanize.js: -------------------------------------------------------------------------------- 1 | // ---------------------------------------------------------------------------- 2 | // Copyright (c) Microsoft Corporation. All rights reserved. 3 | // ---------------------------------------------------------------------------- 4 | 5 | var types = require('./utilities/types'), 6 | ExpressionVisitor = require('./ExpressionVisitor'), 7 | expressions = require('./expressions'); 8 | 9 | var SqlBooleanizer = types.deriveClass(ExpressionVisitor, null, { 10 | visitUnary: function (expr) { 11 | var operand = this.visit(expr.operand); 12 | 13 | if (operand && expr.expressionType == 'Not') { 14 | // Convert expression 'x' to a boolean expression '(x = true)' since 15 | // the SQL Not operator requires a boolean expression (not a BIT) 16 | return new expressions.Unary(ensureExpressionIsBoolean(operand), 'Not'); 17 | } 18 | 19 | if (operand != expr.operand) { 20 | return new expressions.Unary(operand, expr.expressionType); 21 | } 22 | 23 | return expr; 24 | }, 25 | 26 | visitBinary: function (expr) { 27 | var left = null; 28 | var right = null; 29 | 30 | // first visit the expressions to do any sub conversions, before 31 | // doing any transformations below 32 | if (expr.left !== null) { 33 | left = this.visit(expr.left); 34 | } 35 | if (expr.right !== null) { 36 | right = this.visit(expr.right); 37 | } 38 | 39 | if ((expr.expressionType == 'And') || (expr.expressionType == 'Or')) { 40 | // both operands must be boolean expressions 41 | left = ensureExpressionIsBoolean(left); 42 | right = ensureExpressionIsBoolean(right); 43 | } 44 | else if ((expr.expressionType == 'Equal') || (expr.expressionType == 'NotEqual')) { 45 | // remove any comparisons between boolean and bit 46 | var converted = rewriteBitComparison(left, right); 47 | if (converted) { 48 | return converted; 49 | } 50 | } 51 | 52 | if (left != expr.left || right != expr.right) { 53 | return new expressions.Binary(left, right, expr.expressionType); 54 | } 55 | 56 | return expr; 57 | } 58 | }); 59 | 60 | // if a boolean expression is being compared to a bit expression, convert 61 | // by removing the comparison. E.g. (endswith('value', title) eq false) => not(endswith('value', title)) 62 | function rewriteBitComparison(left, right) { 63 | if (isBooleanExpression(left) && isBitConstant(right)) { 64 | return (right.value === true) ? left : new expressions.Unary(left, 'Not'); 65 | } 66 | else if (isBooleanExpression(right) && isBitConstant(left)) { 67 | return (left.value === true) ? right : new expressions.Unary(right, 'Not'); 68 | } 69 | 70 | // no conversion necessary 71 | return null; 72 | } 73 | 74 | // returns true if the expression is the constant 'true' or 'false' 75 | function isBitConstant(expr) { 76 | return (expr.expressionType == 'Constant') && (expr.value === true || expr.value === false); 77 | } 78 | 79 | // if the expression isn't boolean, convert to a boolean expression (e.g. (isDiscontinued) => (isDiscontinued = 1)) 80 | function ensureExpressionIsBoolean(expr) { 81 | if (!isBooleanExpression(expr)) { 82 | return new expressions.Binary(expr, new expressions.Constant(true), 'Equal'); 83 | } 84 | return expr; 85 | } 86 | 87 | function isBooleanExpression(expr) { 88 | if (!expr) { 89 | return false; 90 | } 91 | 92 | // see if this is a logical boolean expression 93 | switch (expr.expressionType) { 94 | case 'And': 95 | case 'Or': 96 | case 'GreaterThan': 97 | case 'GreaterThanOrEqual': 98 | case 'LessThan': 99 | case 'LessThanOrEqual': 100 | case 'Not': 101 | case 'Equal': 102 | case 'NotEqual': 103 | return true; 104 | default: 105 | break; 106 | } 107 | 108 | // boolean odata functions 109 | if (expr.expressionType == 'Call') { 110 | switch (expr.memberInfo.memberName) { 111 | case 'startswith': 112 | case 'endswith': 113 | case 'substringof': 114 | return true; 115 | default: 116 | break; 117 | } 118 | } 119 | 120 | return false; 121 | } 122 | 123 | module.exports = function (expr) { 124 | var booleanizer = new SqlBooleanizer(); 125 | 126 | expr = booleanizer.visit(expr); 127 | expr = ensureExpressionIsBoolean(expr); 128 | 129 | return expr; 130 | }; 131 | -------------------------------------------------------------------------------- /src/convertTypes.js: -------------------------------------------------------------------------------- 1 | // ---------------------------------------------------------------------------- 2 | // Copyright (c) Microsoft Corporation. All rights reserved. 3 | // ---------------------------------------------------------------------------- 4 | 5 | var types = require('./utilities/types'), 6 | expressions = require('./expressions'), 7 | ExpressionVisitor = require('./ExpressionVisitor'); 8 | 9 | function ctor(tableMetadata) { 10 | this.tableMetadata = tableMetadata; 11 | } 12 | 13 | var TypeConverter = types.deriveClass(ExpressionVisitor, ctor, { 14 | visitBinary: function (expr) { 15 | var left = expr.left ? this.visit(expr.left) : null; 16 | var right = expr.right ? this.visit(expr.right) : null; 17 | 18 | if (this._isStringConstant(left) && this._isBinaryMemberAccess(right)) { 19 | left.value = new Buffer(left.value, 'base64'); 20 | } 21 | else if (this._isStringConstant(right) && this._isBinaryMemberAccess(left)) { 22 | right.value = new Buffer(right.value, 'base64'); 23 | } 24 | 25 | if (left != expr.left || right != expr.right) { 26 | return new expressions.Binary(left, right, expr.expressionType); 27 | } 28 | 29 | return expr; 30 | }, 31 | 32 | _isStringConstant: function(expr) { 33 | return expr && 34 | expr.expressionType === 'Constant' && 35 | types.isString(expr.value); 36 | }, 37 | 38 | _isBinaryMemberAccess: function (expr) { 39 | return expr && 40 | expr.expressionType === 'MemberAccess' && 41 | types.isString(expr.member) && // tableConfig.binaryColumns is not currently used - hard coded __version column 42 | ((this.tableMetadata.binaryColumns && this.tableMetadata.binaryColumns.indexOf(expr.member.toLowerCase()) > -1) || expr.member.toLowerCase() === 'version'); 43 | } 44 | }); 45 | 46 | module.exports = function (expr, tableMetadata) { 47 | return new TypeConverter(tableMetadata).visit(expr); 48 | }; 49 | -------------------------------------------------------------------------------- /src/expressions.js: -------------------------------------------------------------------------------- 1 | // ---------------------------------------------------------------------------- 2 | // Copyright (c) Microsoft Corporation. All rights reserved. 3 | // ---------------------------------------------------------------------------- 4 | 5 | var types = require('./utilities/types'); 6 | 7 | var Expression = types.defineClass( 8 | null, { 9 | accept: function (visitor) { 10 | return visitor.visit(this); 11 | } 12 | }, 13 | null); 14 | 15 | module.exports = { 16 | MappedMemberInfo: types.defineClass( 17 | function (type, memberName, isStatic, isMethod) { 18 | this.type = type; 19 | this.memberName = memberName; 20 | this.isStatic = isStatic; 21 | this.isMethod = isMethod; 22 | }, null, null), 23 | 24 | Constant: types.deriveClass( 25 | Expression, 26 | function (value) { 27 | this.value = value; 28 | this.expressionType = 'Constant'; 29 | }, { 30 | accept: function (visitor) { 31 | return visitor.visitConstant(this); 32 | } 33 | }, 34 | null), 35 | 36 | FloatConstant: types.deriveClass( 37 | Expression, 38 | function (value) { 39 | this.value = value; 40 | this.expressionType = 'FloatConstant'; 41 | }, { 42 | accept: function (visitor) { 43 | return visitor.visitFloatConstant(this); 44 | } 45 | }, 46 | null), 47 | 48 | Binary: types.deriveClass( 49 | Expression, 50 | function (left, right, expressionType) { 51 | this.left = left; 52 | this.right = right; 53 | this.expressionType = expressionType; 54 | }, { 55 | accept: function (visitor) { 56 | return visitor.visitBinary(this); 57 | } 58 | }, 59 | null), 60 | 61 | Unary: types.deriveClass( 62 | Expression, 63 | function (operand, expressionType) { 64 | this.operand = operand; 65 | this.expressionType = expressionType; 66 | }, { 67 | accept: function (visitor) { 68 | return visitor.visitUnary(this); 69 | } 70 | }, 71 | null), 72 | 73 | Member: types.deriveClass( 74 | Expression, 75 | // member may be either a member name or a MappedMemberInfo 76 | function (instance, member) { 77 | this.instance = instance; 78 | this.member = member; 79 | this.expressionType = 'MemberAccess'; 80 | }, { 81 | accept: function (visitor) { 82 | return visitor.visitMember(this); 83 | } 84 | }, 85 | null), 86 | 87 | FunctionCall: types.deriveClass( 88 | Expression, 89 | function (instance, memberInfo, args) { 90 | this.instance = instance; 91 | this.memberInfo = memberInfo; 92 | this.args = args; 93 | this.expressionType = 'Call'; 94 | }, { 95 | accept: function (visitor) { 96 | return visitor.visitFunction(this); 97 | } 98 | }, 99 | null), 100 | 101 | Parameter: types.defineClass( 102 | function () { 103 | this.ExpressionType = 'Parameter'; 104 | }, { 105 | accept: function (visitor) { 106 | return visitor.visitParameter(this); 107 | } 108 | }, 109 | null), 110 | 111 | Convert: types.deriveClass( 112 | Expression, 113 | function (desiredType, operand) { 114 | this.desiredType = desiredType; 115 | this.operand = operand; 116 | this.expressionType = 'Convert'; 117 | }, { 118 | accept: function (visitor) { 119 | return visitor.visitUnary(this); 120 | } 121 | }, 122 | null) 123 | }; 124 | -------------------------------------------------------------------------------- /src/format.js: -------------------------------------------------------------------------------- 1 | // ---------------------------------------------------------------------------- 2 | // Copyright (c) Microsoft Corporation. All rights reserved. 3 | // ---------------------------------------------------------------------------- 4 | 5 | var types = require('./utilities/types'), 6 | util = require('util'), 7 | parseOData = require('./parseOData'), 8 | ExpressionVisitor = require('./ExpressionVisitor'), 9 | convertTypes = require('./convertTypes'), 10 | booleanize = require('./booleanize'), 11 | helpers = require('./helpers'), 12 | expressions = require('./expressions'); 13 | 14 | function ctor(tableConfig) { 15 | this.tableConfig = tableConfig || {}; 16 | this.flavor = this.tableConfig.flavor || 'mssql'; 17 | this.statement = { sql: '', parameters: [], multiple: true }; 18 | this.paramNumber = 0; 19 | this.parameterPrefix = 'p'; 20 | 21 | if (this.flavor !== 'sqlite') { 22 | this.schemaName = this.tableConfig.schema || 'dbo'; 23 | } 24 | } 25 | 26 | var SqlFormatter = types.deriveClass(ExpressionVisitor, ctor, { 27 | format: function (query) { 28 | // if a skip is requested but no top is defined, we need 29 | // to still generate the paging query, so default top to 30 | // max. Really when doing paging, the user should also be 31 | // specifying a top explicitly however. 32 | if (query.skip > 0 && (query.take === undefined || query.take === null)) { 33 | if (this.flavor !== 'sqlite') { 34 | query.take = 9007199254740992; // Number.MAX_SAFE_INTEGER + 1; // ES6 35 | } else { 36 | // A negative LIMIT in sqlite returns all rows. 37 | query.take = -1; 38 | } 39 | } 40 | 41 | var statements = []; 42 | 43 | this.statement.sql = this._formatQuery(query).trim(); 44 | statements.push(this.statement); 45 | 46 | if (query.inlineCount === 'allpages' || query.includeTotalCount) { 47 | this.statement = { sql: '', parameters: [], multiple: true }; 48 | this.statement.sql = this._formatCountQuery(helpers.formatTableName(this.schemaName, query.table), query).trim(); 49 | statements.push(this.statement); 50 | } 51 | 52 | return statements; 53 | }, 54 | 55 | _formatQuery: function (query) { 56 | 57 | if (this.flavor !== 'sqlite' && query.skip >= 0 && query.take >= 0 && query.skip !== null && query.take !== null) { 58 | return this._formatPagedQuery(query); 59 | } 60 | 61 | var takeClause = '', 62 | skipClause = '', 63 | whereClause = '', 64 | orderbyClause = '', 65 | limit = -1, 66 | formattedSql, 67 | selection = query.selections ? this._formatSelection(query.selections) : '*'; 68 | 69 | // set the top clause to be the minimumn of the top 70 | // and result limit values if either has been set. 71 | var resultLimit = query.resultLimit || Number.MAX_VALUE; 72 | if (query.take >= 0 && query.take !== null) { 73 | limit = Math.min(resultLimit, query.take); 74 | } else if (resultLimit != Number.MAX_VALUE) { 75 | limit = query.resultLimit; 76 | } 77 | 78 | if (this.flavor !== 'sqlite') { 79 | if (limit != -1) { 80 | takeClause = 'TOP ' + limit.toString() + ' '; 81 | } 82 | } else { 83 | if (query.skip > 0) { 84 | skipClause = ' OFFSET ' + query.skip.toString(); 85 | } 86 | 87 | // Specifiy a take clause if either skip or limit is specified. 88 | // Note: SQLite needs LIMIT for OFFSET to work. 89 | if (query.skip > 0 || limit >= 0) { 90 | takeClause = ' LIMIT ' + limit.toString(); 91 | } 92 | } 93 | 94 | var filter = this._formatFilter(query); 95 | if (filter.length > 0) { 96 | whereClause = ' WHERE ' + filter; 97 | } 98 | 99 | var ordering = this._formatOrderBy(query); 100 | if (ordering.length > 0) { 101 | orderbyClause = ' ORDER BY ' + ordering; 102 | } 103 | 104 | var tableName = helpers.formatTableName(this.schemaName, query.table); 105 | 106 | if (this.flavor !== 'sqlite') { 107 | formattedSql = util.format("SELECT %s%s FROM %s%s%s", takeClause, selection, tableName, whereClause, orderbyClause); 108 | } else { 109 | formattedSql = util.format("SELECT %s FROM %s%s%s%s%s", selection, tableName, whereClause, orderbyClause, takeClause, skipClause); 110 | } 111 | 112 | return formattedSql; 113 | }, 114 | 115 | _formatPagedQuery: function (query) { 116 | var formattedSql, selection = ''; 117 | 118 | if (query.selections) { 119 | selection = this._formatSelection(query.selections); 120 | } else { 121 | selection = "*"; 122 | } 123 | 124 | var filter = this._formatFilter(query, '(1 = 1)'); 125 | var ordering = this._formatOrderBy(query, '[id]'); 126 | 127 | // Plug all the pieces into the template to get the paging sql 128 | var tableName = helpers.formatTableName(this.schemaName, query.table); 129 | formattedSql = util.format( 130 | "SELECT %s " + 131 | "FROM %s " + 132 | "WHERE %s " + 133 | "ORDER BY %s " + 134 | "OFFSET %d ROWS FETCH NEXT %d ROWS ONLY", 135 | selection, tableName, filter, ordering, query.skip, query.take); 136 | 137 | return formattedSql; 138 | }, 139 | 140 | _formatCountQuery: function (table, query) { 141 | var filter; 142 | 143 | if (query.filters || query.id !== undefined || this.tableConfig.supportsSoftDelete) { 144 | this.statement.sql = ''; 145 | filter = this._formatFilter(query); 146 | } 147 | 148 | var sql = 'SELECT COUNT(*) AS [count] FROM ' + table; 149 | if (filter) { 150 | sql += ' WHERE ' + filter; 151 | } 152 | return sql; 153 | }, 154 | 155 | _formatOrderBy: function (query, defaultOrder) { 156 | if (!query.ordering) { 157 | return defaultOrder || ''; 158 | } 159 | 160 | var orderings = parseOData.orderBy(query.ordering), 161 | order = '', 162 | self = this; 163 | 164 | orderings.forEach(function (ordering) { 165 | if (order.length > 0) { 166 | order += ', '; 167 | } 168 | self.statement.sql = ''; 169 | self.visit(ordering.selector); 170 | if (!ordering.ascending) { 171 | self.statement.sql += ' DESC'; 172 | } 173 | order += self.statement.sql; 174 | }); 175 | 176 | return order; 177 | }, 178 | 179 | _formatSelection: function (selection, prefix) { 180 | var formattedSelection = '', 181 | columns = selection.split(','); 182 | 183 | columns.forEach(function (column) { 184 | var member = column.trim(); 185 | if (formattedSelection.length > 0) { 186 | formattedSelection += ', '; 187 | } 188 | formattedSelection += (prefix || '') + helpers.formatMember(member); 189 | }); 190 | 191 | return formattedSelection; 192 | }, 193 | 194 | _formatFilter: function (query, defaultFilter) { 195 | // if we already have a parsed filter use it, 196 | // otherwise parse the filter 197 | var filterExpr; 198 | if (query.filters && query.filters.length > 0) { 199 | filterExpr = parseOData(query.filters); 200 | } 201 | 202 | if (query.id !== undefined) { 203 | var id = this.tableConfig.hasStringId ? "'" + query.id.replace(/'/g, "''") + "'" : query.id; 204 | var idFilterExpr = parseOData(util.format('(id eq %s)', id)); 205 | 206 | // append the id filter to any existing filter 207 | if (filterExpr) { 208 | filterExpr = new expressions.Binary(filterExpr, idFilterExpr, 'And'); 209 | } 210 | else { 211 | filterExpr = idFilterExpr; 212 | } 213 | } 214 | 215 | // if soft delete is enabled filter out deleted records 216 | if (this.tableConfig.softDelete && !query.includeDeleted) { 217 | var deletedFilter = parseOData(util.format('(deleted eq false)')); 218 | if (filterExpr) { 219 | filterExpr = new expressions.Binary(filterExpr, deletedFilter, 'And'); 220 | } 221 | else { 222 | filterExpr = deletedFilter; 223 | } 224 | } 225 | 226 | if (!filterExpr) { 227 | return defaultFilter || ''; 228 | } 229 | 230 | this.statement.sql = ''; 231 | filterExpr = this._finalizeExpression(filterExpr); 232 | this.visit(filterExpr); 233 | 234 | return this.statement.sql; 235 | }, 236 | 237 | // run the final query translation pipeline on the specified 238 | // expression, modifying the expression tree as needed 239 | _finalizeExpression: function (expr) { 240 | expr = booleanize(expr); 241 | expr = convertTypes(expr, this.tableConfig); 242 | return expr; 243 | }, 244 | 245 | visitBinary: function (expr) { 246 | this.statement.sql += '('; 247 | 248 | var left = null; 249 | var right = null; 250 | 251 | // modulo requires the dividend to be an integer, monetary or numeric 252 | // rewrite the expression to convert to numeric, allowing the DB to apply 253 | // rounding if needed. our default data type for number is float which 254 | // is incompatible with modulo. 255 | if (expr.expressionType == 'Modulo') { 256 | expr.left = new expressions.Convert('numeric', expr.left); 257 | } 258 | 259 | if (expr.left) { 260 | left = this.visit(expr.left); 261 | } 262 | 263 | if (expr.right && (expr.right.value === null)) { 264 | // inequality expressions against a null literal have a special 265 | // translation in SQL 266 | if (expr.expressionType == 'Equal') { 267 | this.statement.sql += ' IS NULL'; 268 | } 269 | else if (expr.expressionType == 'NotEqual') { 270 | this.statement.sql += ' IS NOT NULL'; 271 | } 272 | } 273 | else { 274 | switch (expr.expressionType) { 275 | case 'Equal': 276 | this.statement.sql += ' = '; 277 | break; 278 | case 'NotEqual': 279 | this.statement.sql += ' != '; 280 | break; 281 | case 'LessThan': 282 | this.statement.sql += ' < '; 283 | break; 284 | case 'LessThanOrEqual': 285 | this.statement.sql += ' <= '; 286 | break; 287 | case 'GreaterThan': 288 | this.statement.sql += ' > '; 289 | break; 290 | case 'GreaterThanOrEqual': 291 | this.statement.sql += ' >= '; 292 | break; 293 | case 'And': 294 | this.statement.sql += ' AND '; 295 | break; 296 | case 'Or': 297 | this.statement.sql += ' OR '; 298 | break; 299 | case 'Concat': 300 | if (this.flavor === 'sqlite') { 301 | this.statement.sql += ' || '; 302 | } else { 303 | this.statement.sql += ' + '; 304 | } 305 | break; 306 | case 'Add': 307 | this.statement.sql += ' + '; 308 | break; 309 | case 'Subtract': 310 | this.statement.sql += ' - '; 311 | break; 312 | case 'Multiply': 313 | this.statement.sql += ' * '; 314 | break; 315 | case 'Divide': 316 | this.statement.sql += ' / '; 317 | break; 318 | case 'Modulo': 319 | this.statement.sql += ' % '; 320 | break; 321 | } 322 | 323 | if (expr.right) { 324 | right = this.visit(expr.right); 325 | } 326 | } 327 | 328 | this.statement.sql += ')'; 329 | 330 | if ((left !== expr.left) || (right !== expr.right)) { 331 | return new expressions.Binary(left, right); 332 | } 333 | 334 | return expr; 335 | }, 336 | 337 | visitConstant: function (expr) { 338 | if (expr.value === null) { 339 | this.statement.sql += 'NULL'; 340 | return expr; 341 | } 342 | 343 | this.statement.sql += this._createParameter(expr.value); 344 | 345 | return expr; 346 | }, 347 | 348 | visitFloatConstant: function (expr) { 349 | if (expr.value === null) { 350 | this.statement.sql += 'NULL'; 351 | return expr; 352 | } 353 | 354 | this.statement.sql += this._createParameter(expr.value, 'float'); 355 | 356 | return expr; 357 | }, 358 | 359 | _createParameter: function (value, type) { 360 | var parameter = { 361 | name: this.parameterPrefix + (++this.paramNumber).toString(), 362 | pos: this.paramNumber, 363 | value: value, 364 | type: type 365 | }; 366 | 367 | this.statement.parameters.push(parameter); 368 | 369 | return '@' + this.parameterPrefix + this.paramNumber.toString(); 370 | }, 371 | 372 | visitMember: function (expr) { 373 | if (typeof expr.member === 'string') { 374 | this.statement.sql += helpers.formatMember(expr.member); 375 | } 376 | else { 377 | this._formatMappedMember(expr); 378 | } 379 | 380 | return expr; 381 | }, 382 | 383 | visitUnary: function (expr) { 384 | if (expr.expressionType == 'Not') { 385 | this.statement.sql += 'NOT '; 386 | this.visit(expr.operand); 387 | } 388 | else if (expr.expressionType == 'Convert') { 389 | this.statement.sql += util.format("CONVERT(%s, ", expr.desiredType); 390 | this.visit(expr.operand); 391 | this.statement.sql += ')'; 392 | } 393 | 394 | return expr; 395 | }, 396 | 397 | visitFunction: function (expr) { 398 | if (expr.memberInfo) { 399 | this._formatMappedFunction(expr); 400 | } 401 | return expr; 402 | }, 403 | 404 | _formatMappedFunction: function (expr) { 405 | if (expr.memberInfo.type == 'string') { 406 | this._formatMappedStringMember(expr.instance, expr.memberInfo, expr.args); 407 | } 408 | else if (expr.memberInfo.type == 'date') { 409 | this._formatMappedDateMember(expr.instance, expr.memberInfo, expr.args); 410 | } 411 | else if (expr.memberInfo.type == 'math') { 412 | this._formatMappedMathMember(expr.instance, expr.memberInfo, expr.args); 413 | } 414 | }, 415 | 416 | _formatMappedMember: function (expr) { 417 | if (expr.member.type == 'string') { 418 | this._formatMappedStringMember(expr.instance, expr.member, null); 419 | } 420 | }, 421 | 422 | _formatMappedDateMember: function (instance, mappedMemberInfo, args) { 423 | var functionName = mappedMemberInfo.memberName; 424 | 425 | if (functionName == 'day') { 426 | this.statement.sql += 'DAY('; 427 | this.visit(instance); 428 | this.statement.sql += ')'; 429 | } 430 | else if (mappedMemberInfo.memberName == 'month') { 431 | this.statement.sql += 'MONTH('; 432 | this.visit(instance); 433 | this.statement.sql += ')'; 434 | } 435 | else if (mappedMemberInfo.memberName == 'year') { 436 | this.statement.sql += 'YEAR('; 437 | this.visit(instance); 438 | this.statement.sql += ')'; 439 | } 440 | else if (mappedMemberInfo.memberName == 'hour') { 441 | this.statement.sql += 'DATEPART(HOUR, '; 442 | this.visit(instance); 443 | this.statement.sql += ')'; 444 | } 445 | else if (mappedMemberInfo.memberName == 'minute') { 446 | this.statement.sql += 'DATEPART(MINUTE, '; 447 | this.visit(instance); 448 | this.statement.sql += ')'; 449 | } 450 | else if (mappedMemberInfo.memberName == 'second') { 451 | this.statement.sql += 'DATEPART(SECOND, '; 452 | this.visit(instance); 453 | this.statement.sql += ')'; 454 | } 455 | }, 456 | 457 | _formatMappedMathMember: function (instance, mappedMemberInfo, args) { 458 | var functionName = mappedMemberInfo.memberName; 459 | 460 | if (functionName == 'floor') { 461 | this.statement.sql += 'FLOOR('; 462 | this.visit(instance); 463 | this.statement.sql += ')'; 464 | } 465 | else if (functionName == 'ceiling') { 466 | this.statement.sql += 'CEILING('; 467 | this.visit(instance); 468 | this.statement.sql += ')'; 469 | } 470 | else if (functionName == 'round') { 471 | // Use the 'away from zero' midpoint rounding strategy - when 472 | // a number is halfway between two others, it is rounded toward 473 | // the nearest number that is away from zero. 474 | this.statement.sql += 'ROUND('; 475 | this.visit(instance); 476 | this.statement.sql += ', 0)'; 477 | } 478 | }, 479 | 480 | _formatMappedStringMember: function (instance, mappedMemberInfo, args) { 481 | var functionName = mappedMemberInfo.memberName; 482 | 483 | if (functionName == 'substringof') { 484 | this.statement.sql += '('; 485 | this.visit(instance); 486 | 487 | this.statement.sql += ' LIKE '; 488 | 489 | // form '%' + + '%' 490 | this.statement.sql += "('%' + "; 491 | this.visit(args[0]); 492 | this.statement.sql += " + '%')"; 493 | 494 | this.statement.sql += ')'; 495 | } 496 | else if (functionName == 'startswith') { 497 | this.statement.sql += '('; 498 | this.visit(instance); 499 | 500 | this.statement.sql += ' LIKE '; 501 | 502 | // form ' + '%' 503 | this.statement.sql += '('; 504 | this.visit(args[0]); 505 | this.statement.sql += " + '%')"; 506 | 507 | this.statement.sql += ')'; 508 | } 509 | else if (functionName == 'endswith') { 510 | this.statement.sql += '('; 511 | this.visit(instance); 512 | 513 | this.statement.sql += ' LIKE '; 514 | 515 | // form '%' + ' 516 | this.statement.sql += "('%' + "; 517 | this.visit(args[0]); 518 | this.statement.sql += ')'; 519 | 520 | this.statement.sql += ')'; 521 | } 522 | else if (functionName == 'concat') { 523 | if (this.flavor !== 'sqlite') { 524 | // Rewrite as an string addition with appropriate conversions. 525 | // Note: due to sql operator precidence, we only need to inject a 526 | // single conversion - the other will be upcast to string. 527 | if (!isConstantOfType(args[0], 'string')) { 528 | args[0] = new expressions.Convert(helpers.getSqlType(''), args[0]); 529 | } else if (!isConstantOfType(args[1], 'string')) { 530 | args[1] = new expressions.Convert(helpers.getSqlType(''), args[1]); 531 | } 532 | } 533 | var concat = new expressions.Binary(args[0], args[1], 'Concat'); 534 | this.visit(concat); 535 | } 536 | else if (functionName == 'tolower') { 537 | this.statement.sql += 'LOWER('; 538 | this.visit(instance); 539 | this.statement.sql += ')'; 540 | } 541 | else if (functionName == 'toupper') { 542 | this.statement.sql += 'UPPER('; 543 | this.visit(instance); 544 | this.statement.sql += ')'; 545 | } 546 | else if (functionName == 'length') { 547 | // special translation since SQL LEN function doesn't 548 | // preserve trailing spaces 549 | this.statement.sql += '(LEN('; 550 | this.visit(instance); 551 | this.statement.sql += " + 'X') - 1)"; 552 | } 553 | else if (functionName == 'trim') { 554 | this.statement.sql += 'LTRIM(RTRIM('; 555 | this.visit(instance); 556 | this.statement.sql += '))'; 557 | } 558 | else if (functionName == 'indexof') { 559 | if (this.flavor === 'sqlite') { 560 | this.statement.sql += "(INSTR("; 561 | this.visit(instance); 562 | this.statement.sql += ", "; 563 | this.visit(args[0]); 564 | this.statement.sql += ') - 1)'; 565 | } else { 566 | this.statement.sql += "(PATINDEX('%' + "; 567 | this.visit(args[0]); 568 | this.statement.sql += " + '%', "; 569 | this.visit(instance); 570 | this.statement.sql += ') - 1)'; 571 | } 572 | } 573 | else if (functionName == 'replace') { 574 | this.statement.sql += "REPLACE("; 575 | this.visit(instance); 576 | this.statement.sql += ", "; 577 | this.visit(args[0]); 578 | this.statement.sql += ", "; 579 | this.visit(args[1]); 580 | this.statement.sql += ')'; 581 | } 582 | else if (functionName == 'substring') { 583 | if (this.flavor === 'sqlite') { 584 | this.statement.sql += 'SUBSTR('; 585 | } else { 586 | this.statement.sql += 'SUBSTRING('; 587 | } 588 | this.visit(instance); 589 | 590 | this.statement.sql += ", "; 591 | this.visit(args[0]); 592 | this.statement.sql += " + 1, "; // need to add 1 since SQL is 1 based, but OData is zero based 593 | 594 | if (args.length == 1) { 595 | // Overload not taking an explicit length. The 596 | // LEN of the entire expression is used in this case 597 | // which means everything after the start index will 598 | // be taken. 599 | this.statement.sql += 'LEN('; 600 | this.visit(instance); 601 | this.statement.sql += ')'; 602 | } 603 | else if (args.length == 2) { 604 | // overload taking a length 605 | this.visit(args[1]); 606 | } 607 | 608 | this.statement.sql += ')'; 609 | } 610 | } 611 | }); 612 | 613 | function isConstantOfType(expr, type) { 614 | return (expr.expressionType == 'Constant') && (typeof expr.value === type); 615 | } 616 | 617 | // query should be in the format as generated by query.js toOData function 618 | module.exports = function (query, tableConfig) { 619 | query.table = (tableConfig && (tableConfig.containerName || tableConfig.databaseTableName || tableConfig.name)) || query.table; 620 | var formatter = new SqlFormatter(tableConfig); 621 | return formatter.format(query); 622 | }; 623 | 624 | module.exports.filter = function (query, parameterPrefix, tableConfig) { 625 | var formatter = new SqlFormatter(tableConfig); 626 | formatter.parameterPrefix = parameterPrefix || 'p'; 627 | formatter._formatFilter(query); 628 | return formatter.statement; 629 | }; 630 | -------------------------------------------------------------------------------- /src/helpers.js: -------------------------------------------------------------------------------- 1 | // ---------------------------------------------------------------------------- 2 | // Copyright (c) Microsoft Corporation. All rights reserved. 3 | // ---------------------------------------------------------------------------- 4 | 5 | var types = require('./utilities/types'), 6 | strings = require('./utilities/strings'); 7 | 8 | var helpers = module.exports = { 9 | // Performs the following validations on the specified identifier: 10 | // - first char is alphabetic or an underscore 11 | // - all other characters are alphanumeric or underscore 12 | // - the identifier is LTE 128 in length 13 | isValidIdentifier: function (identifier) { 14 | if (!identifier || !types.isString(identifier) || identifier.length > 128) { 15 | return false; 16 | } 17 | 18 | for (var i = 0; i < identifier.length; i++) { 19 | var char = identifier[i]; 20 | if (i === 0) { 21 | if (!(strings.isLetter(char) || (char == '_'))) { 22 | return false; 23 | } 24 | } else { 25 | if (!(strings.isLetter(char) || strings.isDigit(char) || (char == '_'))) { 26 | return false; 27 | } 28 | } 29 | } 30 | 31 | return true; 32 | }, 33 | 34 | validateIdentifier: function (identifier) { 35 | if (!this.isValidIdentifier(identifier)) { 36 | throw new Error(identifier + " is not a valid identifier. Identifiers must be under 128 characters in length, start with a letter or underscore, and can contain only alpha-numeric and underscore characters."); 37 | } 38 | }, 39 | 40 | formatTableName: function (schemaName, tableName) { 41 | 42 | this.validateIdentifier(tableName); 43 | 44 | if (schemaName !== undefined) { 45 | schemaName = module.exports.formatSchemaName(schemaName); 46 | this.validateIdentifier(schemaName); 47 | return '[' + schemaName + '].[' + tableName + ']'; 48 | } 49 | 50 | return '[' + tableName + ']'; 51 | }, 52 | 53 | formatSchemaName: function (appName) { 54 | // Hyphens are not supported in schema names 55 | return appName.replace(/-/g, '_'); 56 | }, 57 | 58 | formatMember: function (memberName) { 59 | this.validateIdentifier(memberName); 60 | return '[' + memberName + ']'; 61 | }, 62 | 63 | getSqlType: function (value, primaryKey) { 64 | if(value === undefined || value === null) 65 | throw new Error('Cannot create column for null or undefined value'); 66 | 67 | switch (value.constructor) { 68 | case String: 69 | // 900 bytes is the maximum length for a primary key - http://stackoverflow.com/questions/10555642/varcharmax-column-not-allowed-to-be-a-primary-key-in-sql-server 70 | return primaryKey ? "NVARCHAR(255)" : "NVARCHAR(MAX)"; 71 | case Number: 72 | return primaryKey ? "INT" : "FLOAT(53)"; 73 | case Boolean: 74 | return "BIT"; 75 | case Date: 76 | return "DATETIMEOFFSET(7)"; 77 | default: 78 | throw new Error("Unable to map value " + value.toString() + " to a SQL type."); 79 | } 80 | }, 81 | 82 | getPredefinedColumnType: function (value) { 83 | switch(value) { 84 | case 'string': 85 | return 'NVARCHAR(MAX)'; 86 | case 'number': 87 | return 'FLOAT(53)'; 88 | case 'boolean': 89 | case 'bool': 90 | return 'BIT'; 91 | case 'datetime': 92 | case 'date': 93 | return 'DATETIMEOFFSET(7)'; 94 | } 95 | 96 | throw new Error('Unrecognised column type: ' + value); 97 | }, 98 | 99 | getPredefinedType: function (value) { 100 | switch(value) { 101 | case 'nvarchar': 102 | return 'string'; 103 | case 'float': 104 | return 'number'; 105 | case 'bit': 106 | return 'boolean'; 107 | case 'datetimeoffset': 108 | return 'datetime'; 109 | case 'timestamp': 110 | return 'string'; 111 | default: 112 | return value; 113 | } 114 | }, 115 | 116 | getSystemPropertiesDDL: function () { 117 | return { 118 | version: 'version ROWVERSION NOT NULL', 119 | createdAt: 'createdAt DATETIMEOFFSET(7) NOT NULL DEFAULT CONVERT(DATETIMEOFFSET(7),SYSUTCDATETIME(),0)', 120 | updatedAt: 'updatedAt DATETIMEOFFSET(7) NOT NULL DEFAULT CONVERT(DATETIMEOFFSET(7),SYSUTCDATETIME(),0)', 121 | deleted: 'deleted bit NOT NULL DEFAULT 0' 122 | }; 123 | }, 124 | 125 | getSystemProperties: function () { 126 | return Object.keys(helpers.getSystemPropertiesDDL()); 127 | }, 128 | 129 | isSystemProperty: function (property) { 130 | return helpers.getSystemProperties().some(function (systemProperty) { return property === systemProperty; }); 131 | }, 132 | }; 133 | -------------------------------------------------------------------------------- /src/index.js: -------------------------------------------------------------------------------- 1 | // ---------------------------------------------------------------------------- 2 | // Copyright (c) Microsoft Corporation. All rights reserved. 3 | // ---------------------------------------------------------------------------- 4 | var format = require('./format'); 5 | 6 | module.exports = { 7 | format: format 8 | }; 9 | -------------------------------------------------------------------------------- /src/parseOData.js: -------------------------------------------------------------------------------- 1 | // ---------------------------------------------------------------------------- 2 | // Copyright (c) Microsoft Corporation. All rights reserved. 3 | // ---------------------------------------------------------------------------- 4 | 5 | var util = require('util'), 6 | types = require('./utilities/types'), 7 | strings = require('./utilities/strings'), 8 | expressions = require('./expressions'); 9 | 10 | function ctor(expression) { 11 | this.keywords = this._createKeywords(); 12 | 13 | // define the default root parameter for all member expressions 14 | this.it = new expressions.Parameter(); 15 | 16 | this.text = expression; 17 | this.textLen = this.text.length; 18 | this.token = {}; 19 | this._setTextPos(0); 20 | this._nextToken(); 21 | } 22 | 23 | var ODataParser = types.defineClass(ctor, { 24 | parse: function () { 25 | var expr = this._parseExpression(); 26 | 27 | this._validateToken('End', 'Syntax error'); 28 | return expr; 29 | }, 30 | 31 | parseOrdering: function () { 32 | var orderings = []; 33 | while (true) { 34 | var expr = this._parseExpression(); 35 | var ascending = true; 36 | if (this._tokenIdentifierIs('asc')) { 37 | this._nextToken(); 38 | } 39 | else if (this._tokenIdentifierIs('desc')) { 40 | this._nextToken(); 41 | ascending = false; 42 | } 43 | orderings.push({ 44 | selector: expr, 45 | ascending: ascending 46 | }); 47 | if (this.token.id != 'Comma') { 48 | break; 49 | } 50 | this._nextToken(); 51 | } 52 | this._validateToken('End', 'Syntax error'); 53 | return orderings; 54 | }, 55 | 56 | _tokenIdentifierIs: function (id) { 57 | return this.token.id == 'Identifier' && id == this.token.text; 58 | }, 59 | 60 | _parseExpression: function () { 61 | return this._parseLogicalOr(); 62 | }, 63 | 64 | // 'or' operator 65 | _parseLogicalOr: function () { 66 | var left = this._parseLogicalAnd(); 67 | while (this.token.id == 'Or') { 68 | this._nextToken(); 69 | var right = this._parseLogicalAnd(); 70 | left = new expressions.Binary(left, right, 'Or'); 71 | } 72 | return left; 73 | }, 74 | 75 | // 'and' operator 76 | _parseLogicalAnd: function () { 77 | var left = this._parseComparison(); 78 | while (this.token.id == 'And') { 79 | this._nextToken(); 80 | var right = this._parseComparison(); 81 | left = new expressions.Binary(left, right, 'And'); 82 | } 83 | return left; 84 | }, 85 | 86 | _parseComparison: function () { 87 | var left = this._parseAdditive(); 88 | while (this.token.id == 'Equal' || this.token.id == 'NotEqual' || this.token.id == 'GreaterThan' || 89 | this.token.id == 'GreaterThanEqual' || this.token.id == 'LessThan' || this.token.id == 'LessThanEqual') { 90 | 91 | var opId = this.token.id; 92 | this._nextToken(); 93 | var right = this._parseAdditive(); 94 | 95 | switch (opId) { 96 | case 'Equal': 97 | left = new expressions.Binary(left, right, 'Equal'); 98 | break; 99 | case 'NotEqual': 100 | left = new expressions.Binary(left, right, 'NotEqual'); 101 | break; 102 | case 'GreaterThan': 103 | left = new expressions.Binary(left, right, 'GreaterThan'); 104 | break; 105 | case 'GreaterThanEqual': 106 | left = new expressions.Binary(left, right, 'GreaterThanOrEqual'); 107 | break; 108 | case 'LessThan': 109 | left = new expressions.Binary(left, right, 'LessThan'); 110 | break; 111 | case 'LessThanEqual': 112 | left = new expressions.Binary(left, right, 'LessThanOrEqual'); 113 | break; 114 | } 115 | } 116 | return left; 117 | }, 118 | 119 | // 'add','sub' operators 120 | _parseAdditive: function () { 121 | var left = this._parseMultiplicative(); 122 | while (this.token.id == 'Add' || this.token.id == 'Sub') { 123 | var opId = this.token.id; 124 | this._nextToken(); 125 | var right = this._parseMultiplicative(); 126 | switch (opId) { 127 | case 'Add': 128 | left = new expressions.Binary(left, right, 'Add'); 129 | break; 130 | case 'Sub': 131 | left = new expressions.Binary(left, right, 'Subtract'); 132 | break; 133 | } 134 | } 135 | return left; 136 | }, 137 | 138 | // 'mul', 'div', 'mod' operators 139 | _parseMultiplicative: function () { 140 | var left = this._parseUnary(); 141 | while (this.token.id == 'Multiply' || this.token.id == 'Divide' || 142 | this.token.id == 'Modulo') { 143 | var opId = this.token.id; 144 | this._nextToken(); 145 | var right = this._parseUnary(); 146 | switch (opId) { 147 | case 'Multiply': 148 | left = new expressions.Binary(left, right, 'Multiply'); 149 | break; 150 | case 'Divide': 151 | left = new expressions.Binary(left, right, 'Divide'); 152 | break; 153 | case 'Modulo': 154 | left = new expressions.Binary(left, right, 'Modulo'); 155 | break; 156 | } 157 | } 158 | return left; 159 | }, 160 | 161 | // -, 'not' unary operators 162 | _parseUnary: function () { 163 | if (this.token.id == 'Minus' || this.token.id == 'Not') { 164 | var opId = this.token.id; 165 | var opPos = this.token.pos; 166 | this._nextToken(); 167 | if (opId == 'Minus' && (this.token.id == 'IntegerLiteral' || 168 | this.token.id == 'RealLiteral')) { 169 | this.token.text = "-" + this.token.text; 170 | this.token.pos = opPos; 171 | return this._parsePrimary(); 172 | } 173 | 174 | var expr = this._parseUnary(); 175 | if (opId == 'Minus') { 176 | expr = new expressions.Unary(expr, 'Negate'); 177 | } else { 178 | expr = new expressions.Unary(expr, 'Not'); 179 | } 180 | return expr; 181 | } 182 | return this._parsePrimary(); 183 | }, 184 | 185 | _parsePrimary: function () { 186 | var expr = this._parsePrimaryStart(); 187 | while (true) { 188 | if (this.token.id == 'Dot') { 189 | this._nextToken(); 190 | expr = this._parseMemberAccess(expr); 191 | } 192 | else { 193 | break; 194 | } 195 | } 196 | return expr; 197 | }, 198 | 199 | _parseMemberAccess: function (instance) { 200 | var errorPos = this.token.pos; 201 | var id = this._getIdentifier(); 202 | this._nextToken(); 203 | if (this.token.id == 'OpenParen') { 204 | var mappedFunction = this._mapFunction(id); 205 | if (mappedFunction !== null) { 206 | return this._parseMappedFunction(mappedFunction, errorPos); 207 | } 208 | else { 209 | throw this._parseError(util.format("Unknown identifier '%s'", id), errorPos); 210 | } 211 | } 212 | else { 213 | return new expressions.Member(instance, id); 214 | } 215 | }, 216 | 217 | _parseMappedFunction: function (mappedMember, errorPos) { 218 | var mappedMemberName = mappedMember.memberName; 219 | var args; 220 | var instance = null; 221 | 222 | this._beginValidateFunction(mappedMemberName, errorPos); 223 | 224 | if (this.token.id == 'OpenParen') { 225 | args = this._parseArgumentList(); 226 | 227 | this._completeValidateFunction(mappedMemberName, args); 228 | 229 | if (mappedMember.mapParams) { 230 | mappedMember.mapParams(args); 231 | } 232 | 233 | // static methods need to include the target 234 | if (!mappedMember.isStatic) { 235 | if (args.length === 0) { 236 | throw this._parseError( 237 | util.format("No applicable method '%s' exists in type '%s'", mappedMember.memberName, mappedMember.type), errorPos); 238 | } 239 | 240 | instance = args[0]; 241 | args = args.slice(1); 242 | } 243 | else { 244 | instance = null; 245 | } 246 | } 247 | else { 248 | // if it is a function it should begin with a '(' 249 | throw this._parseError("'(' expected"); 250 | } 251 | 252 | if (mappedMember.isMethod) { 253 | // a mapped function 254 | return new expressions.FunctionCall(instance, mappedMember, args); 255 | } 256 | else { 257 | // a mapped Property/Field 258 | return new expressions.Member(instance, mappedMember); 259 | } 260 | }, 261 | 262 | _beginValidateFunction: function (functionName, errorPos) { 263 | if (functionName === 'replace') { 264 | // Security: nested calls to replace must be prevented to avoid an exploit 265 | // wherein the client can force the server to allocate arbitrarily large 266 | // strings. 267 | if (this.inStringReplace) { 268 | throw this._parseError("Calls to 'replace' cannot be nested.", errorPos); 269 | } 270 | this.inStringReplace = true; 271 | } 272 | }, 273 | 274 | _completeValidateFunction: function (functionName, functionArgs, errorPos) { 275 | // validate parameters 276 | switch (functionName) { 277 | case 'day': 278 | case 'month': 279 | case 'year': 280 | case 'hour': 281 | case 'minute': 282 | case 'second': 283 | case 'floor': 284 | case 'ceiling': 285 | case 'round': 286 | case 'tolower': 287 | case 'toupper': 288 | case 'length': 289 | case 'trim': 290 | this._validateFunctionParameters(functionName, functionArgs, 1); 291 | break; 292 | case 'substringof': 293 | case 'startswith': 294 | case 'endswith': 295 | case 'concat': 296 | case 'indexof': 297 | this._validateFunctionParameters(functionName, functionArgs, 2); 298 | break; 299 | case 'replace': 300 | this._validateFunctionParameters(functionName, functionArgs, 3); 301 | // Security: we limit the replacement value to avoid an exploit 302 | // wherein the client can force the server to allocate arbitrarily large 303 | // strings. 304 | var replaceArg = functionArgs[2]; 305 | if ((replaceArg.expressionType !== 'Constant') || (replaceArg.value.length > 100)) { 306 | throw this._parseError("The third parameter to 'replace' must be a string constant less than 100 in length.", errorPos); 307 | } 308 | break; 309 | case 'substring': 310 | if (functionArgs.length != 2 && functionArgs.length != 3) { 311 | throw new Error("Function 'substring' requires 2 or 3 parameters."); 312 | } 313 | break; 314 | } 315 | 316 | this.inStringReplace = false; 317 | }, 318 | 319 | _validateFunctionParameters: function (functionName, args, expectedArgCount) { 320 | if (args.length !== expectedArgCount) { 321 | var error = util.format("Function '%s' requires %d %s", 322 | functionName, expectedArgCount, (expectedArgCount > 1) ? "parameters." : "parameter."); 323 | throw new Error(error); 324 | } 325 | }, 326 | 327 | _parseArgumentList: function () { 328 | this._validateToken('OpenParen', "'(' expected"); 329 | this._nextToken(); 330 | var args = this.token.id != 'CloseParen' ? this._parseArguments() : []; 331 | this._validateToken('CloseParen', "')' or ',' expected"); 332 | this._nextToken(); 333 | return args; 334 | }, 335 | 336 | _parseArguments: function () { 337 | var args = []; 338 | while (true) { 339 | args.push(this._parseExpression()); 340 | if (this.token.id != 'Comma') { 341 | break; 342 | } 343 | this._nextToken(); 344 | } 345 | return args; 346 | }, 347 | 348 | _mapFunction: function (functionName) { 349 | var mappedMember = this._mapStringFunction(functionName); 350 | if (mappedMember !== null) { 351 | return mappedMember; 352 | } 353 | 354 | mappedMember = this._mapDateFunction(functionName); 355 | if (mappedMember !== null) { 356 | return mappedMember; 357 | } 358 | 359 | mappedMember = this._mapMathFunction(functionName); 360 | if (mappedMember !== null) { 361 | return mappedMember; 362 | } 363 | 364 | return null; 365 | }, 366 | 367 | _mapStringFunction: function (functionName) { 368 | if (functionName == 'startswith') { 369 | return new expressions.MappedMemberInfo('string', functionName, false, true); 370 | } 371 | else if (functionName == 'endswith') { 372 | return new expressions.MappedMemberInfo('string', functionName, false, true); 373 | } 374 | else if (functionName == 'length') { 375 | return new expressions.MappedMemberInfo('string', functionName, false, false); 376 | } 377 | else if (functionName == 'toupper') { 378 | return new expressions.MappedMemberInfo('string', functionName, false, true); 379 | } 380 | else if (functionName == 'tolower') { 381 | return new expressions.MappedMemberInfo('string', functionName, false, true); 382 | } 383 | else if (functionName == 'trim') { 384 | return new expressions.MappedMemberInfo('string', functionName, false, true); 385 | } 386 | else if (functionName == 'substringof') { 387 | var memberInfo = new expressions.MappedMemberInfo('string', functionName, false, true); 388 | memberInfo.mapParams = function (args) { 389 | // reverse the order of arguments for string.Contains 390 | var tmp = args[0]; 391 | args[0] = args[1]; 392 | args[1] = tmp; 393 | }; 394 | return memberInfo; 395 | } 396 | else if (functionName == 'indexof') { 397 | return new expressions.MappedMemberInfo('string', functionName, false, true); 398 | } 399 | else if (functionName == 'replace') { 400 | return new expressions.MappedMemberInfo('string', functionName, false, true); 401 | } 402 | else if (functionName == 'substring') { 403 | return new expressions.MappedMemberInfo('string', functionName, false, true); 404 | } 405 | else if (functionName == 'trim') { 406 | return new expressions.MappedMemberInfo('string', functionName, false, true); 407 | } 408 | else if (functionName == 'concat') { 409 | return new expressions.MappedMemberInfo('string', functionName, true, true); 410 | } 411 | 412 | return null; 413 | }, 414 | 415 | _mapDateFunction: function (functionName) { 416 | if (functionName == 'day') { 417 | return new expressions.MappedMemberInfo('date', functionName, false, true); 418 | } 419 | else if (functionName == 'month') { 420 | return new expressions.MappedMemberInfo('date', functionName, false, true); 421 | } 422 | else if (functionName == 'year') { 423 | return new expressions.MappedMemberInfo('date', functionName, false, true); 424 | } 425 | if (functionName == 'hour') { 426 | return new expressions.MappedMemberInfo('date', functionName, false, true); 427 | } 428 | else if (functionName == 'minute') { 429 | return new expressions.MappedMemberInfo('date', functionName, false, true); 430 | } 431 | else if (functionName == 'second') { 432 | return new expressions.MappedMemberInfo('date', functionName, false, true); 433 | } 434 | return null; 435 | }, 436 | 437 | _mapMathFunction: function (functionName) { 438 | if (functionName == 'floor') { 439 | return new expressions.MappedMemberInfo('math', functionName, false, true); 440 | } 441 | else if (functionName == 'ceiling') { 442 | return new expressions.MappedMemberInfo('math', functionName, false, true); 443 | } 444 | else if (functionName == 'round') { 445 | return new expressions.MappedMemberInfo('math', functionName, false, true); 446 | } 447 | return null; 448 | }, 449 | 450 | _getIdentifier: function () { 451 | this._validateToken('Identifier', 'Identifier expected'); 452 | return this.token.text; 453 | }, 454 | 455 | _parsePrimaryStart: function () { 456 | switch (this.token.id) { 457 | case 'Identifier': 458 | return this._parseIdentifier(); 459 | case 'StringLiteral': 460 | return this._parseStringLiteral(); 461 | case 'IntegerLiteral': 462 | return this._parseIntegerLiteral(); 463 | case 'RealLiteral': 464 | return this._parseRealLiteral(); 465 | case 'OpenParen': 466 | return this._parseParenExpression(); 467 | default: 468 | throw this._parseError('Expression expected'); 469 | } 470 | }, 471 | 472 | _parseIntegerLiteral: function () { 473 | this._validateToken('IntegerLiteral'); 474 | var text = this.token.text; 475 | 476 | // parseInt will return the integer portion of the string, and won't 477 | // error on something like '1234xyz'. 478 | var value = parseInt(text, 10); 479 | if (isNaN(value) || (value != text)) { 480 | throw this._parseError(util.format("Invalid integer literal '%s'", text)); 481 | } 482 | 483 | this._nextToken(); 484 | if (this.token.text.toUpperCase() == 'L') { 485 | // in JS there is only one type of integer number, so this code is only here 486 | // to parse the OData 'L/l' correctly 487 | this._nextToken(); 488 | return new expressions.Constant(value); 489 | } 490 | return new expressions.Constant(value); 491 | }, 492 | 493 | _parseRealLiteral: function () { 494 | this._validateToken('RealLiteral'); 495 | var text = this.token.text; 496 | 497 | var last = text.slice(-1); 498 | if (last.toUpperCase() == 'F' || last.toUpperCase() == 'M' || last.toUpperCase() == 'D') { 499 | // in JS there is only one floating point type, 500 | // so terminating F/f, M/m, D/d have no effect. 501 | text = text.slice(0, -1); 502 | } 503 | 504 | var value = parseFloat(text); 505 | 506 | if (isNaN(value) || (value != text)) { 507 | throw this._parseError(util.format("Invalid real literal '%s'", text)); 508 | } 509 | 510 | this._nextToken(); 511 | return new expressions.FloatConstant(value); 512 | }, 513 | 514 | _parseParenExpression: function () { 515 | this._validateToken('OpenParen', "'(' expected"); 516 | this._nextToken(); 517 | var e = this._parseExpression(); 518 | this._validateToken('CloseParen', "')' or operator expected"); 519 | this._nextToken(); 520 | return e; 521 | }, 522 | 523 | _parseIdentifier: function () { 524 | this._validateToken('Identifier'); 525 | var value = this.keywords[this.token.text]; 526 | if (value) { 527 | // type construction has the format of type'value' e.g. datetime'2001-04-01T00:00:00Z' 528 | // therefore if the next character is a single quote then we try to 529 | // interpret this as type construction else its a normal member access 530 | if (typeof value === 'string' && this.ch == '\'') { 531 | return this._parseTypeConstruction(value); 532 | } 533 | else if (typeof value !== 'string') { // this is a constant 534 | this._nextToken(); 535 | return value; 536 | } 537 | } 538 | 539 | if (this.it !== null) { 540 | return this._parseMemberAccess(this.it); 541 | } 542 | 543 | throw this._parseError(util.format("Unknown identifier '%s'", this.token.text)); 544 | }, 545 | 546 | _parseTypeConstruction: function (type) { 547 | var typeIdentifier = this.token.text; 548 | var errorPos = this.token.pos; 549 | this._nextToken(); 550 | var typeExpression = null; 551 | 552 | if (this.token.id == 'StringLiteral') { 553 | errorPos = this.token.pos; 554 | var stringExpr = this._parseStringLiteral(); 555 | var literalValue = stringExpr.value; 556 | var date = null; 557 | 558 | try { 559 | if (type == 'datetime') { 560 | date = strings.parseISODate(literalValue); 561 | if (date) { 562 | typeExpression = new expressions.Constant(date); 563 | } 564 | } 565 | else if (type == 'datetimeoffset') { 566 | date = strings.parseDateTimeOffset(literalValue); 567 | if (date) { 568 | typeExpression = new expressions.Constant(date); 569 | } 570 | } 571 | } 572 | catch (e) { 573 | throw this._parseError(e, errorPos); 574 | } 575 | } 576 | 577 | if (!typeExpression) { 578 | throw this._parseError(util.format("Invalid '%s' type creation expression", typeIdentifier), errorPos); 579 | } 580 | 581 | return typeExpression; 582 | }, 583 | 584 | _parseStringLiteral: function () { 585 | this._validateToken('StringLiteral'); 586 | // Unwrap string (remove surrounding quotes) and unwrap escaped quotes. 587 | var s = this.token.text.substr(1, this.token.text.length - 2).replace(/''/g, "'"); 588 | 589 | this._nextToken(); 590 | return new expressions.Constant(s); 591 | }, 592 | 593 | _validateToken: function (tokenId, error) { 594 | if (this.token.id != tokenId) { 595 | throw this._parseError(error || 'Syntax error'); 596 | } 597 | }, 598 | 599 | _createKeywords: function () { 600 | return { 601 | "true": new expressions.Constant(true), 602 | "false": new expressions.Constant(false), 603 | "null": new expressions.Constant(null), 604 | 605 | // type keywords 606 | datetime: 'datetime', 607 | datetimeoffset: 'datetimeoffset' 608 | }; 609 | }, 610 | 611 | _setTextPos: function (pos) { 612 | this.textPos = pos; 613 | this.ch = this.textPos < this.textLen ? this.text[this.textPos] : '\\0'; 614 | }, 615 | 616 | _nextToken: function () { 617 | while (this._isWhiteSpace(this.ch)) { 618 | this._nextChar(); 619 | } 620 | var t; // TokenId 621 | var tokenPos = this.textPos; 622 | switch (this.ch) { 623 | case '(': 624 | this._nextChar(); 625 | t = 'OpenParen'; 626 | break; 627 | case ')': 628 | this._nextChar(); 629 | t = 'CloseParen'; 630 | break; 631 | case ',': 632 | this._nextChar(); 633 | t = 'Comma'; 634 | break; 635 | case '-': 636 | this._nextChar(); 637 | t = 'Minus'; 638 | break; 639 | case '/': 640 | this._nextChar(); 641 | t = 'Dot'; 642 | break; 643 | case '\'': 644 | var quote = this.ch; 645 | do { 646 | this._nextChar(); 647 | while (this.textPos < this.textLen && this.ch != quote) { 648 | this._nextChar(); 649 | } 650 | 651 | if (this.textPos == this.textLen) { 652 | throw this._parseError("Unterminated string literal", this.textPos); 653 | } 654 | this._nextChar(); 655 | } 656 | while (this.ch == quote); 657 | t = 'StringLiteral'; 658 | break; 659 | default: 660 | if (this._isIdentifierStart(this.ch) || this.ch == '@' || this.ch == '_') { 661 | do { 662 | this._nextChar(); 663 | } 664 | while (this._isIdentifierPart(this.ch) || this.ch == '_'); 665 | t = 'Identifier'; 666 | break; 667 | } 668 | if (strings.isDigit(this.ch)) { 669 | t = 'IntegerLiteral'; 670 | do { 671 | this._nextChar(); 672 | } 673 | while (strings.isDigit(this.ch)); 674 | if (this.ch == '.') { 675 | t = 'RealLiteral'; 676 | this._nextChar(); 677 | this._validateDigit(); 678 | do { 679 | this._nextChar(); 680 | } 681 | while (strings.isDigit(this.ch)); 682 | } 683 | if (this.ch == 'E' || this.ch == 'e') { 684 | t = 'RealLiteral'; 685 | this._nextChar(); 686 | if (this.ch == '+' || this.ch == '-') { 687 | this._nextChar(); 688 | } 689 | this._validateDigit(); 690 | do { 691 | this._nextChar(); 692 | } 693 | while (strings.isDigit(this.ch)); 694 | } 695 | if (this.ch == 'F' || this.ch == 'f' || this.ch == 'M' || this.ch == 'm' || this.ch == 'D' || this.ch == 'd') { 696 | t = 'RealLiteral'; 697 | this._nextChar(); 698 | } 699 | break; 700 | } 701 | if (this.textPos == this.textLen) { 702 | t = 'End'; 703 | break; 704 | } 705 | throw this._parseError("Syntax error '" + this.ch + "'", this.textPos); 706 | } 707 | this.token.id = t; 708 | this.token.text = this.text.substr(tokenPos, this.textPos - tokenPos); 709 | this.token.pos = tokenPos; 710 | 711 | this.token.id = this._reclassifyToken(this.token); 712 | }, 713 | 714 | _reclassifyToken: function (token) { 715 | if (token.id == 'Identifier') { 716 | if (token.text == "or") { 717 | return 'Or'; 718 | } 719 | else if (token.text == "add") { 720 | return 'Add'; 721 | } 722 | else if (token.text == "and") { 723 | return 'And'; 724 | } 725 | else if (token.text == "div") { 726 | return 'Divide'; 727 | } 728 | else if (token.text == "sub") { 729 | return 'Sub'; 730 | } 731 | else if (token.text == "mul") { 732 | return 'Multiply'; 733 | } 734 | else if (token.text == "mod") { 735 | return 'Modulo'; 736 | } 737 | else if (token.text == "ne") { 738 | return 'NotEqual'; 739 | } 740 | else if (token.text == "not") { 741 | return 'Not'; 742 | } 743 | else if (token.text == "le") { 744 | return 'LessThanEqual'; 745 | } 746 | else if (token.text == "lt") { 747 | return 'LessThan'; 748 | } 749 | else if (token.text == "eq") { 750 | return 'Equal'; 751 | } 752 | else if (token.text == "ge") { 753 | return 'GreaterThanEqual'; 754 | } 755 | else if (token.text == "gt") { 756 | return 'GreaterThan'; 757 | } 758 | } 759 | 760 | return token.id; 761 | }, 762 | 763 | _nextChar: function () { 764 | if (this.textPos < this.textLen) { 765 | this.textPos++; 766 | } 767 | this.ch = this.textPos < this.textLen ? this.text[this.textPos] : '\\0'; 768 | }, 769 | 770 | _isWhiteSpace: function (ch) { 771 | return (/\s/).test(ch); 772 | }, 773 | 774 | _validateDigit: function () { 775 | if (!strings.isDigit(this.ch)) { 776 | throw this._parseError('Digit expected', this.textPos); 777 | } 778 | }, 779 | 780 | _parseError: function (error, pos) { 781 | pos = pos || this.token.pos || 0; 782 | return new Error(error + ' (at index ' + pos + ')'); 783 | }, 784 | 785 | _isIdentifierStart: function (ch) { 786 | return strings.isLetter(ch); 787 | }, 788 | 789 | _isIdentifierPart: function (ch) { 790 | if (this._isIdentifierStart(ch)) { 791 | return true; 792 | } 793 | 794 | if (strings.isDigit(ch)) { 795 | return true; 796 | } 797 | 798 | if (ch == '_' || ch == '-') { 799 | return true; 800 | } 801 | 802 | return false; 803 | } 804 | }); 805 | 806 | module.exports = function (predicate) { 807 | return new ODataParser(predicate).parse(); 808 | }; 809 | 810 | module.exports.orderBy = function (ordering) { 811 | return new ODataParser(ordering).parseOrdering(); 812 | }; 813 | -------------------------------------------------------------------------------- /src/utilities/assert.js: -------------------------------------------------------------------------------- 1 | // ---------------------------------------------------------------------------- 2 | // Copyright (c) Microsoft Corporation. All rights reserved. 3 | // ---------------------------------------------------------------------------- 4 | 5 | module.exports = { 6 | argument: function (value, message) { 7 | if(value === undefined || value === null) 8 | throw new Error(message); 9 | } 10 | }; 11 | -------------------------------------------------------------------------------- /src/utilities/errors.js: -------------------------------------------------------------------------------- 1 | // ---------------------------------------------------------------------------- 2 | // Copyright (c) Microsoft Corporation. All rights reserved. 3 | // ---------------------------------------------------------------------------- 4 | var util = require('util'); 5 | 6 | function addFactory(target, type) { 7 | target[type] = function(message) { 8 | var error = new Error(util.format.apply(null, arguments)); 9 | error[type] = true; 10 | return error; 11 | }; 12 | return target; 13 | } 14 | 15 | module.exports = ['badRequest', 'concurrency', 'duplicate', 'notFound'].reduce(addFactory, {}); 16 | -------------------------------------------------------------------------------- /src/utilities/strings.js: -------------------------------------------------------------------------------- 1 | // ---------------------------------------------------------------------------- 2 | // Copyright (c) Microsoft Corporation. All rights reserved. 3 | // ---------------------------------------------------------------------------- 4 | 5 | // Regex to validate string ids to ensure that it does not include any characters which can be used within a URI 6 | var stringIdValidatorRegex = /([\u0000-\u001F]|[\u007F-\u009F]|["\+\?\\\/\`]|^\.{1,2}$)/; 7 | 8 | // Match YYYY-MM-DDTHH:MM:SS.sssZ, with the millisecond (.sss) part optional 9 | // Note: we only support a subset of ISO 8601 10 | var iso8601Regex = /^(\d{4})-(\d{2})-(\d{2})T(\d{2})\:(\d{2})\:(\d{2})(\.(\d{3}))?Z$/; 11 | 12 | // Match MS Date format "\/Date(1336003790912-0700)\/" 13 | var msDateRegex = /^\/Date\((-?)(\d+)(([+\-])(\d{2})(\d{2})?)?\)\/$/; 14 | 15 | var strings = module.exports = { 16 | isLetter: function (ch) { 17 | return (ch >= 'A' && ch <= 'Z') || (ch >= 'a' && ch <= 'z'); 18 | }, 19 | 20 | isDigit: function (ch) { 21 | return ch >= '0' && ch <= '9'; 22 | }, 23 | 24 | isValidStringId: function (id) { 25 | return !stringIdValidatorRegex.test(id); 26 | }, 27 | 28 | // remove starting and finishing quotes and remove quote escaping from the middle of a string 29 | getVersionFromEtag: function (etag) { 30 | return etag.replace(/^"|\\(?=")|"$/g, ''); 31 | }, 32 | 33 | getEtagFromVersion: function (version) { 34 | return '"' + version.replace(/\"/g, '\\"') + '"'; 35 | }, 36 | 37 | convertDate: function (value) { 38 | var date = strings.parseISODate(value); 39 | if (date) { 40 | return date; 41 | } 42 | 43 | date = strings.parseMsDate(value); 44 | if (date) { 45 | return date; 46 | } 47 | 48 | return null; 49 | }, 50 | 51 | // attempt to parse the value as an ISO 8601 date (e.g. 2012-05-03T00:06:00.638Z) 52 | parseISODate: function (value) { 53 | if (iso8601Regex.test(value)) { 54 | return strings.parseDateTimeOffset(value); 55 | } 56 | 57 | return null; 58 | }, 59 | 60 | // parse a date and convert to UTC 61 | parseDateTimeOffset: function (value) { 62 | var ms = Date.parse(value); 63 | if (!isNaN(ms)) { 64 | return new Date(ms); 65 | } 66 | return null; 67 | }, 68 | 69 | // attempt to parse the value as an MS date (e.g. "\/Date(1336003790912-0700)\/") 70 | parseMsDate: function (value) { 71 | var match = msDateRegex.exec(value); 72 | if (match) { 73 | // Get the ms and offset 74 | var milliseconds = parseInt(match[2], 10); 75 | var offsetMinutes = 0; 76 | if (match[5]) { 77 | var hours = parseInt(match[5], 10); 78 | var minutes = parseInt(match[6] || '0', 10); 79 | offsetMinutes = (hours * 60) + minutes; 80 | } 81 | 82 | // Handle negation 83 | if (match[1] === '-') { 84 | milliseconds = -milliseconds; 85 | } 86 | if (match[4] === '-') { 87 | offsetMinutes = -offsetMinutes; 88 | } 89 | 90 | var date = new Date(); 91 | date.setTime(milliseconds + offsetMinutes * 60000); 92 | return date; 93 | } 94 | return null; 95 | }, 96 | 97 | parseBoolean: function (bool) { 98 | if (bool === undefined || bool === null || typeof bool !== 'string') { 99 | return undefined; 100 | } else if (bool.toLowerCase() === 'true') { 101 | return true; 102 | } else if (bool.toLowerCase() === 'false') { 103 | return false; 104 | } else { 105 | return undefined; 106 | } 107 | } 108 | }; 109 | -------------------------------------------------------------------------------- /src/utilities/types.js: -------------------------------------------------------------------------------- 1 | // ---------------------------------------------------------------------------- 2 | // Copyright (c) Microsoft Corporation. All rights reserved. 3 | // ---------------------------------------------------------------------------- 4 | var types = module.exports = { 5 | curry: function (fn) { 6 | var slice = Array.prototype.slice, 7 | args = slice.call(arguments, 1); 8 | return function () { 9 | return fn.apply(null, args.concat(slice.call(arguments))); 10 | }; 11 | }, 12 | 13 | extend: function (target, members) { 14 | for (var member in members) { 15 | if(members.hasOwnProperty(member)) 16 | target[member] = members[member]; 17 | } 18 | return target; 19 | }, 20 | 21 | defineClass: function (ctor, instanceMembers, classMembers) { 22 | ctor = ctor || function () { }; 23 | if (instanceMembers) { 24 | types.extend(ctor.prototype, instanceMembers); 25 | } 26 | if (classMembers) { 27 | types.extend(ctor, classMembers); 28 | } 29 | return ctor; 30 | }, 31 | 32 | deriveClass: function (baseClass, ctor, instanceMembers) { 33 | var basePrototype = baseClass.prototype; 34 | var prototype = {}; 35 | types.extend(prototype, basePrototype); 36 | 37 | var getPrototype = function (name, fn) { 38 | return function () { 39 | var tmp = this._super; 40 | this._super = basePrototype; 41 | var ret = fn.apply(this, arguments); 42 | this._super = tmp; 43 | return ret; 44 | }; 45 | }; 46 | 47 | if (instanceMembers) 48 | for (var name in instanceMembers) 49 | if(instanceMembers.hasOwnProperty(name)) 50 | // Check if we're overwriting an existing function 51 | prototype[name] = typeof instanceMembers[name] === 'function' && typeof basePrototype[name] === 'function' ? 52 | getPrototype(name, instanceMembers[name]) : 53 | instanceMembers[name]; 54 | 55 | ctor = ctor ? 56 | (function (fn) { 57 | return function () { 58 | var tmp = this._super; 59 | this._super = basePrototype; 60 | var ret = fn.apply(this, arguments); 61 | this._super = tmp; 62 | return ret; 63 | }; 64 | })(ctor) 65 | : function () { }; 66 | 67 | ctor.prototype = prototype; 68 | ctor.prototype.constructor = ctor; 69 | return ctor; 70 | }, 71 | 72 | classof: function (o) { 73 | if (o === null) { 74 | return 'null'; 75 | } 76 | if (o === undefined) { 77 | return 'undefined'; 78 | } 79 | return Object.prototype.toString.call(o).slice(8, -1).toLowerCase(); 80 | }, 81 | 82 | isArray: function (o) { 83 | return types.classof(o) === 'array'; 84 | }, 85 | 86 | isObject: function (o) { 87 | return types.classof(o) === 'object'; 88 | }, 89 | 90 | isDate: function (o) { 91 | return types.classof(o) === 'date'; 92 | }, 93 | 94 | isFunction: function (o) { 95 | return types.classof(o) === 'function'; 96 | }, 97 | 98 | isString: function (o) { 99 | return types.classof(o) === 'string'; 100 | }, 101 | 102 | isNumber: function (o) { 103 | return types.classof(o) === 'number'; 104 | }, 105 | 106 | isError: function (o) { 107 | return types.classof(o) === 'error'; 108 | }, 109 | 110 | isGuid: function (value) { 111 | return types.isString(value) && /[a-fA-F\d]{8}-(?:[a-fA-F\d]{4}-){3}[a-fA-F\d]{12}/.test(value); 112 | }, 113 | 114 | isEmpty: function (obj) { 115 | if (obj === null || obj === undefined) { 116 | return true; 117 | } 118 | for (var key in obj) { 119 | if (obj.hasOwnProperty(key)) { 120 | return false; 121 | } 122 | } 123 | return true; 124 | } 125 | }; 126 | -------------------------------------------------------------------------------- /test/expressions.tests.js: -------------------------------------------------------------------------------- 1 | // ---------------------------------------------------------------------------- 2 | // Copyright (c) Microsoft Corporation. All rights reserved. 3 | // ---------------------------------------------------------------------------- 4 | var expressions = require('../src/expressions'), 5 | equal = require('assert').equal; 6 | 7 | describe('azure-odata-sql.expressions', function () { 8 | it("constant expression test", function () { 9 | var constExpr = new expressions.Constant('hello'); 10 | equal(constExpr.value, 'hello'); 11 | equal(constExpr.expressionType, 'Constant'); 12 | }); 13 | 14 | it("basic expression tree test", function () { 15 | var p = new expressions.Parameter(); 16 | var left = new expressions.Member(p, 'user'); 17 | var right = new expressions.Constant('mathewc'); 18 | var binExpr = new expressions.Binary(left, right, 'Equal'); 19 | 20 | equal(binExpr.left.member, 'user'); 21 | equal(binExpr.right.value, 'mathewc'); 22 | equal(binExpr.expressionType, 'Equal'); 23 | }); 24 | }); 25 | -------------------------------------------------------------------------------- /test/mssql.tests.js: -------------------------------------------------------------------------------- 1 | // ---------------------------------------------------------------------------- 2 | // Copyright (c) Microsoft Corporation. All rights reserved. 3 | // ---------------------------------------------------------------------------- 4 | var formatSql = require('../src/format'), 5 | equal = require('assert').equal; 6 | 7 | describe('azure-odata-sql.mssql', function () { 8 | it("preserves float parameters with zeroes", function () { 9 | var query = { 10 | table: 'intIdMovies', 11 | filters: 'ceiling((Duration div 60.0)) eq 2.0' 12 | }, 13 | statements = formatSql(query, { schema: 'testapp'}); 14 | equal(statements.length, 1); 15 | equal(statements[0].parameters[1].type, 'float'); 16 | }); 17 | 18 | it("correctly handles null take", function () { 19 | var query = { 20 | table: 'intIdMovies', 21 | filters: '((Duration eq Duration))', 22 | orderClauses: "Title", 23 | ordering: "Title", 24 | skip: 500, 25 | take: null 26 | }, 27 | expectedSql = "SELECT * " + 28 | "FROM [testapp].[intIdMovies] WHERE ([Duration] = [Duration]) " + 29 | "ORDER BY [Title] " + 30 | "OFFSET 500 ROWS FETCH NEXT 9007199254740992 ROWS ONLY"; 31 | 32 | verifySqlFormatting(query, expectedSql); 33 | }); 34 | 35 | it("adds totalCount query when specified", function () { 36 | var query = { 37 | table: 'intIdMovies', 38 | skip: 10, 39 | take: 10, 40 | includeTotalCount: true 41 | }, 42 | expectedSql = [ 43 | "SELECT * FROM [testapp].[intIdMovies] WHERE (1 = 1) ORDER BY [id] OFFSET 10 ROWS FETCH NEXT 10 ROWS ONLY", 44 | "SELECT COUNT(*) AS [count] FROM [testapp].[intIdMovies]" 45 | ]; 46 | 47 | verifySqlFormatting(query, expectedSql); 48 | }) 49 | 50 | it("generates correct parameter names", function () { 51 | var query = { 52 | table: 'books', 53 | filters: "(col1 eq 1) and (col2 eq 2)", 54 | }, 55 | expectedSql = "SELECT * FROM [testapp].[books] WHERE (([col1] = @p1) AND ([col2] = @p2))", 56 | statements = verifySqlFormatting(query, expectedSql); 57 | 58 | equal(statements.length, 1); 59 | equal(statements[0].parameters[0].name, 'p1'); 60 | equal(statements[0].parameters[1].name, 'p2'); 61 | }) 62 | 63 | it("query with skip no top", function () { 64 | var query = { 65 | table: 'books', 66 | filters: "(type eq 'psychology') and (price lt 25.00)", 67 | skip: 4 68 | }, 69 | expectedSql = "SELECT * FROM [testapp].[books] WHERE (([type] = @p1) AND ([price] < @p2)) ORDER BY [id] OFFSET 4 ROWS FETCH NEXT 9007199254740992 ROWS ONLY"; 70 | 71 | verifySqlFormatting(query, expectedSql); 72 | }); 73 | 74 | it("query on constants", function () { 75 | var query = { 76 | table: 'books', 77 | filters: "(true eq null) and false", 78 | }, 79 | expectedSql = "SELECT * FROM [testapp].[books] WHERE ((@p1 IS NULL) AND (@p2 = @p3))", 80 | statements = verifySqlFormatting(query, expectedSql); 81 | 82 | equal(statements.length, 1); 83 | equal(statements[0].parameters[0].value, true); 84 | equal(statements[0].parameters[1].value, false); 85 | equal(statements[0].parameters[2].value, true); 86 | }); 87 | 88 | it("query on datetime field", function () { 89 | var query = { 90 | table: 'books', 91 | filters: "datetime eq 1", 92 | }, 93 | expectedSql = "SELECT * FROM [testapp].[books] WHERE ([datetime] = @p1)", 94 | statements = verifySqlFormatting(query, expectedSql); 95 | 96 | equal(statements.length, 1); 97 | equal(statements[0].parameters[0].value, 1); 98 | }); 99 | 100 | it("query with no select but includeDeleted", function () { 101 | var query = { 102 | table: 'checkins', 103 | includeDeleted: true 104 | }, 105 | expectedSql = "SELECT * FROM [testapp].[checkins]"; 106 | 107 | verifySqlFormatting(query, expectedSql, { hasStringId: true, softDelete: true }); 108 | }); 109 | 110 | it("query with no select but without includeDeleted", function () { 111 | var query = { 112 | table: 'checkins' 113 | }, 114 | expectedSql = "SELECT * FROM [testapp].[checkins] WHERE ([deleted] = @p1)"; 115 | 116 | verifySqlFormatting(query, expectedSql, { hasStringId: true, softDelete: true }); 117 | }); 118 | 119 | it("query with top, skip and no select but without includeDeleted", function () { 120 | var query = { 121 | table: 'checkins', 122 | skip: 4, 123 | take: 4 124 | }, 125 | expectedSql = "SELECT * FROM [testapp].[checkins] WHERE ([deleted] = @p1) ORDER BY [id] OFFSET 4 ROWS FETCH NEXT 4 ROWS ONLY"; 126 | 127 | verifySqlFormatting(query, expectedSql, { hasStringId: true, softDelete: true }); 128 | }); 129 | 130 | it("inline count with paging and filter", function () { 131 | var query = { 132 | table: 'books', 133 | filters: "(type eq 'psychology') and (price lt 25.00)", 134 | selections: 'title,type,price', 135 | skip: 4, 136 | take: 4, 137 | inlineCount: 'allpages' 138 | }; 139 | var expectedSql = [ 140 | "SELECT [title], [type], [price] FROM [testapp].[books] WHERE (([type] = @p1) AND ([price] < @p2)) ORDER BY [id] OFFSET 4 ROWS FETCH NEXT 4 ROWS ONLY", 141 | "SELECT COUNT(*) AS [count] FROM [testapp].[books] WHERE (([type] = @p3) AND ([price] < @p4))" 142 | ]; 143 | 144 | var statements = verifySqlFormatting(query, expectedSql); 145 | 146 | equal(statements.length, 2); 147 | equal(statements[0].parameters[0].value, 'psychology'); 148 | equal(statements[0].parameters[1].value, 25); 149 | equal(statements[1].parameters[0].value, 'psychology'); 150 | equal(statements[1].parameters[1].value, 25); 151 | }); 152 | 153 | it("basic statement test", function () { 154 | var query = { 155 | table: 'checkins', 156 | filters: "(user eq 'mathewc')" 157 | }, 158 | expectedSql = "SELECT * FROM [testapp].[checkins] WHERE ([user] = @p1)"; 159 | 160 | verifySqlFormatting(query, expectedSql, { idType: "number", binaryColumns: [] }); 161 | }); 162 | 163 | it("advanced statement tests", function () { 164 | var query = { 165 | table: 'products', 166 | filters: "((ProductName ne 'Doritos') or (UnitPrice lt 5.00))" 167 | }, 168 | expectedSql = "SELECT * FROM [testapp].[products] WHERE (([ProductName] != @p1) OR ([UnitPrice] < @p2))"; 169 | 170 | verifySqlFormatting(query, expectedSql, { idType: "number", binaryColumns: [] }); 171 | 172 | query = { 173 | table: 'products', 174 | filters: "((ProductName ne 'Doritos') or (UnitPrice lt 5.00))", 175 | selections: 'ProductID, ProductName', 176 | ordering: 'UnitPrice asc', 177 | resultLimit: 1000 178 | }; 179 | expectedSql = "SELECT TOP 1000 [ProductID], [ProductName] FROM [testapp].[products] WHERE (([ProductName] != @p1) OR ([UnitPrice] < @p2)) ORDER BY [UnitPrice]"; 180 | verifySqlFormatting(query, expectedSql, { idType: "number", binaryColumns: [] }); 181 | 182 | query.take = 5; 183 | expectedSql = "SELECT TOP 5 [ProductID], [ProductName] FROM [testapp].[products] WHERE (([ProductName] != @p1) OR ([UnitPrice] < @p2)) ORDER BY [UnitPrice]"; 184 | verifySqlFormatting(query, expectedSql, { idType: "number", binaryColumns: [] }); 185 | }); 186 | 187 | it("test ordering", function () { 188 | var query = { 189 | table: 'products', 190 | filters: "((ProductName ne 'Doritos') or (UnitPrice lt 5.00))", 191 | ordering: "UnitPrice desc" 192 | }, 193 | expectedSql = "SELECT * FROM [testapp].[products] WHERE (([ProductName] != @p1) OR ([UnitPrice] < @p2)) ORDER BY [UnitPrice] DESC"; 194 | 195 | var statements = verifySqlFormatting(query, expectedSql, { idType: "number", binaryColumns: [] }); 196 | equal(statements.length, 1); 197 | equal(statements[0].parameters.length, 2); 198 | equal(statements[0].parameters[0].value, 'Doritos'); 199 | equal(statements[0].parameters[1].value, 5.00); 200 | }); 201 | 202 | it("test multipart ordering", function () { 203 | var query = { 204 | table: 'products', 205 | ordering: "UnitPrice desc, Category, ProductName" 206 | }, 207 | expectedSql = "SELECT * FROM [testapp].[products] ORDER BY [UnitPrice] DESC, [Category], [ProductName]"; 208 | 209 | verifySqlFormatting(query, expectedSql, { idType: "number", binaryColumns: [] }); 210 | }); 211 | 212 | it("simple multipart query", function () { 213 | var query = { 214 | table: 'products', 215 | filters: "name eq 'Doritos'", 216 | ordering: "price", 217 | take: 100 218 | }; 219 | verifySqlFormatting(query, "SELECT TOP 100 * FROM [testapp].[products] WHERE ([name] = @p1) ORDER BY [price]"); 220 | }); 221 | 222 | it("orderby", function () { 223 | var query = { 224 | table: 'products', 225 | ordering: 'price' 226 | }; 227 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] ORDER BY [price]"); 228 | }); 229 | 230 | it("orderby ascending descending", function () { 231 | var query = { 232 | table: 'products', 233 | ordering: 'price asc' 234 | }; 235 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] ORDER BY [price]"); 236 | 237 | query.ordering = 'price desc'; 238 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] ORDER BY [price] DESC"); 239 | }); 240 | 241 | it("equality operator", function () { 242 | var query = { 243 | table: 'products', 244 | filters: "name eq 'Doritos'" 245 | }; 246 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ([name] = @p1)"); 247 | }); 248 | 249 | it("not equal operator", function () { 250 | var query = { 251 | table: 'products', 252 | filters: "name ne 'Doritos'" 253 | }; 254 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ([name] != @p1)"); 255 | }); 256 | 257 | it("greater than operator", function () { 258 | var query = { 259 | table: 'products', 260 | filters: "price gt 5.00" 261 | }; 262 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ([price] > @p1)"); 263 | }); 264 | 265 | it("greater than equal operator", function () { 266 | var query = { 267 | table: 'products', 268 | filters: "price ge 5.00" 269 | }; 270 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ([price] >= @p1)"); 271 | }); 272 | 273 | it("less than operator", function () { 274 | var query = { 275 | table: 'products', 276 | filters: "price lt 5.00" 277 | }; 278 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ([price] < @p1)"); 279 | }); 280 | 281 | it("less than equal operator", function () { 282 | var query = { 283 | table: 'products', 284 | filters: "price le 5.00" 285 | }; 286 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ([price] <= @p1)"); 287 | }); 288 | 289 | it("or operator", function () { 290 | var query = { 291 | table: 'products', 292 | filters: "price le 5.00" 293 | }; 294 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ([price] <= @p1)"); 295 | }); 296 | 297 | it("negative numbers", function () { 298 | var query = { 299 | table: 'products', 300 | filters: "price eq 5.00 or price eq 10.00" 301 | }; 302 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE (([price] = @p1) OR ([price] = @p2))"); 303 | }); 304 | 305 | it("and operator", function () { 306 | var query = { 307 | table: 'products', 308 | filters: "price gt 5.00 and price lt 10.00" 309 | }; 310 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE (([price] > @p1) AND ([price] < @p2))"); 311 | }); 312 | 313 | it("negation operator", function () { 314 | var query = { 315 | table: 'products' 316 | }; 317 | 318 | // boolean odata functions 319 | query.filters = "not(substringof('foo', name))"; 320 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE NOT ([name] LIKE ('%' + @p1 + '%'))"); 321 | 322 | // inequality 323 | query.filters = "not(price lt 5.00)"; 324 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE NOT ([price] < @p1)"); 325 | 326 | // simple not requiring no conversion 327 | query.filters = "not(price eq 5.00)"; 328 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE NOT ([price] = @p1)"); 329 | 330 | // non boolean expression 331 | query.filters = "not(discontinued)"; 332 | var statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE NOT ([discontinued] = @p1)"); 333 | equal(statements.length, 1); 334 | equal((statements[0].parameters[0].value === true), true); 335 | 336 | // nested not 337 | query.filters = "not(not(discontinued))"; 338 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE NOT NOT ([discontinued] = @p1)"); 339 | }); 340 | 341 | it("subtraction", function () { 342 | var query = { 343 | table: 'products', 344 | filters: "price sub 1.00 lt 5.00" 345 | }; 346 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE (([price] - @p1) < @p2)"); 347 | }); 348 | 349 | // verifies that bit expressions are translated to boolean expressions when required 350 | it("bit to boolean conversion", function () { 351 | var query = { 352 | table: 'products', 353 | filters: 'not(discontinued)' 354 | }; 355 | 356 | var statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE NOT ([discontinued] = @p1)"); 357 | equal(statements.length, 1); 358 | equal((statements[0].parameters[0].value === true), true); 359 | 360 | query.filters = 'discontinued'; 361 | statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ([discontinued] = @p1)"); 362 | equal(statements.length, 1); 363 | equal((statements[0].parameters[0].value === true), true); 364 | 365 | query.table = 'person'; 366 | query.filters = 'likesBeer and isMale'; 367 | statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[person] WHERE (([likesBeer] = @p1) AND ([isMale] = @p2))"); 368 | equal(statements.length, 1); 369 | equal((statements[0].parameters[0].value === true), true); 370 | equal((statements[0].parameters[1].value === true), true); 371 | 372 | query.table = 'person'; 373 | query.filters = 'not(isUgly) and (likesBeer or isMale)'; 374 | verifySqlFormatting(query, "SELECT * FROM [testapp].[person] WHERE (NOT ([isUgly] = @p1) AND (([likesBeer] = @p2) OR ([isMale] = @p3)))"); 375 | }); 376 | 377 | // verifies that when any boolean expression is compared to a bit literal (true/false) 378 | // the expression is rewritten to remove the comparison 379 | it("boolean comparison to bit", function () { 380 | var query = { 381 | table: 'products', 382 | filters: "substringof('foo', name) eq true" 383 | }; 384 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ([name] LIKE ('%' + @p1 + '%'))"); 385 | 386 | query.filters = "substringof('foo', name) eq false"; 387 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE NOT ([name] LIKE ('%' + @p1 + '%'))"); 388 | 389 | query.filters = "true eq substringof('foo', name)"; 390 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ([name] LIKE ('%' + @p1 + '%'))"); 391 | 392 | query.filters = "false eq substringof('foo', name)"; 393 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE NOT ([name] LIKE ('%' + @p1 + '%'))"); 394 | 395 | query.table = 'person'; 396 | query.filters = '(likesBeer or isMale) eq true'; 397 | verifySqlFormatting(query, "SELECT * FROM [testapp].[person] WHERE (([likesBeer] = @p1) OR ([isMale] = @p2))"); 398 | 399 | query.table = 'person'; 400 | query.filters = 'false eq (likesBeer or isMale)'; 401 | verifySqlFormatting(query, "SELECT * FROM [testapp].[person] WHERE NOT (([likesBeer] = @p1) OR ([isMale] = @p2))"); 402 | }); 403 | 404 | it("mixed bit boolean conversions", function () { 405 | var query = { 406 | table: 'person', 407 | filters: "(endswith(name, 'foo') eq true) and (likesBeer)" 408 | }; 409 | verifySqlFormatting(query, "SELECT * FROM [testapp].[person] WHERE (([name] LIKE ('%' + @p1)) AND ([likesBeer] = @p2))"); 410 | }); 411 | 412 | it("addition", function () { 413 | var query = { 414 | table: 'products', 415 | filters: "price add 1.00 lt 5.00" 416 | }; 417 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE (([price] + @p1) < @p2)"); 418 | }); 419 | 420 | it("multiplication", function () { 421 | var query = { 422 | table: 'products', 423 | filters: "price mul 1.25 lt 5.00" 424 | }; 425 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE (([price] * @p1) < @p2)"); 426 | }); 427 | 428 | it("division", function () { 429 | var query = { 430 | table: 'products', 431 | filters: "price div 1.25 lt 5.00" 432 | }; 433 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE (([price] / @p1) < @p2)"); 434 | }); 435 | 436 | // Bug#599392 437 | it("modulo", function () { 438 | var query = { 439 | table: 'products', 440 | filters: "price mod 1.25 lt 5.00" 441 | }; 442 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ((CONVERT(numeric, [price]) % @p1) < @p2)"); 443 | }); 444 | 445 | it("grouping", function () { 446 | var query = { 447 | table: 'products', 448 | filters: "((name ne 'Doritos') or (price lt 5.00))" 449 | }; 450 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE (([name] != @p1) OR ([price] < @p2))"); 451 | }); 452 | 453 | it("null literal equality", function () { 454 | var query = { 455 | table: 'products', 456 | filters: "name eq null" 457 | }; 458 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ([name] IS NULL)"); 459 | }); 460 | 461 | it("null literal inequality", function () { 462 | var query = { 463 | table: 'products', 464 | filters: "name ne null" 465 | }; 466 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ([name] IS NOT NULL)"); 467 | }); 468 | 469 | it("string length", function () { 470 | var query = { 471 | table: 'products', 472 | filters: "length(name) gt 5" 473 | }; 474 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ((LEN([name] + 'X') - 1) > @p1)"); 475 | 476 | // pass a string concat expression into length 477 | query = { 478 | table: 'products', 479 | filters: "length(concat(name, category)) gt 5" 480 | }; 481 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ((LEN((CONVERT(NVARCHAR(MAX), [name]) + [category]) + 'X') - 1) > @p1)"); 482 | }); 483 | 484 | it("string startswith", function () { 485 | var query = { 486 | table: 'products', 487 | filters: "startswith(name, 'Abc')" 488 | }; 489 | var statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ([name] LIKE (@p1 + '%'))"); 490 | equal(statements.length, 1); 491 | equal(statements[0].parameters[0].value, 'Abc'); 492 | }); 493 | 494 | it("string endswith", function () { 495 | var query = { 496 | table: 'products', 497 | filters: "endswith(name, 'Abc')" 498 | }; 499 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ([name] LIKE ('%' + @p1))"); 500 | }); 501 | 502 | it("string substringof", function () { 503 | var query = { 504 | table: 'products', 505 | filters: "substringof('Abc', name)" 506 | }; 507 | var statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ([name] LIKE ('%' + @p1 + '%'))"); 508 | equal(statements.length, 1); 509 | equal(statements[0].parameters[0].value, 'Abc'); 510 | }); 511 | 512 | it("string indexof", function () { 513 | var query = { 514 | table: 'products', 515 | filters: "indexof(name, 'Abc') eq 5" 516 | }; 517 | var statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ((PATINDEX('%' + @p1 + '%', [name]) - 1) = @p2)"); 518 | equal(statements.length, 1); 519 | equal(statements[0].parameters[0].value, 'Abc'); 520 | equal(statements[0].parameters[1].value, 5); 521 | }); 522 | 523 | it("string concat", function () { 524 | var query = { 525 | table: 'customers', 526 | filters: "concat(concat(city, ', '), country) eq 'Berlin, Germany'" 527 | }; 528 | var statements = verifySqlFormatting(query, 529 | "SELECT * FROM [testapp].[customers] WHERE ((CONVERT(NVARCHAR(MAX), (CONVERT(NVARCHAR(MAX), [city]) + @p1)) + [country]) = @p2)"); 530 | equal(statements.length, 1); 531 | equal(statements[0].parameters[0].value, ', '); 532 | equal(statements[0].parameters[1].value, 'Berlin, Germany'); 533 | }); 534 | 535 | it("string replace", function () { 536 | var query = { 537 | table: 'products', 538 | filters: "replace(name, ' ', '') eq 'ApplePie'" 539 | }; 540 | var statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE (REPLACE([name], @p1, @p2) = @p3)"); 541 | equal(statements.length, 1); 542 | equal(statements[0].parameters[0].value, ' '); 543 | equal(statements[0].parameters[1].value, ''); 544 | equal(statements[0].parameters[2].value, 'ApplePie'); 545 | }); 546 | 547 | it("string substring", function () { 548 | // first overload not taking an explicit length - will return 549 | // the rest of the string 550 | var query = { 551 | table: 'books', 552 | filters: "substring(title, 1) eq 'he Rise and Fall of the Roman Empire'" 553 | }; 554 | var statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[books] WHERE (SUBSTRING([title], @p1 + 1, LEN([title])) = @p2)"); 555 | equal(statements.length, 1); 556 | equal(statements[0].parameters[0].value, 1); 557 | equal(statements[0].parameters[1].value, 'he Rise and Fall of the Roman Empire'); 558 | 559 | // second overload taking a length 560 | query.filters = "substring(title, 1, 10) eq 'he Rise and Fall of the Roman Empire'"; 561 | statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[books] WHERE (SUBSTRING([title], @p1 + 1, @p2) = @p3)"); 562 | equal(statements.length, 1); 563 | equal(statements[0].parameters[0].value, 1); 564 | equal(statements[0].parameters[1].value, 10); 565 | equal(statements[0].parameters[2].value, 'he Rise and Fall of the Roman Empire'); 566 | }); 567 | 568 | it("string trim", function () { 569 | var query = { 570 | table: 'products', 571 | filters: "trim(name) eq 'foobar'" 572 | }; 573 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE (LTRIM(RTRIM([name])) = @p1)"); 574 | }); 575 | 576 | it("string tolower", function () { 577 | var query = { 578 | table: 'products', 579 | filters: "tolower(name) eq 'tasty treats'" 580 | }; 581 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE (LOWER([name]) = @p1)"); 582 | }); 583 | 584 | it("string toupper", function () { 585 | var query = { 586 | table: 'products', 587 | filters: "toupper(name) eq 'TASTY TREATS'" 588 | }; 589 | verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE (UPPER([name]) = @p1)"); 590 | }); 591 | 592 | it("string concat", function () { 593 | var query = { 594 | table: 'products', 595 | filters: "concat(name, 'Bar') eq 'FooBar'" 596 | }; 597 | var statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[products] WHERE ((CONVERT(NVARCHAR(MAX), [name]) + @p1) = @p2)"); 598 | equal(statements.length, 1); 599 | equal(statements[0].parameters[0].value, 'Bar'); 600 | equal(statements[0].parameters[1].value, 'FooBar'); 601 | }); 602 | 603 | it("date functions ", function () { 604 | var query = { 605 | table: 'checkins', 606 | filters: "day(checkinDate) lt 25" 607 | }; 608 | var statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[checkins] WHERE (DAY([checkinDate]) < @p1)"); 609 | equal(statements.length, 1); 610 | equal(statements[0].parameters[0].value, 25); 611 | 612 | query.filters = "month(checkinDate) eq 8"; 613 | statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[checkins] WHERE (MONTH([checkinDate]) = @p1)"); 614 | equal(statements.length, 1); 615 | equal(statements[0].parameters[0].value, 8); 616 | 617 | query.filters = "year(checkinDate) gt 1974"; 618 | statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[checkins] WHERE (YEAR([checkinDate]) > @p1)"); 619 | equal(statements.length, 1); 620 | equal(statements[0].parameters[0].value, 1974); 621 | 622 | query.filters = "hour(checkinDate) gt 6"; 623 | statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[checkins] WHERE (DATEPART(HOUR, [checkinDate]) > @p1)"); 624 | 625 | query.filters = "minute(checkinDate) eq 33"; 626 | statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[checkins] WHERE (DATEPART(MINUTE, [checkinDate]) = @p1)"); 627 | 628 | query.filters = "second(checkinDate) lt 30"; 629 | statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[checkins] WHERE (DATEPART(SECOND, [checkinDate]) < @p1)"); 630 | }); 631 | 632 | it("math functions", function () { 633 | var query = { 634 | table: 'books', 635 | filters: "floor(price) lt 77" 636 | }; 637 | var statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[books] WHERE (FLOOR([price]) < @p1)"); 638 | equal(statements.length, 1); 639 | equal(statements[0].parameters[0].value, 77); 640 | 641 | query.filters = "ceiling(price) eq 8"; 642 | statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[books] WHERE (CEILING([price]) = @p1)"); 643 | equal(statements.length, 1); 644 | equal(statements[0].parameters[0].value, 8); 645 | 646 | query.filters = "round(price) gt 19.00"; 647 | statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[books] WHERE (ROUND([price], 0) > @p1)"); 648 | equal(statements.length, 1); 649 | equal(statements[0].parameters[0].value, 19.00); 650 | }); 651 | 652 | it("simple paging query", function () { 653 | var query = { 654 | table: 'books', 655 | skip: 4, 656 | take: 4 657 | }; 658 | var expectedSql = "SELECT * FROM [testapp].[books] WHERE (1 = 1) ORDER BY [id] OFFSET 4 ROWS FETCH NEXT 4 ROWS ONLY"; 659 | verifySqlFormatting(query, expectedSql); 660 | }); 661 | 662 | it("uses table specified in table config", function () { 663 | var query = { 664 | table: 'query' 665 | }; 666 | var expectedSql = "SELECT * FROM [testapp].[tableName]"; 667 | verifySqlFormatting(query, expectedSql, { idType: "number", binaryColumns: [], schema: 'testapp', name: 'tableName' }); 668 | }) 669 | 670 | it("paging query with filter and select", function () { 671 | var query = { 672 | table: 'books', 673 | filters: "type eq 'psychology'", 674 | selections: 'title,type,price', 675 | skip: 4, 676 | take: 4 677 | }; 678 | var expectedSql = "SELECT [title], [type], [price] FROM [testapp].[books] WHERE ([type] = @p1) ORDER BY [id] OFFSET 4 ROWS FETCH NEXT 4 ROWS ONLY"; 679 | verifySqlFormatting(query, expectedSql); 680 | }); 681 | 682 | it("paging query with filter and select and ordering", function () { 683 | var query = { 684 | table: 'books', 685 | filters: "type eq 'psychology'", 686 | selections: 'title,type,price', 687 | ordering: 'price desc', 688 | skip: 4, 689 | take: 4 690 | }; 691 | var expectedSql = "SELECT [title], [type], [price] FROM [testapp].[books] WHERE ([type] = @p1) ORDER BY [price] DESC OFFSET 4 ROWS FETCH NEXT 4 ROWS ONLY"; 692 | verifySqlFormatting(query, expectedSql); 693 | }); 694 | 695 | it("datetime expression", function () { 696 | var query = { 697 | table: 'checkins', 698 | filters: "checkinDate lt datetime'2000-12-12T12:00:00Z'" 699 | }; 700 | var statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[checkins] WHERE ([checkinDate] < @p1)"); 701 | 702 | equal(statements.length, 1); 703 | var value = statements[0].parameters[0].value; 704 | equal(value.constructor, Date); 705 | 706 | // try a parse failure case 707 | var expectedExceptionCaught = false; 708 | try { 709 | query.filters = "checkinDate lt datetime'2000x12-12blah2:00'"; 710 | verifySqlFormatting(query, "SELECT * FROM [testapp].[checkins] WHERE ([checkinDate] < @p1)"); 711 | } 712 | catch (e) { 713 | expectedExceptionCaught = true; 714 | equal(e.message, "Invalid 'datetime' type creation expression (at index 23)"); 715 | } 716 | equal(expectedExceptionCaught, true); 717 | }); 718 | 719 | it("datetimeoffset expression", function () { 720 | var query = { 721 | table: 'checkins', 722 | filters: "checkinDate lt datetimeoffset'2000-12-12T04:00:00.0000000-08:00'" 723 | }; 724 | var statements = verifySqlFormatting(query, "SELECT * FROM [testapp].[checkins] WHERE ([checkinDate] < @p1)"); 725 | 726 | equal(statements.length, 1); 727 | var value = statements[0].parameters[0].value; 728 | equal(value.constructor, Date); 729 | equal(value.toISOString(), '2000-12-12T12:00:00.000Z'); 730 | }); 731 | 732 | it("parse multiple quotes", function () { 733 | var query = { 734 | table: 'products', 735 | filters: "description eq 'lots of qu''ote''''s i''n he''r''e!'" 736 | }, 737 | expectedSql = "SELECT * FROM [testapp].[products] WHERE ([description] = @p1)"; 738 | 739 | var statements = verifySqlFormatting(query, expectedSql, { idType: "number", binaryColumns: [] }) 740 | equal(statements.length, 1); 741 | equal(statements[0].parameters[0].value, "lots of qu'ote''s i'n he'r'e!"); 742 | }); 743 | 744 | it("converts base64 version columns to binary buffers", function () { 745 | var query = { 746 | table: 'products', 747 | filters: "version eq 'AAAAAAAAUDU='" 748 | }, 749 | statements = formatSql(query, { schema: 'testapp' }); 750 | equal(statements.length, 1); 751 | equal(statements[0].parameters[0].value.constructor, Buffer); 752 | equal(statements[0].parameters[0].value.toString('base64'), 'AAAAAAAAUDU='); 753 | }); 754 | 755 | it("verify function arguments", function () { 756 | var testCases = [ 757 | // date functions 758 | { filters: "day(a, b, c)", expectedParamCount: 1 }, 759 | { filters: "day()", expectedParamCount: 1 }, 760 | { filters: "month(a, b, c)", expectedParamCount: 1 }, 761 | { filters: "month()", expectedParamCount: 1 }, 762 | { filters: "year(a, b, c)", expectedParamCount: 1 }, 763 | { filters: "year()", expectedParamCount: 1 }, 764 | { filters: "hour()", expectedParamCount: 1 }, 765 | { filters: "minute()", expectedParamCount: 1 }, 766 | { filters: "second()", expectedParamCount: 1 }, 767 | { filters: "floor(a, b, c)", expectedParamCount: 1 }, 768 | { filters: "ceiling(a, b, c)", expectedParamCount: 1 }, 769 | { filters: "round(a, b, c)", expectedParamCount: 1 }, 770 | 771 | // string functions 772 | { filters: "substringof(a)", expectedParamCount: 2 }, 773 | { filters: "endswith(a)", expectedParamCount: 2 }, 774 | { filters: "startswith(a)", expectedParamCount: 2 }, 775 | { filters: "concat(a)", expectedParamCount: 2 }, 776 | { filters: "tolower(a, b)", expectedParamCount: 1 }, 777 | { filters: "toupper()", expectedParamCount: 1 }, 778 | { filters: "length()", expectedParamCount: 1 }, 779 | { filters: "trim(a, 5)", expectedParamCount: 1 }, 780 | { filters: "indexof(a)", expectedParamCount: 2 }, 781 | { filters: "replace(a)", expectedParamCount: 3 }, 782 | { filters: "substring(a)", expectedParamCount: 3, expectedError: "Function 'substring' requires 2 or 3 parameters." }, 783 | { filters: "concat()", expectedParamCount: 2 }, 784 | 785 | // math functions 786 | { filters: "floor()", expectedParamCount: 1 }, 787 | { filters: "ceiling()", expectedParamCount: 1 }, 788 | { filters: "round()", expectedParamCount: 1 } 789 | ]; 790 | 791 | for (var idx in testCases) { 792 | var testCase = testCases[idx], 793 | query = { 794 | table: 'foo', 795 | filters: testCase.filters 796 | }, 797 | expectedExceptionCaught = false; 798 | 799 | try { 800 | formatSql(query, 'testapp', { idType: "number", binaryColumns: [] }); 801 | } 802 | catch (e) { 803 | expectedExceptionCaught = true; 804 | var expectedError; 805 | if (!testCase.expectedError) { 806 | var parenIdx = testCase.filters.indexOf('('); 807 | var functionName = testCase.filters.substr(0, parenIdx); 808 | expectedError = "Function '" + functionName + "' requires " + testCase.expectedParamCount; 809 | expectedError += (testCase.expectedParamCount > 1) ? " parameters." : " parameter."; 810 | } 811 | else { 812 | expectedError = testCase.expectedError; 813 | } 814 | equal(e.message, expectedError); 815 | } 816 | equal(expectedExceptionCaught, true); 817 | } 818 | }); 819 | 820 | it("formats filters", function () { 821 | var query = { filters : "p1 eq 'test'" }, 822 | result = formatSql.filter(query); 823 | equal(result.sql, "([p1] = @p1)"); 824 | equal(result.parameters[0].name, 'p1') 825 | equal(result.parameters[0].value, 'test') 826 | }); 827 | 828 | it("formats filters with custom parameter prefixes", function () { 829 | var query = { filters : "p1 eq 'test'" }, 830 | result = formatSql.filter(query, 'z'); 831 | equal(result.sql, "([p1] = @z1)"); 832 | equal(result.parameters[0].name, 'z1') 833 | }); 834 | 835 | function verifySqlFormatting(query, expectedSql, metadata) { 836 | if(metadata) metadata.schema = 'testapp'; 837 | var statements = formatSql(query, metadata || { idType: "number", binaryColumns: [], schema: 'testapp' }); 838 | 839 | var expectedStatements = expectedSql; 840 | if (expectedSql.constructor !== Array) { 841 | expectedStatements = [expectedSql]; 842 | } 843 | 844 | for (var i = 0; i < statements.length; i++) { 845 | equal(statements[i].sql, expectedStatements[i]); 846 | } 847 | 848 | return statements; 849 | } 850 | }) 851 | -------------------------------------------------------------------------------- /test/parseOData.tests.js: -------------------------------------------------------------------------------- 1 | // ---------------------------------------------------------------------------- 2 | // Copyright (c) Microsoft Corporation. All rights reserved. 3 | // ---------------------------------------------------------------------------- 4 | var parse = require('../src/parseOData'), 5 | equal = require('assert').equal; 6 | 7 | describe('azure-odata-sql.parseOData', function () { 8 | it("basic parser test", function () { 9 | var result = parse("(user eq 'mathewc')"); 10 | 11 | equal(result.expressionType, 'Equal'); 12 | equal(result.left.member, 'user'); 13 | equal(result.right.value, 'mathewc'); 14 | }); 15 | 16 | // bug 740863: backslash should not be escape character 17 | it("parse backslash", function () { 18 | var result = parse("(user eq 'hasan\\')"); 19 | 20 | equal(result.expressionType, 'Equal'); 21 | equal(result.left.member, 'user'); 22 | equal(result.right.value, 'hasan\\'); 23 | }); 24 | 25 | it("parse positive / negative numbers", function () { 26 | var result = parse('(val eq -1.5)'); 27 | equal(result.right.value, -1.5); 28 | 29 | result = parse('(val eq -1)'); 30 | equal(result.right.value, -1); 31 | 32 | result = parse('(val eq 1)'); 33 | equal(result.right.value, 1); 34 | 35 | result = parse('(val eq 1.5)'); 36 | equal(result.right.value, 1.5); 37 | }); 38 | 39 | // verify that the odata literal type suffixes are parsed correctly, even 40 | // though the values actually map to the same number type 41 | it("numeric literal parsing", function () { 42 | var testCases = [ 43 | // long literal 44 | { expr: '1234', value: 1234, type: 'Constant' }, 45 | { expr: '1234L', value: 1234, type: 'Constant' }, 46 | { expr: '1234l', value: 1234, type: 'Constant' }, 47 | 48 | // decimal literal 49 | { expr: '1234M', value: 1234 }, 50 | { expr: '1234.56M', value: 1234.56 }, 51 | { expr: '1234.56m', value: 1234.56 }, 52 | 53 | // single literal 54 | { expr: '1234F', value: 1234 }, 55 | { expr: '1234.56f', value: 1234.56 }, 56 | { expr: '1234.56f', value: 1234.56 }, 57 | 58 | // double literal 59 | { expr: '1234D', value: 1234 }, 60 | { expr: '1234.56d', value: 1234.56 }, 61 | { expr: '1234.56D', value: 1234.56 } 62 | ]; 63 | 64 | for (var i = 0; i < testCases.length; i++) { 65 | var testCase = testCases[i]; 66 | var expr = parse(testCase.expr); 67 | equal(expr.expressionType, testCase.type || 'FloatConstant'); 68 | equal(expr.value, testCase.value); 69 | } 70 | }); 71 | 72 | it("string replace - nested calls disallowed", function () { 73 | var expectedExceptionCaught = false; 74 | try { 75 | parse("replace(replace(name, 'x', 'y'), 'x', 'y') eq 'ApplePie'"); 76 | } 77 | catch (e) { 78 | expectedExceptionCaught = true; 79 | equal(e.message, "Calls to 'replace' cannot be nested. (at index 8)"); 80 | } 81 | equal(expectedExceptionCaught, true); 82 | }); 83 | 84 | it("string replace - replace arg must be constant with valid length", function () { 85 | var expectedExceptionCaught = false; 86 | try { 87 | // try to specify a non-constant for the replace value 88 | parse("replace(name, 'x', nonConstant) eq 'ApplePie'"); 89 | } 90 | catch (e) { 91 | expectedExceptionCaught = true; 92 | equal(e.message, "The third parameter to 'replace' must be a string constant less than 100 in length. (at index 32)"); 93 | } 94 | equal(expectedExceptionCaught, true); 95 | 96 | expectedExceptionCaught = false; 97 | try { 98 | // try to specify a string greater than 100 characters in length 99 | parse("replace(name, 'x', 'xxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxx') eq 'ApplePie'"); 100 | } 101 | catch (e) { 102 | expectedExceptionCaught = true; 103 | equal(e.message, "The third parameter to 'replace' must be a string constant less than 100 in length. (at index 124)"); 104 | } 105 | equal(expectedExceptionCaught, true); 106 | }); 107 | 108 | it("parse error double quotes", function () { 109 | // try a parse failure case 110 | var expectedExceptionCaught = false; 111 | try { 112 | parse('user eq "mathewc"'); 113 | } 114 | catch (e) { 115 | expectedExceptionCaught = true; 116 | equal(e.message, "Syntax error '\"' (at index 8)"); 117 | } 118 | equal(expectedExceptionCaught, true); 119 | }); 120 | }) 121 | -------------------------------------------------------------------------------- /test/sqlite.tests.js: -------------------------------------------------------------------------------- 1 | // ---------------------------------------------------------------------------- 2 | // Copyright (c) Microsoft Corporation. All rights reserved. 3 | // ---------------------------------------------------------------------------- 4 | var formatSql = require('../src/format'), 5 | equal = require('assert').equal; 6 | 7 | describe('azure-odata-sql.sqlite', function () { 8 | it("preserves float parameters with zeroes", function () { 9 | var query = { 10 | table: 'intIdMovies', 11 | filters: 'ceiling((Duration div 60.0)) eq 2.0' 12 | }, 13 | statements = formatSql(query); 14 | equal(statements.length, 1); 15 | equal(statements[0].parameters[1].type, 'float'); 16 | }); 17 | 18 | it("correctly handles null take", function () { 19 | var query = { 20 | table: 'intIdMovies', 21 | filters: '((Duration eq Duration))', 22 | orderClauses: "Title", 23 | ordering: "Title", 24 | skip: 500, 25 | take: null 26 | }, 27 | expectedSql = "SELECT * FROM [intIdMovies] WHERE ([Duration] = [Duration]) ORDER BY [Title] LIMIT -1 OFFSET 500"; 28 | 29 | verifySqlFormatting(query, expectedSql); 30 | }); 31 | 32 | it("adds totalCount query when specified", function () { 33 | var query = { 34 | table: 'intIdMovies', 35 | skip: 10, 36 | take: 11, 37 | includeTotalCount: true 38 | }, 39 | expectedSql = [ 40 | "SELECT * FROM [intIdMovies] LIMIT 11 OFFSET 10", 41 | "SELECT COUNT(*) AS [count] FROM [intIdMovies]" 42 | ]; 43 | 44 | verifySqlFormatting(query, expectedSql); 45 | }) 46 | 47 | it("generates correct parameter names", function () { 48 | var query = { 49 | table: 'books', 50 | filters: "(col1 eq 1) and (col2 eq 2)", 51 | }, 52 | expectedSql = "SELECT * FROM [books] WHERE (([col1] = @p1) AND ([col2] = @p2))", 53 | statements = verifySqlFormatting(query, expectedSql); 54 | 55 | equal(statements.length, 1); 56 | equal(statements[0].parameters[0].name, 'p1'); 57 | equal(statements[0].parameters[1].name, 'p2'); 58 | }) 59 | 60 | it("query with skip no top", function () { 61 | var query = { 62 | table: 'books', 63 | filters: "(type eq 'psychology') and (price lt 25.00)", 64 | skip: 4 65 | }, 66 | expectedSql = "SELECT * FROM [books] WHERE (([type] = @p1) AND ([price] < @p2)) LIMIT -1 OFFSET 4"; 67 | 68 | verifySqlFormatting(query, expectedSql); 69 | }); 70 | 71 | it("query on constants", function () { 72 | var query = { 73 | table: 'books', 74 | filters: "(true eq null) and false", 75 | }, 76 | expectedSql = "SELECT * FROM [books] WHERE ((@p1 IS NULL) AND (@p2 = @p3))", 77 | statements = verifySqlFormatting(query, expectedSql); 78 | 79 | equal(statements.length, 1); 80 | equal(statements[0].parameters[0].value, true); 81 | equal(statements[0].parameters[1].value, false); 82 | equal(statements[0].parameters[2].value, true); 83 | }); 84 | 85 | it("query on datetime field", function () { 86 | var query = { 87 | table: 'books', 88 | filters: "datetime eq 1", 89 | }, 90 | expectedSql = "SELECT * FROM [books] WHERE ([datetime] = @p1)", 91 | statements = verifySqlFormatting(query, expectedSql); 92 | 93 | equal(statements.length, 1); 94 | equal(statements[0].parameters[0].value, 1); 95 | }); 96 | 97 | it("query with no select but includeDeleted", function () { 98 | var query = { 99 | table: 'checkins', 100 | includeDeleted: true 101 | }, 102 | expectedSql = "SELECT * FROM [checkins]"; 103 | 104 | verifySqlFormatting(query, expectedSql, { hasStringId: true, softDelete: true }); 105 | }); 106 | 107 | it("query with no select but without includeDeleted", function () { 108 | var query = { 109 | table: 'checkins' 110 | }, 111 | expectedSql = "SELECT * FROM [checkins] WHERE ([deleted] = @p1)"; 112 | 113 | verifySqlFormatting(query, expectedSql, { hasStringId: true, softDelete: true }); 114 | }); 115 | 116 | it("query with top, skip and no select but without includeDeleted", function () { 117 | var query = { 118 | table: 'checkins', 119 | skip: 4, 120 | take: 5 121 | }, 122 | expectedSql = "SELECT * FROM [checkins] WHERE ([deleted] = @p1) LIMIT 5 OFFSET 4"; 123 | 124 | verifySqlFormatting(query, expectedSql, { hasStringId: true, softDelete: true }); 125 | }); 126 | 127 | it("inline count with paging and filter", function () { 128 | var query = { 129 | table: 'books', 130 | filters: "(type eq 'psychology') and (price lt 25.00)", 131 | selections: 'title,type,price', 132 | skip: 4, 133 | take: 5, 134 | inlineCount: 'allpages' 135 | }; 136 | var expectedSql = [ 137 | "SELECT [title], [type], [price] FROM [books] WHERE (([type] = @p1) AND ([price] < @p2)) LIMIT 5 OFFSET 4", 138 | "SELECT COUNT(*) AS [count] FROM [books] WHERE (([type] = @p3) AND ([price] < @p4))" 139 | ]; 140 | 141 | var statements = verifySqlFormatting(query, expectedSql); 142 | 143 | equal(statements.length, 2); 144 | equal(statements[0].parameters[0].value, 'psychology'); 145 | equal(statements[0].parameters[1].value, 25); 146 | equal(statements[1].parameters[0].value, 'psychology'); 147 | equal(statements[1].parameters[1].value, 25); 148 | }); 149 | 150 | it("basic statement test", function () { 151 | var query = { 152 | table: 'checkins', 153 | filters: "(user eq 'mathewc')" 154 | }, 155 | expectedSql = "SELECT * FROM [checkins] WHERE ([user] = @p1)"; 156 | 157 | verifySqlFormatting(query, expectedSql, { idType: "number", binaryColumns: [] }); 158 | }); 159 | 160 | it("advanced statement tests", function () { 161 | var query = { 162 | table: 'products', 163 | filters: "((ProductName ne 'Doritos') or (UnitPrice lt 5.00))" 164 | }, 165 | expectedSql = "SELECT * FROM [products] WHERE (([ProductName] != @p1) OR ([UnitPrice] < @p2))"; 166 | 167 | verifySqlFormatting(query, expectedSql, { idType: "number", binaryColumns: [] }); 168 | 169 | query = { 170 | table: 'products', 171 | filters: "((ProductName ne 'Doritos') or (UnitPrice lt 5.00))", 172 | selections: 'ProductID, ProductName', 173 | ordering: 'UnitPrice asc', 174 | resultLimit: 1000 175 | }; 176 | expectedSql = "SELECT [ProductID], [ProductName] FROM [products] WHERE (([ProductName] != @p1) OR ([UnitPrice] < @p2)) ORDER BY [UnitPrice] LIMIT 1000"; 177 | verifySqlFormatting(query, expectedSql, { idType: "number", binaryColumns: [] }); 178 | 179 | query.take = 5; 180 | expectedSql = "SELECT [ProductID], [ProductName] FROM [products] WHERE (([ProductName] != @p1) OR ([UnitPrice] < @p2)) ORDER BY [UnitPrice] LIMIT 5"; 181 | verifySqlFormatting(query, expectedSql, { idType: "number", binaryColumns: [] }); 182 | }); 183 | 184 | it("test ordering", function () { 185 | var query = { 186 | table: 'products', 187 | filters: "((ProductName ne 'Doritos') or (UnitPrice lt 5.00))", 188 | ordering: "UnitPrice desc" 189 | }, 190 | expectedSql = "SELECT * FROM [products] WHERE (([ProductName] != @p1) OR ([UnitPrice] < @p2)) ORDER BY [UnitPrice] DESC"; 191 | 192 | var statements = verifySqlFormatting(query, expectedSql, { idType: "number", binaryColumns: [] }); 193 | equal(statements.length, 1); 194 | equal(statements[0].parameters.length, 2); 195 | equal(statements[0].parameters[0].value, 'Doritos'); 196 | equal(statements[0].parameters[1].value, 5.00); 197 | }); 198 | 199 | it("test multipart ordering", function () { 200 | var query = { 201 | table: 'products', 202 | ordering: "UnitPrice desc, Category, ProductName" 203 | }, 204 | expectedSql = "SELECT * FROM [products] ORDER BY [UnitPrice] DESC, [Category], [ProductName]"; 205 | 206 | verifySqlFormatting(query, expectedSql, { idType: "number", binaryColumns: [] }); 207 | }); 208 | 209 | it("simple multipart query", function () { 210 | var query = { 211 | table: 'products', 212 | filters: "name eq 'Doritos'", 213 | ordering: "price", 214 | take: 100 215 | }; 216 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE ([name] = @p1) ORDER BY [price] LIMIT 100"); 217 | }); 218 | 219 | it("orderby", function () { 220 | var query = { 221 | table: 'products', 222 | ordering: 'price' 223 | }; 224 | verifySqlFormatting(query, "SELECT * FROM [products] ORDER BY [price]"); 225 | }); 226 | 227 | it("orderby ascending descending", function () { 228 | var query = { 229 | table: 'products', 230 | ordering: 'price asc' 231 | }; 232 | verifySqlFormatting(query, "SELECT * FROM [products] ORDER BY [price]"); 233 | 234 | query.ordering = 'price desc'; 235 | verifySqlFormatting(query, "SELECT * FROM [products] ORDER BY [price] DESC"); 236 | }); 237 | 238 | it("equality operator", function () { 239 | var query = { 240 | table: 'products', 241 | filters: "name eq 'Doritos'" 242 | }; 243 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE ([name] = @p1)"); 244 | }); 245 | 246 | it("not equal operator", function () { 247 | var query = { 248 | table: 'products', 249 | filters: "name ne 'Doritos'" 250 | }; 251 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE ([name] != @p1)"); 252 | }); 253 | 254 | it("greater than operator", function () { 255 | var query = { 256 | table: 'products', 257 | filters: "price gt 5.00" 258 | }; 259 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE ([price] > @p1)"); 260 | }); 261 | 262 | it("greater than equal operator", function () { 263 | var query = { 264 | table: 'products', 265 | filters: "price ge 5.00" 266 | }; 267 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE ([price] >= @p1)"); 268 | }); 269 | 270 | it("less than operator", function () { 271 | var query = { 272 | table: 'products', 273 | filters: "price lt 5.00" 274 | }; 275 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE ([price] < @p1)"); 276 | }); 277 | 278 | it("less than equal operator", function () { 279 | var query = { 280 | table: 'products', 281 | filters: "price le 5.00" 282 | }; 283 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE ([price] <= @p1)"); 284 | }); 285 | 286 | it("or operator", function () { 287 | var query = { 288 | table: 'products', 289 | filters: "price le 5.00" 290 | }; 291 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE ([price] <= @p1)"); 292 | }); 293 | 294 | it("negative numbers", function () { 295 | var query = { 296 | table: 'products', 297 | filters: "price eq 5.00 or price eq 10.00" 298 | }; 299 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE (([price] = @p1) OR ([price] = @p2))"); 300 | }); 301 | 302 | it("and operator", function () { 303 | var query = { 304 | table: 'products', 305 | filters: "price gt 5.00 and price lt 10.00" 306 | }; 307 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE (([price] > @p1) AND ([price] < @p2))"); 308 | }); 309 | 310 | it("negation operator", function () { 311 | var query = { 312 | table: 'products' 313 | }; 314 | 315 | // boolean odata functions 316 | query.filters = "not(substringof('foo', name))"; 317 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE NOT ([name] LIKE ('%' + @p1 + '%'))"); 318 | 319 | // inequality 320 | query.filters = "not(price lt 5.00)"; 321 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE NOT ([price] < @p1)"); 322 | 323 | // simple not requiring no conversion 324 | query.filters = "not(price eq 5.00)"; 325 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE NOT ([price] = @p1)"); 326 | 327 | // non boolean expression 328 | query.filters = "not(discontinued)"; 329 | var statements = verifySqlFormatting(query, "SELECT * FROM [products] WHERE NOT ([discontinued] = @p1)"); 330 | equal(statements.length, 1); 331 | equal((statements[0].parameters[0].value === true), true); 332 | 333 | // nested not 334 | query.filters = "not(not(discontinued))"; 335 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE NOT NOT ([discontinued] = @p1)"); 336 | }); 337 | 338 | it("subtraction", function () { 339 | var query = { 340 | table: 'products', 341 | filters: "price sub 1.00 lt 5.00" 342 | }; 343 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE (([price] - @p1) < @p2)"); 344 | }); 345 | 346 | // verifies that bit expressions are translated to boolean expressions when required 347 | it("bit to boolean conversion", function () { 348 | var query = { 349 | table: 'products', 350 | filters: 'not(discontinued)' 351 | }; 352 | 353 | var statements = verifySqlFormatting(query, "SELECT * FROM [products] WHERE NOT ([discontinued] = @p1)"); 354 | equal(statements.length, 1); 355 | equal((statements[0].parameters[0].value === true), true); 356 | 357 | query.filters = 'discontinued'; 358 | statements = verifySqlFormatting(query, "SELECT * FROM [products] WHERE ([discontinued] = @p1)"); 359 | equal(statements.length, 1); 360 | equal((statements[0].parameters[0].value === true), true); 361 | 362 | query.table = 'person'; 363 | query.filters = 'likesBeer and isMale'; 364 | statements = verifySqlFormatting(query, "SELECT * FROM [person] WHERE (([likesBeer] = @p1) AND ([isMale] = @p2))"); 365 | equal(statements.length, 1); 366 | equal((statements[0].parameters[0].value === true), true); 367 | equal((statements[0].parameters[1].value === true), true); 368 | 369 | query.table = 'person'; 370 | query.filters = 'not(isUgly) and (likesBeer or isMale)'; 371 | verifySqlFormatting(query, "SELECT * FROM [person] WHERE (NOT ([isUgly] = @p1) AND (([likesBeer] = @p2) OR ([isMale] = @p3)))"); 372 | }); 373 | 374 | // verifies that when any boolean expression is compared to a bit literal (true/false) 375 | // the expression is rewritten to remove the comparison 376 | it("boolean comparison to bit", function () { 377 | var query = { 378 | table: 'products', 379 | filters: "substringof('foo', name) eq true" 380 | }; 381 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE ([name] LIKE ('%' + @p1 + '%'))"); 382 | 383 | query.filters = "substringof('foo', name) eq false"; 384 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE NOT ([name] LIKE ('%' + @p1 + '%'))"); 385 | 386 | query.filters = "true eq substringof('foo', name)"; 387 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE ([name] LIKE ('%' + @p1 + '%'))"); 388 | 389 | query.filters = "false eq substringof('foo', name)"; 390 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE NOT ([name] LIKE ('%' + @p1 + '%'))"); 391 | 392 | query.table = 'person'; 393 | query.filters = '(likesBeer or isMale) eq true'; 394 | verifySqlFormatting(query, "SELECT * FROM [person] WHERE (([likesBeer] = @p1) OR ([isMale] = @p2))"); 395 | 396 | query.table = 'person'; 397 | query.filters = 'false eq (likesBeer or isMale)'; 398 | verifySqlFormatting(query, "SELECT * FROM [person] WHERE NOT (([likesBeer] = @p1) OR ([isMale] = @p2))"); 399 | }); 400 | 401 | it("mixed bit boolean conversions", function () { 402 | var query = { 403 | table: 'person', 404 | filters: "(endswith(name, 'foo') eq true) and (likesBeer)" 405 | }; 406 | verifySqlFormatting(query, "SELECT * FROM [person] WHERE (([name] LIKE ('%' + @p1)) AND ([likesBeer] = @p2))"); 407 | }); 408 | 409 | it("addition", function () { 410 | var query = { 411 | table: 'products', 412 | filters: "price add 1.00 lt 5.00" 413 | }; 414 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE (([price] + @p1) < @p2)"); 415 | }); 416 | 417 | it("multiplication", function () { 418 | var query = { 419 | table: 'products', 420 | filters: "price mul 1.25 lt 5.00" 421 | }; 422 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE (([price] * @p1) < @p2)"); 423 | }); 424 | 425 | it("division", function () { 426 | var query = { 427 | table: 'products', 428 | filters: "price div 1.25 lt 5.00" 429 | }; 430 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE (([price] / @p1) < @p2)"); 431 | }); 432 | 433 | // Bug#599392 434 | it("modulo", function () { 435 | var query = { 436 | table: 'products', 437 | filters: "price mod 1.25 lt 5.00" 438 | }; 439 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE ((CONVERT(numeric, [price]) % @p1) < @p2)"); 440 | }); 441 | 442 | it("grouping", function () { 443 | var query = { 444 | table: 'products', 445 | filters: "((name ne 'Doritos') or (price lt 5.00))" 446 | }; 447 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE (([name] != @p1) OR ([price] < @p2))"); 448 | }); 449 | 450 | it("null literal equality", function () { 451 | var query = { 452 | table: 'products', 453 | filters: "name eq null" 454 | }; 455 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE ([name] IS NULL)"); 456 | }); 457 | 458 | it("null literal inequality", function () { 459 | var query = { 460 | table: 'products', 461 | filters: "name ne null" 462 | }; 463 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE ([name] IS NOT NULL)"); 464 | }); 465 | 466 | it("string length", function () { 467 | var query = { 468 | table: 'products', 469 | filters: "length(name) gt 5" 470 | }; 471 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE ((LEN([name] + 'X') - 1) > @p1)"); 472 | 473 | // pass a string concat expression into length 474 | query = { 475 | table: 'products', 476 | filters: "length(concat(name, category)) gt 5" 477 | }; 478 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE ((LEN(([name] || [category]) + 'X') - 1) > @p1)"); 479 | }); 480 | 481 | it("string startswith", function () { 482 | var query = { 483 | table: 'products', 484 | filters: "startswith(name, 'Abc')" 485 | }; 486 | var statements = verifySqlFormatting(query, "SELECT * FROM [products] WHERE ([name] LIKE (@p1 + '%'))"); 487 | equal(statements.length, 1); 488 | equal(statements[0].parameters[0].value, 'Abc'); 489 | }); 490 | 491 | it("string endswith", function () { 492 | var query = { 493 | table: 'products', 494 | filters: "endswith(name, 'Abc')" 495 | }; 496 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE ([name] LIKE ('%' + @p1))"); 497 | }); 498 | 499 | it("string substringof", function () { 500 | var query = { 501 | table: 'products', 502 | filters: "substringof('Abc', name)" 503 | }; 504 | var statements = verifySqlFormatting(query, "SELECT * FROM [products] WHERE ([name] LIKE ('%' + @p1 + '%'))"); 505 | equal(statements.length, 1); 506 | equal(statements[0].parameters[0].value, 'Abc'); 507 | }); 508 | 509 | it("string indexof", function () { 510 | var query = { 511 | table: 'products', 512 | filters: "indexof(name, 'Abc') eq 5" 513 | }; 514 | var statements = verifySqlFormatting(query, "SELECT * FROM [products] WHERE ((INSTR([name], @p1) - 1) = @p2)"); 515 | equal(statements.length, 1); 516 | equal(statements[0].parameters[0].value, 'Abc'); 517 | equal(statements[0].parameters[1].value, 5); 518 | }); 519 | 520 | it("string concat", function () { 521 | var query = { 522 | table: 'customers', 523 | filters: "concat(concat(city, ', '), country) eq 'Berlin, Germany'" 524 | }; 525 | var statements = verifySqlFormatting(query, 526 | "SELECT * FROM [customers] WHERE ((([city] || @p1) || [country]) = @p2)"); 527 | equal(statements.length, 1); 528 | equal(statements[0].parameters[0].value, ', '); 529 | equal(statements[0].parameters[1].value, 'Berlin, Germany'); 530 | }); 531 | 532 | it("string replace", function () { 533 | var query = { 534 | table: 'products', 535 | filters: "replace(name, ' ', '') eq 'ApplePie'" 536 | }; 537 | var statements = verifySqlFormatting(query, "SELECT * FROM [products] WHERE (REPLACE([name], @p1, @p2) = @p3)"); 538 | equal(statements.length, 1); 539 | equal(statements[0].parameters[0].value, ' '); 540 | equal(statements[0].parameters[1].value, ''); 541 | equal(statements[0].parameters[2].value, 'ApplePie'); 542 | }); 543 | 544 | it("string substring", function () { 545 | // first overload not taking an explicit length - will return 546 | // the rest of the string 547 | var query = { 548 | table: 'books', 549 | filters: "substring(title, 1) eq 'he Rise and Fall of the Roman Empire'" 550 | }; 551 | var statements = verifySqlFormatting(query, "SELECT * FROM [books] WHERE (SUBSTR([title], @p1 + 1, LEN([title])) = @p2)"); 552 | equal(statements.length, 1); 553 | equal(statements[0].parameters[0].value, 1); 554 | equal(statements[0].parameters[1].value, 'he Rise and Fall of the Roman Empire'); 555 | 556 | // second overload taking a length 557 | query.filters = "substring(title, 1, 10) eq 'he Rise and Fall of the Roman Empire'"; 558 | statements = verifySqlFormatting(query, "SELECT * FROM [books] WHERE (SUBSTR([title], @p1 + 1, @p2) = @p3)"); 559 | equal(statements.length, 1); 560 | equal(statements[0].parameters[0].value, 1); 561 | equal(statements[0].parameters[1].value, 10); 562 | equal(statements[0].parameters[2].value, 'he Rise and Fall of the Roman Empire'); 563 | }); 564 | 565 | it("string trim", function () { 566 | var query = { 567 | table: 'products', 568 | filters: "trim(name) eq 'foobar'" 569 | }; 570 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE (LTRIM(RTRIM([name])) = @p1)"); 571 | }); 572 | 573 | it("string tolower", function () { 574 | var query = { 575 | table: 'products', 576 | filters: "tolower(name) eq 'tasty treats'" 577 | }; 578 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE (LOWER([name]) = @p1)"); 579 | }); 580 | 581 | it("string toupper", function () { 582 | var query = { 583 | table: 'products', 584 | filters: "toupper(name) eq 'TASTY TREATS'" 585 | }; 586 | verifySqlFormatting(query, "SELECT * FROM [products] WHERE (UPPER([name]) = @p1)"); 587 | }); 588 | 589 | it("string concat", function () { 590 | var query = { 591 | table: 'products', 592 | filters: "concat(name, 'Bar') eq 'FooBar'" 593 | }; 594 | var statements = verifySqlFormatting(query, "SELECT * FROM [products] WHERE (([name] || @p1) = @p2)"); 595 | equal(statements.length, 1); 596 | equal(statements[0].parameters[0].value, 'Bar'); 597 | equal(statements[0].parameters[1].value, 'FooBar'); 598 | }); 599 | 600 | it("date functions ", function () { 601 | var query = { 602 | table: 'checkins', 603 | filters: "day(checkinDate) lt 25" 604 | }; 605 | var statements = verifySqlFormatting(query, "SELECT * FROM [checkins] WHERE (DAY([checkinDate]) < @p1)"); 606 | equal(statements.length, 1); 607 | equal(statements[0].parameters[0].value, 25); 608 | 609 | query.filters = "month(checkinDate) eq 8"; 610 | statements = verifySqlFormatting(query, "SELECT * FROM [checkins] WHERE (MONTH([checkinDate]) = @p1)"); 611 | equal(statements.length, 1); 612 | equal(statements[0].parameters[0].value, 8); 613 | 614 | query.filters = "year(checkinDate) gt 1974"; 615 | statements = verifySqlFormatting(query, "SELECT * FROM [checkins] WHERE (YEAR([checkinDate]) > @p1)"); 616 | equal(statements.length, 1); 617 | equal(statements[0].parameters[0].value, 1974); 618 | 619 | query.filters = "hour(checkinDate) gt 6"; 620 | statements = verifySqlFormatting(query, "SELECT * FROM [checkins] WHERE (DATEPART(HOUR, [checkinDate]) > @p1)"); 621 | 622 | query.filters = "minute(checkinDate) eq 33"; 623 | statements = verifySqlFormatting(query, "SELECT * FROM [checkins] WHERE (DATEPART(MINUTE, [checkinDate]) = @p1)"); 624 | 625 | query.filters = "second(checkinDate) lt 30"; 626 | statements = verifySqlFormatting(query, "SELECT * FROM [checkins] WHERE (DATEPART(SECOND, [checkinDate]) < @p1)"); 627 | }); 628 | 629 | it("math functions", function () { 630 | var query = { 631 | table: 'books', 632 | filters: "floor(price) lt 77" 633 | }; 634 | var statements = verifySqlFormatting(query, "SELECT * FROM [books] WHERE (FLOOR([price]) < @p1)"); 635 | equal(statements.length, 1); 636 | equal(statements[0].parameters[0].value, 77); 637 | 638 | query.filters = "ceiling(price) eq 8"; 639 | statements = verifySqlFormatting(query, "SELECT * FROM [books] WHERE (CEILING([price]) = @p1)"); 640 | equal(statements.length, 1); 641 | equal(statements[0].parameters[0].value, 8); 642 | 643 | query.filters = "round(price) gt 19.00"; 644 | statements = verifySqlFormatting(query, "SELECT * FROM [books] WHERE (ROUND([price], 0) > @p1)"); 645 | equal(statements.length, 1); 646 | equal(statements[0].parameters[0].value, 19.00); 647 | }); 648 | 649 | it("simple paging query", function () { 650 | var query = { 651 | table: 'books', 652 | skip: 4, 653 | take: 5 654 | }; 655 | var expectedSql = "SELECT * FROM [books] LIMIT 5 OFFSET 4"; 656 | verifySqlFormatting(query, expectedSql); 657 | }); 658 | 659 | it("uses table specified in table config", function () { 660 | var query = { 661 | table: 'query' 662 | }; 663 | var expectedSql = "SELECT * FROM [tableName]"; 664 | verifySqlFormatting(query, expectedSql, { idType: "number", binaryColumns: [], name: 'tableName' }); 665 | }) 666 | 667 | it("paging query with filter and select", function () { 668 | var query = { 669 | table: 'books', 670 | filters: "type eq 'psychology'", 671 | selections: 'title,type,price', 672 | skip: 4, 673 | take: 5 674 | }; 675 | var expectedSql = "SELECT [title], [type], [price] FROM [books] WHERE ([type] = @p1) LIMIT 5 OFFSET 4"; 676 | verifySqlFormatting(query, expectedSql); 677 | }); 678 | 679 | it("paging query with filter and select and ordering", function () { 680 | var query = { 681 | table: 'books', 682 | filters: "type eq 'psychology'", 683 | selections: 'title,type,price', 684 | ordering: 'price desc', 685 | skip: 4, 686 | take: 5 687 | }; 688 | var expectedSql = "SELECT [title], [type], [price] FROM [books] WHERE ([type] = @p1) ORDER BY [price] DESC LIMIT 5 OFFSET 4"; 689 | verifySqlFormatting(query, expectedSql); 690 | }); 691 | 692 | it("datetime expression", function () { 693 | var query = { 694 | table: 'checkins', 695 | filters: "checkinDate lt datetime'2000-12-12T12:00:00Z'" 696 | }; 697 | var statements = verifySqlFormatting(query, "SELECT * FROM [checkins] WHERE ([checkinDate] < @p1)"); 698 | 699 | equal(statements.length, 1); 700 | var value = statements[0].parameters[0].value; 701 | equal(value.constructor, Date); 702 | 703 | // try a parse failure case 704 | var expectedExceptionCaught = false; 705 | try { 706 | query.filters = "checkinDate lt datetime'2000x12-12blah2:00'"; 707 | verifySqlFormatting(query, "SELECT * FROM [checkins] WHERE ([checkinDate] < @p1)"); 708 | } 709 | catch (e) { 710 | expectedExceptionCaught = true; 711 | equal(e.message, "Invalid 'datetime' type creation expression (at index 23)"); 712 | } 713 | equal(expectedExceptionCaught, true); 714 | }); 715 | 716 | it("datetimeoffset expression", function () { 717 | var query = { 718 | table: 'checkins', 719 | filters: "checkinDate lt datetimeoffset'2000-12-12T04:00:00.0000000-08:00'" 720 | }; 721 | var statements = verifySqlFormatting(query, "SELECT * FROM [checkins] WHERE ([checkinDate] < @p1)"); 722 | 723 | equal(statements.length, 1); 724 | var value = statements[0].parameters[0].value; 725 | equal(value.constructor, Date); 726 | equal(value.toISOString(), '2000-12-12T12:00:00.000Z'); 727 | }); 728 | 729 | it("parse multiple quotes", function () { 730 | var query = { 731 | table: 'products', 732 | filters: "description eq 'lots of qu''ote''''s i''n he''r''e!'" 733 | }, 734 | expectedSql = "SELECT * FROM [products] WHERE ([description] = @p1)"; 735 | 736 | var statements = verifySqlFormatting(query, expectedSql, { idType: "number", binaryColumns: [] }) 737 | equal(statements.length, 1); 738 | equal(statements[0].parameters[0].value, "lots of qu'ote''s i'n he'r'e!"); 739 | }); 740 | 741 | it("converts base64 version columns to binary buffers", function () { 742 | var query = { 743 | table: 'products', 744 | filters: "version eq 'AAAAAAAAUDU='" 745 | }, 746 | statements = formatSql(query); 747 | equal(statements.length, 1); 748 | equal(statements[0].parameters[0].value.constructor, Buffer); 749 | equal(statements[0].parameters[0].value.toString('base64'), 'AAAAAAAAUDU='); 750 | }); 751 | 752 | it("verify function arguments", function () { 753 | var testCases = [ 754 | // date functions 755 | { filters: "day(a, b, c)", expectedParamCount: 1 }, 756 | { filters: "day()", expectedParamCount: 1 }, 757 | { filters: "month(a, b, c)", expectedParamCount: 1 }, 758 | { filters: "month()", expectedParamCount: 1 }, 759 | { filters: "year(a, b, c)", expectedParamCount: 1 }, 760 | { filters: "year()", expectedParamCount: 1 }, 761 | { filters: "hour()", expectedParamCount: 1 }, 762 | { filters: "minute()", expectedParamCount: 1 }, 763 | { filters: "second()", expectedParamCount: 1 }, 764 | { filters: "floor(a, b, c)", expectedParamCount: 1 }, 765 | { filters: "ceiling(a, b, c)", expectedParamCount: 1 }, 766 | { filters: "round(a, b, c)", expectedParamCount: 1 }, 767 | 768 | // string functions 769 | { filters: "substringof(a)", expectedParamCount: 2 }, 770 | { filters: "endswith(a)", expectedParamCount: 2 }, 771 | { filters: "startswith(a)", expectedParamCount: 2 }, 772 | { filters: "concat(a)", expectedParamCount: 2 }, 773 | { filters: "tolower(a, b)", expectedParamCount: 1 }, 774 | { filters: "toupper()", expectedParamCount: 1 }, 775 | { filters: "length()", expectedParamCount: 1 }, 776 | { filters: "trim(a, 5)", expectedParamCount: 1 }, 777 | { filters: "indexof(a)", expectedParamCount: 2 }, 778 | { filters: "replace(a)", expectedParamCount: 3 }, 779 | { filters: "substring(a)", expectedParamCount: 3, expectedError: "Function 'substring' requires 2 or 3 parameters." }, 780 | { filters: "concat()", expectedParamCount: 2 }, 781 | 782 | // math functions 783 | { filters: "floor()", expectedParamCount: 1 }, 784 | { filters: "ceiling()", expectedParamCount: 1 }, 785 | { filters: "round()", expectedParamCount: 1 } 786 | ]; 787 | 788 | for (var idx in testCases) { 789 | var testCase = testCases[idx], 790 | query = { 791 | table: 'foo', 792 | filters: testCase.filters 793 | }, 794 | expectedExceptionCaught = false; 795 | 796 | try { 797 | formatSql(query, 'testapp', { idType: "number", binaryColumns: [] }); 798 | } 799 | catch (e) { 800 | expectedExceptionCaught = true; 801 | var expectedError; 802 | if (!testCase.expectedError) { 803 | var parenIdx = testCase.filters.indexOf('('); 804 | var functionName = testCase.filters.substr(0, parenIdx); 805 | expectedError = "Function '" + functionName + "' requires " + testCase.expectedParamCount; 806 | expectedError += (testCase.expectedParamCount > 1) ? " parameters." : " parameter."; 807 | } 808 | else { 809 | expectedError = testCase.expectedError; 810 | } 811 | equal(e.message, expectedError); 812 | } 813 | equal(expectedExceptionCaught, true); 814 | } 815 | }); 816 | 817 | it("SQL statement formatting with schema specified", function () { 818 | var query = { 819 | table: 'books' 820 | }, 821 | statements = formatSql(query, { flavor: 'sqlite', schema: 'someschema' }); 822 | 823 | equal(statements.length, 1); 824 | equal(statements[0].sql, "SELECT * FROM [books]"); 825 | }); 826 | 827 | function verifySqlFormatting(query, expectedSql, metadata) { 828 | 829 | if (metadata) { 830 | metadata.flavor = 'sqlite'; 831 | } else { 832 | metadata = { idType: "number", binaryColumns: [], flavor: 'sqlite' }; 833 | } 834 | 835 | var statements = formatSql(query, metadata); 836 | 837 | var expectedStatements = expectedSql; 838 | if (expectedSql.constructor !== Array) { 839 | expectedStatements = [expectedSql]; 840 | } 841 | 842 | for (var i = 0; i < statements.length; i++) { 843 | equal(statements[i].sql, expectedStatements[i]); 844 | } 845 | 846 | return statements; 847 | } 848 | }) 849 | --------------------------------------------------------------------------------