Skip to content

Commit 94fcf0d

Browse files
authored
Assorted SQL analyzer fixes (#82)
* fix #79 * fix #80; add new rule 243 for invalid datepart expressions * groundwork for aggregate * fix #81; add new rule DAP244 for mixing aggregate and non-aggregate data
1 parent a5fba00 commit 94fcf0d

File tree

12 files changed

+301
-27
lines changed

12 files changed

+301
-27
lines changed

docs/rules/DAP243.md

+12
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,12 @@
1+
# DAP243
2+
3+
Date functions like `DATEADD`, `DATEPART` expect a *datepart* token as the first argument; for example in
4+
5+
``` sql
6+
DATEPART(year, GETDATE())
7+
```
8+
9+
the `year` is the *datepart* token. These values cannot be parameterized or take a value
10+
from a column - they are a special kind of literal value.
11+
12+
For the list of valid tokens, see [here](https://learn.microsoft.com/sql/t-sql/functions/dateadd-transact-sql).

docs/rules/DAP244.md

+28
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,28 @@
1+
# DAP244
2+
3+
A `SELECT` expression cannot mix aggregate and non-aggregate results;
4+
5+
Fine:
6+
7+
``` sql
8+
select Name
9+
from SomeTable
10+
```
11+
12+
or
13+
14+
``` sql
15+
select COUNT(1)
16+
from SomeTable
17+
```
18+
19+
Invalid:
20+
21+
or
22+
23+
``` sql
24+
select Name, COUNT(1)
25+
from SomeTable
26+
```
27+
28+
Aggregate functions are [listed here](https://learn.microsoft.com/sql/t-sql/functions/aggregate-functions-transact-sql).

src/Dapper.AOT.Analyzers/CodeAnalysis/DapperAnalyzer.Diagnostics.cs

+3-1
Original file line numberDiff line numberDiff line change
@@ -93,6 +93,8 @@ public static readonly DiagnosticDescriptor
9393
InvalidNullExpression = SqlWarning("DAP239", "Invalid null expression", "Operation requires a non-null operand"),
9494
VariableParameterConflict = SqlError("DAP240", "Parameter/variable conflict", "The declaration of variable '{0}' conflicts with a parameter"),
9595
InterpolatedStringSqlExpression = SqlWarning("DAP241", "Interpolated string usage", "Data values should not be interpolated into SQL string - use parameters instead"),
96-
ConcatenatedStringSqlExpression = SqlWarning("DAP242", "Concatenated string usage", "Data values should not be concatenated into SQL string - use parameters instead");
96+
ConcatenatedStringSqlExpression = SqlWarning("DAP242", "Concatenated string usage", "Data values should not be concatenated into SQL string - use parameters instead"),
97+
InvalidDatepartToken = SqlWarning("DAP243", "Valid datepart token expected", "Date functions require a recognized datepart argument"),
98+
SelectAggregateMismatch = SqlWarning("DAP244", "SELECT aggregate mismatch", "SELECT has mixture of aggregate and non-aggregate expressions");
9799
}
98100
}

src/Dapper.AOT.Analyzers/Internal/DiagnosticTSqlProcessor.cs

+6-3
Original file line numberDiff line numberDiff line change
@@ -4,10 +4,7 @@
44
using Microsoft.CodeAnalysis;
55
using Microsoft.CodeAnalysis.Diagnostics;
66
using Microsoft.SqlServer.TransactSql.ScriptDom;
7-
using System;
8-
using System.Data;
97
using System.Diagnostics;
10-
using static Dapper.SqlAnalysis.TSqlProcessor;
118

129
namespace Dapper.Internal;
1310

@@ -126,6 +123,10 @@ protected override void OnFromMultiTableMissingAlias(Location location)
126123
=> OnDiagnostic(DapperAnalyzer.Diagnostics.FromMultiTableMissingAlias, location);
127124
protected override void OnFromMultiTableUnqualifiedColumn(Location location, string name)
128125
=> OnDiagnostic(DapperAnalyzer.Diagnostics.FromMultiTableUnqualifiedColumn, location, name);
126+
127+
protected override void OnInvalidDatepartToken(Location location)
128+
=> OnDiagnostic(DapperAnalyzer.Diagnostics.InvalidDatepartToken, location);
129+
129130
protected override void OnNonIntegerTop(Location location)
130131
=> OnDiagnostic(DapperAnalyzer.Diagnostics.NonIntegerTop, location);
131132
protected override void OnNonPositiveTop(Location location)
@@ -138,6 +139,8 @@ protected override void OnSelectFirstTopError(Location location)
138139
=> OnDiagnostic(DapperAnalyzer.Diagnostics.SelectFirstTopError, location);
139140
protected override void OnSelectSingleRowWithoutWhere(Location location)
140141
=> OnDiagnostic(DapperAnalyzer.Diagnostics.SelectSingleRowWithoutWhere, location);
142+
protected override void OnSelectAggregateAndNonAggregate(Location location)
143+
=> OnDiagnostic(DapperAnalyzer.Diagnostics.SelectAggregateMismatch, location);
141144
protected override void OnSelectSingleTopError(Location location)
142145
=> OnDiagnostic(DapperAnalyzer.Diagnostics.SelectSingleTopError, location);
143146

src/Dapper.AOT.Analyzers/SqlAnalysis/TSqlProcessor.cs

+148-20
Original file line numberDiff line numberDiff line change
@@ -238,6 +238,8 @@ protected virtual void OnSelectFirstTopError(Location location)
238238
=> OnError($"SELECT for First* should use TOP 1", location);
239239
protected virtual void OnSelectSingleRowWithoutWhere(Location location)
240240
=> OnError($"SELECT for single row without WHERE or (TOP and ORDER BY)", location);
241+
protected virtual void OnSelectAggregateAndNonAggregate(Location location)
242+
=> OnError($"SELECT has mixture of aggregate and non-aggregate expressions", location);
241243
protected virtual void OnNonPositiveTop(Location location)
242244
=> OnError($"TOP literals should be positive", location);
243245
protected virtual void OnNonPositiveFetch(Location location)
@@ -250,6 +252,9 @@ protected virtual void OnFromMultiTableMissingAlias(Location location)
250252
=> OnError($"FROM expressions with multiple elements should use aliases", location);
251253
protected virtual void OnFromMultiTableUnqualifiedColumn(Location location, string name)
252254
=> OnError($"FROM expressions with multiple elements should qualify all columns; it is unclear where '{name}' is located", location);
255+
256+
protected virtual void OnInvalidDatepartToken(Location location)
257+
=> OnError($"Valid datepart token expected", location);
253258
protected virtual void OnTopWithOffset(Location location)
254259
=> OnError($"TOP cannot be used when OFFSET is specified", location);
255260

@@ -702,6 +707,66 @@ public override void Visit(QuerySpecification node)
702707
base.Visit(node);
703708
}
704709

710+
public override void ExplicitVisit(FunctionCall node)
711+
{
712+
ScalarExpression? ignore = null;
713+
if (node.Parameters.Count != 0 && IsSpecialDateFunction(node.FunctionName.Value))
714+
{
715+
ValidateDateArg(ignore = node.Parameters[0]);
716+
}
717+
var oldIgnore = _demandAliases.IgnoreNode; // stash
718+
_demandAliases.IgnoreNode = ignore;
719+
base.ExplicitVisit(node); // dive
720+
_demandAliases.IgnoreNode = oldIgnore; // restore
721+
722+
static bool IsSpecialDateFunction(string name)
723+
=> name.StartsWith("DATE", StringComparison.OrdinalIgnoreCase)
724+
&& IsAnyCaseInsensitive(name, DateTokenFunctions);
725+
}
726+
727+
static bool IsAnyCaseInsensitive(string value, string[] options)
728+
{
729+
if (value is not null)
730+
{
731+
foreach (var option in options)
732+
{
733+
if (string.Equals(option, value, StringComparison.OrdinalIgnoreCase))
734+
{
735+
return true;
736+
}
737+
}
738+
}
739+
return false;
740+
}
741+
// arg0 has special meaning - not a column/etc
742+
static readonly string[] DateTokenFunctions = ["DATE_BUCKET", "DATEADD", "DATEDIFF", "DATEDIFF_BIG", "DATENAME", "DATEPART", "DATETRUNC"];
743+
static readonly string[] DateTokens = [
744+
"year", "yy", "yyyy",
745+
"quarter", "qq", "q",
746+
"month", "mm", "m",
747+
"dayofyear", "dy", "y",
748+
"day", "dd", "d",
749+
"week", "wk", "ww",
750+
"weekday", "dw", "w",
751+
"hour", "hh",
752+
"minute", "mi", "n",
753+
"second", "ss", "s",
754+
"millisecond", "ms",
755+
"microsecond", "mcs",
756+
"nanosecond", "ns"
757+
];
758+
759+
private void ValidateDateArg(ScalarExpression value)
760+
{
761+
if (!(value is ColumnReferenceExpression col
762+
&& col.MultiPartIdentifier.Count == 1 && IsAnyCaseInsensitive(
763+
col.MultiPartIdentifier[0].Value, DateTokens)))
764+
{
765+
parser.OnInvalidDatepartToken(value);
766+
}
767+
768+
}
769+
705770
public override void Visit(SelectStatement node)
706771
{
707772
if (node.QueryExpression is QuerySpecification spec)
@@ -717,13 +782,15 @@ public override void Visit(SelectStatement node)
717782
var checkNames = ValidateSelectNames;
718783
HashSet<string> names = checkNames ? new HashSet<string>(StringComparer.InvariantCultureIgnoreCase) : null!;
719784

785+
var aggregate = AggregateFlags.None;
720786
int index = 0;
721787
foreach (var el in spec.SelectElements)
722788
{
723789
switch (el)
724790
{
725791
case SelectStarExpression:
726792
parser.OnSelectStar(el);
793+
aggregate |= AggregateFlags.HaveNonAggregate;
727794
reads++;
728795
break;
729796
case SelectScalarExpression scalar:
@@ -747,6 +814,7 @@ public override void Visit(SelectStatement node)
747814
parser.OnSelectDuplicateColumnName(scalar, name!);
748815
}
749816
}
817+
aggregate |= IsAggregate(scalar.Expression);
750818
reads++;
751819
break;
752820
case SelectSetVariable:
@@ -755,33 +823,43 @@ public override void Visit(SelectStatement node)
755823
}
756824
index++;
757825
}
826+
827+
if (aggregate == (AggregateFlags.HaveAggregate | AggregateFlags.HaveNonAggregate))
828+
{
829+
parser.OnSelectAggregateAndNonAggregate(spec);
830+
}
831+
758832
if (reads != 0)
759833
{
760834
if (sets != 0)
761835
{
762836
parser.OnSelectAssignAndRead(spec);
763837
}
764-
bool firstQuery = AddQuery();
765-
if (firstQuery && SingleRow // optionally enforce single-row validation
766-
&& spec.FromClause is not null) // no "from" is things like 'select @id, @name' - always one row
838+
if (node.Into is null) // otherwise not actually a query
767839
{
768-
bool haveTopOrFetch = false;
769-
if (spec.TopRowFilter is { Percent: false, Expression: ScalarExpression top })
770-
{
771-
haveTopOrFetch = EnforceTop(top);
772-
}
773-
else if (spec.OffsetClause is { FetchExpression: ScalarExpression fetch })
840+
bool firstQuery = AddQuery();
841+
if (firstQuery && SingleRow // optionally enforce single-row validation
842+
&& spec.FromClause is not null) // no "from" is things like 'select @id, @name' - always one row
774843
{
775-
haveTopOrFetch = EnforceTop(fetch);
776-
}
844+
bool haveTopOrFetch = false;
845+
if (spec.TopRowFilter is { Percent: false, Expression: ScalarExpression top })
846+
{
847+
haveTopOrFetch = EnforceTop(top);
848+
}
849+
else if (spec.OffsetClause is { FetchExpression: ScalarExpression fetch })
850+
{
851+
haveTopOrFetch = EnforceTop(fetch);
852+
}
777853

778-
// we want *either* a WHERE (which we will allow with/without a TOP),
779-
// or a TOP + ORDER BY
780-
if (!IsUnfiltered(spec.FromClause, spec.WhereClause)) { } // fine
781-
else if (haveTopOrFetch && spec.OrderByClause is not null) { } // fine
782-
else
783-
{
784-
parser.OnSelectSingleRowWithoutWhere(node);
854+
// we want *either* a WHERE (which we will allow with/without a TOP),
855+
// or a TOP + ORDER BY
856+
if (!IsUnfiltered(spec.FromClause, spec.WhereClause)) { } // fine
857+
else if (haveTopOrFetch && spec.OrderByClause is not null) { } // fine
858+
else if ((aggregate & (AggregateFlags.HaveAggregate | AggregateFlags.Uncertain)) != 0) { } // fine
859+
else
860+
{
861+
parser.OnSelectSingleRowWithoutWhere(node);
862+
}
785863
}
786864
}
787865
}
@@ -790,6 +868,50 @@ public override void Visit(SelectStatement node)
790868
base.Visit(node);
791869
}
792870

871+
enum AggregateFlags
872+
{
873+
None = 0,
874+
HaveAggregate = 1 << 0,
875+
HaveNonAggregate = 1 << 1,
876+
Uncertain = 1 << 2,
877+
}
878+
879+
private AggregateFlags IsAggregate(ScalarExpression expression)
880+
{
881+
// any use of an aggregate function contributes HaveAggregate
882+
// - there could be unary/binary operations on that aggregate function
883+
// - column references etc inside an aggregate expression,
884+
// otherwise they contribute HaveNonAggregate
885+
switch (expression)
886+
{
887+
case Literal:
888+
return AggregateFlags.None;
889+
case UnaryExpression ue:
890+
return IsAggregate(ue.Expression);
891+
case BinaryExpression be:
892+
return IsAggregate(be.FirstExpression)
893+
| IsAggregate(be.SecondExpression);
894+
case FunctionCall func when IsAggregateFunction(func.FunctionName.Value):
895+
return AggregateFlags.HaveAggregate; // don't need to look inside
896+
case ScalarSubquery sq:
897+
throw new NotSupportedException();
898+
case IdentityFunctionCall:
899+
case PrimaryExpression:
900+
return AggregateFlags.HaveNonAggregate;
901+
default:
902+
return AggregateFlags.Uncertain;
903+
}
904+
905+
static bool IsAggregateFunction(string name)
906+
=> IsAnyCaseInsensitive(name, AggregateFunctions);
907+
}
908+
909+
static readonly string[] AggregateFunctions = [
910+
"APPROX_COUNT_DISTINCT", "AVG","CHECKSUM_AGG", "COUNT", "COUNT_BIG",
911+
"GROUPING", "GROUPING_ID", "MAX", "MIN", "STDEV",
912+
"STDEVP", "STRING_AGG", "SUM", "VAR", "VARP",
913+
];
914+
793915
private bool EnforceTop(ScalarExpression expr)
794916
{
795917
if (IsInt32(expr, out var i) == TryEvaluateResult.SuccessConstant && i.HasValue)
@@ -1291,7 +1413,7 @@ bool TrySimplifyExpression(ScalarExpression node)
12911413
{
12921414
if (_expressionAlreadyEvaluated) return true;
12931415

1294-
if (node is UnaryExpression { UnaryExpressionType: UnaryExpressionType.Negative, Expression: IntegerLiteral or NumericLiteral })
1416+
if (node is UnaryExpression { UnaryExpressionType: UnaryExpressionType.Negative, Expression: IntegerLiteral or NumericLiteral })
12951417
{
12961418
// just "-4" or similar; don't warn the user to simplify that!
12971419
_expressionAlreadyEvaluated = true;
@@ -1340,6 +1462,9 @@ public override void ExplicitVisit(BinaryExpression node)
13401462

13411463
public override void Visit(OutputClause node)
13421464
{
1465+
// note that this doesn't handle OUTPUT INTO,
1466+
// which is via OutputIntoClause
1467+
13431468
AddQuery(); // works like a query
13441469
base.Visit(node);
13451470
}
@@ -1409,6 +1534,8 @@ public DemandAliasesState(bool active, TableReference? amnesty)
14091534
public readonly bool Active;
14101535
public readonly TableReference? Amnesty; // we can't validate the target until too late
14111536
public bool AmnestyNodeIsAlias;
1537+
1538+
public ScalarExpression? IgnoreNode { get; set; }
14121539
}
14131540

14141541
private DemandAliasesState _demandAliases;
@@ -1435,7 +1562,8 @@ public override void Visit(TableReferenceWithAlias node)
14351562
}
14361563
public override void Visit(ColumnReferenceExpression node)
14371564
{
1438-
if (_demandAliases.Active && node.MultiPartIdentifier.Count == 1)
1565+
if (_demandAliases.Active && node.MultiPartIdentifier.Count == 1
1566+
&& !ReferenceEquals(node, _demandAliases.IgnoreNode))
14391567
{
14401568
parser.OnFromMultiTableUnqualifiedColumn(node, node.MultiPartIdentifier[0].Value);
14411569
}

test/Dapper.AOT.Test/Verifiers/DAP025.cs

+13
Original file line numberDiff line numberDiff line change
@@ -46,4 +46,17 @@ exec SomeLookupFetch
4646
Diagnostic(Diagnostics.ExecuteCommandWithQuery).WithLocation(0),
4747
]);
4848

49+
[Fact]
50+
public Task ReportWhenNoQueryExpected() => SqlVerifyAsync("""
51+
SELECT [Test]
52+
FROM MyTable
53+
""", SqlAnalysis.SqlParseInputFlags.ExpectNoQuery,
54+
Diagnostic(Diagnostics.ExecuteCommandWithQuery).WithLocation(Execute));
55+
56+
[Fact] // false positive scenario, https://github.com/DapperLib/DapperAOT/issues/79
57+
public Task DoNotReportSelectInto() => SqlVerifyAsync("""
58+
SELECT [Test]
59+
INTO #MyTemporaryTable FROM MyTable
60+
""", SqlAnalysis.SqlParseInputFlags.ExpectNoQuery);
61+
4962
}

test/Dapper.AOT.Test/Verifiers/DAP026.cs

+13
Original file line numberDiff line numberDiff line change
@@ -47,4 +47,17 @@ exec SomeLookupInsert 'North'
4747
Diagnostic(Diagnostics.QueryCommandMissingQuery).WithLocation(0),
4848
]);
4949

50+
[Fact]
51+
public Task DoNotReportWhenQueryExpected() => SqlVerifyAsync("""
52+
SELECT [Test]
53+
FROM MyTable
54+
""", SqlAnalysis.SqlParseInputFlags.ExpectQuery);
55+
56+
[Fact]
57+
public Task ReportSelectInto() => SqlVerifyAsync("""
58+
SELECT [Test]
59+
INTO #MyTemporaryTable FROM MyTable
60+
""", SqlAnalysis.SqlParseInputFlags.ExpectQuery,
61+
Diagnostic(Diagnostics.QueryCommandMissingQuery).WithLocation(Execute));
62+
5063
}

test/Dapper.AOT.Test/Verifiers/DAP226.cs

+8-1
Original file line numberDiff line numberDiff line change
@@ -16,5 +16,12 @@ from A a
1616
from A a
1717
inner join B b on b.X = a.Id
1818
""", Diagnostic(Diagnostics.FromMultiTableUnqualifiedColumn).WithLocation(0).WithArguments("Name"));
19-
19+
20+
[Fact] // false positive: https://github.com/DapperLib/DapperAOT/issues/80
21+
public Task DoNotReportDateAdd() => SqlVerifyAsync("""
22+
SELECT DATEADD(YEAR, 1, t.Year) AS NextYear
23+
FROM MyTable t
24+
JOIN MyOtherTable o ON o.Id = t.Id
25+
""");
26+
2027
}

0 commit comments

Comments
 (0)