InterSystems SQL Reference
INSTR
|
|
A string function that returns the position of a substring within a string, with optional search start point and occurrence count.
Synopsis
INSTR(string,substring[,start[,occurrence]])
INSTR searches
string for
substring, and returns the position of the first character of
substring. The position is returned as an integer, counting from the beginning of
string. If
substring is not found, 0 (zero) is returned.
INSTR returns NULL if passed a NULL value for either argument.
INSTR supports specifying
start as the starting point for substring search.
INSTR also support specifying the substring
occurrence from that starting point.
INSTR is case-sensitive. Use one of the case-conversion functions to locate both uppercase and lowercase instances of a letter or character string.
This function can also be invoked from ObjectScript using the
INSTR() method call:
WRITE $SYSTEM.SQL.INSTR("The broken brown briefcase","br",6,2)
INSTR, CHARINDEX, POSITION, and $FIND
INSTR,
CHARINDEX,
POSITION, and
$FIND all search a string for a specified substring and return an integer position corresponding to the first match.
CHARINDEX,
POSITION, and
INSTR return the integer position of the first character of the matching substring.
$FIND returns the integer position of the first character after the end of the matching substring.
CHARINDEX,
$FIND, and
INSTR support specifying a starting point for substring search.
INSTR also support specifying the substring occurrence from that starting point.
The following example demonstrates these four functions, specifying all optional arguments. Note that the positions of
string and
substring differ in these functions:
SELECT POSITION('br' IN 'The broken brown briefcase') AS Position,
CHARINDEX('br','The broken brown briefcase',6) AS Charindex,
$FIND('The broken brown briefcase','br',6) AS Find,
INSTR('The broken brown briefcase','br',6,2) AS Inst
The following example returns 11, because b is the 11th character in the string:
SELECT INSTR('The quick brown fox','b',1) AS PosInt
The following example returns the length of the last name (surname) for each name in the Sample.Person table. It locates the comma used to separate the last name from the rest of the name field, then subtracts 1 from that position:
SELECT Name,
INSTR(Name,',',1)-1 AS LNameLen
FROM Sample.Person
The following example returns the position of the first instance of the letter B in each name in the Sample.Person table. Because
INSTR is case-sensitive, the
%SQLUPPER function is used to convert all name values to uppercase before performing the search. Because
%SQLUPPER adds a blank space at the beginning of a string, this example subtracts 1 to get the actual letter position. Searches that do not locate the specified string return zero (0); in this example, because of the subtraction of 1, the value displayed for these searches is 1:
SELECT Name,
INSTR(%SQLUPPER(Name),'B',1)-1 AS BPos
FROM Sample.Person
Content Date/Time: 2019-02-18 22:53:32