Prise en charge de la diffusion en continu SqlClient
La prise en charge du streaming entre SQL Server et une application (nouveau dans .NET Framework 4.5) prend en charge les données non structurées sur le serveur (documents, images et fichiers multimédias). Une base de données SQL Server peut stocker des objets BLOB, mais la récupération de BLOB peut utiliser beaucoup de mémoire.
La prise en charge de la diffusion en continu de SQL Serveur simplifie l’écriture d’applications qui diffusent les données, sans devoir entièrement charger les données dans la mémoire, ce qui réduit le nombre d’exceptions de dépassement de capacité de mémoire.
La prise en charge de la diffusion en continu facilite la montée en charge des applications intermédiaires, surtout dans les scénarios où les objets métiers se connectent à SQL Azure afin d'envoyer, de récupérer et manipuler des BLOB.
Avertissement
Les appels asynchrones ne sont pas pris en charge si une application utilise également le mot clé de chaîne de connexion Context Connection
.
Les membres ajoutés pour la prise en charge de la diffusion en continu sont utilisés pour récupérer des données de requêtes et passer des paramètres aux requêtes et aux procédures stockées. La fonctionnalité de diffusion en continu résout les scénarios OLTP et de migration des données de base et s’applique aux environnements de migration de données locaux et hors site.
Prise en charge du streaming depuis SQL Server
La prise en charge de la diffusion en continu de SQL Server introduit une nouvelle fonctionnalité dans les classes DbDataReader et SqlDataReader pour obtenir les objets Stream, XmlReader et TextReader et réagir à ces derniers. Ces classes sont utilisées pour récupérer les données des requêtes. Par conséquent, la prise en charge de la diffusion en continu de SQL Server répond aux scénarios OLTP et s’applique aux environnements sur site et hors site.
Les membres suivants ont été ajoutés à SqlDataReader pour activer la prise en charge de la diffusion en continu de SQL Server :
Les membres suivants ont été ajoutés à DbDataReader pour activer la prise en charge de la diffusion en continu de SQL Server :
Prise en charge du streaming vers SQL Server
La prise en charge du streaming vers SQL Server introduit une nouvelle fonctionnalité dans la classe SqlParameter pour qu’elle puisse accepter et réagir à des objets XmlReader, Stream et TextReader. SqlParameter est utilisé pour passer des paramètres aux requêtes et aux procédures stockées.
Supprimer un objet SqlCommand ou appeler Cancel doit annuler toute opération en continu. Si une application envoie CancellationToken, l'annulation n'est pas garantie.
Les types suivants SqlDbType acceptent un Value de Stream :
- Binaire
- VarBinary
Les types suivants SqlDbType acceptent un Value de TextReader :
- Char
- NChar
- NVarChar
- Xml
Le type XMLSqlDbType accepte une Value de XmlReader.
SqlValue accepte des valeurs de type XmlReader, TextReader et Stream.
XmlReader, TextReader, et l'objet Stream seront envoyés jusqu'à la valeur définie par Size.
Exemple : diffusion depuis SQL Server
Utilisez la commande Transact-SQL suivante pour créer l’exemple de base de données :
CREATE DATABASE [Demo]
GO
USE [Demo]
GO
CREATE TABLE [Streams] (
[id] INT PRIMARY KEY IDENTITY(1, 1),
[textdata] NVARCHAR(MAX),
[bindata] VARBINARY(MAX),
[xmldata] XML)
GO
INSERT INTO [Streams] (textdata, bindata, xmldata) VALUES (N'This is a test', 0x48656C6C6F, N'<test>value</test>')
INSERT INTO [Streams] (textdata, bindata, xmldata) VALUES (N'Hello, World!', 0x54657374696E67, N'<test>value2</test>')
INSERT INTO [Streams] (textdata, bindata, xmldata) VALUES (N'Another row', 0x666F6F626172, N'<fff>bbb</fff><fff>bbc</fff>')
GO
L'exemple montre comment effectuer les actions suivantes :
- Éviter de bloquer un thread d'interface utilisateur en fournissant une façon asynchrone de récupérer des fichiers volumineux.
- Transférer un grand fichier texte depuis SQL Server dans .NET Framework 4.5.
- Transférer un grand fichier XML depuis SQL Server dans .NET Framework 4.5.
- Récupérez les données de SQL Server.
- Transférer des fichiers volumineux (objets BLOB) d’une base de données SQL Server à une autre sans insuffisance de mémoire.
using System;
using System.Data;
using System.Data.SqlClient;
using System.IO;
using System.Threading.Tasks;
using System.Xml;
namespace StreamingFromServer {
class Program {
private const string connectionString = @"...";
static void Main(string[] args) {
CopyBinaryValueToFile().Wait();
PrintTextValues().Wait();
PrintXmlValues().Wait();
PrintXmlValuesViaNVarChar().Wait();
Console.WriteLine("Done");
}
// Retrieve a large BLOB from SQL Server in .NET Framework 4.5 using the asynchronous capability.
private static async Task CopyBinaryValueToFile() {
string filePath = Path.Combine(Environment.GetFolderPath(Environment.SpecialFolder.MyDocuments), "binarydata.bin");
using (SqlConnection connection = new SqlConnection(connectionString)) {
await connection.OpenAsync();
using (SqlCommand command = new SqlCommand("SELECT [bindata] FROM [Streams] WHERE [id]=@id", connection)) {
command.Parameters.AddWithValue("id", 1);
// The reader needs to be executed with the SequentialAccess behavior to enable network streaming.
// Otherwise ReadAsync will buffer the entire BLOB into memory which can cause scalability issues or even OutOfMemoryExceptions.
using (SqlDataReader reader = await command.ExecuteReaderAsync(CommandBehavior.SequentialAccess)) {
if (await reader.ReadAsync()) {
if (!(await reader.IsDBNullAsync(0))) {
using (FileStream file = new FileStream(filePath, FileMode.Create, FileAccess.Write)) {
using (Stream data = reader.GetStream(0)) {
// Asynchronously copy the stream from the server to the file we just created.
await data.CopyToAsync(file);
}
}
}
}
}
}
}
}
// Transfer a large Text File from SQL Server in .NET Framework 4.5.
private static async Task PrintTextValues() {
using (SqlConnection connection = new SqlConnection(connectionString)) {
await connection.OpenAsync();
using (SqlCommand command = new SqlCommand("SELECT [id], [textdata] FROM [Streams]", connection)) {
// The reader needs to be executed with the SequentialAccess behavior to enable network streaming.
// Otherwise ReadAsync will buffer the entire text document into memory which can cause scalability issues or even OutOfMemoryExceptions.
using (SqlDataReader reader = await command.ExecuteReaderAsync(CommandBehavior.SequentialAccess)) {
while (await reader.ReadAsync()) {
Console.Write("{0}: ", reader.GetInt32(0));
if (await reader.IsDBNullAsync(1)) {
Console.Write("(NULL)");
}
else {
char[] buffer = new char[4096];
int charsRead = 0;
using (TextReader data = reader.GetTextReader(1)) {
do {
// Grab each chunk of text and write it to the console.
// If you are writing to a TextWriter, you should use WriteAsync or WriteLineAsync.
charsRead = await data.ReadAsync(buffer, 0, buffer.Length);
Console.Write(buffer, 0, charsRead);
} while (charsRead > 0);
}
}
Console.WriteLine();
}
}
}
}
}
// Transfer a large Xml Document from SQL Server in .NET Framework 4.5.
private static async Task PrintXmlValues() {
using (SqlConnection connection = new SqlConnection(connectionString)) {
await connection.OpenAsync();
using (SqlCommand command = new SqlCommand("SELECT [id], [xmldata] FROM [Streams]", connection)) {
// The reader needs to be executed with the SequentialAccess behavior to enable network streaming.
// Otherwise ReadAsync will buffer the entire Xml Document into memory which can cause scalability issues or even OutOfMemoryExceptions.
using (SqlDataReader reader = await command.ExecuteReaderAsync(CommandBehavior.SequentialAccess)) {
while (await reader.ReadAsync()) {
Console.WriteLine("{0}: ", reader.GetInt32(0));
if (await reader.IsDBNullAsync(1)) {
Console.WriteLine("\t(NULL)");
}
else {
using (XmlReader xmlReader = reader.GetXmlReader(1)) {
int depth = 1;
// NOTE: The XmlReader returned by GetXmlReader does NOT support async operations.
// See the example below (PrintXmlValuesViaNVarChar) for how to get an XmlReader with asynchronous capabilities.
while (xmlReader.Read()) {
switch (xmlReader.NodeType) {
case XmlNodeType.Element:
Console.WriteLine("{0}<{1}>", new string('\t', depth), xmlReader.Name);
depth++;
break;
case XmlNodeType.Text:
Console.WriteLine("{0}{1}", new string('\t', depth), xmlReader.Value);
break;
case XmlNodeType.EndElement:
depth--;
Console.WriteLine("{0}</{1}>", new string('\t', depth), xmlReader.Name);
break;
}
}
}
}
}
}
}
}
}
// Transfer a large Xml Document from SQL Server in .NET Framework 4.5.
// This goes via NVarChar and TextReader to enable asynchronous reading.
private static async Task PrintXmlValuesViaNVarChar() {
XmlReaderSettings xmlSettings = new XmlReaderSettings() {
// Async must be explicitly enabled in the XmlReaderSettings otherwise the XmlReader will throw exceptions when async methods are called.
Async = true,
// Since we will immediately wrap the TextReader we are creating in an XmlReader, we will permit the XmlReader to take care of closing\disposing it.
CloseInput = true,
// If the Xml you are reading is not a valid document (as per <https://learn.microsoft.com/previous-versions/dotnet/netframework-4.0/6bts1x50(v=vs.100)>) you will need to set the conformance level to Fragment.
ConformanceLevel = ConformanceLevel.Fragment
};
using (SqlConnection connection = new SqlConnection(connectionString)) {
await connection.OpenAsync();
// Cast the XML into NVarChar to enable GetTextReader - trying to use GetTextReader on an XML type will throw an exception.
using (SqlCommand command = new SqlCommand("SELECT [id], CAST([xmldata] AS NVARCHAR(MAX)) FROM [Streams]", connection)) {
// The reader needs to be executed with the SequentialAccess behavior to enable network streaming.
// Otherwise ReadAsync will buffer the entire Xml Document into memory which can cause scalability issues or even OutOfMemoryExceptions.
using (SqlDataReader reader = await command.ExecuteReaderAsync(CommandBehavior.SequentialAccess)) {
while (await reader.ReadAsync()) {
Console.WriteLine("{0}:", reader.GetInt32(0));
if (await reader.IsDBNullAsync(1)) {
Console.WriteLine("\t(NULL)");
}
else {
// Grab the row as a TextReader, then create an XmlReader on top of it.
// The code doesn't keep a reference to the TextReader since the XmlReader is created with the "CloseInput" setting (so it will close the TextReader when needed).
using (XmlReader xmlReader = XmlReader.Create(reader.GetTextReader(1), xmlSettings)) {
int depth = 1;
// The XmlReader above now supports asynchronous operations, so we can use ReadAsync here.
while (await xmlReader.ReadAsync()) {
switch (xmlReader.NodeType) {
case XmlNodeType.Element:
Console.WriteLine("{0}<{1}>", new string('\t', depth), xmlReader.Name);
depth++;
break;
case XmlNodeType.Text:
// Depending on what your data looks like, you should either use Value or GetValueAsync.
// Value has less overhead (since it doesn't create a Task), but it may also block if additional data is required.
Console.WriteLine("{0}{1}", new string('\t', depth), await xmlReader.GetValueAsync());
break;
case XmlNodeType.EndElement:
depth--;
Console.WriteLine("{0}</{1}>", new string('\t', depth), xmlReader.Name);
break;
}
}
}
}
}
}
}
}
}
}
}
Exemple : diffusion vers SQL Server
Utilisez la commande Transact-SQL suivante pour créer l’exemple de base de données :
CREATE DATABASE [Demo2]
GO
USE [Demo2]
GO
CREATE TABLE [BinaryStreams] (
[id] INT PRIMARY KEY IDENTITY(1, 1),
[bindata] VARBINARY(MAX))
GO
CREATE TABLE [TextStreams] (
[id] INT PRIMARY KEY IDENTITY(1, 1),
[textdata] NVARCHAR(MAX))
GO
CREATE TABLE [BinaryStreamsCopy] (
[id] INT PRIMARY KEY IDENTITY(1, 1),
[bindata] VARBINARY(MAX))
GO
L'exemple montre comment effectuer les actions suivantes :
- Transférer un objet BLOB volumineux vers SQL Server dans .NET Framework 4.5.
- Transférer un fichier texte volumineux vers SQL Server dans .NET Framework 4.5.
- Utiliser la nouvelle fonctionnalité asynchrone pour transférer un objet BLOB volumineux.
- Utiliser la nouvelle fonctionnalité asynchrone et du mot clé await pour transférer un objet BLOB volumineux.
- Annuler le transfert d’un objet BLOB volumineux.
- Diffuser en continu d'un SQL Server à un autre via la nouvelle fonctionnalité asynchrone.
using System;
using System.Data;
using System.Data.SqlClient;
using System.IO;
using System.Threading;
using System.Threading.Tasks;
namespace StreamingToServer {
class Program {
private const string connectionString = @"...";
static void Main(string[] args) {
CreateDemoFiles();
StreamBLOBToServer().Wait();
StreamTextToServer().Wait();
// Create a CancellationTokenSource that will be cancelled after 100ms
// Typically this token source will be cancelled by a user request (e.g. a Cancel button).
CancellationTokenSource tokenSource = new CancellationTokenSource();
tokenSource.CancelAfter(100);
try {
CancelBLOBStream(tokenSource.Token).Wait();
}
catch (AggregateException ex) {
// Cancelling an async operation will throw an exception.
// Since we are using the Task's Wait method, this exception will be wrapped in an AggregateException.
// If you were using the 'await' keyword, the compiler would take care of unwrapping the AggregateException.
// Depending on when the cancellation occurs, you can either get an error from SQL Server or from .Net.
if ((ex.InnerException is SqlException) || (ex.InnerException is TaskCanceledException)) {
// This is an expected exception.
Console.WriteLine("Got expected exception: {0}", ex.InnerException.Message);
}
else {
// Did not expect this exception - rethrow it.
throw;
}
}
Console.WriteLine("Done");
}
// This is used to generate the files which are used by the other sample methods.
private static void CreateDemoFiles() {
Random rand = new Random();
byte[] data = new byte[1024];
rand.NextBytes(data);
using (FileStream file = File.Open("binarydata.bin", FileMode.Create)) {
file.Write(data, 0, data.Length);
}
using (StreamWriter writer = new StreamWriter(File.Open("textdata.txt", FileMode.Create))) {
writer.Write(Convert.ToBase64String(data));
}
}
// Transfer a large BLOB to SQL Server in .NET Framework 4.5.
private static async Task StreamBLOBToServer() {
using (SqlConnection conn = new SqlConnection(connectionString)) {
await conn.OpenAsync();
using (SqlCommand cmd = new SqlCommand("INSERT INTO [BinaryStreams] (bindata) VALUES (@bindata)", conn)) {
using (FileStream file = File.Open("binarydata.bin", FileMode.Open)) {
// Add a parameter which uses the FileStream we just opened
// Size is set to -1 to indicate "MAX".
cmd.Parameters.Add("@bindata", SqlDbType.Binary, -1).Value = file;
// Send the data to the server asynchronously.
await cmd.ExecuteNonQueryAsync();
}
}
}
}
// Transfer a large Text File to SQL Server in .NET Framework 4.5.
private static async Task StreamTextToServer() {
using (SqlConnection conn = new SqlConnection(connectionString)) {
await conn.OpenAsync();
using (SqlCommand cmd = new SqlCommand("INSERT INTO [TextStreams] (textdata) VALUES (@textdata)", conn)) {
using (StreamReader file = File.OpenText("textdata.txt")) {
// Add a parameter which uses the StreamReader we just opened.
// Size is set to -1 to indicate "MAX".
cmd.Parameters.Add("@textdata", SqlDbType.NVarChar, -1).Value = file;
// Send the data to the server asynchronously.
await cmd.ExecuteNonQueryAsync();
}
}
}
}
// Cancel the transfer of a large BLOB.
private static async Task CancelBLOBStream(CancellationToken cancellationToken) {
using (SqlConnection conn = new SqlConnection(connectionString)) {
// We can cancel not only sending the data to the server, but also opening the connection.
await conn.OpenAsync(cancellationToken);
// Artificially delay the command by 100ms.
using (SqlCommand cmd = new SqlCommand("WAITFOR DELAY '00:00:00:100';INSERT INTO [BinaryStreams] (bindata) VALUES (@bindata)", conn)) {
using (FileStream file = File.Open("binarydata.bin", FileMode.Open)) {
// Add a parameter which uses the FileStream we just opened.
// Size is set to -1 to indicate "MAX".
cmd.Parameters.Add("@bindata", SqlDbType.Binary, -1).Value = file;
// Send the data to the server asynchronously.
// Pass the cancellation token such that the command will be cancelled if needed.
await cmd.ExecuteNonQueryAsync(cancellationToken);
}
}
}
}
}
}
Exemple : diffusion d’une instance SQL Server vers une autre
Cet exemple montre comment diffuser en continu un objet BLOB d’un SQL Server à un autre, avec la prise en charge de l’annulation.
using System;
using System.Data;
using System.Data.SqlClient;
using System.IO;
using System.Threading;
using System.Threading.Tasks;
namespace StreamingFromServerToAnother {
class Program {
private const string connectionString = @"...";
static void Main(string[] args) {
// For this example, we don't want to cancel,
// so pass in a "blank" cancellation token.
E2EStream(CancellationToken.None).Wait();
Console.WriteLine("Done");
}
// Streaming from one SQL Server to Another One using the new Async.NET.
private static async Task E2EStream(CancellationToken cancellationToken) {
using (SqlConnection readConn = new SqlConnection(connectionString)) {
using (SqlConnection writeConn = new SqlConnection(connectionString)) {
// Note that we are using the same cancellation token for calls to both connections\commands.
// Also we can start both the connection opening asynchronously, and then wait for both to complete.
Task openReadConn = readConn.OpenAsync(cancellationToken);
Task openWriteConn = writeConn.OpenAsync(cancellationToken);
await Task.WhenAll(openReadConn, openWriteConn);
using (SqlCommand readCmd = new SqlCommand("SELECT [bindata] FROM [BinaryStreams]", readConn)) {
using (SqlCommand writeCmd = new SqlCommand("INSERT INTO [BinaryStreamsCopy] (bindata) VALUES (@bindata)", writeConn)) {
// Add an empty parameter to the write command which will be used for the streams we are copying.
// Size is set to -1 to indicate "MAX".
SqlParameter streamParameter = writeCmd.Parameters.Add("@bindata", SqlDbType.Binary, -1);
// The reader needs to be executed with the SequentialAccess behavior to enable network streaming.
// Otherwise ReadAsync will buffer the entire BLOB into memory which can cause scalability issues or even OutOfMemoryExceptions.
using (SqlDataReader reader = await readCmd.ExecuteReaderAsync(CommandBehavior.SequentialAccess, cancellationToken)) {
while (await reader.ReadAsync(cancellationToken)) {
// Grab a stream to the binary data in the source database.
using (Stream dataStream = reader.GetStream(0)) {
// Set the parameter value to the stream source that was opened.
streamParameter.Value = dataStream;
// Asynchronously send data from one database to another.
await writeCmd.ExecuteNonQueryAsync(cancellationToken);
}
}
}
}
}
}
}
}
}
}