Skip to content

kakserpom/php-sqlx-rs

Repository files navigation

SQLx PHP Extension

CI License: MIT PHP 8.1+ Rust

The extension is powered by Rust 🦀 and SQLx, built using ext-php-rs. It enables safe, fast, and expressive database access with additional SQL syntax. It comes with a powerful query builder.

Postgres, MySQL and Mssql protocols are natively supported. Other protocols may require a custom wrapper.

The project's goals are centered o----n providing a secure and ergonomic way to interact with SQL-based DBMS without any compromise on performance.

Architecture

┌─────────────────────────────────────────────────────────────────┐
│                         PHP Application                         │
├─────────────────────────────────────────────────────────────────┤
│  DriverFactory  │  QueryBuilder  │  PreparedQuery  │  Clauses   │
├─────────────────────────────────────────────────────────────────┤
│                     Driver (PgDriver, MySqlDriver, etc.)        │
│  ┌────────────┐  ┌─────────────┐  ┌───────────────────────────┐ │
│  │ Connection │  │ Transaction │  │       Retry Policy        │ │
│  │    Pool    │  │    Stack    │  │  (exponential backoff)    │ │
│  └────────────┘  └─────────────┘  └───────────────────────────┘ │
├─────────────────────────────────────────────────────────────────┤
│                         AST Engine                              │
│  ┌────────────┐  ┌─────────────┐  ┌───────────────────────────┐ │
│  │   Parser   │  │   Renderer  │  │   LRU Cache (per shard)   │ │
│  │            │  │  (per DBMS) │  │                           │ │
│  └────────────┘  └─────────────┘  └───────────────────────────┘ │
├─────────────────────────────────────────────────────────────────┤
│                      SQLx (Rust)                                │
│         Async runtime (Tokio) + Native protocol drivers         │
├─────────────────────────────────────────────────────────────────┤
│              PostgreSQL  │  MySQL  │  SQL Server                │
└─────────────────────────────────────────────────────────────────┘

Data flow: PHP calls → Driver → AST parse/render (cached) → SQLx async execution → Database

Getting Started

Installation

Install with cargo-php:

cargo install cargo-php --locked
cd php-sqlx-cdylib

For macOS:

export MACOSX_DEPLOYMENT_TARGET=$(sw_vers -productVersion | tr -d '\n')
export RUSTFLAGS="-C link-arg=-undefined -C link-arg=dynamic_lookup"
#export RUSTFLAGS="-Zmacro-backtrace -Zproc-macro-backtrace -Clink-arg=-undefined -Clink-arg=dynamic_lookup"
cargo install cargo-php --locked
cd php-sqlx-cdylib
cargo php install --release --yes

Usage example

$driver = Sqlx\DriverFactory::make("postgres://user:pass@localhost/db");

$posts = $driver->queryAll('SELECT * FROM posts WHERE author_id = ?', [12345]);

Features

  • AST-based SQL augmentation (e.g., conditional blocks)
  • Named parameters with $param, :param, or positional :1 syntax
  • Type-safe placeholders with type suffixes (?i, ?s, ?d, ?u, ?ud)
  • Nullable type support with n prefix (?ni, ?ns, ?nud)
  • Automatic result conversion to PHP arrays or objects
  • Painless IN (?) / NOT IN (?) clauses expansion and collapse
  • Safe and robust ORDER BY / GROUP BY clauses
  • Pagination with PAGINATE
  • Safe and robust SELECT
  • SQL transactions are supported in full
  • Upsert support with upsert() (PostgreSQL ON CONFLICT, MySQL ON DUPLICATE KEY)
  • Batch inserts with insertMany() for efficient multi-row inserts
  • Powerful Query Builder
  • Native JSON support (with lazy decoding and SIMD 🚀)
  • Optional persistent connections (with connection pooling)
  • Automatic retry with exponential backoff for transient failures
  • Custom SqlxException class with error codes for precise error handling
  • Schema introspection via describeTable() for table column metadata
  • Query profiling via onQuery() callback for logging and performance monitoring
  • Connection tagging via setApplicationName() and setClientInfo() for debugging
  • Read replica support with automatic query routing and round-robin load balancing
  • IDE support for VS Code and PHPStorm (syntax highlighting, live templates)

Augmented SQL Syntax

This extension introduces a powerful SQL preprocessor that supports conditional blocks, optional fragments, and named parameters. Both positional (?, $1, :1) and named ($param, :param) placeholders are supported. All can be used interchangeably.


Conditional Blocks

Wrap parts of your query with double braces {{ ... }} to make them conditional:

SELECT *
FROM users
WHERE TRUE
  {{ AND name = $name }}
  {{ AND status = $status }}

If a named parameter used inside the block is not provided, the entire block is omitted from the final query.

Nested conditional blocks are supported:

SELECT *
FROM logs
WHERE TRUE {{ AND date > $since {{ AND level = $level }} }}

In the above example the level condition will only be rendered when both $level and $since are set.

SELECT *
FROM logs
WHERE date > $since {{ AND level = $level }}

The above example will throw an exception if $since is not set.


Type-Safe Placeholders

You can enforce type constraints on placeholders using type suffixes. When a value doesn't match the expected type, an exception is thrown during query rendering.

Scalar Types

Suffix Named Syntax Description
?i :id!i, $id!i Integer
?u :age!u, $age!u Unsigned integer (≥ 0)
?d :score!d, $score!d Decimal (int, float, or numeric string)
?ud :price!ud, $price!ud Unsigned decimal (≥ 0, int/float/numeric string)
?s :name!s, $name!s String
?j :data!j, $data!j JSON (object, array, or Json wrapper)
// Type validation examples
$driver->queryAll('SELECT * FROM users WHERE id = ?i', [42]);        // OK
$driver->queryAll('SELECT * FROM users WHERE id = ?i', ["string"]);  // Error: Type mismatch
$driver->queryAll('SELECT * FROM users WHERE age = ?u', [-5]);       // Error: negative not allowed

// Decimal accepts int, float, and numeric strings
$driver->queryAll('SELECT * FROM products WHERE price = ?d', [19.99]);     // OK (float)
$driver->queryAll('SELECT * FROM products WHERE price = ?d', [20]);        // OK (int)
$driver->queryAll('SELECT * FROM products WHERE price = ?d', ["19.99"]);   // OK (numeric string)
$driver->queryAll('SELECT * FROM products WHERE price = ?d', ["abc"]);     // Error: not numeric

// JSON serializes arrays/objects as JSON strings
$driver->execute('INSERT INTO events (data) VALUES (?j)', [['event' => 'click', 'count' => 5]]);
// Bound value: '{"event":"click","count":5}'

Array Types (for IN clauses)

Suffix Named Syntax Description
?ia :ids!ia Array of integers
?ua :ids!ua Array of unsigned integers
?da :scores!da Array of decimals
?uda :prices!uda Array of unsigned decimals
?sa :names!sa Array of strings
?ja :items!ja Array of JSON (each element serialized as JSON)
$driver->queryAll('SELECT * FROM users WHERE id IN :ids!ia', [
    'ids' => [1, 2, 3]
]); // OK

$driver->queryAll('SELECT * FROM users WHERE id IN :ids!ia', [
    'ids' => [1, "two", 3]
]); // Error: Type mismatch

// JSON array - each element is serialized as JSON (useful for PostgreSQL JSONB[])
$driver->execute(
    'INSERT INTO logs (items) VALUES (ARRAY[?ja]::jsonb[])',
    [[['type' => 'click'], ['type' => 'view']]]
);
// Expands to: ARRAY[$1, $2]::jsonb[]
// Bound values: '{"type":"click"}', '{"type":"view"}'

Nullable Types

By default, typed placeholders reject null values. Use the n prefix to allow nulls:

Suffix Named Syntax Description
?n :data!n Nullable mixed (any type including null)
?ni :id!ni Nullable integer
?nu :age!nu Nullable unsigned integer
?nd :score!nd Nullable decimal
?nud :price!nud Nullable unsigned decimal
?ns :name!ns Nullable string
?nj :data!nj Nullable JSON

Nullable array types: ?nia, ?nua, ?nda, ?nuda, ?nsa, ?nja

// Non-nullable rejects null
$driver->queryAll('SELECT * FROM users WHERE id = ?i', [null]);   // Error: Type mismatch

// Nullable accepts null
$driver->queryAll('SELECT * FROM users WHERE id = ?ni', [null]);  // OK - renders NULL
$driver->queryAll('SELECT * FROM users WHERE id = ?ni', [42]);    // OK - renders 42

Nullable in Conditional Blocks

The nullable flag affects how conditional blocks behave:

Placeholder Value Block Behavior
:status!ni (nullable) absent Block skipped
:status!ni (nullable) null Block rendered
:status!ni (nullable) 5 Block rendered
:status!i (non-nullable) null Block skipped
:status (untyped) null Block skipped
$sql = 'SELECT * FROM users WHERE 1=1 {{ AND status = :status!ni }}';

// Absent - block skipped
$driver->queryAll($sql, []);
// Result: SELECT * FROM users WHERE 1=1

// Null provided - block rendered (nullable allows null)
$driver->queryAll($sql, ['status' => null]);
// Result: SELECT * FROM users WHERE 1=1 AND status = NULL

// Value provided - block rendered
$driver->queryAll($sql, ['status' => 1]);
// Result: SELECT * FROM users WHERE 1=1 AND status = $1

This is useful when you want to explicitly query for NULL values vs. omitting the condition entirely.

Quick Reference Cheat Sheet

Type Scalar Nullable Array Nullable Array
Any ? ?n
Integer ?i ?ni ?ia ?nia
Unsigned Int ?u ?nu ?ua ?nua
Decimal ?d ?nd ?da ?nda
Unsigned Dec ?ud ?nud ?uda ?nuda
String ?s ?ns ?sa ?nsa
JSON ?j ?nj ?ja ?nja

Named syntax: Add ! before suffix: $id!i, :name!s, $prices!uda, $data!j


Painless IN (?) / NOT IN (?) clauses expansion and collapse

Passing an array as a parameter to a single placeholder automatically expands it:

// Expands to: SELECT * FROM people WHERE name IN (?, ?, ?)
// with values ['Peter', 'John', 'Jane']
$rows = $driver->queryAll(
  'SELECT * FROM people WHERE name IN :names', [
    'names' => ['Peter', 'John', 'Jane']
  ]
);

Omitting the parameter or passing an empty array will make IN collapse into boolean FALSE.

var_dump($driver->dry(
  'SELECT * FROM people WHERE name IN :names', [
    'names' => []
  ]
));
array(2) {
  [0]=>
  string(53) "SELECT * FROM people WHERE FALSE /* name IN :names */"
  [1]=>
  array(0) {
  }
}

Same goes for NOT IN, except it will collapse into boolean TRUE.

var_dump($driver->dry(
  'SELECT * FROM people WHERE name NOT IN :names', [
    'names' => []
  ]
));
array(2) {
  [0]=>
  string(56) "SELECT * FROM people WHERE TRUE /* name NOT IN :names */"
  [1]=>
  array(0) {
  }
}

Makes sense, right? Given that x IN (1, 2, 3) is sugar for (x = 1 OR x = 2 OR x = 3) and x NOT IN (1, 2, 3) is sugar for (x != 1 AND x != 2 AND x != 3).

Keep in mind that you can not only use it in WHERE, but also in ON clauses when joining.

It is true that in simpler cases of IN :empty like the above example you could just immediately return an empty result set without sending it to DBMS, but there could be a JOIN or a UNION.


Safe and robust ORDER BY / GROUP BY clauses

Sql\ByClause helper class for safe ORDER BY / GROUP BY clauses from user input.

SAFETY CONCERNS

  • 🟢 You can safely pass any user input as sorting settings.
  • 🔴 Do NOT pass unsanitized user input into ByClause constructor to avoid SQL injection vulnerabilities. If you absolutely have to, then apply array_values() to the argument to avoid SQL injections.

Examples:

// Let's define allowed columns
$orderBy = new Sqlx\ByClause([
    'name',
    'created_at',
    'random' => 'RANDOM()'
]);

// Equivalent to: SELECT * FROM users ORDER BY `name` ASC, RANDOM()
$driver->queryAll('SELECT * FROM users ORDER BY :order_by', [
  'order_by' => $orderBy([
    ['name', Sqlx\ByClause::ASC],
    'random'
  ])
]);

Field names are case-sensitive, but they get trimmed.


Pagination with PAGINATE

Sql\PaginateClause helper class for safe pagination based on user input.

// Let's define pagination rules
$pagination = new Sqlx\PaginateClause;
$pagination->perPage(5);
$pagination->maxPerPage(20);

// Equivalent to: SELECT * FROM people ORDER by id LIMIT 5 OFFSET 500
$rows = $driver->queryAll(
  'SELECT * FROM people ORDER by id PAGINATE :pagination', [
    'pagination' => $pagination(100)
  ]
);


// Equivalent to: SELECT * FROM people ORDER by id LIMIT 10 OFFSET 1000
$rows = $driver->queryAll(
  'SELECT * FROM people ORDER by id PAGINATE :pagination', [
    'pagination' => $pagination(100, 10)
  ]
);

// Equivalent to: SELECT * FROM people ORDER by id LIMIT 5 OFFSET 0
$rows = $driver->queryAll(
  'SELECT * FROM people ORDER by id PAGINATE :pagination', [
    'pagination' => $pagination()
  ]
);

You can safely pass any unsanitized values as arguments, but keep in mind that perPage()/maxPerPage()/ defaultPerPage() functions take a positive integer and throw an exception otherwise.


Safe and robust SELECT

A helper class for safe SELECT clauses from user input.

SAFETY CONCERNS

  • 🟢 You can safely pass any user input as invocation argument.
  • 🔴 Do NOT pass unsanitized user input into SelectClause constructor to avoid SQL injection vulnerabilities. If you absolutely have to, then apply array_values() to the argument to avoid SQL injections.

Examples:

$select = new Sqlx\SelectClause([
    'id',
    'created_at',
    'name',
    'num_posts' => 'COUNT(posts.*)'
]);

// Equivalent to: SELECT `id`, `name`, COUNT(posts.*) AS `num_posts` FROM users
$rows = $driver->queryAll('SELECT :select FROM users', [
  'select' => $select(['id','name', 'num_posts'])
]);

Note that column names are case-sensitive, but they get trimmed.


Transactions

$driver->begin(function($driver) {
    // All queries inside this function will be wrapped in a transaction.
    // You can use all driver functions here.
    
    $driver->insert('users', ['name' => 'John', 'age' => 25]);
    $driver->insert('users', ['name' => 'Mary', 'age' => 20]);
    
    // return false; 
});

A ROLLBACK happens if the closure returns false or throws an exception. Otherwise, a COMMIT gets sent when functions finishes normally.

Additional supported methods to be called from inside a closure:

  • savepoint(name: String)
  • rollbackToSavepoint(name: String)
  • releaseSavepoint(name: String)

Pinned Connections

For session-scoped operations that require multiple queries to run on the same connection without a database transaction, use withConnection:

$lastId = $driver->withConnection(function($driver) {
    $driver->execute("INSERT INTO users (name) VALUES ('Alice')");
    return $driver->queryValue('SELECT LAST_INSERT_ID()');
});

Use cases:

  • LAST_INSERT_ID() in MySQL (session-scoped)
  • Temporary tables (connection-scoped)
  • Session variables (SET @var = ...)
  • Advisory locks

Key differences from transactions:

  • No BEGIN/COMMIT is issued
  • Each query is auto-committed immediately
  • No rollback on failure

If you need transactional semantics (atomicity, rollback), use begin() instead.


Batch Insert

The insertMany() method inserts multiple rows in a single statement for better performance:

$driver->insertMany('users', [
    ['name' => 'Alice', 'email' => 'alice@example.com'],
    ['name' => 'Bob', 'email' => 'bob@example.com'],
    ['name' => 'Carol', 'email' => 'carol@example.com'],
]);

Generated SQL:

INSERT INTO users (email, name)
VALUES ($email_0, $name_0),
       ($email_1, $name_1),
       ($email_2, $name_2)
  • Columns are determined from the first row
  • Missing columns in subsequent rows default to NULL
  • Returns the number of inserted rows

Upsert (Insert or Update)

The upsert() method inserts a row or updates it if a conflict occurs on the specified columns:

// Insert or update user by email (unique constraint)
$driver->upsert('users', [
    'email' => 'alice@example.com',
    'name' => 'Alice',
    'login_count' => 1
], ['email'], ['name', 'login_count']);

// Update all non-key columns on conflict (auto-detect)
$driver->upsert('users', $userData, ['email']);

Database-specific SQL generated:

Database SQL Pattern
PostgreSQL INSERT ... ON CONFLICT (cols) DO UPDATE SET col = EXCLUDED.col
MySQL INSERT ... ON DUPLICATE KEY UPDATE col = VALUES(col)
MSSQL Not supported (use MERGE statement directly)

Parameters:

  • $table – Table name
  • $row – Associative array of column → value
  • $conflictColumns – Columns that form the unique constraint
  • $updateColumns – (Optional) Columns to update on conflict. If omitted, updates all non-conflict columns.

Retry Policy

The driver supports automatic retry with exponential backoff for transient failures like connection drops, pool exhaustion, and timeouts.

$driver = Sqlx\DriverFactory::make([
    Sqlx\DriverOptions::OPT_URL => 'postgres://user:pass@localhost/db',
    Sqlx\DriverOptions::OPT_RETRY_MAX_ATTEMPTS => 3,
    Sqlx\DriverOptions::OPT_RETRY_INITIAL_BACKOFF => '100ms',
    Sqlx\DriverOptions::OPT_RETRY_MAX_BACKOFF => '5s',
    Sqlx\DriverOptions::OPT_RETRY_MULTIPLIER => 2.0,
]);

Retry Behavior

  • Disabled by default – Set OPT_RETRY_MAX_ATTEMPTS > 0 to enable
  • Exponential backoff – Each retry waits longer: 100ms → 200ms → 400ms → ...
  • Capped backoff – Backoff never exceeds OPT_RETRY_MAX_BACKOFF
  • Transient errors only – Only retries pool exhaustion, timeouts, and connection errors
  • No retry in transactions – Retries are skipped inside begin() to prevent partial commits

Transient vs Non-Transient Errors

Error Type Retried? Examples
Pool exhausted ✅ Yes All connections in use
Timeout ✅ Yes Connection or query timeout
Connection error ✅ Yes Connection dropped, network error
Query error ❌ No Syntax error, constraint violation
Transaction error ❌ No Deadlock, serialization failure
Parse error ❌ No Invalid SQL syntax

Error Handling

All errors thrown by the extension are instances of exception classes in the Sqlx\Exceptions namespace. Each error type has its own exception class for precise catch handling:

use Sqlx\Exceptions\{SqlxException, QueryException, ConnectionException};

try {
    $driver->queryRow('SELECT * FROM non_existent_table');
} catch (QueryException $e) {
    // Handle query-specific errors
    echo "Query failed: " . $e->getMessage() . "\n";
} catch (ConnectionException $e) {
    // Handle connection errors
    echo "Connection failed: " . $e->getMessage() . "\n";
} catch (SqlxException $e) {
    // Catch-all for any other sqlx errors
    echo "Error: " . $e->getMessage() . "\n";
}

Exception Classes

All exceptions extend Sqlx\Exceptions\SqlxException, which extends PHP's base Exception:

Exception Class Error Code Description
Sqlx\Exceptions\SqlxException 0 Base class / General error
Sqlx\Exceptions\ConnectionException 1 Database connection failed
Sqlx\Exceptions\QueryException 2 Query execution failed
Sqlx\Exceptions\TransactionException 3 Transaction-related error
Sqlx\Exceptions\ParseException 4 SQL parsing/AST error
Sqlx\Exceptions\ParameterException 5 Missing or invalid parameter
Sqlx\Exceptions\ConfigurationException 6 Configuration/options error
Sqlx\Exceptions\ValidationException 7 Invalid identifier or input validation error
Sqlx\Exceptions\NotPermittedException 8 Operation not permitted (e.g., write on readonly)
Sqlx\Exceptions\TimeoutException 9 Operation timed out
Sqlx\Exceptions\PoolExhaustedException 10 Connection pool exhausted

Error codes are also available as constants on SqlxException for backwards compatibility:

use Sqlx\Exceptions\SqlxException;

if ($e->getCode() === SqlxException::CONNECTION) {
    // Handle connection error
}

Parameter types

Supported parameter types:

"text"
123
3.14
true
[1, 2, 3]

✅ PostgreSQL BIGINT values are safely mapped to PHP integers:

 var_dump($driver->queryValue('SELECT ((1::BIGINT << 62) - 1) * 2 + 1');
 // Output: int(9223372036854775807)

Nested arrays are automatically flattened and bound in order.

PostgreSQL/MySQL JSON types are automatically decoded into PHP arrays or objects.

var_dump($driver->queryValue(
    'SELECT $1::json',
    ['{"foo": ["bar", "baz"]}']
));
/* Output:
object(stdClass)#2 (1) {
  ["foo"]=>
  array(2) {
    [0]=>
    string(3) "bar"
    [1]=>
    string(3) "baz"
  }
}*/

var_dump($driver->queryRow(
    'SELECT $1::json AS col',
    ['{"foo": ["bar", "baz"]}']
)->col->foo[0]);
// Output: string(3) "bar"

Query Builder overview

See the full Query Builder guide.

You can fluently build SQL queries using $driver->builder():

$query = $driver->builder()
    ->select("*")
    ->from("users")
    ->where(["active" => true])
    ->orderBy("created_at DESC")
    ->limit(10);

The builder supports most SQL clauses:

  • select(), from(), where(), groupBy(), orderBy(), having()
  • insertInto(), values(), valuesMany(), returning()
  • update(), set()
  • deleteFrom(), using()
  • with(), withRecursive()
  • join(), leftJoin(), rightJoin(), fullJoin(), naturalJoin(), crossJoin()
  • onConflict(), onDuplicateKeyUpdate()
  • limit(), offset(), paginate()
  • union(), unionAll()
  • forUpdate(), forShare()
  • truncateTable(), raw(), end()

Each method returns the builder itself, allowing fluent chaining.


Insert: Multi-row Example

Use valuesMany() to insert multiple rows in one statement:

$driver->builder()->insert("users")->valuesMany([
    ["Alice", "alice@example.com"],
    ["Bob", "bob@example.com"]
]);

// or with named keys:
$driver->builder()->insert("users")->valuesMany([
    ["name" => "Alice", "email" => "alice@example.com"],
    ["name" => "Bob",   "email" => "bob@example.com"]
]);

Executing the Query

After building the query, you can run it just like with prepared statements:

$query->execute();
// OR
$row = $query->queryRow();
// OR
$rows = $query->queryAll();

You can also preview the rendered SQL and parameters without executing:

var_dump((string) $query); // SQL with placeholders rendered

API

Sql\DriverFactory

$driver = Sqlx\DriverFactory::make("postgres://user:pass@localhost/db");

Or with options:

$driver = Sqlx\DriverFactory::make([
    Sqlx\DriverOptions::OPT_URL => 'postgres://user:pass@localhost/db',
    Sqlx\DriverOptions::OPT_ASSOC_ARRAYS => true,   // return arrays instead of objects
    Sqlx\DriverOptions::OPT_PERSISTENT_NAME => 'main_db'
    Sqlx\DriverOptions::OPT_MAX_CONNECTIONS => 5,
    Sqlx\DriverOptions::OPT_MIN_CONNECTIONS => 0,
    //Sqlx\DriverOptions::OPT_MAX_LIFETIME => "30 min",
    Sqlx\DriverOptions::OPT_IDLE_TIMEOUT => 120,
    Sqlx\DriverOptions::OPT_ACQUIRE_TIMEOUT => 10,
]);

// With automatic retry for transient failures
$driver = Sqlx\DriverFactory::make([
    Sqlx\DriverOptions::OPT_URL => 'postgres://user:pass@localhost/db',
    Sqlx\DriverOptions::OPT_RETRY_MAX_ATTEMPTS => 3,        // retry up to 3 times
    Sqlx\DriverOptions::OPT_RETRY_INITIAL_BACKOFF => '100ms',
    Sqlx\DriverOptions::OPT_RETRY_MAX_BACKOFF => '5s',
    Sqlx\DriverOptions::OPT_RETRY_MULTIPLIER => 2.0,        // exponential backoff
]);
DriverOptions reference
Option Type Description Default
OPT_URL string Required. Database connection URL. Example: postgres://user:pass@localhost/db (required)
OPT_ASSOC_ARRAYS bool If true, rows are returned as associative arrays instead of objects false
OPT_PERSISTENT_NAME string | null Enables persistent connection pool reuse under a given name null
OPT_MAX_CONNECTIONS int > 0 Maximum number of connections in the pool 10
OPT_MIN_CONNECTIONS int ≥ 0 Minimum number of connections to keep alive 0
OPT_MAX_LIFETIME string | int | null Max lifetime of a pooled connection. Accepts "30s", "5 min", or seconds null
OPT_IDLE_TIMEOUT string | int | null Idle timeout before closing pooled connections. Same format as above null
OPT_ACQUIRE_TIMEOUT string | int | null Timeout to wait for a connection from the pool null
OPT_TEST_BEFORE_ACQUIRE bool Whether to test connections before acquisition false
OPT_COLLAPSIBLE_IN bool Enables automatic collapsing of IN () / NOT IN () into FALSE / TRUE true
OPT_AST_CACHE_SHARD_COUNT int > 0 Number of internal SQL AST cache shards (advanced tuning) 8
OPT_AST_CACHE_SHARD_SIZE int > 0 Max number of entries per AST cache shard 256
OPT_RETRY_MAX_ATTEMPTS int ≥ 0 Max retry attempts for transient failures (0 = disabled) 0
OPT_RETRY_INITIAL_BACKOFF string | int Initial backoff between retries. Accepts "100ms", "1s", or seconds "100ms"
OPT_RETRY_MAX_BACKOFF string | int Maximum backoff duration (caps exponential growth) "5s"
OPT_RETRY_MULTIPLIER float Backoff multiplier for exponential backoff (e.g., 2.0 doubles each retry) 2.0

Basics

  • assocArrays(): bool – returns true if the driver is currently set to produce associative arrays instead of objects.
  • prepare(string $query): Sqlx\PreparedQuery – returns a reusable prepared query object bound to the same driver.

Row helpers

Method Returns Notes
queryRow() first row (array | object) exception if no rows returned
queryRowAssoc() first row (array) ∟ enforces array mode
queryRowObj() first row (object) ∟ enforces object mode
queryMaybeRow() first row (array | object | null) null if no rows returned
queryMaybeRowAssoc() first row (array | null) ∟ enforces array mode
queryMaybeRowObj() first row (object | null) ∟ enforces object mode

Column helpers (single-row)

Method Returns Notes
queryValue() first row column value exception if no rows returned
queryValueAssoc() ∟ enforces array mode for JSON objects
queryValueObj() ∟ enforces object mode for JSON objects
queryMaybeValue() first row column value or null null if no rows returned
queryMaybeValueAssoc() ∟ enforces array mode for JSON objects
queryMaybeValueObj() ∟ enforces object mode for JSON objects

Column helpers (multi-row)

Method Returns Notes
queryColumn() array of column's values from each row exception if no rows returned
queryColumnAssoc() ∟ enforces array mode for JSON objects
queryColumnObj() ∟ enforces object mode for JSON objects

List helpers (all rows)

Method Returns
queryAll() array of rows
queryAllAssoc() array of assoc arrays
queryAllObj() array of objects

Mutation helpers

  • execute(string $query, array $parameters = null): int – run INSERT/UPDATE/DELETE and return affected count.
  • insert(string $table, array $row): int – convenience wrapper around INSERT.
  • insertMany(string $table, array $rows): int – insert multiple rows in a single statement.
  • upsert(string $table, array $row, array $conflictColumns, ?array $updateColumns = null): int – insert or update on conflict.

Utilities

  • dry(string $query, array $parameters = null): array – render final SQL + bound parameters without executing. Handy for debugging.

Quoting helpers

  • quote(mixed $value): string – quote a value as a SQL literal (e.g., 'O''Reilly', 123, TRUE).
  • quoteLike(string $value): string – quote with LIKE metacharacter escaping (% and _ escaped).
  • quoteIdentifier(string $name): string – quote an identifier (table/column name) using database-specific style.
// PostgreSQL
$driver->quote("O'Reilly");        // 'O''Reilly'
$driver->quoteLike("100%_safe");   // '100\%\_safe'
$driver->quoteIdentifier("user");  // "user"

// MySQL
$driver->quoteIdentifier("user");  // `user`

// MSSQL
$driver->quoteIdentifier("user");  // [user]

Query Profiling

  • onQuery(?callable $callback): void – registers a callback for query profiling/logging.
// Enable query logging
$driver->onQuery(function(string $sql, string $sqlInline, float $durationMs) {
    Logger::debug("Query took {$durationMs}ms: $sqlInline");
});

// Run some queries - the callback is called after each one
$users = $driver->queryAll('SELECT * FROM users WHERE status = $status', ['status' => 'active']);

// Disable the hook
$driver->onQuery(null);

The callback receives:

  • $sql – The rendered SQL with placeholders (SELECT * FROM users WHERE status = $1)
  • $sqlInline – The SQL with inlined values for logging (SELECT * FROM users WHERE status = 'active')
  • $durationMs – Execution time in milliseconds

Performance: When no hook is registered, there is zero overhead. Timing only starts when a hook is active.

Connection Tagging

Tag connections with metadata for easier debugging in database monitoring tools:

  • setApplicationName(string $name): void – sets the application name for this connection.
  • setClientInfo(string $applicationName, array $info): void – sets application name with additional metadata.
// Simple application name
$driver->setApplicationName('order-service');

// With additional context (useful for debugging)
$driver->setClientInfo('order-service', [
    'request_id' => $requestId,
    'user_id' => $userId,
]);
// Result: "order-service {request_id='abc123',user_id=42}"

Database-specific visibility:

  • PostgreSQL: Visible in pg_stat_activity.application_name
  • MySQL: Stored in session variable @sqlx_application_name (queryable via SELECT @sqlx_application_name)
  • MSSQL: Stored in session context (queryable via SELECT SESSION_CONTEXT(N'application_name'))

Read Replicas

Configure read replicas for automatic read/write splitting:

$driver = Sqlx\DriverFactory::make([
    Sqlx\DriverOptions::OPT_URL => 'postgres://user:pass@primary/db',
    Sqlx\DriverOptions::OPT_READ_REPLICAS => [
        'postgres://user:pass@replica1/db',
        'postgres://user:pass@replica2/db',
    ],
]);

// SELECT queries automatically route to replicas (round-robin)
$users = $driver->queryAll('SELECT * FROM users');

// Write operations always go to primary
$driver->execute('INSERT INTO users (name) VALUES (?s)', ['John']);

Weighted load balancing: Assign weights to control traffic distribution:

$driver = Sqlx\DriverFactory::make([
    Sqlx\DriverOptions::OPT_URL => 'postgres://user:pass@primary/db',
    Sqlx\DriverOptions::OPT_READ_REPLICAS => [
        ['url' => 'postgres://user:pass@replica1/db', 'weight' => 3],  // 75% traffic
        ['url' => 'postgres://user:pass@replica2/db', 'weight' => 1],  // 25% traffic
    ],
]);

Routing rules:

  • queryAll, queryRow, queryMaybeRow, queryValue, queryColumn → replicas
  • execute → primary
  • All queries inside transactions → primary (consistency guarantee)

Load balancing: Weighted round-robin (or simple round-robin if all weights equal).

// Check if replicas are configured
if ($driver->hasReadReplicas()) {
    echo "Read queries are load balanced across replicas";
}

Schema Introspection

  • describeTable(string $table, ?string $schema = null): array – returns column metadata for the specified table.
$columns = $driver->describeTable('users');
// Returns:
// [
//   ['name' => 'id', 'type' => 'integer', 'nullable' => false, 'default' => null, 'ordinal' => 1],
//   ['name' => 'email', 'type' => 'varchar(255)', 'nullable' => false, 'default' => null, 'ordinal' => 2],
//   ['name' => 'created_at', 'type' => 'timestamp', 'nullable' => true, 'default' => 'now()', 'ordinal' => 3],
// ]

// With explicit schema
$columns = $driver->describeTable('users', 'public');

Each column entry contains:

  • name – Column name (string)
  • type – Database-specific type (string), e.g., varchar(255), integer, timestamp
  • nullable – Whether NULL is allowed (bool)
  • default – Default value expression (string|null)
  • ordinal – 1-based column position (int)

Sqlx\PreparedQuery

Prepared queries expose exactly the same surface as the driver, but without the SQL argument:

$query = $driver->prepare('SELECT * FROM logs WHERE level = $level');
$rows  = $query->queryAll(['level' => 'warn']);

All helpers listed above have their prepared-query counterparts:

  • execute()
  • queryRow() / queryRowAssoc() / queryRowObj()
  • queryAll() / queryAllAssoc() / queryAllObj()
  • queryDictionary() / queryDictionaryAssoc() / queryDictionaryObj()
  • queryGroupedDictionary() / queryGroupedDictionaryAssoc() / queryGroupedDictionaryObj()
  • queryColumnDictionary() / queryColumnDictionaryAssoc() / queryColumnDictionaryObj()

Dictionary helpers (first column as key, row as value)

Method Returns Notes
queryDictionary() array<string | int, array | object> key = first column, value = entire row
queryDictionaryAssoc() array<string | int, array> ∟ forces associative arrays
queryDictionaryObj() array<string | int, object> ∟ forces objects
  • ⚠️ First column must be scalar, otherwise an exception will be thrown.
  • 🔀 The iteration order is preserved.
var_dump($driver->queryGroupedColumnDictionary(
    'SELECT department, name FROM employees WHERE department IN (?)',
    [['IT', 'HR']]
));
/* Output:
array(2) {
  ["IT"]=> array("Alice", "Bob")
  ["HR"]=> array("Eve")
}
*/

Column Dictionary helpers (first column as key, second as value)

Method Returns Notes
queryColumnDictionary() array<string | int, mixed> key = first column, value = second column
queryColumnDictionaryAssoc() ∟ enforces array mode for second column if it's a JSON
queryColumnDictionaryObj() ∟ enforces object mode for second column if it's a JSON
var_dump($driver->queryColumnDictionary(
    'SELECT name, age FROM people WHERE name IN (?)',
    [["Peter", "John", "Jane"]]
));
/* Output:
array(1) {
  ["John"]=>
  int(22)
}
*/

Grouped Dictionary helpers (first column as key, many rows per key)

Method Returns Notes
queryGroupedDictionary() array<string, array<array | object>> key = first column, value = list of matching rows
queryGroupedDictionaryAssoc() array<string, array<array> ∟ forces associative arrays
queryGroupedDictionaryObj() array<string, array<object>> ∟ forces objects
var_dump($driver->queryGroupedDictionary(
    'SELECT department, name FROM employees WHERE department IN (?)',
    [['IT', 'HR']]
));
/* Output:
array(1) {
  ["IT"]=>
  array(2) {
    [0]=>
    object(stdClass)#2 (2) {
      ["department"]=>
      string(2) "IT"
      ["name"]=>
      string(5) "Alice"
    }
    [1]=>
    object(stdClass)#3 (2) {
      ["department"]=>
      string(2) "IT"
      ["name"]=>
      string(3) "Bob"
    }
  }
}
*/

Interfaces

⚠️ Note: Due to current limitations in ext-php-rs, it is not yet possible to declare PHP interfaces directly from within a Rust extension. This feature is actively being developed.

Until this is resolved, you can still benefit from type hints, auto-completion, and instanceof checks by including the interfaces.php stub early in your PHP application:

require_once '/path/to/sqlx/interfaces.php';

This stub defines the expected interfaces and registers them before any classes from the extension are loaded. The extension will automatically associate its internal classes with these interfaces at runtime when they get instantiated for the first time.


Available Interfaces

namespace Sqlx;

/**
 * Represents a database driver (e.g. PostgreSQL, MySQL, SQL Server).
 *
 * Drivers expose methods to create builders and manage connections.
 */
interface DriverInterface {}

/**
 * Represents a prepared SQL query that can be executed or fetched.
 *
 * Allows safe parameter binding and controlled query execution.
 */
interface PreparedQueryInterface {}

/**
 * Factory for creating query builders and managing connections.
 *
 * Handles master/slave configuration and provides both read and write builders.
 */
interface FactoryInterface {}

/**
 * Base interface for fluent SQL query builders.
 *
 * Includes methods like `from()`, `where()`, `groupBy()`, `orderBy()`, etc.
 * Suitable for generic query construction.
 */
interface QueryBuilderInterface {}

/**
 * Interface for read-only query builders.
 *
 * Adds `select()`, `limit()`, `offset()`, `forUpdate()`, and other non-mutating clauses.
 */
interface ReadQueryBuilderInterface extends QueryBuilderInterface {}

/**
 * Interface for builders that support INSERT/UPDATE/DELETE queries.
 *
 * Extends the read builder with methods like `insertInto()`, `update()`, `deleteFrom()`, and `set()`.
 */
interface WriteQueryBuilderInterface extends ReadQueryBuilderInterface {}

Design Philosophy

These interfaces follow the SOLID principles, particularly:

  • Interface Segregation Principle – Read and write operations are clearly separated.
  • Liskov Substitution Principle – Code working with ReadQueryBuilderInterface doesn’t require awareness of mutation.
  • Dependency Inversion Principle – You can depend on high-level interfaces (e.g. for mocking or type-constrained injection).

This structure makes it easier to write generic code that works across multiple database types and capabilities. For example:

function exportAsCsv(Sqlx\ReadQueryBuilderInterface $builder): void {
    $builder->select("*")->from("users");
    $rows = $builder->fetchAll();
    // ...
}

You can later swap in a full WriteQueryBuilderInterface without changing the contract.


Performance

Well, it's fast. Nothing like similar projects written in userland PHP.

The AST cache eliminates repeated parsing overhead and speeds up query rendering.

JSON decoding is lazy (on-demand) with optional SIMD support.

Rust benchmark suite

It is useful for measuring the performance of backend parts such as AST parsing/rendering.

Command:

cargo bench

M1 Max results for parsing and rendering without AST caching:

Ast::parse_small        time:   [2.2591 µs 2.2661 µs 2.2744 µs]
Found 5 outliers among 100 measurements (5.00%)
  3 (3.00%) high mild
  2 (2.00%) high severe

Ast::parse_big          time:   [6.6006 µs 6.6175 µs 6.6361 µs]
Found 9 outliers among 100 measurements (9.00%)
  5 (5.00%) high mild
  4 (4.00%) high severe

Ast::render_big         time:   [607.02 ns 608.43 ns 610.11 ns]
Found 8 outliers among 100 measurements (8.00%)
  4 (4.00%) high mild
  4 (4.00%) high severe

PHP benchmarks

Run:

cd benches
curl -s https://raw.githubusercontent.com/composer/getcomposer.org/f3108f64b4e1c1ce6eb462b159956461592b3e3e/web/installer | php -- --quiet
./composer.phar require phpbench/phpbench --dev
./vendor/bin/phpbench run benchmark.php

Or use Docker:

docker build . -t php-sqlx-benches
docker run php-sqlx-benches

M1 Max results for parsing and rendering with AST caching:

    benchDrySmall...........................I0 - Mo1.246μs (±0.00%)
    benchDryBig.............................I0 - Mo2.906μs (±0.00%)

Running Tests

cargo test

Fuzzing

The AST parser can be fuzzed to find edge cases and potential security issues:

# Install cargo-fuzz (requires nightly)
cargo install cargo-fuzz

# Run the PostgreSQL parser fuzzer
cargo +nightly fuzz run ast_postgres

# Run for 60 seconds
cargo +nightly fuzz run ast_postgres -- -max_total_time=60

Available fuzz targets:

  • ast_postgres - PostgreSQL parser
  • ast_mysql - MySQL parser
  • ast_mssql - MSSQL parser
  • ast_render - Parser + renderer with random parameters

See fuzz/README.md for more details.


IDE Support

Syntax highlighting for conditional blocks ({{ }}), type-safe placeholders (?i, ?s), and named parameters.

VS Code

Install the extension from editors/vscode:

cd editors/vscode
npx vsce package
# Then install the .vsix file in VS Code

Or manually copy/symlink to ~/.vscode/extensions/php-sqlx.

Features:

  • Highlights {{ }} conditional blocks
  • Highlights typed placeholders (?i, ?ni, ?ia, $name!s)
  • Auto-injects into PHP strings starting with SQL keywords

See editors/vscode/README.md for details.

PHPStorm / IntelliJ

Import the language injection configuration:

  1. Settings > Editor > Language Injections
  2. Click Import and select editors/phpstorm/IntelliLang.xml

Also includes live templates for common patterns (sqlxq, sqlxcond, sqlxtx).

See editors/phpstorm/README.md for details.


Testing

Running Unit Tests (Rust)

cargo test --all-features

Running Integration Tests (PHPUnit)

Start the test databases with Docker Compose:

docker-compose up -d

Install PHPUnit and run tests:

cd tests
composer install
vendor/bin/phpunit                       # Run all tests
vendor/bin/phpunit --testsuite PostgreSQL  # PostgreSQL only
vendor/bin/phpunit --testsuite MySQL       # MySQL only
vendor/bin/phpunit --testsuite MSSQL       # MSSQL only

Test Configuration

Database URLs are configured in tests/phpunit.xml:

<env name="POSTGRES_URL" value="postgres://postgres:postgres@localhost:5432/test_db"/>
<env name="MYSQL_URL" value="mysql://root:root@localhost:3306/test_db"/>
<env name="MSSQL_URL" value="mssql://sa:TestPassword123!@localhost:1433/test_db?TrustServerCertificate=true"/>

Test Coverage

The integration tests cover:

  • Connection handling
  • Basic queries (queryAll, queryRow, queryMaybeRow, queryValue, queryColumn)
  • Named and positional parameters
  • Type-safe placeholders
  • IN clause expansion
  • Conditional blocks
  • Transactions (commit, rollback, callback)
  • Schema introspection (describeTable)
  • Query hooks
  • Connection tagging
  • Database-specific features (RETURNING, OUTPUT, JSON types, etc.)

License

MIT

About

A modern feature-rich SQL driver for PHP.

Topics

Resources

License

Stars

Watchers

Forks

Releases

No releases published

Packages

No packages published