Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Prepared statement support for SQL Server #78

Merged
merged 1 commit into from
Jan 29, 2017
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
27 changes: 27 additions & 0 deletions Tests/DriverSqlsrvTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -484,6 +484,33 @@ public function testExecute()
$this->assertNotEquals(self::$driver->execute(), false, __LINE__);
}

/**
* Test the execute method with a prepared statement
*
* @return void
*
* @since 1.0
*/
public function testExecutePreparedStatement()
{
$title = 'testTitle';
$startDate = '2013-04-01 00:00:00.000';
$description = 'description';

/** @var \Joomla\Database\Sqlsrv\SqlsrvQuery $query */
$query = self::$driver->getQuery(true);
$query->insert('jos_dbtest')
->columns('title,start_date,description')
->values('?, ?, ?');
$query->bind(1, $title);
$query->bind(2, $startDate);
$query->bind(3, $description);

self::$driver->setQuery($query);

$this->assertNotEquals(self::$driver->execute(), false, __LINE__);
}

/**
* Tests the renameTable method
*
Expand Down
65 changes: 60 additions & 5 deletions src/Sqlsrv/SqlsrvDriver.php
Original file line number Diff line number Diff line change
Expand Up @@ -8,9 +8,12 @@

namespace Joomla\Database\Sqlsrv;

use Joomla\Database\DatabaseQuery;
use Joomla\Database\Exception\ConnectionFailureException;
use Joomla\Database\Exception\ExecutionFailureException;
use Joomla\Database\Exception\UnsupportedAdapterException;
use Joomla\Database\Query\LimitableInterface;
use Joomla\Database\Query\PreparableInterface;
use Psr\Log;
use Joomla\Database\DatabaseDriver;

Expand Down Expand Up @@ -604,18 +607,33 @@ public function execute()
$this->errorNum = 0;
$this->errorMsg = '';

$options = array();

// SQLSrv_num_rows requires a static or keyset cursor.
if (strncmp(ltrim(strtoupper($sql)), 'SELECT', strlen('SELECT')) == 0)
{
$array = array('Scrollable' => SQLSRV_CURSOR_KEYSET);
$options = array('Scrollable' => SQLSRV_CURSOR_KEYSET);
}
else

$params = array();

// Bind the variables:
if ($this->sql instanceof PreparableInterface)
{
$array = array();
$bounded =& $this->sql->getBounded();
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

What's the reason for this being via reference?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

To be perfectly honest, not a clue. It's how the other implementations do it though, so I assume there was a reason at some point.


if (count($bounded))
{
foreach ($bounded as $key => $obj)
{
// And add the value as an additional param
$params[] = $obj->value;
}
}
}

// Execute the query. Error suppression is used here to prevent warnings/notices that the connection has been lost.
$this->cursor = @sqlsrv_query($this->connection, $sql, array(), $array);
$this->cursor = @sqlsrv_query($this->connection, $sql, $params, $options);

// If an error occurred handle it.
if (!$this->cursor)
Expand Down Expand Up @@ -803,6 +821,38 @@ public function select($database)
return true;
}

/**
* Sets the SQL statement string for later execution.
*
* @param DatabaseQuery|string $query The SQL statement to set either as a DatabaseQuery object or a string.
* @param integer $offset The affected row offset to set.
* @param integer $limit The maximum affected rows to set.
*
* @return SqlsrvDriver This object to support method chaining.
*
* @since __DEPLOY_VERSION__
*/
public function setQuery($query, $offset = null, $limit = null)
{
$this->connect();

$this->freeResult();

if (is_string($query))
{
// Allows taking advantage of bound variables in a direct query:
$query = $this->getQuery(true)->setQuery($query);
}

if ($query instanceof LimitableInterface && !is_null($offset) && !is_null($limit))
{
$query->setLimit($limit, $offset);
}

// Store reference to the DatabaseQuery instance
return parent::setQuery($query, $offset, $limit);
}

/**
* Set the connection to use UTF-8 character encoding.
*
Expand Down Expand Up @@ -962,7 +1012,12 @@ protected function fetchObject($cursor = null, $class = 'stdClass')
*/
protected function freeResult($cursor = null)
{
sqlsrv_free_stmt($cursor ? $cursor : $this->cursor);
$useCursor = $cursor ?: $this->cursor;

if (is_resource($useCursor))
{
sqlsrv_free_stmt($useCursor);
}
}

/**
Expand Down
101 changes: 100 additions & 1 deletion src/Sqlsrv/SqlsrvQuery.php
Original file line number Diff line number Diff line change
Expand Up @@ -10,14 +10,15 @@

use Joomla\Database\DatabaseDriver;
use Joomla\Database\DatabaseQuery;
use Joomla\Database\Query\PreparableInterface;
use Joomla\Database\Query\QueryElement;

/**
* SQL Server Query Building Class.
*
* @since 1.0
*/
class SqlsrvQuery extends DatabaseQuery
class SqlsrvQuery extends DatabaseQuery implements PreparableInterface
{
/**
* The character(s) used to quote SQL statement names such as table names or field names,
Expand All @@ -39,6 +40,14 @@ class SqlsrvQuery extends DatabaseQuery
*/
protected $null_date = '1900-01-01 00:00:00';

/**
* Holds key / value pair of bound objects.
*
* @var mixed
* @since __DEPLOY_VERSION__
*/
protected $bounded = array();

/**
* Magic function to convert the query to a string.
*
Expand Down Expand Up @@ -95,6 +104,96 @@ public function __toString()
return $query;
}

/**
* Method to add a variable to an internal array that will be bound to a prepared SQL statement before query execution. Also
* removes a variable that has been bounded from the internal bounded array when the passed in value is null.
*
* @param string|integer $key The key that will be used in your SQL query to reference the value. Usually of
* the form ':key', but can also be an integer.
* @param mixed &$value The value that will be bound. The value is passed by reference to support output
* parameters such as those possible with stored procedures.
* @param string $dataType The corresponding bind type. (Unused)
* @param integer $length The length of the variable. Usually required for OUTPUT parameters. (Unused)
* @param array $driverOptions Optional driver options to be used. (Unused)
*
* @return SqlsrvQuery
*
* @since __DEPLOY_VERSION__
*/
public function bind($key = null, &$value = null, $dataType = 's', $length = 0, $driverOptions = array())
{
// Case 1: Empty Key (reset $bounded array)
if (empty($key))
{
$this->bounded = array();

return $this;
}

// Case 2: Key Provided, null value (unset key from $bounded array)
if (is_null($value))
{
if (isset($this->bounded[$key]))
{
unset($this->bounded[$key]);
}

return $this;
}

$obj = new \stdClass;
$obj->value = &$value;

// Case 3: Simply add the Key/Value into the bounded array
$this->bounded[$key] = $obj;

return $this;
}

/**
* Retrieves the bound parameters array when key is null and returns it by reference. If a key is provided then that item is
* returned.
*
* @param mixed $key The bounded variable key to retrieve.
*
* @return mixed
*
* @since __DEPLOY_VERSION__
*/
public function &getBounded($key = null)
{
if (empty($key))
{
return $this->bounded;
}

if (isset($this->bounded[$key]))
{
return $this->bounded[$key];
}
}

/**
* Clear data from the query or a specific clause of the query.
*
* @param string $clause Optionally, the name of the clause to clear, or nothing to clear the whole query.
*
* @return SqlsrvQuery Returns this object to allow chaining.
*
* @since __DEPLOY_VERSION__
*/
public function clear($clause = null)
{
switch ($clause)
{
case null:
$this->bounded = array();
break;
}

return parent::clear($clause);
}

/**
* Casts a value to a char.
*
Expand Down