使用 OpenSqlFilestream 存取 FILESTREAM 資料
OpenSqlFilestream API 會取得 FILESTREAM 二進位大型物件的 Win32 相容檔案控制代碼, (BLOB) 儲存在檔案系統中。 此控制代碼可傳遞給下列任何 Win32 API:ReadFile、WriteFile、TransmitFile、SetFilePointer、SetEndOfFile 或 FlushFileBuffers。 如果您將此控制代碼傳遞給其他任何 Win32 API,將會傳回錯誤 ERROR_ACCESS_DENIED。 在認可或回復交易之前,必須將此控制代碼傳遞給 Win32 的 CloseHandle API 來關閉此控制代碼。 如果無法關閉此控制代碼,將會導致伺服器端資源洩露。
所有 FILESTREAM 資料容器存取都必須在SQL Server交易中執行。 Transact-SQL 陳述式也可在同一交易中執行。 以維護 SQL 資料與 FILESTREAM 資料之間的一致性。
若要使用 Win32 存取 FILESTREAM BLOB,必須啟用 Windows 授權 。
重要
當檔案已針對寫入存取開啟時,FILESTREAM 代理程式就會擁有此交易。 在釋放交易之前,僅允許 Win32 檔案 I/O。 若要釋放該異動,您必須關閉寫入控制代碼。
語法
HANDLE OpenSqlFilestream (
LPCWSTR
FilestreamPath
,
SQL_FILESTREAM_DESIRED_ACCESS
DesiredAccess,
ULONGOpenOptions,LPBYTEFilestreamTransactionContext,SIZE_TFilestreamTransactionContextLength,PLARGE_INTEGERAllocationSize);
參數
FilestreamPath
[in] nvarchar(max)
這是 PathName 函式所傳回的路徑。 PathName 必須從具有 FILESTREAM 資料表與資料行之 SQL Server SELECT 或 UPDATE 權限的帳戶內容中呼叫。
DesiredAccess
[in] 設定用來存取 FILESTREAM BLOB 資料的模式。 此值會傳遞給 DeviceIoControl 函式。
名稱 | 值 | 意義 |
---|---|---|
SQL_FILESTREAM_READ | 0 | 資料可以從檔案讀取。 |
SQL_FILESTREAM_WRITE | 1 | 資料可以寫入檔案。 |
SQL_FILESTREAM_READWRITE | 2 | 資料可以寫入檔案和從檔案讀取。 |
注意
這些值會定義在 sqlncli.h 中的 SQL_FILESTREAM_DESIRED_ACCESS 列舉內。
OpenOptions
[in] 檔案屬性和旗標。 這個參數也可以包含下列旗標的任意組合。
旗標 | 值 | 意義 |
---|---|---|
SQL_FILESTREAM_OPEN_NONE | 0x00000000: | 開啟或建立這個檔案時,不搭配任何特殊選項。 |
SQL_FILESTREAM_OPEN_FLAG_ASYNC | 0x00000001L | 開啟或建立這個檔案是為了非同步 I/O。 |
SQL_FILESTREAM_OPEN_FLAG_NO_BUFFERING | 0x00000002L | 系統藉由不使用任何系統快取來開啟檔案。 |
SQL_FILESTREAM_OPEN_FLAG_NO_WRITE_THROUGH | 0x00000004L | 系統不會透過中繼快取來寫入。 會直接寫入磁碟。 |
SQL_FILESTREAM_OPEN_FLAG_SEQUENTIAL_SCAN | 0x00000008L | 按順序從開頭至結尾存取檔案。 系統可使用這個做為最佳化檔案快取的提示。 如果應用程式藉移動檔案指標來進行隨機存取,則可能不會發生最佳快取。 |
SQL_FILESTREAM_OPEN_FLAG_RANDOM_ACCESS | 0x00000010L | 隨機存取檔案。 系統可使用這個做為最佳化檔案快取的提示。 |
FilestreamTransactionContext
[in] 此值由 GET_FILESTREAM_TRANSACTION_CONTEXT 函式傳回。
FilestreamTransactionContextLength
[in] varbinary(max)
中由 GET_FILESTREAM_TRANSACTION_CONTEXT 函數傳回之資料的位元組數。 此函數會傳回 N 個位元組的陣列。 N 是由此函數所決定,而且是所傳回之位元組陣列的屬性。
AllocationSize
[in] 指定資料檔的初始配置大小 (以位元組為單位)。 在讀取模式下將會被忽略。 這個參數可以是 NULL,此時會使用預設檔案系統行為。
傳回值
如果此函數成功,傳回值就是指定之檔案的開啟控制代碼。 如果此函數失敗,傳回值就是 INVALID_HANDLE_VALUE。 如需更多的錯誤資訊,可呼叫 GetLastError()。
範例
下列範例將示範如何使用 OpenSqlFilestream
API 來取得 Win32 控制代碼。
using System.IO;
using System;
using System.Collections.Generic;
using System.Text;
using System.Data;
using System.Data.SqlClient;
using System.Data.SqlTypes;
namespace FILESTREAM
{
class Program
{
static void Main(string[] args)
{
SqlConnection sqlConnection = new SqlConnection(
"Integrated Security=true;server=(local)");
SqlCommand sqlCommand = new SqlCommand();
sqlCommand.Connection = sqlConnection;
try
{
sqlConnection.Open();
//The first task is to retrieve the file path
//of the SQL FILESTREAM BLOB that we want to
//access in the application.
sqlCommand.CommandText =
"SELECT Chart.PathName()"
+ " FROM Archive.dbo.Records"
+ " WHERE SerialNumber = 3";
String filePath = null;
Object pathObj = sqlCommand.ExecuteScalar();
if (DBNull.Value != pathObj)
filePath = (string)pathObj;
else
{
throw new System.Exception(
"Chart.PathName() failed"
+ " to read the path name "
+ " for the Chart column.");
}
//The next task is to obtain a transaction
//context. All FILESTREAM BLOB operations
//occur within a transaction context to
//maintain data consistency.
//All SQL FILESTREAM BLOB access must occur in
//a transaction. MARS-enabled connections
//have specific rules for batch scoped transactions,
//which the Transact-SQL BEGIN TRANSACTION statement
//violates. To avoid this issue, client applications
//should use appropriate API facilities for transaction management,
//management, such as the SqlTransaction class.
SqlTransaction transaction = sqlConnection.BeginTransaction("mainTranaction");
sqlCommand.Transaction = transaction;
sqlCommand.CommandText =
"SELECT GET_FILESTREAM_TRANSACTION_CONTEXT()";
Object obj = sqlCommand.ExecuteScalar();
byte[] txContext = (byte[])obj;
//The next step is to obtain a handle that
//can be passed to the Win32 FILE APIs.
SqlFileStream sqlFileStream = new SqlFileStream(filePath, txContext, FileAccess.ReadWrite);
byte[] buffer = new byte[512];
int numBytes = 0;
//Write the string, "EKG data." to the FILESTREAM BLOB.
//In your application this string would be replaced with
//the binary data that you want to write.
string someData = "EKG data.";
Encoding unicode = Encoding.GetEncoding(0);
sqlFileStream.Write(unicode.GetBytes(someData.ToCharArray()),
0,
someData.Length);
//Read the data from the FILESTREAM
//BLOB.
sqlFileStream.Seek(0L, SeekOrigin.Begin);
numBytes = sqlFileStream.Read(buffer, 0, buffer.Length);
string readData = unicode.GetString(buffer);
if (numBytes != 0)
Console.WriteLine(readData);
//Because reading and writing are finished, FILESTREAM
//must be closed. This closes the c# FileStream class,
//but does not necessarily close the underlying
//FILESTREAM handle.
sqlFileStream.Close();
//The final step is to commit or roll back the read and write
//operations that were performed on the FILESTREAM BLOB.
sqlCommand.Transaction.Commit();
}
catch (System.Exception ex)
{
Console.WriteLine(ex.ToString());
}
finally
{
sqlConnection.Close();
}
return;
}
}
}
Imports System.IO
Imports System
Imports System.Collections.Generic
Imports System.Text
Imports System.Data
Imports System.Data.SqlClient
Imports System.Data.SqlTypes
Module Module1
Public Sub Main(ByVal args As String())
' Dim sqlConnection As New SqlConnection("Integrated Security=true;server=(local)")
Dim sqlConnection As New SqlConnection("Integrated Security=true;server=kellyreyue\MSSQL1")
Dim sqlCommand As New SqlCommand()
sqlCommand.Connection = sqlConnection
Try
sqlConnection.Open()
'The first task is to retrieve the file path
'of the SQL FILESTREAM BLOB that we want to
'access in the application.
sqlCommand.CommandText = "SELECT Chart.PathName()" + " FROM Archive.dbo.Records" + " WHERE SerialNumber = 3"
Dim filePath As String = Nothing
Dim pathObj As Object = sqlCommand.ExecuteScalar()
If Not pathObj.Equals(DBNull.Value) Then
filePath = DirectCast(pathObj, String)
Else
Throw New System.Exception("Chart.PathName() failed" + " to read the path name " + " for the Chart column.")
End If
'The next task is to obtain a transaction
'context. All FILESTREAM BLOB operations
'occur within a transaction context to
'maintain data consistency.
'All SQL FILESTREAM BLOB access must occur in
'a transaction. MARS-enabled connections
'have specific rules for batch scoped transactions,
'which the Transact-SQL BEGIN TRANSACTION statement
'violates. To avoid this issue, client applications
'should use appropriate API facilities for transaction management,
'management, such as the SqlTransaction class.
Dim transaction As SqlTransaction = sqlConnection.BeginTransaction("mainTranaction")
sqlCommand.Transaction = transaction
sqlCommand.CommandText = "SELECT GET_FILESTREAM_TRANSACTION_CONTEXT()"
Dim obj As Object = sqlCommand.ExecuteScalar()
Dim txContext As Byte() = Nothing
Dim contextLength As UInteger
If Not obj.Equals(DBNull.Value) Then
txContext = DirectCast(obj, Byte())
contextLength = txContext.Length()
Else
Dim message As String = "GET_FILESTREAM_TRANSACTION_CONTEXT() failed"
Throw New System.Exception(message)
End If
'The next step is to obtain a handle that
'can be passed to the Win32 FILE APIs.
Dim sqlFileStream As New SqlFileStream(filePath, txContext, FileAccess.ReadWrite)
Dim buffer As Byte() = New Byte(511) {}
Dim numBytes As Integer = 0
'Write the string, "EKG data." to the FILESTREAM BLOB.
'In your application this string would be replaced with
'the binary data that you want to write.
Dim someData As String = "EKG data."
Dim unicode As Encoding = Encoding.GetEncoding(0)
sqlFileStream.Write(unicode.GetBytes(someData.ToCharArray()), 0, someData.Length)
'Read the data from the FILESTREAM
'BLOB.
sqlFileStream.Seek(0, SeekOrigin.Begin)
numBytes = sqlFileStream.Read(buffer, 0, buffer.Length)
Dim readData As String = unicode.GetString(buffer)
If numBytes <> 0 Then
Console.WriteLine(readData)
End If
'Because reading and writing are finished, FILESTREAM
'must be closed. This closes the c# FileStream class,
'but does not necessarily close the underlying
'FILESTREAM handle.
sqlFileStream.Close()
'The final step is to commit or roll back the read and write
'operations that were performed on the FILESTREAM BLOB.
sqlCommand.Transaction.Commit()
Catch ex As System.Exception
Console.WriteLine(ex.ToString())
Finally
sqlConnection.Close()
End Try
Return
End Sub
End Module
#include <windows.h>
#include <sql.h>
#include<sqltypes.h>
#include<sqlext.h>
#include <stdio.h>
#include <sqlncli.h>
#define COPYBUFFERSIZE 4096
/// <summary>
///This class iterates though the ODBC error queue and prints all of the
///accumulated error messages to the console.
/// </summary>
class ODBCErrors
{
private:
int m_iLine; //Source code line on which the error occurred
SQLSMALLINT m_type; //Type of handle on which the error occurred
SQLHANDLE m_handle; //ODBC handle on which the error occurred
public:
/// <summary>
///Default constructor for the ODBCErrors class
///</summary>
ODBCErrors()
{
m_iLine = -1;
m_type = 0;
m_handle = SQL_NULL_HANDLE;
}
/// <summary>
///Constructor for the ODBCErrors class
/// </summary>
/// <param name="iLine">
/// This parameter is the source code line
/// at which the error occurred.
///</param>
/// <param name="type">
/// This parameter is the type of ODBC handle passed in
/// the next parameter.
///</param>
/// <param name="handle">
/// This parameter is the handle on which the error occurred.
///</param>
ODBCErrors(int iLine, SQLSMALLINT type, SQLHANDLE handle)
{
m_iLine = iLine;
m_type = type;
m_handle = handle;
}
///<summary>
/// This method iterates though the error stack for the handle passed
/// into the constructor and displays those errors on the console.
///</summary>
void Print()
{
SQLSMALLINT i = 0, len = 0;
SQLINTEGER native;
SQLTCHAR state[9], text[256];
SQLRETURN sqlReturn = SQL_SUCCESS;
if ( m_handle == SQL_NULL_HANDLE )
{
wprintf_s(TEXT("The error handle is not a valid handle.\n"), m_iLine);
return;
}
wprintf_s(TEXT("Error Line(%d)\n"), m_iLine);
while( sqlReturn == SQL_SUCCESS )
{
len = 0;
sqlReturn = SQLGetDiagRec(
m_type,
m_handle,
++i,
state,
&native,
text,
sizeof(text)/sizeof(SQLTCHAR),
&len);
if ( SQL_SUCCEEDED(sqlReturn) )
wprintf_s(TEXT("Error(%d, %ld, %s) : %s\n"), i, native, state, text);
}
}
};
BOOL CopyFileToSQL(LPTSTR srcFilePath, LPTSTR dstFilePath, LPBYTE transactionToken, SQLINTEGER cbTransactionToken)
{
BOOL bRetCode = FALSE;
HANDLE srcHandle = INVALID_HANDLE_VALUE;
HANDLE dstHandle = INVALID_HANDLE_VALUE;
BYTE buffer[COPYBUFFERSIZE] = { 0 };
TCHAR *szErrMsgSrc = TEXT("Error opening source file.");
TCHAR *szErrMsgDst = TEXT("Error opening destFile file.");
TCHAR *szErrMsgRead = TEXT("Error reading source file.");
TCHAR *szErrMsgWrite = TEXT("Error writing SQL file.");
try
{
if ( (srcHandle = CreateFile(
srcFilePath,
GENERIC_READ,
FILE_SHARE_READ,
NULL,
OPEN_EXISTING,
FILE_FLAG_SEQUENTIAL_SCAN,
NULL)) == INVALID_HANDLE_VALUE )
throw szErrMsgSrc;
if ( (dstHandle = OpenSqlFilestream(
dstFilePath,
Write,
0,
transactionToken,
cbTransactionToken,
0)) == INVALID_HANDLE_VALUE)
throw szErrMsgDst;
DWORD bytesRead = 0;
DWORD bytesWritten = 0;
do
{
if ( ReadFile(srcHandle, buffer, COPYBUFFERSIZE, &bytesRead, NULL) == 0 )
throw szErrMsgRead;
if (bytesRead > 0)
{
if ( WriteFile(dstHandle, buffer, bytesRead, &bytesWritten, NULL) == 0 )
throw szErrMsgWrite;
}
} while (bytesRead > 0);
bRetCode = TRUE;
}
catch( TCHAR *szErrMsg )
{
wprintf_s(szErrMsg);
bRetCode = FALSE;
}
if ( srcHandle != INVALID_HANDLE_VALUE )
CloseHandle(srcHandle);
if ( dstHandle != INVALID_HANDLE_VALUE )
CloseHandle(dstHandle);
return bRetCode;
}
void main()
{
TCHAR *sqlDBQuery =
TEXT("INSERT INTO Archive.dbo.Records(Id, SerialNumber, Chart)")
TEXT(" OUTPUT GET_FILESTREAM_TRANSACTION_CONTEXT(), inserted.Chart.PathName()")
TEXT("VALUES (newid (), 5, CONVERT(VARBINARY, '**Temp**'))");
SQLCHAR transactionToken[32];
SQLHANDLE henv = SQL_NULL_HANDLE;
SQLHANDLE hdbc = SQL_NULL_HANDLE;
SQLHANDLE hstmt = SQL_NULL_HANDLE;
try
{
//These statements Initialize ODBC for the client application and
//connect to the database.
if ( SQLAllocHandle(SQL_HANDLE_ENV, SQL_NULL_HANDLE, &henv) != SQL_SUCCESS )
throw new ODBCErrors(__LINE__, SQL_HANDLE_ENV, henv);
if ( SQLSetEnvAttr(henv, SQL_ATTR_ODBC_VERSION,(void*)SQL_OV_ODBC3, NULL) != SQL_SUCCESS )
throw new ODBCErrors(__LINE__, SQL_HANDLE_ENV, henv);
if ( SQLAllocHandle(SQL_HANDLE_DBC, henv, &hdbc) != SQL_SUCCESS )
throw new ODBCErrors(__LINE__, SQL_HANDLE_ENV, henv);
//This code assumes that the dataset name "Sql Server FILESTREAM"
//has been previously created on the client computer system. An
//ODBC DSN is created with the ODBC Data Source item in
//the Windows Control Panel.
if ( SQLConnect(hdbc, TEXT("Sql Server FILESTREAM"),
SQL_NTS, NULL, 0, NULL, 0) <= 0 )
throw new ODBCErrors(__LINE__, SQL_HANDLE_DBC, hdbc);
//FILESTREAM requires that all read and write operations occur
//within a transaction.
if ( SQLSetConnectAttr(hdbc,
SQL_ATTR_AUTOCOMMIT,
(SQLPOINTER)SQL_AUTOCOMMIT_OFF,
SQL_IS_UINTEGER) != SQL_SUCCESS )
throw new ODBCErrors(__LINE__, SQL_HANDLE_DBC, hdbc);
if ( SQLAllocHandle(SQL_HANDLE_STMT, hdbc, &hstmt) != SQL_SUCCESS )
throw new ODBCErrors(__LINE__, SQL_HANDLE_DBC, hdbc);
if ( SQLExecDirect(hstmt, sqlDBQuery, SQL_NTS) != SQL_SUCCESS )
throw new ODBCErrors(__LINE__, SQL_HANDLE_STMT, hstmt);
//Retrieve the transaction token.
if ( SQLFetch(hstmt) != SQL_SUCCESS )
throw new ODBCErrors(__LINE__, SQL_HANDLE_STMT, hstmt);
SQLINTEGER cbTransactionToken = sizeof(transactionToken);
if ( SQLGetData(hstmt, 1,
SQL_C_BINARY,
transactionToken,
sizeof(transactionToken),
&cbTransactionToken) != SQL_SUCCESS )
throw new ODBCErrors(__LINE__, SQL_HANDLE_STMT, hstmt);
//Retrieve the file path for the inserted record.
TCHAR dstFilePath[1024];
SQLINTEGER cbDstFilePath;
if ( SQLGetData(hstmt, 2, SQL_C_TCHAR, dstFilePath, sizeof(dstFilePath), &cbDstFilePath) != SQL_SUCCESS )
throw new ODBCErrors(__LINE__, SQL_HANDLE_STMT, hstmt);
if ( SQLCloseCursor(hstmt) != SQL_SUCCESS )
throw new ODBCErrors(__LINE__, SQL_HANDLE_STMT, hstmt);
SQLUSMALLINT mode = SQL_ROLLBACK;
if ( CopyFileToSQL(
TEXT("C:\\Users\\Data\\chart1.jpg"),
dstFilePath,
transactionToken,
cbTransactionToken) == TRUE )
mode = SQL_COMMIT;
SQLTransact(henv, hdbc, mode);
}
catch(ODBCErrors *pErrors)
{
pErrors->Print();
delete pErrors;
}
if ( hstmt != SQL_NULL_HANDLE )
SQLFreeHandle(SQL_HANDLE_STMT, hstmt);
if ( hdbc != SQL_NULL_HANDLE )
SQLDisconnect(hdbc);
if ( hdbc != SQL_NULL_HANDLE )
SQLFreeHandle(SQL_HANDLE_DBC, hdbc);
if ( henv != SQL_NULL_HANDLE )
SQLFreeHandle(SQL_HANDLE_ENV, henv);
}
備註
SQL Server Native Client必須安裝才能使用此 API。 SQL Server Native Client會與SQL Server或SQL Server用戶端工具一起安裝。 如需詳細資訊,請參閱 安裝 SQL Server Native Client。
另請參閱
二進位大型物件 (Blob) 資料 (SQL Server)
對 FILESTREAM 資料進行部分更新
避免與 FILESTREAM 應用程式中的資料庫作業相衝突