SUBSTRING (Transact-SQL)

Applies to: SQL Server Azure SQL Database Azure SQL Managed Instance Azure Synapse Analytics Analytics Platform System (PDW) SQL analytics endpoint in Microsoft Fabric Warehouse in Microsoft Fabric

Returns part of a character, binary, text, or image expression in SQL Server.

Transact-SQL syntax conventions

Syntax

SUBSTRING ( expression, start, length )  

Note

To view Transact-SQL syntax for SQL Server 2014 (12.x) and earlier versions, see Previous versions documentation.

Arguments

expression
Is a character, binary, text, ntext, or image expression.

start
Is an integer or bigint expression that specifies where the returned characters start. (The numbering is 1 based, meaning that the first character in the expression is 1). If start is less than 1, the returned expression will begin at the first character that is specified in expression. In this case, the number of characters that are returned is the largest value of either the sum of start + length- 1 or 0. If start is greater than the number of characters in the value expression, a zero-length expression is returned.

length
Is a positive integer or bigint expression that specifies how many characters of the expression will be returned. If length is negative, an error is generated and the statement is terminated. If the sum of start and length is greater than the number of characters in expression, the whole value expression beginning at start is returned.

Return Types

Returns character data if expression is one of the supported character data types. Returns binary data if expression is one of the supported binary data types. The returned string is the same type as the specified expression with the exceptions shown in the table.

Specified expression Return type
char/varchar/text varchar
nchar/nvarchar/ntext nvarchar
binary/varbinary/image varbinary

Remarks

The values for start and length must be specified in number of characters for ntext, char, or varchar data types and bytes for text, image, binary, or varbinary data types.

The expression must be varchar(max) or varbinary(max) when the start or length contains a value larger than 2147483647.

Supplementary Characters (Surrogate Pairs)

When using supplementary character (SC) collations, both start and length count each surrogate pair in expression as a single character. For more information, see Collation and Unicode Support.

Examples

A. Using SUBSTRING with a character string

The following example shows how to return only a part of a character string. From the sys.databases table, this query returns the system database names in the first column, the first letter of the database in the second column, and the third and fourth characters in the final column.

SELECT name, SUBSTRING(name, 1, 1) AS Initial ,
SUBSTRING(name, 3, 2) AS ThirdAndFourthCharacters
FROM sys.databases  
WHERE database_id < 5;   

Here is the result set.

name Initial ThirdAndFourthCharacters
master m st
tempdb t mp
model m de
msdb m db

Here is how to display the second, third, and fourth characters of the string constant abcdef.

SELECT x = SUBSTRING('abcdef', 2, 3);  

Here is the result set.

x  
----------  
bcd  
 
(1 row(s) affected)

B. Using SUBSTRING with text, ntext, and image data

Note

To run the following examples, you must install the pubs database.

The following example shows how to return the first 10 characters from each of a text and image data column in the pub_info table of the pubs database. text data is returned as varchar, and image data is returned as varbinary.

USE pubs;  
SELECT pub_id, SUBSTRING(logo, 1, 10) AS logo,   
   SUBSTRING(pr_info, 1, 10) AS pr_info  
FROM pub_info  
WHERE pub_id = '1756';  

Here is the result set.

pub_id logo    pr_info
------ ---------------------- ----------
1756   0x474946383961E3002500 This is sa

(1 row(s) affected)

The following example shows the effect of SUBSTRING on both text and ntext data. First, this example creates a new table in the pubs database named npub_info. Second, the example creates the pr_info column in the npub_info table from the first 80 characters of the pub_info.pr_info column and adds an ü as the first character. Lastly, an INNER JOIN retrieves all publisher identification numbers and the SUBSTRING of both the text and ntext publisher information columns.

IF EXISTS (SELECT table_name FROM INFORMATION_SCHEMA.TABLES   
      WHERE table_name = 'npub_info')  
   DROP TABLE npub_info;  
GO  
-- Create npub_info table in pubs database. Borrowed from instpubs.sql.  
USE pubs;  
GO  
CREATE TABLE npub_info  
(  
 pub_id CHAR(4) NOT NULL  
    REFERENCES publishers(pub_id)  
    CONSTRAINT UPKCL_npubinfo PRIMARY KEY CLUSTERED,  
pr_info ntext NULL  
);  
  
GO  
  
-- Fill the pr_info column in npub_info with international data.  
RAISERROR('Now at the inserts to pub_info...',0,1);  
  
GO  
  
INSERT npub_info VALUES('0736', N'üThis is sample text data for New Moon Books, publisher 0736 in the pubs database')  
,('0877', N'üThis is sample text data for Binnet & Hardley, publisher 0877 in the pubs databa')  
,('1389', N'üThis is sample text data for Algodata Infosystems, publisher 1389 in the pubs da')  
,('9952', N'üThis is sample text data for Scootney Books, publisher 9952 in the pubs database')  
,('1622', N'üThis is sample text data for Five Lakes Publishing, publisher 1622 in the pubs d')  
,('1756', N'üThis is sample text data for Ramona Publishers, publisher 1756 in the pubs datab')  
,('9901', N'üThis is sample text data for GGG&G, publisher 9901 in the pubs database. GGG&G i')  
,('9999', N'üThis is sample text data for Lucerne Publishing, publisher 9999 in the pubs data');  
GO  
-- Join between npub_info and pub_info on pub_id.  
SELECT pr.pub_id, SUBSTRING(pr.pr_info, 1, 35) AS pr_info,  
   SUBSTRING(npr.pr_info, 1, 35) AS npr_info  
FROM pub_info pr INNER JOIN npub_info npr  
   ON pr.pub_id = npr.pub_id  
ORDER BY pr.pub_id ASC;  

Examples: Azure Synapse Analytics and Analytics Platform System (PDW)

C. Using SUBSTRING with a character string

The following example shows how to return only a part of a character string. From the dbo.DimEmployee table, this query returns the last name in one column with only the first initial in the second column.

-- Uses AdventureWorks  
  
SELECT LastName, SUBSTRING(FirstName, 1, 1) AS Initial  
FROM dbo.DimEmployee  
WHERE LastName LIKE 'Bar%'  
ORDER BY LastName;  

Here is the result set.

LastName             Initial
-------------------- -------
Barbariol            A
Barber               D
Barreto de Mattos    P

The following example shows how to return the second, third, and fourth characters of the string constant abcdef.

USE ssawPDW;  
  
SELECT TOP 1 SUBSTRING('abcdef', 2, 3) AS x FROM dbo.DimCustomer;  

Here is the result set.

x
-----
bcd

See Also

LEFT (Transact-SQL)
LTRIM (Transact-SQL)
RIGHT (Transact-SQL)
RTRIM (Transact-SQL)
STRING_SPLIT (Transact-SQL)
TRIM (Transact-SQL)
String Functions (Transact-SQL)