@demmings/gssql
Version:
Google Sheets QUERY function replacement using real SQL select syntax.
1,293 lines (1,100 loc) • 111 kB
JavaScript
/* *** DEBUG START ***
// Remove comments for testing in NODE
export { DERIVEDTABLE, VirtualFields, VirtualField, SelectTables, TableFields, TableField, CalculatedField, SqlServerFunctions, DerivedTable, FieldComparisons };
import { Table } from './Table.js';
import { Sql, BindData, TableExtract } from './Sql.js';
import { SqlParse } from './SimpleParser.js';
import { JoinTables } from './JoinTables.js';
// *** DEBUG END ***/
const DERIVEDTABLE = "::DERIVEDTABLE::";
/**
* @classdesc
* Perform SQL SELECT operations to retrieve requested data.
*/
class SelectTables {
/**
* @param {Object} ast - Abstract Syntax Tree
* @param {Map<String,Table>} tableInfo - Map of table info.
* @param {BindData} bindVariables - List of bind data.
*/
constructor(ast, tableInfo, bindVariables) {
/** @property {String} - primary table name. */
this.primaryTable = ast.FROM.table;
/** @property {Object} - AST of SELECT fields */
this.astFields = ast.SELECT;
/** @property {Map<String,Table>} tableInfo - Map of table info. */
this.tableInfo = tableInfo;
/** @property {BindData} - Bind variable data. */
this.bindVariables = bindVariables;
/** @property {TableFields} */
this.tableFields = new TableFields();
/** @property {Table} - Primary table info. */
this.primaryTableInfo = tableInfo.get(this.primaryTable.toUpperCase());
/** @property {JoinTables} - Join table object. */
this.dataJoin = new JoinTables()
.setTableFields(this.tableFields)
.setTableInfo(this.tableInfo)
.setBindVariables(bindVariables)
.setPrimaryTableInfo(this.primaryTableInfo);
if (!tableInfo.has(this.primaryTable.toUpperCase()))
throw new Error(`Invalid table name: ${this.primaryTable}`);
// Keep a list of all possible fields from all tables.
this.tableFields.loadVirtualFields(this.primaryTable, tableInfo);
}
/**
* Update internal FIELDS list to indicate those fields that are in the SELECT fields - that will be returned in data.
* @param {Object} ast
* @returns {void}
*/
updateSelectedFields(ast) {
let astFields = ast.SELECT;
const tableInfo = this.dataJoin.isDerivedTable() ? this.dataJoin.derivedTable.tableInfo : this.primaryTableInfo;
// Expand any 'SELECT *' fields and add the actual field names into 'astFields'.
astFields = VirtualFields.expandWildcardFields(tableInfo, astFields);
// Define the data source of each field in SELECT field list.
this.tableFields.updateSelectFieldList(astFields, 0, false);
// These are fields REFERENCED, but not actually in the SELECT FIELDS.
// So columns referenced by GROUP BY, ORDER BY and not in SELECT.
// These temp columns need to be removed after processing.
if (ast["GROUP BY"] !== undefined) {
const referencedFields = this.getAggregateFunctionFieldsInGroupByCalculation(astFields);
this.tableFields.updateSelectFieldList(referencedFields, this.tableFields.getNextSelectColumnNumber(), true);
this.tableFields.updateSelectFieldList(ast["GROUP BY"], this.tableFields.getNextSelectColumnNumber(), true);
}
if (ast["ORDER BY"] !== undefined) {
this.tableFields.updateSelectFieldList(ast["ORDER BY"], this.tableFields.getNextSelectColumnNumber(), true);
}
}
/**
*
* @param {Object[]} astFields
* @returns {Object[]}
*/
getAggregateFunctionFieldsInGroupByCalculation(astFields) {
const fields = [];
const aggFuncList = ["SUM", "MIN", "MAX", "COUNT", "AVG", "DISTINCT", "GROUP_CONCAT"];
// When fld.terms is defined, it is a calculation, not just a single function.
const aggregateFunctions = astFields.filter(f => f.terms !== undefined);
for (const fld of aggregateFunctions) {
const functionString = SelectTables.toUpperCaseExceptQuoted(fld.name, true);
const usedFunctions = aggFuncList.map(func => SelectTables.parseForFunctions(functionString, func)).filter(f => f != null);
for (const parsedFunctionList of usedFunctions) {
this.tableFields.updateCalculatedFieldAsAggregateCalculation(fld.name);
if (!this.tableFields.isFieldAlreadyInSelectList(parsedFunctionList)) {
fields.push({ name: parsedFunctionList[0], as: '', order: '' });
}
}
}
return fields;
}
/**
* Process any JOIN condition.
* @param {Object} ast - Abstract Syntax Tree
* @returns {void}
*/
join(ast) {
if (ast.JOIN !== undefined) {
this.dataJoin.load(ast);
}
}
/**
* Retrieve filtered record ID's.
* @param {Object} ast - Abstract Syntax Tree
* @returns {Number[]} - Records ID's that match WHERE condition.
*/
whereCondition(ast) {
// Default is entire table is selected.
let conditions = { operator: "=", left: "\"A\"", right: "\"A\"" };
if (ast.WHERE !== undefined) {
conditions = ast.WHERE;
}
else if (ast["GROUP BY"] === undefined && ast.HAVING !== undefined) {
// This will work in mySql as long as select field is in having clause.
conditions = ast.HAVING;
}
let sqlData = [];
if (conditions.logic === undefined) {
sqlData = this.resolveCondition("OR", [conditions]);
}
else {
sqlData = this.resolveCondition(conditions.logic, conditions.terms);
}
return sqlData;
}
/**
* Recursively resolve WHERE condition and then apply AND/OR logic to results.
* @param {String} logic - logic condition (AND/OR) between terms
* @param {Object} terms - terms of WHERE condition (value compared to value)
* @returns {Number[]} - record ID's
*/
resolveCondition(logic, terms) {
const recordIDs = terms.map(cond => cond.logic === undefined
? this.getRecordIDs(cond)
: this.resolveCondition(cond.logic, cond.terms));
return SelectTables.applyLogicOperatorToRecordIds(logic, recordIDs);
}
/**
* Each array element in recordIDs is an array of record ID's.
* Either 'AND' or 'OR' logic is applied to the ID's to find the final set of record ID's.
* @param {String} logic ["AND", "OR"]
* @param {Number[][]} recordIDs
* @returns {Number[]}
*/
static applyLogicOperatorToRecordIds(logic, recordIDs) {
let results = [];
if (logic === "AND") {
results = recordIDs.reduce((a, b) => a.filter(c => b.includes(c)), recordIDs[0]);
}
else if (logic === "OR") {
results = Array.from(new Set(recordIDs.reduce((a, b) => a.concat(b), recordIDs[0])));
}
return results;
}
/**
* Find record ID's where condition is TRUE.
* @param {Object} condition - WHERE test condition
* @returns {Number[]} - record ID's which are true.
*/
getRecordIDs(condition) {
/** @type {Number[]} */
const recordIDs = [];
const leftFieldConditions = this.resolveFieldCondition(condition.left);
const rightFieldConditions = this.resolveFieldCondition(condition.right);
const conditionFunction = FieldComparisons.getComparisonFunction(condition.operator);
/** @type {Table} */
this.masterTable = this.dataJoin.isDerivedTable() ? this.dataJoin.getJoinedTableInfo() : this.primaryTableInfo;
const calcSqlField = new CalculatedField(this.masterTable, this.primaryTableInfo, this.tableFields);
for (let masterRecordID = 1; masterRecordID < this.masterTable.tableData.length; masterRecordID++) {
let leftValue = SelectTables.getConditionValue(leftFieldConditions, calcSqlField, masterRecordID);
let rightValue = SelectTables.getConditionValue(rightFieldConditions, calcSqlField, masterRecordID);
if (leftValue instanceof Date || rightValue instanceof Date) {
leftValue = SelectTables.dateToMs(leftValue);
rightValue = SelectTables.dateToMs(rightValue);
}
if (conditionFunction(leftValue, rightValue))
recordIDs.push(masterRecordID);
}
return recordIDs;
}
/**
* Evaulate value on left/right side of condition
* @param {ResolvedFieldCondition} fieldConditions - the value to be found will come from:
* * constant data
* * field data
* * calculated field
* * sub-query
* @param {CalculatedField} calcSqlField - data to resolve the calculated field.
* @param {Number} masterRecordID - current record in table to grab field data from
* @returns {any} - resolve value.
*/
static getConditionValue(fieldConditions, calcSqlField, masterRecordID) {
let fieldValue = fieldConditions.constantData;
if (fieldConditions.columnNumber >= 0) {
fieldValue = fieldConditions.fieldConditionTableInfo.tableData[masterRecordID][fieldConditions.columnNumber];
}
else if (fieldConditions.calculatedField !== "") {
fieldValue = "NULL";
if (fieldConditions.calculatedField.toUpperCase() !== "NULL") {
fieldValue = calcSqlField.evaluateCalculatedField(fieldConditions.calculatedField, masterRecordID);
}
}
else if (fieldConditions.subQuery !== null) {
const arrayResult = fieldConditions.subQuery.select(masterRecordID, calcSqlField);
if (arrayResult !== undefined && arrayResult !== null && arrayResult.length > 0) {
fieldValue = arrayResult[0][0];
}
}
return fieldValue;
}
/**
* Retrieve the data for the record ID's specified for ALL SELECT fields.
* @param {Number[]} recordIDs - record ID's which are SELECTed.
* @returns {any[][]} - double array of select data. No column title is included here.
*/
getViewData(recordIDs) {
const virtualData = [];
const calcSqlField = new CalculatedField(this.masterTable, this.primaryTableInfo, this.tableFields);
const subQuery = new CorrelatedSubQuery(this.tableInfo, this.tableFields, this.bindVariables);
const selectedFields = this.tableFields.getSelectFields();
for (const masterRecordID of recordIDs) {
const newRow = [];
for (const field of selectedFields) {
if (field.tableInfo !== null)
newRow.push(field.getData(masterRecordID));
else if (field.subQueryAst !== null) {
const result = subQuery.select(masterRecordID, calcSqlField, field.subQueryAst);
newRow.push(result[0][0]);
}
else if (field.calculatedFormula !== "") {
let result = null;
if (field.calculatedAggregateFunction === "") {
result = calcSqlField.evaluateCalculatedField(field.calculatedFormula, masterRecordID);
}
newRow.push(result);
}
}
virtualData.push(newRow);
}
return virtualData;
}
/**
* Returns the entire string in UPPER CASE - except for anything between quotes.
* @param {String} srcString - source string to convert.
* @param {Boolean} removeExtraSpaces - if true, will remove spaces EXCEPT within quotes.
* @returns {String} - converted string.
*/
static toUpperCaseExceptQuoted(srcString, removeExtraSpaces = false) {
let finalString = "";
let inQuotes = "";
for (let i = 0; i < srcString.length; i++) {
let ch = srcString.charAt(i);
if (inQuotes === "") {
if (ch === '"' || ch === "'") {
inQuotes = ch;
}
ch = removeExtraSpaces && ch === ' ' ? '' : ch.toUpperCase();
}
else if (ch === inQuotes) {
inQuotes = "";
}
finalString += ch;
}
return finalString;
}
/**
* Parse input string for 'func' and then parse if found.
* @param {String} functionString - Select field which may contain a function.
* @param {String} func - Function name to parse for.
* @returns {String[]} - Parsed function string.
* * null if function not found,
* * string array[0] - original string, e.g. **sum(quantity)**
* * string array[1] - function parameter, e.g. **quantity**
*/
static parseForFunctions(functionString, func) {
const args = [];
const expMatch = String.raw`\b%1\b\s*\(`;
const matchStr = new RegExp(expMatch.replace("%1", func));
const startMatchPos = functionString.search(matchStr);
if (startMatchPos !== -1) {
const searchStr = functionString.substring(startMatchPos);
let i = searchStr.indexOf("(");
const startLeft = i;
let leftBracket = 1;
for (i = i + 1; i < searchStr.length; i++) {
const ch = searchStr.charAt(i);
if (ch === "(") leftBracket++;
if (ch === ")") leftBracket--;
if (leftBracket === 0) {
args.push(
searchStr.substring(0, i + 1),
searchStr.substring(startLeft + 1, i)
);
return args;
}
}
}
return null;
}
/**
* Parse the input for a calculated field.
* String split on comma, EXCEPT if comma is within brackets (i.e. within an inner function)
* or within a string like ", "
* @param {String} paramString - Search and parse this string for parameters.
* @returns {String[]} - List of function parameters.
*/
static parseForParams(paramString, startBracket = "(", endBracket = ")") {
const args = [];
let bracketCount = 0;
let inQuotes = "";
let start = 0;
for (let i = 0; i < paramString.length; i++) {
const ch = paramString.charAt(i);
if (ch === "," && bracketCount === 0 && inQuotes === "") {
args.push(paramString.substring(start, i));
start = i + 1;
}
else {
bracketCount += SelectTables.functionBracketCounter(ch, startBracket, endBracket);
}
inQuotes = SelectTables.checkIfWithinString(ch, inQuotes);
}
const lastStr = paramString.substring(start);
if (lastStr !== "")
args.push(lastStr);
return args;
}
/**
* Track net brackets encountered in string.
* @param {String} ch
* @param {String} startBracket
* @param {String} endBracket
* @returns {Number}
*/
static functionBracketCounter(ch, startBracket, endBracket) {
if (ch === startBracket)
return 1;
else if (ch === endBracket)
return -1;
return 0;
}
/**
* Track if current ch(ar) is within quotes.
* @param {String} ch
* @param {String} inQuotes
* @returns {String} - Returns empty string if not within a string constant.
* If it is within a string, it will return either a single or double quote so we can
* determine when the string ends (it will match the starting quote.)
*/
static checkIfWithinString(ch, inQuotes) {
if (inQuotes === "") {
if (ch === '"' || ch === "'")
return ch;
}
else if (ch === inQuotes) {
return "";
}
return inQuotes;
}
/**
* Compress the table data so there is one record per group (fields in GROUP BY).
* The other fields MUST be aggregate calculated fields that works on the data in that group.
* @param {Object} ast - Abstract Syntax Tree
* @param {any[][]} viewTableData - Table data.
* @returns {any[][]} - Aggregated table data.
*/
groupBy(ast, viewTableData) {
let groupedTableData = viewTableData;
if (ast['GROUP BY'] !== undefined) {
groupedTableData = this.groupByFields(ast['GROUP BY'], viewTableData);
if (ast.HAVING !== undefined) {
groupedTableData = this.having(ast.HAVING, groupedTableData);
}
}
// If any conglomerate field functions (SUM, COUNT,...)
// we summarize all records into ONE.
else if (this.tableFields.getConglomerateFieldCount() > 0) {
const compressedData = [];
const conglomerate = new ConglomerateRecord(this.tableFields.getSelectFields());
compressedData.push(conglomerate.squish(viewTableData));
groupedTableData = compressedData;
}
return groupedTableData;
}
/**
* Group table data by group fields.
* @param {any[]} astGroupBy - AST group by fields.
* @param {any[][]} selectedData - table data
* @returns {any[][]} - compressed table data
*/
groupByFields(astGroupBy, selectedData) {
if (selectedData.length === 0)
return selectedData;
// Sort the least important first, and most important last.
astGroupBy.reverse();
selectedData = this.orderDataByListOfFields(astGroupBy, selectedData);
const groupedData = [];
let groupRecords = [];
const conglomerate = new ConglomerateRecord(this.tableFields.getSelectFields());
let lastKey = this.createGroupByKey(selectedData[0], astGroupBy);
for (const row of selectedData) {
const newKey = this.createGroupByKey(row, astGroupBy);
if (newKey !== lastKey) {
groupedData.push(conglomerate.squish(groupRecords));
lastKey = newKey;
groupRecords = [];
}
groupRecords.push(row);
}
if (groupRecords.length > 0)
groupedData.push(conglomerate.squish(groupRecords));
return groupedData;
}
/**
* Create a composite key that is comprised from all field data in group by clause.
* @param {any[]} row - current row of data.
* @param {any[]} astGroupBy - group by fields
* @returns {String} - group key
*/
createGroupByKey(row, astGroupBy) {
let key = "";
for (const orderField of astGroupBy) {
const selectColumn = this.tableFields.getSelectFieldColumn(orderField.name);
if (selectColumn !== -1)
key += row[selectColumn].toString();
}
return key;
}
/**
* Take the compressed data from GROUP BY and then filter those records using HAVING conditions.
* @param {Object} astHaving - AST HAVING conditons
* @param {any[][]} selectedData - compressed table data (from group by)
* @returns {any[][]} - filtered data using HAVING conditions.
*/
having(astHaving, selectedData) {
// Add in the title row for now
selectedData.unshift(this.tableFields.getColumnNames());
// Create our virtual GROUP table with data already selected.
const groupTable = new Table(this.primaryTable).loadArrayData(selectedData);
/** @type {Map<String, Table>} */
const tableMapping = new Map();
tableMapping.set(this.primaryTable.toUpperCase(), groupTable);
// Set up for our SQL.
const inSQL = new Sql().setTables(tableMapping);
// Fudge the HAVING to look like a SELECT.
const astSelect = {};
astSelect.FROM = { table: this.primaryTable, as: '' };
astSelect.SELECT = [{ name: "*" }];
astSelect.WHERE = astHaving;
return inSQL.execute(astSelect);
}
/**
* Take select data and sort by columns specified in ORDER BY clause.
* @param {Object} ast - Abstract Syntax Tree for SELECT
* @param {any[][]} selectedData - Table data to sort. On function return, this array is sorted.
* @returns {any[][]}
*/
orderBy(ast, selectedData) {
if (ast['ORDER BY'] === undefined)
return selectedData;
return this.orderDataByListOfFields(ast['ORDER BY'].reverse(), selectedData);
}
/**
*
* @param {any[]} orderedFieldList
* @param {any[][]} selectedData
* @returns {any[][]}
*/
orderDataByListOfFields(orderedFieldList, selectedData) {
for (const orderField of orderedFieldList) {
const selectColumn = this.tableFields.getSelectFieldColumn(orderField.name);
if (selectColumn === -1) {
throw new Error(`Invalid FIELD: ${orderField.name}`);
}
if (orderField.order !== undefined && orderField.order.toUpperCase() === "DESC") {
SelectTables.sortByColumnDESC(selectedData, selectColumn);
}
else {
// Default ordering is ASC.
SelectTables.sortByColumnASC(selectedData, selectColumn);
}
}
return selectedData;
}
/**
* Removes temporary fields from return data. These temporary fields were needed to generate
* the final table data, but are not included in the SELECT fields for final output.
* @param {any[][]} viewTableData - table data that may contain temporary columns.
* @returns {any[][]} - table data with temporary columns removed.
*/
removeTempColumns(viewTableData) {
const tempColumns = this.tableFields.getSelectedTempColumnNumbers();
if (tempColumns.length === 0)
return viewTableData;
for (const row of viewTableData) {
for (const col of tempColumns) {
row.splice(col, 1);
}
}
return viewTableData;
}
/**
* Returns the first 'x' records from table if a LIMIT is defined.
* @param {Object} ast AST that may contain a LIMIT clause
* @param {any[][]} viewTableData Table data before limit is applied.
* @returns {any[][]} Table data after limit is applied.
*/
static limit(ast, viewTableData) {
if (ast.LIMIT !== undefined) {
const maxItems = ast.LIMIT.nb;
if (viewTableData.length > maxItems)
viewTableData.splice(maxItems);
}
return viewTableData;
}
/**
* Sort the table data from lowest to highest using the data in colIndex for sorting.
* @param {any[][]} tableData - table data to sort.
* @param {Number} colIndex - column index which indicates which column to use for sorting.
* @returns {any[][]} - sorted table data.
*/
static sortByColumnASC(tableData, colIndex) {
tableData.sort(sortFunction);
/**
*
* @param {any} a
* @param {any} b
* @returns {Number}
*/
function sortFunction(a, b) {
if (a[colIndex] === b[colIndex]) {
return 0;
}
return (a[colIndex] < b[colIndex]) ? -1 : 1;
}
return tableData;
}
/**
* Sort the table data from highest to lowest using the data in colIndex for sorting.
* @param {any[][]} tableData - table data to sort.
* @param {Number} colIndex - column index which indicates which column to use for sorting.
* @returns {any[][]} - sorted table data.
*/
static sortByColumnDESC(tableData, colIndex) {
tableData.sort(sortFunction);
/**
*
* @param {any} a
* @param {any} b
* @returns {Number}
*/
function sortFunction(a, b) {
if (a[colIndex] === b[colIndex]) {
return 0;
}
return (a[colIndex] > b[colIndex]) ? -1 : 1;
}
return tableData;
}
/**
* @typedef {Object} ResolvedFieldCondition
* @property {Table} fieldConditionTableInfo
* @property {Number} columnNumber - use column data from this column, unless -1.
* @property {String} constantData - constant data used for column, unless null.
* @property {String} calculatedField - calculation of data for column, unless empty.
* @property {CorrelatedSubQuery} subQuery - use this correlated subquery object if not null.
*
*/
/**
* Determine what the source of value is for the current field condition.
* @param {Object} fieldCondition - left or right portion of condition
* @returns {ResolvedFieldCondition}
*/
resolveFieldCondition(fieldCondition) {
let constantData = null;
let columnNumber = -1;
let fieldConditionTableInfo = null;
let calculatedField = "";
let subQuery = null;
if (fieldCondition.SELECT !== undefined) {
// Maybe a SELECT within...
[subQuery, constantData] = this.resolveSubQuery(fieldCondition);
}
else if (SelectTables.isStringConstant(fieldCondition))
// String constant
constantData = SelectTables.extractStringConstant(fieldCondition);
else if (fieldCondition.startsWith('?')) {
// Bind variable data.
constantData = this.resolveBindData(fieldCondition);
}
else if (!isNaN(fieldCondition)) {
// Literal number.
constantData = fieldCondition;
}
else if (this.tableFields.hasField(fieldCondition)) {
// Table field.
columnNumber = this.tableFields.getFieldColumn(fieldCondition);
fieldConditionTableInfo = this.tableFields.getTableInfo(fieldCondition);
}
else {
// Calculated field?
calculatedField = fieldCondition;
}
return { fieldConditionTableInfo, columnNumber, constantData, calculatedField, subQuery };
}
/**
* Handle subquery. If correlated subquery, return object to handle, otherwise resolve and return constant data.
* @param {Object} fieldCondition - left or right portion of condition
* @returns {any[]}
*/
resolveSubQuery(fieldCondition) {
/** @type {CorrelatedSubQuery} */
let subQuery = null;
/** @type {String} */
let constantData = null;
if (SelectTables.isCorrelatedSubQuery(fieldCondition)) {
subQuery = new CorrelatedSubQuery(this.tableInfo, this.tableFields, this.bindVariables, fieldCondition);
}
else {
const subQueryTableInfo = SelectTables.getSubQueryTableSet(fieldCondition, this.tableInfo);
const inData = new Sql()
.setTables(subQueryTableInfo)
.setBindValues(this.bindVariables)
.execute(fieldCondition);
constantData = inData.join(",");
}
return [subQuery, constantData];
}
/**
* Get constant bind data
* @param {String} fieldCondition - left or right portion of condition
* @returns {any}
*/
resolveBindData(fieldCondition) {
// Bind variable data.
const constantData = this.bindVariables.get(fieldCondition);
if (constantData !== undefined) {
return constantData;
}
if (fieldCondition === '?') {
throw new Error("Bind variable naming is ?1, ?2... where ?1 is first bind data point in list.")
}
throw new Error(`Bind variable ${fieldCondition} was not found`);
}
/**
* Check if correlated sub-query is used.
* Check all table references in WHERE clause.
* Any table found NOT in FROM is deemed a reference to correlated subquery.
* @param {Object} ast
* @returns {Boolean} - TRUE if a reference to a WHERE table field not in FROM.
*/
static isCorrelatedSubQuery(ast) {
const tableSet = new Map();
TableExtract.extractAstTables(ast, tableSet);
const tableSetCorrelated = new Map();
if (ast.WHERE !== undefined) {
TableExtract.getTableNamesWhereCondition(ast.WHERE, tableSetCorrelated);
}
// @ts-ignore
for (const tableName of tableSetCorrelated.keys()) {
let isFound = false;
// @ts-ignore
for (const outerTable of tableSet.keys()) {
if (outerTable === tableName || tableSet.get(outerTable) === tableName) {
isFound = true;
break;
}
};
if (!isFound) {
return true;
}
}
return false;
}
/**
* Create a set of tables that are used in sub-query.
* @param {Object} ast - Sub-query AST.
* @param {Map<String,Table>} tableInfo - Master set of tables used for entire select.
* @returns {Map<String,Table>} - table set for sub-query.
*/
static getSubQueryTableSet(ast, tableInfo) {
const tableSubSet = new Map();
const selectTables = TableExtract.getReferencedTableNamesFromAst(ast);
for (const found of selectTables) {
if (found[0] !== "" && !tableSubSet.has(found[0])) {
tableSubSet.set(found[0], tableInfo.get(found[0]));
}
if (found[1] !== "" && !tableSubSet.has(found[1])) {
tableSubSet.set(found[1], tableInfo.get(found[1]));
}
}
return tableSubSet;
}
/**
* Is the string a constant in the SELECT condition.
* @param {String} value - condition to test
* @returns {Boolean} - Is this string a constant.
*/
static isStringConstant(value) {
return value.startsWith('"') && value.endsWith('"') || value.startsWith("'") && value.endsWith("'");
}
/**
* Extract the string literal out of condition. This removes surrounding quotes.
* @param {String} value - String that encloses literal string data.
* @returns {String} - String with quotes removed.
*/
static extractStringConstant(value) {
if (value.startsWith('"') && value.endsWith('"'))
return value.replaceAll('"', '');
if (value.startsWith("'") && value.endsWith("'"))
return value.replaceAll("'", '');
return value;
}
/**
* Convert input into milliseconds.
* @param {any} value - date as as Date or String.
* @returns {Number} - date as ms.
*/
static dateToMs(value) {
let year = 0;
let month = 0;
let dayNum = 0;
if (value instanceof Date) {
year = value.getFullYear();
month = value.getMonth();
dayNum = value.getDate();
}
else if (typeof value === "string") {
const dateParts = value.split("/"); // We assume MM/DD/YY (this could be improved)
if (dateParts.length === 3) {
year = Number(dateParts[2]);
month = Number(dateParts[0]) - 1;
dayNum = Number(dateParts[1]);
}
if (dateParts.length !== 3 || (year === 0 && month === 0 && dayNum === 0)) {
return null;
}
}
const newDate = new Date(Date.UTC(year, month, dayNum, 12, 0, 0, 0));
return newDate.getTime();
}
/**
* Return a list of column titles for this table.
* @param {String} columnTableNameReplacement
* @returns {String[]} - column titles
*/
getColumnTitles(columnTableNameReplacement) {
return this.tableFields.getColumnTitles(columnTableNameReplacement);
}
}
/**
* @classdesc
* Finds a function to be used for doing data comparisons.
* The WHERE condition needs to execute the exact same data comparison for all records, so
* there is no need to find (through the switch) what to execute for every record.
*/
class FieldComparisons {
/**
* Returns a function to be used for data comparisons.
* @param {String} operator SQL comparison operator.
* @returns {function}
}}
*/
static getComparisonFunction(operator) {
switch (operator.toUpperCase()) {
case "=":
return (leftValue, rightValue) => { [leftValue, rightValue] = FieldComparisons.parmsToUpperCase(leftValue, rightValue); return leftValue !== null && rightValue !== null && leftValue == rightValue }; // skipcq: JS-0050
case ">":
return (leftValue, rightValue) => { [leftValue, rightValue] = FieldComparisons.parmsToUpperCase(leftValue, rightValue); return leftValue !== null && rightValue !== null && leftValue > rightValue };
case "<":
return (leftValue, rightValue) => { [leftValue, rightValue] = FieldComparisons.parmsToUpperCase(leftValue, rightValue); return leftValue !== null && rightValue !== null && leftValue < rightValue };
case ">=":
return (leftValue, rightValue) => { [leftValue, rightValue] = FieldComparisons.parmsToUpperCase(leftValue, rightValue); return leftValue !== null && rightValue !== null && leftValue >= rightValue };
case "<=":
return (leftValue, rightValue) => { [leftValue, rightValue] = FieldComparisons.parmsToUpperCase(leftValue, rightValue); return leftValue !== null && rightValue !== null && leftValue <= rightValue };
case "<>":
return (leftValue, rightValue) => { [leftValue, rightValue] = FieldComparisons.parmsToUpperCase(leftValue, rightValue); return leftValue !== null && rightValue !== null && leftValue != rightValue }; // skipcq: JS-0050
case "!=":
return (leftValue, rightValue) => { [leftValue, rightValue] = FieldComparisons.parmsToUpperCase(leftValue, rightValue); return leftValue !== null && rightValue !== null && leftValue != rightValue }; // skipcq: JS-0050
case "LIKE":
return (leftValue, rightValue) => { [leftValue, rightValue] = FieldComparisons.parmsToUpperCase(leftValue, rightValue); return FieldComparisons.likeCondition(leftValue, rightValue) };
case "NOT LIKE":
return (leftValue, rightValue) => { [leftValue, rightValue] = FieldComparisons.parmsToUpperCase(leftValue, rightValue); return FieldComparisons.notLikeCondition(leftValue, rightValue) };
case "IN":
return (leftValue, rightValue) => { [leftValue, rightValue] = FieldComparisons.parmsToUpperCase(leftValue, rightValue); return FieldComparisons.inCondition(leftValue, rightValue) };
case "NOT IN":
return (leftValue, rightValue) => { [leftValue, rightValue] = FieldComparisons.parmsToUpperCase(leftValue, rightValue); return !(FieldComparisons.inCondition(leftValue, rightValue)) };
case "IS NOT":
return (leftValue, rightValue) => { [leftValue, rightValue] = FieldComparisons.parmsToUpperCase(leftValue, rightValue); return !(FieldComparisons.isCondition(leftValue, rightValue)) };
case "IS":
return (leftValue, rightValue) => { [leftValue, rightValue] = FieldComparisons.parmsToUpperCase(leftValue, rightValue); return FieldComparisons.isCondition(leftValue, rightValue) };
case "EXISTS":
return (leftValue, rightValue) => { [, rightValue] = FieldComparisons.parmsToUpperCase(leftValue, rightValue); return FieldComparisons.existsCondition(rightValue) };
case "NOT EXISTS":
return (leftValue, rightValue) => { [, rightValue] = FieldComparisons.parmsToUpperCase(leftValue, rightValue); return !(FieldComparisons.existsCondition(rightValue)) };
default:
throw new Error(`Invalid Operator: ${operator}`);
}
}
/**
*
* @param {any} leftValue
* @param {any} rightValue
* @returns {[any,any]}
*/
static parmsToUpperCase(leftValue, rightValue) {
leftValue = typeof leftValue === 'string' ? leftValue.toUpperCase() : leftValue;
rightValue = typeof rightValue === 'string' ? rightValue.toUpperCase() : rightValue;
return [leftValue, rightValue];
}
/**
* Compare strings in LIKE condition
* @param {String} leftValue - string for comparison
* @param {String} rightValue - string with wildcard
* @returns {Boolean} - Do strings match?
*/
static likeCondition(leftValue, rightValue) {
if ((leftValue === null || rightValue === null) && !(leftValue === null && rightValue === null)) {
return false;
}
return FieldComparisons.likeConditionMatch(leftValue, rightValue) !== -1;
}
/**
* Compare strings in NOT LIKE condition
* @param {String} leftValue - string for comparison
* @param {String} rightValue - string with wildcard
* @returns {Boolean} - Do strings NOT match?
*/
static notLikeCondition(leftValue, rightValue) {
if ((leftValue === null || rightValue === null) && !(leftValue === null && rightValue === null)) {
return false;
}
return FieldComparisons.likeConditionMatch(leftValue, rightValue) === -1;
}
/**
* Compare strings in (NOT) LIKE condition
* @param {String} leftValue - string for comparison
* @param {String} rightValue - string with wildcard
* @returns {Number} - Found position (not found === -1)
*/
static likeConditionMatch(leftValue, rightValue) {
// @ts-ignore
const expanded = `^${rightValue.replaceAll("%", ".*").replaceAll("_", ".")}`;
const result = leftValue.search(expanded);
return result;
}
/**
* Check if leftValue is contained in list in rightValue
* @param {any} leftValue - value to find in right value
* @param {String} rightValue - list of comma separated values
* @returns {Boolean} - Is contained IN list.
*/
static inCondition(leftValue, rightValue) {
let items = [];
if (typeof rightValue === 'string') {
items = rightValue.split(",");
}
else {
// select * from table WHERE IN (select number from table)
// @ts-ignore
items = [rightValue.toString()];
}
let index = items.indexOf(leftValue);
if (index === -1 && typeof leftValue === 'number') {
index = items.indexOf(leftValue.toString());
}
return index !== -1;
}
/**
* If leftValue is empty (we will consider that as NULL), condition will be true
* @param {any} leftValue - test this value for NULL
* @param {any} rightValue - 'NULL' considered as NULL.
* @returns {Boolean} - Is leftValue NULL (like).
*/
static isCondition(leftValue, rightValue) {
return (leftValue === "" && rightValue === "NULL");
}
/**
* Test if input is not empty
* @param {*} rightValue - value to check if empty
* @returns - true if NOT empty
*/
static existsCondition(rightValue) {
return rightValue !== '';
}
}
/**
* @classdesc
* Evaulate calculated fields in SELECT statement. This is achieved by converting the request
* into javascript and then using 'Function' to evaulate it.
*/
class CalculatedField {
/**
*
* @param {Table} masterTable - JOINed table (unless not joined, then primary table)
* @param {Table} primaryTable - First table in SELECT
* @param {TableFields} tableFields - All fields from all tables
*/
constructor(masterTable, primaryTable, tableFields) {
/** @property {Table} */
this.masterTable = masterTable;
/** @property {Table} */
this.primaryTable = primaryTable;
/** @property {Map<String,String>} - Map key=calculated field in SELECT, value=javascript equivalent code */
this.sqlServerFunctionCache = new Map();
/** @property {TableField[]} */
this.masterFields = tableFields.allFields.filter((vField) => this.masterTable === vField.tableInfo);
/** @property {Map<String, TableField>} */
this.mapMasterFields = new Map();
for (const fld of this.masterFields) {
this.mapMasterFields.set(fld.fieldName, fld)
}
}
/**
* Get data from the table for the requested field name and record number
* @param {String} fldName - Name of field to get data for.
* @param {Number} masterRecordID - The row number in table to extract data from.
* @returns {any} - Data from table. undefined if not found.
*/
getData(fldName, masterRecordID) {
const vField = this.mapMasterFields.get(fldName);
if (vField === undefined)
return vField;
return vField.getData(masterRecordID);
}
/**
* Evaluate the calculated field for the current table record and return a value.
* @param {String} calculatedFormula - calculation from SELECT statement
* @param {Number} masterRecordID - current record ID.
* @returns {any} - Evaluated data from calculation.
*/
evaluateCalculatedField(calculatedFormula, masterRecordID) {
let result = "";
// e.g. special case. count(*)
if (calculatedFormula === "*") {
return "*";
}
const functionString = this.sqlServerCalcFields(calculatedFormula, masterRecordID);
try {
result = new Function(functionString)();
}
catch (ex) {
if (calculatedFormula !== '') {
throw new Error(`Invalid CALCULATED field: ${calculatedFormula}`);
}
throw new Error(`Calculated Field Error: ${ex.message}. ${functionString}`);
}
return result;
}
/**
* The program is attempting to build some javascript code which we can then execute to
* find the value of the calculated field. There are two parts.
* 1) Build LET statements to assign to all possible field name variants,
* 2) Add the 'massaged' calculated field so that it can be run in javascript.
* @param {String} calculatedFormula - calculation from SELECT statement
* @param {Number} masterRecordID - current table record ID.
* @returns {String} - String to be executed. It is valid javascript lines of code.
*/
sqlServerCalcFields(calculatedFormula, masterRecordID) {
// Working on a calculated field.
const objectsDeclared = new Map();
const variablesDeclared = new Map();
let myVars = "";
for (/** @type {TableField} */ const vField of this.masterFields) {
// Get the DATA from this field. We then build a series of LET statments
// and we assign that data to the field name that might be found in a calculated field.
let varData = vField.getData(masterRecordID);
if (typeof varData === "string") {
varData = varData.replaceAll('\t', ' ')
.replaceAll('\n', ' ')
.replaceAll('\r', ' ');
varData = `'${varData.replaceAll("'", String.raw`\'`)}'`;
}
else if (varData instanceof Date) {
varData = `'${varData}'`;
}
myVars += this.createAssignmentStatments(vField, objectsDeclared, variablesDeclared, varData);
}
const functionString = this.sqlServerFunctions(calculatedFormula);
return `${myVars} return ${functionString}`;
}
/**
* Creates a javascript code block. For the current field (vField), a variable is assigned the appropriate
* value from 'varData'. For example, if the column was 'ID' and the table was 'BOOKS'.
* ```
* "let BOOKS = {};BOOKS.ID = '9';"
* ```
* If the BOOKS object had already been declared, later variables would just be:
* ```
* "BOOKS.NAME = 'To Kill a Blue Jay';"
* ```
* @param {TableField} vField - current field that LET statements will be assigning to.
* @param {Map<String, Boolean>} objectsDeclared - tracks if TABLE name was been encountered yet.
* @param {Map<String, Boolean>} variablesDeclared - tracks if variables has already been assigned.
* @param {String} varData - the data from the table that will be assigned to the variable.
* @returns {String} - the javascript code block.
*/
createAssignmentStatments(vField, objectsDeclared, variablesDeclared, varData) {
let myVars = "";
for (const aliasName of vField.aliasNames) {
if ((this.primaryTable.tableName !== vField.tableInfo.tableName && !aliasName.includes("."))) {
continue;
}
if (aliasName.includes(".")) {
const parts = aliasName.split(".");
if (!objectsDeclared.has(parts[0])) {
myVars += `let ${parts[0]} = {};`;
objectsDeclared.set(parts[0], true);
}
myVars += `${aliasName} = ${varData};`;
}
else {
if (!variablesDeclared.has(aliasName)) {
myVars += `let ${aliasName} = ${varData};`;
variablesDeclared.set(aliasName, true);
}
}
}
return myVars;
}
/**
* Anything 'calculated' in SQL statement is converted to equivalent Javascript code.
* The input 'calculatedFormula' and resulting JS is placed in map so it does not need to be
* recalculated over and over again.
* @param {String} calculatedFormula - SQL statement calculation.
* @returns {String} - Equivalent SQL calculation in Javascript.
*/
sqlServerFunctions(calculatedFormula) {
// If this calculated field formula has already been put into the required format,
// pull this out of our cache rather than redo.
if (this.sqlServerFunctionCache.has(calculatedFormula))
return this.sqlServerFunctionCache.get(calculatedFormula);
const func = new SqlServerFunctions();
const functionString = func.convertToJs(calculatedFormula, this.masterFields);
// No need to recalculate for each row.
this.sqlServerFunctionCache.set(calculatedFormula, functionString);
return functionString;
}
}
/**
* @classdesc
* Correlated Sub-Query requires special lookups for every record in the primary table. */
class CorrelatedSubQuery {
/**
*
* @param {Map<String, Table>} tableInfo - Map of table info.
* @param {TableFields} tableFields - Fields from all tables.
* @param {BindData} bindData - List of bind data.
* @param {Object} defaultSubQuery - Select AST
*/
constructor(tableInfo, tableFields, bindData, defaultSubQuery = null) {
/** @property {Map<String, Table>} - Map of table info. */
this.tableInfo = tableInfo;
/** @property {TableFields} - Fields from all tables.*/
this.tableFields = tableFields;
/** @property {BindData} */
this.bindVariables = bindData;
/** @property {Object} - AST can be set here and skipped in select() statement. */
this.defaultSubQuery = defaultSubQuery;
}
/**
* Perform SELECT on sub-query using data from current record in outer table.
* @param {Number} masterRecordID - Current record number in outer table.
* @param {CalculatedField} calcSqlField - Calculated field object.
* @param {Object} ast - Sub-query AST.
* @returns {any[][]} - double array of selected table data.
*/
select(masterRecordID, calcSqlField, ast = this.defaultSubQuery) {
const innerTableInfo = this.tableInfo.get(ast.FROM.table.toUpperCase());
if (innerTableInfo === undefined)
throw new Error(`No table data found: ${ast.FROM.table}`);
// Add BIND variable for all matching fields in WHERE.
const tempAst = JSON.parse(JSON.stringify(ast));
const tempBindVariables = new BindData();
tempBindVariables.addList(this.bindVariables.getBindDataList());
this.replaceOuterFieldValueInCorrelatedWhere(calcSqlField, masterRecordID, tempAst, tempBindVariables);
const inData = new Sql()
.setTables(this.tableInfo)
.setBindValues(tempBindVariables)
.execute(tempAst);
return inData;
}
/**
* If we find the field name in the AST, just replace with '?' and add to bind data variable list.
* @param {CalculatedField} calcSqlField - List of fields in outer query. If any are found in subquery, the value of that field for the current record is inserted into subquery before it is executed.
* @param {Number} masterRecordID - current record number in outer query.
* @param {Object} tempAst - AST for subquery. Any field names found from outer query will be replaced with bind place holder '?'.
* @param {BindData} bindData
*/
replaceOuterFieldValueInCorrelatedWhere(calcSqlField, masterRecordID, tempAst, bindData) {
const where = tempAst.WHERE;
if (where === undefined)
return;
if (where.logic === undefined)
this.traverseWhere(calcSqlField, [where], masterRecordID, bindData);
else
this.traverseWhere(calcSqlField, where.terms, masterRecordID, bindData);
}
/**
* Search the WHERE portion of the subquery to find all references to the table in the outer query.
* @param {CalculatedField} calcSqlField - List of fields in outer query.
* @param {Object} terms - terms of WHERE. It is modified with bind