From 6ca3888166008019ad84db8c7bea0259b14e44b1 Mon Sep 17 00:00:00 2001 From: Curlack Date: Sun, 22 Oct 2023 13:32:27 +0200 Subject: [PATCH 1/6] Fixes #255 also in PagingHelper. Add unit test to confirm. --- .../Utilities/PagingHelperTests.cs | 70 +++++++++++++++++++ PetaPoco/Utilities/PagingHelper.cs | 12 ++-- 2 files changed, 78 insertions(+), 4 deletions(-) create mode 100644 PetaPoco.Tests.Unit/Utilities/PagingHelperTests.cs diff --git a/PetaPoco.Tests.Unit/Utilities/PagingHelperTests.cs b/PetaPoco.Tests.Unit/Utilities/PagingHelperTests.cs new file mode 100644 index 00000000..9a792ab5 --- /dev/null +++ b/PetaPoco.Tests.Unit/Utilities/PagingHelperTests.cs @@ -0,0 +1,70 @@ +using System; +using System.Diagnostics; +using System.Text; +using PetaPoco.Utilities; +using Shouldly; +using Xunit; + +namespace PetaPoco.Tests.Unit.Utilities +{ + public class PagingHelperTests + { + [Fact] + public void SplitSQL_GivenBigSqlStringWithOrWithoutOrderBy_ShouldPerformTheSameInBothCases() + { + var inputWithOrderBy = GenerateSql(200, 5, 100, true); + var inputWithoutOrderBy = inputWithOrderBy.Substring(0, inputWithOrderBy.IndexOf("ORDER BY")); + + var sw = Stopwatch.StartNew(); + + PagingHelper.Instance.SplitSQL(inputWithOrderBy, out SQLParts partsWithOrderBy); + sw.Stop(); + var elapsedMillSecondsWithOrderBy = sw.ElapsedMilliseconds; + + sw.Restart(); + + PagingHelper.Instance.SplitSQL(inputWithoutOrderBy, out SQLParts partsWithoutOrderBy); + sw.Stop(); + var elapsedMillSecondsWithoutOrderBy = sw.ElapsedMilliseconds; + + var actualTimeDiffInMilliSeconds = Math.Abs(elapsedMillSecondsWithOrderBy - elapsedMillSecondsWithoutOrderBy); + var maxExpectedTimeDiffInMilliSeconds = 200; + actualTimeDiffInMilliSeconds.ShouldBeLessThanOrEqualTo(maxExpectedTimeDiffInMilliSeconds, + $"{nameof(PagingHelper.SplitSQL)} degrades in performance. Expected {maxExpectedTimeDiffInMilliSeconds}ms or less, but was {actualTimeDiffInMilliSeconds}ms."); + } + + private static string GenerateSql(int numberOfColumns, int numberOfTables, int numberOfConditions, bool includeOrderBy) + { + var columns = GenerateSqlPart("column{0}", numberOfColumns, true); + var tables = GenerateSqlPart("table{0}", numberOfTables, true); + var conditions = GenerateSqlPart("AND column{0} = {0}", numberOfConditions, false); + + var builder = new StringBuilder(); + + if (!string.IsNullOrEmpty(columns)) builder.Append($"SELECT {columns}"); + if (!string.IsNullOrEmpty(tables)) builder.Append($"FROM {tables}"); + if (!string.IsNullOrEmpty(conditions)) builder.Append($"WHERE {conditions}"); + + if (includeOrderBy) + { + var sortColumns = GenerateSqlPart("column{0} ASC", 10, true); + builder.Append($"ORDER BY {sortColumns}"); + } + + return builder.ToString(); + } + + private static string GenerateSqlPart(string template, int count, bool subIndent) + { + var builder = new StringBuilder(); + + for (var i = 0; i < count; i++) + { + if (i > 0 && subIndent) builder.Append("\t"); + builder.AppendLine(string.Format(template, i + 1)); + } + + return builder.ToString(); + } + } +} diff --git a/PetaPoco/Utilities/PagingHelper.cs b/PetaPoco/Utilities/PagingHelper.cs index f90fb545..21cd78f6 100644 --- a/PetaPoco/Utilities/PagingHelper.cs +++ b/PetaPoco/Utilities/PagingHelper.cs @@ -108,11 +108,15 @@ public bool SplitSQL(string sql, out SQLParts parts) return false; // Look for the last "ORDER BY " clause not part of a ROW_NUMBER expression - var orderByMatch = RegexOrderBy.Match(sql); - if (orderByMatch.Success) + // when the query does not contain an "order by", it is very slow + if (SimpleRegexOrderBy.IsMatch(sql)) { - parts.SqlOrderBy = orderByMatch.Value; - parts.SqlCount = sql.Replace(orderByMatch.Value, string.Empty); + var orderByMatch = RegexOrderBy.Match(sql); + if (orderByMatch.Success) + { + parts.SqlOrderBy = orderByMatch.Value; + parts.SqlCount = sql.Replace(orderByMatch.Value, string.Empty); + } } // Save column list and replace with COUNT(*) From 7052c393b1b9ef47198536384b0d91244e50b779 Mon Sep 17 00:00:00 2001 From: Curlack Date: Sun, 22 Oct 2023 22:31:29 +0200 Subject: [PATCH 2/6] Modify Oracle setup scripts 1. Try to drop the user first so we can use the "user still connected" failure to bypass setup i.e. assume already setup correctly. This is to allow the developer to stay connected to the database (via SQLPlus or SQL Developer). Modify OracleTestProvider 1. If Oracle setup fails, propagate failure to all tests without retrying for every test in the batch. This makes all tests fail with the same exception. In the case the user is still connected, setup is bypassed. Fix Oracle build scripts 1. Stored procedures don't use any characters to denote a parameter, so they have to be fully qualified e.g. ProcName.paramName to differentiate them from column names (if the same name is used e.g. age). Fix breaking tests: 1. QueryTests.cs had couple of malformed sql statements after string concatenation (missing space). 2. Override all (Oracle)StoredProcTests.cs methods that require an additional RefCursor output parameter. 3. Override all (Oracle)QueryTests.cs paging methods that require '*' to be aliased. 4. OracleQueryTests.cs had a couple of statements ending in a semi-colon, which it didn't appreciate. 5. Fix top 1 query in "QueryMultiple ForSingleResultsSetWithMultiPoco ShouldReturnValidPocoCollection". Also provide version 12c and above syntax. 6. Skip MultiResultSetWithMultiPoco tests since Oracle also does not support it (as with MSAccess and Firebird). --- .../Databases/OracleTests/OracleQueryTests.cs | 133 +++++++++++- .../OracleTests/OracleStoredProcTests.cs | 194 ++++++++++++++++++ .../Databases/QueryTests.cs | 36 ++-- .../Providers/OracleTestProvider.cs | 35 +++- .../Scripts/OracleBuildDatabase.sql | 6 +- .../Scripts/OracleSetupDatabase.sql | 32 +-- 6 files changed, 386 insertions(+), 50 deletions(-) diff --git a/PetaPoco.Tests.Integration/Databases/OracleTests/OracleQueryTests.cs b/PetaPoco.Tests.Integration/Databases/OracleTests/OracleQueryTests.cs index 781bdd87..18c01da9 100644 --- a/PetaPoco.Tests.Integration/Databases/OracleTests/OracleQueryTests.cs +++ b/PetaPoco.Tests.Integration/Databases/OracleTests/OracleQueryTests.cs @@ -1,6 +1,7 @@ using System; using System.Collections.Generic; using System.Linq; +using System.Threading.Tasks; using PetaPoco.Core; using PetaPoco.Tests.Integration.Models; using PetaPoco.Tests.Integration.Providers; @@ -17,6 +18,107 @@ public OracleQueryTests() { } + [Fact] + public override async Task FetchAsyncWithPaging_ForDynamicTypeGivenSql_ShouldReturnValidDynamicTypeCollection() + { + AddOrders(12); + var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); + + var sql = new Sql( + $"SELECT t.* FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} t " + + $"WHERE t.{DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0", OrderStatus.Pending); + + var results = await DB.FetchAsync(2, 1, sql); + results.Count.ShouldBe(1); + } + + [Fact] + public override async Task FetchAsyncWithPaging_ForDynamicTypeGivenSqlStringAndParameters_ShouldReturnValidDynamicTypeCollection() + { + AddOrders(12); + var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); + var sql = $"SELECT t.* FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} t " + + $"WHERE t.{DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0"; + + var results = await DB.FetchAsync(2, 1, sql, OrderStatus.Pending); + results.Count.ShouldBe(1); + } + + [Fact] + public override void FetchWithPaging_ForDynamicTypeGivenSql_ShouldReturnValidDynamicTypeCollection() + { + AddOrders(12); + var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); + var sql = new Sql( + $"SELECT t.* FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} t " + + $"WHERE t.{DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0", OrderStatus.Pending); + + var results = DB.Fetch(2, 1, sql); + results.Count.ShouldBe(1); + } + + [Fact] + public override void FetchWithPaging_ForDynamicTypeGivenSqlStringAndParameters_ShouldReturnValidDynamicTypeCollection() + { + AddOrders(12); + var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); + var sql = $"SELECT t.* FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} t " + + $"WHERE t.{DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0"; + + var results = DB.Fetch(2, 1, sql, OrderStatus.Pending); + results.Count.ShouldBe(1); + } + + [Fact] + public override void SkipAndTake_ForDynamicTypeGivenSql_ShouldReturnValidDynamicTypeCollection() + { + AddOrders(12); + var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); + var sql = new Sql( + $"SELECT t.* FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} t " + + $"WHERE t.{DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0", OrderStatus.Pending); + + var results = DB.SkipTake(2, 1, sql); + results.Count.ShouldBe(1); + } + + [Fact] + public override void SkipAndTake_ForDynamicTypeGivenSqlStringAndParameters_ShouldReturnValidDynamicTypeCollection() + { + AddOrders(12); + var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); + var sql = $"SELECT t.* FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} t " + + $"WHERE t.{DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0"; + + var results = DB.SkipTake(2, 1, sql, OrderStatus.Pending); + results.Count.ShouldBe(1); + } + + [Fact] + public override async Task SkipAndTakeAsync_ForDynamicTypeGivenSql_ShouldReturnValidDynamicTypeCollection() + { + AddOrders(12); + var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); + var sql = new Sql( + $"SELECT t.* FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} t " + + $"WHERE t.{DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0", OrderStatus.Pending); + + var results = await DB.SkipTakeAsync(2, 1, sql); + results.Count.ShouldBe(1); + } + + [Fact] + public override async Task SkipAndTakeAsync_ForDynamicTypeGivenSqlStringAndParameters_ShouldReturnValidDynamicTypeCollection() + { + AddOrders(12); + var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); + var sql = $"SELECT t.* FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} t " + + $"WHERE t.{DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0"; + + var results = await DB.SkipTakeAsync(2, 1, sql, OrderStatus.Pending); + results.Count.ShouldBe(1); + } + [Fact] public override void QueryMultiple_ForSingleResultsSetWithSinglePoco_ShouldReturnValidPocoCollection() { @@ -26,8 +128,8 @@ public override void QueryMultiple_ForSingleResultsSetWithSinglePoco_ShouldRetur var pdName = pd.Columns.Values.First(c => c.PropertyInfo.Name == "Name").ColumnName; var sql = $@"SELECT * - FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} - WHERE {DB.Provider.EscapeSqlIdentifier(pdName)} LIKE @0 || '%';"; + FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} + WHERE {DB.Provider.EscapeSqlIdentifier(pdName)} LIKE @0 || '%'"; List result; using (var multi = DB.QueryMultiple(sql, "Peta")) @@ -54,11 +156,22 @@ public override void QueryMultiple_ForSingleResultsSetWithMultiPoco_ShouldReturn var pdName = pd.Columns.Values.First(c => c.PropertyInfo.Name == "Name").ColumnName; var odPersonId = od.Columns.Values.First(c => c.PropertyInfo.Name == "PersonId").ColumnName; - var sql = $@"SELECT * FROM {DB.Provider.EscapeTableName(od.TableInfo.TableName)} o - INNER JOIN {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} p ON p.{DB.Provider.EscapeSqlIdentifier(pdId)} = o.{DB.Provider.EscapeSqlIdentifier(odPersonId)} - WHERE p.{DB.Provider.EscapeSqlIdentifier(pdName)} = @0 - ORDER BY 1 DESC - LIMIT 1;"; + //Oracle 12c and above only + // var sql = $@"SELECT * + //FROM {DB.Provider.EscapeTableName(od.TableInfo.TableName)} o + // INNER JOIN {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} p ON p.{DB.Provider.EscapeSqlIdentifier(pdId)} = o.{DB.Provider.EscapeSqlIdentifier(odPersonId)} + //WHERE p.{DB.Provider.EscapeSqlIdentifier(pdName)} = @0 + //ORDER BY 1 DESC + //FETCH FIRST 1 ROWS ONLY"; + + var sql = $@"SELECT * + FROM (SELECT * + FROM {DB.Provider.EscapeTableName(od.TableInfo.TableName)} o + INNER JOIN {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} p + ON p.{DB.Provider.EscapeSqlIdentifier(pdId)} = o.{DB.Provider.EscapeSqlIdentifier(odPersonId)} + WHERE p.{DB.Provider.EscapeSqlIdentifier(pdName)} = @0 + ORDER BY 1 DESC) + WHERE ROWNUM <= 1"; List result; using (var multi = DB.QueryMultiple(sql, "Peta0")) @@ -86,7 +199,8 @@ public override void QueryMultiple_ForSingleResultsSetWithMultiPoco_ShouldReturn order.Person.Age.ShouldBe(18); } - [Fact] + // FIXME: Oracle.ManagedDataAccess.Client.OracleException : ORA-03048: SQL reserved word ';' is not syntactically valid following '...ORDER BY o.Id ASC' + [Fact(Skip = "Limited support for QueryMultiple by provider due to need for multiple statements in a single command.")] public override void QueryMultiple_ForMultiResultsSetWithSinglePoco_ShouldReturnValidPocoCollection() { AddOrders(1); @@ -120,7 +234,8 @@ public override void QueryMultiple_ForMultiResultsSetWithSinglePoco_ShouldReturn order.Person.Age.ShouldBe(18); } - [Fact] + // FIXME: Oracle.ManagedDataAccess.Client.OracleException : ORA-03048: SQL reserved word ';' is not syntactically valid following '...ORDER BY o.Id ASC' + [Fact(Skip = "Limited support for QueryMultiple by provider due to need for multiple statements in a single command.")] public override void QueryMultiple_ForMultiResultsSetWithMultiPoco_ShouldReturnValidPocoCollection() { AddOrders(12); diff --git a/PetaPoco.Tests.Integration/Databases/OracleTests/OracleStoredProcTests.cs b/PetaPoco.Tests.Integration/Databases/OracleTests/OracleStoredProcTests.cs index 2dcebf19..1cf298ef 100644 --- a/PetaPoco.Tests.Integration/Databases/OracleTests/OracleStoredProcTests.cs +++ b/PetaPoco.Tests.Integration/Databases/OracleTests/OracleStoredProcTests.cs @@ -1,6 +1,12 @@ using System; +using System.Collections.Generic; +using System.Data; +using System.Linq; +using System.Threading.Tasks; using Oracle.ManagedDataAccess.Client; +using PetaPoco.Tests.Integration.Models; using PetaPoco.Tests.Integration.Providers; +using Shouldly; using Xunit; namespace PetaPoco.Tests.Integration.Databases.Oracle @@ -14,5 +20,193 @@ public OracleStoredProcTests() : base(new OracleTestProvider()) { } + + private IDataParameter GetOutputParameter() => new OracleParameter("p_out_cursor", OracleDbType.RefCursor, ParameterDirection.Output); + + [Fact] + public override void QueryProc_NoParam_ShouldReturnAll() + { + var results = DB.QueryProc("SelectPeople", GetOutputParameter()).ToArray(); + results.Length.ShouldBe(6); + } + + [Fact] + public override void QueryProc_WithParam_ShouldReturnSome() + { + var results = DB.QueryProc("SelectPeopleWithParam", new { age = 20 }, GetOutputParameter()).ToArray(); + results.Length.ShouldBe(3); + } + + [Fact] + public override void QueryProc_WithDbParam_ShouldReturnSome() + { + var results = DB.QueryProc("SelectPeopleWithParam", GetDataParameter(), GetOutputParameter()).ToArray(); + results.Length.ShouldBe(3); + } + + [Fact] + public override void FetchProc_NoParam_ShouldReturnAll() + { + var results = DB.FetchProc("SelectPeople", GetOutputParameter()); + results.Count.ShouldBe(6); + } + + [Fact] + public override void FetchProc_WithParam_ShouldReturnSome() + { + var results = DB.FetchProc("SelectPeopleWithParam", new { age = 20 }, GetOutputParameter()); + results.Count.ShouldBe(3); + } + + [Fact] + public override void FetchProc_WithDbParam_ShouldReturnSome() + { + var results = DB.FetchProc("SelectPeopleWithParam", GetDataParameter(), GetOutputParameter()); + results.Count.ShouldBe(3); + } + + [Fact] + public override void ScalarProc_NoParam_ShouldReturnAll() + { + var count = DB.ExecuteScalarProc("CountPeople", GetOutputParameter()); + count.ShouldBe(6); + } + + [Fact] + public override void ScalarProc_WithParam_ShouldReturnSome() + { + var count = DB.ExecuteScalarProc("CountPeopleWithParam", new { age = 20 }, GetOutputParameter()); + count.ShouldBe(3); + } + + [Fact] + public override void ScalarProc_WithDbParam_ShouldReturnSome() + { + var count = DB.ExecuteScalarProc("CountPeopleWithParam", GetDataParameter(), GetOutputParameter()); + count.ShouldBe(3); + } + + [Fact] + public override void NonQueryProc_NoParam_ShouldUpdateAll() + { + DB.ExecuteNonQueryProc("UpdatePeople"); + DB.Query($"WHERE {DB.Provider.EscapeSqlIdentifier("FullName")}='Updated'").Count().ShouldBe(6); + } + + [Fact] + public override void NonQueryProc_WithParam_ShouldUpdateSome() + { + DB.ExecuteNonQueryProc("UpdatePeopleWithParam", new { age = 20 }); + DB.Query($"WHERE {DB.Provider.EscapeSqlIdentifier("FullName")}='Updated'").Count().ShouldBe(3); + } + + [Fact] + public override void NonQueryProc_WithDbParam_ShouldUpdateSome() + { + DB.ExecuteNonQueryProc("UpdatePeopleWithParam", GetDataParameter()); + DB.Query($"WHERE {DB.Provider.EscapeSqlIdentifier("FullName")}='Updated'").Count().ShouldBe(3); + } + + [Fact] + public override async Task QueryProcAsync_NoParam_ShouldReturnAll() + { + var results = new List(); + await DB.QueryProcAsync(p => results.Add(p), "SelectPeople", GetOutputParameter()); + results.Count.ShouldBe(6); + } + + [Fact] + public override async Task QueryProcAsync_WithParam_ShouldReturnSome() + { + var results = new List(); + await DB.QueryProcAsync(p => results.Add(p), "SelectPeopleWithParam", new { age = 20 }, GetOutputParameter()); + results.Count.ShouldBe(3); + } + + [Fact] + public override async Task QueryProcAsync_WithDbParam_ShouldReturnSome() + { + var results = new List(); + await DB.QueryProcAsync(p => results.Add(p), "SelectPeopleWithParam", GetDataParameter(), GetOutputParameter()); + results.Count.ShouldBe(3); + } + + [Fact] + public override async Task QueryProcAsyncReader_NoParam_ShouldReturnAll() + { + var results = new List(); + using (var reader = await DB.QueryProcAsync("SelectPeople", GetOutputParameter())) + { + while (await reader.ReadAsync()) + results.Add(reader.Poco); + } + results.Count.ShouldBe(6); + } + + [Fact] + public override async Task QueryProcAsyncReader_WithParam_ShouldReturnSome() + { + var results = new List(); + using (var reader = await DB.QueryProcAsync("SelectPeopleWithParam", new { age = 20 }, GetOutputParameter())) + { + while (await reader.ReadAsync()) + results.Add(reader.Poco); + } + results.Count.ShouldBe(3); + } + + [Fact] + public override async Task QueryProcAsyncReader_WithDbParam_ShouldReturnSome() + { + var results = new List(); + using (var reader = await DB.QueryProcAsync("SelectPeopleWithParam", GetDataParameter(), GetOutputParameter())) + { + while (await reader.ReadAsync()) + results.Add(reader.Poco); + } + results.Count.ShouldBe(3); + } + + [Fact] + public override async Task FetchProcAsync_NoParam_ShouldReturnAll() + { + var results = await DB.FetchProcAsync("SelectPeople", GetOutputParameter()); + results.Count.ShouldBe(6); + } + + [Fact] + public override async Task FetchProcAsync_WithParam_ShouldReturnSome() + { + var results = await DB.FetchProcAsync("SelectPeopleWithParam", new { age = 20 }, GetOutputParameter()); + results.Count.ShouldBe(3); + } + + [Fact] + public override async Task FetchProcAsync_WithDbParam_ShouldReturnSome() + { + var results = await DB.FetchProcAsync("SelectPeopleWithParam", GetDataParameter(), GetOutputParameter()); + results.Count.ShouldBe(3); + } + + [Fact] + public override async Task ScalarProcAsync_NoParam_ShouldReturnAll() + { + var count = await DB.ExecuteScalarProcAsync("CountPeople", GetOutputParameter()); + count.ShouldBe(6); + } + + [Fact] + public override async Task ScalarProcAsync_WithParam_ShouldReturnSome() + { + var count = await DB.ExecuteScalarProcAsync("CountPeopleWithParam", new { age = 20 }, GetOutputParameter()); + count.ShouldBe(3); + } + + [Fact] + public override async Task ScalarProcAsync_WithDbParam_ShouldReturnSome() + { + var count = await DB.ExecuteScalarProcAsync("CountPeopleWithParam", GetDataParameter(), GetOutputParameter()); + count.ShouldBe(3); + } } } diff --git a/PetaPoco.Tests.Integration/Databases/QueryTests.cs b/PetaPoco.Tests.Integration/Databases/QueryTests.cs index 203a51ec..ec04cc88 100644 --- a/PetaPoco.Tests.Integration/Databases/QueryTests.cs +++ b/PetaPoco.Tests.Integration/Databases/QueryTests.cs @@ -436,7 +436,7 @@ public virtual void Query_ForValueTypeGivenSqlStringAndParameters_ShouldReturnVa AddOrders(12); var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); var sql = $"SELECT {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "PoNumber").ColumnName)} " + - $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)}" + + $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} " + $"WHERE {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0"; var results = DB.Query(sql, OrderStatus.Pending).ToList(); @@ -451,7 +451,7 @@ public virtual void Query_ForValueTypeGivenSql_ShouldReturnValidValueTypeCollect var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); var sql = new Sql( $"SELECT {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "PoNumber").ColumnName)} " + - $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)}" + + $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} " + $"WHERE {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0", OrderStatus.Pending); var results = DB.Query(sql).ToList(); @@ -581,7 +581,7 @@ public virtual async Task QueryAsync_ForValueTypeGivenSqlStringAndParameters_Sho AddOrders(12); var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); var sql = $"SELECT {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "PoNumber").ColumnName)} " + - $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)}" + + $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} " + $"WHERE {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0"; var results = new List(); @@ -597,7 +597,7 @@ public virtual async Task QueryAsync_ForValueTypeGivenSql_ShouldReturnValidValue var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); var sql = new Sql( $"SELECT {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "PoNumber").ColumnName)} " + - $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)}" + + $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} " + $"WHERE {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0", OrderStatus.Pending); var results = new List(); @@ -746,7 +746,7 @@ public virtual async Task QueryAsyncReader_ForValueTypeGivenSqlStringAndParamete AddOrders(12); var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); var sql = $"SELECT {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "PoNumber").ColumnName)} " + - $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)}" + + $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} " + $"WHERE {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0"; var results = new List(); @@ -766,7 +766,7 @@ public virtual async Task QueryAsyncReader_ForValueTypeGivenSql_ShouldReturnVali var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); var sql = new Sql( $"SELECT {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "PoNumber").ColumnName)} " + - $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)}" + + $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} " + $"WHERE {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0", OrderStatus.Pending); var results = new List(); @@ -895,7 +895,7 @@ public virtual void Fetch_ForValueTypeGivenSqlStringAndParameters_ShouldReturnVa AddOrders(12); var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); var sql = $"SELECT {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "PoNumber").ColumnName)} " + - $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)}" + + $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} " + $"WHERE {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0"; var results = DB.Fetch(sql, OrderStatus.Pending); @@ -910,7 +910,7 @@ public virtual void Fetch_ForValueTypeGivenSql_ShouldReturnValidValueTypeCollect var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); var sql = new Sql( $"SELECT {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "PoNumber").ColumnName)} " + - $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)}" + + $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} " + $"WHERE {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0", OrderStatus.Pending); var results = DB.Fetch(sql); @@ -995,7 +995,7 @@ public virtual void SkipAndTake_ForValueTypeGivenSqlStringAndParameters_ShouldRe AddOrders(12); var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); var sql = $"SELECT {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "PoNumber").ColumnName)} " + - $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)}" + + $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} " + $"WHERE {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0"; var results = DB.SkipTake(2, 1, sql, OrderStatus.Pending); @@ -1010,7 +1010,7 @@ public virtual void SkipAndTake_ForValueTypeGivenSql_ShouldReturnValidValueTypeC var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); var sql = new Sql( $"SELECT {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "PoNumber").ColumnName)} " + - $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)}" + + $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} " + $"WHERE {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0", OrderStatus.Pending); var results = DB.SkipTake(2, 1, sql); @@ -1094,7 +1094,7 @@ public virtual void FetchWithPaging_ForValueTypeGivenSqlStringAndParameters_Shou AddOrders(12); var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); var sql = $"SELECT {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "PoNumber").ColumnName)} " + - $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)}" + + $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} " + $"WHERE {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0"; var results = DB.Fetch(2, 1, sql, OrderStatus.Pending); @@ -1109,7 +1109,7 @@ public virtual void FetchWithPaging_ForValueTypeGivenSql_ShouldReturnValidValueT var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); var sql = new Sql( $"SELECT {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "PoNumber").ColumnName)} " + - $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)}" + + $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} " + $"WHERE {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0", OrderStatus.Pending); var results = DB.Fetch(2, 1, sql); @@ -1232,7 +1232,7 @@ public virtual async Task FetchAsync_ForValueTypeGivenSqlStringAndParameters_Sho AddOrders(12); var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); var sql = $"SELECT {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "PoNumber").ColumnName)} " + - $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)}" + + $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} " + $"WHERE {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0"; var results = await DB.FetchAsync(sql, OrderStatus.Pending); @@ -1247,7 +1247,7 @@ public virtual async Task FetchAsync_ForValueTypeGivenSql_ShouldReturnValidValue var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); var sql = new Sql( $"SELECT {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "PoNumber").ColumnName)} " + - $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)}" + + $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} " + $"WHERE {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0", OrderStatus.Pending); var results = await DB.FetchAsync(sql); @@ -1332,7 +1332,7 @@ public virtual async Task FetchAsyncWithPaging_ForValueTypeGivenSqlStringAndPara AddOrders(12); var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); var sql = $"SELECT {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "PoNumber").ColumnName)} " + - $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)}" + + $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} " + $"WHERE {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0"; var results = await DB.FetchAsync(2, 1, sql, OrderStatus.Pending); @@ -1347,7 +1347,7 @@ public virtual async Task FetchAsyncWithPaging_ForValueTypeGivenSql_ShouldReturn var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); var sql = new Sql( $"SELECT {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "PoNumber").ColumnName)} " + - $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)}" + + $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} " + $"WHERE {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0", OrderStatus.Pending); var results = await DB.FetchAsync(2, 1, sql); @@ -1431,7 +1431,7 @@ public virtual async Task SkipAndTakeAsync_ForValueTypeGivenSqlStringAndParamete AddOrders(12); var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); var sql = $"SELECT {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "PoNumber").ColumnName)} " + - $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)}" + + $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} " + $"WHERE {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0"; var results = await DB.SkipTakeAsync(2, 1, sql, OrderStatus.Pending); @@ -1446,7 +1446,7 @@ public virtual async Task SkipAndTakeAsync_ForValueTypeGivenSql_ShouldReturnVali var pd = PocoData.ForType(typeof(Order), DB.DefaultMapper); var sql = new Sql( $"SELECT {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "PoNumber").ColumnName)} " + - $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)}" + + $"FROM {DB.Provider.EscapeTableName(pd.TableInfo.TableName)} " + $"WHERE {DB.Provider.EscapeSqlIdentifier(pd.Columns.Values.First(c => c.PropertyInfo.Name == "Status").ColumnName)} = @0", OrderStatus.Pending); var results = await DB.SkipTakeAsync(2, 1, sql); diff --git a/PetaPoco.Tests.Integration/Providers/OracleTestProvider.cs b/PetaPoco.Tests.Integration/Providers/OracleTestProvider.cs index 2ced4fdd..0a42aebb 100644 --- a/PetaPoco.Tests.Integration/Providers/OracleTestProvider.cs +++ b/PetaPoco.Tests.Integration/Providers/OracleTestProvider.cs @@ -1,5 +1,6 @@ using System; using System.Linq; +using Oracle.ManagedDataAccess.Client; /* * Converted build scripts from SqlServerBuildDatabase.sql using MSSQLTips.com for datatype conversions @@ -18,6 +19,7 @@ public class OracleTestProvider : TestProvider "PetaPoco.Tests.Integration.Scripts.OracleSetupDatabase.sql", "PetaPoco.Tests.Integration.Scripts.OracleBuildDatabase.sql" }; + private static volatile Exception _setupException; private static ExecutionPhase _phase = ExecutionPhase.Setup; private string _connectionName = "Oracle"; @@ -60,13 +62,38 @@ private void EnsureDatabaseSetup() //No need to run database setup scripts for every test if (_phase != ExecutionPhase.Setup) return; + //No need to fail multiple times during setup failure, just fail with the same exception for every test + if (_setupException != null) throw _setupException; + var previousName = _connectionName; - _connectionName = "Oracle_Builder"; - _ = base.Execute(); + try + { + _connectionName = "Oracle_Builder"; + + //Double check exception in case another thread updated it + if (_setupException != null) throw _setupException; - _connectionName = previousName; - _phase = ExecutionPhase.Build; + _ = base.Execute(); + _phase = ExecutionPhase.Build; + } + catch (Exception ex) + { + if (ex is OracleException oex && oex.Number == 1940) + { + //If we cannot drop a user who is currently connected, assume setup to be completed successfully. + //This code was added to improve the development experience, while investigating failing tests. + _phase = ExecutionPhase.Build; + return; + } + + if (_setupException is null) _setupException = ex; + throw; + } + finally + { + _connectionName = previousName; + } } private string StripLineComments(string script) diff --git a/PetaPoco.Tests.Integration/Scripts/OracleBuildDatabase.sql b/PetaPoco.Tests.Integration/Scripts/OracleBuildDatabase.sql index ccf3ffa8..673dfe36 100644 --- a/PetaPoco.Tests.Integration/Scripts/OracleBuildDatabase.sql +++ b/PetaPoco.Tests.Integration/Scripts/OracleBuildDatabase.sql @@ -153,7 +153,7 @@ CREATE PROCEDURE SelectPeopleWithParam p_out_cursor OUT SYS_REFCURSOR) AS BEGIN OPEN p_out_cursor FOR - SELECT * FROM People WHERE Age > age; + SELECT * FROM People WHERE Age > SelectPeopleWithParam.age; END; / @@ -171,7 +171,7 @@ CREATE PROCEDURE CountPeopleWithParam p_out_cursor OUT SYS_REFCURSOR) AS BEGIN OPEN p_out_cursor FOR - SELECT COUNT(*) FROM People WHERE Age > age; + SELECT COUNT(*) FROM People WHERE Age > CountPeopleWithParam.age; END; / @@ -184,6 +184,6 @@ END; CREATE PROCEDURE UpdatePeopleWithParam (age IN NUMERIC DEFAULT 0) AS BEGIN - UPDATE People SET FullName = 'Updated' WHERE Age > age; + UPDATE People SET FullName = 'Updated' WHERE Age > UpdatePeopleWithParam.age; END; / diff --git a/PetaPoco.Tests.Integration/Scripts/OracleSetupDatabase.sql b/PetaPoco.Tests.Integration/Scripts/OracleSetupDatabase.sql index 5633ad68..05f1c0f8 100644 --- a/PetaPoco.Tests.Integration/Scripts/OracleSetupDatabase.sql +++ b/PetaPoco.Tests.Integration/Scripts/OracleSetupDatabase.sql @@ -1,45 +1,45 @@ --- Drop DATA_TS tablespace COMPLETELY (if it exists) +-- Drop PETAPOCO user COMPLETELY (if it exists) DECLARE found number := 0; BEGIN SELECT COUNT(*) INTO found - FROM dba_data_files - WHERE tablespace_name = 'DATA_TS'; + FROM all_users + WHERE username = 'PETAPOCO'; IF found <> 0 THEN BEGIN - EXECUTE IMMEDIATE 'DROP TABLESPACE data_ts ' || - 'INCLUDING CONTENTS AND DATAFILES ' || - 'CASCADE CONSTRAINTS'; + EXECUTE IMMEDIATE 'DROP USER petapoco CASCADE'; END; END IF; END; / --- Create a fresh tablespace -CREATE TABLESPACE data_ts -DATAFILE '/opt/oracle/oradata/FREE/FREEPDB1/data01.dbf' -SIZE 200M AUTOEXTEND ON NEXT 10M MAXSIZE UNLIMITED; +-- Create fresh user +CREATE USER petapoco IDENTIFIED BY petapoco; / --- Drop PETAPOCO user COMPLETELY (if it exists) +-- Drop DATA_TS tablespace COMPLETELY (if it exists) DECLARE found number := 0; BEGIN SELECT COUNT(*) INTO found - FROM all_users - WHERE username = 'PETAPOCO'; + FROM dba_data_files + WHERE tablespace_name = 'DATA_TS'; IF found <> 0 THEN BEGIN - EXECUTE IMMEDIATE 'DROP USER petapoco CASCADE'; + EXECUTE IMMEDIATE 'DROP TABLESPACE data_ts ' || + 'INCLUDING CONTENTS AND DATAFILES ' || + 'CASCADE CONSTRAINTS'; END; END IF; END; / --- Create fresh user -CREATE USER petapoco IDENTIFIED BY petapoco; +-- Create a fresh tablespace +CREATE TABLESPACE data_ts +DATAFILE '/opt/oracle/oradata/FREE/FREEPDB1/data01.dbf' +SIZE 200M AUTOEXTEND ON NEXT 10M MAXSIZE UNLIMITED; / -- Convenience procedure to drop certain database objects without having to deal with exceptions From cddc7b9cb9f304fd51fd743b2249a8463bab55e6 Mon Sep 17 00:00:00 2001 From: Curlack Date: Sun, 22 Oct 2023 22:45:43 +0200 Subject: [PATCH 3/6] Revert command paramater name changes for StoredProcedure type commands. Oracle doesn't utilize the parameter prefix in this case. Fixes #691 Give OracleDatabaseProvider its own implementation of BuildPageQuery and use "Select null from dual" instead of "Select null" when ORDER BY clause is absent. Alo include version 12c and above syntax in a comment for future reference. --- PetaPoco/Database.cs | 4 +- PetaPoco/Providers/OracleDatabaseProvider.cs | 46 ++++++++++++++++++-- 2 files changed, 46 insertions(+), 4 deletions(-) diff --git a/PetaPoco/Database.cs b/PetaPoco/Database.cs index b128720e..be9d3bd2 100644 --- a/PetaPoco/Database.cs +++ b/PetaPoco/Database.cs @@ -3365,7 +3365,9 @@ public string FormatCommand(string sql, object[] args) sb.Append("\n"); for (int i = 0; i < args.Length; i++) { - sb.AppendFormat("\t -> {0}{1} [{2}] = \"{3}\"\n", _paramPrefix, i, args[i].GetType().Name, args[i]); + var arg = args[i]; + var argTypeName = arg == null ? "Unknown Type" : args.GetType().Name; + sb.AppendFormat("\t -> {0}{1} [{2}] = \"{3}\"\n", _paramPrefix, i, argTypeName, arg); } sb.Remove(sb.Length - 1, 1); diff --git a/PetaPoco/Providers/OracleDatabaseProvider.cs b/PetaPoco/Providers/OracleDatabaseProvider.cs index f4769750..5ff90094 100644 --- a/PetaPoco/Providers/OracleDatabaseProvider.cs +++ b/PetaPoco/Providers/OracleDatabaseProvider.cs @@ -3,8 +3,8 @@ using System.Data.Common; using System.Text.RegularExpressions; using PetaPoco.Core; -using PetaPoco.Internal; using PetaPoco.Utilities; +using System.Linq; #if ASYNC using System.Threading; using System.Threading.Tasks; @@ -35,6 +35,23 @@ public override void PreExecute(IDbCommand cmd) { cmd.GetType().GetProperty("BindByName")?.SetValue(cmd, true, null); cmd.GetType().GetProperty("InitialLONGFetchSize")?.SetValue(cmd, -1, null); + + if (cmd.CommandType == CommandType.StoredProcedure) + { + //Oracle stored procedure parameter names do not use the parameter prefix + //They also need to match the db exactly, so it's up to the consumer to specify the correct name + //In Database.AddParameter, the parameter prefix is prepended and it didn't seem right to cater for this case there... + //...so we need to undo those changes here + var paramPrefix = GetParameterPrefix(null); + var enumerator = cmd.Parameters.GetEnumerator(); + while (enumerator.MoveNext()) + { + var parameter = (IDataParameter)enumerator.Current; + + if (parameter.ParameterName.StartsWith(paramPrefix, StringComparison.OrdinalIgnoreCase)) + parameter.ParameterName = parameter.ParameterName.Substring(paramPrefix.Length); + } + } } /// @@ -44,8 +61,31 @@ public override string BuildPageQuery(long skip, long take, SQLParts parts, ref if (parts.SqlSelectRemoved.StartsWith("*")) throw new Exception("Query must alias '*' when performing a paged query.\neg. select t.* from table t order by t.id"); - // Same deal as SQL Server - return Singleton.Instance.BuildPageQuery(skip, take, parts, ref args); + //Supported by Oracle v12c and above only + //var sql = $"{parts.Sql}\nOFFSET @{args.Length} ROWS FETCH NEXT @{args.Length + 1} ROWS ONLY"; + //args = args.Concat(new object[] { skip, take }).ToArray(); + //return sql; + + //Similar to SqlServerProvider with the exception of SELECT NULL FROM DUAL vs SELECT NULL + var helper = (PagingHelper)PagingUtility; + // when the query does not contain an "order by", it is very slow + if (helper.SimpleRegexOrderBy.IsMatch(parts.SqlSelectRemoved)) + { + var m = helper.SimpleRegexOrderBy.Match(parts.SqlSelectRemoved); + if (m.Success) + { + var g = m.Groups[0]; + parts.SqlSelectRemoved = parts.SqlSelectRemoved.Substring(0, g.Index); + } + } + + if (helper.RegexDistinct.IsMatch(parts.SqlSelectRemoved)) + parts.SqlSelectRemoved = "peta_inner.* FROM (SELECT " + parts.SqlSelectRemoved + ") peta_inner"; + + var sqlPage = + $"SELECT * FROM (SELECT ROW_NUMBER() OVER ({parts.SqlOrderBy ?? "ORDER BY (SELECT NULL FROM DUAL)"}) peta_rn, {parts.SqlSelectRemoved}) peta_paged WHERE peta_rn > @{args.Length} AND peta_rn <= @{args.Length + 1}"; + args = args.Concat(new object[] { skip, skip + take }).ToArray(); + return sqlPage; } /// From 8d5b363f169fb0cb4921ea2c66436e358f966863 Mon Sep 17 00:00:00 2001 From: Curlack Date: Mon, 23 Oct 2023 21:00:35 +0200 Subject: [PATCH 4/6] Update PetaPoco.Tests.Unit/Utilities/PagingHelperTests.cs Co-authored-by: Stelio Kontos <37424493+Ste1io@users.noreply.github.com> --- PetaPoco.Tests.Unit/Utilities/PagingHelperTests.cs | 12 +++++------- 1 file changed, 5 insertions(+), 7 deletions(-) diff --git a/PetaPoco.Tests.Unit/Utilities/PagingHelperTests.cs b/PetaPoco.Tests.Unit/Utilities/PagingHelperTests.cs index 9a792ab5..5202b645 100644 --- a/PetaPoco.Tests.Unit/Utilities/PagingHelperTests.cs +++ b/PetaPoco.Tests.Unit/Utilities/PagingHelperTests.cs @@ -19,20 +19,18 @@ public void SplitSQL_GivenBigSqlStringWithOrWithoutOrderBy_ShouldPerformTheSameI PagingHelper.Instance.SplitSQL(inputWithOrderBy, out SQLParts partsWithOrderBy); sw.Stop(); - var elapsedMillSecondsWithOrderBy = sw.ElapsedMilliseconds; + var elapsedWithOrderBy = sw.Elapsed; sw.Restart(); PagingHelper.Instance.SplitSQL(inputWithoutOrderBy, out SQLParts partsWithoutOrderBy); sw.Stop(); - var elapsedMillSecondsWithoutOrderBy = sw.ElapsedMilliseconds; + var elapsedWithoutOrderBy = sw.Elapsed; - var actualTimeDiffInMilliSeconds = Math.Abs(elapsedMillSecondsWithOrderBy - elapsedMillSecondsWithoutOrderBy); - var maxExpectedTimeDiffInMilliSeconds = 200; - actualTimeDiffInMilliSeconds.ShouldBeLessThanOrEqualTo(maxExpectedTimeDiffInMilliSeconds, - $"{nameof(PagingHelper.SplitSQL)} degrades in performance. Expected {maxExpectedTimeDiffInMilliSeconds}ms or less, but was {actualTimeDiffInMilliSeconds}ms."); + var tolerance = TimeSpan.FromMilliseconds(200); + elapsedWithOrderBy.ShouldBe(elapsedWithoutOrderBy, tolerance, () => $"{nameof(PagingHelper.SplitSQL)} degrades in performance. " + + $"Expected the difference to be {tolerance.TotalMilliseconds}ms or less, but was {Math.Abs((elapsedWithOrderBy - elapsedWithoutOrderBy).TotalMilliseconds)}ms."); } - private static string GenerateSql(int numberOfColumns, int numberOfTables, int numberOfConditions, bool includeOrderBy) { var columns = GenerateSqlPart("column{0}", numberOfColumns, true); From 0dfc8e8b447a2d58a275ce1a4eeaafd90ffca05c Mon Sep 17 00:00:00 2001 From: Curlack Date: Mon, 23 Oct 2023 23:02:21 +0200 Subject: [PATCH 5/6] Cater for optional parameter prefix in Database.AddParameter instead of "undoing" the pramPrefix modification in OracleDatabaseProvider. --- PetaPoco/Database.cs | 12 ++++++++++-- PetaPoco/Providers/OracleDatabaseProvider.cs | 17 ----------------- 2 files changed, 10 insertions(+), 19 deletions(-) diff --git a/PetaPoco/Database.cs b/PetaPoco/Database.cs index be9d3bd2..e8a8ab53 100644 --- a/PetaPoco/Database.cs +++ b/PetaPoco/Database.cs @@ -3161,14 +3161,22 @@ private void AddParameter(IDbCommand cmd, object value, PocoColumn pc) if (cmd.CommandType == CommandType.Text) idbParam.ParameterName = cmd.Parameters.Count.EnsureParamPrefix(_paramPrefix); else if (idbParam.ParameterName?.StartsWith(_paramPrefix) != true) - idbParam.ParameterName = idbParam.ParameterName.EnsureParamPrefix(_paramPrefix); + { + // only add param prefix if it's not an Oracle stored procedures + if (!(cmd.CommandType == CommandType.StoredProcedure && _provider is Providers.OracleDatabaseProvider)) + idbParam.ParameterName = idbParam.ParameterName.EnsureParamPrefix(_paramPrefix); + } cmd.Parameters.Add(idbParam); } else { var p = cmd.CreateParameter(); - p.ParameterName = cmd.Parameters.Count.EnsureParamPrefix(_paramPrefix); + + // only add param prefix if it's not an Oracle stored procedures + if (!(cmd.CommandType == CommandType.StoredProcedure && _provider is Providers.OracleDatabaseProvider)) + p.ParameterName = cmd.Parameters.Count.EnsureParamPrefix(_paramPrefix); + SetParameterProperties(p, value, pc); cmd.Parameters.Add(p); diff --git a/PetaPoco/Providers/OracleDatabaseProvider.cs b/PetaPoco/Providers/OracleDatabaseProvider.cs index 5ff90094..7c16feac 100644 --- a/PetaPoco/Providers/OracleDatabaseProvider.cs +++ b/PetaPoco/Providers/OracleDatabaseProvider.cs @@ -35,23 +35,6 @@ public override void PreExecute(IDbCommand cmd) { cmd.GetType().GetProperty("BindByName")?.SetValue(cmd, true, null); cmd.GetType().GetProperty("InitialLONGFetchSize")?.SetValue(cmd, -1, null); - - if (cmd.CommandType == CommandType.StoredProcedure) - { - //Oracle stored procedure parameter names do not use the parameter prefix - //They also need to match the db exactly, so it's up to the consumer to specify the correct name - //In Database.AddParameter, the parameter prefix is prepended and it didn't seem right to cater for this case there... - //...so we need to undo those changes here - var paramPrefix = GetParameterPrefix(null); - var enumerator = cmd.Parameters.GetEnumerator(); - while (enumerator.MoveNext()) - { - var parameter = (IDataParameter)enumerator.Current; - - if (parameter.ParameterName.StartsWith(paramPrefix, StringComparison.OrdinalIgnoreCase)) - parameter.ParameterName = parameter.ParameterName.Substring(paramPrefix.Length); - } - } } /// From b36c22ba289a1a763e771d7045b0a899bd14df9f Mon Sep 17 00:00:00 2001 From: Curlack Date: Mon, 23 Oct 2023 23:13:36 +0200 Subject: [PATCH 6/6] Update PetaPoco/Database.cs Co-authored-by: Stelio Kontos <37424493+Ste1io@users.noreply.github.com> --- PetaPoco/Database.cs | 4 +--- 1 file changed, 1 insertion(+), 3 deletions(-) diff --git a/PetaPoco/Database.cs b/PetaPoco/Database.cs index e8a8ab53..f2a02776 100644 --- a/PetaPoco/Database.cs +++ b/PetaPoco/Database.cs @@ -3373,9 +3373,7 @@ public string FormatCommand(string sql, object[] args) sb.Append("\n"); for (int i = 0; i < args.Length; i++) { - var arg = args[i]; - var argTypeName = arg == null ? "Unknown Type" : args.GetType().Name; - sb.AppendFormat("\t -> {0}{1} [{2}] = \"{3}\"\n", _paramPrefix, i, argTypeName, arg); + sb.AppendFormat("\t -> {0}{1} [{2}] = \"{3}\"\n", _paramPrefix, i, args[i]?.GetType().Name ?? "Unknown Type", args[i]); } sb.Remove(sb.Length - 1, 1);