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 series of [!INCLUDE [tsql](../../includes/tsql-md.md)] statements so that a group of [!INCLUDE [tsql](../../includes/tsql-md.md)] statements can be executed in a logical block of code. `BEGIN` and `END` are control-of-flow language keywords.
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.
33
+
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.
@@ -48,61 +51,148 @@ Any valid [!INCLUDE [tsql](../../includes/tsql-md.md)] statement or statement gr
48
51
49
52
## Remarks
50
53
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
+
51
56
`BEGIN...END` blocks can be nested.
52
57
53
-
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.
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).
67
+
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.
54
75
55
76
## Examples
56
77
57
-
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 would execute, and both `PRINT` messages would be returned.
### A. Define a sequence of logically related statements in order
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.
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. */
130
+
SELECT @nameConcat AS NameAndEmails;
131
+
```
132
+
133
+
### B. Use BEGIN...END in a transaction
134
+
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.
136
+
137
+
```sql
138
+
USE AdventureWorks2025;
64
139
GO
65
140
141
+
BEGIN TRANSACTION;
142
+
66
143
IF @@TRANCOUNT =0
67
-
BEGIN
68
-
SELECT FirstName, MiddleName
69
-
FROMPerson.Person
70
-
WHERE LastName ='Adams';
144
+
BEGIN
145
+
SELECT FirstName,
146
+
MiddleName
147
+
FROMPerson.Person
148
+
WHERE LastName ='Adams';
71
149
72
-
ROLLBACK TRANSACTION;
150
+
ROLLBACK TRANSACTION;
73
151
74
-
PRINT N'Rolling back the transaction two times would cause an error.';
75
-
END;
152
+
PRINT N'Rolling back the transaction two times causes an error.';
153
+
END
76
154
77
155
ROLLBACK TRANSACTION;
78
156
79
157
PRINT N'Rolled back the transaction.';
80
-
GO
81
158
```
82
159
83
-
##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
84
161
85
-
In the following example, `BEGIN` and `END`define a series of [!INCLUDE [DWsql](../../includes/dwsql-md.md)] statements that run together. If the `BEGIN...END`block isn't included, the following example runs in a continuous loop.
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.
86
163
87
164
```sql
88
-
-- Uses AdventureWorksDW
165
+
BEGIN
166
+
unusedLabel:
167
+
END
168
+
```
89
169
90
-
DECLARE @Iteration INT=0;
170
+
## Examples: Azure Synapse Analytics and Analytics Platform System (PDW)
91
171
92
-
WHILE @Iteration <10
93
-
BEGIN
94
-
SELECT FirstName,
95
-
MiddleName
96
-
FROMdbo.DimCustomer
97
-
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.
98
175
99
-
SET @Iteration +=1;
100
-
END;
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