有時候,在資料庫中建立、更新或刪除一組數據列會很有用。 有數種方法可用來達成該目標。 其中一個是使用 CLR 整合使用者定義資料類型,將資訊陣列從客戶端傳遞至伺服器上的 Common Language Runtime (CLR) 整合預存程式。 這類使用者定義數據類型的性質會將提供給伺服器的數據大小限製為8000個字節。 因此,此方法對大型或複雜數據不盡如人意。 如果所作的數據很小且簡單,這個方法比針對每個數據列呼叫預存程式更有效率。 藉由傳遞陣列,數據的順序會保留給順序很重要的應用程式。此範例包含下列專案:
ContactTypeNames使用者定義數據類型。 這包含所需聯繫人類型名稱的清單。實
usp_EnsureContactTypeNames作為 Microsoft Visual C# 或 Microsoft Visual Basic 方法的預存程式。 這會接受使用者定義數據類型的ContactTypeNames實例,並在數據表中Person.ContactType插入新的數據列,以取得任何包含在數據表中尚未存在於使用者定義數據類型實例中的聯繫人名稱。主控台
TestArrayParameter應用程式。 這會根據傳入的命令行參數建立使用者定義數據類型的ContactTypeNames實例,然後將使用者定義的數據類型實例當做參數傳遞來叫usp_EnsureContactTypeNames用預存程式。
先決條件
若要建立並執行此專案,必須安裝下列軟體:
SQL Server 或 SQL Server Express。 您可以從 SQL Server Express 檔和範例網站免費取得 SQL Server Express
SQL Server 開發人員網站提供的 AdventureWorks 資料庫
.NET Framework SDK 2.0 或更新版本或Microsoft Visual Studio 2005 或更新版本。 您可以免費取得 .NET Framework SDK。
此外,必須符合下列條件:
您使用的 SQL Server 實例必須啟用 CLR 整合。
若要啟用 CLR 整合,請執行下列步驟:
啟用 CLR 整合
- 執行下列 Transact-SQL 命令:
sp_configure 'clr enabled', 1GORECONFIGUREGO備註
若要啟用 CLR,您必須具有
ALTER SETTINGS由 和sysadmin固定伺服器角色成員serveradmin隱含持有的伺服器層級許可權。AdventureWorks 資料庫必須安裝在您使用的 SQL Server 實例上。
如果您不是您使用之 SQL Server 實例的系統管理員,您必須有系統管理員授與 CreateAssembly 許可權才能完成安裝。
建立範例
使用下列指示建立並執行範例:
開啟 Visual Studio 或 .NET Framework 命令提示字元。
如有必要,請為您的範例建立目錄。 在此範例中,我們將使用 C:\MySample。
在 c:\MySample 中,建立
ContactTypeNames.vb(針對 Visual Basic 範例) 或ContactTypeNames.cs[C# 範例] ,並將適當的 Visual Basic 或 C# 範例程式代碼 (以下) 複製到 檔案中。視您選擇的語言而定,從命令行提示字元將範例程式代碼編譯為必要的元件,方法是執行下列其中一項。
Vbc /reference:C:\Windows\Microsoft.NET\Framework\v2.0.50727\System.Data.dll,C:\Windows\Microsoft.NET\Framework\v2.0.50727\System.dll,C:\Windows\Microsoft.NET\Framework\v2.0.50727\System.Xml.dll /target:library ContactTypeNames.vbCsc /reference:C:\Windows\Microsoft.NET\Framework\v2.0.50727\System.Data.dll /reference:C:\Windows\Microsoft.NET\Framework\v2.0.50727\System.dll /reference:C:\Windows\Microsoft.NET\Framework\v2.0.50727\System.Xml.dll /target:library ContactTypeNames.cs
在 c:\MySample 中,建立
Program.vb(針對 Visual Basic 範例) 或Program.cs[C# 範例] ,並將適當的 Visual Basic 或 C# 範例程式代碼 (以下) 複製到 檔案中。在 [程式] 檔案中找出適當的行(大約第 24 行),並以 SQL Server 實例的名稱取代
XXXDim connection As New SqlConnection("data source=XXX;initial catalog=AdventureWorks;Integrated Security=SSPI")using (SqlConnection connection = new SqlConnection("data source=XXX;initial catalog=AdventureWorks;Integrated Security=SSPI"))
根據您選擇的語言,從命令行提示字元將範例程式代碼編譯為必要的可執行檔,方法是執行下列其中一項。
vbc /reference:C:\Windows\Microsoft.NET\Framework\v2.0.50727\System.Data.dll,C:\Windows\Microsoft.NET\Framework\v2.0.50727\System.Deployment.dll,C:\Windows\Microsoft.NET\Framework\v2.0.50727\System.dll,C:\Windows\Microsoft.NET\Framework\v2.0.50727\System.Drawing.dll,C:\Windows\Microsoft.NET\Framework\v2.0.50727\System.Windows.Forms.dll,C:\Windows\Microsoft.NET\Framework\v2.0.50727\System.Xml.dll,C:\MySample\ContactTypeNames.dll /out:TestArrayParameter Program.vbCsc /reference:ContactTypeNames.dll /reference:C:\Windows\Microsoft.NET\Framework\v2.0.50727\System.Data.dll /reference:C:\Windows\Microsoft.NET\Framework\v2.0.50727\System.dll /reference:C:\Windows\Microsoft.NET\Framework\v2.0.50727\System.Xml.dll /out:TestArrayParameter.exe Program.cs
將 Transact-SQL 安裝程式代碼複製到檔案中,並將它儲存為
Install.sql範例目錄中。如果範例安裝在另一個 目錄中,請
C:\MySample\編輯Install.sql檔案,如指示指向該位置。執行 來部署元件、預存程式和函式
sqlcmd -E -I -i install.sql
在命令提示字元中執行下列程式代碼列來測試應用程式:
TestArrayParameter "Executive Sales Representative" "Executive Sales Manager"
將 Transact-SQL 清除文本複製到檔案中,並將其儲存為
cleanup.sql範例目錄中。使用下列命令執行腳本
sqlcmd -E -I -i cleanup.sql
範例程式碼
以下是此範例的程式代碼清單。
這是連結庫的程序代碼 ContactTypeNames.
C#
#region Using directives
using System;
using System.Data;
using System.Data.Sql;
using System.Data.SqlTypes;
using System.Collections;
using System.Collections.Generic;
using System.Text;
using System.Globalization;
using Microsoft.SqlServer.Server;
#endregion
// This class is used to demonstrate passing an array of a fairly small number of reasonably small strings
// to a CLR integration based stored procedure on the server. Because a UDT is limited to 8000 bytes
// this approach will not work well for large numbers of strings or long strings. See the contact
// creation stored procedure in the AdventureWorks CLR integration sample for an alternative approach
// using XML which does not have these limitations.
[Serializable]
[Microsoft.SqlServer.Server.SqlUserDefinedType(Microsoft.SqlServer.Server.Format.UserDefined, IsByteOrdered = true, MaxByteSize = 8000)]
public class ContactTypeNames : INullable, Microsoft.SqlServer.Server.IBinarySerialize
{
#region Constructors
private const int maxByteSize = 8000;
public ContactTypeNames()
{
}
public ContactTypeNames(string[] names)
{
int numberOfCharacters = 0;
foreach (string name in names)
{
if (name.Length == 0)
throw new ArgumentException("Zero length names are not allowed");
numberOfCharacters += name.Length;
}
int dataByteSize = numberOfCharacters*2 //UTF-16 characters take 2 bytes
+ names.Length*4 //Four byte header for each string
+ 4 //Four byte header for null string at end
+ 1; //One byte boolean for null flag
if (dataByteSize >= maxByteSize)
throw new ArgumentException(string.Format(CultureInfo.InvariantCulture, "Data provided occupies {0} bytes but only {1} bytes "
+ "are available", dataByteSize, maxByteSize));
this._names = names;
}
#endregion
#region Accessors
public string[] GetTypeNameArray()
{
//Don't let caller modify our copy of the array
return (string[])_names.Clone();
}
//This has an odd API because we can only define Transact-SQL functions on static methods.
[SqlFunctionAttribute(FillRowMethodName = "FillNameRow")]
public static IEnumerable GetContactTypeNames(ContactTypeNames names)
{
if (names == null)
throw new ArgumentNullException("names");
return names.GetTypeNameArray();
}
public static void FillNameRow(object nameArrayElement, out string contactName)
{
contactName = (string)nameArrayElement;
}
#endregion
#region String Conversions
/// <summary>
/// The string format for contact type names is a sequence of names separated by commas
/// </summary>
/// <param name="s">a string containing contact type names separated by commas</param>
/// <returns>An instance of contact type name containing the specified names</returns>
[Microsoft.SqlServer.Server.SqlMethod(DataAccess = Microsoft.SqlServer.Server.DataAccessKind.None, IsDeterministic = false, IsMutator = false, IsPrecise = false,
SystemDataAccess = Microsoft.SqlServer.Server.SystemDataAccessKind.None)]
public static ContactTypeNames Parse(SqlString s)
{
if (s.IsNull)
return Null;
return new ContactTypeNames(s.Value.Split(new char[] {','}));
}
/// <summary>
/// Convert the contact type names to a string
/// </summary>
/// <returns>The contact type names separated by commas</returns>
public override string ToString()
{
if (this.IsNull)
return null;
StringBuilder sb = new StringBuilder();
foreach (string name in _names)
{
if (sb.Length > 0) sb.Append(", ");
sb.Append(name);
}
return sb.ToString();
}
#endregion
#region INullable Members
public static ContactTypeNames Null
{
get
{
return new ContactTypeNames();
}
}
public bool IsNull
{
get
{
return _names == null;
}
}
#endregion
#region IBinarySerialize Members
//Format:
//Byte 1: Null flag (boolean) (true = null)
//Byte 2 - 7994: Strings with 4 byte length headers,
// last string is a zero length string.
//This format is in part dictated by how the BinaryWriter serializes strings. See
//the Microsoft .NET Framework documentation on System.IO.BinaryWriter for more details.
public void Read(System.IO.BinaryReader r)
{
if (r.ReadBoolean())
{
_names = null;
return;
}
List<String> nameList = new List<String>();
string name;
while ((name = r.ReadString()).Length != 0)
{
nameList.Add(name);
}
_names = new string[nameList.Count];
nameList.CopyTo(_names);
}
public void Write(System.IO.BinaryWriter w)
{
if (w == null)
throw new ArgumentNullException("w");
w.Write(this.IsNull);
foreach (string name in _names)
{
w.Write(name);
}
w.Write(string.Empty);
}
#endregion
#region Private Implementation
private string[] _names;
#endregion
}
Visual Basic
#Region "Using directives"
Imports System
Imports System.Data
Imports System.Data.Sql
Imports System.Data.SqlTypes
Imports System.Collections
Imports System.Collections.Generic
Imports System.Text
Imports System.Globalization
Imports Microsoft.SqlServer.Server
Imports System.Runtime.InteropServices
#End Region
' This class is used to demonstrate passing an array of a fairly small number of reasonably small strings
' to a CLR integration based stored procedure on the server. Because a UDT is limited to 8000 bytes
' this approach will not work well for large numbers of strings or long strings. See the contact
' creation stored procedure in the AdventureWorks CLR integration sample for an alternative approach
' using XML which does not have these limitations.
<Serializable()> _
<SqlUserDefinedType(Format.UserDefined, IsByteOrdered:=True, maxByteSize:=8000), CLSCompliant(False)> _
Public Class ContactTypeNames
Implements INullable, IBinarySerialize
#Region "Constructors"
Private Const maxByteSize As Integer = 8000
Public Sub New()
End Sub
Public Sub New(ByVal names() As String)
Dim numberOfCharacters As Integer = 0
For Each name As String In names
If name.Length = 0 Then
Throw New ArgumentException("Zero length names are not allowed")
End If
numberOfCharacters += name.Length
Next
'UTF-16 characters take 2 bytes
'Four byte header for each string
'Four byte header for null string at end
'One byte boolean for null flag
Dim dataByteSize As Integer = numberOfCharacters * 2 _
+ names.Length * 4 _
+ 4 _
+ 1
If dataByteSize >= maxByteSize Then
Throw New ArgumentException(String.Format(CultureInfo.InvariantCulture, _
"Data provided occupies {0} bytes but only {1} bytes are available", _
dataByteSize, maxByteSize))
End If
Me._names = names
End Sub
#End Region
#Region "Accessors"
Public Function GetTypeNameArray() As String()
'Don't let caller modify our copy of the array
Return CType(Me._names.Clone(), String())
End Function
'This has an odd API because we can only define Transact-SQL functions on static methods.
<SqlFunction(FillRowMethodName:="FillNameRow", TableDefinition:="[Name] [Name]")> _
Public Shared Function GetContactTypeNames(ByVal names As ContactTypeNames) As IEnumerable
If names Is Nothing Then
Throw New ArgumentNullException("names")
End If
Return names.GetTypeNameArray()
End Function
Public Shared Sub FillNameRow(ByVal nameArrayElement As Object, <Out()> ByRef contactName As String)
contactName = CStr(nameArrayElement)
End Sub
#End Region
#Region "String Conversions"
''' <summary>
''' The string format for contact type names is a sequence of names separated by commas
''' </summary>
''' <param name="s">a string containing contact type names separated by commas</param>
''' <returns>An instance of contact type name containing the specified names</returns>
<Microsoft.SqlServer.Server.SqlMethod(DataAccess:=Microsoft.SqlServer.Server.DataAccessKind.None, IsDeterministic:=False, IsMutator:=False, IsPrecise:=False, SystemDataAccess:=Microsoft.SqlServer.Server.SystemDataAccessKind.None)> _
Public Shared Function Parse(ByVal s As SqlString) As ContactTypeNames
If s.IsNull Then
Return Nothing
End If
Return New ContactTypeNames(s.Value.Split(New Char() {","c}))
End Function
''' <summary>
''' Convert the contact type names to a string
''' </summary>
''' <returns>The contact type names separated by commas</returns>
Public Overrides Function ToString() As String
If Me.IsNull Then
Return Nothing
End If
Dim sb As New StringBuilder()
For Each name As String In Me._names
If sb.Length > 0 Then
sb.Append(", ")
End If
sb.Append(name)
Next name
Return sb.ToString()
End Function
#End Region
#Region "INullable Members"
Shared ReadOnly Property Null() As ContactTypeNames
Get
Return New ContactTypeNames()
End Get
End Property
Public ReadOnly Property IsNull() As Boolean Implements INullable.IsNull
Get
Return Me._names Is Nothing
End Get
End Property
#End Region
#Region "IBinarySerialize Members"
'Format:
'Byte 1: Null flag (boolean) (true = null)
'Byte 2 - 7994: Strings with 4 byte length headers,
' last string is a zero length string.
'This format is in part dictated by how the BinaryWriter serializes strings. See
'the Microsoft .NET Framework documentation on System.IO.BinaryWriter for more details.
Public Sub Read(ByVal r As System.IO.BinaryReader) Implements IBinarySerialize.Read
If r.ReadBoolean() Then
Me._names = Nothing
Return
End If
Dim nameList As New List(Of String)
Dim name As String = r.ReadString()
While name.Length <> 0
nameList.Add(name)
name = r.ReadString()
End While
Me._names = New String(nameList.Count - 1) {}
nameList.CopyTo(Me._names)
End Sub
Public Sub Write(ByVal w As System.IO.BinaryWriter) Implements IBinarySerialize.Write
If w Is Nothing Then
Throw New ArgumentNullException("w")
End If
w.Write(Me.IsNull)
For Each name As String In Me._names
w.Write(name)
Next
w.Write(String.Empty)
End Sub
#End Region
#Region "Private Implementation"
Private _names() As String
#End Region
End Class
這是測試可執行檔的程序代碼。
C#
#region Using directives
using System;
using System.Collections.Generic;
using System.Text;
using System.IO;
using System.Data;
using System.Data.Sql;
using System.Data.SqlTypes;
using System.Data.SqlClient;
#endregion
class Program
{
static void Main(string[] args)
{
if (args.Length == 0)
{
Console.WriteLine("Usage: TestArrayParameter contactTypeName1 "
+ "contactTypeName2 ... contactTypeNamen");
return;
}
using (SqlConnection connection = new SqlConnection("data source=XXX;initial catalog=AdventureWorks;Integrated Security=SSPI"))
{
connection.Open();
ShowTypeNames(connection, "before any inserts");
SqlCommand command = connection.CreateCommand();
command.CommandText = "usp_EnsureContactTypeNames";
command.CommandType = CommandType.StoredProcedure;
SqlParameter namesParameter = new SqlParameter("@names", SqlDbType.Udt);
namesParameter.UdtTypeName = "ContactTypeNames";
namesParameter.Value = new ContactTypeNames(args);
command.Parameters.Add(namesParameter);
command.ExecuteNonQuery();
ShowTypeNames(connection, "after any inserts");
}
}
private static void ShowTypeNames(SqlConnection connection, string whenRan)
{
SqlCommand command = connection.CreateCommand();
command.CommandText = "SELECT Name FROM Person.ContactType ORDER BY Name";
using (SqlDataReader reader = command.ExecuteReader())
{
Console.BackgroundColor = ConsoleColor.Blue;
Console.Write("Contact type names {0}: ", whenRan);
Console.ResetColor();
bool first = true;
while (reader.Read())
{
if (!first) Console.Write(", ");
Console.Write(reader[0].ToString());
first = false;
}
Console.WriteLine("");
Console.WriteLine("");
}
}
}
Visual Basic
#Region "Using directives"
Imports System
Imports System.Collections.Generic
Imports System.Text
Imports System.IO
Imports System.Data
Imports System.Data.Sql
Imports System.Data.SqlTypes
Imports System.Data.SqlClient
#End Region
Class Program
Shared Sub Main(ByVal args() As String)
If args.Length = 0 Then
Console.WriteLine("Usage: TestArrayParameter contactTypeName1 " _
+ "contactTypeName2 ... contactTypeNamen")
Return
End If
Dim connection As New SqlConnection("data source=XXX;initial catalog=AdventureWorks;Integrated Security=SSPI")
Try
connection.Open()
ShowTypeNames(connection, "Before any inserts")
Dim command As SqlCommand = connection.CreateCommand()
command.CommandText = "usp_EnsureContactTypeNames"
command.CommandType = CommandType.StoredProcedure
Dim namesParameter As New SqlParameter("@names", SqlDbType.Udt)
namesParameter.UdtTypeName = "ContactTypeNames"
namesParameter.Value = New ContactTypeNames(args)
command.Parameters.Add(namesParameter)
command.ExecuteNonQuery()
ShowTypeNames(connection, "After any inserts")
Finally
connection.Dispose()
End Try
End Sub
Private Shared Sub ShowTypeNames(ByVal connection As SqlConnection, ByVal whenRan As String)
Dim command As SqlCommand = connection.CreateCommand()
command.CommandText = "SELECT [Name] FROM [Person].[ContactType] ORDER BY Name"
Dim reader As SqlDataReader = command.ExecuteReader()
Try
Console.BackgroundColor = ConsoleColor.Blue
Console.Write("Contact type names {0}: ", whenRan)
Console.ResetColor()
Dim first As Boolean = True
While reader.Read()
If Not first Then
Console.Write(", ")
End If
Console.Write(reader(0).ToString())
first = False
End While
Console.WriteLine("")
Console.WriteLine("")
Finally
reader.Dispose()
End Try
End Sub
End Class
這是 Transact-SQL 安裝文本 (Install.sql),它會部署元件,並在資料庫中建立預存程式和函式。
USE AdventureWorks
GO
-- Drop existing sprocs, type, and assemblies if any.
IF EXISTS (SELECT * FROM sys.procedures WHERE [name] = 'usp_EnsureContactTypeNames')
DROP PROCEDURE usp_EnsureContactTypeNames;
GO
IF EXISTS (SELECT * FROM sys.objects WHERE [name] = N'GetContactTypeNames' and (type = 'FS' or type = 'FT'))
DROP FUNCTION [GetContactTypeNames];
GO
IF EXISTS (SELECT * FROM sys.types WHERE [name] = 'ContactTypeNames')
DROP TYPE ContactTypeNames;
GO
IF EXISTS (SELECT * FROM sys.assemblies WHERE [name] = 'ContactTypeNames')
DROP ASSEMBLY ContactTypeNames;
GO
-- Add assemblies, type, and sproc
DECLARE @SamplesPath nvarchar(1024)
-- You may need to modify the value of the this variable if you have installed the sample someplace other than the default location.
set @SamplesPath= 'C:\MySample\'
CREATE ASSEMBLY ContactTypeNames
FROM @SamplesPath + 'ContactTypeNames.dll'
WITH permission_set = Safe;
CREATE TYPE ContactTypeNames
EXTERNAL NAME ContactTypeNames.ContactTypeNames;
GO
CREATE FUNCTION GetContactTypeNames
(
@names dbo.ContactTypeNames
)
RETURNS TABLE
(
[Name] [Name]
)
AS EXTERNAL NAME [ContactTypeNames].[ContactTypeNames].[GetContactTypeNames];
GO
CREATE PROCEDURE usp_EnsureContactTypeNames
(
@names dbo.ContactTypeNames
)
AS
SET NOCOUNT ON;
INSERT Person.ContactType ([Name])
SELECT [Name] FROM GetContactTypeNames(@names) AS PotentialNames
WHERE [Name] NOT IN (SELECT [Name] FROM Person.ContactType);
GO
下列 Transact-SQL 會從資料庫移除元件和預存程式。
USE AdventureWorks
GO
DELETE Person.ContactType WHERE ContactTypeID > 20;
GO
-- Drop existing sprocs, type, and assemblies if any.
IF EXISTS (SELECT * FROM sys.procedures WHERE [name] = 'usp_EnsureContactTypeNames')
DROP PROCEDURE usp_EnsureContactTypeNames;
GO
IF EXISTS (SELECT * FROM sys.objects WHERE [name] = N'GetContactTypeNames' and (type = 'FS' or type = 'FT'))
DROP FUNCTION [GetContactTypeNames];
GO
IF EXISTS (SELECT * FROM sys.types WHERE [name] = 'ContactTypeNames')
DROP TYPE ContactTypeNames;
GO
IF EXISTS (SELECT * FROM sys.assemblies WHERE [name] = 'ContactTypeNames')
DROP ASSEMBLY ContactTypeNames;
GO