From 9a1f71804a0e3ada631bff79c33c0d4c434ae561 Mon Sep 17 00:00:00 2001 From: Affan Khan Date: Mon, 1 Feb 2021 16:51:13 -0500 Subject: [PATCH 1/6] cte test and docs --- core/backend/src/test/standalone/CTE.test.ts | 176 +++++++++++++++++++ docs/learning/CommonTableExp.md | 84 +++++++++ docs/learning/ECSQL.md | 4 + 3 files changed, 264 insertions(+) create mode 100644 core/backend/src/test/standalone/CTE.test.ts create mode 100644 docs/learning/CommonTableExp.md diff --git a/core/backend/src/test/standalone/CTE.test.ts b/core/backend/src/test/standalone/CTE.test.ts new file mode 100644 index 000000000000..4a8fc526e001 --- /dev/null +++ b/core/backend/src/test/standalone/CTE.test.ts @@ -0,0 +1,176 @@ + +/*--------------------------------------------------------------------------------------------- +* Copyright (c) Bentley Systems, Incorporated. All rights reserved. +* See LICENSE.md in the project root for license terms and full copyright notice. +*--------------------------------------------------------------------------------------------*/ +import { assert } from "chai"; +import { IModelDb, SnapshotDb } from "../../imodeljs-backend"; +import { IModelTestUtils } from "../IModelTestUtils"; + +// cspell:ignore mirukuru ibim + +async function executeQuery(iModel: IModelDb, ecsql: string, bindings?: any[] | object, abbreviateBlobs?: boolean): Promise { + const rows: any[] = []; + for await (const row of iModel.query(ecsql, bindings, undefined, undefined, undefined, abbreviateBlobs)) { + rows.push(row); + } + return rows; +} + +describe("Common table expression support in ECSQL", () => { + let imodel1: SnapshotDb; + + before(async () => { + imodel1 = SnapshotDb.openFile(IModelTestUtils.resolveAssetFile("test.bim")); + }); + + after(async () => { + imodel1.close(); + }); + it("Collect base properties recursively", async () => { + const query = ` + WITH RECURSIVE + base_classes (aId, aParentId, aPath, aDepth) AS ( + SELECT c.ECInstanceId, null, c.Name, 0 FROM meta.ECClassDef c WHERE c.Name=? + UNION ALL + SELECT c.ECInstanceId, cbc.TargetECInstanceId, aPath || '/' || c.Name, aDepth + 1 + FROM meta.ECClassDef c + JOIN meta.ClassHasBaseClasses cbc ON cbc.SourceECInstanceId = c.ECInstanceId + JOIN base_classes ON aId = cbc.TargetECInstanceId + ORDER BY 1 + ) + SELECT group_concat( DISTINCT p.Name) prop from base_classes join meta.ECPropertyDef p on p.Class.id = aId`; + const rows = await executeQuery(imodel1, query, ["Element"]); + const expected = ["BBoxHigh", "BBoxLow", "Category", "GeometryStream", "Origin", "Rotation", "TypeDefinition", "CodeScope", "CodeSpec", "CodeValue", "FederationGuid", "JsonProperties", "LastMod", "Model", "Parent", "UserLabel", "Description", "Rank", "IsPrivate", "Recipe", "Data", "Type", "Angle", "Pitch", "Roll", "Yaw", "BaseModel", "Extents", "RotationAngle", "CategorySelector", "DisplayStyle", "Properties", "Name", "InSpatialIndex", "Enabled", "ModelSelector", "EyePoint", "FocusDistance", "IsCameraOn", "LensAngle", "RepositoryGuid", "Url", "PaletteName", "Height", "Scale", "SheetTemplate", "Width", "Border", "BorderTemplate", "Flags", "Format", "View", "DrawingModel", "ViewAttachment"]; + const actual = (rows[0].prop as string).split(","); + assert.sameOrderedMembers(actual, expected); + }); + + it("Generate mandelbrot set", async () => { + const rows = await executeQuery(imodel1, ` + WITH RECURSIVE + [xaxis]([x]) AS( + VALUES (- 2.0) + UNION ALL + SELECT [x] + 0.05 + FROM [xaxis] + WHERE [x] < 1.2 + ), + [yaxis]([y]) AS( + VALUES (- 1.0) + UNION ALL + SELECT [y] + 0.1 + FROM [yaxis] + WHERE [y] < 1.0 + ), + [m]([iter], [cx], [cy], [x], [y]) AS( + SELECT + 0, + [x], + [y], + 0.0, + 0.0 + FROM [xaxis], + [yaxis] + UNION ALL + SELECT + [iter] + 1, + [cx], + [cy], + [x] * [x] - [y] * [y] + [cx], + 2.0 * [x] * [y] + [cy] + FROM [m] + WHERE ([x] * [x] + [y] * [y]) < 4.0 AND [iter] < 28 + ), + [m2]([iter], [cx], [cy]) AS( + SELECT + MAX ([iter]), + [cx], + [cy] + FROM [m] + GROUP BY + [cx], + [cy] + ), + [a]([t]) AS( + SELECT GROUP_CONCAT (SUBSTR (' .+*#', 1 + (CASE WHEN [iter] / 7 > 4 THEN 4 ELSE [iter] / 7 END), 1), '') + FROM [m2] + GROUP BY [cy] + ) + SELECT GROUP_CONCAT (RTRIM ([t]), CHAR (0xa)) mandelbrot_set + FROM [a]; + `); + + const expected = + " ....#\n" + + " ..#*..\n" + + " ..+####+.\n" + + " .......+####.... +\n" + + " ..##+*##########+.++++\n" + + " .+.##################+.\n" + + " .............+###################+.+\n" + + " ..++..#.....*#####################+.\n" + + " ...+#######++#######################.\n" + + " ....+*################################.\n" + + " #############################################...\n" + + " ....+*################################.\n" + + " ...+#######++#######################.\n" + + " ..++..#.....*#####################+.\n" + + " .............+###################+.+\n" + + " .+.##################+.\n" + + " ..##+*##########+.++++\n" + + " .......+####.... +\n" + + " ..+####+.\n" + + " ..#*..\n" + + " ....#\n" + + " +."; + assert(rows[0].mandelbrot_set === expected); + }); + + it("Basic test", async () => { + let rows = []; + rows = await executeQuery(imodel1, ` + WITH RECURSIVE + cnt (x,y) AS ( + SELECT 100, 200 + UNION ALL + SELECT x+1, 200 FROM cnt WHERE x<210 + ) + SELECT * from cnt`); + assert(rows.length === 111); + + rows = await executeQuery(imodel1, ` + WITH RECURSIVE + cnt (x,y) AS ( + SELECT 100, 200 + ) + SELECT * from cnt`); + assert(rows.length === 1); + try { + rows = await executeQuery(imodel1, ` + WITH + cte_1 (a,b,c) AS ( + SELECT 100, 400, 300 + ), + cte_1 (a,b,c) AS ( + SELECT 100, 400, 300 + ) + SELECT * from cte_1`); + assert(false); + } catch { + assert(true); // should fail as cte_1 is used for two ct expression. + } + + try { + rows = await executeQuery(imodel1, ` + WITH + cte_1 (a,b,c) AS ( + SELECT 100, 400 + ) + SELECT * from cte_1`); + assert(false); + } catch { + assert(true); // number are to ct expression does not match select + } + }); +}); diff --git a/docs/learning/CommonTableExp.md b/docs/learning/CommonTableExp.md new file mode 100644 index 000000000000..35f0a43272e5 --- /dev/null +++ b/docs/learning/CommonTableExp.md @@ -0,0 +1,84 @@ +# Common table expression + +``` +WITH [RECURSIVE] cte-table-name AS ( select-stmt )[,...] primary-select-stmt +``` + +## What is Common Table Expressions? +Common table expressions or CTEs act like temporary views that exist only for the duration of a single ECSQL statement. There are following two type of CTEs + +### Ordinary Common Table Expressions +This is many used to factoring out subqueries and making the overall ECSQL statement easier to read and understand. It contain just a select statement with or without `RECURSIVE` key word. + +```sql + WITH + el (Id, ClassId) AS ( + SELECT ECInstanceId, ECClassId FROM bis.Element + ) SELECT * FROM el; +``` + +### Recursive Common Table Expressions + +A recursive common table expression can be used to walk a tree or graph. It is of the +following form. + +``` + cte-table-name AS ( initial-select) UNION [ALL] recursive-select) +``` + +Take simple example to see how we can write a CTE. In following query we want to generate a sequence from 1 through 5. The initial value of x = 1 and then we recursively do x+1 until the value of x is less then 6. + +```sql + WITH RECURSIVE + cnt (x) AS ( + SELECT 1 + UNION ALL + SELECT x+1 FROM cnt WHERE x<6 + ) + SELECT * from cnt; + +-- output + x + ------ + 1 + 2 + 3 + 4 + 5 + 6 +``` + +Take another example where we like to traverse class hierarchy starting from a class down to all derived classes and generate a path string show where each of them are along with the depth of the derived class w.r.t `GeomerticElement3d` + +```sql +WITH RECURSIVE + base_classes (aId, aParentId, aPath, aDepth) AS ( + SELECT c.ECInstanceId, NULL, c.Name, 0 FROM meta.ECClassDef c WHERE c.Name='GeometricElement2d' + UNION ALL + SELECT c.ECInstanceId, cbc.TargetECInstanceId, aPath || '/' || c.Name, aDepth + 1 + FROM meta.ECClassDef c + JOIN meta.ClassHasBaseClasses cbc ON cbc.SourceECInstanceId = c.ECInstanceId + JOIN base_classes ON aId = cbc.TargetECInstanceId + ) + SELECT bc.aDepth depth, bc.aPath FROM base_classes bc + JOIN meta.ECClassDef a ON a.ECInstanceId= bc.aId + JOIN meta.ECClassDef b ON b.ECInstanceId= bc.aParentId;; + +-- output +depth | aPath +--------------------------------------- +1 | GeometricElement2d/GraphicalElement2d +2 | GeometricElement2d/GraphicalElement2d/AnnotationElement2d +2 | GeometricElement2d/GraphicalElement2d/DrawingGraphic +2 | GeometricElement2d/GraphicalElement2d/ViewAttachment +2 | GeometricElement2d/GraphicalElement2d/DetailingSymbol +3 | GeometricElement2d/GraphicalElement2d/AnnotationElement2d/TextAnnotation2d +3 | GeometricElement2d/GraphicalElement2d/DrawingGraphic/SheetBorder +3 | GeometricElement2d/GraphicalElement2d/DetailingSymbol/Callout +3 | GeometricElement2d/GraphicalElement2d/DetailingSymbol/TitleText +3 | GeometricElement2d/GraphicalElement2d/DetailingSymbol/ViewAttachmentLabel +4 | GeometricElement2d/GraphicalElement2d/DetailingSymbol/Callout/DetailCallout +4 | GeometricElement2d/GraphicalElement2d/DetailingSymbol/Callout/ElevationCallout +4 | GeometricElement2d/GraphicalElement2d/DetailingSymbol/Callout/PlanCallout +4 | GeometricElement2d/GraphicalElement2d/DetailingSymbol/Callout/SectionCalloutt +``` diff --git a/docs/learning/ECSQL.md b/docs/learning/ECSQL.md index 66bedf6966f3..984c841ffab4 100644 --- a/docs/learning/ECSQL.md +++ b/docs/learning/ECSQL.md @@ -382,3 +382,7 @@ See also [SQLite Functions overview](https://www.sqlite.org/lang_corefunc.html). ECSQL can perform [spatial queries](./SpatialQueries.md). ECSQL has a number of [built-in geometry functions](./GeometrySqlFuncs.md) + +## Common Table Expressions + +ECSQL can do regular and recursive [CTE queries](./CommonTableExp./md) From 3af1e5d70442f60790c31a435f3a8c31c08ba2ac Mon Sep 17 00:00:00 2001 From: Affan Khan Date: Mon, 1 Feb 2021 16:52:45 -0500 Subject: [PATCH 2/6] rush change --- .../imodeljs-backend/master_2021-02-01-21-52.json | 11 +++++++++++ 1 file changed, 11 insertions(+) create mode 100644 common/changes/@bentley/imodeljs-backend/master_2021-02-01-21-52.json diff --git a/common/changes/@bentley/imodeljs-backend/master_2021-02-01-21-52.json b/common/changes/@bentley/imodeljs-backend/master_2021-02-01-21-52.json new file mode 100644 index 000000000000..d261b92830d1 --- /dev/null +++ b/common/changes/@bentley/imodeljs-backend/master_2021-02-01-21-52.json @@ -0,0 +1,11 @@ +{ + "changes": [ + { + "packageName": "@bentley/imodeljs-backend", + "comment": "Add docs and test for CTE support", + "type": "none" + } + ], + "packageName": "@bentley/imodeljs-backend", + "email": "khanaffan@users.noreply.github.com" +} \ No newline at end of file From 1775a634300b679bcc111d68d9898a4009de4d1b Mon Sep 17 00:00:00 2001 From: Affan Khan Date: Mon, 1 Feb 2021 16:58:40 -0500 Subject: [PATCH 3/6] NextVersion --- docs/changehistory/NextVersion.md | 4 ++++ 1 file changed, 4 insertions(+) diff --git a/docs/changehistory/NextVersion.md b/docs/changehistory/NextVersion.md index 16665c2032e1..5eb8a0ac69a5 100644 --- a/docs/changehistory/NextVersion.md +++ b/docs/changehistory/NextVersion.md @@ -64,3 +64,7 @@ In order to support partial updates and clearing an existing value, the update e The new behavior is documented as part of the method documentation here: [IModelDb.Elements.updateElement]($backend) + +## Common table expression support in ECSQL + +CTE are now supported in ECSQL. For more information read [Common Table Expression](..\learning\CommonTableExp.md) From 21ac28f14bf9639eea192be4f96b177e2d7372e3 Mon Sep 17 00:00:00 2001 From: Paul Connelly <22944042+pmconne@users.noreply.github.com> Date: Mon, 8 Feb 2021 13:32:52 -0500 Subject: [PATCH 4/6] spelling+clarity --- docs/learning/CommonTableExp.md | 13 ++++++------- 1 file changed, 6 insertions(+), 7 deletions(-) diff --git a/docs/learning/CommonTableExp.md b/docs/learning/CommonTableExp.md index 35f0a43272e5..013a64edad10 100644 --- a/docs/learning/CommonTableExp.md +++ b/docs/learning/CommonTableExp.md @@ -4,11 +4,11 @@ WITH [RECURSIVE] cte-table-name AS ( select-stmt )[,...] primary-select-stmt ``` -## What is Common Table Expressions? -Common table expressions or CTEs act like temporary views that exist only for the duration of a single ECSQL statement. There are following two type of CTEs +## What are Common Table Expressions? +Common table expressions ("CTEs") act like temporary views that exist only for the duration of a single ECSQL statement. There are two types of CTE: ### Ordinary Common Table Expressions -This is many used to factoring out subqueries and making the overall ECSQL statement easier to read and understand. It contain just a select statement with or without `RECURSIVE` key word. +This is mainly used to factor out subqueries, making the overall ECSQL statement easier to read and understand. It contains just a `SELECT` statement with or without `RECURSIVE` keyword. ```sql WITH @@ -19,14 +19,13 @@ This is many used to factoring out subqueries and making the overall ECSQL state ### Recursive Common Table Expressions -A recursive common table expression can be used to walk a tree or graph. It is of the -following form. +A recursive common table expression can be used to walk a tree or graph. It is of the following form: ``` cte-table-name AS ( initial-select) UNION [ALL] recursive-select) ``` -Take simple example to see how we can write a CTE. In following query we want to generate a sequence from 1 through 5. The initial value of x = 1 and then we recursively do x+1 until the value of x is less then 6. +Here is a simple example of how we can write a CTE. In the following query we want to generate a sequence from 1 through 5. We start with an initial value of x = 1 and then recursively do x+1 until the value of x is less then 6. ```sql WITH RECURSIVE @@ -48,7 +47,7 @@ Take simple example to see how we can write a CTE. In following query we want to 6 ``` -Take another example where we like to traverse class hierarchy starting from a class down to all derived classes and generate a path string show where each of them are along with the depth of the derived class w.r.t `GeomerticElement3d` +As another example, we might want to traverse a class hierarchy starting from a base class down to all derived classes, generating a row for each class. Each row should could contain 2 columns: the depth of the derived class relative to the base class and a path string describing its relationship to the base class. Using `BisCore:GeometricElement2d` as the base class produces the following ECSql and resultant output: ```sql WITH RECURSIVE From efc15d9b2102994bee438ca2a403933aabed8278 Mon Sep 17 00:00:00 2001 From: Paul Connelly <22944042+pmconne@users.noreply.github.com> Date: Mon, 8 Feb 2021 13:33:52 -0500 Subject: [PATCH 5/6] Fix link. --- docs/learning/ECSQL.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/docs/learning/ECSQL.md b/docs/learning/ECSQL.md index 9654acbdd8e3..6132d3ddf96e 100644 --- a/docs/learning/ECSQL.md +++ b/docs/learning/ECSQL.md @@ -386,4 +386,4 @@ ECSQL has a number of [built-in geometry functions](./GeometrySqlFuncs.md) ## Common Table Expressions -ECSQL can do regular and recursive [CTE queries](./CommonTableExp./md) +ECSQL can do regular and recursive [CTE queries](./CommonTableExp.md) From f4c03ec9dfe9737c435fc866d99b80c9c59bcda2 Mon Sep 17 00:00:00 2001 From: Paul Connelly <22944042+pmconne@users.noreply.github.com> Date: Mon, 8 Feb 2021 13:37:04 -0500 Subject: [PATCH 6/6] ECSql => ECSQL --- docs/learning/CommonTableExp.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/docs/learning/CommonTableExp.md b/docs/learning/CommonTableExp.md index 013a64edad10..0648b01959b8 100644 --- a/docs/learning/CommonTableExp.md +++ b/docs/learning/CommonTableExp.md @@ -47,7 +47,7 @@ Here is a simple example of how we can write a CTE. In the following query we wa 6 ``` -As another example, we might want to traverse a class hierarchy starting from a base class down to all derived classes, generating a row for each class. Each row should could contain 2 columns: the depth of the derived class relative to the base class and a path string describing its relationship to the base class. Using `BisCore:GeometricElement2d` as the base class produces the following ECSql and resultant output: +As another example, we might want to traverse a class hierarchy starting from a base class down to all derived classes, generating a row for each class. Each row should could contain 2 columns: the depth of the derived class relative to the base class and a path string describing its relationship to the base class. Using `BisCore:GeometricElement2d` as the base class produces the following ECSQL and resultant output: ```sql WITH RECURSIVE