SqlCommand Class
 

Represents a Transact-SQL statement or stored procedure to execute against a SQL Server database. This class cannot be inherited.

Namespace:   System.Data.SqlClient
Assembly:  System.Data (in System.Data.dll)

Inheritance Hierarchy
SystemObject
   SystemMarshalByRefObject
     System.ComponentModelComponent
       System.Data.CommonDbCommand
        System.Data.SqlClientSqlCommand

Syntax
public sealed class SqlCommand : DbCommand, ICloneable
public ref class SqlCommand sealed : DbCommand, ICloneable
[<Sealed>]
type SqlCommand = 
    class
        inherit DbCommand
        interface ICloneable
    end
Public NotInheritable Class SqlCommand
	Inherits DbCommand
	Implements ICloneable
Constructors
NameDescription
System_CAPS_pubmethod SqlCommand

Initializes a new instance of the SqlCommand class.

System_CAPS_pubmethod SqlCommand

Initializes a new instance of the SqlCommand class with the text of the query.

System_CAPS_pubmethod SqlCommand

Initializes a new instance of the SqlCommand class with the text of the query and a SqlConnection.

System_CAPS_pubmethod SqlCommand

Initializes a new instance of the SqlCommand class with the text of the query, a SqlConnection, and the SqlTransaction.

System_CAPS_pubmethod SqlCommand

Initializes a new instance of the SqlCommand class with specified command text, connection, transaction, and encryption setting.

Properties
NameDescription
System_CAPS_pubproperty

Gets or sets the column encryption setting for this command.

System_CAPS_pubproperty

Gets or sets the Transact-SQL statement, table name or stored procedure to execute at the data source.(Overrides .)

System_CAPS_pubproperty

Gets or sets the wait time before terminating the attempt to execute a command and generating an error.(Overrides .)

System_CAPS_pubproperty

Gets or sets a value indicating how the property is to be interpreted.(Overrides .)

System_CAPS_pubproperty

Gets or sets the SqlConnection used by this instance of the SqlCommand.

System_CAPS_pubproperty

Gets the IContainer that contains the Component.(Inherited from Component.)

System_CAPS_pubproperty

Gets or sets a value indicating whether the command object should be visible in a Windows Form Designer control.(Overrides .)

System_CAPS_pubproperty

Gets or sets a value that specifies the SqlNotificationRequest object bound to this command.

System_CAPS_pubproperty

Gets or sets a value indicating whether the application should automatically receive query notifications from a common SqlDependency object.

System_CAPS_pubproperty
System_CAPS_pubproperty

Gets or sets the ISite of the Component.(Inherited from Component.)

System_CAPS_pubproperty

Gets or sets the SqlTransaction within which the SqlCommand executes.

System_CAPS_pubproperty

Gets or sets how command results are applied to the DataRow when used by the Update method of the DbDataAdapter.(Overrides .)

Methods
NameDescription
System_CAPS_pubmethod BeginExecuteNonQuery

Initiates the asynchronous execution of the Transact-SQL statement or stored procedure that is described by this SqlCommand.

System_CAPS_pubmethod BeginExecuteNonQuery

Initiates the asynchronous execution of the Transact-SQL statement or stored procedure that is described by this SqlCommand, given a callback procedure and state information.

System_CAPS_pubmethod BeginExecuteReader

Initiates the asynchronous execution of the Transact-SQL statement or stored procedure that is described by this SqlCommand, and retrieves one or more result sets from the server.

System_CAPS_pubmethod BeginExecuteReader

Initiates the asynchronous execution of the Transact-SQL statement or stored procedure that is described by this SqlCommand and retrieves one or more result sets from the server, given a callback procedure and state information.

System_CAPS_pubmethod BeginExecuteReader

Initiates the asynchronous execution of the Transact-SQL statement or stored procedure that is described by this SqlCommand, using one of the CommandBehavior values, and retrieving one or more result sets from the server, given a callback procedure and state information.

System_CAPS_pubmethod BeginExecuteReader

Initiates the asynchronous execution of the Transact-SQL statement or stored procedure that is described by this SqlCommand using one of the CommandBehavior values.

System_CAPS_pubmethod BeginExecuteXmlReader

Initiates the asynchronous execution of the Transact-SQL statement or stored procedure that is described by this SqlCommand and returns results as an XmlReader object.

System_CAPS_pubmethod BeginExecuteXmlReader

Initiates the asynchronous execution of the Transact-SQL statement or stored procedure that is described by this SqlCommand and returns results as an XmlReader object, using a callback procedure.

System_CAPS_pubmethod Cancel

Tries to cancel the execution of a SqlCommand.(Overrides DbCommandCancel.)

System_CAPS_pubmethod Clone

Creates a new SqlCommand object that is a copy of the current instance.

System_CAPS_pubmethod CreateObjRef

Creates an object that contains all the relevant information required to generate a proxy used to communicate with a remote object.(Inherited from MarshalByRefObject.)

System_CAPS_pubmethod CreateParameter

Creates a new instance of a SqlParameter object.

System_CAPS_pubmethod Dispose

Releases all resources used by the Component.(Inherited from Component.)

System_CAPS_pubmethod EndExecuteNonQuery

Finishes asynchronous execution of a Transact-SQL statement.

System_CAPS_pubmethod EndExecuteReader

Finishes asynchronous execution of a Transact-SQL statement, returning the requested SqlDataReader.

System_CAPS_pubmethod EndExecuteXmlReader

Finishes asynchronous execution of a Transact-SQL statement, returning the requested data as XML.

System_CAPS_pubmethod Equals

Determines whether the specified object is equal to the current object.(Inherited from Object.)

System_CAPS_pubmethod ExecuteNonQuery

Executes a Transact-SQL statement against the connection and returns the number of rows affected.(Overrides DbCommandExecuteNonQuery.)

System_CAPS_pubmethod ExecuteNonQueryAsync

An asynchronous version of ExecuteNonQuery, which executes a SQL statement against a connection object.

Invokes ExecuteNonQueryAsync with CancellationToken.None.(Inherited from DbCommand.)

System_CAPS_pubmethod ExecuteNonQueryAsync

An asynchronous version of ExecuteNonQuery, which executes a Transact-SQL statement against the connection and returns the number of rows affected. The cancellation token can be used to request that the operation be abandoned before the command timeout elapses. Exceptions will be reported via the returned Task object.(Overrides DbCommandExecuteNonQueryAsync.)

System_CAPS_pubmethod ExecuteReader

Sends the to the and builds a SqlDataReader.

System_CAPS_pubmethod ExecuteReader

Sends the to the , and builds a SqlDataReader using one of the CommandBehavior values.

System_CAPS_pubmethod ExecuteReaderAsync

An asynchronous version of ExecuteReader, which sends the to the and builds a SqlDataReader. Exceptions will be reported via the returned Task object.

System_CAPS_pubmethod ExecuteReaderAsync

An asynchronous version of ExecuteReader, which sends the to the and builds a SqlDataReader.

The cancellation token can be used to request that the operation be abandoned before the command timeout elapses. Exceptions will be reported via the returned Task object.

System_CAPS_pubmethod ExecuteReaderAsync

An asynchronous version of ExecuteReader, which sends the to the , and builds a SqlDataReader. Exceptions will be reported via the returned Task object.

System_CAPS_pubmethod ExecuteReaderAsync

An asynchronous version of ExecuteReader, which sends the to the , and builds a SqlDataReader

The cancellation token can be used to request that the operation be abandoned before the command timeout elapses. Exceptions will be reported via the returned Task object.

System_CAPS_pubmethod ExecuteScalar

Executes the query, and returns the first column of the first row in the result set returned by the query. Additional columns or rows are ignored.(Overrides DbCommandExecuteScalar.)

System_CAPS_pubmethod ExecuteScalarAsync

An asynchronous version of ExecuteScalar, which executes the query and returns the first column of the first row in the result set returned by the query. All other columns and rows are ignored.

Invokes ExecuteScalarAsync with CancellationToken.None.(Inherited from DbCommand.)

System_CAPS_pubmethod ExecuteScalarAsync

An asynchronous version of ExecuteScalar, which executes the query asynchronously and returns the first column of the first row in the result set returned by the query. Additional columns or rows are ignored.

The cancellation token can be used to request that the operation be abandoned before the command timeout elapses. Exceptions will be reported via the returned Task object.(Overrides DbCommandExecuteScalarAsync.)

System_CAPS_pubmethod ExecuteXmlReader

Sends the to the and builds an XmlReader object.

System_CAPS_pubmethod ExecuteXmlReaderAsync

An asynchronous version of ExecuteXmlReader, which sends the to the and builds an XmlReader object.

Exceptions will be reported via the returned Task object.

System_CAPS_pubmethod ExecuteXmlReaderAsync

An asynchronous version of ExecuteXmlReader, which sends the to the and builds an XmlReader object.

The cancellation token can be used to request that the operation be abandoned before the command timeout elapses. Exceptions will be reported via the returned Task object.

System_CAPS_pubmethod GetHashCode

Serves as the default hash function. (Inherited from Object.)

System_CAPS_pubmethod GetLifetimeService

Retrieves the current lifetime service object that controls the lifetime policy for this instance.(Inherited from MarshalByRefObject.)

System_CAPS_pubmethod GetType

Gets the Type of the current instance.(Inherited from Object.)

System_CAPS_pubmethod InitializeLifetimeService

Obtains a lifetime service object to control the lifetime policy for this instance.(Inherited from MarshalByRefObject.)

System_CAPS_pubmethod Prepare

Creates a prepared version of the command on an instance of SQL Server.(Overrides DbCommandPrepare.)

System_CAPS_pubmethod ResetCommandTimeout

Resets the property to its default value.

System_CAPS_pubmethod ToString

Returns a String containing the name of the Component, if any. This method should not be overridden.(Inherited from Component.)

Events
NameDescription
System_CAPS_pubevent Disposed

Occurs when the component is disposed by a call to the Dispose method. (Inherited from Component.)

System_CAPS_pubevent StatementCompleted

Occurs when the execution of a Transact-SQL statement completes.

Explicit Interface Implementations
NameDescription
System_CAPS_pubinterface System_CAPS_privmethod IDbCommandCreateParameter

Creates a new instance of an IDbDataParameter object.(Inherited from DbCommand.)

System_CAPS_pubinterface System_CAPS_privmethod IDbCommandExecuteReader

Executes the against the and builds an IDataReader.(Inherited from DbCommand.)

System_CAPS_pubinterface System_CAPS_privmethod IDbCommandExecuteReader

Executes the against the , and builds an IDataReader using one of the CommandBehavior values.(Inherited from DbCommand.)

System_CAPS_pubinterface System_CAPS_privmethod ICloneableClone

Creates a new SqlCommand object that is a copy of the current instance.

System_CAPS_pubinterface System_CAPS_privproperty

Gets or sets the IDbConnection used by this instance of the IDbCommand.(Inherited from DbCommand.)

System_CAPS_pubinterface System_CAPS_privproperty

Gets the IDataParameterCollection.(Inherited from DbCommand.)

System_CAPS_pubinterface System_CAPS_privproperty

Gets or sets the within which this DbCommand object executes.(Inherited from DbCommand.)

Remarks

When an instance of SqlCommand is created, the read/write properties are set to their initial values. For a list of these values, see the SqlCommand constructor.

SqlCommand features the following methods for executing commands at a SQL Server database:

Item

Description

BeginExecuteNonQuery

Initiates the asynchronous execution of the Transact-SQL statement or stored procedure that is described by this SqlCommand, generally executing commands such as INSERT, DELETE, UPDATE, and SET statements. Each call to BeginExecuteNonQuery must be paired with a call to EndExecuteNonQuery which finishes the operation, typically on a separate thread.

BeginExecuteReader

Initiates the asynchronous execution of the Transact-SQL statement or stored procedure that is described by this SqlCommand and retrieves one or more results sets from the server. Each call to BeginExecuteReader must be paired with a call to EndExecuteReader which finishes the operation, typically on a separate thread.

BeginExecuteXmlReader

Initiates the asynchronous execution of the Transact-SQL statement or stored procedure that is described by this SqlCommand. Each call to BeginExecuteXmlReader must be paired with a call to EndExecuteXmlReader, which finishes the operation, typically on a separate thread, and returns an XmlReader object.

ExecuteReader

Executes commands that return rows. For increased performance, ExecuteReader invokes commands using the Transact-SQL sp_executesql system stored procedure. Therefore, ExecuteReader might not have the effect that you want if used to execute commands such as Transact-SQL SET statements.

ExecuteNonQuery

Executes commands such as Transact-SQL INSERT, DELETE, UPDATE, and SET statements.

ExecuteScalar

Retrieves a single value (for example, an aggregate value) from a database.

ExecuteXmlReader

Sends the to the and builds an XmlReader object.

You can reset the property and reuse the SqlCommand object. However, you must close the SqlDataReader before you can execute a new or previous command.

If a SqlException is generated by the method executing a SqlCommand, the SqlConnection remains open when the severity level is 19 or less. When the severity level is 20 or greater, the server ordinarily closes the SqlConnection. However, the user can reopen the connection and continue.

System_CAPS_noteNote

Nameless, also called ordinal, parameters are not supported by the .NET Framework Data Provider for SQL Server.

Examples

The following example creates a SqlConnection, a SqlCommand, and a SqlDataReader. The example reads through the data, writing it to the console. Finally, the example closes the SqlDataReader and then the SqlConnection as it exits the Using code blocks.

private static void ReadOrderData(string connectionString)
{
    string queryString = 
        "SELECT OrderID, CustomerID FROM dbo.Orders;";
    using (SqlConnection connection = new SqlConnection(
               connectionString))
    {
        SqlCommand command = new SqlCommand(
            queryString, connection);
        connection.Open();
        SqlDataReader reader = command.ExecuteReader();
        try
        {
            while (reader.Read())
            {
                Console.WriteLine(String.Format("{0}, {1}",
                    reader[0], reader[1]));
            }
        }
        finally
        {
            // Always call Close when done reading.
            reader.Close();
        }
    }
}
Public Sub ReadOrderData(ByVal connectionString As String)
    Dim queryString As String = _
        "SELECT OrderID, CustomerID FROM dbo.Orders;"
    Using connection As New SqlConnection(connectionString)
        Dim command As New SqlCommand(queryString, connection)
        connection.Open()
        Dim reader As SqlDataReader = command.ExecuteReader()
        Try
            While reader.Read()
                Console.WriteLine(String.Format("{0}, {1}", _
                    reader(0), reader(1)))
            End While
        Finally
            ' Always call Close when done reading.
            reader.Close()
        End Try
    End Using
End Sub

The following sample shows how to create and execute different types of SqlCommand objects.

First you must create the sample database, by executing the following script:

USE [master]
GO

CREATE DATABASE [MySchool]
GO

USE [MySchool]
GO

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE procedure [dbo].[CourseExtInfo] @CourseId int
as
select c.CourseID,c.Title,c.Credits,d.Name as DepartmentName
from Course as c left outer join Department as d on c.DepartmentID=d.DepartmentID
where c.CourseID=@CourseId

GO

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
create procedure [dbo].[DepartmentInfo] @DepartmentId int,@CourseCount int output
as
select @CourseCount=Count(c.CourseID)
from course as c
where c.DepartmentID=@DepartmentId

select d.DepartmentID,d.Name,d.Budget,d.StartDate,d.Administrator
from Department as d
where d.DepartmentID=@DepartmentId

GO

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
Create PROCEDURE [dbo].[GetDepartmentsOfSpecifiedYear] 
@Year int,@BudgetSum money output
AS
BEGIN
        SELECT @BudgetSum=SUM([Budget])
  FROM [MySchool].[dbo].[Department]
  Where YEAR([StartDate])=@Year 

SELECT [DepartmentID]
      ,[Name]
      ,[Budget]
      ,[StartDate]
      ,[Administrator]
  FROM [MySchool].[dbo].[Department]
  Where YEAR([StartDate])=@Year

END
GO

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[Course](
[CourseID] [nvarchar](10) NOT NULL,
[Year] [smallint] NOT NULL,
[Title] [nvarchar](100) NOT NULL,
[Credits] [int] NOT NULL,
[DepartmentID] [int] NOT NULL,
 CONSTRAINT [PK_Course] PRIMARY KEY CLUSTERED 
(
[CourseID] ASC,
[Year] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[Department](
[DepartmentID] [int] IDENTITY(1,1) NOT NULL,
[Name] [nvarchar](50) NOT NULL,
[Budget] [money] NOT NULL,
[StartDate] [datetime] NOT NULL,
[Administrator] [int] NULL,
 CONSTRAINT [PK_Department] PRIMARY KEY CLUSTERED 
(
[DepartmentID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[Person](
[PersonID] [int] IDENTITY(1,1) NOT NULL,
[LastName] [nvarchar](50) NOT NULL,
[FirstName] [nvarchar](50) NOT NULL,
[HireDate] [datetime] NULL,
[EnrollmentDate] [datetime] NULL,
 CONSTRAINT [PK_School.Student] PRIMARY KEY CLUSTERED 
(
[PersonID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[StudentGrade](
[EnrollmentID] [int] IDENTITY(1,1) NOT NULL,
[CourseID] [nvarchar](10) NOT NULL,
[StudentID] [int] NOT NULL,
[Grade] [decimal](3, 2) NOT NULL,
 CONSTRAINT [PK_StudentGrade] PRIMARY KEY CLUSTERED 
(
[EnrollmentID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
create view [dbo].[EnglishCourse]
as
select c.CourseID,c.Title,c.Credits,c.DepartmentID
from Course as c join Department as d on c.DepartmentID=d.DepartmentID
where d.Name=N'English'

GO
INSERT [dbo].[Course] ([CourseID], [Year], [Title], [Credits], [DepartmentID]) VALUES (N'C1045', 2012, N'Calculus', 4, 7)
INSERT [dbo].[Course] ([CourseID], [Year], [Title], [Credits], [DepartmentID]) VALUES (N'C1061', 2012, N'Physics', 4, 1)
INSERT [dbo].[Course] ([CourseID], [Year], [Title], [Credits], [DepartmentID]) VALUES (N'C2021', 2012, N'Composition', 3, 2)
INSERT [dbo].[Course] ([CourseID], [Year], [Title], [Credits], [DepartmentID]) VALUES (N'C2042', 2012, N'Literature', 4, 2)
SET IDENTITY_INSERT [dbo].[Department] ON 

INSERT [dbo].[Department] ([DepartmentID], [Name], [Budget], [StartDate], [Administrator]) VALUES (1, N'Engineering', 350000.0000, CAST(0x0000999C00000000 AS DateTime), 2)
INSERT [dbo].[Department] ([DepartmentID], [Name], [Budget], [StartDate], [Administrator]) VALUES (2, N'English', 120000.0000, CAST(0x0000999C00000000 AS DateTime), 6)
INSERT [dbo].[Department] ([DepartmentID], [Name], [Budget], [StartDate], [Administrator]) VALUES (4, N'Economics', 200000.0000, CAST(0x0000999C00000000 AS DateTime), 4)
INSERT [dbo].[Department] ([DepartmentID], [Name], [Budget], [StartDate], [Administrator]) VALUES (7, N'Mathematics', 250024.0000, CAST(0x0000999C00000000 AS DateTime), 3)
SET IDENTITY_INSERT [dbo].[Department] OFF
SET IDENTITY_INSERT [dbo].[Person] ON 

INSERT [dbo].[Person] ([PersonID], [LastName], [FirstName], [HireDate], [EnrollmentDate]) VALUES (1, N'Hu', N'Nan', NULL, CAST(0x0000A0BF00000000 AS DateTime))
INSERT [dbo].[Person] ([PersonID], [LastName], [FirstName], [HireDate], [EnrollmentDate]) VALUES (2, N'Norman', N'Laura', NULL, CAST(0x0000A0BF00000000 AS DateTime))
INSERT [dbo].[Person] ([PersonID], [LastName], [FirstName], [HireDate], [EnrollmentDate]) VALUES (3, N'Olivotto', N'Nino', NULL, CAST(0x0000A0BF00000000 AS DateTime))
INSERT [dbo].[Person] ([PersonID], [LastName], [FirstName], [HireDate], [EnrollmentDate]) VALUES (4, N'Anand', N'Arturo', NULL, CAST(0x0000A0BF00000000 AS DateTime))
INSERT [dbo].[Person] ([PersonID], [LastName], [FirstName], [HireDate], [EnrollmentDate]) VALUES (5, N'Jai', N'Damien', NULL, CAST(0x0000A0BF00000000 AS DateTime))
INSERT [dbo].[Person] ([PersonID], [LastName], [FirstName], [HireDate], [EnrollmentDate]) VALUES (6, N'Holt', N'Roger', CAST(0x000097F100000000 AS DateTime), NULL)
INSERT [dbo].[Person] ([PersonID], [LastName], [FirstName], [HireDate], [EnrollmentDate]) VALUES (7, N'Martin', N'Randall', CAST(0x00008B1A00000000 AS DateTime), NULL)
SET IDENTITY_INSERT [dbo].[Person] OFF
SET IDENTITY_INSERT [dbo].[StudentGrade] ON 

INSERT [dbo].[StudentGrade] ([EnrollmentID], [CourseID], [StudentID], [Grade]) VALUES (1, N'C1045', 1, CAST(3.50 AS Decimal(3, 2)))
INSERT [dbo].[StudentGrade] ([EnrollmentID], [CourseID], [StudentID], [Grade]) VALUES (2, N'C1045', 2, CAST(3.00 AS Decimal(3, 2)))
INSERT [dbo].[StudentGrade] ([EnrollmentID], [CourseID], [StudentID], [Grade]) VALUES (3, N'C1045', 3, CAST(2.50 AS Decimal(3, 2)))
INSERT [dbo].[StudentGrade] ([EnrollmentID], [CourseID], [StudentID], [Grade]) VALUES (4, N'C1045', 4, CAST(4.00 AS Decimal(3, 2)))
INSERT [dbo].[StudentGrade] ([EnrollmentID], [CourseID], [StudentID], [Grade]) VALUES (5, N'C1045', 5, CAST(3.50 AS Decimal(3, 2)))
INSERT [dbo].[StudentGrade] ([EnrollmentID], [CourseID], [StudentID], [Grade]) VALUES (6, N'C1061', 1, CAST(4.00 AS Decimal(3, 2)))
INSERT [dbo].[StudentGrade] ([EnrollmentID], [CourseID], [StudentID], [Grade]) VALUES (7, N'C1061', 3, CAST(3.50 AS Decimal(3, 2)))
INSERT [dbo].[StudentGrade] ([EnrollmentID], [CourseID], [StudentID], [Grade]) VALUES (8, N'C1061', 4, CAST(2.50 AS Decimal(3, 2)))
INSERT [dbo].[StudentGrade] ([EnrollmentID], [CourseID], [StudentID], [Grade]) VALUES (9, N'C1061', 5, CAST(1.50 AS Decimal(3, 2)))
INSERT [dbo].[StudentGrade] ([EnrollmentID], [CourseID], [StudentID], [Grade]) VALUES (10, N'C2021', 1, CAST(2.50 AS Decimal(3, 2)))
INSERT [dbo].[StudentGrade] ([EnrollmentID], [CourseID], [StudentID], [Grade]) VALUES (11, N'C2021', 2, CAST(3.50 AS Decimal(3, 2)))
INSERT [dbo].[StudentGrade] ([EnrollmentID], [CourseID], [StudentID], [Grade]) VALUES (12, N'C2021', 4, CAST(3.00 AS Decimal(3, 2)))
INSERT [dbo].[StudentGrade] ([EnrollmentID], [CourseID], [StudentID], [Grade]) VALUES (13, N'C2021', 5, CAST(3.00 AS Decimal(3, 2)))
INSERT [dbo].[StudentGrade] ([EnrollmentID], [CourseID], [StudentID], [Grade]) VALUES (14, N'C2042', 1, CAST(2.00 AS Decimal(3, 2)))
INSERT [dbo].[StudentGrade] ([EnrollmentID], [CourseID], [StudentID], [Grade]) VALUES (15, N'C2042', 2, CAST(3.50 AS Decimal(3, 2)))
INSERT [dbo].[StudentGrade] ([EnrollmentID], [CourseID], [StudentID], [Grade]) VALUES (16, N'C2042', 3, CAST(4.00 AS Decimal(3, 2)))
INSERT [dbo].[StudentGrade] ([EnrollmentID], [CourseID], [StudentID], [Grade]) VALUES (17, N'C2042', 5, CAST(3.00 AS Decimal(3, 2)))
SET IDENTITY_INSERT [dbo].[StudentGrade] OFF
ALTER TABLE [dbo].[Course]  WITH CHECK ADD  CONSTRAINT [FK_Course_Department] FOREIGN KEY([DepartmentID])
REFERENCES [dbo].[Department] ([DepartmentID])
GO
ALTER TABLE [dbo].[Course] CHECK CONSTRAINT [FK_Course_Department]
GO
ALTER TABLE [dbo].[StudentGrade]  WITH CHECK ADD  CONSTRAINT [FK_StudentGrade_Student] FOREIGN KEY([StudentID])
REFERENCES [dbo].[Person] ([PersonID])
GO
ALTER TABLE [dbo].[StudentGrade] CHECK CONSTRAINT [FK_StudentGrade_Student]
GO

Next, compile and execute the following:

using System;
using System.Data;
using System.Data.SqlClient;
using System.Threading.Tasks;

class Program {

   static class SqlHelper {
      // Set the connection, command, and then execute the command with non query.
      public static Int32 ExecuteNonQuery(String connectionString, String commandText,
          CommandType commandType, params SqlParameter[] parameters) {
         using (SqlConnection conn = new SqlConnection(connectionString)) {
            using (SqlCommand cmd = new SqlCommand(commandText, conn)) {
               // There're three command types: StoredProcedure, Text, TableDirect. The TableDirect 
               // type is only for OLE DB.  
               cmd.CommandType = commandType;
               cmd.Parameters.AddRange(parameters);

               conn.Open();
               return cmd.ExecuteNonQuery();
            }
         }
      }

      // Set the connection, command, and then execute the command and only return one value.
      public static Object ExecuteScalar(String connectionString, String commandText,
          CommandType commandType, params SqlParameter[] parameters) {
         using (SqlConnection conn = new SqlConnection(connectionString)) {
            using (SqlCommand cmd = new SqlCommand(commandText, conn)) {
               cmd.CommandType = commandType;
               cmd.Parameters.AddRange(parameters);

               conn.Open();
               return cmd.ExecuteScalar();
            }
         }
      }

      // Set the connection, command, and then execute the command with query and return the reader.
      public static SqlDataReader ExecuteReader(String connectionString, String commandText,
          CommandType commandType, params SqlParameter[] parameters) {
         SqlConnection conn = new SqlConnection(connectionString);

         using (SqlCommand cmd = new SqlCommand(commandText, conn)) {
            cmd.CommandType = commandType;
            cmd.Parameters.AddRange(parameters);

            conn.Open();
            // When using CommandBehavior.CloseConnection, the connection will be closed when the 
            // IDataReader is closed.
            SqlDataReader reader = cmd.ExecuteReader(CommandBehavior.CloseConnection);

            return reader;
         }
      }
   }

   static void Main(string[] args) {
      String connectionString = "Data Source=(local);Initial Catalog=MySchool;Integrated Security=True;Asynchronous Processing=true;";

      CountCourses(connectionString, 2012);
      Console.WriteLine();

      Console.WriteLine("Following result is the departments that started from 2007:");
      GetDepartments(connectionString, 2007);
      Console.WriteLine();

      Console.WriteLine("Add the credits when the credits of course is lower than 4.");
      AddCredits(connectionString, 4);
      Console.WriteLine();

      Console.WriteLine("Please press any key to exit...");
      Console.ReadKey();
   }

   static void CountCourses(String connectionString, Int32 year) {
      String commandText = "Select Count([CourseID]) FROM [MySchool].[dbo].[Course] Where Year=@Year";
      SqlParameter parameterYear = new SqlParameter("@Year", SqlDbType.Int);
      parameterYear.Value = year;

      Object oValue = SqlHelper.ExecuteScalar(connectionString, commandText, CommandType.Text, parameterYear);
      Int32 count;
      if (Int32.TryParse(oValue.ToString(), out count))
         Console.WriteLine("There {0} {1} course{2} in {3}.", count > 1 ? "are" : "is", count, count > 1 ? "s" : null, year);
   }

   // Display the Departments that start from the specified year.
   static void GetDepartments(String connectionString, Int32 year) {
      String commandText = "dbo.GetDepartmentsOfSpecifiedYear";

      // Specify the year of StartDate
      SqlParameter parameterYear = new SqlParameter("@Year", SqlDbType.Int);
      parameterYear.Value = year;

      // When the direction of parameter is set as Output, you can get the value after 
      // executing the command.
      SqlParameter parameterBudget = new SqlParameter("@BudgetSum", SqlDbType.Money);
      parameterBudget.Direction = ParameterDirection.Output;

      using (SqlDataReader reader = SqlHelper.ExecuteReader(connectionString, commandText,
          CommandType.StoredProcedure, parameterYear, parameterBudget)) {
         Console.WriteLine("{0,-20}{1,-20}{2,-20}{3,-20}", "Name", "Budget", "StartDate",
             "Administrator");
         while (reader.Read()) {
            Console.WriteLine("{0,-20}{1,-20:C}{2,-20:d}{3,-20}", reader["Name"],
                reader["Budget"], reader["StartDate"], reader["Administrator"]);
         }
      }
      Console.WriteLine("{0,-20}{1,-20:C}", "Sum:", parameterBudget.Value);
   }

   // If credits of course is lower than the certain value, the method will add the credits.
   static void AddCredits(String connectionString, Int32 creditsLow) {
      String commandText = "Update [MySchool].[dbo].[Course] Set Credits=Credits+1 Where Credits<@Credits";

      SqlParameter parameterCredits = new SqlParameter("@Credits", creditsLow);

      Int32 rows = SqlHelper.ExecuteNonQuery(connectionString, commandText, CommandType.Text, parameterCredits);

      Console.WriteLine("{0} row{1} {2} updated.", rows, rows > 1 ? "s" : null, rows > 1 ? "are" : "is");
   }
}
Version Information
Universal Windows Platform
Available since 10
.NET Framework
Available since 1.1
Thread Safety

Any public static (Shared in Visual Basic) members of this type are thread safe. Any instance members are not guaranteed to be thread safe.

Return to top