Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with
or
.
Download ZIP
Browse files

Paging for MsSql2012 changed to the new recommended standard syntax a…

…nd made MsSql20xxDialect.GetLimitString() implementations more consistent.
  • Loading branch information...
commit 171ae483a3a0052806da42655991a34b4b56b8da 1 parent 65ac675
@ggeurts ggeurts authored hazzik committed
View
160 src/NHibernate.Test/DialectTest/MsSql2012DialectFixture.cs
@@ -0,0 +1,160 @@
+using NHibernate.Dialect;
+using NHibernate.SqlCommand;
+using NUnit.Framework;
+
+namespace NHibernate.Test.DialectTest
+{
+ [TestFixture]
+ public class MsSql2012DialectFixture
+ {
+ [Test]
+ public void GetLimitString()
+ {
+ var d = new MsSql2012Dialect();
+
+ SqlString str = d.GetLimitString(new SqlString("select distinct c.Contact_Id as Contact1_19_0_, c.Rating as Rating2_19_0_, c.Last_Name as Last_Name3_19_0, c.First_Name as First_Name4_19_0 from dbo.Contact c where COALESCE(c.Rating, 0) > 0 order by c.Rating desc , c.Last_Name , c.First_Name"), new SqlString("111"), new SqlString("222"));
+ Assert.AreEqual(
+ "select distinct c.Contact_Id as Contact1_19_0_, c.Rating as Rating2_19_0_, c.Last_Name as Last_Name3_19_0, c.First_Name as First_Name4_19_0 from dbo.Contact c where COALESCE(c.Rating, 0) > 0 order by c.Rating desc , c.Last_Name , c.First_Name OFFSET 111 ROWS FETCH FIRST 222 ROWS ONLY",
+ str.ToString());
+
+ str = d.GetLimitString(new SqlString("SELECT fish.id FROM fish"), new SqlString("111"), new SqlString("222"));
+ Assert.AreEqual(
+ "SELECT fish.id FROM fish ORDER BY CURRENT_TIMESTAMP OFFSET 111 ROWS FETCH FIRST 222 ROWS ONLY",
+ str.ToString());
+
+ str = d.GetLimitString(new SqlString("SELECT DISTINCT fish_.id FROM fish fish_"), new SqlString("111"), new SqlString("222"));
+ Assert.AreEqual(
+ "SELECT DISTINCT fish_.id FROM fish fish_ ORDER BY CURRENT_TIMESTAMP OFFSET 111 ROWS FETCH FIRST 222 ROWS ONLY",
+ str.ToString());
+
+ str = d.GetLimitString(new SqlString("SELECT DISTINCT fish_.id as ixx9_ FROM fish fish_"), new SqlString("111"), new SqlString("222"));
+ Assert.AreEqual(
+ "SELECT DISTINCT fish_.id as ixx9_ FROM fish fish_ ORDER BY CURRENT_TIMESTAMP OFFSET 111 ROWS FETCH FIRST 222 ROWS ONLY",
+ str.ToString());
+
+ str = d.GetLimitString(new SqlString("SELECT * FROM fish ORDER BY name"), new SqlString("111"), new SqlString("222"));
+ Assert.AreEqual(
+ "SELECT * FROM fish ORDER BY name OFFSET 111 ROWS FETCH FIRST 222 ROWS ONLY",
+ str.ToString());
+
+ str = d.GetLimitString(new SqlString("SELECT fish.id, fish.name FROM fish ORDER BY name DESC"), new SqlString("111"), new SqlString("222"));
+ Assert.AreEqual(
+ "SELECT fish.id, fish.name FROM fish ORDER BY name DESC OFFSET 111 ROWS FETCH FIRST 222 ROWS ONLY",
+ str.ToString());
+
+ str = d.GetLimitString(new SqlString("SELECT * FROM fish LEFT JOIN (SELECT * FROM meat ORDER BY weight) AS t ORDER BY name DESC"), new SqlString("111"), new SqlString("222"));
+ Assert.AreEqual(
+ "SELECT * FROM fish LEFT JOIN (SELECT * FROM meat ORDER BY weight) AS t ORDER BY name DESC OFFSET 111 ROWS FETCH FIRST 222 ROWS ONLY",
+ str.ToString());
+
+ str = d.GetLimitString(new SqlString("SELECT *, (SELECT COUNT(1) FROM fowl WHERE fish_id = fish.id) AS some_count FROM fish"), new SqlString("111"), new SqlString("222"));
+ Assert.AreEqual(
+ "SELECT *, (SELECT COUNT(1) FROM fowl WHERE fish_id = fish.id) AS some_count FROM fish ORDER BY CURRENT_TIMESTAMP OFFSET 111 ROWS FETCH FIRST 222 ROWS ONLY",
+ str.ToString());
+
+ str = d.GetLimitString(new SqlString("SELECT * FROM fish WHERE scales = ", Parameter.Placeholder), new SqlString("111"), new SqlString("222"));
+ Assert.AreEqual(
+ "SELECT * FROM fish WHERE scales = ? ORDER BY CURRENT_TIMESTAMP OFFSET 111 ROWS FETCH FIRST 222 ROWS ONLY",
+ str.ToString());
+
+ str = d.GetLimitString(new SqlString("SELECT f.Type, COUNT(DISTINCT f.Name) AS Name FROM Fish f GROUP BY f.Type ORDER BY COUNT(DISTINCT f.Name)"), new SqlString("111"), new SqlString("222"));
+ Assert.AreEqual(
+ "SELECT f.Type, COUNT(DISTINCT f.Name) AS Name FROM Fish f GROUP BY f.Type ORDER BY COUNT(DISTINCT f.Name) OFFSET 111 ROWS FETCH FIRST 222 ROWS ONLY",
+ str.ToString());
+ }
+
+ [Test]
+ public void OnlyOffsetLimit()
+ {
+ var d = new MsSql2012Dialect();
+
+ SqlString str = d.GetLimitString(new SqlString("select distinct c.Contact_Id as Contact1_19_0_, c._Rating as Rating2_19_0_ from dbo.Contact c where COALESCE(c.Rating, 0) > 0 order by c.Rating desc , c.Last_Name , c.First_Name"), null, new SqlString("10"));
+ Assert.That(str.ToString(), Is.EqualTo("select distinct c.Contact_Id as Contact1_19_0_, c._Rating as Rating2_19_0_ from dbo.Contact c where COALESCE(c.Rating, 0) > 0 order by c.Rating desc , c.Last_Name , c.First_Name OFFSET 0 ROWS FETCH FIRST 10 ROWS ONLY"));
+ }
+
+ [Test]
+ public void GetLimitStringWithSqlComments()
+ {
+ var d = new MsSql2012Dialect();
+ var limitSqlQuery = d.GetLimitString(new SqlString(" /* criteria query */ SELECT p from lcdtm"), null, new SqlString("2"));
+ Assert.That(limitSqlQuery, Is.Not.Null);
+ Assert.That(limitSqlQuery.ToString(), Is.EqualTo(" /* criteria query */ SELECT p from lcdtm ORDER BY CURRENT_TIMESTAMP OFFSET 0 ROWS FETCH FIRST 2 ROWS ONLY"));
+ }
+
+ [Test]
+ public void GetLimitStringWithSqlCommonTableExpression()
+ {
+ const string SQL = @"
+ WITH DirectReports (ManagerID, EmployeeID, Title, DeptID, Level)
+ ( -- Anchor member definition
+ SELECT ManagerID, EmployeeID, Title, Deptid, 0 AS Level
+ FROM MyEmployees
+ WHERE ManagerID IS NULL
+
+ UNION ALL
+
+ -- Recursive member definition
+ SELECT e.ManagerID, e.EmployeeID, e.Title, e.Deptid, Level + 1
+ FROM MyEmployees AS e
+ INNER JOIN DirectReports AS ON e.ManagerID = d.EmployeeID
+ )
+ -- Statement that executes the CTE
+ SELECT ManagerID, EmployeeID, Title, Level
+ FROM DirectReports";
+
+ const string EXPECTED_SQL = @"
+ WITH DirectReports (ManagerID, EmployeeID, Title, DeptID, Level)
+ ( -- Anchor member definition
+ SELECT ManagerID, EmployeeID, Title, Deptid, 0 AS Level
+ FROM MyEmployees
+ WHERE ManagerID IS NULL
+
+ UNION ALL
+
+ -- Recursive member definition
+ SELECT e.ManagerID, e.EmployeeID, e.Title, e.Deptid, Level + 1
+ FROM MyEmployees AS e
+ INNER JOIN DirectReports AS ON e.ManagerID = d.EmployeeID
+ )
+ -- Statement that executes the CTE
+ SELECT ManagerID, EmployeeID, Title, Level
+ FROM DirectReports ORDER BY CURRENT_TIMESTAMP OFFSET 0 ROWS FETCH FIRST 2 ROWS ONLY";
+
+ var d = new MsSql2012Dialect();
+ var limitSqlQuery = d.GetLimitString(new SqlString(SQL), null, new SqlString("2"));
+ Assert.That(limitSqlQuery, Is.Not.Null);
+ Assert.That(limitSqlQuery.ToString(), Is.EqualTo(EXPECTED_SQL));
+ }
+
+ [Test]
+ public void DontReturnLimitStringForStoredProcedureCall()
+ {
+ VerifyLimitStringForStoredProcedureCalls("EXEC sp_stored_procedures");
+ VerifyLimitStringForStoredProcedureCalls(@"
+ DECLARE @id int
+ SELECT @id = id FROM persons WHERE name LIKE ?
+ EXEC get_person_summary @id");
+ VerifyLimitStringForStoredProcedureCalls(@"
+ DECLARE @id int
+ SELECT DISTINCT TOP 1 @id = id FROM persons WHERE name LIKE ?
+ EXEC get_person_summary @id");
+ VerifyLimitStringForStoredProcedureCalls(@"
+ DECLARE @id int
+ SELECT DISTINCT TOP (?) PERCENT WITH TIES @id = id FROM persons WHERE name LIKE ?
+ EXEC get_person_summary @id");
+ }
+
+ private static void VerifyLimitStringForStoredProcedureCalls(string sql)
+ {
+ var d = new MsSql2012Dialect();
+ var limitSql = d.GetLimitString(new SqlString(sql), null, new SqlString("2"));
+ Assert.That(limitSql, Is.Null, "Limit only: {0}", sql);
+
+ limitSql = d.GetLimitString(new SqlString(sql), new SqlString("10"), null);
+ Assert.That(limitSql, Is.Null, "Offset only: {0}", sql);
+
+ limitSql = d.GetLimitString(new SqlString(sql), new SqlString("10"), new SqlString("2"));
+ Assert.That(limitSql, Is.Null, "Limit and Offset: {0}", sql);
+ }
+ }
+}
View
1  src/NHibernate.Test/NHibernate.Test.csproj
@@ -218,6 +218,7 @@
<Compile Include="Criteria\Reptile.cs" />
<Compile Include="DialectTest\FunctionTests\SubstringSupportFixture.cs" />
<Compile Include="DialectTest\FunctionTests\SequenceSupportFixture.cs" />
+ <Compile Include="DialectTest\MsSql2012DialectFixture.cs" />
<Compile Include="DialectTest\MsSqlCe40DialectFixture.cs" />
<Compile Include="DialectTest\SchemaTests\ColumnMetaDataFixture.cs" />
<Compile Include="DriverTest\DbProviderFactoryDriveConnectionCommandProviderTest.cs" />
View
23 src/NHibernate/Dialect/MsSql2000Dialect.cs
@@ -341,26 +341,11 @@ public override bool SupportsVariableLimit
public override SqlString GetLimitString(SqlString querySqlString, SqlString offset, SqlString limit)
{
- int insertPoint;
- return TryFindLimitInsertPoint(querySqlString, out insertPoint)
- ? querySqlString.Insert(insertPoint, new SqlString("top ", limit, " "))
- : null;
- }
-
- protected static bool TryFindLimitInsertPoint(SqlString sql, out int result)
- {
- var tokenEnum = new SqlTokenizer(sql).GetEnumerator();
-
- SqlToken selectToken;
- bool isDistinct;
- if (tokenEnum.TryParseUntilFirstMsSqlSelectColumn(out selectToken, out isDistinct))
- {
- result = tokenEnum.Current.SqlIndex;
- return true;
- }
+ var tokenEnum = new SqlTokenizer(querySqlString).GetEnumerator();
+ if (!tokenEnum.TryParseUntilFirstMsSqlSelectColumn()) return null;
- result = -1;
- return false;
+ int insertPoint = tokenEnum.Current.SqlIndex;
+ return querySqlString.Insert(insertPoint, new SqlString("top ", limit, " "));
}
/// <summary>
View
25 src/NHibernate/Dialect/MsSql2005DialectQueryPager.cs
@@ -33,10 +33,11 @@ public SqlString PageBy(SqlString offset, SqlString limit)
private SqlString PageByLimitOnly(SqlString limit)
{
- int insertPoint;
- return TryFindLimitInsertPoint(_sourceQuery, out insertPoint)
- ? _sourceQuery.Insert(insertPoint, new SqlString("TOP (", limit, ") "))
- : null;
+ var tokenEnum = new SqlTokenizer(_sourceQuery).GetEnumerator();
+ if (!tokenEnum.TryParseUntilFirstMsSqlSelectColumn()) return null;
+
+ int insertPoint = tokenEnum.Current.SqlIndex;
+ return _sourceQuery.Insert(insertPoint, new SqlString("TOP (", limit, ") "));
}
private SqlString PageByLimitAndOffset(SqlString offset, SqlString limit)
@@ -58,22 +59,6 @@ private SqlString PageByLimitAndOffset(SqlString offset, SqlString limit)
return result.ToSqlString();
}
- protected static bool TryFindLimitInsertPoint(SqlString sql, out int result)
- {
- var tokenEnum = new SqlTokenizer(sql).GetEnumerator();
-
- SqlToken selectToken;
- bool isDistinct;
- if (tokenEnum.TryParseUntilFirstMsSqlSelectColumn(out selectToken, out isDistinct))
- {
- result = tokenEnum.Current.SqlIndex;
- return true;
- }
-
- result = -1;
- return false;
- }
-
private static void BuildSelectClauseForPagingQuery(MsSqlSelectParser sqlQuery, SqlString limit, SqlStringBuilder result)
{
result.Add(sqlQuery.Sql.Substring(0, sqlQuery.SelectIndex));
View
33 src/NHibernate/Dialect/MsSql2012Dialect.cs
@@ -1,4 +1,6 @@
-using NHibernate.Dialect.Function;
+using NHibernate.Dialect.Function;
+using NHibernate.SqlCommand;
+using NHibernate.SqlCommand.Parser;
namespace NHibernate.Dialect
{
@@ -51,5 +53,34 @@ protected override void RegisterFunctions()
base.RegisterFunctions();
RegisterFunction("iif", new StandardSafeSQLFunction("iif", 3));
}
+
+ public override SqlString GetLimitString(SqlString querySqlString, SqlString offset, SqlString limit)
+ {
+ var tokenEnum = new SqlTokenizer(querySqlString).GetEnumerator();
+ if (!tokenEnum.TryParseUntilFirstMsSqlSelectColumn()) return null;
+
+ var result = new SqlStringBuilder(querySqlString);
+ if (!tokenEnum.TryParseUntil("order"))
+ {
+ result.Add(" ORDER BY CURRENT_TIMESTAMP");
+ }
+
+ result.Add(" OFFSET ");
+ if (offset != null)
+ {
+ result.Add(offset).Add(" ROWS");
+ }
+ else
+ {
+ result.Add("0 ROWS");
+ }
+
+ if (limit != null)
+ {
+ result.Add(" FETCH FIRST ").Add(limit).Add(" ROWS ONLY");
+ }
+
+ return result.ToSqlString();
+ }
}
}
View
7 src/NHibernate/SqlCommand/Parser/SqlTokenizerExtensions.cs
@@ -31,6 +31,13 @@ public static bool TryParseUntil(this IEnumerator<SqlToken> tokenEnum, string ke
return false;
}
+ public static bool TryParseUntilFirstMsSqlSelectColumn(this IEnumerator<SqlToken> tokenEnum)
+ {
+ SqlToken selectToken;
+ bool isDistinct;
+ return TryParseUntilFirstMsSqlSelectColumn(tokenEnum, out selectToken, out isDistinct);
+ }
+
public static bool TryParseUntilFirstMsSqlSelectColumn(this IEnumerator<SqlToken> tokenEnum, out SqlToken selectToken, out bool isDistinct)
{
selectToken = null;
Please sign in to comment.
Something went wrong with that request. Please try again.