You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
Encloses a sequence of [!INCLUDE [tsql](../../includes/tsql-md.md)] statements into a logical block of code. Note this use of "`BEGIN`" is unrelated to the `BEGIN TRANSACTION` and `BEGIN ATOMIC` statements.
32
+
Encloses a sequence of [!INCLUDE [tsql](../../includes/tsql-md.md)] statements into a logical block of code. This use of `BEGIN` is unrelated to the `BEGIN TRANSACTION` and `BEGIN ATOMIC` statements.
32
33
33
-
`BEGIN...END` blocks are often used with a preceding flow-control statement such as `IF`, `ELSE` and `WHILE`, but these blocks can also be used without any preceding flow-control to aesthetically group sequences of statements in a way similar to an anonymous scope `{ ... }` in C-style languages except that `BEGIN...END`blocks do not create a new lexical scope.
34
+
You can use `BEGIN...END` blocks with a preceding flow-control statement such as `IF`, `ELSE`, and `WHILE`. However, you can also use these blocks without any preceding flow-control statement to group sequences of statements in an organized way. However, each new `BEGIN...END`block doesn't create a new lexical scope.
* The use of semicolons after the `BEGIN` and `END` keywords is optional [but recommended]((../../t-sql/language-elements/transact-sql-syntax-conventions-transact-sql.md)), excepting for some cases where they are required, such as when a CTE (`WITH`) or `THROW` statement is used within a block.
46
-
* Using a semicolon after `BEGIN` can help avoid potential confusion with the `BEGIN TRANSACTION` or `BEGIN ATOMIC` statements.
47
-
Using a semicolon after `END` ensures that any subsequent statement, in particular the `WITH` keyword or `THROW` statement, will not need any preceding semicolon.
48
-
*`BEGIN...END` must contain at least one statement: attempting to use an empty `BEGIN...END` block will result in a syntax error, even when each keyword is used with a semicolon terminator.
49
-
50
46
## Arguments
51
47
52
48
#### { *sql_statement* | *statement_block* }
@@ -55,87 +51,148 @@ Any valid [!INCLUDE [tsql](../../includes/tsql-md.md)] statement or statement gr
55
51
56
52
## Remarks
57
53
58
-
*`BEGIN...END` blocks can be nested.
59
-
*`BEGIN...END` blocks cannot span multiple batches, i.e. the `GO` batch separator cannot be used inside a `BEGIN...END` block.
60
-
*`BEGIN...END` blocks do not define any lexical scope: a variable declared within a block will be visible throughout the parent batch and not just within the block containing the `DECLARE` statement.
61
-
* Using a `BEGIN...END` block to group statements does not imply all that all statements in the group will be executed atomically: When a batch runs outside of a transaction and an error is raised or an exception is thrown by the 2nd statement of a multi-statement `BEGIN...END` block then the 1st statement will not be rolled-back.
62
-
* To avoid having a (syntactically invalid) empty `BEGIN...END` block, you may use a `GOTO` label as a "no-op" placeholder statement.
54
+
A `BEGIN...END` block must contain at least one statement. If you try to use an empty `BEGIN...END` block, you get a syntax error, even if you use a semicolon after each keyword. You can avoid empty `BEGIN...END` blocks by using a `GOTO` label as a placeholder statement. See [Example C: Use a GOTO label for dynamically generated BEGIN...END blocks](#c-use-a-goto-label-for-dynamically-generated-beginend-blocks).
55
+
56
+
`BEGIN...END` blocks can be nested.
57
+
58
+
`BEGIN...END` blocks don't define any lexical scope. If you declare a variable within a block, it's visible throughout the parent batch, not just within the block containing the `DECLARE` statement.
59
+
60
+
You can't use `BEGIN...END` blocks across multiple batches. For example, you can't use the `GO` batch separator inside a `BEGIN...END` block.
61
+
62
+
Using a `BEGIN...END` block to group statements doesn't mean all statements in the group run atomically. When a batch runs outside a transaction and an error is raised or an exception is thrown by the second statement of a multistatement `BEGIN...END` block, the first statement isn't rolled back.
63
+
64
+
Semicolons after the `BEGIN` and `END` keywords are [optional but recommended](../../t-sql/language-elements/transact-sql-syntax-conventions-transact-sql.md), except in the following cases:
65
+
66
+
- You need a semicolon before the `WITH` keyword that starts a [common table expression](../queries/recursive-common-table-expression-transact-sql.md) (CTE).
63
67
64
-
Although all [!INCLUDE [tsql](../../includes/tsql-md.md)] statements are valid within a `BEGIN...END` block, certain [!INCLUDE [tsql](../../includes/tsql-md.md)] statements shouldn't be grouped together within the same batch, or statement block<!-- TODO: Is there an authoritative list of statements that should not be used? -->.
68
+
- You need a semicolon with a `THROW` statement within a block.
69
+
70
+
- Use a semicolon after `BEGIN` to prevent confusion with the `BEGIN TRANSACTION` or `BEGIN ATOMIC` statements.
71
+
72
+
- Using a semicolon after `END` ensures that any subsequent statement, particularly a `WITH` keyword or `THROW` statement, doesn't need a preceding semicolon.
73
+
74
+
Although all [!INCLUDE [tsql](../../includes/tsql-md.md)] statements are valid within a `BEGIN...END` block, you shouldn't group certain [!INCLUDE [tsql](../../includes/tsql-md.md)] statements together within the same batch or statement block. Make sure statements don't conflict with existing Transact-SQL batch requirements.
65
75
66
76
## Examples
67
77
68
-
In the following example, `BEGIN` and `END` define sequences of logically related [!INCLUDE [tsql](../../includes/tsql-md.md)] statements to be executed in-order; nested blocks are also demonstrated.
### A. Define a sequence of logically related statements in order
72
81
82
+
In the following example, `BEGIN` and `END` define sequences of logically related [!INCLUDE [tsql](../../includes/tsql-md.md)] statements to execute in order. The example also shows nested blocks.
83
+
84
+
```sql
85
+
USE AdventureWorks2025;
73
86
GO
74
87
75
-
DECLARE @personId int= ( SELECTp.BusinessEntityIDFROMPerson.PersonAS p WHEREp.rowguid= {guid'92C4279F-1207-48A3-8448-4636514EB7E2'} );
76
-
IF( @personId IS NULL ) THROW 50001, 'Person not found.', 1;
SET @nameConcat = CONCAT(@nameConcat, N' (', @emails, N')');
124
+
END
125
+
END
126
+
127
+
/* BEGIN...END blocks do not define a lexical scope, so
128
+
even though @nameAndEmails is declared above, it is
129
+
still in-scope after the END keyword. */
104
130
SELECT @nameConcat AS NameAndEmails;
105
131
```
106
132
107
-
##Empty blocks:
133
+
### B. Use BEGIN...END in a transaction
108
134
109
-
If you are generating Dynamic SQL with a `BEGIN...END`block such that it's simpler for your program to always render the `BEGIN...END`keywords then you may use a `GOTO` label as a "NOOP" or placeholder statement:
135
+
In the following example, `BEGIN` and `END`define a series of [!INCLUDE [tsql](../../includes/tsql-md.md)] statements that execute together. If the `BEGIN...END`block isn't included, both `ROLLBACK TRANSACTION` statements execute, and both `PRINT` messages are returned.
110
136
111
137
```sql
112
-
BEGIN;
113
-
unusedNoopLabel:
114
-
END;
138
+
USE AdventureWorks2025;
139
+
GO
140
+
141
+
BEGIN TRANSACTION;
142
+
143
+
IF @@TRANCOUNT =0
144
+
BEGIN
145
+
SELECT FirstName,
146
+
MiddleName
147
+
FROMPerson.Person
148
+
WHERE LastName ='Adams';
149
+
150
+
ROLLBACK TRANSACTION;
151
+
152
+
PRINT N'Rolling back the transaction two times causes an error.';
153
+
END
154
+
155
+
ROLLBACK TRANSACTION;
156
+
157
+
PRINT N'Rolled back the transaction.';
115
158
```
116
159
117
-
##Examples: [!INCLUDE [ssazuresynapse-md](../../includes/ssazuresynapse-md.md)] and [!INCLUDE [ssPDW](../../includes/sspdw-md.md)]
160
+
### C. Use a GOTO label for dynamically generated BEGIN...END blocks
118
161
119
-
In the following example, `BEGIN` and `END`define a series of [!INCLUDE [DWsql](../../includes/dwsql-md.md)] statements that run together. If the `BEGIN` and `END` keywords are commented-out then the following example will run forever in an infinite loop because only the `SELECT` query will be looped by the `WHILE`statement while the `SET @Iteration += 1` statement will never be reached.
162
+
If you generate dynamic Transact-SQL with a `BEGIN...END`block and you want your program to always render the `BEGIN...END` keywords, you can use a `GOTO` label as a placeholder statement to avoid having an empty `BEGIN...END` block.
120
163
121
164
```sql
122
-
USE AdventureWorksDW;
165
+
BEGIN
166
+
unusedLabel:
167
+
END
168
+
```
123
169
124
-
DECLARE @Iteration INT=0;
170
+
## Examples: Azure Synapse Analytics and Analytics Platform System (PDW)
125
171
126
-
WHILE @Iteration <10
127
-
BEGIN;
128
-
SELECT FirstName, MiddleName
129
-
FROMdbo.DimCustomer
130
-
WHERE LastName ='Adams';
172
+
### C. Define a series of statements that run together
173
+
174
+
In the following example, `BEGIN` and `END` define a series of [!INCLUDE [DWsql](../../includes/dwsql-md.md)] statements that run together.
175
+
176
+
> [!CAUTION]
177
+
> If you remove the `BEGIN` and `END` keywords, the following example runs in an infinite loop. The `WHILE` statement loops only the `SELECT` query, and never reaches the `SET @Iteration += 1` statement.
0 commit comments