Skip to content

Commit 497e2c3

Browse files
committed
Edit pass
1 parent 20e7201 commit 497e2c3

File tree

1 file changed

+123
-66
lines changed

1 file changed

+123
-66
lines changed

docs/t-sql/language-elements/begin-end-transact-sql.md

Lines changed: 123 additions & 66 deletions
Original file line numberDiff line numberDiff line change
@@ -3,7 +3,7 @@ title: "BEGIN...END (Transact-SQL)"
33
description: BEGIN...END allows the execution of a group of Transact-SQL statements in a control of flow.
44
author: rwestMSFT
55
ms.author: randolphwest
6-
ms.date: 05/18/2024
6+
ms.date: 11/21/2025
77
ms.service: sql
88
ms.subservice: t-sql
99
ms.topic: reference
@@ -22,31 +22,27 @@ helpviewer_keywords:
2222
- "statements [SQL Server], grouping"
2323
dev_langs:
2424
- "TSQL"
25+
ai-usage: ai-assisted
2526
monikerRange: ">=aps-pdw-2016 || =azuresqldb-current || =azure-sqldw-latest || >=sql-server-2016 || >=sql-server-linux-2017 || =azuresqldb-mi-current || =fabric || =fabric-sqldb"
2627
---
2728
# BEGIN...END (Transact-SQL)
2829

2930
[!INCLUDE [sql-asdb-asdbmi-asa-pdw-fabricse-fabricdw-fabricsqldb](../../includes/applies-to-version/sql-asdb-asdbmi-asa-pdw-fabricse-fabricdw-fabricsqldb.md)]
3031

31-
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.
3233

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.
3435

35-
:::image type="icon" source="../../includes/media/topic-link-icon.svg" border="false"::: [Transact-SQL syntax conventions](../../t-sql/language-elements/transact-sql-syntax-conventions-transact-sql.md#:~:text=semicolon)
36+
:::image type="icon" source="../../includes/media/topic-link-icon.svg" border="false"::: [Transact-SQL syntax conventions](../../t-sql/language-elements/transact-sql-syntax-conventions-transact-sql.md)
3637

3738
## Syntax
3839

3940
```syntaxsql
40-
BEGIN[;]
41+
BEGIN [ ; ]
4142
{ sql_statement | statement_block }
42-
END[;]
43+
END [ ; ]
4344
```
4445

45-
* 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-
5046
## Arguments
5147

5248
#### { *sql_statement* | *statement_block* }
@@ -55,87 +51,148 @@ Any valid [!INCLUDE [tsql](../../includes/tsql-md.md)] statement or statement gr
5551

5652
## Remarks
5753

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).
6367

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.
6575

6676
## Examples
6777

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.
78+
[!INCLUDE [article-uses-adventureworks](../../includes/article-uses-adventureworks.md)]
6979

70-
```sql
71-
USE AdventureWorks2022;
80+
### A. Define a sequence of logically related statements in order
7281

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;
7386
GO
7487

75-
DECLARE @personId int = ( SELECT p.BusinessEntityID FROM Person.Person AS p WHERE p.rowguid = {guid'92C4279F-1207-48A3-8448-4636514EB7E2'} );
76-
IF( @personId IS NULL ) THROW 50001, 'Person not found.', 1;
77-
78-
/* Concatenate the person's name fields: */
79-
BEGIN;
80-
DECLARE @title nvarchar(8), @first nvarchar(50), @middle nvarchar(50), @last nvarchar(50), @suffix nvarchar(10);
81-
82-
SELECT
83-
@title = NULLIF( p.Title, N'' ),
84-
@first = p.FirstName,
85-
@middle = NULLIF( p.MiddleName, N'' ),
86-
@last = p.LastName,
87-
@suffix = NULLIF( p.Suffix, N'' )
88-
FROM
89-
Person.Person AS p
90-
WHERE
91-
p.BusinessEntityID = @personId;
92-
93-
DECLARE @nameConcat nvarchar(255) = CONCAT_WS( /*separator: */ N' ', @title, @first, @middle, @last, @suffix );
94-
95-
/* This is a nested BEGIN...END block: */
96-
BEGIN;
97-
DECLARE @emails nvarchar(max) = ( SELECT STRING_AGG( e.EmailAddress, /*separator:*/ N'; ' ) FROM Person.EmailAddress AS e WHERE e.BusinessEntityID = @personId );
98-
SET @nameConcat = CONCAT( @nameConcat, N' (', @emails, N')' );
99-
END;
100-
101-
END;
102-
103-
/* BEGIN...END blocks do not define a lexical scope, so even though @nameAndEmails is declared above, it is still in-scope after the END keyword. */
88+
DECLARE @personId AS INT = (
89+
SELECT p.BusinessEntityID
90+
FROM Person.Person AS p
91+
WHERE p.rowguid = { GUID '92C4279F-1207-48A3-8448-4636514EB7E2' }
92+
);
93+
94+
IF (@personId IS NULL)
95+
THROW 50001, 'Person not found.', 1;
96+
97+
/* Concatenate the person's name fields: */;
98+
BEGIN
99+
DECLARE @title AS NVARCHAR (8),
100+
@first AS NVARCHAR (50),
101+
@middle AS NVARCHAR (50),
102+
@last AS NVARCHAR (50),
103+
@suffix AS NVARCHAR (10);
104+
105+
SELECT @title = NULLIF (p.Title, N''),
106+
@first = p.FirstName,
107+
@middle = NULLIF (p.MiddleName, N''),
108+
@last = p.LastName,
109+
@suffix = NULLIF (p.Suffix, N'')
110+
FROM Person.Person AS p
111+
WHERE p.BusinessEntityID = @personId;
112+
113+
DECLARE @nameConcat AS NVARCHAR (255) = CONCAT_WS(N' ', @title, @first, @middle, @last, @suffix);
114+
115+
/* This is a nested BEGIN...END block: */;
116+
BEGIN
117+
DECLARE @emails AS NVARCHAR (MAX) = (
118+
SELECT STRING_AGG(e.EmailAddress, /*separator:*/N'; ')
119+
FROM Person.EmailAddress AS e
120+
WHERE e.BusinessEntityID = @personId
121+
);
122+
123+
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. */
104130
SELECT @nameConcat AS NameAndEmails;
105131
```
106132

107-
## Empty blocks:
133+
### B. Use BEGIN...END in a transaction
108134

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.
110136

111137
```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+
FROM Person.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.';
115158
```
116159

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
118161

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.
120163

121164
```sql
122-
USE AdventureWorksDW;
165+
BEGIN
166+
unusedLabel:
167+
END
168+
```
123169

124-
DECLARE @Iteration INT = 0;
170+
## Examples: Azure Synapse Analytics and Analytics Platform System (PDW)
125171

126-
WHILE @Iteration < 10
127-
BEGIN;
128-
SELECT FirstName, MiddleName
129-
FROM dbo.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.
131178
132-
SET @Iteration += 1;
133-
END;
179+
```sql
180+
-- Uses AdventureWorksDW;
181+
DECLARE @Iteration AS INT = 0;
182+
183+
WHILE @Iteration < 10
184+
BEGIN
185+
SELECT FirstName,
186+
MiddleName
187+
FROM dbo.DimCustomer
188+
WHERE LastName = 'Adams';
189+
SET @Iteration + = 1;
190+
END
134191
```
135192

136193
## Related content
137194

138195
- [ALTER TRIGGER (Transact-SQL)](../statements/alter-trigger-transact-sql.md)
139-
- [Control-of-Flow Language (Transact-SQL)](control-of-flow.md)
196+
- [Control-of-Flow](control-of-flow.md)
140197
- [CREATE TRIGGER (Transact-SQL)](../statements/create-trigger-transact-sql.md)
141198
- [END (BEGIN...END) (Transact-SQL)](end-begin-end-transact-sql.md)

0 commit comments

Comments
 (0)