9.4. String Functions and Operators
  This section describes functions and operators for examining and
    manipulating string values.  Strings in this context include values
    of the types
  
   character
  
  ,
  
   character varying
  
  ,
    and
  
   text
  
  .  Except where noted, these functions and operators
    are declared to accept and return type
  
   text
  
  .  They will
    interchangeably accept
  
   character varying
  
  arguments.
    Values of type
  
   character
  
  will be converted
    to
  
   text
  
  before the function or operator is applied, resulting
    in stripping any trailing spaces in the
  
   character
  
  value.
 
SQL defines some string functions that use key words, rather than commas, to separate arguments. Details are in Table 9.9 . PostgreSQL also provides versions of these functions that use the regular function invocation syntax (see Table 9.10 ).
Note
   The string concatenation operator (
   
    ||
   
   ) will accept
     non-string input, so long as at least one input is of string type, as shown
     in
   
    Table 9.9
   
   .  For other cases, inserting an
     explicit coercion to
   
    text
   
   can be used to have non-string input
     accepted.
  
Table 9.9. SQL String Functions and Operators
| Function/Operator Description Example(s) | 
|---|
| Concatenates the two strings. 
         | 
| 
         
         
        Converts the non-string input to text, then concatenates the two
        strings.  (The non-string input cannot be of an array type, because
        that would create ambiguity with the array
         
         | 
| 
        
        
         
        Removes the longest string containing only characters
        in
        
          
         | 
| 
        
        
        
        
         
        Checks whether the string is in the specified Unicode normalization
        form.  The optional
        
          
         | 
| 
        Returns number of bits in the string (8
        times the
         
         | 
| 
        
        
        
        
        
        
         
        
        
         Returns number of characters in the string. 
         | 
| Converts the string to all lower case, according to the rules of the database's locale. 
         | 
| 
        
        
         
        Extends the
        
          
         | 
| 
        
        
         
        Removes the longest string containing only characters in
        
          
         | 
| 
        
        
        
        
         
        Converts the string to the specified Unicode
        normalization form.  The optional
        
          
         | 
| 
        
        
         Returns number of bytes in the string. 
         | 
| 
        
        
         
        Returns number of bytes in the string.  Since this version of the
        function accepts type
         
         | 
| 
        
        
         
        Replaces the substring of
        
          
         | 
| 
        
        
         
        Returns first starting index of the specified
        
          
         | 
| 
        
        
         
        Extends the
        
          
         | 
| 
        
        
         
        Removes the longest string containing only characters in
        
          
         | 
| 
        
        
         
        Extracts the substring of
        
          
         
         
         | 
| 
         Extracts the first substring matching POSIX regular expression; see Section 9.7.3 . 
         | 
| 
         
         Extracts the first substring matching SQL regular expression; see Section 9.7.2 . The first form has been specified since SQL:2003; the second form was only in SQL:1999 and should be considered obsolete. 
         | 
| 
        
        
         
        Removes the longest string containing only characters in
        
          
         | 
| 
         
        This is a non-standard syntax for
         
         | 
| 
        
        
         
        Returns
         | 
| Converts the string to all upper case, according to the rules of the database's locale. 
         | 
Additional string manipulation functions and operators are available and are listed in Table 9.10 . (Some of these are used internally to implement the SQL -standard string functions listed in Table 9.9 .) There are also pattern-matching operators, which are described in Section 9.7 , and operators for full-text search, which are described in Chapter 12 .
Table 9.10. Other String Functions and Operators
| Function/Operator Description Example(s) | 
|---|
| 
        Returns true if the first string starts with the second string
        (equivalent to the
         
         | 
| Returns the numeric code of the first character of the argument. In UTF8 encoding, returns the Unicode code point of the character. In other multibyte encodings, the argument must be an ASCII character. 
         | 
| 
        Returns the character with the given code. In
        
         UTF8
        
        encoding the argument is treated as a Unicode code point. In other
        multibyte encodings the argument must designate
        an
        
         ASCII
        
        character.
         
         | 
| 
        
        
         Concatenates the text representations of all the arguments. NULL arguments are ignored. 
         | 
| 
        
        
         Concatenates all but the first argument, with separators. The first argument is used as the separator string, and should not be NULL. Other NULL arguments are ignored. 
         | 
| 
        
        
         
        Formats arguments according to a format string;
         see
        
         Section 9.4.1
        
        .
         This function is similar to the C function
         
         | 
| Converts the first letter of each word to upper case and the rest to lower case. Words are sequences of alphanumeric characters separated by non-alphanumeric characters. 
         | 
| 
        
        
         
        Returns first
        
          
         | 
| Returns the number of characters in the string. 
         | 
| Computes the MD5 hash of the argument, with the result written in hexadecimal. 
         | 
| 
        
        
         
        Splits
        
          
         | 
| Returns current client encoding name. 
         | 
| Returns the given string suitably quoted to be used as an identifier in an SQL statement string. Quotes are added only if necessary (i.e., if the string contains non-identifier characters or would be case-folded). Embedded quotes are properly doubled. See also Example 41.1 . 
         | 
| 
        Returns the given string suitably quoted to be used as a string literal
        in an
        
         SQL
        
        statement string.
        Embedded single-quotes and backslashes are properly doubled.
        Note that
         
         | 
| 
         Converts the given value to text and then quotes it as a literal. Embedded single-quotes and backslashes are properly doubled. 
         | 
| 
        
        
         
        Returns the given string suitably quoted to be used as a string literal
        in an
        
         SQL
        
        statement string; or, if the argument
        is null, returns
         
         | 
| 
         
        Converts the given value to text and then quotes it as a literal;
        or, if the argument is null, returns
         
         | 
| 
        
        
         
        Returns the number of times the POSIX regular
        expression
        
          
         | 
| 
        
        
         
        Returns the position within
        
          
         
         | 
| 
        
        
         
        Checks whether a match of the POSIX regular
        expression
        
          
         | 
| 
        
        
         
        Returns substrings within the first match of the POSIX regular
        expression
        
          
         | 
| 
        
        
         
        Returns substrings within the first match of the POSIX regular
        expression
        
          
         
 {bar}
 {baz}
 | 
| 
        
        
         
        Replaces the substring that is the first match to the POSIX
        regular expression
        
          
         | 
| 
         
        Replaces the substring that is the
        
          
         | 
| 
        
        
         
        Splits
        
          
         | 
| 
        
        
         
        Splits
        
          
         hello world 
 | 
| 
        
        
         
        Returns the substring within
        
          
         
         | 
| 
        
        
         
        Repeats
        
          
         | 
| 
        
        
         
        Replaces all occurrences in
        
          
         | 
| Reverses the order of the characters in the string. 
         | 
| 
        
        
         
        Returns last
        
          
         | 
| 
        
        
         
        Splits
        
          
         
         | 
| 
        
        
         
        Returns true if
        
          
         | 
| 
        
        
         
        Splits the
        
          
         | 
| 
        
        
         
        Splits the
        
          
         xx NULL zz 
 | 
| 
        
        
         
        Returns first starting index of the specified
        
          
         | 
| 
        
        
         
        Extracts the substring of
        
          
         
         | 
| 
        
        
         
         
         
        Converts
        
          
         | 
| 
         Converts the number to its equivalent two's complement binary representation. 
         
         | 
| 
         Converts the number to its equivalent two's complement hexadecimal representation. 
         
         | 
| 
         Converts the number to its equivalent two's complement octal representation. 
         
         | 
| 
        
        
         
        Replaces each character in
        
          
         | 
| 
        Evaluate escaped Unicode characters in the argument.  Unicode characters
        can be specified as
         If the server encoding is not UTF-8, the Unicode code point identified by one of these escape sequences is converted to the actual server encoding; an error is reported if that's not possible. This function provides a (non-standard) alternative to string constants with Unicode escapes (see Section 4.1.2.3 ). 
         
         | 
  The
  
   concat
  
  ,
  
   concat_ws
  
  and
  
   format
  
  functions are variadic, so it is possible to
    pass the values to be concatenated or formatted as an array marked with
    the
  
   VARIADIC
  
  keyword (see
  
   Section 36.5.6
  
  ).  The array's elements are
    treated as if they were separate ordinary arguments to the function.
    If the variadic array argument is NULL,
  
   concat
  
  and
  
   concat_ws
  
  return NULL, but
  
   format
  
  treats a NULL as a zero-element array.
 
  See also the aggregate function
  
   string_agg
  
  in
  
   Section 9.21
  
  , and the functions for
    converting between strings and the
  
   bytea
  
  type in
  
   Table 9.13
  
  .
 
      9.4.1. 
      
       format
      
      
       #
      
     
    
   The function
   
    format
   
   produces output formatted according to
     a format string, in a style similar to the C function
   
    sprintf
   
   .
  
format(formatstrtext[,formatarg"any"[, ...] ])
   
    
     formatstr
    
   
   is a format string that specifies how the
     result should be formatted.  Text in the format string is copied
     directly to the result, except where
   
    format specifiers
   
   are
     used.  Format specifiers act as placeholders in the string, defining how
     subsequent function arguments should be formatted and inserted into the
     result.  Each
   
    
     formatarg
    
   
   argument is converted to text
     according to the usual output rules for its data type, and then formatted
     and inserted into the result string according to the format specifier(s).
  
   Format specifiers are introduced by a
   
    %
   
   character and have
     the form
  
%[position][flags][width]type
where the component fields are:
- 
     
      
       position(optional)
- 
     A string of the form n$nis the index of the argument to print. Index 1 means the first argument afterformatstr. If thepositionis omitted, the default is to use the next argument in sequence.
- 
     
      
       flags(optional)
- 
     Additional options controlling how the format specifier's output is formatted. Currently the only supported flag is a minus sign ( -) which will cause the format specifier's output to be left-justified. This has no effect unless thewidthfield is also specified.
- 
     
      
       width(optional)
- 
     Specifies the minimum number of characters to use to display the format specifier's output. The output is padded on the left or right (depending on the -flag) with spaces as needed to fill the width. A too-small width does not cause truncation of the output, but is simply ignored. The width may be specified using any of the following: a positive integer; an asterisk (*) to use the next function argument as the width; or a string of the form*to use then$nth function argument as the width.If the width comes from a function argument, that argument is consumed before the argument that is used for the format specifier's value. If the width argument is negative, the result is left aligned (as if the -flag had been specified) within a field of lengthabs(width).
- 
     
      
       type(required)
- 
     The type of format conversion to use to produce the format specifier's output. The following types are supported: - 
        sformats the argument value as a simple string. A null value is treated as an empty string.
- 
        Itreats the argument value as an SQL identifier, double-quoting it if necessary. It is an error for the value to be null (equivalent toquote_ident).
- 
        Lquotes the argument value as an SQL literal. A null value is displayed as the stringNULL, without quotes (equivalent toquote_nullable).
 
- 
        
   In addition to the format specifiers described above, the special sequence
   
    %%
   
   may be used to output a literal
   
    %
   
   character.
  
Here are some examples of the basic format conversions:
SELECT format('Hello %s', 'World');
Result: Hello World
SELECT format('Testing %s, %s, %s, %%', 'one', 'two', 'three');
Result: Testing one, two, three, %
SELECT format('INSERT INTO %I VALUES(%L)', 'Foo bar', E'O\'Reilly');
Result: INSERT INTO "Foo bar" VALUES('O''Reilly')
SELECT format('INSERT INTO %I VALUES(%L)', 'locations', 'C:\Program Files');
Result: INSERT INTO locations VALUES('C:\Program Files')
  
   Here are examples using
   
    
     width
    
   
   fields
     and the
   
    -
   
   flag:
  
SELECT format('|%10s|', 'foo');
Result: |       foo|
SELECT format('|%-10s|', 'foo');
Result: |foo       |
SELECT format('|%*s|', 10, 'foo');
Result: |       foo|
SELECT format('|%*s|', -10, 'foo');
Result: |foo       |
SELECT format('|%-*s|', 10, 'foo');
Result: |foo       |
SELECT format('|%-*s|', -10, 'foo');
Result: |foo       |
  
   These examples show use of
   
    
     position
    
   
   fields:
  
SELECT format('Testing %3$s, %2$s, %1$s', 'one', 'two', 'three');
Result: Testing three, two, one
SELECT format('|%*2$s|', 'foo', 10, 'bar');
Result: |       bar|
SELECT format('|%1$*2$s|', 'foo', 10, 'bar');
Result: |       foo|
  
   Unlike the standard C function
   
    sprintf
   
   ,
   
    PostgreSQL
   
   's
   
    format
   
   function allows format
     specifiers with and without
   
    
     position
    
   
   fields to be mixed
     in the same format string.  A format specifier without a
   
    
     position
    
   
   field always uses the next argument after the
     last argument consumed.
     In addition, the
   
    format
   
   function does not require all
     function arguments to be used in the format string.
     For example:
  
SELECT format('Testing %3$s, %2$s, %s', 'one', 'two', 'three');
Result: Testing three, two, three
  
   The
   
    %I
   
   and
   
    %L
   
   format specifiers are particularly
     useful for safely constructing dynamic SQL statements.  See
   
    Example 41.1
   
   .