Sending a DataTable to a Stored Procedure
Sending a DataTable to a Stored Procedure using Table Valued Parameters.
Introduction
This is a small article explaining how to send an entire data-table to a Stored Procedure in the database server as an input parameter.
Background
It uses a logic which allows us to do add, modify, and delete operations on a set of records in the database using a simple form. The details also need to be shown after adding, updating, and deleting of records in a table. And the data-table should be given to a stored procedure to perform the operations. This feature will work with SQL Server 2008.
Advantages
- For each event on the page the form will not be interacting with the database. This reduces server round trips.
- All necessary operations such as:
- Inserting a new record
- Updating an existing record
- Deleting an existing record
- After performing a certain action (such as Insert, Update, or Delete) on the grid-view the data will be saved in “Session”. And whenever the data is required, it is be fetched from the Session.
- We send the entire data-table from the session to the database for manipulation, and with the use of a Stored Procedure we can do operations such as insert, delete, and update.
- It is easier to perform all operations on a set of rows at a time.
- The user can deal with thousands of data-rows at the same time without a connection.
- Extends the functionality of programming in a database engine.
are performed on client side only. They will be persisted in the database only after getting confirmation from the user. So, the performance of the application will improve.
Using the code
When a page is getting loaded the first time, data from the database is loaded to a data-table. In that data-table a column is added (named
Operation
). Whenever the user performs an action on the grid-view,
the indicator bit is added to that column for that record (Insert 0, Update 1, and Delete
2). If the user clicks on
a delete link on a particular row then the operation column of that row is updated to 2, and in
the RowDataBound
event of the grid-view we hide the records
whose operation bit is 2. The temporary table is stored in session state. Before performing any operation, the session table will be called and the action will be
performed on that table and again that table will be stored in the session. After performing all the necessary operations, when
the user clicks on the Save button, the function fnMangeOperations
is called which will filter all the rows on which the operation was performed and the
Save button will
send only those details in which the operation has to be performed (you can find
the function fnMangeOperations
in the source code
from the attached files).
Step 1: Declaring global variables:
private clsEmpDetails _objEmpDetails;
private DataTable _dtEmpDetails;
private DataTable _dtEmpDetailsVals;
Step 2: Initializing the data members when page loads.
protected void Page_Load(object sender, EventArgs e)
{
if (!IsPostBack)
{
_objEmpDetails = new clsEmpDetails();
_dtEmpDetails = _objEmpDetails.fnGetDetails();
if(_dtEmpDetails != null){
//Adding a new column to the table which will store the operation details
//For new insert it will store 1
//For updating the existing record it will store 0
_dtEmpDetails.Columns.Add("Operation", typeof(string));
Session["EmpDetails"] = _dtEmpDetails;
gvEmpDetails.DataSource = _dtEmpDetails;
gvEmpDetails.DataBind();
}
}
}
Just store the data in session and maintain the indicator for each operation. The operation will be like this:
protected void gvEmpDetails_RowCommand(object sender, GridViewCommandEventArgs e)
{
if (e.CommandName == "AddNew")
{
try{
_dtEmpDetails = Session["EmpDetails"] as DataTable;
string strID = (TextBox)gvEmpDetails.FooterRow.Cells[0].FindControl("txtInsID")).Text;
string strName = (TextBox)gvEmpDetails.FooterRow.Cells[1].FindControl("txtInsName")).Text;
string strAddress = (TextBox)gvEmpDetails.FooterRow.Cells[1].FindControl("txtInsAddress")).Text;
_dtEmpDetails.Rows.Add(strID, strName, strAddress, "0");
Session["EmpDetails"] = _dtEmpDetails;
fnBindEmpDetails(); //This function will bind the data to the gridview by fetching the data from session
}
catch(Exception ex){
//Handle your exception
}
}
}
On click of the Save button, call the following function by passing your
DataTable
as a parameter.
public string fnStoredProc(DataTable dtDetails)
{
string strMsg = "";
try
{
fnConOpen();//Function for opening connection
SqlCommand cmdProc = new SqlCommand("spEmpDetails", con);
cmdProc.CommandType = CommandType.StoredProcedure;
cmdProc.Parameters.AddWithValue("@Type", "InsertDetails");
cmdProc.Parameters.AddWithValue("@Details", dtDetails);
cmdProc.ExecuteNonQuery();
strMsg = "Saved successfully.";
}
catch (SqlException e) {
//strMsg = "Data not saved successfully.";
strMsg = e.Message.ToString();
}
finally
{
fnConClose();//Function for closing connection
}
return strMsg;
}
Procedure structure
First create a table type with matching columns which comes from the front-end. In this case:
/*Creating type for the procedure parameter*/
CREATE TYPE EmpType AS TABLE
(
ID INT, Name VARCHAR(3000), Address VARCHAR(8000), Operation SMALLINT
)
Write the procedure for the operations.
ALTER PROCEDURE spEmpDetails
@Type VARCHAR(15),
@Details EmpType READONLY
AS
BEGIN
IF(@Type='FetchDetails')
SELECT * FROM EmployeeDetails
ELSE
BEGIN
--For deleting the details from the table
DELETE FROM EmployeeDetails WHERE ID IN(SELECT ID FROM @Details WHERE Operation=2)
--For updating the details in the table
UPDATE e SET e.Name=d.Name, e.Address=d.Address FROM EmployeeDetails e, @Details d
WHERE d.ID=e.ID and d.Operation=1
--For inserting the new records in the table
INSERT INTO EmployeeDetails(ID, Name, Address)
SELECT ID, Name, Address FROM @Details WHERE Operation=0;
END
END
GO
Note: This procedure takes a datatabe as its parameter and performs insert, update, and delete operations based on the table data.
End point
Thank you for reading this article. Any suggestions will be appreciated.