Feeds:
Posts
Comments

Mostly, there are multiple ways to write a script to perform a single task. It varies from Developers to Developers, who normally try to follow the best practice. But sometimes some standards discard from time to time (version to version). In this article, I will go through some standard formats that we used in the prior version of SQL server but does not work in SQL Server 2012. It may break your script.

Let me create a sample in SQL Server 2005/ 2008 to explain it.

USE [test]
GO
CREATE TABLE [dbo].[t_Student](
[Student ID] [int] IDENTITY(1,1) NOT NULL,
[Student Name] [nvarchar](50) NULL
)

After creating the sample table lets alter this table. But there are three different formats that you can use to alter the table in earlier version of SQL server (2005/2008)


Method 1 :
In method 1, the format to alter the table will be .Database Name.Schema.Table Name

Alter table .[test].dbo.[t_Student] Add [Contact Details] varchar(50) NULL
--OUTPUT

Command(s) completed successfully

Method 2 :
In method 2, the format to alter the table will be ..Schema.Table Name

use test
GO
Alter table ..dbo.[t_Student] Add [Date of Birth] Datetime NULL
--OUTPUT

Command(s) completed successfully

Method 3 :
In method 3, the format to alter the table will be Schema.Table Name

use test
GO
Alter table dbo.[t_Student] Add [Date of Admission] Datetime NULL
--OUTPUT

Command(s) completed successfully

All of the above methods executed successfully in SQL Server 2005/ 2008.

Lets browse the table.

Select * from t_Student

alter table 1.1

Now, lets do the same exercise in SQL Server 2012.

Method 1 :
In method 1, the format to alter the table will be .Database Name.Schema.Table Name

Alter table .[test].dbo.[t_Student] Add [Contact Details] varchar(50) NULL
--OUTPUT

Msg 117, Level 15, State 1, Line 1
The object name ‘.test.dbo.t_Student’ contains more than the maximum number of prefixes. The maximum is 2.

Method 2 :
In method 2, the format to alter the table will be ..Schema.Table Name

use test
GO
Alter table ..dbo.[t_Student] Add [Date of Birth] Datetime NULL
--OUTPUT

Msg 117, Level 15, State 1, Line 1
The object name ‘..dbo.t_Student’ contains more than the maximum number of prefixes. The maximum is 2.

Method 3 :
In method 3, the format to alter the table will be Schema.Table Name

use test
GO
Alter table dbo.[t_Student] Add [Date of Admission] Datetime NULL
--OUTPUT

Command(s) completed successfully

Conclusion :
If you are planning to upgrade your SQL Server earlier version to SQL Server 2012 or you are using SQL Server 2012, remember, it will not allow you to use methods 1 & 2. In case your are using above methods 1 & 2 in Dynamic SQL or Static SQL, it may break your script.

Reference : MSDN

I have been using Database email for a long time. This is very nice features introduced in SQL Server 2005. But when it comes to HTML formatting, you need to know a little bit HTML to format it and it takes a quite a while to format it. In this article, I will share a tip that can make your life easy and you can format even a complex HTML formatted email in few minutes.

Lets process it step by step.

Step 1 :
Mostly we receive the email format in word documents. First of all, you need to open the word document in MS word.
Sample attached Test Document 1.1.
SQL email1.1

Step 2 :
Then Go to File menu>>Save as and save it as html document.
SQL email1.2

Step 3 :
Open the saved html document, right click on it and go to view source.
SQL email1.3

Step 4 :
It will open a new window. Now you need to search for the tags namely Body and /Body and whatever text lies between both tags, just copy and paste it in the SQL query window.
SQL email1.4

Step 5 :
Now, you need to replace one single quote (‘) to two single quotes (”) in SQL query window and add single quote (‘) in the beginning and end of the text. Rest of the format will remain same.

Use msdb
GO
EXEC sp_send_dbmail @profile_name='My profile',
@recipients='mimran18@gmail.com',
@subject='Test Message with Formatted HTML',
@body_format = 'HTML' ,
@body='</pre>
<div class="WordSection1"><s>This is a TEST email</s>

<i><span style="text-decoration: underline;">This
is a TEST email</span></i>

This is a TEST email

This is a TEST
<table class="MsoTableLightListAccent1" border="1" cellspacing="0" cellpadding="0">
<tbody>
<tr>
<td valign="top" width="97"><span class="SpellE"><b>S.No</b></span><b></b></td>
<td valign="top" width="375"><b>SQL Server Versions</b></td>
</tr>
<tr>
<td valign="top" width="97"><b>1</b></td>
<td valign="top" width="375">SQL Server 2005</td>
</tr>
<tr>
<td valign="top" width="97"><b>2</b></td>
<td valign="top" width="375">SQL Server 2008</td>
</tr>
<tr>
<td valign="top" width="97"><b>3</b></td>
<td valign="top" width="375">SQL Server 2012</td>
</tr>
</tbody>
</table>
</div>
<pre>
'

Step 6 :
Now, just execute it and it will send a nice formatted HTML email.

In this article,  we will discuss how to convert user defined objects to system objects and the reason to convert. Sometimes you develop general database procedures and functions that help you perform your daily operation quickly. But the issue is you need to create all these procedures and functions in the databases and after finishing the task you need to remove it also. A few days ago during my research I found a solution and with the help of this solution you don’t need to create / remove the script again and again in all databases. The solution is an undocumented stored procedure namely sp_ms_marksystemobject . But how it works, lets discuss stepwise.

Step 1 :
Given below is the script that can give you the column name (along with comma and brackets [ ]) of any table in a particular database and later on you can use it to insert, update or select statements.

Use AdventureWorks2012
GO
Create Procedure SP_ColumnNames
@object_name nvarchar(Max)
as
Select (Case when [column_id] = 1 then ' ' else ',' end)
+ QuoteName([name]) As [Column Name]
from sys.columns
where object_id=Object_id(@Object_name)
GO

Step 2 :
Now, you need to use the same database to execute the above stored procedure.

Use AdventureWorks2012
Go
SP_ColumnNames 'Sales'

systemobjects1.1

Step 3 :
If you try to use the same procedure in another database it will not work until unless you create the same procedure there. Lets see.

Use test
GO
SP_ColumnNames 'Student'

systemobjects1.2

If you look at the above error, it says you must deploy the above stored procedure in all databases wherever you need to use it. But this is a common tool and I need to deploy it once and need to use it in all the databases at the server. The solution is available in Step 4.

Step 4 :
Simply create your user defined stored procedure in master database and convert it to system stored procedure using sp_ms_marksystemobject.

Use master
GO
Create Procedure SP_ColumnNames
@object_name nvarchar(Max)
as
Select (Case when [column_id] = 1 then ' ' else ',' end)
+ QuoteName([name]) As [Column Name]
from sys.columns
where object_id=Object_id(@Object_name)
GO
sp_ms_marksystemobject  'SP_ColumnNames'

Step 5 :
Now, you can use this stored procedure in any database in the same server without creating it in all databases.
Lets try.

Use AdventureWorks2012
Go
SP_ColumnNames 'dbo.sales'
GO
Use test
Go
SP_ColumnNames 'Student'

sytemobject1.4

Conclusion :
You can deploy your general stored procedure and function once in the master database to perform daily operations and as many times as you can use it, in as many as databases you wish, without creating the stored procedure and functions time and again.

Note : This solution is not recommended for live database servers, you can use it in the development and testing server to expedite your development and testing.

Whenever you upgrade previous version of SQL Server to SQL Server 2012 you need to take care of few issues. In this article, I will discuss one of the important issues that is Create trigger with append clause. This clause will not stop you to upgrade it to SQL Server 2012 but it will break your scripts. But how ?
Let me explain it Step by Step with the simple examples.
Step 1 :
First create given below table and triggers on any database prior to SQL Server 2012.

CREATE TABLE dbo.Student
([Student_ID] INT,
[Student_Name] VARCHAR(100)
)
GO
CREATE TRIGGER dbo.FirstTrigger
ON dbo.Student
FOR INSERT
AS
BEGIN
PRINT 'First Trigger'
END
GO
CREATE TRIGGER dbo.SecondTrigger
ON dbo.Student
FOR INSERT
WITH APPEND
AS
BEGIN
PRINT 'Second Trigger'
END
GO

Step 2 :
Upgrade the database on SQL Server 2012. Once you upgrade it will not alert you.
Step 3 :
Immediately after upgrade, run the given below query to view if any with append clause is available in the trigger.

Select A.object_id,A.definition from sys.sql_modules A
Inner Join sys.triggers B On A.object_id =B.object_id
where definition like '%with append%'

withappend1.1-1

Step 4 :
In the above example, we have one trigger with append clause, so alter the trigger and remove the with append clause because it is no more required for the triggers in latest versions of SQL Server.

Now, you are ready to use this trigger in the SQL Server 2012.

In case, if you don’t follow step 3 and 4, lets see what may happen.

insert into student values (1,'Imran')
--OUTPUT

First Trigger
Msg 195, Level 15, State 1, Procedure SecondTrigger, Line 5
‘APPEND’ is not a recognized option.

Conclusion :
Remember, whenever you upgrade to SQL Server 2012, check WITH APPEND clause  in the triggers to avoid this error.

DBCC SHRINKFILE for FILESTREAM containers requires EMPTYFILE option and does not allow any other options is one of the error messages shipped with SQL Server 2012. It happens due to the new feature File table (File stream) introduced in SQL Server 2012. Lets explore this error message.
Message Number: 2563
Severity : 16
Error Message: DBCC SHRINKFILE for FILESTREAM containers requires EMPTYFILE option and does not allow any other options.

Error Generation:
This error message looks as if something is wrong with the “DBCC SHRINKFILE”. Lets generate this error step by step.
Step 1 :
First of all create a database having File stream.

CREATE DATABASE [MyFileTableDB]
ON PRIMARY
( NAME = N'MyFileTableDB', FILENAME = N'C:\DATA\MyFileTableDB.mdf'),
FILEGROUP MyFileGroup CONTAINS FILESTREAM (NAME = MyFileTableFS,FILENAME='C:\Data\MyFileTable')
LOG ON
( NAME = N'MyFileTableDB_log', FILENAME = N'C:\DATA\MyFileTableDB_log.ldf')
WITH FILESTREAM ( NON_TRANSACTED_ACCESS = FULL, DIRECTORY_NAME = N'MyFileTableDB' )
GO

Step 2 :
Shrink the data file.

-- Shrink the data file
USE My_FileTableDB
GO
DBCC SHRINKFILE (N'MyFileTableDB' , 0, TRUNCATEONLY)

msg25631.1

Step 3 :
Shrink the log file.

-- Shrink the log file
USE My_FileTableDB
GO
DBCC SHRINKFILE (N'MyFileTableDB_log' , 0, TRUNCATEONLY)

msg25631.2

Step 4 :
Shrink the filestream file.

-- Shrink the FileStream file
USE My_FileTableDB
GO
DBCC SHRINKFILE (N'MyFileTableFS' , 0, TRUNCATEONLY)

Oooops……………
Msg 2563, Level 16, State 1, Line 1
DBCC SHRINKFILE for FILESTREAM containers requires EMPTYFILE option and does not allow any other options.

Resolution:
You cannot shrink FileStream files like data file or log file. The correct syntax to shrink file stream is given below :

DBCC SHRINKFILE (N'MyFileTableFS' , EMPTYFILE)

msg25631.3

Conclusion:
Remember, whenever you shrink the FILESTREAM files follow the exact syntax given above to avoid this error.

sys.sysprocesses is one of the helpful system views when it comes to query the processes of SQL Server. I have been using this system view for quite a while. But a few days ago I read on MSDN, “This feature will be removed in a future version of Microsoft SQL Server. Avoid using this feature in new development work, and plan to modify applications that currently uses this feature.”

So, I planned to upgrade my query.
Given below is my query that I used to retrieve processes using specified database since SQL Server 2000.

--This query will work fine on SQL Server 2000 and above.
Declare @database_name as varchar(max)
Set @database_name ='AdventureWorks2012'

Select [spid] as [session_id], [last_batch],[status]
,cmd as [Command], hostname as [host_name]
,[program_name], [loginame] as [Login_name]
from sys.sysprocesses
Where dbid = db_id(@database_name)

sysprocesses1.1

Given below is my new query that works on SQL Server 2012 and above, having the same result set as the above.

Declare @database_name as varchar(max)
Set @database_name ='AdventureWorks2012'

Select A.session_id,A.last_request_end_time as [last_batch],A.[status]
, B.[command],A.[host_name]
,A.[program_name],A.[login_name]
from sys.dm_exec_sessions A
Left Join sys.dm_exec_requests B
On A.[session_id]=B.[session_id]
Where A.[database_id]=db_id(@database_name)

sysprocesses1.2

Conclusion :
You can see that both the above queries result set is same but first query (sys.sysprocesses) will not be applicable for future versions of SQL.

Let me know your feedback regarding both queries.

sp_spaceused is one of the frequently used stored procedures when it comes to view the number of rows, reserved size, data size, index size, unused space in a table. I myself utilized it many a time.

Given below are the three methods to run sp_spaceused or equivalent for all tables in a database to get number of rows, reserved size, data size, index size, unused space but this time we will measure the performance as well.

Method 1 :
Given below is one line script that can achieve the required result but it will cost you a performance issue because it will loop all the tables in the database one by one and will give you the result set.

EXECUTE sp_MSforeachtable 'EXECUTE sp_spaceused [?]';

Given below is one of the server execution times.
SQL Server Execution Times:
CPU time = 203 ms, elapsed time = 1768 ms.

If you have more tables, it will give you the error message as given below.
The query has exceeded the maximum number of result sets that can be displayed in the results grid. Only the first 100 result sets are displayed in the grid.

Method 2 :
Given below is another method to achieve it but this method will also cost you a performance issue because it will also loop all the tables in the database one by one and will give you the result set. Reference

Set statistics time on
CREATE TABLE ##TempTable
(name nvarchar(128)
,rows char(11)
,reserved varchar(18)
,data varchar(18)
,index_size varchar(18)
,unused varchar(18)
)
declare @UserTableName nvarchar(40)
declare UserTableSize cursor for
select rtrim(name) from dbo.sysobjects
where OBJECTPROPERTY(id, N'IsUserTable') = 1 order by name

open UserTableSize
fetch next from UserTableSize into @UserTableName
while @@fetch_status = 0
begin
Insert ##TempTable
exec sp_spaceused @UserTableName
fetch next from UserTableSize into @UserTableName
end
close UserTableSize
deallocate UserTableSize
Select *  from ##TempTable
--Drop Table ##TempTable
Set statistics time off
GO

Given below is one of the server execution times.
SQL Server Execution Times:
CPU time = 125 ms, elapsed time = 1034 ms.

Method 3 :
This method will not loop all the tables in the database one by one and also you don’t need to insert its result set into a temporary table to utilize it further. The performance of this method is also better than the other two methods also.
Given below is the script.

Set statistics time on
declare @PageSize float
select @PageSize=v.low/1024.0 from master.dbo.spt_values v where v.number=1 and v.type='E'

Select object_Name(i.object_id) as [name]
,p.rows
,Convert(varchar(50),@PageSize * SUM(total_pages)) + ' KB' as [reserved]
,Convert(varchar(50),@PageSize * SUM(CASE WHEN a.type <> 1 THEN a.used_pages WHEN p.index_id < 2 THEN a.data_pages ELSE 0 END)) + ' KB' as [data]
,Convert(varchar(50),@PageSize * SUM(a.used_pages - CASE WHEN a.type <> 1 THEN a.used_pages WHEN p.index_id < 2 THEN a.data_pages ELSE 0 END)) +  ' KB' as [index_size]
,Convert(varchar(50),@PageSize * SUM(total_pages-used_pages)) +  ' KB' as [unused]
FROM sys.indexes as i
JOIN sys.partitions as p ON p.object_id = i.object_id and p.index_id = i.index_id
JOIN sys.allocation_units as a ON a.container_id = p.partition_id
JOIN sys.tables t ON i.object_id=t.object_id
Where i.type<=1 and a.type=1
and
t.type='U' and is_ms_shipped=0
Group By i.object_id,p.rows
GO
Set statistics time off

Given below is the server execution times.

SQL Server Execution Times:
CPU time = 0 ms, elapsed time = 6 ms.

Conclusion :
You can see that all the above methods produce the same result set but the issue is with the performance. I recommend Method 3 because it will take less effort and time to generate the same result set.

Any comments ?

Few days ago, I developed two excel functions Future Value of Annuity and
Present Value of Annuity in SQL Server as a User defined function and shared it.

In this article, I will share, how to use common excel financial functions in SQL Server using CLR.
Note : You don’t need to install Excel on the server.
Given below is the list of Excel Financial Functions, we will implement using CLR.

  • FV
  • PV
  • Rate
  • DDB
  • IPMT
  • PPMT
  • SLN
  • SYD

Deployment:
There are two methods to deploy above CLR functions in SQL.
Method -1 : (If you have Visual Studio)
First download the source code from here and extract it.
Open it in the Visual Studio, go to Build, first build the solution then deploy the solution.
It will ask for SQL server name and credentials and will directly deploy it on the SQL Server.
This is simple solution.

Method -2: (If you do not have Visual Studio)
Lets deploy and test it step by step.

Step 1 :
First download DLL from here and rename it to .zip and extract it.

Step 2 :
Copy the above DLL in a specified folder. (eg. C:\CLRExcel_Financial_Functions.DLL)

Step 3 :
Enable CLR in the SQL Server.

sp_configure 'show advanced options', 1;
GO
RECONFIGURE;
GO
sp_configure 'clr enabled', 1;
GO
RECONFIGURE;
GO

Step 4 :
Restart SQL Server.

Step 5 :
Create assembly and CLR functions in SQL Server.

CREATE ASSEMBLY [CLRExcel_Financial_Functions]
AUTHORIZATION
[dbo] from 'c:\CLRExcel_Financial_Functions.dll' WITH PERMISSION_SET = SAFE
GO

CREATE FUNCTION [dbo].[FV](@Rate [float], @NPer [float], @Pmt [float], @PV [float], @Type [bit])
RETURNS [float] WITH EXECUTE AS CALLER
AS
EXTERNAL NAME [CLRExcel_Financial_Functions].[CLRExcel_Financial_Functions.ExcelFunctions].[FV]

GO
CREATE FUNCTION [dbo].[DDB](@Cost [float], @Salvage [float], @Life [float], @Period [float], @Factor [float])
RETURNS [float] WITH EXECUTE AS CALLER
AS
EXTERNAL NAME [CLRExcel_Financial_Functions].[CLRExcel_Financial_Functions.ExcelFunctions].[DDB]
GO

CREATE FUNCTION [dbo].[IPMT](@Rate [float], @NPer [float], @PV [float], @FV [float], @Type [bit])
RETURNS [float] WITH EXECUTE AS CALLER
AS
EXTERNAL NAME [CLRExcel_Financial_Functions].[CLRExcel_Financial_Functions.ExcelFunctions].[IPMT]
GO

CREATE FUNCTION [dbo].[PPMT](@Rate [float], @Per [float], @NPer [float], @PV [float], @FV [float], @Type [bit])
RETURNS [float] WITH EXECUTE AS CALLER
AS
EXTERNAL NAME [CLRExcel_Financial_Functions].[CLRExcel_Financial_Functions.ExcelFunctions].[PPMT]

GO

CREATE FUNCTION [dbo].[PV](@Rate [float], @NPer [float], @Pmt [float], @FV [float], @Type [bit])
RETURNS [float] WITH EXECUTE AS CALLER
AS
EXTERNAL NAME [CLRExcel_Financial_Functions].[CLRExcel_Financial_Functions.ExcelFunctions].[PV]

GO

CREATE FUNCTION [dbo].[Rate](@NPer [float], @Pmt [float], @PV [float], @FV [float], @Type [bit], @Guess [float])
RETURNS [float] WITH EXECUTE AS CALLER
AS
EXTERNAL NAME [CLRExcel_Financial_Functions].[CLRExcel_Financial_Functions.ExcelFunctions].[Rate]

GO

CREATE FUNCTION [dbo].[SLN](@Cost [float], @Salvage [float], @Life [float])
RETURNS [float] WITH EXECUTE AS CALLER
AS
EXTERNAL NAME [CLRExcel_Financial_Functions].[CLRExcel_Financial_Functions.ExcelFunctions].[SLN]

GO

CREATE FUNCTION [dbo].[SYD](@Cost [float], @Salvage [float], @Life [float], @Period [float])
RETURNS [float] WITH EXECUTE AS CALLER
AS
EXTERNAL NAME [CLRExcel_Financial_Functions].[CLRExcel_Financial_Functions.ExcelFunctions].[SYD]
GO

Step 6 :
Now, we are ready to use Excel financial function in SQL.

Given below are some examples of above functions.


Select dbo.FV(0.075/12,24,-250,-5000,0) as [Future Value]
GO
Select dbo.FV(0.06,30,0,-5000,1) as [Future Value]
GO
Select dbo.FV(0.06,30,-1200,0,1) as [Future Value]
GO

SELECT dbo.PV(0.075/12,24,250,0,0) as [Present Value]
GO
SELECT dbo.PV(0.06/52,4*52,50,0,1) as [Present Value]
GO
SELECT dbo.PV(0.0525,10,100,0,0) as [Present Value]
GO

Select dbo.Rate(24,-250,5000,0,0,0.1) as [Rate]
GO
Select dbo.Rate(4*52,-700,8000,0,0,0.1) as [Rate]
GO
Select dbo.Rate(10*1,-1000,6500,0,0,0.1) as [Rate]
GO

Select dbo.DDB(10000, 5000, 5, 1,2.0) as [DDB]
GO
Select dbo.DDB(10000, 5000, 5, 2,2.0) as [DDB]
GO
Select dbo.DDB(10000, 5000, 5, 3,2.0) as [DDB]
GO

Select dbo.IPMT(0.075/12, 8, 2*12, 5000,0) as [IPMT]
GO
Select dbo.IPMT(0.075/12, 8, 2*12, 8000,0) as [IPMT]
GO
Select dbo.IPMT(0.06/12, 8, 2*12, 8000,0) as [IPMT]
GO

Select dbo.PPMT(0.075/12, 5, 2*12, 5000, 0, 1) as [PPMT]
GO
Select dbo.PPMT(0.06/12, 5, 2*12, 5000, 0, 1) as [PPMT]
GO
Select dbo.PPMT(0.06/12, 5, 2*12, 10000, 0, 1) as [PPMT]
GO

Select dbo.SLN(10000, 5000, 5) as [SLN]
GO
Select dbo.SLN(1000, 5000, 5) as [SLN]
GO
Select dbo.SLN(100, 5000, 5) as [SLN]
GO

Select dbo.SYD(10000, 5000, 5, 1) as [SYD]
GO
Select dbo.SYD(10000, 5000, 5, 2) as [SYD]
GO
Select dbo.SYD(10000, 5000, 5, 3) as [SYD]

Cleaning


Drop Function dbo.DDB
Drop Function dbo.FV
Drop Function dbo.IPMT
Drop Function dbo.PPMT
Drop Function dbo.PV
Drop Function dbo.Rate
Drop Function dbo.SLN
Drop Function dbo.SYD
Drop Assembly CLRExcel_Financial_Functions

Let me know your valuable feedback.

In my previous article, I explained how to use offset rows and fetch next statement. In this article, I will explain Dont's for Offset Rows and Fetch Next.

Let me explain it with simple examples.

Example 1 : (Fetch clause must be greater than zero)

USE AdventureWorks2012
GO
SELECT * FROM [HumanResources].[vEmployee]
ORDER BY [JobTitle]
OFFSET 10 ROWS
FETCH NEXT 0 ROWS ONLY
--OUTPUT

Msg 10744, Level 15, State 1, Line 4
The number of rows provided for a FETCH clause must be greater then zero.

Example 2 : (Offset clause must have integer only)

USE AdventureWorks2012
GO
SELECT * FROM [HumanResources].[vEmployee]
ORDER BY [JobTitle]
OFFSET 1.1 ROWS
FETCH NEXT 10 ROWS ONLY
--OUTPUT

Msg 10743, Level 15, State 1, Line 3
The number of rows provided for an OFFSET clause must be an integer.

Example 3 : (Offset clause may not be negative)

USE AdventureWorks2012
GO
SELECT * FROM [HumanResources].[vEmployee]
ORDER BY [JobTitle]
OFFSET -10 ROWS
FETCH NEXT 10 ROWS ONLY
--OUTPUT

Msg 10742, Level 15, State 1, Line 3
The offset specified in an OFFSET clause may not be negative.

Example 4 : (A Top cannot be used in the same query or sub query as an offset.)

USE AdventureWorks2012
GO
SELECT Top 5 * FROM [HumanResources].[vEmployee]
ORDER BY [JobTitle]
OFFSET 10 ROWS
FETCH NEXT 10 ROWS ONLY
--OUTPUT

Msg 10741, Level 15, State 2, Line 2
A TOP cannot be used in the same query or sub-query as an OFFSET.

If you know any other Dont’s, do share.

Reference : MSDN