REGEXP_INSTR - Teradata Database

SQL Functions, Operators, Expressions, and Predicates

Product
Teradata Database
Release Number
15.00
Language
English (United States)
Last Update
2018-09-24
dita:id
B035-1145
lifecycle
previous
Product Category
Teradata® Database

REGEXP_INSTR

Purpose  

Searches source_string for a match to regexp_string.

REGEXP_INSTR supports 2, 3, 4, 5, or 6 parameters.

Syntax  

where:

 

Syntax element …

Specifies …

TD_SYSFNLIB

the name of the database where the function is located.

source_string

a character argument.

If source_string is NULL, NULL is returned.

regexp_string

a character argument.

If regexp_string is NULL, NULL is returned.

position_arg

a numeric argument.

position_arg specifies the position in source_string from which to start searching (default is 1).

If position_arg is greater than the input string length, zero is returned.

If position_arg is NULL, the NULL value is used. If position_arg is not specified, the value 1 is used.

occurrence_arg

a numeric argument.

occurrence_arg specifies the number of the occurrence to be returned. For example, if occurrence_arg is 2, the function matches the first occurrence in source_string and starts searching from the character following the first occurrence in source_string for the second occurrence in source_string.

If occurrence_arg is greater than the number of matches found, 0 is returned.

If occurrence_arg is NULL, a NULL result is returned. If occurrence_arg is omitted, the default value (1) is used.

return_opt

a numeric argument.

Valid values are:

0 = function returns the beginning position of the match (default).

1 = function returns the end position (character following the occurrence) of the match

If return_opt is not valid, an error is returned.

match_arg

a character argument.

Valid values are:

'i' = case-insensitive matching.

'c' = case sensitive matching.

'n' = the period character (match any character) can match the newline character.

'm' = source string is treated as multiple lines instead of as a single line. With this option the '^' and '$' characters apply to each line in source_string instead of the entire source_string.

'l' = if source_string exceeds the current maximum allowed source_string size (currently 16 MB), a NULL is returned instead of an error. This is useful for long-running queries where you do not want long strings causing an error that would make the query fail.

'x' = ignore whitespace.

The argument can contain more than one character. If a character in the argument is not valid, then that character is ignored.

If match_arg is not specified:

  • The match is case sensitive.
  • A period does not match the newline character.
  • source_string is treated as a single line.
  • If match_arg is NULL, a NULL value is used. If the match_arg is omitted, 0 is used.

    ANSI Compliance

    This is a Teradata extension to the ANSI SQL:2011 standard.

    Invocation

    REGEXP_INSTR is an embedded services system function. For information on activating and invoking embedded services functions, see “Embedded Services System Functions” on page 24.

    Argument Types and Rules

    Expressions passed to this function must have the following data types:

  • source_string= CHAR, VARCHAR, or CLOB
  • regexp_string = CHAR or VARCHAR (maximum size of 512 bytes)
  • position_arg = NUMBER
  • occurrence_arg = NUMBER
  • return_opt = NUMBER
  • match_arg = VARCHAR
  • source_string parameters that are CLOBs can be a maximum of 16 MB. The function returns an error if this size is exceeded unless match_arg = 'l' is specified. If this is specified, a NULL is returned instead of an error.

    You can also pass arguments with data types that can be converted to the above types using the implicit data type conversion rules that apply to UDFs.

    Note: The UDF implicit type conversion rules are more restrictive than the implicit type conversion rules normally used by Teradata Database. If an argument cannot be converted to the required data type following the UDF implicit conversion rules, it must be explicitly cast.

    For details, see “Compatible Types” in SQL External Routine Programming.

    Result Type

    REGEXP_INSTR is a scalar function whose return value data type is:

  • INTEGER if source_string is a CHAR or VARCHAR
  • BIGINT if source_string is a CLOB
  • Example  

    The following query:

    SELECT REGEXP_INSTR('Hello Santa says ho ho','Hello Santa says ho ho', 1, 1, 1, 'c');

    returns the result 23.

    Example  

    The following query:

    SELECT REGEXP_INSTR('Hello Santa says ho ho', 'Hello Santa says ho ho', 1, 1, 0, 'c');

    returns the result 1.