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

Fixes #50 Nested CTE is not rendered in top level query #140

Merged
merged 2 commits into from Sep 27, 2018
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
98 changes: 98 additions & 0 deletions QueryBuilder.Tests/QueryBuilderTest.cs
Expand Up @@ -163,6 +163,104 @@ public void ColumnsEscaping()
Assert.Equal("SELECT [mycol[isthis]]] FROM [users]", c[0]);
}

// test for issue #50
[Fact]
public void CascadedCteAndBindings()
{
var cte1 = new Query("Table1");
cte1.Select("Column1", "Column2");
cte1.Where("Column2", 1);

var cte2 = new Query("Table2");
cte2.With("cte1", cte1);
cte2.Select("Column3", "Column4");
cte2.Join("cte1", join => join.On("Column1", "Column3"));
cte2.Where("Column4", 2);

var mainQuery = new Query("Table3");
mainQuery.With("cte2", cte2);
mainQuery.Select("*");
mainQuery.From("cte2");
mainQuery.Where("Column3", 5);

var sql = Compile(mainQuery);

Assert.Equal("WITH [cte1] AS (SELECT [Column1], [Column2] FROM [Table1] WHERE [Column2] = 1),\n[cte2] AS (SELECT [Column3], [Column4] FROM [Table2] \nINNER JOIN [cte1] ON ([Column1] = [Column3]) WHERE [Column4] = 2)\nSELECT * FROM [cte2] WHERE [Column3] = 5", sql[0]);
Assert.Equal("WITH `cte1` AS (SELECT `Column1`, `Column2` FROM `Table1` WHERE `Column2` = 1),\n`cte2` AS (SELECT `Column3`, `Column4` FROM `Table2` \nINNER JOIN `cte1` ON (`Column1` = `Column3`) WHERE `Column4` = 2)\nSELECT * FROM `cte2` WHERE `Column3` = 5", sql[1]);
Assert.Equal("WITH \"cte1\" AS (SELECT \"Column1\", \"Column2\" FROM \"Table1\" WHERE \"Column2\" = 1),\n\"cte2\" AS (SELECT \"Column3\", \"Column4\" FROM \"Table2\" \nINNER JOIN \"cte1\" ON (\"Column1\" = \"Column3\") WHERE \"Column4\" = 2)\nSELECT * FROM \"cte2\" WHERE \"Column3\" = 5", sql[2]);
Assert.Equal("WITH \"CTE1\" AS (SELECT \"COLUMN1\", \"COLUMN2\" FROM \"TABLE1\" WHERE \"COLUMN2\" = 1),\n\"CTE2\" AS (SELECT \"COLUMN3\", \"COLUMN4\" FROM \"TABLE2\" \nINNER JOIN \"CTE1\" ON (\"COLUMN1\" = \"COLUMN3\") WHERE \"COLUMN4\" = 2)\nSELECT * FROM \"CTE2\" WHERE \"COLUMN3\" = 5", sql[3]);
}

// test for issue #50
[Fact]
public void CascadedAndMultiReferencedCteAndBindings()
{
var cte1 = new Query("Table1");
cte1.Select("Column1", "Column2");
cte1.Where("Column2", 1);

var cte2 = new Query("Table2");
cte2.With("cte1", cte1);
cte2.Select("Column3", "Column4");
cte2.Join("cte1", join => join.On("Column1", "Column3"));
cte2.Where("Column4", 2);

var cte3 = new Query("Table3");
cte3.With("cte1", cte1);
cte3.Select("Column3_3", "Column3_4");
cte3.Join("cte1", join => join.On("Column1", "Column3_3"));
cte3.Where("Column3_4", 33);

var mainQuery = new Query("Table3");
mainQuery.With("cte2", cte2);
mainQuery.With("cte3", cte3);
mainQuery.Select("*");
mainQuery.From("cte2");
mainQuery.Where("Column3", 5);

var sql = Compile(mainQuery);

Assert.Equal("WITH [cte1] AS (SELECT [Column1], [Column2] FROM [Table1] WHERE [Column2] = 1),\n[cte2] AS (SELECT [Column3], [Column4] FROM [Table2] \nINNER JOIN [cte1] ON ([Column1] = [Column3]) WHERE [Column4] = 2),\n[cte3] AS (SELECT [Column3_3], [Column3_4] FROM [Table3] \nINNER JOIN [cte1] ON ([Column1] = [Column3_3]) WHERE [Column3_4] = 33)\nSELECT * FROM [cte2] WHERE [Column3] = 5", sql[0]);
Assert.Equal("WITH `cte1` AS (SELECT `Column1`, `Column2` FROM `Table1` WHERE `Column2` = 1),\n`cte2` AS (SELECT `Column3`, `Column4` FROM `Table2` \nINNER JOIN `cte1` ON (`Column1` = `Column3`) WHERE `Column4` = 2),\n`cte3` AS (SELECT `Column3_3`, `Column3_4` FROM `Table3` \nINNER JOIN `cte1` ON (`Column1` = `Column3_3`) WHERE `Column3_4` = 33)\nSELECT * FROM `cte2` WHERE `Column3` = 5", sql[1]);
Assert.Equal("WITH \"cte1\" AS (SELECT \"Column1\", \"Column2\" FROM \"Table1\" WHERE \"Column2\" = 1),\n\"cte2\" AS (SELECT \"Column3\", \"Column4\" FROM \"Table2\" \nINNER JOIN \"cte1\" ON (\"Column1\" = \"Column3\") WHERE \"Column4\" = 2),\n\"cte3\" AS (SELECT \"Column3_3\", \"Column3_4\" FROM \"Table3\" \nINNER JOIN \"cte1\" ON (\"Column1\" = \"Column3_3\") WHERE \"Column3_4\" = 33)\nSELECT * FROM \"cte2\" WHERE \"Column3\" = 5", sql[2]);
Assert.Equal("WITH \"CTE1\" AS (SELECT \"COLUMN1\", \"COLUMN2\" FROM \"TABLE1\" WHERE \"COLUMN2\" = 1),\n\"CTE2\" AS (SELECT \"COLUMN3\", \"COLUMN4\" FROM \"TABLE2\" \nINNER JOIN \"CTE1\" ON (\"COLUMN1\" = \"COLUMN3\") WHERE \"COLUMN4\" = 2),\n\"CTE3\" AS (SELECT \"COLUMN3_3\", \"COLUMN3_4\" FROM \"TABLE3\" \nINNER JOIN \"CTE1\" ON (\"COLUMN1\" = \"COLUMN3_3\") WHERE \"COLUMN3_4\" = 33)\nSELECT * FROM \"CTE2\" WHERE \"COLUMN3\" = 5", sql[3]);
}

// test for issue #50
[Fact]
public void MultipleCtesAndBindings()
{
var cte1 = new Query("Table1");
cte1.Select("Column1", "Column2");
cte1.Where("Column2", 1);

var cte2 = new Query("Table2");
cte2.Select("Column3", "Column4");
cte2.Join("cte1", join => join.On("Column1", "Column3"));
cte2.Where("Column4", 2);

var cte3 = new Query("Table3");
cte3.Select("Column3_3", "Column3_4");
cte3.Join("cte1", join => join.On("Column1", "Column3_3"));
cte3.Where("Column3_4", 33);

var mainQuery = new Query("Table3");
mainQuery.With("cte1", cte1);
mainQuery.With("cte2", cte2);
mainQuery.With("cte3", cte3);
mainQuery.Select("*");
mainQuery.From("cte3");
mainQuery.Where("Column3_4", 5);

var sql = Compile(mainQuery);

Assert.Equal("WITH [cte1] AS (SELECT [Column1], [Column2] FROM [Table1] WHERE [Column2] = 1),\n[cte2] AS (SELECT [Column3], [Column4] FROM [Table2] \nINNER JOIN [cte1] ON ([Column1] = [Column3]) WHERE [Column4] = 2),\n[cte3] AS (SELECT [Column3_3], [Column3_4] FROM [Table3] \nINNER JOIN [cte1] ON ([Column1] = [Column3_3]) WHERE [Column3_4] = 33)\nSELECT * FROM [cte3] WHERE [Column3_4] = 5", sql[0]);
Assert.Equal("WITH `cte1` AS (SELECT `Column1`, `Column2` FROM `Table1` WHERE `Column2` = 1),\n`cte2` AS (SELECT `Column3`, `Column4` FROM `Table2` \nINNER JOIN `cte1` ON (`Column1` = `Column3`) WHERE `Column4` = 2),\n`cte3` AS (SELECT `Column3_3`, `Column3_4` FROM `Table3` \nINNER JOIN `cte1` ON (`Column1` = `Column3_3`) WHERE `Column3_4` = 33)\nSELECT * FROM `cte3` WHERE `Column3_4` = 5", sql[1]);
Assert.Equal("WITH \"cte1\" AS (SELECT \"Column1\", \"Column2\" FROM \"Table1\" WHERE \"Column2\" = 1),\n\"cte2\" AS (SELECT \"Column3\", \"Column4\" FROM \"Table2\" \nINNER JOIN \"cte1\" ON (\"Column1\" = \"Column3\") WHERE \"Column4\" = 2),\n\"cte3\" AS (SELECT \"Column3_3\", \"Column3_4\" FROM \"Table3\" \nINNER JOIN \"cte1\" ON (\"Column1\" = \"Column3_3\") WHERE \"Column3_4\" = 33)\nSELECT * FROM \"cte3\" WHERE \"Column3_4\" = 5", sql[2]);
Assert.Equal("WITH \"CTE1\" AS (SELECT \"COLUMN1\", \"COLUMN2\" FROM \"TABLE1\" WHERE \"COLUMN2\" = 1),\n\"CTE2\" AS (SELECT \"COLUMN3\", \"COLUMN4\" FROM \"TABLE2\" \nINNER JOIN \"CTE1\" ON (\"COLUMN1\" = \"COLUMN3\") WHERE \"COLUMN4\" = 2),\n\"CTE3\" AS (SELECT \"COLUMN3_3\", \"COLUMN3_4\" FROM \"TABLE3\" \nINNER JOIN \"CTE1\" ON (\"COLUMN1\" = \"COLUMN3_3\") WHERE \"COLUMN3_4\" = 33)\nSELECT * FROM \"CTE3\" WHERE \"COLUMN3_4\" = 5", sql[3]);
}


[Fact]
public void CteAndBindings()
{
Expand Down
60 changes: 34 additions & 26 deletions QueryBuilder/Compilers/Compiler.cs
Expand Up @@ -2,6 +2,7 @@
using System.Collections.Generic;
using System.Linq;
using System.Reflection;
using System.Text;

namespace SqlKata.Compilers
{
Expand Down Expand Up @@ -54,11 +55,28 @@ public virtual SqlResult Compile(Query query)
// handle CTEs
if (query.HasComponent("cte", EngineCode))
{
var cteCtx = CompileCte(query.GetComponents<AbstractFrom>("cte", EngineCode));
ctx.Bindings.InsertRange(0, cteCtx.Bindings);
ctx.RawSql = cteCtx.RawSql.Trim() + "\n" + ctx.RawSql;
}
var cteFinder = new CteFinder(query, EngineCode);
var cteSearchResult = cteFinder.Find();

var rawSql = new StringBuilder("WITH ");
var cteBindings = new List<object>();

foreach (var cte in cteSearchResult)
{
var cteCtx = CompileCte(cte);

cteBindings.AddRange(cteCtx.Bindings);
rawSql.Append(cteCtx.RawSql.Trim());
rawSql.Append(",\n");
}

rawSql.Length -= 2; // remove last comma
rawSql.Append('\n');
rawSql.Append(ctx.RawSql);

ctx.Bindings.InsertRange(0, cteBindings);
ctx.RawSql = rawSql.ToString();
}

return ctx;
}
Expand Down Expand Up @@ -277,35 +295,28 @@ public virtual string OnAfterCompile(string sql)
return sql;
}

public virtual SqlResult CompileCte(List<AbstractFrom> cteClauses)
public virtual SqlResult CompileCte(AbstractFrom cte)
{
var ctx = new SqlResult();

var ctx = new SqlResult { };

if (!cteClauses.Any())
if (null == cte)
{
return ctx;
}

var sql = new List<string>();

foreach (var cte in cteClauses)
if (cte is RawFromClause raw)
{
if (cte is RawFromClause raw)
{
ctx.Bindings.AddRange(raw.Bindings);
sql.Add($"{WrapValue(raw.Alias)} AS ({WrapIdentifiers(raw.Expression)})");
}
else if (cte is QueryFromClause queryFromClause)
{
var subCtx = CompileSelectQuery(queryFromClause.Query);
ctx.Bindings.AddRange(subCtx.Bindings);
ctx.Bindings.AddRange(raw.Bindings);
ctx.RawSql = $"{WrapValue(raw.Alias)} AS ({WrapIdentifiers(raw.Expression)})";
}
else if (cte is QueryFromClause queryFromClause)
{
var subCtx = CompileSelectQuery(queryFromClause.Query);
ctx.Bindings.AddRange(subCtx.Bindings);

sql.Add($"{WrapValue(queryFromClause.Alias)} AS ({subCtx.RawSql})");
}
ctx.RawSql = $"{WrapValue(queryFromClause.Alias)} AS ({subCtx.RawSql})";
}

ctx.RawSql = "WITH " + string.Join(",\n", sql) + " ";
return ctx;
}

Expand Down Expand Up @@ -697,7 +708,4 @@ public virtual string WrapIdentifiers(string input)
}

}



}
56 changes: 56 additions & 0 deletions QueryBuilder/Compilers/CteFinder.cs
@@ -0,0 +1,56 @@
using System.Collections.Generic;

namespace SqlKata.Compilers
{
public class CteFinder
{
private readonly Query query;
private readonly string engineCode;
private HashSet<string> namesOfPreviousCtes;
private List<AbstractFrom> orderedCteList;

public CteFinder(Query query, string engineCode)
{
this.query = query;
this.engineCode = engineCode;
}

public List<AbstractFrom> Find()
{
if (null != orderedCteList)
return orderedCteList;

namesOfPreviousCtes = new HashSet<string>();

orderedCteList = FindInternal(query);

namesOfPreviousCtes.Clear();
namesOfPreviousCtes = null;

return orderedCteList;
}

private List<AbstractFrom> FindInternal(Query queryToSearch)
{
var cteList = queryToSearch.GetComponents<AbstractFrom>("cte", engineCode);

var resultList = new List<AbstractFrom>();

foreach (var cte in cteList)
{
if (namesOfPreviousCtes.Contains(cte.Alias))
continue;

namesOfPreviousCtes.Add(cte.Alias);
resultList.Add(cte);

if (cte is QueryFromClause queryFromClause)
{
resultList.InsertRange(0, FindInternal(queryFromClause.Query));
}
}

return resultList;
}
}
}