Skip to content
Open
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
110 changes: 110 additions & 0 deletions doc/README.using_statement.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,110 @@
# The `USING` Statement

## Overview

The `USING` statement is a new DSQL extension designed to bridge the gap between standard DSQL statements and the
powerful but verbose `EXECUTE BLOCK`.

When adapting a standard DSQL command to use `EXECUTE BLOCK` (for instance, to utilize sub-routines or reuse a single
input parameter in multiple places), the developer is currently forced to explicitly declare all input parameters and,
more tediously, all output fields.

The `USING` statement simplifies this workflow. It provides the ability to declare parameters and sub-routines while
allowing the engine to infer outputs automatically from the contained SQL command.

## Syntax

```sql
USING [ ( <input_parameter_list> ) ]
[ <subroutines> ]
DO <sql_command>
```

**Note:** At least one of `<input_parameter_list>` or `<subroutines>` must be present. A `USING ... DO` statement
without parameters and without subroutines is invalid.

### Components

* **`<input_parameter_list>`**: A strictly typed list of parameters. These can be bound to values using the `?`
placeholder.
* **`<subroutines>`**: Standard PSQL function or procedure declarations.
* **`<sql_command>`**: The DSQL statement to execute. Supported statements include:
* `SELECT`
* `INSERT` (with or without `RETURNING`)
* `UPDATE` (with or without `RETURNING`)
* `UPDATE OR INSERT` (with or without `RETURNING`)
* `DELETE` (with or without `RETURNING`)
* `MERGE` (with or without `RETURNING`)
* `CALL`
* `EXECUTE PROCEDURE`

## Key Features

1. **Inferred Outputs**: Unlike `EXECUTE BLOCK`, you do not need to explicitly declare a `RETURNS (...)` clause. The
output columns are automatically inferred from the `<sql_command>` in the `DO` clause.
2. **Statement Type Transparency**: The API returns the statement type of the inner `<sql_command>` (e.g., if the
inner command is a `SELECT`, the client sees a `SELECT` statement).
3. **Parameter Reuse**: Input parameters declared in the `USING` clause can be used multiple times within the script
using named references (e.g., `:p1`), while only requiring a single bind from the client application.
4. **Mixed Parameter Binding**: You can mix declared parameters (bound via `?` in the declaration) and direct
positional parameters (using `?` inside the `DO` command).

## Examples

### 1. Basic Parameter Reuse and Subroutines

This example demonstrates declaring typed parameters, defining local functions/procedures, and using them in a query.

```sql
using (p1 integer = ?, p2 integer = ?)
-- Declare a local function
declare function subfunc (i1 integer) returns integer
as
begin
return i1;
end

-- Declare a local procedure
declare procedure subproc (i1 integer) returns (o1 integer)
as
begin
o1 = i1;
suspend;
end
do
-- The main query
select subfunc(:p1) + o1
from subproc(:p2 + ?)
```

In this scenario:
1. The client binds values to `p1` and `p2`.
2. The client binds a third value to the `?` inside the `DO` clause.
3. The result set structure is inferred from the `SELECT` statement.

### 2. Simplifying Parameter Reuse

Without `USING`, inserting the same bind value into multiple columns requires sending the data twice.

**Standard DSQL:**
```sql
insert into generic_table (col_a, col_b) values (?, ?);
-- Client must bind: [100, 100]
```

**With `USING`:**
```sql
using (val integer = ?)
do insert into generic_table (col_a, col_b) values (:val, :val);
-- Client binds: [100]
```

## Comparison

| Feature | Standard DSQL | `EXECUTE BLOCK` | `USING` |
| :---------------------- | :------------------------------ | :-------------------------------------------- | :-------------------------------------------- |
| **Subroutines** | No | Yes | Yes |
| **Input Declarations** | Implicit (Positional) | Explicit | Hybrid (implicit and explicit) |
| **Output Declarations** | Inferred | Explicit (`RETURNS`) | Inferred |
| **Verbosity** | Low | High | Medium |
| **Use Case** | Simple queries | Complex logic, loops, no result set inference | Reusing params, subroutines, standard queries |
9 changes: 9 additions & 0 deletions src/dsql/DdlNodes.epp
Original file line number Diff line number Diff line change
Expand Up @@ -2465,7 +2465,10 @@ void CreateAlterFunctionNode::compile(thread_db* /*tdbb*/, DsqlCompilerScratch*
dsqlScratch->setPsql(true);

if (localDeclList)
{
localDeclList = localDeclList->dsqlPass(dsqlScratch);
localDeclList->genBlr(dsqlScratch);
}

dsqlScratch->loopLevel = 0;
dsqlScratch->cursorNumber = 0;
Expand Down Expand Up @@ -3381,7 +3384,10 @@ void CreateAlterProcedureNode::compile(thread_db* /*tdbb*/, DsqlCompilerScratch*
dsqlScratch->setPsql(true);

if (localDeclList)
{
localDeclList = localDeclList->dsqlPass(dsqlScratch);
localDeclList->genBlr(dsqlScratch);
}

dsqlScratch->loopLevel = 0;
dsqlScratch->cursorNumber = 0;
Expand Down Expand Up @@ -3936,7 +3942,10 @@ void CreateAlterTriggerNode::compile(thread_db* /*tdbb*/, DsqlCompilerScratch* d
dsqlScratch->setPsql(true);

if (localDeclList)
{
localDeclList = localDeclList->dsqlPass(dsqlScratch);
localDeclList->genBlr(dsqlScratch);
}

dsqlScratch->loopLevel = 0;
dsqlScratch->cursorNumber = 0;
Expand Down
1 change: 1 addition & 0 deletions src/dsql/DsqlCompilerScratch.h
Original file line number Diff line number Diff line change
Expand Up @@ -76,6 +76,7 @@ class DsqlCompilerScratch : public BlrDebugWriter
static const unsigned FLAG_FETCH = 0x4000;
static const unsigned FLAG_VIEW_WITH_CHECK = 0x8000;
static const unsigned FLAG_EXEC_BLOCK = 0x010000;
static const unsigned FLAG_USING_STATEMENT = 0x020000;

static const unsigned MAX_NESTING = 512;

Expand Down
7 changes: 4 additions & 3 deletions src/dsql/ExprNodes.cpp
Original file line number Diff line number Diff line change
Expand Up @@ -14176,9 +14176,10 @@ void VariableNode::genBlr(DsqlCompilerScratch* dsqlScratch)
{
auto varScratch = outerDecl ? dsqlScratch->mainScratch : dsqlScratch;

const bool execBlock = (varScratch->flags & DsqlCompilerScratch::FLAG_EXEC_BLOCK);
const bool execBlockOrUsing = (varScratch->flags &
(DsqlCompilerScratch::FLAG_EXEC_BLOCK | DsqlCompilerScratch::FLAG_USING_STATEMENT));

if (dsqlVar->type == dsql_var::TYPE_INPUT && !execBlock)
if (dsqlVar->type == dsql_var::TYPE_INPUT && !execBlockOrUsing)
{
dsqlScratch->appendUChar(blr_parameter2);

Expand All @@ -14196,7 +14197,7 @@ void VariableNode::genBlr(DsqlCompilerScratch* dsqlScratch)
}
else
{
// If this is an EXECUTE BLOCK input parameter, use the internal variable.
// If this is an EXECUTE BLOCK or USING input parameter, use the internal variable.
dsqlScratch->appendUChar(blr_variable);

if (outerDecl)
Expand Down
1 change: 1 addition & 0 deletions src/dsql/Nodes.h
Original file line number Diff line number Diff line change
Expand Up @@ -1490,6 +1490,7 @@ class StmtNode : public DmlNode
TYPE_SUSPEND,
TYPE_TRUNCATE_LOCAL_TABLE,
TYPE_UPDATE_OR_INSERT,
TYPE_USING,

TYPE_EXT_INIT_PARAMETERS,
TYPE_EXT_TRIGGER
Expand Down
Loading
Loading