Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register todayThis browser is no longer supported.
Upgrade to Microsoft Edge to take advantage of the latest features, security updates, and technical support.
This article provides information on how to develop PHP applications using Always Encrypted (Database Engine) and the PHP Drivers for SQL Server.
Always Encrypted allows client applications to encrypt sensitive data and never reveal the data or the encryption keys to SQL Server or Azure SQL Database. An Always Encrypted enabled driver, such as the ODBC Driver for SQL Server, transparently encrypts and decrypts sensitive data in the client application. The driver automatically determines which query parameters correspond to sensitive database columns (protected using Always Encrypted), and encrypts the values of those parameters before passing the data to SQL Server or Azure SQL Database. Similarly, the driver transparently decrypts data retrieved from encrypted database columns in query results. For more information, see Always Encrypted (Database Engine). The PHP Drivers for SQL Server use the ODBC Driver for SQL Server to encrypt sensitive data.
The easiest way to enable the encryption of parameters targeting the encrypted columns and the decryption of query results is by setting the value of the ColumnEncryption
connection string keyword to Enabled
. The following are examples of enabling Always Encrypted in the SQLSRV and PDO_SQLSRV drivers:
SQLSRV:
$connectionInfo = array("Database"=>$databaseName, "UID"=>$uid, "PWD"=>$pwd, "ColumnEncryption"=>"Enabled");
$conn = sqlsrv_connect($server, $connectionInfo);
PDO_SQLSRV:
$connectionInfo = "Database = $databaseName; ColumnEncryption = Enabled;";
$conn = new PDO("sqlsrv:server = $server; $connectionInfo", $uid, $pwd);
Enabling Always Encrypted isn't sufficient for encryption or decryption to succeed; you also need to make sure that:
Once you enable Always Encrypted on a connection, you can use standard SQLSRV APIs (see SQLSRV Driver API Reference) or PDO_SQLSRV APIs (see PDO_SQLSRV Driver API Reference) to retrieve or modify data in encrypted database columns. Assuming your application has the required database permissions and can access the column master key, the driver encrypts any query parameters that target encrypted columns and decrypt data retrieved from encrypted columns, behaving transparently to the application as if the columns weren't encrypted.
If Always Encrypted isn't enabled, queries with parameters that target encrypted columns fail. Data can still be retrieved from encrypted columns, as long as the query has no parameters targeting encrypted columns. However, the driver doesn't attempt any decryption and the application receives the binary encrypted data (as byte arrays).
The following table summarizes the behavior of queries, depending on whether Always Encrypted is enabled or not:
Query characteristic | Always Encrypted is enabled and application can access the keys and key metadata | Always Encrypted is enabled and application can't access the keys or key metadata | Always Encrypted is disabled |
---|---|---|---|
Parameters targeting encrypted columns. | Parameter values are transparently encrypted. | Error | Error |
Retrieving data from encrypted columns, without parameters targeting encrypted columns. | Results from encrypted columns are transparently decrypted. The application receives plaintext column values. | Error | Results from encrypted columns aren't decrypted. The application receives encrypted values as byte arrays. |
The following examples illustrate retrieving and modifying data in encrypted columns. The examples assume a table with the following schema. The SSN and BirthDate columns are encrypted.
CREATE TABLE [dbo].[Patients](
[PatientId] [int] IDENTITY(1,1),
[SSN] [char](11) COLLATE Latin1_General_BIN2
ENCRYPTED WITH (ENCRYPTION_TYPE = DETERMINISTIC,
ALGORITHM = 'AEAD_AES_256_CBC_HMAC_SHA_256',
COLUMN_ENCRYPTION_KEY = CEK1) NOT NULL,
[FirstName] [nvarchar](50) NULL,
[LastName] [nvarchar](50) NULL,
[BirthDate] [date]
ENCRYPTED WITH (ENCRYPTION_TYPE = RANDOMIZED,
ALGORITHM = 'AEAD_AES_256_CBC_HMAC_SHA_256',
COLUMN_ENCRYPTION_KEY = CEK1) NOT NULL
PRIMARY KEY CLUSTERED ([PatientId] ASC) ON [PRIMARY])
GO
The following examples demonstrate how to use the SQLSRV and PDO_SQLSRV drivers to insert a row into the Patient table. Note the following points:
sqlsrv_prepare
and sqlsrv_execute
to execute a parameterized query.sqlsrv_prepare
and sqlsrv_execute
.sqlsrv_query
is preferred, the user is responsible for specifying the SQL types for all parameters. The specified SQL type must include the string length for string types, and the scale and precision for decimal types.PDO::SQLSRV_ATTR_DIRECT_QUERY
isn't supported in a parameterized query.PDO::ATTR_EMULATE_PREPARES
isn't supported in a parameterized query.SQLSRV driver and sqlsrv_prepare:
// insertion into encrypted columns must use a parameterized query
$query = "INSERT INTO [dbo].[Patients] ([SSN], [FirstName], [LastName], [BirthDate]) VALUES (?, ?, ?, ?)";
$ssn = "795-73-9838";
$firstName = "Catherine";
$lastName = "Abel;
$birthDate = "1996-10-19";
$params = array($ssn, $firstName, $lastName, $birthDate);
// during sqlsrv_prepare, the driver determines the SQL types for each parameter and pass them to SQL Server
$stmt = sqlsrv_prepare($conn, $query, $params);
sqlsrv_execute($stmt);
SQLSRV driver and sqlsrv_query:
// insertion into encrypted columns must use a parameterized query
$query = "INSERT INTO [dbo].[Patients] ([SSN], [FirstName], [LastName], [BirthDate]) VALUES (?, ?, ?, ?)";
$ssn = "795-73-9838";
$firstName = "Catherine";
$lastName = "Abel";
$birthDate = "1996-10-19";
// need to provide the SQL types for ALL parameters
// note the SQL types (including the string length) have to be the same at the column definition
$params = array(array(&$ssn, null, null, SQLSRV_SQLTYPE_CHAR(11)),
array(&$firstName, null, null, SQLSRV_SQLTYPE_NVARCHAR(50)),
array(&$lastName, null, null, SQLSRV_SQLTYPE_NVARCHAR(50)),
array(&$birthDate, null, null, SQLSRV_SQLTYPE_DATE));
sqlsrv_query($conn, $query, $params);
PDO_SQLSRV driver and PDO::prepare:
// insertion into encrypted columns must use a parameterized query
$query = "INSERT INTO [dbo].[Patients] ([SSN], [FirstName], [LastName], [BirthDate]) VALUES (?, ?, ?, ?)";
$ssn = "795-73-9838";
$firstName = "Catherine";
$lastName = "Able";
$birthDate = "1996-10-19";
// during PDO::prepare, the driver determines the SQL types for each parameter and pass them to SQL Server
$stmt = $conn->prepare($query);
$stmt->bindParam(1, $ssn);
$stmt->bindParam(2, $firstName);
$stmt->bindParam(3, $lastName);
$stmt->bindParam(4, $birthDate);
$stmt->execute();
The following examples demonstrate filtering data based on encrypted values, and retrieving plaintext data from encrypted columns using the SQLSRV and PDO_SQLSRV drivers. Note the following points:
Note
Queries can perform equality comparisons on encrypted columns only if the encryption is deterministic.
SQLSRV:
// since SSN is an encrypted column, need to pass the value in the WHERE clause through bind parameter
$query = "SELECT [SSN], [FirstName], [LastName], [BirthDate] FROM [dbo].[Patients] WHERE [SSN] = ?";
$ssn = "795-73-9838";
$stmt = sqlsrv_prepare($conn, $query, array(&$ssn));
// during sqlsrv_execute, the driver encrypts the ssn value and passes it to the database
sqlsrv_execute($stmt);
// fetch like usual
$row = sqlsrv_fetch_array($stmt);
PDO_SQLSRV:
// since SSN is an encrypted column, need to pass the value in the WHERE clause through bind parameter
$query = "SELECT [SSN], [FirstName], [LastName], [BirthDate] FROM [dbo].[Patients] WHERE [SSN] = ?";
$ssn = "795-73-9838";
$stmt = $conn->prepare($query);
$stmt->bindParam(1, $ssn);
// during PDOStatement::execute, the driver encrypts the ssn value and passes it to the database
$stmt->execute();
// fetch like usual
$row = $stmt->fetch();
If Always Encrypted isn't enabled, a query can still retrieve data from encrypted columns, as long as the query has no parameters targeting encrypted columns.
The following examples illustrate retrieving binary encrypted data from encrypted columns using the SQLSRV and PDO_SQLSRV drivers. Note the following points:
SQLSRV:
$query = "SELECT [SSN], [FirstName], [LastName], [BirthDate] FROM [dbo].[Patients] WHERE [LastName] = ?";
$lastName = "Abel";
$stmt = sqlsrv_prepare($conn, $query, array(&$lastName));
sqlsrv_execute($stmt);
$row = sqlsrv_fetch_array($stmt);
PDO_SQLSRV:
$query = "SELECT [SSN], [FirstName], [LastName], [BirthDate] FROM [dbo].[Patients] WHERE [LastName] = ?";
$lastName = "Abel";
$stmt = $conn->prepare($query);
$stmt->bindParam(1, $lastName);
$stmt->execute();
$row = $stmt->fetch();
This section describes common categories of errors when querying encrypted columns from PHP applications and a few guidelines on how to avoid them.
Always Encrypted supports few conversions for encrypted data types. See Always Encrypted (Database Engine) for the detailed list of supported type conversions. Do the following to avoid data type conversion errors:
sqlsrv_prepare
and sqlsrv_execute
the SQL type, along with the column size and the number of decimal digits of the parameter is automatically determined.sqlsrv_query
to execute a query:
decimal
and numeric
SQL Server data types is the same as the precision and scale configure for the target column.datetime2
, datetimeoffset
, or time
SQL Server data types isn't greater than the precision for the target column, in queries that modify the target column.PDO::SQLSRV_ATTR_DIRECT_QUERY
or PDO::ATTR_EMULATE_PREPARES
in a parameterized queryAny value that targets an encrypted column needs to be encrypted before being sent to the server. An attempt to insert, modify, or filter by a plaintext value on an encrypted column results in an error. To prevent such errors, make sure that:
ColumnEncryption
keyword to Enabled
).$query = "SELECT [SSN], [FirstName], [LastName], [BirthDate] FROM [dbo].[Patients] WHERE SSN='795-73-9838'";
Because Always Encrypted is a client-side encryption technology, most of the performance overhead is observed on the client side, not in the database. Apart from the cost of encryption and decryption operations, the other sources of performance overhead on the client side are:
If Always Encrypted is enabled for a connection, the ODBC Driver will, by default, call sys.sp_describe_parameter_encryption for each parameterized query, passing the query statement (without any parameter values) to SQL Server. This stored procedure analyzes the query statement to find out if any parameters need to be encrypted, and if so, returns the encryption-related information for each parameter to allow the driver to encrypt them.
Since the PHP drivers allow the user to bind a parameter in a prepared statement without providing the SQL type, when binding a parameter in an Always Encrypted enabled connection, the PHP Drivers call SQLDescribeParam on the parameter to get the SQL type, column size, and decimal digits. The metadata is then used to call SQLBindParameter. These extra SQLDescribeParam
calls don't require extra round-trips to the database as the ODBC Driver has already stored the information on the client side when sys.sp_describe_parameter_encryption
was called.
The preceding behaviors ensure a high level of transparency to the client application (and the application developer) doesn't need to be aware of which queries access encrypted columns, as long as the values targeting encrypted columns are passed to the driver in parameters.
Unlike the ODBC Driver for SQL Server, enabling Always Encrypted at the statement/query-level isn't yet supported in the PHP drivers.
To reduce the number of calls to a column master key store to decrypt column encryption keys (CEK), the driver caches the plaintext CEKs in memory. After receiving the encrypted CEK (ECEK) from database metadata, the ODBC driver first tries to find the plaintext CEK corresponding to the encrypted key value in the cache. The driver calls the key store containing the CMK only if it can't find the corresponding plaintext CEK in the cache.
Note: In the ODBC Driver for SQL Server, the entries in the cache are evicted after a two-hour timeout. This behavior means that for a given ECEK, the driver contacts the key store only once during the lifetime of the application or every two hours, whichever is less.
To encrypt or decrypt data, the driver needs to obtain a CEK that is configured for the target column. CEKs are stored in encrypted form (ECEKs) in the database metadata. Each CEK has a corresponding CMK that was used to encrypt it. The database metadata doesn't store the CMK itself; it only contains the name of the key store and information that the key store can use to locate the CMK.
To obtain the plaintext value of an ECEK, the driver first obtains the metadata about both the CEK and its corresponding CMK, and then it uses this information to contact the key store containing the CMK and requests it to decrypt the ECEK. The driver communicates with a key store using a key store provider.
For Microsoft Driver 5.3.0 for PHP for SQL Server, only Windows Certificate Store Provider and Azure Key Vault are supported. The other Keystore Provider supported by the ODBC Driver (Custom Keystore Provider) isn't yet supported.
The ODBC Driver for SQL Server on Windows includes a built-in column master key store provider for the Windows Certificate Store, named MSSQL_CERTIFICATE_STORE
. (This provider isn't available on macOS or Linux.) With this provider, the CMK is stored locally on the client machine and no other configuration by the application is necessary to use it with the driver. However, the application must have access to the certificate and its private key in the store. For more information, see Create and Store Column Master Keys (Always Encrypted).
Azure Key Vault offers a way to store encryption keys, passwords, and other secrets using Azure and can be used to store keys for Always Encrypted. The ODBC Driver for SQL Server (version 17 and higher) includes a built-in master key store provider for Azure Key Vault. The following connection options handle Azure Key Vault configuration: KeyStoreAuthentication
, KeyStorePrincipalId
, and KeyStoreSecret
.
KeyStoreAuthentication
can take one of two possible string values: KeyVaultPassword
and KeyVaultClientSecret
. These values control what kind of authentication credentials are used with the other two keywords.KeyStorePrincipalId
takes a string representing an identifier for the account seeking to access the Azure Key Vault.
KeyStoreAuthentication
is set to KeyVaultPassword
, then KeyStorePrincipalId
must be the name of a Microsoft Entra user.KeyStoreAuthentication
is set to KeyVaultClientSecret
, then KeyStorePrincipalId
must be an application client ID.KeyStoreSecret
takes a string representing a credential secret.
KeyStoreAuthentication
is set to KeyVaultPassword
, then KeyStoreSecret
must be the user's password.KeyStoreAuthentication
is set to KeyVaultClientSecret
, then KeyStoreSecret
must be the application secret associated with the application client ID.All three options must be present in the connection string to use Azure Key Vault. Also, ColumnEncryption
must be set to Enabled
. If ColumnEncryption
is set to Disabled
but the Azure Key Vault options are present, the script will continue without errors but no encryption will be performed.
The following examples show how to connect to SQL Server using Azure Key Vault.
SQLSRV:
Using a Microsoft Entra account:
$connectionInfo = array("Database"=>$databaseName, "UID"=>$uid, "PWD"=>$pwd, "ColumnEncryption"=>"Enabled", "KeyStoreAuthentication"=>"KeyVaultPassword", "KeyStorePrincipalId"=>$MSEntraUsername, "KeyStoreSecret"=>$MSEntraPassword);
$conn = sqlsrv_connect($server, $connectionInfo);
Using an Azure application client ID and secret:
$connectionInfo = array("Database"=>$databaseName, "UID"=>$uid, "PWD"=>$pwd, "ColumnEncryption"=>"Enabled", "KeyStoreAuthentication"=>"KeyVaultClientSecret", "KeyStorePrincipalId"=>$applicationClientID, "KeyStoreSecret"=>$applicationClientSecret);
$conn = sqlsrv_connect($server, $connectionInfo);
PDO_SQLSRV: Using a Microsoft Entra account:
$connectionInfo = "Database = $databaseName; ColumnEncryption = Enabled; KeyStoreAuthentication = KeyVaultPassword; KeyStorePrincipalId = $AADUsername; KeyStoreSecret = $AADPassword;";
$conn = new PDO("sqlsrv:server = $server; $connectionInfo", $uid, $pwd);
Using an Azure application client ID and secret:
$connectionInfo = "Database = $databaseName; ColumnEncryption = Enabled; KeyStoreAuthentication = KeyVaultClientSecret; KeyStorePrincipalId = $applicationClientID; KeyStoreSecret = $applicationClientSecret;";
$conn = new PDO("sqlsrv:server = $server; $connectionInfo", $uid, $pwd);
SQLSRV and PDO_SQLSRV:
SQLSRV only:
sqlsrv_query
for binding parameter without specifying the SQL typesqlsrv_prepare
for binding parameters in a batch of SQL statementsPDO_SQLSRV only:
PDO::SQLSRV_ATTR_DIRECT_QUERY
statement attribute specified in a parameterized queryPDO::ATTR_EMULATE_PREPARE
statement attribute specified in a parameterized queryThe PHP drivers also inherit the limitations imposed by the ODBC Driver for SQL Server and the database. See Limitations of the ODBC driver when using Always Encrypted and Always Encrypted limitations.
Programming Guide for PHP SQL Driver
SQLSRV Driver API Reference
PDO_SQLSRV Driver API Reference
Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register todayTraining