OREPLACE - 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

OREPLACE

Purpose  

Replaces every occurrence of search_string in the source_string with the replace_string. Use this function either to replace or remove portions of a string.

Syntax  

where:

 

Syntax element…

Specifies…

TD_SYSFNLIB

the name of the database where the function is located.

source_string

a character string or string expression.

If source_string is NULL, the function returns NULL.

search_string

a string of characters that will be replaced or removed from source_string.

If search_string is NULL, the function returns source_string.

replace_string

an optional string of characters that replaces the characters specified by search_string.

If replace_string is NULL or is an empty string, or is omitted, all occurrences of search_string are removed from the source_string.

ANSI Compliance

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

Invocation

OREPLACE 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 one of the following data types:

CHAR, VARCHAR, or CLOB

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

The result data type and character set depend on those of the source_string argument.

  • If the source_string is CHAR, the result data type is VARCHAR.
  • If the source_string is VARCHAR, the result data type is VARCHAR.
  • If the source_string is CLOB, the result data type is CLOB.
  • For example, if the source_string argument has a data type of CHAR CHARACTER SET UNICODE, then the result data type will be VARCHAR CHARACTER SET UNICODE.

    The maximum length of a VARCHAR or CLOB result value is the maximum length that Teradata supports for these data types. An error is returned if the result string is larger than the maximum result string size.

    Usage Notes  

    OREPLACE provides a superset of the functionality provided by the OTRANSLATE function. OTRANSLATE provides single character, 1-to-1 substitution while OREPLACE allows you to substitute 1 string for another, as well as to remove character strings.

    For information about the OTRANSLATE function, see “OTRANSLATE” on page 1228.

    Example  

    The following query returns the string 'TD14.0 is the current version'. The string '13.1' in the source string was replaced by the string '14.0'.

       SELECT OREPLACE('TD13.1 is the current version', '13.1', '14.0'); 

    Example  

    The following query returns the string 'This chair is a brown chair'. Both occurrences of the search string 'bag' in the source string were replaced by the string 'chair'.

       SELECT OREPLACE('This bag is a brown bag', 'bag', 'chair'); 

    Example  

    The following query returns the string 'TD13.1 is the current version'. The source string is returned unchanged since the search string is NULL. The result would be the same if the search string is an empty string or a string that has no matches in the source string.

       SELECT OREPLACE('TD13.1 is the current version', NULL, '14.0'); 

    Example  

    The following query returns the string 'We removed the extra word'. The occurrence of the search string 'superfluous' was removed from the source string.

       SELECT OREPLACE('We removed the superfluous extra word',
          'superfluous', NULL); 

    Example  

    The result set from the following query will have an ADDRESS column that is the concatenation of the ADDRESS1 and ADDRESS2 columns from the CUSTOMER table, with every occurrence of 'st.' replaced with ' street'.

       SELECT OREPLACE(ADDRESS1||ADDRESS2, ' st.', ' street') AS ADDRESS
          from CUSTOMER;