Category Archives: Sql Server 2012

TRIM function in Sql Server

Many a times we come across a scenario where we get an input string with leading and/or trailing spaces. In such scenarios we would like to store it into the database by removing the leading and trailing spaces. But Microsoft doesn’t have a built-in TRIM function which can remove both leading and Trailing spaces.

Instead it has LTRIM function which can be used to remove leading blanks and RTRIM function which can be used to remove trailing spaces. Let us understand these functions with examples and then see how we can nest these two functions together as shown in the below examples to remove leading and trailing spaces.

LTRIM Function

LTRIM function removes the leading spaces from the input string

DECLARE @StringToTrim VARCHAR(100) = '    String to trim    '
SELECT @StringToTrim 'String To Trim', 
	  DATALENGTH(@StringToTrim) 'Length of the string',
	  LTRIM(@StringToTrim) 'String trimmed by LTRIM', 
	  DATALENGTH(LTRIM(@StringToTrim)) 'Length of LTRIM string'

RESULT:
ltrim-in-sql-server

From the above result we can see that the LTRIM function is removing only the leading spaces. That is it has removed only the leading 4 spaces and not the trailing 4 spaces.

[ALSO READ] Difference between Len() and Datalength() functions in Sql Server

RTRIM Function

RTRIM function removes the trailing spaces from the input string

DECLARE @StringToTrim VARCHAR(100) = '    String to trim    '
SELECT @StringToTrim 'String To Trim', 
	  DATALENGTH(@StringToTrim) 'Length of the string',
	  RTRIM(@StringToTrim) 'String trimmed by RTRIM', 
	  DATALENGTH(RTRIM(@StringToTrim)) 'Length of RTRIM string'

RESULT:
rtrim-in-sql-server

From the above result we can see that the RTRIM function is removing only the trailing spaces. That is it has removed only the trailing 4 spaces and not the leading 4 spaces.

[ALSO READ] Usage of Function on Index Column in WHERE Caluse Leads to Index/Table Scan

TRIM Function

To remove the leading and trailing spaces we can nest the above LTRIM and RTRIM functions as shown in the below example:

DECLARE @StringToTrim VARCHAR(100) = '    String to trim    '
SELECT @StringToTrim 'String To Trim', 
 DATALENGTH(@StringToTrim) 'Length of the string',
 RTRIM(LTRIM(@StringToTrim)) 'String trimmed by LTRIM and RTRIM', 
 DATALENGTH(RTRIM(LTRIM(@StringToTrim)))
  AS 'Length of trimmed string'

RESULT:
trim-in-sql-server

From the above result we can see that the nested use of RTRIM and LTRIM functions has removed both the leading and trailing paces.. That is it has removed both the leading 4 spaces and the trailing 4 spaces from the input string.

We can create a user defined function like the below one. And use it wherever we want to remove both leading and trailing spaces.

CREATE	FUNCTION dbo.TRIM(@StringToTrim VARCHAR(MAX))
RETURNS	VARCHAR(MAX)
BEGIN 
	RETURN	RTRIM(LTRIM(@StringToTrim))
END

Below example shows how we can use the above created user defined TRIM function:

DECLARE @StringToTrim VARCHAR(100) = '    String to trim    '
SELECT dbo.TRIM( @StringToTrim ) 'Trimmed string',
 DATALENGTH(dbo.TRIM( @StringToTrim )) 
  AS 'Length of trimmed string'

RESULT:
trim-function-in-sql-server

[ALSO READ] 100 Frequently used queries in Sql Server – Part 1

Sequence Cache management and Internals – Sql Server 2012

This article basically focuses on the Sequence Cache Management and it’s internals. To know Sequence basics and it’s limitations you may like to visit the articles: Sequence Introduction with Extensive List of examples and Sequence Limitations and restrictions with Extensive List of examples

Sql Server provides option to specify the CACHING options while Creating/Altering Sequence. Basically Sequence created with CACHE option improves the performance by reducing the number of disk IOs that are required to generate sequence numbers.

SEQUENCE CACHE Property:

[ CACHE [<constant> ] | NO CACHE ]

WHERE:

CACHE [<constant> ]: This property can be specified if we want the Sequence with caching enabled, where <constant> is the CACHE size. If the Sequence is Created without specifying CACHE Property then by DEFAULT Sql Server creates the Sequence with CACHING option enabled and as per MSDN the Database Engine will select a size. However, users should not rely upon the selection of the CACHE size being consistent, so it is always advisable to define the required CACHE size if we want to have Sequence Caching instead of relying on the default.

NO CACHE: We can specify this option if we don’t want the Sequence to use the CACHING.

[ALSO READ] :New Features in Sql Server 2012

Let us understand in detail the Performance implications of Creating a Sequence with NO CACHE option or with CACHE enabled option.

SEQUENCE WITHOUT CACHING (i.e. Sequence created with NO CACHE option):

Below diagram demonstrates the steps are performed by Sql Server whenever Next Value is requested from a Sequence object created with NO CACHE option

Sequence with NO CACHE

So, it is clear from the above diagram that, if Sequence object created with NO CACHE option each time a next sequence value is requested it will write the calculated value to the system table before returning it to the calling statement.

[ALSO READ] Introduction to Sequence

SEQUENCE WITH CACHING:

Sequence created with CACHE option improves the performance by minimizing the no of writes to the System table for the generation of the Sequence number. In case of a sequence object created with NO CACHE option each time a next sequence value is requested, it will write the calculated value to the system table before returning it to the calling statement. But if sequence is created with CACHE of Size 50, it will write to the System table only after each 50 sequence values are served.

[ALSO READ] Sequence Vs Identity

Internals of Cache management
For a sequence object which is created with CACHE option, it will not pre-allocate the number of sequence numbers specified by the CACHE argument. Instead CACHE is maintained by two In-Memory variables one for tracking the Sequence Current Value another for the number of values left in the cache. So for sequence CACHE management the memory used will always be two instances of the data type of the Sequence object. For example, if a cache size of 50 is chosen, SQL Server does not keep 50 individual values cached. It only caches the current value and the number of values left in the cache. This means that the amount of memory required to store the cache is always two instances of the data type of the sequence object.

CACHE Management By Two In-Memory Variables

Following steps are performed by Sql Server whenever Next Value is requested from a Sequence object created with CACHING enabled option:

Sequence With CACHING Enabled

[ALSO READ] SEQUENCE Limitations and Restrictions

Let us understand this Sequence Cache Management Internals with an example:

Create the Sequence object SequenceExample with CACHE size as 50 as below:

CREATE SEQUENCE dbo.SequenceExample AS INT
    START WITH 1
    INCREMENT BY 1 
    CACHE 50;
GO

Let us request the first value from the Sequence object SequenceExample and verify that the last cached value 50 (because cache size is 50 and start value is 1 and increment value of the sequence is 1) is written to the system tables on the disk.

--Get First Sequence Value
SELECT (NEXT VALUE FOR dbo.SequenceEx) As NextSeqValue
--Verify the CACHE size 
SELECT * FROM SYS.SYSSCHOBJS 
WHERE ID = OBJECT_ID('dbo.SequenceEx')
--Verify the Last CACHED value written to the system table
SELECT * FROM SYS.SYSOBJVALUES 
WHERE OBJID = OBJECT_ID('dbo.SequenceEx')

Sequence Last CACHED VALUE

From the above queries it is clear that when the first value is requested from the sequence, values 1 through 50 are made available from the two in-memory variables. The last cached value 50 is written to the system tables on the disk.

Now let us verify whether next sequence value 2 through 50 are made available from the two in-memory variables and no updates happen to the system table by using the below queries.


Second Sequence Value

From the above queries results it is clear that no updates happened to the system tables when next sequence value is requested. This holds for all the next values till the sequence value 50.

By using the below queries read the sequence values from 3 through 50.

--Get sequence values from 3 to 50
SELECT (NEXT VALUE FOR dbo.SequenceEx) As NextSeqValue
GO 48

Now the request for the next sequence value i.e. 51 will cause the cache to be allocated again. The new last cached value 100 will be written to the system tables. Let us verify this using the below queries:

Sequence New Last Cached Value

From the results of the above queries it is clear that the request for the sequence value 51 causes the cache to be allocated again. The new last cached value 100 is written to the system tables.

If the Database Engine is stopped after you use 55 numbers, the next intended sequence number in memory 56 is written to the system tables, replacing the previously stored number 100 before database engine is stopped.

After SQL Server restarts and a sequence number is needed, the starting number is read from the system table 56. The cache amount of 50 numbers (56-106) is allocated to memory and the new last cached value 106 is written to the system tables.

If the Database Engine stops abnormally say for example due to power failure (To simulate this you can go to task manager and kill the Sql Server process, please don’t try this on production database). As the last sequence value we have read is the 56, so next sequence value expected is 57 but instead of 57 it will return 107. Any sequence numbers allocated to memory (but never requested by a user or application) are lost. This functionality may leave gaps, but guarantees that the same value will never be issued two times for a single sequence object unless it is defined as CYCLE or is manually restarted.

[ALSO READ] :
SEQUENCE IN SQL SERVER 2012
SEQUENCE Limitations and Restrictions
Sequence Vs Identity
New Features in Sql Server 2012

SEQUENCE Limitations and restrictions – Sql Server 2012

This article basically focuses on the Sequence Limitations and Restrictions with extensive list of example. To know Sequence basics and Sequence Cache Management and internals you may like to visit the articles: Sequence Introduction with Extensive List of examples and Sequence Cache Management and Internals with examples.

In this article let us understand on the limitations and restrictions on the usage of Sequences when using it in queries. Let us understand some of these major limitations with below extensive list of examples.

To demonstrate the limitations let us create a Sequence and a table as below:

--Create A DataBase for Demo 
CREATE DATABASE SqlHintsDemoDB
GO
USE SqlHintsDemoDB
GO
--Create a Sequence with Initial value 1 and Increment by 1
CREATE SEQUENCE [DBO].[SequenceExample] AS INT
 START WITH 1
 INCREMENT BY 1
GO
--Create Employee Table
CREATE TABLE dbo.Employee(ID INT,Name VARCHAR(100))
GO
-- INSERT RECORDS to the Employee table with Sequence object
INSERT INTO dbo.Employee VALUES
 (NEXT VALUE FOR DBO.SequenceExample,'BASAV'),
 (NEXT VALUE FOR DBO.SequenceExample,'SHREE'),
 (NEXT VALUE FOR DBO.SequenceExample,'PRATHAM')
GO

The NEXT VALUE FOR function cannot be used in the following situations:
1) In a statement using the DISTINCT, UNION, UNION ALL, EXCEPT or INTERSECT operator.

SELECT (NEXT VALUE FOR DBO.SequenceExample)
UNION
SELECT (NEXT VALUE FOR DBO.SequenceExample)
GO

RESULT:

Msg 11721, Level 15, State 1, Line 1
NEXT VALUE FOR function cannot be used directly in a statement that uses a DISTINCT, UNION, UNION ALL, EXCEPT or INTERSECT operator.

2) In a statement using the ORDER BY clause unless NEXT VALUE FOR … OVER (ORDER BY …) is used.

SELECT NAME, (NEXT VALUE FOR DBO.SequenceExample) SeqValue
FROM dbo.Employee
ORDER BY NAME
GO

RESULT:

Msg 11723, Level 15, State 1, Line 1
NEXT VALUE FOR function cannot be used directly in a statement that contains an ORDER BY clause unless the OVER clause is specified.

3) In a statement using TOP, OFFSET, or when the ROWCOUNT option is set.

SELECT TOP 10  (NEXT VALUE FOR DBO.SequenceExample)
GO

RESULT:

Msg 11739, Level 15, State 1, Line 1
NEXT VALUE FOR function cannot be used if ROWCOUNT option has been set, or the query contains TOP or OFFSET.

4) In conditional expressions using CASE, CHOOSE, COALESCE, IIF, ISNULL, or NULLIF.

DECLARE @v INT
SELECT ISNULL(@v,(NEXT VALUE FOR DBO.SequenceExample))
GO

RESULT:

Msg 11741, Level 15, State 1, Line 2
NEXT VALUE FOR function cannot be used within CASE, CHOOSE, COALESCE, IIF, ISNULL and NULLIF.

5) In the WHERE clause of a statement.

SELECT *
FROM dbo.Employee
WHERE ID = (NEXT VALUE FOR DBO.SequenceExample)
GO

RESULT:

Msg 11720, Level 15, State 1, Line 3
NEXT VALUE FOR function is not allowed in the TOP, OVER, OUTPUT, ON, WHERE, GROUP BY, HAVING, or ORDER BY clauses.

Below table lists few more situations where NEXT VALUE FOR function cannot be used:

Sl. No. Limitation/Restriction of using NEXT VALUE FOR function
1 In views, in user-defined functions, or in computed columns.
2 As an argument to a table-valued function.
3 As an argument to an aggregate function.
4 In the following clauses: FETCH, OVER, OUTPUT, ON, PIVOT, UNPIVOT, GROUP BY, HAVING, COMPUTE, COMPUTE BY, or FOR XML.
5 When a database is in read-only mode.
6 In subqueries including common table expressions and derived tables.
7 In a MERGE statement. (Except when the NEXT VALUE FOR function is used in a default constraint in the target table and default is used in the CREATE statement of the MERGE statement.)
8 In the definition of a check constraint.
9 In the definition of a rule or default object. (It can be used in a default constraint.)
10 As a default in a user-defined table type.
11 In a VALUES clause that is not part of an INSERT statement.

Below table lists out the list of error message that Sql Server may return while working with sequences:

We can use query like below to get this list:

SELECT message_id 'ERROR No.',text 'ERROR Description'
FROM SYS.messages
WHERE language_id = 1033 
  AND message_id between 11700 and 11742
ERROR No. ERROR Description
11700 The increment for sequence object ‘%.*ls’ cannot be zero.
11701 The absolute value of the increment for sequence object ‘%.*ls’ must be less than or equal to the difference between the minimum and maximum value of the sequence object.
11702 The sequence object ‘%.*ls’ must be of data type int, bigint, smallint, tinyint, or decimal or numeric with a scale of 0, or any user-defined data type that is based on one of the above integer data types.
11703 The start value for sequence object ‘%.*ls’ must be between the minimum and maximum value of the sequence object.
11704 The current value ‘%.*ls’ for sequence object ‘%.*ls’ must be between the minimum and maximum value of the sequence object.
11705 The minimum value for sequence object ‘%.*ls’ must be less than its maximum value.
11706 The cache size for sequence object ‘%.*ls’ must be greater than 0.
11707 The cache size for sequence object ‘%.*ls’ has been set to NO CACHE.
11708 An invalid value was specified for argument ‘%.*ls’ for the given data type.
11709 The ‘RESTART WITH’ argument cannot be used in a CREATE SEQUENCE statement.
11710 Argument ‘START WITH’ cannot be used in an ALTER SEQUENCE statement.
11711 Argument ‘AS’ cannot be used in an ALTER SEQUENCE statement.
11712 Argument ‘%.*ls’ can not be specified more than once.
11714 Invalid sequence name ‘%.*ls’.
11715 No properties specified for ALTER SEQUENCE.
11716 NEXT VALUE FOR function does not support the PARTITION BY clause.
11717 NEXT VALUE FOR function does not support the OVER clause in default constraints, UPDATE statements, or MERGE statements.
11718 NEXT VALUE FOR function does not support an empty OVER clause.
11719 NEXT VALUE FOR function is not allowed in check constraints, default objects, computed columns, views, user-defined functions, user-defined aggregates, user-defined table types, sub-queries, common table expressions, or derived tables.
11720 NEXT VALUE FOR function is not allowed in the TOP, OVER, OUTPUT, ON, WHERE, GROUP BY, HAVING, or ORDER BY clauses.
11721 NEXT VALUE FOR function cannot be used directly in a statement that uses a DISTINCT, UNION, UNION ALL, EXCEPT or INTERSECT operator.
11722 NEXT VALUE FOR function is not allowed in the WHEN MATCHED clause, the WHEN NOT MATCHED clause, or the WHEN NOT MATCHED BY SOURCE clause of a merge statement.
11723 NEXT VALUE FOR function cannot be used directly in a statement that contains an ORDER BY clause unless the OVER clause is specified.
11724 An expression that contains a NEXT VALUE FOR function cannot be passed as an argument to a table-valued function.
11725 An expression that contains a NEXT VALUE FOR function cannot be passed as an argument to an aggregate.
11726 Object ‘%.*ls’ is not a sequence object.
11727 NEXT VALUE FOR functions for a given sequence object must have exactly the same OVER clause definition.
11728 The sequence object ‘%.*ls’ has reached its minimum or maximum value. Restart the sequence object to allow new values to be generated.
11729 The sequence object ‘%.*ls’ cache size is greater than the number of available values; the cache size has been automatically set to accommodate the remaining sequence values.
11730 Database name cannot be specified for the sequence object in default constraints.
11731 A column that uses a sequence object in the default constraint must be present in the target columns list, if the same sequence object appears in a row constructor.
11732 The requested range for sequence object ‘%.*ls’ exceeds the maximum or minimum limit. Retry with a smaller range.
11733 Parameter ‘%.*ls’ must be a positive integer.
11734 NEXT VALUE FOR function is not allowed in the SELECT clause when the FROM clause contains a nested INSERT, UPDATE, DELETE, or MERGE statement.
11735 The target table of the INSERT statement cannot have DEFAULT constraints using the NEXT VALUE FOR function when the FROM clause contains a nested INSERT, UPDATE, DELETE, or MERGE statement.
11736 Only one instance of NEXT VALUE FOR function per sequence object is allowed in SET or SELECT with variable assignment.
11737 NEXT VALUE FOR function does not support the ROWS and RANGE clauses.
11738 The use of NEXT VALUE FOR function is not allowed in this context.
11739 NEXT VALUE FOR function cannot be used if ROWCOUNT option has been set, or the query contains TOP or OFFSET.
11740 NEXT VALUE FOR function cannot be used in a default constraint if ROWCOUNT option has been set, or the query contains TOP or OFFSET.
11741 NEXT VALUE FOR function cannot be used within CASE, CHOOSE, COALESCE, IIF, ISNULL and NULLIF.
11742 NEXT VALUE FOR function can only be used with MERGE if it is defined within a default constraint on the target table for insert actions.