IBM Data Server Provider (DB2) .Net Tips – Series 1

I’ve been working with IBM Informix lately and from my previous post, I’ve mentioned a couple of ways to work with Informix. Now that I’ve settled with strictly using DB2 (see my previous post on this), my colleagues and I have been developing abstractions to work with Informix via Entity Framework and/or DB2 SDK (IBM’s version).

So, you’ve just been asked to tackle some data access tasks through Informix via .Net? My colleague, Jeff Crose (https://www.linkedin.com/in/jeff-crose-419797/) came out with some really cool tips worth blogging about. Jeff is a distinguished software developer in our team, working with backend data development through database platforms such as SQL Server and Informix. Shout out to Jeff for coming up with these tips!

TIP: Informix Overloaded Stored Procedures

Unlike other relational database management systems, Informix supports overloaded stores procedures. That may not seem like a big deal, but it can lead you astray if you’re not careful. Consider the following sample:

try
{
    using (DB2Connection conn = new DB2Connection(connectionString))
    {
        conn.Open();

        using (DB2Command cmd = conn.CreateCommand())
        {
            cmd.CommandType = CommandType.Text;
            cmd.CommandText = "EXECUTE PROCEDURE customer_insert_overload(?, ?, ?)";

            cmd.Parameters.Add(new DB2Parameter("customername", DB2Type.VarChar, 30)).Value = "George Washington";
            cmd.Parameters.Add(new DB2Parameter("customerstate", DB2Type.Char, 2)).Value = "WA";
            cmd.Parameters.Add(new DB2Parameter("customerinfo", DB2Type.Text)).Value = "The first President of the United States";

            var customerid = cmd.ExecuteScalar();
Console.WriteLine("customerid: {0}", customerid);
        }
    }
}
catch (DB2Exception exception)
{
    Console.WriteLine("Error Message: {0}", exception.Message);
}

You’ve created the connection, created the command, and created parameters of the correct types to match the signature of the stored procedure but you receive the following error message: ERROR[IX000][IBM][IDS / UNIX64] Routine(customer_insert_overload) cannot be resolved. As it turns out, the issue is not with the overload but with the fact that one of the parameters is a TEXT type. To get past the error, you need to explicitly cast the parameter to TEXT in the CommandText property.

try
{
    using (DB2Connection conn = new DB2Connection(connectionString))
    {
        conn.Open();

        using (DB2Command cmd = conn.CreateCommand())
        {
            cmd.CommandType = CommandType.Text;
            cmd.CommandText = "EXECUTE PROCEDURE customer_insert_overload(?, ?, ?::TEXT)";

            cmd.Parameters.Add(new DB2Parameter("customername", DB2Type.VarChar, 30)).Value = "George Washington";
            cmd.Parameters.Add(new DB2Parameter("customerstate", DB2Type.Char, 2)).Value = "WA";
            cmd.Parameters.Add(new DB2Parameter("customerinfo", DB2Type.Text)).Value = "The first President of the United States";

            var customerid = cmd.ExecuteScalar();
Console.WriteLine("customerid: {0}", customerid);
        }
    }
}
catch (DB2Exception exception)
{
    Console.WriteLine("Error Message: {0}", exception.Message);
}

TIP: ExecuteScalar VS ExecuteNonQuery

Now that the code works, you may be wondering why the ExecuteScalar method was chosen over ExecuteNonQuery for an insert. In this case, the stored procedure returns the identity for the newly inserted row. Even though the stored procedure returns an integer, it does not behave like its SQL Server counterpart. The following code inserts the data successfully but does not return a value.

try
{
    using (DB2Connection conn = new DB2Connection(connectionString))
    {
        conn.Open();

        using (DB2Command cmd = conn.CreateCommand())
        {
            cmd.CommandType = CommandType.Text;
            cmd.CommandText = "EXECUTE PROCEDURE customer_insert_overload(?, ?, ?::TEXT)";

            cmd.Parameters.Add(new DB2Parameter("customername", DB2Type.VarChar, 30)).Value = "Andrew Jackson";
            cmd.Parameters.Add(new DB2Parameter("customerstate", DB2Type.Char, 2)).Value = "MS";
            cmd.Parameters.Add(new DB2Parameter("customerinfo", DB2Type.Text)).Value = "The seventh President of the United States";
            cmd.Parameters.Add(new DB2Parameter("customerid", DB2Type.Integer));
            cmd.Parameters["customerid"].Direction = ParameterDirection.ReturnValue;

            cmd.ExecuteNonQuery();
            var customerid = cmd.Parameters["customerid"].Value;

Console.WriteLine("customerid: {0}", customerid);
        }
    }
}
catch (DB2Exception exception)
{
    Console.WriteLine("Error Message: {0}", exception.Message);
}

To get the “customerid” you need to use the ExcecuteScalar method.

TIP: ExecuteRow for multiple return values

What if the stored procedure returns multiple values? The ExecuteRow method can be used to get all the values.

try
{
    using (DB2Connection conn = new DB2Connection(connectionString))
    {
        conn.Open();

        using (DB2Command cmd = conn.CreateCommand())
        {
            cmd.CommandType = CommandType.Text;
            cmd.CommandText = "EXECUTE PROCEDURE customer_insert(?, ?, ?::TEXT)";

            cmd.Parameters.Add(new DB2Parameter("customername", DB2Type.VarChar, 30)).Value = "Abraham Lincoln";
            cmd.Parameters.Add(new DB2Parameter("customerstate", DB2Type.Char, 2)).Value = "NE";
            cmd.Parameters.Add(new DB2Parameter("customerinfo", DB2Type.Text)).Value = "The sixteenth President of the United States";

            var row = cmd.ExecuteRow();
Console.WriteLine("customerid: {0}, result: {1}", row[0], row[1]);
        }
    }
}
catch (DB2Exception exception)
{
    Console.WriteLine("Error Message: {0}", exception.Message);
}

Notice that the “customerinfo” parameter was once again explicitly cast to a TEXT type in the CommandText property. The following example will once again cause the “ERROR[IX000][IBM][IDS / UNIX64] Routine(customer_insert) can not be resolved.” exception.

try
{
    using (DB2Connection conn = new DB2Connection(connectionString))
    {
        conn.Open();

        using (DB2Command cmd = conn.CreateCommand())
        {
            cmd.CommandType = CommandType.Text;
            cmd.CommandText = "EXECUTE PROCEDURE customer_insert(?, ?, ?)"; 

            cmd.Parameters.Add(new DB2Parameter("customername", DB2Type.VarChar, 30)).Value = "Abraham Lincoln";
            cmd.Parameters.Add(new DB2Parameter("customerstate", DB2Type.Char, 2)).Value = "NE";
            cmd.Parameters.Add(new DB2Parameter("customerinfo", DB2Type.Text)).Value = "The sixteenth President of the United States";

            var row = cmd.ExecuteRow();
Console.WriteLine("customerid: {0}, result: {1}", row[0], row[1]);
        }
    }
}
catch (DB2Exception exception)
{
    Console.WriteLine("Error Message: {0}", exception.Message);
}

 

TIP: And Finally, the “ExecuteReader” …

With all the data inserted successfully, it’s time to find out how return all the rows. Luckily that part is straightforward. Just call the ExecuteReader method and iterate through the results.

try
{
    using (DB2Connection conn = new DB2Connection(connectionString))
    {
        conn.Open();

        using (DB2Command cmd = conn.CreateCommand())
        {
            cmd.CommandType = CommandType.Text;
            cmd.CommandText = "EXECUTE PROCEDURE customer_select()";

            var dr = cmd.ExecuteReader();
            while (dr.Read())
            {
                Console.WriteLine("customer_id: {0}, customer_name: {1}, customer_info: {2}", dr[0], dr[1], dr[2]);
            }
        }
    }
}
catch (DB2Exception exception)
{
    Console.WriteLine("Error Message: {0}", exception.Message);
}

Working with Entity Framework 6.0 ON IBM Informix V11.10+ in Visual Studio 2015

We know EF (Entify Framework) has many benefits working with Databases. Particularly from a development and performance stand-point. There are 2 versions of client connectivity SDK’s for working with Informix Databases:

IBM.Data.Informix.dll— Also referred to as the Common IDS .NET Provider. This assembly has been specifically created to help existing applications that were developed using the CSDK .NET Provider (SQLI protocol) to use the latest DRDA protocol support. It has additional support for some of the earlier Informix client features and is targeted only for .NET application development for Informix.

IBM.Data.DB2.dll— Also referred to as the DB2 .NET Provider. Although the name of the provider indicates DB2, it is in fact the single .NET provider for IBM database servers including DB2 and Informix. It is the recommended and preferred .NET provider for all clients targeting DB2 and new application development targeting Informix (Version 11.10 or later).

These are referenced from IBM’s website:

https://www.ibm.com/developerworks/data/library/techarticle/dm-1007dsnetids/

IBM.Data.DB2.dll is the preferred approach and uses Entity Framework. More importantly, this is the version that IBM will support for new enhancements in conjunction with Entity Framework.

Note: In order to use the .Net Data Provider (DB2) for Entity Framework 6.0, you need to ensure that DRDA protocol has been enabled on the Informix Server. For more information on DRDA overview and troubleshooting, see the following articles:

Overview of DRDA

https://www.ibm.com/support/knowledgecenter/SSGU8G_11.50.0/com.ibm.admin.doc/ids_admin_0206.htm

TCPIP communication errors with DRDA

http://www-01.ibm.com/support/docview.wss?uid=swg21164785

To get started with the .Net Data Provider for IBM Informix V11.10+ in Visual Studio 2015

1) Download and install the latest updates for Visual Studio 2015 (As of writing this blog post, the current updates is version 3)

2) Download and Install the DSDriver Package (Data Server Driver Package) from IBM’s site:

https://www-945.ibm.com/support/fixcentral/swg/selectFixes?parent=ibm~Information%2BManagement&product=ibm/Information+Management/IBM+Data+Server+Client+Packages&release=All&platform=All&function=fixId&fixids=special_35279_DSClients-ntx64-dsdriver-10.5.600.232-FP006%3A898521251824283008&includeSupersedes=0

Specifically, this version” Special Build 35279 for IBM Data Server Driver Package (Windows/x86-64 64 bit) V10.5 Fix Pack 6” (special_35279_ntx64_dsdriver_EN.exe)

NOTE: As of writing on this blog, there could be more fix pack versions of the DS Driver Package, however the fix pack version above works well in VS 2015

3) Download and Install VSAI (IBM Database Add-Ins for Visual Studio) from IBM’s site:

https://www-945.ibm.com/support/fixcentral/swg/selectFixes?parent=ibm~Information%2BManagement&product=ibm/Information+Management/IBM+Data+Server+Client+Packages&release=All&platform=All&function=fixId&fixids=special_35192_DSClients-nt32-vsai-10.5.600.232-FP006%3A295467480640129088&includeSupersedes=0

Specifically, this version” Special Build 35192 for IBM Database Add-Ins for Visual Studio (Windows/x86-32 32 bit) V10.5 Fix Pack 6” (special_35192_nt32_vsai.zip)

NOTE: As of writing on this blog post, none of the Add-Ins for Visual Studio work on machine running Windows 10. IBM hasn’t provided a solution for this problem. Also, do not use DS Driver Package V11. Use DS Driver Package version 10.5+. This version is specifically compiled for EF 6.0

4) Install IBM Entity Framework 6.0 in your projects. Right click on the Project and Select “Manage Nuget Packages” and install latest EntityFramework.IBM.DB2

image

image

Sample Project to verify that you can use EF 6.0 connecting to IBM Informix Database (V11.10+):

  • Start of by creating a sample project in Visual Studio 2015. Any project would be fine, however for testing purposes, create a test project. This will allow you to generate Unit Tests to verify EF on Informix Database V11.10+
  • Right click on the project and Select “Add” then “New Item”.
  • From the list of items, select “ADO.NET Entity Data Model”, “Select IBM DB2 and IDS Servers

image

image

  • Follow the wizard but on the first step, select: “EF Designer from database
  • Click on “New Connection” and provide the proper server settings for the Informix DB server. Note that DRDA protocol needs to be enabled on the target server. Refer back to the top section of this post.

image

  • Click “OK” then click on “Next
  • Select the appropriate Tables then click “Finish

Once completed, your test project should have generated EF files which you can use to connect and work with Informix Server. Here’s an example of an auto generated file which is the actual context file that “inherits” DbContext from EF

image

The tools in VS also generates the entities for you. Since we’ve used the “EF Designer from database” template, all the of table to entity mappings is actually stored in the .EDMX file. You can explore this file visually or to see raw data, open the file in a text editor such as notepad

image

As an example, I’ve written some unit tests to verify some data from a table in Informix V11.10+.

image

With EF, we can greatly improve how are applications integrate on Informix. We can have better design principles and patterns using EF. A common design pattern with Databases is called “UNIT of Work”. Here’s a great article on how to implement Unit of Work design pattern with ASP.Net MVC

https://www.asp.net/mvc/overview/older-versions/getting-started-with-ef-5-using-mvc-4/implementing-the-repository-and-unit-of-work-patterns-in-an-asp-net-mvc-application