In this article I will explain with an example, how to use
Output Parameter in
SQL Server Stored Procedure with
Dapper library in Windows Forms (WinForms) Application using C# and VB.Net.
Installing Dapper package using Nuget
Database
I have made use of the following table Customers with the schema as follows.
Note: You can download the database table SQL by clicking the download link below.
Stored Procedure
This
Stored Procedure accepts following parameters which are used to
insert the records:
Name – This is an INPUT Parameter to pass the Name of the Customer.
Country – This is an INPUT Parameter to pass the Country of the Customer.
CustomerId – This is an OUTPUT Parameter to get the last inserted CustomerId.
Note: Output Parameter is identified by the keyword OUTPUT.
CREATE PROCEDURE [Customers_InsertCustomer_Output]
@Name VARCHAR(100),
@Country VARCHAR(50),
@CustomerId INT OUTPUT
AS
BEGIN
INSERT INTO [Customers]
([Name]
,[Country])
VALUES (@Name
,@Country)
SELECT @CustomerId = SCOPE_IDENTITY()
END
Form Design
The following Form consists of:
Label – For labeling controls.
TextBox – For capturing Name to be inserted.
ComboBox – For capturing Country Name to be inserted.
Button – For inserting records.
The Button has been assigned with a Click event handler.
Namespaces
You will need to import the following namespaces.
C#
using Dapper;
using System.Data;
using System.Data.SqlClient;
using System.Configuration;
VB.Net
Imports Dapper
Imports System.Data
Imports System.Data.SqlClient
Imports System.Configuration
Inserting with Stored Procedure using Dapper in Windows Forms
Inside the Form Load event handler, the ComboBox items are added.
When Insert button is clicked, first the connection is read from App.Config file.
An object of DynamicParameters is created and CustomerId is added as parameter with its Data Type specified and its Direction is set to Output since by default the Direction of all parameter are Input.
Then, the Name and Country values are also added as parameter.
After that, the
Execute method of
Dapper library is used to insert record to the
Customers Table.
The CustomerId of the inserted record i.e. the output parameter value is fetched using Get method of DynamicParameters class.
Finally, the TextBox and ComboBox values are set to empty and CustomerId of the inserted record is displayed in MessageBox.
C#
private void Form1_Load(object sender, EventArgs e)
{
cbCountries.Items.Add("United States");
cbCountries.Items.Add("India");
cbCountries.Items.Add("France");
cbCountries.Items.Add("Russia");
}
private void OnInsert(object sender, EventArgs e)
{
int customerId;
string spName = "Customers_InsertCustomer_Output";
string constr = ConfigurationManager.ConnectionStrings["constr"].ConnectionString;
using (SqlConnection con = new SqlConnection(constr))
{
DynamicParameters dynamicParameters = new DynamicParameters();
// Adding Input parameters.
dynamicParameters.Add("@Name", txtName.Text);
dynamicParameters.Add("@Country", cbCountries.SelectedItem.ToString());
// Adding Output parameter.
dynamicParameters.Add("@CustomerId", dbType: DbType.Int32, direction: ParameterDirection.Output);
con.Execute(spName, dynamicParameters, commandType: CommandType.StoredProcedure);
customerId = dynamicParameters.Get<int>("@CustomerId");
}
txtName.Text = string.Empty;
cbCountries.Text = string.Empty;
MessageBox.Show("Inserted Customer ID: " + customerId);
}
VB.Net
Private Sub Form1_Load(sender As Object, e As EventArgs) Handles Me.Load
cbCountries.Items.Add("United States")
cbCountries.Items.Add("India")
cbCountries.Items.Add("France")
cbCountries.Items.Add("Russia")
End Sub
Private Sub OnInsert(sender As Object, e As EventArgs) Handles btnInsert.Click
Dim customerId As Integer
Dim spName As String = "Customers_InsertCustomer_Output"
Dim constr As String = ConfigurationManager.ConnectionStrings("constr").ConnectionString
Using con As SqlConnection = New SqlConnection(constr)
Dim dynamicParameters As DynamicParameters = New DynamicParameters()
' Adding Input parameters.
dynamicParameters.Add("@Name", txtName.Text)
dynamicParameters.Add("@Country", cbCountries.SelectedItem.ToString())
' Adding Output parameter.
dynamicParameters.Add("@CustomerId", dbType:=DbType.Int32, direction:=ParameterDirection.Output)
con.Execute(spName, dynamicParameters, commandType:=CommandType.StoredProcedure)
customerId = dynamicParameters.Get(Of Integer)("@CustomerId")
End Using
txtName.Text = String.Empty
cbCountries.Text = String.Empty
MessageBox.Show("Inserted Customer ID: " & customerId)
End Sub
Screenshots
The Form
Record after Insert in database
Downloads