Skip to content

Commit

Permalink
Initial except/intersect work
Browse files Browse the repository at this point in the history
  • Loading branch information
MarkMpn committed Jul 24, 2024
1 parent a1efc46 commit 9a1bb1d
Show file tree
Hide file tree
Showing 7 changed files with 412 additions and 111 deletions.
126 changes: 126 additions & 0 deletions MarkMpn.Sql4Cds.Engine.Tests/AdoProviderTests.cs
Original file line number Diff line number Diff line change
Expand Up @@ -2156,5 +2156,131 @@ public void WildcardColumnAsFunctionParameterIsSyntaxError()
}
}
}

[TestMethod]
public void Intersect()
{
using (var con = new Sql4CdsConnection(_localDataSources))
using (var cmd = con.CreateCommand())
{
cmd.CommandText = @"
SELECT * FROM (VALUES ('a', 'b'), ('b', 'c')) AS T(A, B)
INTERSECT
SELECT * FROM (VALUES ('b', 'c'), ('c', 'd')) AS T(A, B)";

using (var reader = cmd.ExecuteReader())
{
Assert.IsTrue(reader.Read());
Assert.AreEqual("b", reader.GetString(0));
Assert.AreEqual("c", reader.GetString(1));
Assert.IsFalse(reader.Read());
}
}
}

[TestMethod]
public void Except()
{
using (var con = new Sql4CdsConnection(_localDataSources))
using (var cmd = con.CreateCommand())
{
cmd.CommandText = @"
SELECT * FROM (VALUES ('a', 'b'), ('b', 'c')) AS T(A, B)
EXCEPT
SELECT * FROM (VALUES ('b', 'c'), ('c', 'd')) AS T(A, B)";

using (var reader = cmd.ExecuteReader())
{
Assert.IsTrue(reader.Read());
Assert.AreEqual("a", reader.GetString(0));
Assert.AreEqual("b", reader.GetString(1));
Assert.IsFalse(reader.Read());
}
}
}

[TestMethod]
public void IntersectRemovesDuplicates()
{
using (var con = new Sql4CdsConnection(_localDataSources))
using (var cmd = con.CreateCommand())
{
cmd.CommandText = @"
SELECT * FROM (VALUES ('a', 'b'), ('b', 'c'), ('a', 'b'), ('b', 'c')) AS T(A, B)
INTERSECT
SELECT * FROM (VALUES ('b', 'c'), ('c', 'd'), ('b', 'c'), ('c', 'd')) AS T(A, B)";

using (var reader = cmd.ExecuteReader())
{
Assert.IsTrue(reader.Read());
Assert.AreEqual("b", reader.GetString(0));
Assert.AreEqual("c", reader.GetString(1));
Assert.IsFalse(reader.Read());
}
}
}

[TestMethod]
public void ExceptRemovesDuplicates()
{
using (var con = new Sql4CdsConnection(_localDataSources))
using (var cmd = con.CreateCommand())
{
cmd.CommandText = @"
SELECT * FROM (VALUES ('a', 'b'), ('b', 'c'), ('a', 'b'), ('b', 'c')) AS T(A, B)
EXCEPT
SELECT * FROM (VALUES ('b', 'c'), ('c', 'd'), ('b', 'c'), ('c', 'd')) AS T(A, B)";

using (var reader = cmd.ExecuteReader())
{
Assert.IsTrue(reader.Read());
Assert.AreEqual("a", reader.GetString(0));
Assert.AreEqual("b", reader.GetString(1));
Assert.IsFalse(reader.Read());
}
}
}

[TestMethod]
public void IntersectHandlesNulls()
{
using (var con = new Sql4CdsConnection(_localDataSources))
using (var cmd = con.CreateCommand())
{
cmd.CommandText = @"
SELECT * FROM (VALUES ('a', 'b'), ('b', null), ('a', 'b'), ('b', null)) AS T(A, B)
INTERSECT
SELECT * FROM (VALUES ('b', null), ('c', 'd'), ('b', null), ('c', 'd')) AS T(A, B)";

using (var reader = cmd.ExecuteReader())
{
Assert.IsTrue(reader.Read());
Assert.AreEqual("b", reader.GetString(0));
Assert.IsTrue(reader.IsDBNull(1));
Assert.IsFalse(reader.Read());
}
}
}

[TestMethod]
public void ExceptHandlesNulls()
{
using (var con = new Sql4CdsConnection(_localDataSources))
using (var cmd = con.CreateCommand())
{
cmd.CommandText = @"
SELECT * FROM (VALUES ('a', 'b'), ('b', null), ('a', 'b'), ('b', null)) AS T(A, B)
EXCEPT
SELECT * FROM (VALUES ('b', null), ('c', 'd'), ('b', null), ('c', 'd')) AS T(A, B)";

using (var reader = cmd.ExecuteReader())
{
Assert.IsTrue(reader.Read());
Assert.AreEqual("a", reader.GetString(0));
Assert.AreEqual("b", reader.GetString(1));
Assert.IsFalse(reader.Read());
}
}
}
}
}
23 changes: 20 additions & 3 deletions MarkMpn.Sql4Cds.Engine/ExecutionPlan/BaseJoinNode.cs
Original file line number Diff line number Diff line change
Expand Up @@ -47,6 +47,14 @@ abstract class BaseJoinNode : BaseDataNode
[DisplayName("Semi Join")]
public bool SemiJoin { get; set; }

/// <summary>
/// Indicates if an anti join should be used (single output row for each row from the left source that does not have a match in the right source)
/// </summary>
[Category("Join")]
[Description("Indicates if an anti join should be used (single output row for each row from the left source that does not have a match in the right source)")]
[DisplayName("Anti Join")]
public bool AntiJoin { get; set; }

/// <summary>
/// For semi joins, lists individual columns that should be created in the output and their corresponding source from the right input
/// </summary>
Expand Down Expand Up @@ -242,20 +250,29 @@ public override string ToString()
break;

case QualifiedJoinType.LeftOuter:
name += "Left Outer";
name += "Left";
break;

case QualifiedJoinType.RightOuter:
name += "Right Outer";
name += "Right";
break;

case QualifiedJoinType.FullOuter:
name += "Full Outer";
name += "Full";
break;
}

if (SemiJoin)
{
if (AntiJoin)
name += " Anti";

name += " Semi";
}
else if (JoinType != QualifiedJoinType.Inner)
{
name += " Outer";
}

name += " Join)";

Expand Down
5 changes: 5 additions & 0 deletions MarkMpn.Sql4Cds.Engine/ExecutionPlan/DistinctNode.cs
Original file line number Diff line number Diff line change
Expand Up @@ -83,6 +83,11 @@ public override IDataExecutionPlanNodeInternal FoldQuery(NodeCompilationContext
if (!String.IsNullOrEmpty(schema.PrimaryKey) && Columns.Contains(schema.PrimaryKey, StringComparer.OrdinalIgnoreCase))
return Source;

// If we know the source doesn't have more than one record, there is no possibility of duplicate
// rows so we can discard the distinct node
if (Source.EstimateRowsOut(context) is RowCountEstimateDefiniteRange range && range.Maximum <= 1)
return Source;

if (Source is FetchXmlScan fetch)
{
fetch.FetchXml.distinct = true;
Expand Down
122 changes: 83 additions & 39 deletions MarkMpn.Sql4Cds.Engine/ExecutionPlan/FoldableJoinNode.cs
Original file line number Diff line number Diff line change
Expand Up @@ -28,18 +28,54 @@ abstract class FoldableJoinNode : BaseJoinNode
/// <summary>
/// The attribute in the <see cref="OuterSource"/> to join on
/// </summary>
[Browsable(false)]
public ColumnReferenceExpression LeftAttribute
{
get => LeftAttributes.Count == 1 ? LeftAttributes[0] : null;
set
{
LeftAttributes.Clear();
LeftAttributes.Add(value);
}
}

/// <summary>
/// The attributes in the <see cref="OuterSource"/> to join on
/// </summary>
[Category("Join")]
[Description("The attribute in the outer data source to join on")]
[DisplayName("Left Attribute")]
public ColumnReferenceExpression LeftAttribute { get; set; }
[Description("The attributes in the outer data source to join on")]
[DisplayName("Left Attributes")]
public List<ColumnReferenceExpression> LeftAttributes { get; } = new List<ColumnReferenceExpression>();

/// <summary>
/// The attribute in the <see cref="InnerSource"/> to join on
/// </summary>
[Browsable(false)]
public ColumnReferenceExpression RightAttribute
{
get => RightAttributes.Count == 1 ? RightAttributes[0] : null;
set
{
RightAttributes.Clear();
RightAttributes.Add(value);
}
}

/// <summary>
/// The attributes in the <see cref="InnerSource"/> to join on
/// </summary>
[Category("Join")]
[Description("The attribute in the inner data source to join on")]
[DisplayName("Right Attribute")]
public ColumnReferenceExpression RightAttribute { get; set; }
[Description("The attributes in the inner data source to join on")]
[DisplayName("Right Attributes")]
public List<ColumnReferenceExpression> RightAttributes { get; } = new List<ColumnReferenceExpression>();

/// <summary>
/// The type of comparison that is used for the two inputs
/// </summary>
[Category("Join")]
[Description("The type of comparison that is used for the two inputs")]
[DisplayName("Comparison Type")]
public BooleanComparisonType ComparisonType { get; set; } = BooleanComparisonType.Equals;

/// <summary>
/// Any additional criteria to apply to the join
Expand Down Expand Up @@ -78,49 +114,57 @@ public override IDataExecutionPlanNodeInternal FoldQuery(NodeCompilationContext
if (SemiJoin)
return this;

var leftFilter = JoinType == QualifiedJoinType.Inner || JoinType == QualifiedJoinType.LeftOuter ? LeftSource as FilterNode : null;
var rightFilter = JoinType == QualifiedJoinType.Inner || JoinType == QualifiedJoinType.RightOuter ? RightSource as FilterNode : null;
var leftFetch = (leftFilter?.Source ?? LeftSource) as FetchXmlScan;
var rightFetch = (rightFilter?.Source ?? RightSource) as FetchXmlScan;
var leftJoin = (leftFilter?.Source ?? LeftSource) as BaseJoinNode;
var rightJoin = (rightFilter?.Source ?? RightSource) as BaseJoinNode;
var leftMeta = (leftFilter?.Source ?? LeftSource) as MetadataQueryNode;
var rightMeta = (rightFilter?.Source ?? RightSource) as MetadataQueryNode;
IDataExecutionPlanNodeInternal folded = null;

if (leftFetch != null && rightFetch != null && FoldFetchXmlJoin(context, hints, leftFetch, leftSchema, rightFetch, rightSchema, out var folded))
return PrependFilters(folded, context, hints, leftFilter, rightFilter);
if (LeftAttributes.Count == 1 && ComparisonType == BooleanComparisonType.Equals)
{
var leftFilter = JoinType == QualifiedJoinType.Inner || JoinType == QualifiedJoinType.LeftOuter ? LeftSource as FilterNode : null;
var rightFilter = JoinType == QualifiedJoinType.Inner || JoinType == QualifiedJoinType.RightOuter ? RightSource as FilterNode : null;
var leftFetch = (leftFilter?.Source ?? LeftSource) as FetchXmlScan;
var rightFetch = (rightFilter?.Source ?? RightSource) as FetchXmlScan;
var leftJoin = (leftFilter?.Source ?? LeftSource) as BaseJoinNode;
var rightJoin = (rightFilter?.Source ?? RightSource) as BaseJoinNode;
var leftMeta = (leftFilter?.Source ?? LeftSource) as MetadataQueryNode;
var rightMeta = (rightFilter?.Source ?? RightSource) as MetadataQueryNode;

if (leftJoin != null && rightFetch != null && FoldFetchXmlJoin(context, hints, leftJoin, rightFetch, rightSchema, out folded))
return PrependFilters(folded, context, hints, leftFilter, rightFilter);
if (leftFetch != null && rightFetch != null && FoldFetchXmlJoin(context, hints, leftFetch, leftSchema, rightFetch, rightSchema, out folded))
return PrependFilters(folded, context, hints, leftFilter, rightFilter);

if (rightJoin != null && leftFetch != null && FoldFetchXmlJoin(context, hints, rightJoin, leftFetch, leftSchema, out folded))
return PrependFilters(folded, context, hints, leftFilter, rightFilter);
if (leftJoin != null && rightFetch != null && FoldFetchXmlJoin(context, hints, leftJoin, rightFetch, rightSchema, out folded))
return PrependFilters(folded, context, hints, leftFilter, rightFilter);

if (leftMeta != null && rightMeta != null && JoinType == QualifiedJoinType.Inner && FoldMetadataJoin(context, hints, leftMeta, leftSchema, rightMeta, rightSchema, out folded))
{
folded = PrependFilters(folded, context, hints, leftFilter, rightFilter);
if (rightJoin != null && leftFetch != null && FoldFetchXmlJoin(context, hints, rightJoin, leftFetch, leftSchema, out folded))
return PrependFilters(folded, context, hints, leftFilter, rightFilter);

if (AdditionalJoinCriteria != null)
if (leftMeta != null && rightMeta != null && JoinType == QualifiedJoinType.Inner && FoldMetadataJoin(context, hints, leftMeta, leftSchema, rightMeta, rightSchema, out folded))
{
folded = new FilterNode
folded = PrependFilters(folded, context, hints, leftFilter, rightFilter);

if (AdditionalJoinCriteria != null)
{
Source = folded,
Filter = AdditionalJoinCriteria
}.FoldQuery(context, hints);
}
folded = new FilterNode
{
Source = folded,
Filter = AdditionalJoinCriteria
}.FoldQuery(context, hints);
}

return folded;
return folded;
}
}

// Add not-null filter on join keys
// Inner join - both must be non-null
// Left outer join - right key must be non-null
// Right outer join - left key must be non-null
if (JoinType == QualifiedJoinType.Inner || JoinType == QualifiedJoinType.RightOuter)
LeftSource = AddNotNullFilter(LeftSource, LeftAttribute, context, hints, false);

if (JoinType == QualifiedJoinType.Inner || JoinType == QualifiedJoinType.LeftOuter)
RightSource = AddNotNullFilter(RightSource, RightAttribute, context, hints, false);
if (ComparisonType == BooleanComparisonType.Equals)
{
// Add not-null filter on join keys
// Inner join - both must be non-null
// Left outer join - right key must be non-null
// Right outer join - left key must be non-null
if (JoinType == QualifiedJoinType.Inner || JoinType == QualifiedJoinType.RightOuter)
LeftSource = AddNotNullFilter(LeftSource, LeftAttribute, context, hints, false);

if (JoinType == QualifiedJoinType.Inner || JoinType == QualifiedJoinType.LeftOuter)
RightSource = AddNotNullFilter(RightSource, RightAttribute, context, hints, false);
}

if (FoldSingleRowJoinToNestedLoop(context, hints, leftSchema, rightSchema, out folded))
return folded;
Expand Down
Loading

0 comments on commit 9a1bb1d

Please sign in to comment.