Catatan
Akses ke halaman ini memerlukan otorisasi. Anda dapat mencoba masuk atau mengubah direktori.
Akses ke halaman ini memerlukan otorisasi. Anda dapat mencoba mengubah direktori.
Sampel AssemblyCleanup berisi Prosedur Tersimpan .NET yang membersihkan rakitan yang tidak digunakan dalam database saat ini dengan mengkueri katalog metadata. Satu-satunya parameter, visible_assemblies, digunakan untuk menentukan apakah rakitan yang terlihat yang tidak digunakan harus dihilangkan atau tidak. Nilai 'false' berarti secara default hanya rakitan tak terlihat yang tidak digunakan yang akan dihilangkan, jika tidak, semua rakitan yang tidak digunakan akan dihilangkan. Kumpulan rakitan yang tidak digunakan adalah rakitan yang tidak memiliki titik masuk yang ditentukan (rutinitas / jenis dan agregat) dan tidak ada rakitan yang digunakan yang merujuknya secara langsung atau tidak langsung.
Prasyarat
Untuk membuat dan menjalankan proyek ini, perangkat lunak berikut harus diinstal:
SQL Server atau SQL Server Express. Anda dapat memperoleh SQL Server Express secara gratis dari SQL Server Express Documentation dan Samples Web site
Database AdventureWorks yang tersedia di situs Web Pengembang SQL Server
.NET Framework SDK 2.0 atau yang lebih baru atau Microsoft Visual Studio 2005 atau yang lebih baru. Anda dapat memperoleh .NET Framework SDK secara gratis.
Selain itu, kondisi berikut harus dipenuhi:
Instans SQL Server yang Anda gunakan harus mengaktifkan integrasi CLR.
Untuk mengaktifkan integrasi CLR, lakukan langkah-langkah berikut:
Mengaktifkan Integrasi CLR
- Jalankan perintah Transact-SQL berikut:
sp_configure 'clr enabled', 1GORECONFIGUREGONota
Untuk mengaktifkan CLR, Anda harus memiliki
ALTER SETTINGSizin tingkat server, yang secara implisit dipegang oleh anggotasysadminperan server tetap danserveradmin.Database AdventureWorks harus diinstal pada instans SQL Server yang Anda gunakan.
Jika Anda bukan administrator untuk instans SQL Server yang Anda gunakan, Anda harus memiliki administrator yang memberi Anda izin CreateAssembly untuk menyelesaikan penginstalan.
Membangun Sampel
Buat dan jalankan sampel dengan menggunakan instruksi berikut:
Buka perintah Visual Studio atau .NET Framework.
Jika perlu, buat direktori untuk sampel Anda. Untuk contoh ini, kita akan menggunakan C:\MySample.
Di c:\MySample, buat
AssemblyCleanup.vb(untuk sampel Visual Basic) atauAssemblyCleanup.cs(untuk sampel C#) dan salin kode sampel Visual Basic atau C# yang sesuai (di bawah) ke dalam file.Kompilasikan kode sampel dari prompt baris perintah dengan menjalankan salah satu hal berikut, tergantung pada pilihan bahasa Anda.
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.Transactions.dll,C:\Windows\Microsoft.NET\Framework\v2.0.50727\System.Xml.dll /target:library AssemblyCleanup.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 AssemblyCleanup.cs
Salin kode penginstalan Transact-SQL ke dalam file dan simpan seperti
Install.sqldi direktori sampel.Jika sampel diinstal di direktori lainnya,
C:\MySample\edit fileInstall.sqlseperti yang ditunjukkan untuk menunjuk ke lokasi tersebut.Menyebarkan prosedur rakitan dan tersimpan dengan menjalankan
sqlcmd -E -I -i install.sql
Salin Transact-SQL uji skrip perintah ke dalam file dan simpan seperti
test.sqldi direktori sampel.Jalankan skrip pengujian dengan perintah berikut
sqlcmd -E -I -i test.sql
Salin skrip pembersihan Transact-SQL ke dalam file dan simpan seperti
cleanup.sqldi direktori sampel.Jalankan skrip dengan perintah berikut
sqlcmd -E -I -i cleanup.sql
Contoh Kode
Berikut ini adalah daftar kode untuk sampel ini.
C#
using System;
using System.Text;
using System.Diagnostics;
using System.Data.SqlClient;
using System.Collections.Generic;
using System.Globalization;
using Microsoft.SqlServer.Server;
/// <summary>
/// Defines a CLR user defined function CleanupUnusedAssemblies that drops
/// all the invisible assemblies with no references.
/// </summary>
public sealed class AssemblyCleanup
{
private SqlTransaction transaction;
internal class AssemblySet
{
private Dictionary<int, object> m_dictionary;
/// <summary>
/// Initialize internal structures
/// </summary>
/// <returns></returns>
public AssemblySet()
{
m_dictionary = new Dictionary<int, object>();
}
/// <summary>
/// Adds an assembly id into the current AssemblySet if it is not
/// already part of it.
/// </summary>
/// <returns></returns>
public void Add(int assemblyId)
{
if (!m_dictionary.ContainsKey(assemblyId))
{
m_dictionary.Add(assemblyId, null);
}
}
/// <summary>
/// Number of assembly ids stored in this instance
/// </summary>
/// <returns></returns>
public int Count
{
get
{
return m_dictionary.Count;
}
}
/// <summary>
/// Returns the comma-separated list of assembly ids contained in this instance
/// </summary>
/// <returns>string value that represents a comma-separated list
/// of assembly ids</returns>
public string ToCommaSeparatedList()
{
StringBuilder sb = new StringBuilder();
if (m_dictionary.Count > 0)
{
foreach (KeyValuePair<int, object> kv in m_dictionary)
{
sb.Append(kv.Key);
sb.Append(",");
}
sb.Length--; // remove the trailing comma
}
return sb.ToString();
}
}
/// <summary>
/// Initializes an instance of AssemblyCleanup with a SqlTransaction
/// </summary>
/// <returns></returns>
private AssemblyCleanup(SqlTransaction transaction)
{
this.transaction = transaction;
}
/// <summary>
/// Helper function that creates a SqlCommand object as part of the current
/// transaction
/// </summary>
/// <returns></returns>
private SqlCommand CreateCommandInTransaction()
{
SqlCommand cmd = this.transaction.Connection.CreateCommand();
cmd.Transaction = this.transaction;
return cmd;
}
/// <summary>
/// Helper function that constructs an AssemblySet instance using the
/// first column of the resultset resulting from the query that was passed in.
/// </summary>
/// <param name="query"></param>
/// <returns></returns>
private AssemblySet GetAssemblySetFromQuery(string query)
{
SqlCommand cmd = CreateCommandInTransaction();
AssemblySet set = new AssemblySet();
cmd.CommandText = query;
using (SqlDataReader rd = cmd.ExecuteReader())
{
while (rd.Read())
{
set.Add(rd.GetInt32(0));
}
}
return set;
}
/// <summary>
/// Constructs a DROP ASSEMBLY T-SQL statement using the AssemblySet
/// passed in as a parameter.
/// </summary>
/// <param name="set"></param>
/// <returns></returns>
private void DropAssemblies(AssemblySet unusedAssemblySet)
{
if (unusedAssemblySet.Count > 0)
{
StringBuilder assemblyNamesToDrop = new StringBuilder();
// Gather the list of assembly names we will drop later
SqlCommand cmd = CreateCommandInTransaction();
cmd.CommandText = String.Format(CultureInfo.InvariantCulture,
"SELECT name FROM sys.assemblies WHERE assembly_id IN ({0});",
unusedAssemblySet.ToCommaSeparatedList());
using (SqlDataReader rd = cmd.ExecuteReader())
{
while (rd.Read())
{
assemblyNamesToDrop.Append("[");
assemblyNamesToDrop.Append(rd.GetString(0));
assemblyNamesToDrop.Append("],");
}
}
// Remove trailing comma
assemblyNamesToDrop.Length--;
// Drop all assemblies at the same time
cmd.CommandText = String.Format(CultureInfo.InvariantCulture,
"DROP ASSEMBLY {0}", assemblyNamesToDrop.ToString());
cmd.ExecuteNonQuery();
}
}
/// <summary>
/// Serves as the stored procedure entry point and drives the process
/// of expanding the "assemblies in use" set, negating it, and
/// dropping the results
/// </summary>
/// <param name="visibleAssemblies">If set to true, will also drop
/// unused visible assemblies. Otherwise, will only drop unused invisible
/// assemblies.</param>
/// <returns></returns>
[Microsoft.SqlServer.Server.SqlProcedure()]
public static void CleanupUnusedAssemblies(bool visibleAssemblies)
{
bool succeeded = false;
SqlConnection conn;
SqlTransaction transaction;
string sqlStatement;
AssemblySet assembliesToDrop;
AssemblyCleanup assemblyCleanup;
conn = new SqlConnection("context connection=true");
conn.Open();
transaction = conn.BeginTransaction();
try
{
// Create a set of assemblies in use by looking at
// the metadata of the current database
sqlStatement =
"DECLARE @UsedAssembly TABLE (AssemblyID int NOT NULL); " +
"DECLARE @RowCount int; " +
"INSERT INTO @UsedAssembly " +
"SELECT DISTINCT([assembly_id]) " +
"FROM sys.assembly_modules " +
"UNION " +
"SELECT [assembly_id] " +
"FROM sys.assembly_types; " +
"SET @RowCount = @@ROWCOUNT; " +
"WHILE @RowCount > 0 " +
"BEGIN " +
"INSERT INTO @UsedAssembly " +
"SELECT [referenced_assembly_id] " +
"FROM sys.assembly_references ar " +
"INNER JOIN @UsedAssembly ua " +
"ON ar.[assembly_id] = ua.AssemblyID " +
"WHERE NOT EXISTS (SELECT * FROM @UsedAssembly WHERE AssemblyID = [referenced_assembly_id]) " +
"SET @RowCount = @@ROWCOUNT; " +
"END;";
if (visibleAssemblies)
{
sqlStatement +=
"SELECT assembly_id " +
"FROM sys.assemblies " +
"WHERE assembly_id NOT IN (SELECT AssemblyID FROM @UsedAssembly);";
}
else
{
sqlStatement +=
"SELECT assembly_id " +
"FROM sys.assemblies " +
"WHERE assembly_id NOT IN (SELECT AssemblyID FROM @UsedAssembly) " +
" AND is_visible = 0;";
}
// This marks the beginning of the transaction
assemblyCleanup = new AssemblyCleanup(transaction);
// Assemblies that are currently in use
assembliesToDrop
= assemblyCleanup.GetAssemblySetFromQuery(sqlStatement);
assemblyCleanup.DropAssemblies(assembliesToDrop);
// Mark as succeeded
succeeded = true;
}
finally
{
// We must guarantee that we explicitly call either Commit()
// or Rollback() before we return.
if (succeeded)
{
transaction.Commit();
}
else
{
transaction.Rollback();
}
conn.Dispose();
}
}
}
Visual Basic
Imports Microsoft.SqlServer.Server
Imports Microsoft.VisualBasic
Imports System
Imports System.Collections
Imports System.Collections.Generic
Imports System.Data
Imports System.Data.SqlClient
Imports System.Diagnostics
Imports System.Globalization
Imports System.Text
Imports System.Transactions
Public NotInheritable Class AssemblyCleanup
Private transaction As SqlTransaction
Friend Class AssemblySet
Private m_dictionary As Dictionary(Of Integer, Object)
''' <summary>
''' Initialize internal structures
''' </summary>
''' <returns></returns>
Public Sub New()
m_dictionary = New Dictionary(Of Integer, Object)
End Sub
''' <summary>
''' Adds an assembly id into the current AssemblySet if it is not already part of it.
''' </summary>
''' <returns></returns>
Public Sub Add(ByVal assemblyId As Integer)
If Not m_dictionary.ContainsKey(assemblyId) Then
m_dictionary.Add(assemblyId, Nothing)
End If
End Sub
''' <summary>
''' Number of assembly ids stored in this instance
''' </summary>
''' <returns></returns>
Public ReadOnly Property Count() As Integer
Get
Return m_dictionary.Count
End Get
End Property
''' <summary>
''' Returns the comma-separated list of assembly ids contained in this instance
''' </summary>
''' <returns>string value that represents a comma-separated list of assembly ids</returns>
Public Function ToCommaSeparatedList() As String
Dim sb As New StringBuilder()
If m_dictionary.Count > 0 Then
For Each kv As KeyValuePair(Of Integer, Object) In m_dictionary
If (True) Then
sb.Append(kv.Key)
sb.Append(",")
End If
Next
sb.Length -= 1 ' remove the trailing comma
End If
Return sb.ToString()
End Function
End Class
''' <summary>
''' Initializes an instance of AssemblyCleanup with a SqlTransaction
''' </summary>
''' <returns></returns>
Private Sub New(ByVal trans As SqlTransaction)
Me.transaction = trans
End Sub
''' <summary>
''' Helper function that creates a SqlCommand object as part of the
''' current transaction
''' </summary>
''' <returns></returns>
Private Function CreateCommandInTransaction() As SqlCommand
Dim cmd As SqlCommand = transaction.Connection.CreateCommand()
cmd.Transaction = Me.transaction
Return cmd
End Function
''' <summary>
''' Helper function that constructs an AssemblySet instance using the
''' first column of the resultset resulting from the query that was passed in.
''' </summary>
''' <param name="query"></param>
''' <returns></returns>
Private Function GetAssemblySetFromQuery(ByVal query As String) As AssemblySet
Dim cmd As SqlCommand = CreateCommandInTransaction()
Dim [set] As New AssemblySet()
cmd.CommandText = query
Dim rd As SqlDataReader = cmd.ExecuteReader()
Try
While rd.Read()
[set].Add(rd.GetInt32(0))
End While
Finally
rd.Dispose()
End Try
Return [set]
End Function
''' <summary>
''' Constructs a DROP ASSEMBLY T-SQL statement using the AssemblySet
''' passed in as a parameter.
''' </summary>
''' <param name="set"></param>
''' <returns></returns>
Private Sub DropAssemblies(ByVal unusedAssemblySet As AssemblySet)
If unusedAssemblySet.Count > 0 Then
Dim assemblyNamesToDrop As New StringBuilder()
' Gather the list of assembly names we will drop later
Dim cmd As SqlCommand = CreateCommandInTransaction()
cmd.CommandText = String.Format(CultureInfo.InvariantCulture, _
"SELECT name FROM sys.assemblies WHERE assembly_id IN ({0});", _
unusedAssemblySet.ToCommaSeparatedList())
Dim rd As SqlDataReader = cmd.ExecuteReader()
Try
While rd.Read()
assemblyNamesToDrop.Append("[")
assemblyNamesToDrop.Append(rd.GetString(0))
assemblyNamesToDrop.Append("],")
End While
Finally
rd.Dispose()
End Try
' Remove trailing comma
assemblyNamesToDrop.Length -= 1
' Drop all assemblies at the same time
cmd.CommandText = String.Format(CultureInfo.InvariantCulture, _
"DROP ASSEMBLY {0}", assemblyNamesToDrop.ToString())
cmd.ExecuteNonQuery()
End If
End Sub
''' <summary>
''' Serves as the stored procedure entry point and drives the process of
''' expanding the "assemblies in use" set, negating it, and dropping
''' the results.
''' </summary>
''' <param name="visibleAssemblies">If set to true, will also drop unused
''' visible assemblies. Otherwise, will only drop unused invisible assemblies.</param>
''' <returns></returns>
<Microsoft.SqlServer.Server.SqlProcedure()> _
Public Shared Sub CleanupUnusedAssemblies(ByVal visibleAssemblies As Boolean)
Dim succeeded As Boolean = False
Dim conn As SqlConnection
Dim transaction As SqlTransaction
Dim sqlStatement As String
Dim assembliesToDrop As AssemblySet
Dim assemblyCleanup As AssemblyCleanup
conn = New SqlConnection("context connection=true")
conn.Open()
transaction = conn.BeginTransaction()
Try
' Create a set of assemblies in use by looking at
' the metadata of the current database
sqlStatement = "DECLARE @UsedAssembly TABLE (AssemblyID int NOT NULL); " & _
"DECLARE @RowCount int; " & _
"INSERT INTO @UsedAssembly " & _
"SELECT DISTINCT([assembly_id]) " & _
"FROM sys.assembly_modules " & _
"UNION " & _
"SELECT [assembly_id] " & _
"FROM sys.assembly_types; " & _
"SET @RowCount = @@ROWCOUNT; " & _
"WHILE @RowCount > 0 " & _
"BEGIN " & _
"INSERT INTO @UsedAssembly " & _
"SELECT [referenced_assembly_id] " & _
"FROM sys.assembly_references ar " & _
"INNER JOIN @UsedAssembly ua " & _
"ON ar.[assembly_id] = ua.AssemblyID " & _
"WHERE NOT EXISTS (SELECT * FROM @UsedAssembly WHERE AssemblyID = [referenced_assembly_id]) " & _
"SET @RowCount = @@ROWCOUNT; " & _
"END;"
If visibleAssemblies Then
sqlStatement += "SELECT assembly_id " & _
"FROM sys.assemblies " & _
"WHERE assembly_id NOT IN (SELECT AssemblyID FROM @UsedAssembly);"
Else
sqlStatement += "SELECT assembly_id " & _
"FROM sys.assemblies " & _
"WHERE assembly_id NOT IN (SELECT AssemblyID FROM @UsedAssembly) " & _
" AND is_visible = 0;"
End If
' This marks the beginning of the transaction
assemblyCleanup = New AssemblyCleanup(transaction)
' Assemblies that are currently in use
assembliesToDrop _
= assemblyCleanup.GetAssemblySetFromQuery(sqlStatement)
assemblyCleanup.DropAssemblies(assembliesToDrop)
' Mark as succeeded
succeeded = True
Finally
' We must guarantee that we explicitly call either Commit()
' or Rollback() before we return.
If succeeded Then
transaction.Commit()
Else
transaction.Rollback()
End If
conn.Dispose()
End Try
End Sub
End Class
Ini adalah skrip penginstalan Transact-SQL (Install.sql), yang menyebarkan rakitan dan membuat prosedur tersimpan dalam database.
USE AdventureWorks;
GO
IF EXISTS (SELECT * FROM sys.objects WHERE name = N'CleanupUnusedAssemblies')
DROP PROCEDURE CleanupUnusedAssemblies;
GO
IF EXISTS (SELECT * FROM sys.assemblies WHERE name = N'AssemblyCleanupUtils')
DROP ASSEMBLY AssemblyCleanupUtils;
GO
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 AssemblyCleanupUtils
FROM @SamplesPath + 'AssemblyCleanup.dll'
WITH permission_set = Safe;
GO
CREATE PROCEDURE CleanupUnusedAssemblies (
@visible_assemblies bit
) AS
EXTERNAL NAME [AssemblyCleanupUtils].[AssemblyCleanup].CleanupUnusedAssemblies;
GO
Ini adalah test.sql, yang menguji sampel dengan menjalankan prosedur tersimpan.
USE AdventureWorks;
GO
PRINT 'Before cleanup...'
SELECT [name] FROM sys.assemblies;
GO
-- pass in false, which means the cleanup will only include invisible assemblies
EXEC dbo.CleanupUnusedAssemblies false;
GO
PRINT 'After cleanup'
SELECT [name] FROM sys.assemblies;
Transact-SQL berikut menghapus prosedur rakitan dan tersimpan dari database.
USE AdventureWorks;
GO
IF EXISTS (SELECT * FROM sys.objects WHERE name = N'CleanupUnusedAssemblies')
DROP PROCEDURE CleanupUnusedAssemblies;
GO
IF EXISTS (SELECT * FROM sys.assemblies WHERE name = N'AssemblyCleanupUtils')
DROP ASSEMBLY AssemblyCleanupUtils;
GO
Lihat Juga
Skenario Penggunaan dan Contoh untuk Integrasi Common Language Runtime (CLR)