diff --git a/PetaPoco.Tests.Integration/Databases/OracleTests/OracleDatabaseTests.cs b/PetaPoco.Tests.Integration/Databases/OracleTests/OracleDatabaseTests.cs new file mode 100644 index 00000000..a9ea2f0f --- /dev/null +++ b/PetaPoco.Tests.Integration/Databases/OracleTests/OracleDatabaseTests.cs @@ -0,0 +1,14 @@ +using PetaPoco.Tests.Integration.Providers; +using Xunit; + +namespace PetaPoco.Tests.Integration.Databases.Oracle +{ + [Collection("Oracle")] + public class OracleDatabaseTests : DatabaseTests + { + public OracleDatabaseTests() + : base(new OracleTestProvider()) + { + } + } +} diff --git a/PetaPoco.Tests.Integration/PetaPoco.Tests.Integration.csproj b/PetaPoco.Tests.Integration/PetaPoco.Tests.Integration.csproj index 946558c6..4dec1f97 100644 --- a/PetaPoco.Tests.Integration/PetaPoco.Tests.Integration.csproj +++ b/PetaPoco.Tests.Integration/PetaPoco.Tests.Integration.csproj @@ -1,4 +1,4 @@ - + net472;netcoreapp3.1 @@ -22,6 +22,8 @@ + + @@ -33,6 +35,8 @@ + + @@ -70,6 +74,8 @@ + + diff --git a/PetaPoco.Tests.Integration/Providers/MSAccessTestProvider.cs b/PetaPoco.Tests.Integration/Providers/MSAccessTestProvider.cs index ac2a5a32..faa57ff8 100644 --- a/PetaPoco.Tests.Integration/Providers/MSAccessTestProvider.cs +++ b/PetaPoco.Tests.Integration/Providers/MSAccessTestProvider.cs @@ -8,6 +8,9 @@ namespace PetaPoco.Tests.Integration.Providers { public class MSAccessTestProvider : TestProvider { + private static readonly string[] _splitSemiColon = new[] { ";" }; + private static readonly string[] _splitNewLine = new[] { Environment.NewLine }; + protected override string ConnectionName => "MSAccess"; protected override string ScriptResourceName => "PetaPoco.Tests.Integration.Scripts.MSAccessBuildDatabase.sql"; @@ -33,26 +36,34 @@ public override IDatabase Execute() public override void ExecuteBuildScript(IDatabase database, string script) { - script.Split(new[] { ';' }, StringSplitOptions.RemoveEmptyEntries).Select(s => s.Trim()).ToList().ForEach(s => - { - if (string.IsNullOrEmpty(s) || s.StartsWith("--")) - return; - - if (s.StartsWith("DROP")) + script.Split(_splitSemiColon, StringSplitOptions.RemoveEmptyEntries) + .Select(s => StripLineComments(s).Trim()).ToList() + .ForEach(s => { - try - { - base.ExecuteBuildScript(database, s); - } - catch + if (string.IsNullOrEmpty(s)) return; + + if (s.StartsWith("DROP")) { + try + { + base.ExecuteBuildScript(database, s); + } + catch + { + } + + return; } - return; - } + base.ExecuteBuildScript(database, s); + }); + } - base.ExecuteBuildScript(database, s); - }); + private string StripLineComments(string script) + { + var parts = script.Split(_splitNewLine, StringSplitOptions.RemoveEmptyEntries) + .Where(s => !s.Trim().StartsWith("--")); + return string.Join(_splitNewLine[0], parts); } } } diff --git a/PetaPoco.Tests.Integration/Providers/OracleTestProvider.cs b/PetaPoco.Tests.Integration/Providers/OracleTestProvider.cs new file mode 100644 index 00000000..2ced4fdd --- /dev/null +++ b/PetaPoco.Tests.Integration/Providers/OracleTestProvider.cs @@ -0,0 +1,79 @@ +using System; +using System.Linq; + +/* + * Converted build scripts from SqlServerBuildDatabase.sql using MSSQLTips.com for datatype conversions + * Link: https://www.mssqltips.com/sqlservertip/2944/comparing-sql-server-and-oracle-datatypes + */ + +namespace PetaPoco.Tests.Integration.Providers +{ + public class OracleTestProvider : TestProvider + { + private static readonly string[] _splitSemiColon = new[] { ";" }; + private static readonly string[] _splitNewLine = new[] { Environment.NewLine }; + private static readonly string[] _splitSlash = new[] { Environment.NewLine + "/" }; + private static readonly string[] _resources = new[] + { + "PetaPoco.Tests.Integration.Scripts.OracleSetupDatabase.sql", + "PetaPoco.Tests.Integration.Scripts.OracleBuildDatabase.sql" + }; + private static ExecutionPhase _phase = ExecutionPhase.Setup; + + private string _connectionName = "Oracle"; + protected override string ConnectionName => _connectionName; + + protected override string ScriptResourceName => _resources[(int)_phase]; + + public override IDatabase Execute() + { + EnsureDatabaseSetup(); + return base.Execute(); + } + + public override void ExecuteBuildScript(IDatabase database, string script) + { + //The script file can contain multiple script blocks, separated by a line containing a single forward slash ("\r\n/"). + //Script blocks end with "END;" and can execute as a whole. + //Statements are separated by a semi colon and have to be executed separately. + //This "one statement at a time" limitation is due to the database provider. + + script.Split(_splitSlash, StringSplitOptions.RemoveEmptyEntries) + .Select(s => StripLineComments(s).Trim()).ToList() + .ForEach(s => + { + if (string.IsNullOrEmpty(s)) return; + + if (s.EndsWith("END;", StringComparison.OrdinalIgnoreCase)) + { + base.ExecuteBuildScript(database, s); + return; + } + + s.Split(_splitSemiColon, StringSplitOptions.RemoveEmptyEntries).ToList() + .ForEach(x => base.ExecuteBuildScript(database, x)); + }); + } + + private void EnsureDatabaseSetup() + { + //No need to run database setup scripts for every test + if (_phase != ExecutionPhase.Setup) return; + + var previousName = _connectionName; + _connectionName = "Oracle_Builder"; + + _ = base.Execute(); + + _connectionName = previousName; + _phase = ExecutionPhase.Build; + } + + private string StripLineComments(string script) + { + var parts = script.Split(_splitNewLine, StringSplitOptions.RemoveEmptyEntries) + .Where(s => !s.Trim().StartsWith("--")); + return string.Join(_splitNewLine[0], parts); + } + } +} diff --git a/PetaPoco.Tests.Integration/Providers/TestProvider.cs b/PetaPoco.Tests.Integration/Providers/TestProvider.cs index 0c81eeb3..6642a453 100644 --- a/PetaPoco.Tests.Integration/Providers/TestProvider.cs +++ b/PetaPoco.Tests.Integration/Providers/TestProvider.cs @@ -62,5 +62,11 @@ protected string GetProviderName(string connectionName) return ConfigurationManager.ConnectionStrings[connectionName].ProviderName; #endif } + + public enum ExecutionPhase + { + Setup = 0, + Build = 1 + } } } diff --git a/PetaPoco.Tests.Integration/Scripts/OracleBuildDatabase.sql b/PetaPoco.Tests.Integration/Scripts/OracleBuildDatabase.sql new file mode 100644 index 00000000..71e282a2 --- /dev/null +++ b/PetaPoco.Tests.Integration/Scripts/OracleBuildDatabase.sql @@ -0,0 +1,189 @@ +CALL SYS.DROP_IF_EXISTS('TABLE', 'petapoco.OrderLines'); +/ +CALL SYS.DROP_IF_EXISTS('TABLE', 'petapoco.Orders'); +/ +CALL SYS.DROP_IF_EXISTS('TABLE', 'petapoco.People'); +/ +CALL SYS.DROP_IF_EXISTS('TABLE', 'petapoco.SpecificOrderLines'); +/ +CALL SYS.DROP_IF_EXISTS('TABLE', 'petapoco.SpecificOrders'); +/ +CALL SYS.DROP_IF_EXISTS('TABLE', 'petapoco.SpecificPeople'); +/ +CALL SYS.DROP_IF_EXISTS('TABLE', 'petapoco.TransactionLogs'); +/ +CALL SYS.DROP_IF_EXISTS('TABLE', 'petapoco.Note'); +/ + +CREATE TABLE People ( + Id RAW(16) NOT NULL, + FullName VARCHAR2(255), + Age NUMBER(19) NOT NULL, + Height NUMBER(10) NOT NULL, + Dob TIMESTAMP NULL, + PRIMARY KEY(Id) +); + +CREATE TABLE Orders ( + Id NUMBER(10) GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + PersonId RAW(16), + PoNumber VARCHAR2(15) NOT NULL, + OrderStatus NUMBER(10) NOT NULL, + CreatedOn TIMESTAMP NOT NULL, + CreatedBy VARCHAR2(255) NOT NULL, + PRIMARY KEY(Id), + FOREIGN KEY (PersonId) REFERENCES People(Id) +); + +CREATE TABLE OrderLines ( + Id NUMBER(10) GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + OrderId NUMBER(10) NOT NULL, + Qty NUMBER(5) NOT NULL, + Status NUMBER(3) NOT NULL, + SellPrice NUMERIC(10, 4) NOT NULL, + PRIMARY KEY(Id), + FOREIGN KEY (OrderId) REFERENCES Orders(Id) +); + +CREATE TABLE SpecificPeople ( + Id RAW(16) NOT NULL, + FullName VARCHAR2(255), + Age NUMBER(19) NOT NULL, + Height NUMBER(10) NOT NULL, + Dob TIMESTAMP NULL, + PRIMARY KEY(Id) +); + +CREATE TABLE SpecificOrders ( + Id NUMBER(10) GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + PersonId RAW(16), + PoNumber VARCHAR2(15) NOT NULL, + OrderStatus NUMBER(10) NOT NULL, + CreatedOn TIMESTAMP NOT NULL, + CreatedBy VARCHAR2(255) NOT NULL, + PRIMARY KEY(Id), + FOREIGN KEY(PersonId) REFERENCES SpecificPeople(Id) +); + +CREATE TABLE SpecificOrderLines ( + Id NUMBER(10) GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + OrderId NUMBER(10) NOT NULL, + Qty NUMBER(5) NOT NULL, + Status NUMBER(3) NOT NULL, + SellPrice NUMBER(10, 4) NOT NULL, + PRIMARY KEY(Id), + FOREIGN KEY(OrderId) REFERENCES SpecificOrders(Id) +); + +CREATE TABLE TransactionLogs ( + Description LONG, + CreatedOn TIMESTAMP NOT NULL +); + +CREATE TABLE Note ( + Id NUMBER(10) GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + Text LONG NOT NULL, + CreatedOn TIMESTAMP NOT NULL +); +/ + +-- Investigation Tables +CALL SYS.DROP_IF_EXISTS('TABLE', 'petapoco.BugInvestigation_10R9LZYK'); +/ +CALL SYS.DROP_IF_EXISTS('TABLE', 'petapoco.BugInvestigation_3F489XV0'); +/ +CALL SYS.DROP_IF_EXISTS('TABLE', 'petapoco.BugInvestigation_64O6LT8U'); +/ +CALL SYS.DROP_IF_EXISTS('TABLE', 'petapoco.BugInvestigation_5TN5C4U4'); +/ + +CREATE TABLE BugInvestigation_10R9LZYK ( + Id NUMBER(10) GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + TestColumn1 LONG RAW, + PRIMARY KEY(Id) +); +/ + +CREATE TABLE BugInvestigation_3F489XV0 ( + Id NUMBER(10) GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + TC1 NUMBER(10) NOT NULL, + TC2 NUMBER(10) NOT NULL, + TC3 NUMBER(10) NOT NULL, + TC4 NUMBER(10) NOT NULL, + PRIMARY KEY(Id) +); +/ + +CREATE TABLE BugInvestigation_64O6LT8U ( + ColumnA VARCHAR2(20), + Column2 VARCHAR2(20) +); +/ + +CREATE TABLE BugInvestigation_5TN5C4U4 ( + ColumnA VARCHAR2(20), + Column2 VARCHAR2(20) +); +/ + +-- Stored procedures +CALL SYS.DROP_IF_EXISTS('PROCEDURE', 'petapoco.SelectPeople'); +/ +CALL SYS.DROP_IF_EXISTS('PROCEDURE', 'petapoco.SelectPeopleWithParam'); +/ +CALL SYS.DROP_IF_EXISTS('PROCEDURE', 'petapoco.CountPeople'); +/ +CALL SYS.DROP_IF_EXISTS('PROCEDURE', 'petapoco.CountPeopleWithParam'); +/ +CALL SYS.DROP_IF_EXISTS('PROCEDURE', 'petapoco.UpdatePeople'); +/ +CALL SYS.DROP_IF_EXISTS('PROCEDURE', 'petapoco.UpdatePeopleWithParam'); +/ + +CREATE PROCEDURE SelectPeople + (p_out_cursor OUT SYS_REFCURSOR) AS +BEGIN + OPEN p_out_cursor FOR + SELECT * FROM People; +END; +/ + +CREATE PROCEDURE SelectPeopleWithParam + (age IN NUMERIC DEFAULT 0, + p_out_cursor OUT SYS_REFCURSOR) AS +BEGIN + OPEN p_out_cursor FOR + SELECT * FROM People WHERE Age > age; +END; +/ + +CREATE PROCEDURE CountPeople + (p_out_cursor OUT SYS_REFCURSOR) +AS +BEGIN + OPEN p_out_cursor FOR + SELECT COUNT(*) FROM People; +END; +/ + +CREATE PROCEDURE CountPeopleWithParam + (age IN NUMERIC DEFAULT 0, + p_out_cursor OUT SYS_REFCURSOR) AS +BEGIN + OPEN p_out_cursor FOR + SELECT COUNT(*) FROM People WHERE Age > age; +END; +/ + +CREATE PROCEDURE UpdatePeople AS +BEGIN + UPDATE People SET FullName = 'Updated'; +END; +/ + +CREATE PROCEDURE UpdatePeopleWithParam + (age IN NUMERIC DEFAULT 0) AS +BEGIN + UPDATE People SET FullName = 'Updated' WHERE Age > age; +END; +/ diff --git a/PetaPoco.Tests.Integration/Scripts/OracleSetupDatabase.sql b/PetaPoco.Tests.Integration/Scripts/OracleSetupDatabase.sql new file mode 100644 index 00000000..5633ad68 --- /dev/null +++ b/PetaPoco.Tests.Integration/Scripts/OracleSetupDatabase.sql @@ -0,0 +1,86 @@ +-- Drop DATA_TS tablespace COMPLETELY (if it exists) +DECLARE + found number := 0; +BEGIN + SELECT COUNT(*) INTO found + FROM dba_data_files + WHERE tablespace_name = 'DATA_TS'; + + IF found <> 0 THEN + BEGIN + EXECUTE IMMEDIATE 'DROP TABLESPACE data_ts ' || + 'INCLUDING CONTENTS AND DATAFILES ' || + 'CASCADE CONSTRAINTS'; + 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; +/ + +-- Drop PETAPOCO user COMPLETELY (if it exists) +DECLARE + found number := 0; +BEGIN + SELECT COUNT(*) INTO found + FROM all_users + WHERE username = 'PETAPOCO'; + + IF found <> 0 THEN + BEGIN + EXECUTE IMMEDIATE 'DROP USER petapoco CASCADE'; + END; + END IF; +END; +/ + +-- Create fresh user +CREATE USER petapoco IDENTIFIED BY petapoco; +/ + +-- Convenience procedure to drop certain database objects without having to deal with exceptions +CREATE OR REPLACE PROCEDURE DROP_IF_EXISTS (object_type IN VARCHAR2, object_name IN VARCHAR2) IS + command VARCHAR2(500); +BEGIN + -- Avoid sql injection by limiting object_type values and escaping the object_name + IF UPPER(object_type) NOT IN ('ROLE', 'TABLE', 'VIEW', 'SEQUENCE', 'INDEX', 'TRIGGER', 'PROCEDURE', 'FUNCTION', 'TYPE') THEN + RAISE_APPLICATION_ERROR(-20001, 'Invalid object type: ' || object_type); + END IF; + + command := 'DROP ' || object_type || ' ' || SYS.DBMS_ASSERT.QUALIFIED_SQL_NAME(object_name); + + EXECUTE IMMEDIATE command; +EXCEPTION + WHEN OTHERS THEN + -- ( role, table, sequence, index, trigger, procedure/function/type) + IF SQLCODE IN ( -1919, -942, -2289, -1418, -4080, -4043) THEN + NULL; + ELSE + RAISE; + END IF; +END; +/ + +CALL DROP_IF_EXISTS('ROLE', 'app_dev_role'); +/ + +-- Create an application developer role +CREATE ROLE app_dev_role; + +-- Grant privileges to the application developer role +GRANT CREATE SESSION, CREATE TABLE, CREATE SEQUENCE, CREATE PROCEDURE, CREATE TRIGGER, CREATE VIEW TO app_dev_role; +GRANT EXECUTE ON dbms_lock TO app_dev_role; +GRANT EXECUTE ON DROP_IF_EXISTS TO app_dev_role; + +-- Ensure that the tablespace created above, is the default for the user. This tablespace will be used when creating tables for example +ALTER USER petapoco DEFAULT TABLESPACE data_ts; +-- Give user quota e.g. to perform inserts +ALTER USER petapoco QUOTA UNLIMITED ON data_ts; + +-- Grant the application developer role +GRANT app_dev_role TO petapoco; +/ diff --git a/PetaPoco.Tests.Integration/Scripts/PostgresBuildDatabase.sql b/PetaPoco.Tests.Integration/Scripts/PostgresBuildDatabase.sql index b5c12382..c61c5f7f 100644 --- a/PetaPoco.Tests.Integration/Scripts/PostgresBuildDatabase.sql +++ b/PetaPoco.Tests.Integration/Scripts/PostgresBuildDatabase.sql @@ -80,7 +80,7 @@ CREATE TABLE "Note" ( "CreatedOn" TIMESTAMP NOT NULL ); --- MSAccess Specific Tables; +-- Postgres Specific Tables; DROP TABLE IF EXISTS "BugInvestigation_7K2TX4VR"; diff --git a/PetaPoco.Tests.Integration/app.config b/PetaPoco.Tests.Integration/app.config index f9cbe75e..9e5db441 100644 --- a/PetaPoco.Tests.Integration/app.config +++ b/PetaPoco.Tests.Integration/app.config @@ -12,11 +12,12 @@ + + - diff --git a/PetaPoco.Tests.Integration/appsettings.json b/PetaPoco.Tests.Integration/appsettings.json index d7098a89..4f52c081 100644 --- a/PetaPoco.Tests.Integration/appsettings.json +++ b/PetaPoco.Tests.Integration/appsettings.json @@ -46,6 +46,16 @@ "ConnectionString": "Data Source=localhost,5007;Initial Catalog=PetaPocoMSData;User ID=sa;Password=pAtAp0c8", "ProviderName": "Microsoft.Data.SqlClient" }, + { + "Name": "Oracle_Builder", + "ConnectionString": "Data Source=(DESCRIPTION=(ADDRESS=(PROTOCOL=tcp)(HOST=localhost)(PORT=5008))(CONNECT_DATA=(SERVICE_NAME=FREEPDB1)));User Id=sys;Password=petapoco;DBA PRIVILEGE=sysdba", + "ProviderName": "Oracle.ManagedDataAccess" + }, + { + "Name": "Oracle", + "ConnectionString": "Data Source=(DESCRIPTION=(ADDRESS=(PROTOCOL=tcp)(HOST=localhost)(PORT=5008))(CONNECT_DATA=(SERVICE_NAME=FREEPDB1)));User Id=petapoco;Password=petapoco;", + "ProviderName": "Oracle.ManagedDataAccess" + }, { "Name": "SQLite", "ConnectionString": "Data Source=PetaPoco.sqlite;Pooling=True;Max Pool Size=100", diff --git a/PetaPoco/Utilities/ParametersHelper.cs b/PetaPoco/Utilities/ParametersHelper.cs index a6336ba0..2cd0b78a 100644 --- a/PetaPoco/Utilities/ParametersHelper.cs +++ b/PetaPoco/Utilities/ParametersHelper.cs @@ -170,9 +170,8 @@ void ProcessArg(object arg) else { var type = arg.GetType(); - // TODO: Include second param `paramName: nameof(args)` in thrown ArgumentException if (type.IsValueType || type == typeof(string)) - throw new ArgumentException($"Value type or string passed as stored procedure argument: {arg}"); + throw new ArgumentException($"Value type or string passed as stored procedure argument: {arg}", nameof(args)); var readableProps = type.GetProperties().Where(p => p.CanRead); foreach (var prop in readableProps) { diff --git a/docker-compose.yml b/docker-compose.yml index 45b108ac..731aa384 100644 --- a/docker-compose.yml +++ b/docker-compose.yml @@ -10,6 +10,10 @@ x-mssql-environment: &mssql-environment ACCEPT_EULA: Y SA_PASSWORD: pAtAp0c8 +x-oracle-environment: &oracle-environment + ORACLE_PWD: petapoco + ORACLE_CHARACTERSET: AL32UTF8 + services: postgres: image: postgres:latest @@ -73,11 +77,12 @@ services: environment: <<: *mssql-environment - #oracledb: - # image: sath89/oracle-12c:latest - # container_name: oracledb_petapoco - # ports: - # - "5008:1521" - # - "5009:8008" + oracledb: + image: container-registry.oracle.com/database/free:latest + container_name: oracledb_petapoco + ports: + - "5008:1521" + environment: + <<: *oracle-environment # TODO: teradata