Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add support for common table expression #697

Merged
merged 12 commits into from
Feb 8, 2021
Original file line number Diff line number Diff line change
@@ -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"
}
176 changes: 176 additions & 0 deletions core/backend/src/test/standalone/CTE.test.ts
Original file line number Diff line number Diff line change
@@ -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<any[]> {
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
}
});
});
14 changes: 10 additions & 4 deletions docs/changehistory/NextVersion.md
Original file line number Diff line number Diff line change
Expand Up @@ -6,19 +6,22 @@ publish: false
## GPU memory limits

The [RenderGraphic]($frontend)s used to represent a [Tile]($frontend)'s contents consume WebGL resources - chiefly, GPU memory. If the amount of GPU memory consumed exceeds that available, the WebGL context will be lost, causing an error dialog to be displayed and all rendering to cease. The [TileAdmin]($frontend) can now be configured with a strategy for managing the amount of GPU memory consumed and avoiding context loss. Each strategy defines a maximum amount of GPU memory permitted to be allocated to tile graphics; when that limit is exceeded, graphics for tiles that are not currently being displayed by any [Viewport]($frontend) are discarded one by one until the limit is satisfied or no more tiles remain to be discarded. Graphics are discarded in order from least-recently- to most-recently-displayed, and graphics currently being displayed will not be discarded. The available strategies are:
- "default" - a "reasonable" amount of GPU memory can be consumed.
- "aggressive" - a conservative amount of GPU memory can be consumed.
- "relaxed" - a generous amount of GPU memory can be consumed.
- "none" - an unbounded amount of GPU memory can be consumed - no maximum is imposed.

- "default" - a "reasonable" amount of GPU memory can be consumed.
- "aggressive" - a conservative amount of GPU memory can be consumed.
- "relaxed" - a generous amount of GPU memory can be consumed.
- "none" - an unbounded amount of GPU memory can be consumed - no maximum is imposed.

The precise amount of memory permitted by each strategy varies based on whether or not the client is running on a mobile device; see [TileAdmin.mobileGpuMemoryLimits]($frontend) and [TileAdmin.nonMobileGpuMemoryLimits]($frontend) for precise values. The application can also specify an exact amount in number of bytes instead.

The limit defaults to "default" for mobile devices and "none" for non-mobile devices. To configure the limit when calling [IModelApp.startup]($frontend), specify [TileAdmin.Props.gpuMemoryLimits]($frontend). For example:

```ts
IModelApp.startup({ tileAdmin: TileAdmin.create({ gpuMemoryLimits: "aggressive" }) });
```

Separate limits for mobile and non-mobile devices can be specified at startup if desired; the appropriate limit will be selected based on the type of device the client is running on:

```ts
IModelApp.startup({ tileAdmin: TileAdmin.create({
gpuMemoryLimits: {
Expand All @@ -32,3 +35,6 @@ To adjust the limit after startup, assign to [TileAdmin.gpuMemoryLimit]($fronten

This feature replaces the `@alpha` `TileAdmin.Props.mobileExpirationMemoryThreshold` option.

## Common table expression support in ECSQL

CTE are now supported in ECSQL. For more information read [Common Table Expression](..\learning\CommonTableExp.md)
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Can you switch to forward slash or else won't work on linux/mac?

83 changes: 83 additions & 0 deletions docs/learning/CommonTableExp.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,83 @@
# Common table expression

```
WITH [RECURSIVE] cte-table-name AS ( select-stmt )[,...] primary-select-stmt
```

## 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 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
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)
```

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
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
```

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
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
```
4 changes: 4 additions & 0 deletions docs/learning/ECSQL.md
Original file line number Diff line number Diff line change
Expand Up @@ -383,3 +383,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)