Skip to content

Commit

Permalink
Merge pull request #469 from mk3008/466-review-querysource
Browse files Browse the repository at this point in the history
Improved processing description
  • Loading branch information
mk3008 authored Jul 17, 2024
2 parents a624510 + cf922b0 commit 6e96bb8
Show file tree
Hide file tree
Showing 11 changed files with 374 additions and 83 deletions.
4 changes: 2 additions & 2 deletions demo/CarbunqlWeb/Pages/QuerySource/Labels.razor
Original file line number Diff line number Diff line change
Expand Up @@ -55,7 +55,7 @@ var sources = q.GetQuerySources().ToList();
q.GetQuerySources().ForEach(x =>
{
x.AddSourceComment($""Index:{x.Index}, MaxLv:{x.MaxLevel}, Columns:[{string.Join("", "", x.ColumnNames)}]"");
x.AddSourceComment($""Index:{x.Index}, Alias:{x.Alias}, MaxLv:{x.MaxLevel}, SourceType:{x.SourceType}, Columns:[{string.Join("", "", x.ColumnNames)}]"");
x.ToTreePaths().ForEach(path => x.AddSourceComment($""Path:{string.Join(""-"", path)}""));
});
Console.WriteLine(q.ToText());";
Expand Down Expand Up @@ -85,7 +85,7 @@ Console.WriteLine(q.ToText());";

q.GetQuerySources().ForEach(x =>
{
x.AddSourceComment($"Index:{x.Index}, MaxLv:{x.MaxLevel}, Columns:[{string.Join(", ", x.ColumnNames)}]");
x.AddSourceComment($"Index:{x.Index}, Alias:{x.Alias}, MaxLv:{x.MaxLevel}, SourceType:{x.SourceType}, Columns:[{string.Join(", ", x.ColumnNames)}]");
x.ToTreePaths().ForEach(path => x.AddSourceComment($"Path:{string.Join("-", path)}"));
});

Expand Down
14 changes: 14 additions & 0 deletions demo/QuerySource/Demo.QuerySource.csproj
Original file line number Diff line number Diff line change
@@ -0,0 +1,14 @@
<Project Sdk="Microsoft.NET.Sdk">

<PropertyGroup>
<OutputType>Exe</OutputType>
<TargetFramework>net8.0</TargetFramework>
<ImplicitUsings>enable</ImplicitUsings>
<Nullable>enable</Nullable>
</PropertyGroup>

<ItemGroup>
<ProjectReference Include="..\..\src\Carbunql\Carbunql.csproj" />
</ItemGroup>

</Project>
192 changes: 192 additions & 0 deletions demo/QuerySource/Program.cs
Original file line number Diff line number Diff line change
@@ -0,0 +1,192 @@
using Carbunql;
using Carbunql.Analysis.Parser;
using Carbunql.Building;

var sql = @"select s.sale_id, s.store_id, s.sale_date as journal_date, s.sale_price from sales as s";

//column info
var keyColumn = "sale_id";
var dateColumn = "journal_date";
var valueColumn = "sale_price";
var ignoreColumn = "journal_date";

var keyTable = "sale_keys";
var journalTable = "sale_journals";

var lowerLimit = new DateTime(2024, 1, 1);

Console.WriteLine("--origin----------");
var query = new SelectQuery(sql);
Console.WriteLine(query.ToText());
Console.WriteLine(";");


Console.WriteLine("--sub----------");
query = new SelectQuery(sql).ToSubQuery("q");
Console.WriteLine(query.ToText());
Console.WriteLine(";");

try
{
Console.WriteLine("--snapshot----------");
var crateTablequery = new SelectQuery(sql)
.ToCteQuery("datasource", "ds")
.InjectUnderLimitProcessing(dateColumn, lowerLimit)
.InjectNotJournaledFilter(keyTable, keyColumn)
.AddColumn("nextval('sale_journal_id_seq')", "sale_journal_id")
.ToCteQuery("final", "f")
.ToCreateTableQuery("tmp", isTemporary: true);
Console.WriteLine(crateTablequery.ToText());
Console.WriteLine(";");

Console.WriteLine("--validate----------");
var insertQuery = new SelectQuery(sql)
.ToDiffQuery(journalTable, keyColumn, valueColumn, ignoreColumn)
.InjectUnderLimitProcessing(dateColumn, lowerLimit)
.InjectFilter(keyColumn, 1)
.ToCteQuery("final", "f")
.ToInsertQuery("sale_journals");
Console.WriteLine(insertQuery.ToText());
Console.WriteLine(";");
}
catch (Exception ex)
{
Console.WriteLine(ex.ToString());
}


public static class SelectQueryExtension
{

public static SelectQuery InjectUnderLimitProcessing(this SelectQuery query, string dateColumnName, DateTime lowerLimitDate)
{
var lowerLimit = lowerLimitDate.ToString("yyyy-MM-dd");

query.GetQuerySources()
.Where(x => x.Query.GetSelectableItems().Where(x => x.Alias == dateColumnName).Any())
.GetRootsBySource()
.EnsureAny()
.ForEach(x =>
{
x.Query.AddComment($"Inject a lower limit for {dateColumnName}");
var si = x.Query.GetSelectableItems().Where(x => x.Alias == dateColumnName).First();

//override
si.Value = ValueParser.Parse($"greatest({si.Value.ToOneLineText()}, '{lowerLimit}'::date)");
});

return query;
}

public static SelectQuery InjectNotJournaledFilter(this SelectQuery query, string keyTable, string keyColumn)
{
query.GetQuerySources()
.Where(x => x.ColumnNames.Contains(keyColumn))
.GetRootsBySource()
.EnsureAny()
.ForEach(qs =>
{
//filter
qs.Query.AddComment($"Inject a not archived filter. {keyTable}");
qs.Query.Where(() =>
{
var sq = new SelectQuery($"select * from {keyTable} as x");
sq.Where($"x.{keyColumn} = {qs.Alias}.{keyColumn}");
return sq.ToNotExists();
});
});

return query;
}

public static SelectQuery ToDiffQuery(this SelectQuery actualQuery, string journalTable, string keyColumn, string valueColumn, string ignoreColumn)
{
var expectQuery = new SelectQuery($"select arch.sale_id, arch.store_id, arch.journal_date, arch.sale_price from {journalTable} as arch");

var checkColumns = expectQuery.GetColumnNames().Where(x => x != keyColumn && x != ignoreColumn).ToList();
var notValueColumns = expectQuery.GetColumnNames().Where(x => x != valueColumn).ToList();

var expectCTE = "expect";
var expectAlias = "exp";
var actualCTE = "actual";
var actualAlias = "act";

SelectQuery selectCancellationQuery()
{
var (q, expect) = expectQuery.ToCTE(expectCTE);
var actual = expectQuery.With(actualQuery).As(actualCTE);

var (f, e) = q.From(expect).As(expectAlias);
var a = f.LeftJoin(actual).As(actualAlias).On(e, keyColumn);
q.Where(a, keyColumn).IsNull();

notValueColumns.ForEach(column => q.Select(e, column));
q.Select($"{e.Alias}.{valueColumn} * -1").As(valueColumn);
q.Select("'cancellation'").As("remarks");
return q;
}

SelectQuery selectCollectionQuery()
{
var (q, expect) = expectQuery.ToCTE(expectCTE);
var actual = expectQuery.With(actualQuery).As(actualCTE);

var (f, e) = q.From(expect).As(expectAlias);
var a = f.InnerJoin(actual).As(actualAlias).On(e, keyColumn);
q.Where(() =>
{
var condition = new List<string>();
checkColumns.ForEach(column => condition.Add($"{e.Alias}.{column} <> {a.Alias}.{column}"));
return ValueParser.Parse($"({string.Join(" or ", condition)})");
});

notValueColumns.ForEach(column => q.Select(e, column));
q.Select($"{e.Alias}.{valueColumn} * -1").As(valueColumn);
q.Select("'correction'").As("remarks");
return q;
}

SelectQuery selectRevisedQuery()
{
var (q, expect) = expectQuery.ToCTE(expectCTE);
var actual = expectQuery.With(actualQuery).As(actualCTE);

var (f, e) = q.From(expect).As(expectAlias);
var a = f.InnerJoin(actual).As(actualAlias).On(e, keyColumn);
q.Where(() =>
{
var condition = new List<string>();
checkColumns.ForEach(column => condition.Add($"{e.Alias}.{column} <> {a.Alias}.{column}"));
return ValueParser.Parse($"({string.Join(" or ", condition)})");
});

notValueColumns.ForEach(column => q.Select(a.Alias, column));
q.Select($"{a.Alias}.{valueColumn}").As(valueColumn);
q.Select("'revised'").As("remarks");
return q;
}

//diff
var diffquer = selectCancellationQuery();
diffquer.AddOperatableValue("union all", selectCollectionQuery());
diffquer.AddOperatableValue("union all", selectRevisedQuery());

return diffquer;
}

public static SelectQuery InjectFilter(this SelectQuery query, string keyColumn, int keyValue)
{
query.GetQuerySources()
.Where(x => x.ColumnNames.Contains(keyColumn))
.GetRootsBySource()
.EnsureAny()
.ForEach(x =>
{
//filter
x.Query.AddComment($"Inject a filter {keyColumn}");
x.Query.Where(ValueParser.Parse($"{x.Alias}.{keyColumn} = {keyValue}"));
});

return query;
}
}
6 changes: 6 additions & 0 deletions src/Carbunql.sln
Original file line number Diff line number Diff line change
Expand Up @@ -37,6 +37,8 @@ Project("{9A19103F-16F7-4668-BE54-9A1E7A4F7556}") = "Demo.TypeSafeBuild", "..\de
EndProject
Project("{9A19103F-16F7-4668-BE54-9A1E7A4F7556}") = "Demo.Filtering", "..\demo\Filtering\Demo.Filtering.csproj", "{3EBB0CEC-FE66-4D04-A4DF-20B25A31178B}"
EndProject
Project("{9A19103F-16F7-4668-BE54-9A1E7A4F7556}") = "Demo.QuerySource", "..\demo\QuerySource\Demo.QuerySource.csproj", "{3BF09DA6-FF1F-43BC-B4D5-5FA5360E351F}"
EndProject
Global
GlobalSection(SolutionConfigurationPlatforms) = preSolution
Debug|Any CPU = Debug|Any CPU
Expand Down Expand Up @@ -111,6 +113,10 @@ Global
{3EBB0CEC-FE66-4D04-A4DF-20B25A31178B}.Debug|Any CPU.Build.0 = Debug|Any CPU
{3EBB0CEC-FE66-4D04-A4DF-20B25A31178B}.Release|Any CPU.ActiveCfg = Release|Any CPU
{3EBB0CEC-FE66-4D04-A4DF-20B25A31178B}.Release|Any CPU.Build.0 = Release|Any CPU
{3BF09DA6-FF1F-43BC-B4D5-5FA5360E351F}.Debug|Any CPU.ActiveCfg = Debug|Any CPU
{3BF09DA6-FF1F-43BC-B4D5-5FA5360E351F}.Debug|Any CPU.Build.0 = Debug|Any CPU
{3BF09DA6-FF1F-43BC-B4D5-5FA5360E351F}.Release|Any CPU.ActiveCfg = Release|Any CPU
{3BF09DA6-FF1F-43BC-B4D5-5FA5360E351F}.Release|Any CPU.Build.0 = Release|Any CPU
EndGlobalSection
GlobalSection(SolutionProperties) = preSolution
HideSolutionNode = FALSE
Expand Down
2 changes: 1 addition & 1 deletion src/Carbunql/Carbunql.csproj
Original file line number Diff line number Diff line change
Expand Up @@ -8,7 +8,7 @@
<Title></Title>
<Copyright>mk3008net</Copyright>
<Description>Carbunql provides query parsing and building functionality.</Description>
<Version>0.8.4.1</Version>
<Version>0.8.5</Version>
<Authors>mk3008net</Authors>
<PackageProjectUrl>https://github.com/mk3008/Carbunql</PackageProjectUrl>
<PackageReadmeFile>README.md</PackageReadmeFile>
Expand Down
4 changes: 2 additions & 2 deletions src/Carbunql/Clauses/SelectableItem.cs
Original file line number Diff line number Diff line change
Expand Up @@ -24,7 +24,7 @@ public SelectableItem(ValueBase value, string alias)
/// <summary>
/// Gets or sets the value or column to be selected. This can include expressions, inline queries, or simple column names.
/// </summary>
public ValueBase Value { get; private set; }
public ValueBase Value { get; set; }

/// <summary>
/// Gets or sets the alias name for the selected value, which appears after the "AS" keyword in the query.
Expand Down Expand Up @@ -95,7 +95,7 @@ public IEnumerable<QueryParameter> GetParameters()

public IEnumerable<ColumnValue> GetColumns()
{
foreach(var item in Value.GetColumns())
foreach (var item in Value.GetColumns())
{
yield return item;
}
Expand Down
10 changes: 10 additions & 0 deletions src/Carbunql/IQuerySource.cs
Original file line number Diff line number Diff line change
Expand Up @@ -44,6 +44,16 @@ public interface IQuerySource
/// Gets the query sources that reference this query source.
/// </summary>
IList<IQuerySource> References { get; }

SourceType SourceType { get; }
}

public enum SourceType
{
PhysicalTable,
SubQuery,
CommonTableExtension,
ValuesQuery
}

public static class IQuerySourceExtension
Expand Down
5 changes: 3 additions & 2 deletions src/Carbunql/QuerySource.cs
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,7 @@ namespace Carbunql;
/// Represents a query source, which can be a physical table, subquery, or common table expression (CTE).
/// This class implements the IQuerySource interface and provides concrete implementations for its properties.
/// </summary>
public class QuerySource(int index, HashSet<string> columnNames, SelectQuery query, SelectableTable source) : IQuerySource
public class QuerySource(int index, HashSet<string> columnNames, SelectQuery query, SelectableTable source, SourceType type) : IQuerySource
{
/// <summary>
/// The index of the query source. It is a unique value within a query, starting from 1.
Expand Down Expand Up @@ -40,5 +40,6 @@ public class QuerySource(int index, HashSet<string> columnNames, SelectQuery que
public SelectableTable Source => source;

public IList<IQuerySource> References { get; } = new List<IQuerySource>();
}

public SourceType SourceType => type;
}
43 changes: 37 additions & 6 deletions src/Carbunql/SelectQuery.cs
Original file line number Diff line number Diff line change
Expand Up @@ -154,7 +154,7 @@ private IList<IQuerySource> CreateQuerySources(ref List<IQuerySource> sources, I
}
else if (source.Table.TryGetSelectQuery(out var query))
{
var qs = DisassembleQuerySources(ref sources, source, query, commonTables, numbering);
var qs = DisassembleQuerySources(ref sources, source, query, commonTables, numbering, SourceType.SubQuery);
currentSources.Add(qs);
}
else if (source.Table is PhysicalTable table && commonTables.Any(x => x.Alias == table.GetTableFullName()))
Expand All @@ -166,15 +166,15 @@ private IList<IQuerySource> CreateQuerySources(ref List<IQuerySource> sources, I
{
// select query
var commonQuery = commonTables.First(x => x.Alias == table.GetTableFullName()).GetSelectQuery();
var qs = DisassembleQuerySources(ref sources, source, commonQuery, commonTables, numbering);
var qs = DisassembleQuerySources(ref sources, source, commonQuery, commonTables, numbering, SourceType.CommonTableExtension);
currentSources.Add(qs);
}
else if (ct.Table is VirtualTable vt && vt.Query is ValuesQuery && ct.ColumnAliases != null)
{
// values query
var names = ct.ColumnAliases.OfType<ColumnValue>().Select(x => x.Column).ToHashSet();

var qs = new QuerySource(numbering.GetNext(), names, this, source);
var qs = new QuerySource(numbering.GetNext(), names, this, source, SourceType.ValuesQuery);
sources.Add(qs);
currentSources.Add(qs);
}
Expand All @@ -190,7 +190,7 @@ private IList<IQuerySource> CreateQuerySources(ref List<IQuerySource> sources, I
.Select(x => x.Column)
.ToHashSet();

var qs = new QuerySource(numbering.GetNext(), cname, this, source);
var qs = new QuerySource(numbering.GetNext(), cname, this, source, SourceType.PhysicalTable);
sources.Add(qs);
currentSources.Add(qs);
}
Expand All @@ -208,7 +208,7 @@ private IList<IQuerySource> CreateQuerySources(ref List<IQuerySource> sources, I
return currentSources;
}

private IQuerySource DisassembleQuerySources(ref List<IQuerySource> sources, SelectableTable source, SelectQuery query, IList<CommonTable> commonTables, Numbering numbering)
private IQuerySource DisassembleQuerySources(ref List<IQuerySource> sources, SelectableTable source, SelectQuery query, IList<CommonTable> commonTables, Numbering numbering, SourceType type)
{
var index = numbering.GetNext();

Expand Down Expand Up @@ -244,7 +244,7 @@ private IQuerySource DisassembleQuerySources(ref List<IQuerySource> sources, Sel
}
}

var qs = new QuerySource(index, cname.ToHashSet(), this, source);
var qs = new QuerySource(index, cname.ToHashSet(), this, source, type);

foreach (var item in parents)
{
Expand Down Expand Up @@ -780,4 +780,35 @@ public int GetNext()
return Current;
}
}

public SelectQuery ToCteQuery(string name, string alias)
{
if (GetCommonTables().Where(x => x.Alias == name).Any())
{
throw new InvalidProgramException();
}

var (q, t) = this.ToCTE(name);

q.From(t).As(alias);
GetColumnNames().ForEach(column => q.Select($"{alias}.{column}").As(column));

return q;
}

public SelectQuery ToSubQuery(string alias)
{
var q = new SelectQuery();
var (f, t) = q.From(this).As(alias);

GetColumnNames().ForEach(column => q.Select($"{alias}.{column}").As(column));

return q;
}

public SelectQuery AddColumn(string column, string alias)
{
this.Select(column).As(alias);
return this;
}
}
Loading

0 comments on commit 6e96bb8

Please sign in to comment.