diff --git a/.cursorrules b/.cursorrules new file mode 100644 index 00000000..94f8df90 --- /dev/null +++ b/.cursorrules @@ -0,0 +1,21 @@ +# Original instructions: https://forum.cursor.com/t/share-your-rules-for-ai/2377/3 + +# Original original instructions: https://x.com/NickADobos/status/1814596357879177592 + +You are an expert AI programming assistant that primarily focuses on producing clear, readable Node.js and MongoDB code. + +You always use the latest version of Node.js, and MongoDB, and you are familiar with the latest features and best practices. + +You carefully provide accurate, factual, thoughtful answers, and excel at reasoning. + +This project is a translator library that takes in a SQL dialect called `noql` documented in the `/docs` folder, the objective of the library is to use the provided SQL statement to generate a valid and performant mongodb aggregation pipeline that can be executed to get data. + +- Follow the user’s requirements carefully & to the letter. +- First think step-by-step - describe your plan for what to build in javascript, written out in great detail. +- Confirm, then write code! +- Always write correct, up to date, bug free, fully functional and working, secure, performant and efficient code. +- Focus on readability over being performant. +- Fully implement all requested functionality. +- Leave NO todo’s, placeholders or missing pieces. +- Be concise. Minimize any other prose. +- If you think there might not be a correct answer, you say so. If you do not know the answer, say so instead of guessing. diff --git a/lib/make/apply-pivot.js b/lib/make/apply-pivot.js new file mode 100644 index 00000000..7fa1efbf --- /dev/null +++ b/lib/make/apply-pivot.js @@ -0,0 +1,398 @@ +const {functionByName} = require('../MongoFunctions'); + +module.exports = {applyPivot, applyUnpivot, applyMultipleUnpivots}; + +/** + * + * @param {string} pivotString + * @param {import('../types').PipelineFn[]} pipeline + * @param {import('../types').NoqlContext} context + */ +function applyPivot(pivotString, pipeline, context) { + const pivot = createJSONFromPivotString('pivot', pivotString); + + pivot.fields = pivot.fields.map((field) => { + const functionName = field.split('(')[0]; + const foundFunction = functionByName(functionName); + if (!foundFunction) { + throw new Error( + `Unable to find function "${functionName}" in pivot.fields."` + ); + } + let argumentString = field.replace(functionName, ''); + let name = ''; + if (argumentString.indexOf(' as ') >= 0) { + const parts = argumentString.split(' as '); + argumentString = parts[0]; + name = parts[1]; + } + argumentString = argumentString.substring(1, argumentString.length - 1); + const rawArguments = argumentString.split(','); + if (!name) { + name = rawArguments[0]; + } + const parsedArguments = rawArguments.map((arg) => + isNumeric(arg) ? parseFloat(arg) : `$${arg}` + ); + return { + name, + foundFunction, + parsedArguments, + }; + }); + + pipeline.push({ + $group: { + _id: `$${pivot.for}`, + ...pivot.fields.reduce((previousValue, currentValue) => { + const res = currentValue.foundFunction.parse( + ...currentValue.parsedArguments + ); + previousValue[currentValue.name] = res; + return previousValue; + }, {}), + }, + }); + pipeline.push({ + $group: { + _id: null, + data: { + $push: { + k: { + $toString: '$_id', + }, + v: + pivot.fields.length > 1 + ? { + ...pivot.fields.reduce( + (previousValue, currentValue) => { + previousValue[currentValue.name] = + `$${currentValue.name}`; + return previousValue; + }, + {} + ), + } + : `$${pivot.fields[0].name}`, + }, + }, + }, + }); + pipeline.push({ + $project: { + _id: 0, + data: { + $arrayToObject: '$data', + }, + }, + }); + pipeline.push({ + $project: { + result: { + $mergeObjects: [ + { + ...pivot.columns.reduce( + (previousValue, currentValue) => { + previousValue[currentValue] = null; + return previousValue; + }, + {} + ), + }, + '$data', + ], + }, + }, + }); + pipeline.push({ + $replaceRoot: { + newRoot: '$result', + }, + }); +} + +/** + * + * @param {string} str + * @returns {boolean} + */ +function isNumeric(str) { + if (typeof str != 'string') { + return false; + } + return !isNaN(str) && !isNaN(parseFloat(str)); +} + +/** + * + * @param {'pivot'|'unpivot'} type + * @param {string} inputString + * @returns {{columns: (*|*[]), for: (*|string), fields: *[]}} + */ +function createJSONFromPivotString(type, inputString) { + // Split the string by '|' + const parts = inputString.split('|'); + + const formatErrorMessage = `The ${type} operation had the wrong format`; + // Extract the field from the pivot function + let pivotPart = parts[1]; + let fieldMatch; + if (type === 'pivot') { + fieldMatch = pivotPart.match(/pivot\(\[(.*?)\]/); + } else { + fieldMatch = pivotPart.match(/unpivot\((.*?),/); + } + if (!fieldMatch || !fieldMatch[1] || !fieldMatch[1].trim()) { + throw new Error(formatErrorMessage); + } + + const fields = fieldMatch + ? fieldMatch[1] + .split(',') + .map((f) => f.trim()) + .filter(Boolean) + : []; + + if (!fields.length) { + throw new Error(formatErrorMessage); + } + pivotPart = pivotPart.replace(fieldMatch[0], ''); + if (type === 'unpivot') { + pivotPart = ',' + pivotPart; + } + // Extract the 'for' part + const forMatch = pivotPart.match(/,(.*?),\[/); + const forPart = forMatch ? forMatch[1].trim() : ''; + if (!forPart) { + throw new Error(formatErrorMessage); + } + pivotPart = pivotPart.replace(forMatch[0], ''); + // Extract the columns + const columnsMatch = pivotPart.match(/(.*?)\]/); + const columns = columnsMatch + ? columnsMatch[1] + .split(',') + .map((c) => c.trim()) + .filter(Boolean) + : []; + if (!columns.length) { + throw new Error(formatErrorMessage); + } + + // Construct the JSON object + return { + fields: fields, + for: forPart, + columns: columns, + }; +} + +/** + * + * @param {string} pivotString + * @param {import('../types').PipelineFn[]} pipeline + * @param {import('../types').PipelineFn} projection + * @param {import('../types').NoqlContext} context + */ +function applyUnpivot(pivotString, pipeline, projection, context) { + const unpivot = createJSONFromPivotString('unpivot', pivotString); + + const columnsToExclude = [unpivot.for, '_id'] + .concat(unpivot.columns) + .concat(unpivot.fields); + const columns = Object.keys(projection.$project).filter( + (val) => columnsToExclude.indexOf(val) === -1 + ); + pipeline.push({ + $project: { + ...columns.reduce((previousValue, currentValue) => { + previousValue[currentValue] = `$${currentValue}`; + return previousValue; + }, {}), + fields: { + $objectToArray: '$$ROOT', + }, + }, + }); + pipeline.push({ + $project: { + ...columns.reduce((previousValue, currentValue) => { + previousValue[currentValue] = 1; + return previousValue; + }, {}), + fields: { + $filter: { + input: '$fields', + as: 'field', + cond: { + $and: columns + .map((c) => ({$ne: ['$$field.k', c]})) + .concat([ + { + $or: unpivot.columns.map((c) => ({ + $eq: ['$$field.k', c], + })), + }, + ]), + }, + }, + }, + }, + }); + pipeline.push({ + $unwind: '$fields', + }); + pipeline.push({ + $project: { + ...columns.reduce((previousValue, currentValue) => { + previousValue[currentValue] = 1; + return previousValue; + }, {}), + [unpivot.for]: '$fields.k', + [unpivot.fields[0]]: '$fields.v', // Assuming 'Orders' should be numeric + }, + }); +} + +/** + * + * @param {string[]} pivotStrings + * @param pivotString + * @param {import('../types').PipelineFn[]} pipeline + * @param {import('../types').PipelineFn} projection + * @param {import('../types').NoqlContext} context + */ +function applyMultipleUnpivots(pivotStrings, pipeline, projection, context) { + const unpivots = pivotStrings.map((s) => + createJSONFromPivotString('unpivot', s) + ); + const unpivot = unpivots.reduce( + (previousValue, currentValue) => { + previousValue.for.push(currentValue.for); + previousValue.fields.push(...currentValue.fields); + previousValue.columns.push(...currentValue.columns); + return previousValue; + }, + {fields: [], for: [], columns: []} + ); + const columnsToExclude = [...unpivot.for, '_id'] + .concat(unpivot.columns) + .concat(unpivot.fields); + const columns = Object.entries(projection.$project) + .filter( + ([key, expression]) => + columnsToExclude.indexOf(key) === -1 && + expression.indexOf('.') > 0 + ) + .map(([key]) => key); + pipeline.push({ + $project: { + ...columns.reduce((previousValue, currentValue) => { + previousValue[currentValue] = `$${currentValue}`; + return previousValue; + }, {}), + fields: { + $objectToArray: '$$ROOT', + }, + }, + }); + pipeline.push({ + $project: { + ...columns.reduce((previousValue, currentValue) => { + previousValue[currentValue] = 1; + return previousValue; + }, {}), + fields: { + $filter: { + input: '$fields', + as: 'field', + cond: { + $and: columns + .map((c) => ({$ne: ['$$field.k', c]})) + .concat([ + { + $or: unpivot.columns.map((c) => ({ + $eq: ['$$field.k', c], + })), + }, + ]), + }, + }, + }, + }, + }); + pipeline.push({ + $unwind: '$fields', + }); + const columnProjection = { + $project: { + ...columns.reduce((previousValue, currentValue) => { + previousValue[currentValue] = 1; + return previousValue; + }, {}), + }, + }; + for (const unpivotOp of unpivots) { + columnProjection.$project[unpivotOp.fields[0]] = { + $cond: { + if: { + $or: unpivotOp.columns.map((c) => ({ + $eq: ['$fields.k', c], + })), + }, + then: '$fields.v', + else: '$$REMOVE', + }, + }; + } + pipeline.push(columnProjection); + pipeline.push({ + $group: { + _id: columns.reduce((previousValue, currentValue) => { + previousValue[currentValue] = `$${currentValue}`; + return previousValue; + }, {}), + ...unpivots.reduce((previousValue, currentValue) => { + previousValue[currentValue.for] = { + $push: `$${currentValue.fields[0]}`, + }; + return previousValue; + }, {}), + }, + }); + pipeline.push({ + $unwind: { + path: `$${unpivot.for[0]}`, + includeArrayIndex: '__unwindIndex', + preserveNullAndEmptyArrays: false, + }, + }); + const restOfFor = unpivot.for.splice(1); + const restOfFields = unpivot.fields.splice(1); + pipeline.push({ + $project: { + _id: 0, + ...columns.reduce((previousValue, currentValue) => { + previousValue[currentValue] = `$_id.${currentValue}`; + return previousValue; + }, {}), + [unpivot.fields[0]]: `$${unpivot.for[0]}`, + ...restOfFields.reduce( + (previousValue, currentValue, currentIndex) => { + previousValue[currentValue] = { + $arrayElemAt: [ + `$${restOfFor[currentIndex]}`, + '$__unwindIndex', + ], + }; + return previousValue; + }, + {} + ), + }, + }); + console.log(''); + /** + * + */ +} diff --git a/lib/make/makeAggregatePipeline.js b/lib/make/makeAggregatePipeline.js index a23797aa..926ba076 100644 --- a/lib/make/makeAggregatePipeline.js +++ b/lib/make/makeAggregatePipeline.js @@ -15,9 +15,13 @@ const { const $copy = require('clone-deep'); const {optimizeJoinAndWhere} = require('./optimize-join-and-where'); - +const { + applyPivot, + applyUnpivot, + applyMultipleUnpivots, +} = require('./apply-pivot'); exports.makeAggregatePipeline = makeAggregatePipeline; - +exports.stripJoinHints = stripJoinHints; /** * *Checks whether the query needs to force a group by @@ -335,7 +339,8 @@ function makeAggregatePipeline(ast, context = {}) { } else if ( ast.columns && !isSelectAll(ast.columns) && - ast.columns.length > 0 + ast.columns.length > 0 && + !context.projectionAlreadyAdded ) { /** @type {import('../types').Column[]} */ // @ts-ignore @@ -345,7 +350,7 @@ function makeAggregatePipeline(ast, context = {}) { column, result, context, - ast.from && ast.from[0] ? ast.from[0].as : null + ast.from && ast.from[0] ? stripJoinHints(ast.from[0].as) : null ); }); if (result.count.length > 0) { @@ -354,7 +359,7 @@ function makeAggregatePipeline(ast, context = {}) { if (result.unset) { pipeline.push(result.unset); } - if (result.windowFields) { + if (result.windowFields && result.windowFields.length) { for (const windowField of result.windowFields) { pipeline.push({ $setWindowFields: windowField, @@ -412,11 +417,44 @@ function makeAggregatePipeline(ast, context = {}) { if (!ast.from[0].as) { throw new Error(`AS not specified for initial sub query`); } - const tableAs = stripJoinHints(ast.from[0].as); - pipeline = makeAggregatePipeline(ast.from[0].expr.ast, context) - .concat([{$project: {[tableAs]: '$$ROOT'}}]) - .concat(pipeline); + const as = ast.from[0].as; + const tableAs = stripJoinHints(as); + result.subQueryRootProjections.push(tableAs); + if (as.indexOf('|pivot(') >= 0) { + const prevPipeline = pipeline; + pipeline = makeAggregatePipeline(ast.from[0].expr.ast, context); + applyPivot(as, pipeline, context); + pipeline = pipeline + .concat([{$project: {[tableAs]: '$$ROOT'}}]) + .concat(prevPipeline); + } else if (as.indexOf('|unpivot(') >= 0) { + const prevPipeline = pipeline; + pipeline = makeAggregatePipeline(ast.from[0].expr.ast, context); + const projection = prevPipeline + .slice() + .reverse() + .find((p) => !!p.$project); + const unpivots = as + .split('|unpivot') + .filter((u) => u.startsWith('(')) + .map((u) => '|unpivot' + u); + if (unpivots.length === 1) { + applyUnpivot(unpivots[0], pipeline, projection, context); + pipeline = pipeline + .concat([{$project: {[tableAs]: '$$ROOT'}}]) + .concat(prevPipeline); + } else { + applyMultipleUnpivots(unpivots, pipeline, projection, context); + pipeline = pipeline + .concat([{$project: {[tableAs]: '$$ROOT'}}]) + .concat(prevPipeline); + } + } else { + pipeline = makeAggregatePipeline(ast.from[0].expr.ast, context) + .concat([{$project: {[tableAs]: '$$ROOT'}}]) + .concat(pipeline); + } } if (result.replaceRoot) { @@ -789,12 +827,10 @@ function handleExcept(ast, context, pipeline) { * @returns {string} */ function stripJoinHints(input) { - return input - .replace('|first', '') - .replace('|last', '') - .replace('|unwind', '') - .replace('|optimize', '') - .replace('|nooptimize', ''); + if (!input) { + return input; + } + return input.split('|')[0]; } /** diff --git a/lib/make/makeJoinForPipeline.js b/lib/make/makeJoinForPipeline.js index 14969112..1db4d606 100644 --- a/lib/make/makeJoinForPipeline.js +++ b/lib/make/makeJoinForPipeline.js @@ -2,6 +2,8 @@ const makeFilterConditionModule = require('./makeFilterCondition'); const $check = require('check-types'); const $json = require('@synatic/json-magic'); const makeAggregatePipelineModule = require('./makeAggregatePipeline'); +const projectColumnParserModule = require('./projectColumnParser'); +const {createResultObject} = require('./createResultObject'); exports.makeJoinForPipeline = makeJoinForPipeline; @@ -44,7 +46,14 @@ function makeJoinForPipeline(ast, context) { .map((a) => a.split('|')[0]); for (let i = 1; i < ast.from.length; i++) { - makeJoinPart(ast.from[i], ast.from[i - 1], aliases, pipeline, context); + makeJoinPart( + ast.from[i], + ast.from[i - 1], + aliases, + pipeline, + context, + ast + ); } return pipeline; @@ -57,9 +66,10 @@ function makeJoinForPipeline(ast, context) { * @param {string[]} aliases - the aliases used in the joins * @param {import('../types').PipelineFn[]} pipeline * @param {import('../types').NoqlContext} context - The Noql context to use when generating the output + * @param {import('../types').TableColumnAst} ast * @returns {void} */ -function makeJoinPart(join, previousJoin, aliases, pipeline, context) { +function makeJoinPart(join, previousJoin, aliases, pipeline, context, ast) { let toTable = join.table || ''; let toAs = join.as || ''; @@ -87,7 +97,8 @@ function makeJoinPart(join, previousJoin, aliases, pipeline, context) { toTable, toAs, joinHints, - context + context, + ast ); } const prefixLeft = shouldPrefixSide('left'); @@ -277,6 +288,7 @@ function sanitizeOnCondition(condition, joinAliases) { * @param {string} toAs * @param {string[]} joinHints * @param {import('../types').NoqlContext} context - The Noql context to use when generating the output + * @param {import('../types').TableColumnAst} ast * @returns {void} */ function tableJoin( @@ -286,7 +298,8 @@ function tableJoin( toTable, toAs, joinHints, - context + context, + ast ) { let localPart; let fromPart; @@ -358,6 +371,87 @@ function tableJoin( } } else if (join.join === 'LEFT JOIN') { // dont need anything + } else if (join.join === 'FULL JOIN') { + const toCollection = toAs || toTable; + const localTable = previousJoin.table || localPart.table; + pipeline.push({ + $unwind: { + path: `$${toCollection}`, + preserveNullAndEmptyArrays: true, + }, + }); + pipeline.push({ + $unionWith: { + coll: toTable, + pipeline: [ + { + $lookup: { + from: localTable, + localField: localPart.column, + foreignField: fromPart.column, + as: localPart.table, + }, + }, + ], + }, + }); + pipeline.push({ + $unwind: { + path: `$${localPart.table}`, + preserveNullAndEmptyArrays: true, + }, + }); + const result = createResultObject(); + const columns = ast.columns; + columns.forEach((column) => { + projectColumnParserModule.projectColumnParser( + column, + result, + context, + ast.from && ast.from[0] + ? makeAggregatePipelineModule.stripJoinHints(ast.from[0].as) + : null + ); + }); + const project = (result.parsedProject || {}).$project; + if (!project || Object.keys(project).length === 0) { + throw new Error(`Unable to get $projection for full outer join`); + } + // todo need the projection part and the schema + pipeline.push({ + $project: { + ...Object.entries(project).reduce((previous, current) => { + const [key, value] = current; + previous[key] = { + $ifNull: [`$${key}`, value], + }; + return previous; + }, {}), + }, + }); + pipeline.push({ + $group: { + _id: { + ...Object.keys(project).reduce((previous, current) => { + previous[current] = `$${current}`; + return previous; + }, {}), + }, + }, + }); + pipeline.push({ + $project: { + _id: 0, + ...Object.keys(project).reduce((previous, current) => { + previous[current] = `$_id.${current}`; + return previous; + }, {}), + }, + }); + context.projectionAlreadyAdded = true; + if (result.unset) { + pipeline.push(result.unset); + } } else { throw new Error(`Join not supported:${join.join}`); } diff --git a/lib/types.ts b/lib/types.ts index 52a71404..f75d1878 100644 --- a/lib/types.ts +++ b/lib/types.ts @@ -200,6 +200,7 @@ export interface NoqlContext extends ParserOptions { tables: string[]; fullAst: TableColumnAst; joinHints?: string[]; + projectionAlreadyAdded?: boolean; } export interface ParseResult { diff --git a/package.json b/package.json index a9782276..0745a623 100644 --- a/package.json +++ b/package.json @@ -1,6 +1,6 @@ { "name": "@synatic/noql", - "version": "4.1.6", + "version": "4.1.7", "description": "Convert SQL statements to mongo queries or aggregates", "main": "index.js", "files": [ diff --git a/test/AAA_ALL_Profitability_Activities v2.sql b/test/AAA_ALL_Profitability_Activities v2.sql new file mode 100644 index 00000000..3bc1bfb1 --- /dev/null +++ b/test/AAA_ALL_Profitability_Activities v2.sql @@ -0,0 +1,189 @@ +SELECT DISTINCT + [Uniq Client ID], + [Lookup Code], + [Client Name], + UniqActivity, + ActivityCode, + [Activity Description], + [Who/Owner], + ID, + Event_Uniq, + Event_Date, + CONVERT(varchar, IIF(Event_Type = 1, 'Activity Created', + IIF(Event_Type = 2, 'Activity Closed', + IIF(Event_Type = 3, 'Note Created', + IIF(Event_Type = 4, 'Task Created', + IIF(Event_Type = 5, 'Attachment Created', '')))))) AS 'Event Type', + Event_Desc, + IIF(Event_Type = 5, FileExtension,'') AS 'File Type', + Activity_Status, + [Activity Dept], + [Branch], + [Profit Center], + [RiskAdvisor], + [AccountMgr], + [RACode], + [AMCode], + GETDATE() AS 'Last Refreshed' + +FROM + (SELECT + dbo.Client.UniqEntity AS 'Uniq Client ID', + dbo.Client.LookupCode AS 'Lookup Code', + dbo.Client.NameOf AS 'Client Name', + dbo.Activity.UniqActivity, + dbo.ActivityCode.ActivityCode, + IIF(dbo.Activity.UniqEmployee = -1,dbo.Workgroup.LookupCode,Activity_Owner.LookupCode) AS 'Who/Owner', + dbo.Activity.DescriptionOf AS 'Activity Description', + IIF(dbo.Activity.ClosedDate IS NULL, 'Open', 'Closed') AS Activity_Status, + IIF(dbo.Activity.UniqDepartment <> -1,Act_Dept.DepartmentCode,Pol_Dept.DepartmentCode) AS 'Activity Dept', + IIF(dbo.Activity.UniqBranch <> -1,Act_Branch.BranchCode,Pol_Branch.BranchCode) AS 'Branch', + IIF(dbo.Activity.UniqProfitCenter <> -1,Act_PC.ProfitCenterCode,Pol_PC.ProfitCenterCode) AS 'Profit Center', + + IIF(dbo.ActivityTask.StatusCode IS NULL, NULL, + IIF(dbo.ActivityTask.StatusCode = 'I', 'In Progress', + IIF(dbo.ActivityTask.StatusCode = 'A', 'Cancelled', + IIF(dbo.ActivityTask.StatusCode = 'N', 'Not Started', + IIF(dbo.ActivityTask.StatusCode = 'P', 'Marked N/A', + IIF(dbo.ActivityTask.StatusCode = 'C', 'Complete', 'PICNIC')))))) AS Task_Status, + + CONVERT(varchar(50),dbo.Activity.InsertedByCode) AS 'Act_Ins_By', + CONVERT(varchar(50),dbo.Activity.ClosedByCode) AS 'Act_Cls_By', + CONVERT(varchar(50),dbo.ActivityNote.InsertedByCode) AS 'Note_Ins_By', + CONVERT(varchar(50),dbo.ActivityTask.InsertedByCode) AS 'Task_Ins_By', + CONVERT(varchar(50),dbo.Attachment.InsertedByCode) AS 'Att_Ins_By', + + Act_Ins_ID.UniqSecurityUser AS 'Act_Ins_ID', + Act_Cls_ID.UniqSecurityUser AS 'Act_Cls_ID', + Note_Ins_ID.UniqSecurityUser AS 'Note_Ins_ID', + Task_Ins_ID.UniqSecurityUser AS 'Task_Ins_ID', + Att_Ins_ID.UniqSecurityUser AS 'Att_Ins_ID', + + DATEADD(HOUR, - 8, dbo.Activity.InsertedDate) AS 'Act_Ins_Date', + DATEADD(HOUR, - 8, dbo.Activity.ClosedDate) AS 'Act_Cls_Date', + DATEADD(HOUR, - 8, dbo.ActivityNote.InsertedDate) AS 'Note_Ins_Date', + DATEADD(HOUR, - 8, dbo.ActivityTask.InsertedDate) AS 'Task_Ins_Date', + DATEADD(HOUR, - 8, dbo.Attachment.AttachedDate) AS 'Att_Ins_Date', + + IIF(dbo.Activity.InsertedDate IS NULL, NULL, 1) AS 'Act_Ins_Event', + IIF(dbo.Activity.ClosedDate IS NULL, NULL, 2) AS 'Act_Cls_Event', + IIF(dbo.ActivityNote.InsertedDate IS NULL, NULL, 3) AS 'Note_Ins_Event', + IIF(dbo.ActivityTask.InsertedDate IS NULL, NULL, 4) AS 'Task_Ins_Event', + IIF(dbo.Attachment.AttachedDate IS NULL, NULL, 5) AS 'Att_Ins_Event', + + CONVERT(varchar(100), dbo.Activity.DescriptionOf) AS 'Act_Ins_Desc', + CONVERT(varchar(100), dbo.Activity.DescriptionOf) AS 'Act_Cls_Desc', + CONVERT(varchar(100), dbo.ActivityNote.Note) AS 'Note_Ins_Desc', + CONVERT(varchar(100), dbo.ActivityTask.DescriptionOf) AS 'Task_Ins_Desc', + CONVERT(varchar(100), CONCAT(dbo.Attachment.DescriptionOf,dbo.Attachment.FileExtension)) AS 'Att_Ins_Desc', + + dbo.Activity.UniqActivity AS 'Act_Ins_Uniq', + dbo.Activity.UniqActivity AS 'Act_Cls_Uniq', + dbo.ActivityNote.UniqActivityNote AS 'Note_Ins_Uniq', + dbo.ActivityTask.UniqActivityTask AS 'Task_Ins_Uniq', + dbo.Attachment.UniqAttachment AS 'Att_Ins_Uniq', + dbo.Attachment.FileExtension, + Svc_Role.RiskAdvisor, + Svc_Role.AccountMgr, + Svc_Role.RACode, + Svc_Role.AMCode + + + FROM dbo.Activity + LEFT OUTER JOIN dbo.Employee AS Activity_Owner ON dbo.Activity.UniqEmployee = Activity_Owner.UniqEntity + LEFT OUTER JOIN dbo.Workgroup ON dbo.Activity.UniqWorkGroup = dbo.Workgroup.UniqWorkGroup + LEFT OUTER JOIN dbo.ConfigureLkLanguageResource AS Workgroup_Name ON dbo.Workgroup.ConfigureLkLanguageResourceID = Workgroup_Name.ConfigureLkLanguageResourceID AND Workgroup_Name.CultureCode = 'en-US' + FULL OUTER JOIN dbo.ActivityCode ON dbo.Activity.UniqActivityCode = dbo.ActivityCode.UniqActivityCode + LEFT OUTER JOIN dbo.Client ON dbo.Activity.UniqEntity = dbo.Client.UniqEntity + LEFT OUTER JOIN dbo.Department AS Act_Dept ON dbo.Activity.UniqDepartment = Act_Dept.UniqDepartment + LEFT OUTER JOIN dbo.Branch AS Act_Branch ON dbo.Activity.UniqBranch = Act_Branch.UniqBranch + LEFT OUTER JOIN dbo.ProfitCenter AS Act_PC ON dbo.Activity.UniqProfitCenter = Act_PC.UniqProfitCenter + + LEFT OUTER JOIN dbo.SecurityUser AS Act_Ins_ID ON dbo.Activity.InsertedByCode = Act_Ins_ID.UserCode + LEFT OUTER JOIN dbo.SecurityUser AS Act_Cls_ID ON dbo.Activity.InsertedByCode = Act_Cls_ID.UserCode + + FULL OUTER JOIN dbo.ActivityNote ON dbo.Activity.UniqActivity = dbo.ActivityNote.UniqActivity --AND (dbo.ActivityNote.InsertedDate BETWEEN DATEADD(MONTH,-13,DATEADD(MONTH,DATEDIFF(MONTH,0,GETDATE()),0)) AND EOMONTH(DATEADD(MONTH,-2,DATEADD(MONTH,DATEDIFF(MONTH,0,GETDATE()),0)))) + LEFT OUTER JOIN dbo.SecurityUser AS Note_Ins_ID ON dbo.ActivityNote.InsertedByCode = Note_Ins_ID.UserCode + + LEFT OUTER JOIN dbo.ActivityTask ON dbo.Activity.UniqActivity = dbo.ActivityTask.UniqActivity --AND (dbo.ActivityTask.InsertedDate BETWEEN DATEADD(MONTH,-13,DATEADD(MONTH,DATEDIFF(MONTH,0,GETDATE()),0)) AND EOMONTH(DATEADD(MONTH,-2,DATEADD(MONTH,DATEDIFF(MONTH,0,GETDATE()),0)))) + LEFT OUTER JOIN dbo.SecurityUser AS Task_Ins_ID ON dbo.ActivityTask.InsertedByCode = Task_Ins_ID.UserCode + + LEFT OUTER JOIN dbo.AttachmentAttachedTo ON dbo.Activity.UniqActivity = dbo.AttachmentAttachedTo.UniqActivity + LEFT OUTER JOIN dbo.Attachment ON dbo.AttachmentAttachedTo.UniqAttachment = dbo.Attachment.UniqAttachment --AND ((NOT(dbo.AttachmentAttachedTo.UniqActivity = - 1)) AND (dbo.Attachment.AttachedDate BETWEEN DATEADD(MONTH,-13,DATEADD(MONTH,DATEDIFF(MONTH,0,GETDATE()),0)) AND EOMONTH(DATEADD(MONTH,-2,DATEADD(MONTH,DATEDIFF(MONTH,0,GETDATE()),0))))) + LEFT OUTER JOIN dbo.SecurityUser AS Att_Ins_ID ON dbo.Attachment.InsertedByCode = Att_Ins_ID.UserCode + LEFT OUTER JOIN dbo.ActivityPolicyLineJT ON dbo.Activity.UniqActivity = dbo.ActivityPolicyLineJT.UniqActivity + + LEFT OUTER JOIN dbo.Policy ON dbo.ActivityPolicyLineJT.UniqPolicy = dbo.Policy.UniqPolicy + LEFT OUTER JOIN dbo.Line ON dbo.Policy.UniqPolicy = dbo.Line.UniqPolicy + LEFT OUTER JOIN dbo.Department AS Pol_Dept ON dbo.Activity.UniqDepartment = Pol_Dept.UniqDepartment + LEFT OUTER JOIN dbo.Branch AS Pol_Branch ON dbo.Activity.UniqBranch = Pol_Branch.UniqBranch + LEFT OUTER JOIN dbo.ProfitCenter AS Pol_PC ON dbo.Activity.UniqProfitCenter = Pol_PC.UniqProfitCenter + + LEFT OUTER JOIN + (SELECT + dbo.Line.UniqPolicy, + MAX(CASE WHEN dbo.CdServicingRole.CdServicingRoleCode = 'RA0' THEN dbo.Employee.NameOf ELSE NULL END) AS RiskAdvisor, + MAX(CASE WHEN dbo.CdServicingRole.CdServicingRoleCode = 'AM0' THEN dbo.Employee.NameOf ELSE NULL END) AS AccountMgr, + MAX(CASE WHEN dbo.CdServicingRole.CdServicingRoleCode = 'RA0' THEN dbo.SecurityUser.UniqSecurityUser ELSE NULL END) AS RACode, + MAX(CASE WHEN dbo.CdServicingRole.CdServicingRoleCode = 'AM0' THEN dbo.SecurityUser.UniqSecurityUser ELSE NULL END) AS AMCode + FROM dbo.Line + LEFT OUTER JOIN dbo.LineEmployeeServicingJT ON dbo.Line.UniqLine = dbo.LineEmployeeServicingJT.UniqLine + LEFT OUTER JOIN dbo.CdServicingRole ON dbo.CdServicingRole.UniqCdServicingRole = dbo.LineEmployeeServicingJT.UniqCdServicingRole + AND dbo.CdServicingRole.CdServicingRoleCode IN ('RA0', 'AM0','AA0','BC0','MA0') + LEFT OUTER JOIN dbo.Employee ON dbo.LineEmployeeServicingJT.UniqEntity = dbo.Employee.UniqEntity + LEFT OUTER JOIN dbo.SecurityUser ON dbo.Employee.UniqEntity = dbo.SecurityUser.UniqEmployee + GROUP BY dbo.Line.UniqPolicy + ) AS Svc_Role ON dbo.ActivityPolicyLineJT.UniqPolicy = Svc_Role.UniqPolicy + + WHERE (NOT(dbo.Activity.LkActivityUnsuccessfulReason LIKE 'Incorrect%')) + AND (NOT(dbo.Activity.DescriptionOf LIKE '%Duplicate%')) + AND (dbo.Client.LookupCode <> '') + AND (NOT (dbo.Client.LookupCode LIKE '%TESTACCT%')) + AND (NOT (dbo.Client.LookupCode LIKE '%PLUGACCT%')) + AND (NOT (dbo.Client.LookupCode LIKE 'MORR&GA-01')) + --AND ((dbo.Activity.InsertedDate BETWEEN DATEADD(MONTH,-13,DATEADD(MONTH,DATEDIFF(MONTH,0,GETDATE()),0)) AND EOMONTH(DATEADD(MONTH,-2,DATEADD(MONTH,DATEDIFF(MONTH,0,GETDATE()),0)))) + -- OR (dbo.Activity.ClosedDate BETWEEN DATEADD(MONTH,-13,DATEADD(MONTH,DATEDIFF(MONTH,0,GETDATE()),0)) AND EOMONTH(DATEADD(MONTH,-2,DATEADD(MONTH,DATEDIFF(MONTH,0,GETDATE()),0)))) + -- OR (dbo.ActivityNote.InsertedDate BETWEEN DATEADD(MONTH,-13,DATEADD(MONTH,DATEDIFF(MONTH,0,GETDATE()),0)) AND EOMONTH(DATEADD(MONTH,-2,DATEADD(MONTH,DATEDIFF(MONTH,0,GETDATE()),0)))) + -- OR (dbo.ActivityTask.InsertedDate BETWEEN DATEADD(MONTH,-13,DATEADD(MONTH,DATEDIFF(MONTH,0,GETDATE()),0)) AND EOMONTH(DATEADD(MONTH,-2,DATEADD(MONTH,DATEDIFF(MONTH,0,GETDATE()),0)))) + -- OR (dbo.Attachment.InsertedDate BETWEEN DATEADD(MONTH,-13,DATEADD(MONTH,DATEDIFF(MONTH,0,GETDATE()),0)) AND EOMONTH(DATEADD(MONTH,-2,DATEADD(MONTH,DATEDIFF(MONTH,0,GETDATE()),0))))) + ) AS Activity_Events + +UNPIVOT + ( + Employee FOR Employees IN (Act_Ins_By, Act_Cls_By, Note_Ins_By, Task_Ins_By, Att_Ins_By) + ) AS eeup + +UNPIVOT + ( + ID FOR IDs IN (Act_Ins_ID, Act_Cls_ID, Note_Ins_ID, Task_Ins_ID, Att_Ins_ID) + ) AS idup + +UNPIVOT + ( + Event_Date FOR Event_Dates IN (Act_Ins_Date, Act_Cls_Date, Note_Ins_Date, Task_Ins_Date, Att_Ins_Date) + ) AS dateup + +UNPIVOT + ( + Event_Type FOR Event_Types IN (Act_Ins_Event, Act_Cls_Event, Note_Ins_Event, Task_Ins_Event, Att_Ins_Event) + ) AS typeup + +UNPIVOT + ( + Event_Desc FOR Event_Descs IN (Act_Ins_Desc, Act_Cls_Desc, Note_Ins_Desc, Task_Ins_Desc, Att_Ins_Desc) + ) AS descup +UNPIVOT + ( + Event_Uniq FOR Event_Uniqs IN (Act_Ins_Uniq,Act_Cls_Uniq,Note_Ins_Uniq,Task_Ins_Uniq,Att_Ins_Uniq) + ) AS uniqup + +WHERE + LEFT(Employees, 6) = LEFT(IDs, 6) + AND LEFT(Employees, 6) = LEFT(Event_Dates, 6) + AND LEFT(Employees, 6) = LEFT(Event_Types, 6) + AND LEFT(Event_Types, 6) = LEFT(Event_Descs, 6) + AND LEFT(Event_Uniqs,6) = LEFT(Event_Types,6) + AND (Event_Date BETWEEN DATEADD(MONTH,-13,DATEADD(MONTH,DATEDIFF(MONTH,0,GETDATE()),0)) AND EOMONTH(DATEADD(MONTH,-2,DATEADD(MONTH,DATEDIFF(MONTH,0,GETDATE()),0)))) + AND (NOT([Employee] IN ('XHR001','APPLIED','APPLIEDSUPPORT','APPLIED1','APPLIED3','ZZZZAP','DOWNLOAD','ENTERPRISEADMIN','CONFIG','EPICSDKUSER','GOLIVE','SYSTEM','ZYWAE1'))) + +ORDER BY Event_Date \ No newline at end of file diff --git a/test/exampleData/Production_Product.json b/test/exampleData/Production_Product.json new file mode 100644 index 00000000..5f5a0c0e --- /dev/null +++ b/test/exampleData/Production_Product.json @@ -0,0 +1,6 @@ +[ + {"DaysToManufacture": 0, "StandardCost": 5.0885}, + {"DaysToManufacture": 1, "StandardCost": 223.88}, + {"DaysToManufacture": 2, "StandardCost": 359.1082}, + {"DaysToManufacture": 4, "StandardCost": 949.4105} +] diff --git a/test/exampleData/foj-customers.json b/test/exampleData/foj-customers.json new file mode 100644 index 00000000..ce19c7ab --- /dev/null +++ b/test/exampleData/foj-customers.json @@ -0,0 +1,14 @@ +[ + { + "customerId": 1, + "customerName": "Alfreds Futterkiste" + }, + { + "customerId": 2, + "customerName": "Ana Trujillo Emparedados y helados" + }, + { + "customerId": 3, + "customerName": "Antonio Moreno Taquería" + } +] diff --git a/test/exampleData/foj-orders.json b/test/exampleData/foj-orders.json new file mode 100644 index 00000000..94572116 --- /dev/null +++ b/test/exampleData/foj-orders.json @@ -0,0 +1,20 @@ +[ + { + "orderId": 10308, + "customerId": 2, + "employeeId": 7, + "shipperId": 3 + }, + { + "orderId": 10309, + "customerId": 37, + "employeeId": 3, + "shipperId": 1 + }, + { + "orderId": 10310, + "customerId": 77, + "employeeId": 8, + "shipperId": 2 + } +] diff --git a/test/exampleData/multiple-unpivot.json b/test/exampleData/multiple-unpivot.json new file mode 100644 index 00000000..b7466277 --- /dev/null +++ b/test/exampleData/multiple-unpivot.json @@ -0,0 +1,9 @@ +[{ + "SalesID": 1001, + "Order1Name": "first", + "Order1Date": "2018-01-01", + "Order1Amt": 111.00, + "Order2Name": "second", + "Order2Date": "2018-02-01", + "Order2Amt": 222.00 +}] diff --git a/test/exampleData/pvt.json b/test/exampleData/pvt.json new file mode 100644 index 00000000..f2459806 --- /dev/null +++ b/test/exampleData/pvt.json @@ -0,0 +1,7 @@ +[ + {"VendorID": 1, "Emp1": 4, "Emp2": 3, "Emp3": 5, "Emp4": 4, "Emp5": 4}, + {"VendorID": 2, "Emp1": 4, "Emp2": 1, "Emp3": 5, "Emp4": 5, "Emp5": 5}, + {"VendorID": 3, "Emp1": 4, "Emp2": 3, "Emp3": 5, "Emp4": 4, "Emp5": 4}, + {"VendorID": 4, "Emp1": 4, "Emp2": 2, "Emp3": 5, "Emp4": 5, "Emp5": 4}, + {"VendorID": 5, "Emp1": 5, "Emp2": 1, "Emp3": 5, "Emp4": 5, "Emp5": 5} +] diff --git a/test/individualTests/upgrade.json b/test/individualTests/upgrade.json index 3376bc51..d9d4d837 100644 --- a/test/individualTests/upgrade.json +++ b/test/individualTests/upgrade.json @@ -97,5 +97,221 @@ ] } } + }, + "pivot": { + "case1": { + "expectedResults": [ + { + "0": 5.0885, + "1": 223.88, + "2": 359.1082, + "3": null, + "4": 949.4105, + "CostSortedByProductionDays": "AverageCost" + } + ] + }, + "case2": { + "expectedResults": [ + { + "0": { + "StandardCost": 5.0885, + "MaxCost": 5.0885 + }, + "1": { + "StandardCost": 223.88, + "MaxCost": 223.88 + }, + "2": { + "StandardCost": 359.1082, + "MaxCost": 359.1082 + }, + "3": null, + "4": { + "StandardCost": 949.4105, + "MaxCost": 949.4105 + }, + "CostSortedByProductionDays": "Costs" + } + ] + } + }, + "unpivot": { + "case1": { + "expectedResults": [ + { + "VendorID": 1, + "Employee": "Emp1", + "Orders": 4 + }, + { + "VendorID": 1, + "Employee": "Emp2", + "Orders": 3 + }, + { + "VendorID": 1, + "Employee": "Emp3", + "Orders": 5 + }, + { + "VendorID": 1, + "Employee": "Emp4", + "Orders": 4 + }, + { + "VendorID": 1, + "Employee": "Emp5", + "Orders": 4 + }, + { + "VendorID": 2, + "Employee": "Emp1", + "Orders": 4 + }, + { + "VendorID": 2, + "Employee": "Emp2", + "Orders": 1 + }, + { + "VendorID": 2, + "Employee": "Emp3", + "Orders": 5 + }, + { + "VendorID": 2, + "Employee": "Emp4", + "Orders": 5 + }, + { + "VendorID": 2, + "Employee": "Emp5", + "Orders": 5 + }, + { + "VendorID": 3, + "Employee": "Emp1", + "Orders": 4 + }, + { + "VendorID": 3, + "Employee": "Emp2", + "Orders": 3 + }, + { + "VendorID": 3, + "Employee": "Emp3", + "Orders": 5 + }, + { + "VendorID": 3, + "Employee": "Emp4", + "Orders": 4 + }, + { + "VendorID": 3, + "Employee": "Emp5", + "Orders": 4 + }, + { + "VendorID": 4, + "Employee": "Emp1", + "Orders": 4 + }, + { + "VendorID": 4, + "Employee": "Emp2", + "Orders": 2 + }, + { + "VendorID": 4, + "Employee": "Emp3", + "Orders": 5 + }, + { + "VendorID": 4, + "Employee": "Emp4", + "Orders": 5 + }, + { + "VendorID": 4, + "Employee": "Emp5", + "Orders": 4 + }, + { + "VendorID": 5, + "Employee": "Emp1", + "Orders": 5 + }, + { + "VendorID": 5, + "Employee": "Emp2", + "Orders": 1 + }, + { + "VendorID": 5, + "Employee": "Emp3", + "Orders": 5 + }, + { + "VendorID": 5, + "Employee": "Emp4", + "Orders": 5 + }, + { + "VendorID": 5, + "Employee": "Emp5", + "Orders": 5 + } + ] + }, + "case2": { + "expectedResults": [ + { + "SalesID": 1001, + "OrderNum": 1, + "OrderName": "first", + "OrderDate": "2018-01-01", + "OrderAmt": 111 + }, + { + "SalesID": 1001, + "OrderNum": 2, + "OrderName": "second", + "OrderDate": "2018-02-01", + "OrderAmt": 222 + } + ] + }, + "full-outer-join": { + "expectedResults": [ + { + "VendorID": 1, + "Employee": "Emp1", + "Orders": 4 + }, + { + "VendorID": 1, + "Employee": "Emp2", + "Orders": 3 + }, + { + "VendorID": 1, + "Employee": "Emp3", + "Orders": 5 + }, + { + "VendorID": 1, + "Employee": "Emp4", + "Orders": 4 + }, + { + "VendorID": 1, + "Employee": "Emp5", + "Orders": 4 + } + ] + } } } \ No newline at end of file diff --git a/test/individualTests/upgrade.test.js b/test/individualTests/upgrade.test.js index 39661f23..20755ac3 100644 --- a/test/individualTests/upgrade.test.js +++ b/test/individualTests/upgrade.test.js @@ -392,9 +392,382 @@ describe('node-sql-parser upgrade tests', function () { await queryResultTester({ queryString: queryString, casePath: 'new.left.case1', - mode: 'write', + mode, outputPipeline: false, }); }); }); + describe('PIVOT and UNPIVOT', () => { + describe('PIVOT', () => { + it('should pivot DaysToManufacture to columns with one aggregation function', async () => { + const queryText = ` + SELECT 'AverageCost' as CostSortedByProductionDays, + "0", + "1", + "2", + "3", + "4" + FROM ( + SELECT DaysToManufacture, + StandardCost + FROM Production_Product + GROUP BY DaysToManufacture, StandardCost + ORDER BY DaysToManufacture, StandardCost + ) 'pvt|pivot([avg(StandardCost) as AverageCost],DaysToManufacture,[0,1,2,3,4])' + `; + + await queryResultTester({ + queryString: queryText, + casePath: 'pivot.case1', + mode, + outputPipeline: false, + }); + }); + it('should pivot DaysToManufacture to columns with two aggregation functions, one with an as', async () => { + const queryText = ` + SELECT 'Costs' as CostSortedByProductionDays, + "0", + "1", + "2", + "3", + "4" + FROM ( + SELECT DaysToManufacture, + StandardCost + FROM Production_Product + GROUP BY DaysToManufacture, StandardCost + ORDER BY DaysToManufacture, StandardCost + ) 'pvt|pivot([avg(StandardCost), max(StandardCost) as MaxCost],DaysToManufacture,[0,1,2,3,4])' + `; + + await queryResultTester({ + queryString: queryText, + casePath: 'pivot.case2', + mode, + outputPipeline: false, + }); + }); + const formatErrorSearchString = 'operation had the wrong format'; + it('should throw an error if the pivot is en empty array', async () => { + const queryText = ` + SELECT 'AverageCost' as CostSortedByProductionDays, + "0", + "1", + "2", + "3", + "4" + FROM ( + SELECT DaysToManufacture, + StandardCost + FROM Production_Product + GROUP BY DaysToManufacture, StandardCost + ORDER BY DaysToManufacture, StandardCost + ) 'pvt|pivot([ ],DaysToManufacture,[0,1,2,3,4])' + `; + try { + await queryResultTester({ + queryString: queryText, + casePath: 'pivot.case1', + mode, + outputPipeline: false, + }); + assert.fail('should not pass'); + } catch (err) { + assert(err.message.indexOf(formatErrorSearchString) !== -1); + } + }); + it('should throw an error if the pivot is not provided', async () => { + const queryText = ` + SELECT 'AverageCost' as CostSortedByProductionDays, + "0", + "1", + "2", + "3", + "4" + FROM ( + SELECT DaysToManufacture, + StandardCost + FROM Production_Product + GROUP BY DaysToManufacture, StandardCost + ORDER BY DaysToManufacture, StandardCost + ) 'pvt|pivot(,DaysToManufacture,[0,1,2,3,4])' + `; + try { + await queryResultTester({ + queryString: queryText, + casePath: 'pivot.case1', + mode, + outputPipeline: false, + }); + assert.fail('should not pass'); + } catch (err) { + assert(err.message.indexOf(formatErrorSearchString) !== -1); + } + }); + it('should throw an error if the pivot has only 2 arguments', async () => { + const queryText = ` + SELECT 'AverageCost' as CostSortedByProductionDays, + "0", + "1", + "2", + "3", + "4" + FROM ( + SELECT DaysToManufacture, + StandardCost + FROM Production_Product + GROUP BY DaysToManufacture, StandardCost + ORDER BY DaysToManufacture, StandardCost + ) 'pvt|pivot(DaysToManufacture,[0,1,2,3,4])' + `; + try { + await queryResultTester({ + queryString: queryText, + casePath: 'pivot.case1', + mode, + outputPipeline: false, + }); + assert.fail('should not pass'); + } catch (err) { + assert(err.message.indexOf(formatErrorSearchString) !== -1); + } + }); + it('should throw an error if the pivot has only 2 arguments and the first is empty', async () => { + const queryText = ` + SELECT 'AverageCost' as CostSortedByProductionDays, + "0", + "1", + "2", + "3", + "4" + FROM ( + SELECT DaysToManufacture, + StandardCost + FROM Production_Product + GROUP BY DaysToManufacture, StandardCost + ORDER BY DaysToManufacture, StandardCost + ) 'pvt|pivot(,[0,1,2,3,4])' + `; + try { + await queryResultTester({ + queryString: queryText, + casePath: 'pivot.case1', + mode, + outputPipeline: false, + }); + assert.fail('should not pass'); + } catch (err) { + assert(err.message.indexOf(formatErrorSearchString) !== -1); + } + }); + it('should throw an error if the pivot has only 1 argument', async () => { + const queryText = ` + SELECT 'AverageCost' as CostSortedByProductionDays, + "0", + "1", + "2", + "3", + "4" + FROM ( + SELECT DaysToManufacture, + StandardCost + FROM Production_Product + GROUP BY DaysToManufacture, StandardCost + ORDER BY DaysToManufacture, StandardCost + ) 'pvt|pivot([0,1,2,3,4])' + `; + try { + await queryResultTester({ + queryString: queryText, + casePath: 'pivot.case1', + mode, + outputPipeline: false, + }); + assert.fail('should not pass'); + } catch (err) { + assert(err.message.indexOf(formatErrorSearchString) !== -1); + } + }); + it('should throw an error if the pivot is missing the for argument', async () => { + const queryText = ` + SELECT 'AverageCost' as CostSortedByProductionDays, + "0", + "1", + "2", + "3", + "4" + FROM ( + SELECT DaysToManufacture, + StandardCost + FROM Production_Product + GROUP BY DaysToManufacture, StandardCost + ORDER BY DaysToManufacture, StandardCost + ) 'pvt|pivot([avg(StandardCost) as AverageCost], [0,1,2,3,4])' + `; + try { + await queryResultTester({ + queryString: queryText, + casePath: 'pivot.case1', + mode, + outputPipeline: false, + }); + assert.fail('should not pass'); + } catch (err) { + assert(err.message.indexOf(formatErrorSearchString) !== -1); + } + }); + it('should throw an error if the pivot is missing the columns argument', async () => { + const queryText = ` + SELECT 'AverageCost' as CostSortedByProductionDays, + "0", + "1", + "2", + "3", + "4" + FROM ( + SELECT DaysToManufacture, + StandardCost + FROM Production_Product + GROUP BY DaysToManufacture, StandardCost + ORDER BY DaysToManufacture, StandardCost + ) 'pvt|pivot([avg(StandardCost) as AverageCost],DaysToManufacture' + `; + try { + await queryResultTester({ + queryString: queryText, + casePath: 'pivot.case1', + mode, + outputPipeline: false, + }); + assert.fail('should not pass'); + } catch (err) { + assert(err.message.indexOf(formatErrorSearchString) !== -1); + } + }); + it('should throw an error if the pivot has an empty columns argument', async () => { + const queryText = ` + SELECT 'AverageCost' as CostSortedByProductionDays, + "0", + "1", + "2", + "3", + "4" + FROM ( + SELECT DaysToManufacture, + StandardCost + FROM Production_Product + GROUP BY DaysToManufacture, StandardCost + ORDER BY DaysToManufacture, StandardCost + ) 'pvt|pivot([avg(StandardCost) as AverageCost],DaysToManufacture,[]' + `; + try { + await queryResultTester({ + queryString: queryText, + casePath: 'pivot.case1', + mode, + outputPipeline: false, + }); + assert.fail('should not pass'); + } catch (err) { + assert(err.message.indexOf(formatErrorSearchString) !== -1); + } + }); + it('should throw an error if the pivot has an empty columns argument', async () => { + const queryText = ` + SELECT 'AverageCost' as CostSortedByProductionDays, + "0", + "1", + "2", + "3", + "4" + FROM ( + SELECT DaysToManufacture, + StandardCost + FROM Production_Product + GROUP BY DaysToManufacture, StandardCost + ORDER BY DaysToManufacture, StandardCost + ) 'pvt|pivot([avg(StandardCost) as AverageCost],DaysToManufacture,[,,]' + `; + try { + await queryResultTester({ + queryString: queryText, + casePath: 'pivot.case1', + mode, + outputPipeline: false, + }); + assert.fail('should not pass'); + } catch (err) { + assert(err.message.indexOf(formatErrorSearchString) !== -1); + } + }); + }); + + describe('UNPIVOT', () => { + it('should unpivot employee columns to rows', async () => { + const queryText = ` + SELECT VendorID, Employee, Orders + FROM ( + SELECT VendorID, Emp1, Emp2, Emp3, Emp4, Emp5, unset(_id) + FROM pvt + ) 'unpvt|unpivot(Orders,Employee,[Emp1, Emp2, Emp3, Emp4, Emp5])' + ORDER BY VendorID, Employee + `; + + await queryResultTester({ + queryString: queryText, + casePath: 'unpivot.case1', + mode, + outputPipeline: false, + }); + }); + it('should support multiple unpivots', async () => { + // See https://dba.stackexchange.com/a/222745 + const queryText = ` + SELECT SalesID, + ROW_NUMBER() OVER ( + ORDER BY OrderName + ) OrderNum, + OrderName, + OrderDate, + OrderAmt + FROM ( + SELECT SalesID, Order1Name, Order2Name, Order1Date, Order2Date, Order1Amt, Order2Amt, unset(_id) + FROM multiple-unpivot + ) 'unpvt|unpivot(OrderName,OrderNames,[Order1Name, Order2Name])|unpivot(OrderDate,OrderDates,[Order1Date, Order2Date])|unpivot(OrderAmt,OrderAmts,[Order1Amt, Order2Amt])' + `; + await queryResultTester({ + queryString: queryText, + casePath: 'unpivot.case2', + mode, + outputPipeline: false, + }); + }); + it('should support unpivot on an outer join', async () => { + const queryString = ` + SELECT VendorID, Employee, Orders + FROM ( + SELECT c.customerName as customerName, + o.orderId as orderId, + 1 as VendorID, + 4 as Emp1, + 3 as Emp2, + 5 as Emp3, + 4 as Emp4, + 4 as Emp5, + unset(_id,orderId,customerName) + FROM "foj-customers" c + FULL OUTER JOIN "foj-orders" o + ON c.customerId = o.customerId + ORDER BY c.customerName ASC, orders.orderId ASC + LIMIT 1 + ) 'unpvt|unpivot(Orders,Employee,[Emp1, Emp2, Emp3, Emp4, Emp5])'`; + await queryResultTester({ + queryString, + casePath: 'unpivot.full-outer-join', + mode, + outputPipeline: false, + }); + }); + }); + }); }); diff --git a/test/joins/join-cases.json b/test/joins/join-cases.json index 38bf5a40..6979b76f 100644 --- a/test/joins/join-cases.json +++ b/test/joins/join-cases.json @@ -1778,5 +1778,77 @@ } ] } + }, + "full-outer-join": { + "case1": { + "expectedResults": [ + { + "orderId": 10309 + }, + { + "orderId": 10310 + }, + { + "customerName": "Alfreds Futterkiste" + }, + { + "customerName": "Ana Trujillo Emparedados y helados", + "orderId": 10308 + }, + { + "customerName": "Antonio Moreno Taquería" + } + ] + }, + "case2": { + "expectedResults": [ + { + "orderId": 10309 + }, + { + "orderId": 10310 + }, + { + "customerName": "Alfreds Futterkiste" + }, + { + "customerName": "Ana Trujillo Emparedados y helados", + "orderId": 10308 + }, + { + "customerName": "Antonio Moreno Taquería" + } + ] + }, + "case3-sub-select": { + "expectedResults": [ + { + "foj": { + "orderId": 10309 + } + }, + { + "foj": { + "orderId": 10310 + } + }, + { + "foj": { + "customerName": "Alfreds Futterkiste" + } + }, + { + "foj": { + "customerName": "Ana Trujillo Emparedados y helados", + "orderId": 10308 + } + }, + { + "foj": { + "customerName": "Antonio Moreno Taquería" + } + } + ] + } } } \ No newline at end of file diff --git a/test/joins/joins.test.js b/test/joins/joins.test.js index b1da157a..e880563f 100644 --- a/test/joins/joins.test.js +++ b/test/joins/joins.test.js @@ -145,6 +145,7 @@ describe('joins', function () { }); }); }); + describe('left join', () => { it('should be able to do a left join', async () => { await queryResultTester({ @@ -608,6 +609,7 @@ describe('joins', function () { }); }); }); + describe('optimize', () => { const expectedPipeline = [ { @@ -689,4 +691,60 @@ describe('joins', function () { assert.deepStrictEqual(pipeline, expectedPipeline); }); }); + + describe('full outer join', () => { + it('should work - case 1', async () => { + // https://www.w3schools.com/Sql/sql_join_full.asp + const queryString = ` + SELECT c.customerName as customerName, + o.orderId as orderId, + unset(_id) + FROM "foj-customers" c + FULL OUTER JOIN "foj-orders" o + ON c.customerId = o.customerId + ORDER BY c.customerName ASC, orders.orderId ASC`; + await queryResultTester({ + queryString, + casePath: 'full-outer-join.case1', + mode, + outputPipeline: false, + }); + }); + it('should work - case 2', async () => { + // https://www.w3schools.com/Sql/sql_join_full.asp + const queryString = ` + SELECT customers.customerName as customerName, + orders.orderId as orderId, + unset(_id) + FROM "foj-orders" orders + FULL OUTER JOIN "foj-customers" customers + ON orders.customerId = customers.customerId + ORDER BY customers.customerName ASC, orders.orderId ASC`; + await queryResultTester({ + queryString, + casePath: 'full-outer-join.case2', + mode, + outputPipeline: false, + }); + }); + it('should support a full outer join in a subselect', async () => { + const queryString = ` + SELECT * + FROM ( + SELECT c.customerName as customerName, + o.orderId as orderId, + unset(_id) + FROM "foj-customers" c + FULL OUTER JOIN "foj-orders" o + ON c.customerId = o.customerId + ORDER BY c.customerName ASC, orders.orderId ASC + ) foj`; + await queryResultTester({ + queryString, + casePath: 'full-outer-join.case3-sub-select', + mode, + outputPipeline: false, + }); + }); + }); });