调用 CLR 用户定义的聚合函数
适用范围:SQL Server
在 Transact-SQL SELECT
语句中,可以调用公共语言运行时(CLR)用户定义的聚合,但受应用于系统聚合函数的所有规则的约束。
应遵循下列附加规则:
当前用户必须对用户定义的聚合具有
EXECUTE
权限。必须以 <schema_name>形式使用由两部分组成的名称调用用户定义的聚合。<udagg_name>。
用户定义的聚合的参数类型必须与
CREATE AGGREGATE
语句中定义的聚合 input_type 匹配或隐式转换为聚合的 input_type。用户定义的聚合的返回类型必须与
CREATE AGGREGATE
语句中的 return_type 匹配。
例子
一个。 用户定义的聚合串联字符串值
以下代码是用户定义的聚合函数的示例,该函数连接从表中的列获取的一组字符串值:
using System;
using System.Data;
using Microsoft.SqlServer.Server;
using System.Data.SqlTypes;
using System.IO;
using System.Text;
[Serializable]
[SqlUserDefinedAggregate(
Format.UserDefined, //use clr serialization to serialize the intermediate result
IsInvariantToNulls = true, //optimizer property
IsInvariantToDuplicates = false, //optimizer property
IsInvariantToOrder = false, //optimizer property
MaxByteSize = 8000) //maximum size in bytes of persisted value
]
public class Concatenate : IBinarySerialize
{
/// <summary>
/// The variable that holds the intermediate result of the concatenation
/// </summary>
public StringBuilder intermediateResult;
/// <summary>
/// Initialize the internal data structures
/// </summary>
public void Init()
{
this.intermediateResult = new StringBuilder();
}
/// <summary>
/// Accumulate the next value, not if the value is null
/// </summary>
/// <param name="value"></param>
public void Accumulate(SqlString value)
{
if (value.IsNull)
{
return;
}
this.intermediateResult.Append(value.Value).Append(',');
}
/// <summary>
/// Merge the partially computed aggregate with this aggregate.
/// </summary>
/// <param name="other"></param>
public void Merge(Concatenate other)
{
this.intermediateResult.Append(other.intermediateResult);
}
/// <summary>
/// Called at the end of aggregation, to return the results of the aggregation.
/// </summary>
/// <returns></returns>
public SqlString Terminate()
{
string output = string.Empty;
//delete the trailing comma, if any
if (this.intermediateResult != null
&& this.intermediateResult.Length > 0)
{
output = this.intermediateResult.ToString(0, this.intermediateResult.Length - 1);
}
return new SqlString(output);
}
public void Read(BinaryReader r)
{
intermediateResult = new StringBuilder(r.ReadString());
}
public void Write(BinaryWriter w)
{
w.Write(this.intermediateResult.ToString());
}
}
将代码编译为 MyAgg.dll
后,可以在 SQL Server 中注册聚合,如下所示:
CREATE ASSEMBLY MyAgg
FROM 'C:\MyAgg.dll';
GO
CREATE AGGREGATE MyAgg(@input NVARCHAR (200))
RETURNS NVARCHAR (MAX)
EXTERNAL NAME MyAgg.Concatenate;
注意
SQL Server 中不支持使用 /clr:pure
编译器选项编译的可视化C++数据库对象(如标量值函数)。
与大多数聚合一样,大部分逻辑位于 Accumulate
方法中。 在这里,作为参数传入 Accumulate
方法的字符串将追加到在 Init
方法中初始化的 StringBuilder
对象。 假设尚未调用 Accumulate
方法,在追加传入字符串之前,还会将逗号追加到 StringBuilder
。 在计算任务结束时,将调用 Terminate
方法,该方法将 StringBuilder
作为字符串返回。
例如,请考虑具有以下架构的表:
CREATE TABLE BookAuthors
(
BookID INT NOT NULL,
AuthorName NVARCHAR (200) NOT NULL
);
然后插入以下行:
INSERT BookAuthors
VALUES
(1, 'Johnson'),
(2, 'Taylor'),
(3, 'Steven'),
(2, 'Mayler'),
(3, 'Roberts'),
(3, 'Michaels');
随后,以下查询将生成以下结果:
SELECT BookID, dbo.MyAgg(AuthorName)
FROM BookAuthors
GROUP BY BookID;
BookID | Author Names |
---|---|
1 |
Johnson |
2 |
Taylor, Mayler |
3 |
Roberts, Michaels, Steven |
B. 具有两个参数的用户定义聚合
以下示例显示了一个聚合,该聚合在 Accumulate
方法上具有两个参数。
using System;
using System.Data;
using System.Data.SqlClient;
using System.Data.SqlTypes;
using Microsoft.SqlServer.Server;
[Serializable]
[SqlUserDefinedAggregate(
Format.Native,
IsInvariantToDuplicates = false,
IsInvariantToNulls = true,
IsInvariantToOrder = true,
IsNullIfEmpty = true,
Name = "WeightedAvg")]
public struct WeightedAvg
{
/// <summary>
/// The variable that holds the intermediate sum of all values multiplied by their weight
/// </summary>
private long sum;
/// <summary>
/// The variable that holds the intermediate sum of all weights
/// </summary>
private int count;
/// <summary>
/// Initialize the internal data structures
/// </summary>
public void Init()
{
sum = 0;
count = 0;
}
/// <summary>
/// Accumulate the next value, not if the value is null
/// </summary>
/// <param name="Value">Next value to be aggregated</param>
/// <param name="Weight">The weight of the value passed to Value parameter</param>
public void Accumulate(SqlInt32 Value, SqlInt32 Weight)
{
if (!Value.IsNull && !Weight.IsNull)
{
sum += (long)Value * (long)Weight;
count += (int)Weight;
}
}
/// <summary>
/// Merge the partially computed aggregate with this aggregate
/// </summary>
/// <param name="Group">The other partial results to be merged</param>
public void Merge(WeightedAvg Group)
{
sum += Group.sum;
count += Group.count;
}
/// <summary>
/// Called at the end of aggregation, to return the results of the aggregation.
/// </summary>
/// <returns>The weighted average of all inputed values</returns>
public SqlInt32 Terminate()
{
if (count > 0)
{
int value = (int)(sum / count);
return new SqlInt32(value);
}
else
{
return SqlInt32.Null;
}
}
}
编译 C# 或 Visual Basic .NET 源代码后,运行以下 Transact-SQL。 此脚本假设相应的 DLL 名为 WghtAvg.dll,并且位于 C 驱动器的根目录下, 还假设数据库名为 test。
USE test;
GO
-- EXECUTE sp_configure 'clr enabled', 1;
-- RECONFIGURE WITH OVERRIDE;
-- GO
IF EXISTS (SELECT name
FROM systypes
WHERE name = 'MyTableType')
DROP TYPE MyTableType;
GO
IF EXISTS (SELECT name
FROM sysobjects
WHERE name = 'WeightedAvg')
DROP AGGREGATE WeightedAvg;
GO
IF EXISTS (SELECT name
FROM sys.assemblies
WHERE name = 'MyClrCode')
DROP ASSEMBLY MyClrCode;
GO
CREATE ASSEMBLY MyClrCode
FROM 'C:\WghtAvg.dll';
GO
CREATE AGGREGATE WeightedAvg(@value INT, @weight INT)
RETURNS INT
EXTERNAL NAME MyClrCode.WeightedAvg;
GO
CREATE TYPE MyTableType AS TABLE (
ItemValue INT,
ItemWeight INT);
GO
DECLARE @myTable AS MyTableType;
INSERT INTO @myTable
VALUES (1, 4),
(6, 1);
SELECT dbo.WeightedAvg(ItemValue, ItemWeight)
FROM @myTable;
GO