Permalink
Browse files

NH-2977

- Added limit SQL generation for SQL Server queries with comments, common table expressions, and stored procedure invocations.
- Modified loader to fall back to client-side limit/offset behavior if dialect does not support generation of server side limit/offset SQL for a given (custom) SQL statement.
  • Loading branch information...
ggeurts authored and hazzik committed Jan 23, 2012
1 parent 082fe61 commit 65ac675ff3a9271ca74f56be5601d1473266f34d
@@ -75,7 +75,7 @@ public void OnlyOffsetLimit()
var d = new MsSql2005Dialect();
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 TOP (10) 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"));
+ Assert.That(str.ToString(), Is.EqualTo("select distinct TOP (10) 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"));
}
[Test]
@@ -222,7 +222,85 @@ public void GetIfExistsDropConstraintTest_For_Schema_other_than_dbo()
public void GetLimitStringWithSqlComments()
{
var d = new MsSql2005Dialect();
- Assert.Throws<NotSupportedException>(() => d.GetLimitString(new SqlString(" /* criteria query */ SELECT p from lcdtm"), null, new SqlString("2")));
+ 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 TOP (2) p from lcdtm"));
+ }
+
+ [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 TOP (2) ManagerID, EmployeeID, Title, Level
+ FROM DirectReports";
+
+ var d = new MsSql2005Dialect();
+ 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 MsSql2005Dialect();
+ 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);
}
}
}
@@ -0,0 +1,52 @@
+using NHibernate.Cfg.MappingSchema;
+using NUnit.Framework;
+
+namespace NHibernate.Test.NHSpecificTest.NH2977
+{
+ /// <summary>
+ /// Fixture using 'by code' mappings
+ /// </summary>
+ /// <remarks>
+ /// This fixture is identical to <see cref="Fixture" /> except the <see cref="Entity" /> mapping is performed
+ /// by code in the GetMappings method, and does not require the <c>Mappings.hbm.xml</c> file. Use this approach
+ /// if you prefer.
+ /// </remarks>
+ public class ByCodeFixture : TestCaseMappingByCode
+ {
+ protected override HbmMapping GetMappings()
+ {
+ return new HbmMapping();
+ }
+
+ protected override bool AppliesTo(Dialect.Dialect dialect)
+ {
+ return dialect is Dialect.MsSql2000Dialect;
+ }
+
+ [Test]
+ public void CanGetUniqueStoredProcedureResult()
+ {
+ using (ISession session = OpenSession())
+ using (session.BeginTransaction())
+ {
+ var result = session.CreateSQLQuery("EXEC sp_stored_procedures ?")
+ .SetString(0, "sp_help")
+ .UniqueResult();
+ Assert.That(result, Is.Not.Null);
+ }
+ }
+
+ [Test]
+ public void CanLimitStoredProcedureResults()
+ {
+ using (ISession session = OpenSession())
+ using (session.BeginTransaction())
+ {
+ var result = session.CreateSQLQuery("EXEC sp_stored_procedures")
+ .SetMaxResults(5)
+ .List();
+ Assert.That(result, Has.Count.EqualTo(5));
+ }
+ }
+ }
+}
@@ -1020,6 +1020,7 @@
<Compile Include="NHSpecificTest\NH2960\Fixture.cs" />
<Compile Include="NHSpecificTest\NH2959\Entity.cs" />
<Compile Include="NHSpecificTest\NH2959\Fixture.cs" />
+ <Compile Include="NHSpecificTest\NH2977\FixtureByCode.cs" />
<Compile Include="NHSpecificTest\NH3010\FixtureWithBatcher.cs" />
<Compile Include="NHSpecificTest\NH3010\FixtureWithNoBatcher.cs" />
<Compile Include="NHSpecificTest\NH3010\Model.cs" />
@@ -1452,20 +1452,22 @@ public virtual bool OffsetStartsAtOne
}
/// <summary>
- /// Add a <c>LIMIT</c> clause to the given SQL <c>SELECT</c>.
+ /// Attempts to add a <c>LIMIT</c> clause to the given SQL <c>SELECT</c>.
/// Expects any database-specific offset and limit adjustments to have already been performed (ex. UseMaxForLimit, OffsetStartsAtOne).
/// </summary>
/// <param name="queryString">The <see cref="SqlString"/> to base the limit query off.</param>
/// <param name="offset">Offset of the first row to be returned by the query. This may be represented as a parameter, a string literal, or a null value if no limit is requested. This should have already been adjusted to account for OffsetStartsAtOne.</param>
/// <param name="limit">Maximum number of rows to be returned by the query. This may be represented as a parameter, a string literal, or a null value if no offset is requested. This should have already been adjusted to account for UseMaxForLimit.</param>
- /// <returns>A new <see cref="SqlString"/> that contains the <c>LIMIT</c> clause.</returns>
+ /// <returns>A new <see cref="SqlString"/> that contains the <c>LIMIT</c> clause. Returns <c>null</c>
+ /// if <paramref name="queryString"/> represents a SQL statement to which a limit clause cannot be added,
+ /// for example when the query string is custom SQL invoking a stored procedure.</returns>
public virtual SqlString GetLimitString(SqlString queryString, SqlString offset, SqlString limit)
{
throw new NotSupportedException("Dialect does not have support for limit strings.");
}
/// <summary>
- /// Generates a string to limit the result set to a number of maximum results with a specified offset into the results.
+ /// Attempts to generate a string to limit the result set to a number of maximum results with a specified offset into the results.
/// Expects any database-specific offset and limit adjustments to have already been performed (ex. UseMaxForLimit, OffsetStartsAtOne).
/// Performs error checking based on the various dialect limit support options. If both parameters and fixed valeus are
/// specified, this will use the parameter option if possible. Otherwise, it will fall back to a fixed string.
@@ -9,6 +9,7 @@
using NHibernate.Engine;
using NHibernate.Mapping;
using NHibernate.SqlCommand;
+using NHibernate.SqlCommand.Parser;
using NHibernate.Type;
using NHibernate.Util;
using Environment = NHibernate.Cfg.Environment;
@@ -340,15 +341,26 @@ public override bool SupportsVariableLimit
public override SqlString GetLimitString(SqlString querySqlString, SqlString offset, SqlString limit)
{
- /*
- * "SELECT TOP limit rest-of-sql-statement"
- */
+ int insertPoint;
+ return TryFindLimitInsertPoint(querySqlString, out insertPoint)
+ ? querySqlString.Insert(insertPoint, new SqlString("top ", limit, " "))
+ : null;
+ }
- SqlStringBuilder topFragment = new SqlStringBuilder();
- topFragment.Add(" top ");
- topFragment.Add(limit);
+ 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;
+ }
- return querySqlString.Insert(GetAfterSelectInsertPoint(querySqlString), topFragment.ToSqlString());
+ result = -1;
+ return false;
}
/// <summary>
@@ -398,19 +410,6 @@ public override string UnQuote(string quoted)
return quoted.Replace(new string(CloseQuote, 2), CloseQuote.ToString());
}
- private static int GetAfterSelectInsertPoint(SqlString sql)
- {
- if (sql.StartsWithCaseInsensitive("select distinct"))
- {
- return 15;
- }
- else if (sql.StartsWithCaseInsensitive("select"))
- {
- return 6;
- }
- throw new NotSupportedException("The query should start with 'SELECT' or 'SELECT DISTINCT'");
- }
-
protected bool NeedsLockHint(LockMode lockMode)
{
return lockMode.GreaterThan(LockMode.Read);
@@ -103,4 +103,4 @@ public override string AppendLockHint(LockMode lockMode, string tableName)
return tableName;
}
}
-}
+}
Oops, something went wrong.

0 comments on commit 65ac675

Please sign in to comment.