/****************************************************************************
** (c) Copyright IBM Corp. 2007 All rights reserved.
**
** The following sample of source code ("Sample") is owned by International
** Business Machines Corporation or one of its subsidiaries ("IBM") and is
** copyrighted and licensed, not sold. You may use, copy, modify, and
** distribute the Sample in any form without payment to IBM, for the purpose of
** assisting you in the development of your applications.
**
** The Sample code is provided to you on an "AS IS" basis, without warranty of
** any kind. IBM HEREBY EXPRESSLY DISCLAIMS ALL WARRANTIES, EITHER EXPRESS OR
** IMPLIED, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF
** MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. Some jurisdictions do
** not allow for the exclusion or limitation of implied warranties, so the above
** limitations or exclusions may not apply to you. IBM shall not be liable for
** any damages you suffer as a result of using, copying, modifying or
** distributing the Sample, even if IBM has been advised of the possibility of
** such damages.
*****************************************************************************
**
** SOURCE FILE NAME: DbDatMap.cs
**
** SAMPLE: How to set up and use DataTable and DataColumn mappings
** with the DB2 .NET Data Provider
**
** SQL Statements USED:
** CREATE TABLE
** DROP TABLE
** INSERT
** SELECT
** DELETE
**
** DB2 .NET Data Provider Classes USED:
** DB2Connection
** DB2Command
**
**
*****************************************************************************
**
** Building and Running the sample program
**
** 1. Compile the DbDatMap.cs file with bldapp.bat by entering the following
** at the command prompt:
**
** bldapp DbDatMap
**
** or compile DbDatMap.cs with the makefile by entering the following at
** the command prompt:
**
** nmake DbDatMap
**
** 2. Run the DbDatMap program by entering the program name at the command
** prompt:
**
** DbDatMap
**
*****************************************************************************
**
** For more information on the sample programs, see the README file.
**
** For information on developing applications, see the Application
** Development Guide.
**
** For information on using SQL statements, see the SQL Reference.
**
** For the latest information on programming, compiling, and running DB2
** applications, visit the DB2 Information Center at
** http://publib.boulder.ibm.com/infocenter/db2luw/v9r7/index.jsp
**
****************************************************************************/
using System;
using System.Data;
using System.Data.Common;
using System.IO;
using IBM.Data.DB2;
class DbDatMap
{
public static void Main(String[] args)
{
// Declare a DB2Connection and a DB2Command
DB2Connection conn = null;
DB2Command cmd = null;
try
{
Console.WriteLine();
Console.WriteLine(" THIS SAMPLE SHOWS HOW TO SET UP AND USE " +
"DataTable AND DataColumn MAPPINGS");
Console.WriteLine();
// Connect to a database
Console.WriteLine(" Connecting to a database ...");
conn = ConnectDb(args);
Console.WriteLine();
// Create a DB2DataAdapter, a DataSet and a DB2CommandBuilder
DB2DataAdapter adp = new DB2DataAdapter();
DB2CommandBuilder cb = null;
DataSet dset = new DataSet();
cmd = conn.CreateCommand();
// Create a table 'empsamp' in the SAMPLE database
Console.WriteLine(" CREATE A TABLE empsamp WITH ATTRIBUTES:\n" +
" ID SMALLINT NOT NULL,\n" +
" NAME VARCHAR(9),\n" +
" JOB CHAR(5),\n" +
" SALARY DEC(7,2),\n" +
" PRIMARY KEY(ID)");
cmd.CommandText = "CREATE TABLE EMPSAMP (" +
" ID SMALLINT NOT NULL," +
" NAME VARCHAR(9)," +
" JOB CHAR(5)," +
" SALARY DEC(7,2)," +
" PRIMARY KEY(ID))";
cmd.ExecuteNonQuery();
Console.WriteLine();
// Insert some rows into the empty table 'empsamp'
Console.WriteLine(
" INSERT THE FOLLOWING ROWS IN empsamp:\n" +
" (260, 'EMP1', 'CLERK', 4500.00),\n" +
" (300, 'EMP2', 'SALES', 11000.40)");
cmd.CommandText = "INSERT INTO empsamp(id, name, job, salary) " +
" VALUES (260, 'EMP1', 'CLERK', 4500.00), "+
" (300, 'EMP2', 'SALES', 11000.40) ";
Console.WriteLine();
cmd.ExecuteNonQuery();
// Intialize the SELECT command of the DB2DataAdapter
adp.SelectCommand = new DB2Command("SELECT * FROM empsamp",conn);
Console.WriteLine("\n USE CLASS DB2CommandBuilder TO GENERATE "+
" THE INSERT, UPDATE AND DELETE\n" +
" COMMANDS FOR THE DB2DataAdapter");
// Initialize a DB2CommandBuilder instance that generates the UPDATE,
// DELETE and INSERT commands of the DB2DataAdapter
cb = new DB2CommandBuilder(adp);
// Define the parameters for the generated UPDATE, DELETE and
// INSERT commands of the DB2DataAdapter
AddParameters(cb);
// Create a DataTableMapping named 'Table' for the 'empsamp' table
SetMapping(adp);
// Modify the 'empsamp' table in the sample database through the
// DataTableMapping, using a DB2DataAdapter
UseMapping(adp,cmd,dset);
// Delete the table 'empsamp'
cmd.CommandText = "DROP TABLE empsamp";
cmd.ExecuteNonQuery();
// Disconnect from the database
Console.WriteLine("\n Disconnect from the database");
conn.Close();
}
catch (Exception e)
{
Console.WriteLine(e.Message);
cmd.CommandText = "DROP TABLE empsamp";
cmd.ExecuteNonQuery();
conn.Close();
}
} // Main
// Helper method: This method establishes a connection to a database
public static DB2Connection ConnectDb(String[] argv)
{
String server = "";
String alias = "";
String userId = "";
String password = "";
Int32 portNumber = -1;
String connectString;
if( argv.Length > 5 ||
( argv.Length == 1 &&
( String.Compare(argv[0],"?") == 0 ||
String.Compare(argv[0],"-?") == 0 ||
String.Compare(argv[0],"/?") == 0 ||
String.Compare(argv[0],"-h",true) == 0 ||
String.Compare(argv[0],"/h",true) == 0 ||
String.Compare(argv[0],"-help",true) == 0 ||
String.Compare(argv[0],"/help",true) == 0 ) ) )
{
throw new Exception(
"Usage: prog_name [dbAlias] [userId passwd] \n" +
" prog_name [dbAlias] server portNum userId passwd");
}
switch (argv.Length)
{
case 0: // Use all defaults
alias = "sample";
userId = "";
password = "";
break;
case 1: // dbAlias specified
alias = argv[0];
userId = "";
password = "";
break;
case 2: // userId & passwd specified
alias = "sample";
userId = argv[0];
password = argv[1];
break;
case 3: // dbAlias, userId & passwd specified
alias = argv[0];
userId = argv[1];
password = argv[2];
break;
case 4: // use default dbAlias
alias = "sample";
server = argv[0];
portNumber = Convert.ToInt32(argv[1]);
userId = argv[2];
password = argv[3];
break;
case 5: // everything specified
alias = argv[0];
server = argv[1];
portNumber = Convert.ToInt32(argv[2]);
userId = argv[3];
password = argv[4];
break;
}
if(portNumber==-1)
{
connectString = "Database=" + alias;
}
else
{
connectString = "Server=" + server + ":" + portNumber +
";Database=" + alias;
}
if(userId != "")
{
connectString += ";UID=" + userId + ";PWD=" + password;
}
DB2Connection conn = new DB2Connection(connectString);
conn.Open();
Console.WriteLine(" Connected to the " + alias + " database");
return conn;
} // ConnectDb
// This method defines the parameters for the UPDATE, DELETE and INSERT
// commands of the DB2DataAdapter
public static void AddParameters(DB2CommandBuilder cb)
{
try
{
// Define the parameters for the INSERT command in different ways
cb.GetInsertCommand().Parameters.Add("@empid",
DB2Type.SmallInt,
5,
"ID").SourceVersion =
DataRowVersion.Original;
cb.GetInsertCommand().Parameters.Add(
new DB2Parameter("@empname",
DB2Type.VarChar,
9,
ParameterDirection.Input,
false,
0,
0,
"NAME",
DataRowVersion.Current,
""));
cb.GetInsertCommand().Parameters.Add(new DB2Parameter("@empjob",
DB2Type.Char,
5,
"JOB"));
cb.GetInsertCommand().Parameters.Add("@empsalary",
DB2Type.Decimal,
7);
// Define the parameters for the UPDATE command in different ways
cb.GetUpdateCommand().Parameters.Add(new DB2Parameter("@empname",
DB2Type.VarChar,
9));
cb.GetUpdateCommand().Parameters.Add("@empsalary",
DB2Type.Decimal,
7,
"SALARY");
cb.GetUpdateCommand().Parameters.Add("@empid",
DB2Type.SmallInt,
5).SourceVersion =
DataRowVersion.Original;
DB2Parameter param = new DB2Parameter("@empjob", DB2Type.Char);
cb.GetUpdateCommand().Parameters.Add( param );
// Define the parameter for the DELETE command
cb.GetDeleteCommand().Parameters.Add("@empid",
DB2Type.SmallInt).SourceVersion =
DataRowVersion.Original;
}
catch (Exception e)
{
Console.WriteLine(e.Message);
}
} // AddParameters
// This method creates a DataTableMapping for the table 'empsamp'
public static void SetMapping(DB2DataAdapter adp)
{
try
{
Console.WriteLine("\n CREATE A DataTableMapping named 'Table' FOR" +
"THE TABLE 'empsamp'\n WHICH IS THE DEFAULT " +
"DataTableMapping FOR THE DB2DataAdapter");
Console.WriteLine("\n MAP COLUMN NAMES IN THE 'empsamp' TABLE OF " +
"THE SAMPLE DATABASE\n TO NEW COLUMN NAMES " +
"IN THE 'empsamp' TABLE IN THE DATASET:'\n" +
" 'ID' MAPPED TO 'newid'\n" +
" 'NAME' MAPPED TO 'newname'\n" +
" 'JOB' MAPPED TO 'newjob'\n" +
" 'SALARY' MAPPED TO 'newsalary'");
// Create a DataTableMapping for the table 'empsamp' and map existing
// column names to new column names
DataTableMapping empsamp_map = adp.TableMappings.Add("Table", "empsamp");
empsamp_map.ColumnMappings.Add("ID", "newid");
empsamp_map.ColumnMappings.Add("NAME", "newname");
empsamp_map.ColumnMappings.Add("JOB", "newjob");
empsamp_map.ColumnMappings.Add("SALARY", "newsalary");
}
catch (Exception e)
{
Console.WriteLine(e.Message);
}
} // SetMapping
// This method modifies the 'empsamp' table in the sample database through
// the DataTableMapping, using the DB2DataAdapter
public static void UseMapping(DB2DataAdapter adp,
DB2Command cmd,
DataSet dset)
{
try
{
Console.WriteLine("\n MODIFY THE TABLE 'empsamp' IN THE SAMPLE " +
"DATABASE THROUGH THE" +
"\n DataTableMapping USING THE DB2DataAdapter");
// Fill the DataSet with the data in table 'empsamp' through the
// default (and so does not have to be specified) DataTableMapping
// 'Table'
Console.WriteLine("\n " +
"FILL THE DATASET WITH THE Fill METHOD OF" +
" DB2DataAdapter." +
"\n NO TABLE NAME NEEDS TO BE SPECIFIED BECAUSE" +
" 'Table' IS THE DEFAULT" +
"\n DataTableMapping FOR THE DB2DataAdapter");
adp.Fill(dset);
// Display the table 'empsamp' before any new rows are inserted
Console.WriteLine("\n TABLE BEFORE INSERTING ROWS:");
cmd.CommandText = "SELECT * FROM empsamp";
DB2DataReader reader = cmd.ExecuteReader();
DisplayData(reader);
reader.Close();
// Insert some rows in the table 'empsamp'
Console.WriteLine("\n" +
" INSERT THE FOLLOWING ROWS IN EMPSAMP:\n" +
" (270, 'EMP3', 'SALES', 7500),\n" +
" (280, 'EMP4', 'CLERK', 10000.00),\n" +
" (290, 'EMP5', 'MGR', 15000.00)");
DataRow row = dset.Tables["empsamp"].NewRow();
row["newid"] = 270;
row["newname"] = "EMP3";
row["newjob"] = "SALES";
row["newsalary"] = 7500;
dset.Tables["empsamp"].Rows.Add(row);
row = dset.Tables["empsamp"].NewRow();
row["newid"] = 280;
row["newname"] = "EMP4";
row["newjob"] = "CLERK";
row["newsalary"] = 10000.00;
dset.Tables["empsamp"].Rows.Add(row);
row = dset.Tables["empsamp"].NewRow();
row["newid"] = 290;
row["newname"] = "EMP5";
row["newjob"] = "MGR";
row["newsalary"] = 15000.00;
dset.Tables["empsamp"].Rows.Add(row);
// Update the table 'empsamp' in the sample database through the
// DataTableMapping 'Table' to reflect the insertion of rows in the
// DataSet. The DataTableMapping 'Table' is specified although it does
// not need to be, because it is the default DataTableMapping
adp.Update(dset,"Table");
Console.WriteLine("\n ROWS INSERTED IN THE TABLE 'empsamp' " +
"THROUGH THE DataTableMapping 'Table'" +
"\n BY THE Update METHOD OF THE DB2DataAdapter");
Console.WriteLine("\n TABLE AFTER INSERTING ROWS:");
cmd.CommandText = "SELECT * FROM empsamp";
reader = cmd.ExecuteReader();
DisplayData(reader);
reader.Close();
// Make changes to the Dataset by deleting and changing the contents
// of some rows
Console.WriteLine("\n DELETE EMPLOYEE ID = 300 AND CHANGE DETAILS" +
" OF EMPLOYEE ID = 260");
for (int i=0; i<dset.Tables["empsamp"].Rows.Count; i++)
{
if (((Int16)dset.Tables["empsamp"].Rows[i]["newid"]) == 300)
{
dset.Tables["empsamp"].Rows[i].Delete();
}
else if (((Int16)dset.Tables["empsamp"].Rows[i]["newid"]) == 260)
{
dset.Tables["empsamp"].Rows[i]["newjob"] = "MGR";
dset.Tables["empsamp"].Rows[i]["newsalary"] = 20000;
}
}
// Update the table 'empsamp' in the sample database to reflect the
// changes made to the table in the DataSet through the default(and
// so does not have to be specified) DataTableMapping 'Table'
adp.Update(dset);
Console.WriteLine("\n ROWS UPDATED AND DELETED IN THE TABLE " +
"'empsamp' THROUGH THE DataTableMapping" +
"\n 'Table' BY THE Update METHOD OF THE " +
"DB2DataAdapter");
// Display the table 'empsamp' after updating
Console.WriteLine("\n TABLE AFTER DELETING EMPLOYEE ID = 300 AND" +
" CHANGING DETAILS\n OF EMPLOYEE ID = 260");
reader = cmd.ExecuteReader();
DisplayData(reader);
reader.Close();
}
catch (Exception e)
{
Console.WriteLine(e.Message);
}
} // UseMapping
// This method displays the contents stored in a DB2DataReader instance
public static void DisplayData(DB2DataReader reader)
{
try
{
Console.WriteLine();
// DataTable to store the column metadata of the DB2DataReader
DataTable table = reader.GetSchemaTable();
// Display the column headings for the data in the DB2DataReader
foreach (DataRow row in table.Rows)
{
Console.Write(" " + row["ColumnName"]);
}
Console.WriteLine();
Console.Write(" ");
foreach (DataRow row in table.Rows)
{
int length = 8;
if ((DB2Type)row["ProviderType"] == DB2Type.Integer ||
(DB2Type)row["ProviderType"] == DB2Type.SmallInt)
{
length = 3;
}
else if ((DB2Type)row["ProviderType"] == DB2Type.VarChar ||
(DB2Type)row["ProviderType"] == DB2Type.Char)
{
length = 7;
}
for (int i = 0; i < length; i++)
{
Console.Write("-");
}
Console.Write(" ");
}
// Display the contents of each row of the DB2DataReader
while (reader.Read())
{
Console.WriteLine();
Console.Write(" ");
for (int i = 0; i < table.Rows.Count; i++)
{
if ((DB2Type)table.Rows[i]["ProviderType"] == DB2Type.Integer ||
(DB2Type)table.Rows[i]["ProviderType"] == DB2Type.SmallInt)
{
Console.Write(" " + reader.GetInt16(i).ToString().PadRight(3));
}
else if ((DB2Type)table.Rows[i]["ProviderType"] ==
DB2Type.VarChar ||
(DB2Type)table.Rows[i]["ProviderType"] == DB2Type.Char)
{
Console.Write(" " + reader.GetString(i).PadRight(7));
}
else
{
Decimal dataRound = Decimal.Round(reader.GetDecimal(i),2);
String strData = String.Format("{0:f2}",dataRound);
Console.Write(" " + strData.PadLeft(8));
}
}
}
Console.WriteLine();
}
catch (Exception e)
{
Console.WriteLine(e.Message);
}
} //DisplayData
} // DbDatMap