Skip to content

Allow for ad-hoc table CTEs with parameterized data #304

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

Closed
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
100 changes: 100 additions & 0 deletions QueryBuilder.Tests/GeneralTests.cs
Original file line number Diff line number Diff line change
Expand Up @@ -401,5 +401,105 @@ public void Where_Nested()

Assert.Equal("SELECT * FROM [table] WHERE ([a] = 1 OR [a] = 2)", c[EngineCodes.SqlServer].ToString());
}

[Fact]
public void AdHoc_Throws_WhenNoColumnsProvided() =>
Assert.Throws<InvalidOperationException>(() =>
new Query("rows").With("rows",
new string[0],
new object[][] {
new object[] {},
new object[] {},
}));

[Fact]
public void AdHoc_Throws_WhenNoValueRowsProvided() =>
Assert.Throws<InvalidOperationException>(() =>
new Query("rows").With("rows",
new[] { "a", "b", "c" },
new object[][] {
}));

[Fact]
public void AdHoc_Throws_WhenColumnsOutnumberFieldValues() =>
Assert.Throws<InvalidOperationException>(() =>
new Query("rows").With("rows",
new[] { "a", "b", "c", "d" },
new object[][] {
new object[] { 1, 2, 3 },
new object[] { 4, 5, 6 },
}));

[Fact]
public void AdHoc_Throws_WhenFieldValuesOutNumberColumns() =>
Assert.Throws<InvalidOperationException>(() =>
new Query("rows").With("rows",
new[] { "a", "b" },
new object[][] {
new object[] { 1, 2, 3 },
new object[] { 4, 5, 6 },
}));

[Fact]
public void AdHoc_SingletonRow()
{
var query = new Query("rows").With("rows",
new[] { "a" },
new object[][] {
new object[] { 1 },
});

var c = Compilers.Compile(query);

Assert.Equal("WITH [rows] AS (SELECT [a] FROM (VALUES (1)) AS tbl ([a]))\nSELECT * FROM [rows]", c[EngineCodes.SqlServer].ToString());
Assert.Equal("WITH \"rows\" AS (SELECT 1 AS \"a\")\nSELECT * FROM \"rows\"", c[EngineCodes.PostgreSql].ToString());
Assert.Equal("WITH `rows` AS (SELECT 1 AS `a`)\nSELECT * FROM `rows`", c[EngineCodes.MySql].ToString());
Assert.Equal("WITH \"rows\" AS (SELECT 1 AS \"a\")\nSELECT * FROM \"rows\"", c[EngineCodes.Sqlite].ToString());
Assert.Equal("WITH \"ROWS\" AS (SELECT 1 AS \"A\" FROM RDB$DATABASE)\nSELECT * FROM \"ROWS\"", c[EngineCodes.Firebird].ToString());
Assert.Equal("WITH \"rows\" AS (SELECT 1 AS \"a\" FROM DUAL)\nSELECT * FROM \"rows\"", c[EngineCodes.Oracle].ToString());
}

[Fact]
public void AdHoc_TwoRows()
{
var query = new Query("rows").With("rows",
new[] { "a", "b", "c" },
new object[][] {
new object[] { 1, 2, 3 },
new object[] { 4, 5, 6 },
});

var c = Compilers.Compile(query);

Assert.Equal("WITH [rows] AS (SELECT [a], [b], [c] FROM (VALUES (1, 2, 3), (4, 5, 6)) AS tbl ([a], [b], [c]))\nSELECT * FROM [rows]", c[EngineCodes.SqlServer].ToString());
Assert.Equal("WITH \"rows\" AS (SELECT 1 AS \"a\", 2 AS \"b\", 3 AS \"c\" UNION ALL SELECT 4 AS \"a\", 5 AS \"b\", 6 AS \"c\")\nSELECT * FROM \"rows\"", c[EngineCodes.PostgreSql].ToString());
Assert.Equal("WITH `rows` AS (SELECT 1 AS `a`, 2 AS `b`, 3 AS `c` UNION ALL SELECT 4 AS `a`, 5 AS `b`, 6 AS `c`)\nSELECT * FROM `rows`", c[EngineCodes.MySql].ToString());
Assert.Equal("WITH \"rows\" AS (SELECT 1 AS \"a\", 2 AS \"b\", 3 AS \"c\" UNION ALL SELECT 4 AS \"a\", 5 AS \"b\", 6 AS \"c\")\nSELECT * FROM \"rows\"", c[EngineCodes.Sqlite].ToString());
Assert.Equal("WITH \"ROWS\" AS (SELECT 1 AS \"A\", 2 AS \"B\", 3 AS \"C\" FROM RDB$DATABASE UNION ALL SELECT 4 AS \"A\", 5 AS \"B\", 6 AS \"C\" FROM RDB$DATABASE)\nSELECT * FROM \"ROWS\"", c[EngineCodes.Firebird].ToString());
Assert.Equal("WITH \"rows\" AS (SELECT 1 AS \"a\", 2 AS \"b\", 3 AS \"c\" FROM DUAL UNION ALL SELECT 4 AS \"a\", 5 AS \"b\", 6 AS \"c\" FROM DUAL)\nSELECT * FROM \"rows\"", c[EngineCodes.Oracle].ToString());
}

[Fact]
public void AdHoc_ProperBindingsPlacement()
{
var query = new Query("rows")
.With("othercte", q => q.From("othertable").Where("othertable.status", "A"))
.Where("rows.foo", "bar")
.With("rows",
new[] { "a", "b", "c" },
new object[][] {
new object[] { 1, 2, 3 },
new object[] { 4, 5, 6 },
})
.Where("rows.baz", "buzz");

var c = Compilers.Compile(query);

Assert.Equal(string.Join("\n", new[] {
"WITH [othercte] AS (SELECT * FROM [othertable] WHERE [othertable].[status] = 'A'),",
"[rows] AS (SELECT [a], [b], [c] FROM (VALUES (1, 2, 3), (4, 5, 6)) AS tbl ([a], [b], [c]))",
"SELECT * FROM [rows] WHERE [rows].[foo] = 'bar' AND [rows].[baz] = 'buzz'",
}), c[EngineCodes.SqlServer].ToString());
}
}
}
22 changes: 22 additions & 0 deletions QueryBuilder/Clauses/FromClause.cs
Original file line number Diff line number Diff line change
@@ -1,4 +1,5 @@
using System;
using System.Collections.Generic;

namespace SqlKata
{
Expand Down Expand Up @@ -94,4 +95,25 @@ public override AbstractClause Clone()
};
}
}

/// <summary>
/// Represents a FROM clause that is an ad-hoc table built with predefined values.
/// </summary>
public class AdHocTableFromClause : AbstractFrom
{
public List<string> Columns { get; set; }
public List<object> Values { get; set; }

public override AbstractClause Clone()
{
return new AdHocTableFromClause
{
Engine = Engine,
Alias = Alias,
Columns = Columns,
Values = Values,
Component = Component,
};
}
}
}
29 changes: 29 additions & 0 deletions QueryBuilder/Compilers/Compiler.cs
Original file line number Diff line number Diff line change
Expand Up @@ -24,6 +24,7 @@ protected Compiler()

public virtual string EngineCode { get; }

protected virtual string SingleRowDummyTableName { get => null; }

/// <summary>
/// A list of white-listed operators
Expand Down Expand Up @@ -209,6 +210,27 @@ protected virtual SqlResult CompileSelectQuery(Query query)
return ctx;
}

protected virtual SqlResult CompileAdHocQuery(AdHocTableFromClause adHoc)
{
var ctx = new SqlResult();

var row = "SELECT " + string.Join(", ", adHoc.Columns.Select(col => $"? AS {Wrap(col)}"));

var fromTable = SingleRowDummyTableName;

if (fromTable != null)
{
row += $" FROM {fromTable}";
}

var rows = string.Join(" UNION ALL ", Enumerable.Repeat(row, adHoc.Values.Count / adHoc.Columns.Count));

ctx.RawSql = rows;
ctx.Bindings = adHoc.Values;

return ctx;
}

private SqlResult CompileDeleteQuery(Query query)
{
var ctx = new SqlResult
Expand Down Expand Up @@ -477,6 +499,13 @@ public virtual SqlResult CompileCte(AbstractFrom cte)

ctx.RawSql = $"{WrapValue(queryFromClause.Alias)} AS ({subCtx.RawSql})";
}
else if (cte is AdHocTableFromClause adHoc)
{
var subCtx = CompileAdHocQuery(adHoc);
ctx.Bindings.AddRange(subCtx.Bindings);

ctx.RawSql = $"{WrapValue(adHoc.Alias)} AS ({subCtx.RawSql})";
}

return ctx;
}
Expand Down
1 change: 1 addition & 0 deletions QueryBuilder/Compilers/FirebirdCompiler.cs
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,7 @@ public FirebirdCompiler()
}

public override string EngineCode { get; } = EngineCodes.Firebird;
protected override string SingleRowDummyTableName => "RDB$DATABASE";

protected override SqlResult CompileInsertQuery(Query query)
{
Expand Down
1 change: 1 addition & 0 deletions QueryBuilder/Compilers/OracleCompiler.cs
Original file line number Diff line number Diff line change
Expand Up @@ -16,6 +16,7 @@ public OracleCompiler()

public override string EngineCode { get; } = EngineCodes.Oracle;
public bool UseLegacyPagination { get; set; } = false;
protected override string SingleRowDummyTableName => "DUAL";

protected override SqlResult CompileSelectQuery(Query query)
{
Expand Down
18 changes: 18 additions & 0 deletions QueryBuilder/Compilers/SqlServerCompiler.cs
Original file line number Diff line number Diff line change
@@ -1,3 +1,5 @@
using System.Linq;

namespace SqlKata.Compilers
{
public class SqlServerCompiler : Compiler
Expand Down Expand Up @@ -168,5 +170,21 @@ protected override string CompileBasicDateCondition(SqlResult ctx, BasicDateCond

return sql;
}

protected override SqlResult CompileAdHocQuery(AdHocTableFromClause adHoc)
{
var ctx = new SqlResult();

var colNames = string.Join(", ", adHoc.Columns.Select(Wrap));

var valueRow = string.Join(", ", Enumerable.Repeat("?", adHoc.Columns.Count));
var valueRows = string.Join(", ", Enumerable.Repeat($"({valueRow})", adHoc.Values.Count / adHoc.Columns.Count));
var sql = $"SELECT {colNames} FROM (VALUES {valueRows}) AS tbl ({colNames})";

ctx.RawSql = sql;
ctx.Bindings = adHoc.Values;

return ctx;
}
}
}
34 changes: 34 additions & 0 deletions QueryBuilder/Query.cs
Original file line number Diff line number Diff line change
Expand Up @@ -118,6 +118,40 @@ public Query With(string alias, Func<Query, Query> fn)
return With(alias, fn.Invoke(new Query()));
}

/// <summary>
/// Constructs an ad-hoc table of the given data as a CTE.
/// </summary>
public Query With(string alias, IEnumerable<string> columns, IEnumerable<IEnumerable<object>> valuesCollection)
{
var columnsList = columns?.ToList();
var valuesCollectionList = valuesCollection?.ToList();

if ((columnsList?.Count ?? 0) == 0 || (valuesCollectionList?.Count ?? 0) == 0)
{
throw new InvalidOperationException("Columns and valuesCollection cannot be null or empty");
}

var clause = new AdHocTableFromClause()
{
Alias = alias,
Columns = columnsList,
Values = new List<object>(),
};

foreach (var values in valuesCollectionList)
{
var valuesList = values.ToList();
if (columnsList.Count != valuesList.Count)
{
throw new InvalidOperationException("Columns count should be equal to each Values count");
}

clause.Values.AddRange(valuesList);
}

return AddComponent("cte", clause);
}

public Query WithRaw(string alias, string sql, params object[] bindings)
{
return AddComponent("cte", new RawFromClause
Expand Down