This section describes functions and operators for examining and manipulating string values. Strings in this context include values of all the types CHARACTER, CHARACTER VARYING, and TEXT. Unless otherwise noted, all of the functions listed below work on all of these types, but be wary of potential effects of the automatic padding when using the CHARACTER type. Generally, the functions described here also work on data of non-string types by converting that data to a string representation first. Some functions also exist natively for bit-string types.
SQL defines some string functions with a special syntax where certain key words rather than commas are used to separate the arguments. Details are in Table 6-6. These functions are also implemented using the regular syntax for function invocation. (See Table 6-7.)
Table 6-6. SQL String Functions and Operators
| Function | Return Type | Description | Example | Result | 
|---|---|---|---|---|
| string||string | text | String concatenation | 'Post' || 'greSQL' | PostgreSQL | 
| bit_length(string) | integer | Number of bits in string | bit_length('jose') | 32 | 
| char_length(string) orcharacter_length(string) | integer | Number of characters in string | char_length('jose') | 4 | 
| convert(stringusingconversion_name) | text | Change encoding using specified conversion name. Conversions can be defined by CREATE CONVERSION. Also there are some pre-defined conversion names. See Table 6-8 for available conversion names. | convert('PostgreSQL' using iso_8859_1_to_utf_8) | 'PostgreSQL' in Unicode (UTF-8) encoding | 
| lower(string) | text | Convert string to lower case | lower('TOM') | tom | 
| octet_length(string) | integer | Number of bytes in string | octet_length('jose') | 4 | 
| overlay(stringplacingstringfrom integer [for integer]) | text | Insert substring | overlay('Txxxxas' placing 'hom' from 2 for 4) | Thomas | 
| position(substringinstring) | integer | Location of specified substring | position('om' in 'Thomas') | 3 | 
| substring(string[from integer] [for integer]) | text | Extract substring | substring('Thomas' from 2 for 3) | hom | 
| substring(stringfrom pattern) | text | Extract substring matching POSIX regular expression | substring('Thomas' from '...$') | mas | 
| substring(stringfrom pattern for escape) | text | Extract substring matching SQL regular expression | substring('Thomas' from '%#"o_a#"_' for '#') | oma | 
| trim([leading | trailing | both]
        [characters] fromstring) | text | Remove the longest string containing only the characters(a space by default) from the
        beginning/end/both ends of thestring | trim(both 'x' from 'xTomxx') | Tom | 
| upper(string) | text | Convert string to upper case | upper('tom') | TOM | 
Additional string manipulation functions are available and are listed in Table 6-7. Some of them are used internally to implement the SQL-standard string functions listed in Table 6-6.
Table 6-7. Other String Functions
| Function | Return Type | Description | Example | Result | 
|---|---|---|---|---|
| ascii(text) | integer | ASCII code of the first character of the argument. | ascii('x') | 120 | 
| btrim(stringtext,trimtext) | text | Remove (trim) the longest string consisting only of characters
        in trimfrom the start and end ofstring | btrim('xyxtrimyyx','xy') | trim | 
| chr(integer) | text | Character with the given ASCII code | chr(65) | A | 
| convert(stringtext,
        [src_encodingname,]dest_encodingname) | text | Convert string to dest_encoding.
        The original encoding is specified bysrc_encoding.  Ifsrc_encodingis omitted, database
        encoding is assumed. | convert('text_in_unicode', 'UNICODE', 'LATIN1') | text_in_unicode represented in ISO 8859-1 | 
| decode(stringtext,typetext) | bytea | Decode binary data from stringpreviously 
        encoded withencode().  Parameter type is same as inencode(). | decode('MTIzAAE=', 'base64') | 123\000\001 | 
| encode(databytea,typetext) | text | Encode binary data to ASCII-only representation. Supported types are: base64, hex, escape. | encode('123\\000\\001', 'base64') | MTIzAAE= | 
| initcap(text) | text | Convert first letter of each word (whitespace separated) to upper case | initcap('hi thomas') | Hi Thomas | 
| length(string) | integer | Length of string | length('jose') | 4 | 
| lpad(stringtext,lengthinteger
        [,filltext]) | text | Fill up the stringto lengthlengthby prepending the charactersfill(a space by default).  If thestringis already longer thanlengththen it is truncated (on the
        right). | lpad('hi', 5, 'xy') | xyxhi | 
| ltrim(stringtext,texttext) | text | Remove the longest string containing only characters from trimfrom the start of the string. | ltrim('zzzytrim','xyz') | trim | 
| pg_client_encoding() | name | Current client encoding name. | pg_client_encoding() | SQL_ASCII | 
| quote_ident(stringtext) | text | Return the given string suitably quoted to be used as an identifier in an SQL query 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. | quote_ident('Foo') | "Foo" | 
| quote_literal(stringtext) | text | Return the given string suitably quoted to be used as a literal in an SQL query string. Embedded quotes and backslashes are properly doubled. | quote_literal('O\'Reilly') | 'O''Reilly' | 
| repeat(text, integer) | text | Repeat text a number of times | repeat('Pg', 4) | PgPgPgPg | 
| replace(stringtext,fromtext,totext) | text | Replace all occurrences in stringof substringfromwith substringto | replace('abcdefabcdef', 'cd', 'XX') | abXXefabXXef | 
| rpad(stringtext,lengthinteger
        [,filltext]) | text | Fill up the stringto lengthlengthby appending the charactersfill(a space by default).  If thestringis already longer thanlengththen it is truncated. | rpad('hi', 5, 'xy') | hixyx | 
| rtrim(stringtext,trimtext) | text | Remove the longest string containing only characters from trimfrom the end of the string. | rtrim('trimxxxx','x') | trim | 
| split_part(stringtext,delimitertext,columninteger) | text | Split stringondelimiterreturning the resulting (one based)columnnumber. | split_part('abc~@~def~@~ghi','~@~',2) | def | 
| strpos(string,substring) | int | Locate specified substring (same as
        position( substringinstring), but note the reversed
        argument order) | strpos('high','ig') | 2 | 
| substr(string,from[,count]) | text | Extract specified substring (same as
        substring( stringfromfromforcount)) | substr('alphabet', 3, 2) | ph | 
| to_ascii(text
        [,encoding]) | text | Convert text to ASCII from other encoding [a] | to_ascii('Karel') | Karel | 
| to_hex(numberinteger
       or bigint) | text | Convert numberto its equivalent hexadecimal
        representation | to_hex(9223372036854775807::bigint) | 7fffffffffffffff | 
| translate(stringtext,fromtext,totext) | text | Any character in stringthat matches a
        character in thefromset is replaced by
        the corresponding character in thetoset. | translate('12345', '14', 'ax') | a23x5 | 
| Notes: a. The to_asciifunction supports conversion from
         LATIN1, LATIN2, and WIN1250 only. | ||||
Table 6-8. Built-in Conversions
| Conversion Name [a] | Source Encoding | Destination Encoding | 
|---|---|---|
| ascii_to_mic | SQL_ASCII | MULE_INTERNAL | 
| ascii_to_utf_8 | SQL_ASCII | UNICODE | 
| big5_to_euc_tw | BIG5 | EUC_TW | 
| big5_to_mic | BIG5 | MULE_INTERNAL | 
| big5_to_utf_8 | BIG5 | UNICODE | 
| euc_cn_to_mic | EUC_CN | MULE_INTERNAL | 
| euc_cn_to_utf_8 | EUC_CN | UNICODE | 
| euc_jp_to_mic | EUC_JP | MULE_INTERNAL | 
| euc_jp_to_sjis | EUC_JP | SJIS | 
| euc_jp_to_utf_8 | EUC_JP | UNICODE | 
| euc_kr_to_mic | EUC_KR | MULE_INTERNAL | 
| euc_kr_to_utf_8 | EUC_KR | UNICODE | 
| euc_tw_to_big5 | EUC_TW | BIG5 | 
| euc_tw_to_mic | EUC_TW | MULE_INTERNAL | 
| euc_tw_to_utf_8 | EUC_TW | UNICODE | 
| gb18030_to_utf_8 | GB18030 | UNICODE | 
| gbk_to_utf_8 | GBK | UNICODE | 
| iso_8859_10_to_utf_8 | LATIN6 | UNICODE | 
| iso_8859_13_to_utf_8 | LATIN7 | UNICODE | 
| iso_8859_14_to_utf_8 | LATIN8 | UNICODE | 
| iso_8859_15_to_utf_8 | LATIN9 | UNICODE | 
| iso_8859_16_to_utf_8 | LATIN10 | UNICODE | 
| iso_8859_1_to_mic | LATIN1 | MULE_INTERNAL | 
| iso_8859_1_to_utf_8 | LATIN1 | UNICODE | 
| iso_8859_2_to_mic | LATIN2 | MULE_INTERNAL | 
| iso_8859_2_to_utf_8 | LATIN2 | UNICODE | 
| iso_8859_2_to_windows_1250 | LATIN2 | WIN1250 | 
| iso_8859_3_to_mic | LATIN3 | MULE_INTERNAL | 
| iso_8859_3_to_utf_8 | LATIN3 | UNICODE | 
| iso_8859_4_to_mic | LATIN4 | MULE_INTERNAL | 
| iso_8859_4_to_utf_8 | LATIN4 | UNICODE | 
| iso_8859_5_to_koi8_r | ISO_8859_5 | KOI8 | 
| iso_8859_5_to_mic | ISO_8859_5 | MULE_INTERNAL | 
| iso_8859_5_to_utf_8 | ISO_8859_5 | UNICODE | 
| iso_8859_5_to_windows_1251 | ISO_8859_5 | WIN | 
| iso_8859_5_to_windows_866 | ISO_8859_5 | ALT | 
| iso_8859_6_to_utf_8 | ISO_8859_6 | UNICODE | 
| iso_8859_7_to_utf_8 | ISO_8859_7 | UNICODE | 
| iso_8859_8_to_utf_8 | ISO_8859_8 | UNICODE | 
| iso_8859_9_to_utf_8 | LATIN5 | UNICODE | 
| johab_to_utf_8 | JOHAB | UNICODE | 
| koi8_r_to_iso_8859_5 | KOI8 | ISO_8859_5 | 
| koi8_r_to_mic | KOI8 | MULE_INTERNAL | 
| koi8_r_to_utf_8 | KOI8 | UNICODE | 
| koi8_r_to_windows_1251 | KOI8 | WIN | 
| koi8_r_to_windows_866 | KOI8 | ALT | 
| mic_to_ascii | MULE_INTERNAL | SQL_ASCII | 
| mic_to_big5 | MULE_INTERNAL | BIG5 | 
| mic_to_euc_cn | MULE_INTERNAL | EUC_CN | 
| mic_to_euc_jp | MULE_INTERNAL | EUC_JP | 
| mic_to_euc_kr | MULE_INTERNAL | EUC_KR | 
| mic_to_euc_tw | MULE_INTERNAL | EUC_TW | 
| mic_to_iso_8859_1 | MULE_INTERNAL | LATIN1 | 
| mic_to_iso_8859_2 | MULE_INTERNAL | LATIN2 | 
| mic_to_iso_8859_3 | MULE_INTERNAL | LATIN3 | 
| mic_to_iso_8859_4 | MULE_INTERNAL | LATIN4 | 
| mic_to_iso_8859_5 | MULE_INTERNAL | ISO_8859_5 | 
| mic_to_koi8_r | MULE_INTERNAL | KOI8 | 
| mic_to_sjis | MULE_INTERNAL | SJIS | 
| mic_to_windows_1250 | MULE_INTERNAL | WIN1250 | 
| mic_to_windows_1251 | MULE_INTERNAL | WIN | 
| mic_to_windows_866 | MULE_INTERNAL | ALT | 
| sjis_to_euc_jp | SJIS | EUC_JP | 
| sjis_to_mic | SJIS | MULE_INTERNAL | 
| sjis_to_utf_8 | SJIS | UNICODE | 
| tcvn_to_utf_8 | TCVN | UNICODE | 
| uhc_to_utf_8 | UHC | UNICODE | 
| utf_8_to_ascii | UNICODE | SQL_ASCII | 
| utf_8_to_big5 | UNICODE | BIG5 | 
| utf_8_to_euc_cn | UNICODE | EUC_CN | 
| utf_8_to_euc_jp | UNICODE | EUC_JP | 
| utf_8_to_euc_kr | UNICODE | EUC_KR | 
| utf_8_to_euc_tw | UNICODE | EUC_TW | 
| utf_8_to_gb18030 | UNICODE | GB18030 | 
| utf_8_to_gbk | UNICODE | GBK | 
| utf_8_to_iso_8859_1 | UNICODE | LATIN1 | 
| utf_8_to_iso_8859_10 | UNICODE | LATIN6 | 
| utf_8_to_iso_8859_13 | UNICODE | LATIN7 | 
| utf_8_to_iso_8859_14 | UNICODE | LATIN8 | 
| utf_8_to_iso_8859_15 | UNICODE | LATIN9 | 
| utf_8_to_iso_8859_16 | UNICODE | LATIN10 | 
| utf_8_to_iso_8859_2 | UNICODE | LATIN2 | 
| utf_8_to_iso_8859_3 | UNICODE | LATIN3 | 
| utf_8_to_iso_8859_4 | UNICODE | LATIN4 | 
| utf_8_to_iso_8859_5 | UNICODE | ISO_8859_5 | 
| utf_8_to_iso_8859_6 | UNICODE | ISO_8859_6 | 
| utf_8_to_iso_8859_7 | UNICODE | ISO_8859_7 | 
| utf_8_to_iso_8859_8 | UNICODE | ISO_8859_8 | 
| utf_8_to_iso_8859_9 | UNICODE | LATIN5 | 
| utf_8_to_johab | UNICODE | JOHAB | 
| utf_8_to_koi8_r | UNICODE | KOI8 | 
| utf_8_to_sjis | UNICODE | SJIS | 
| utf_8_to_tcvn | UNICODE | TCVN | 
| utf_8_to_uhc | UNICODE | UHC | 
| utf_8_to_windows_1250 | UNICODE | WIN1250 | 
| utf_8_to_windows_1251 | UNICODE | WIN | 
| utf_8_to_windows_1256 | UNICODE | WIN1256 | 
| utf_8_to_windows_866 | UNICODE | ALT | 
| utf_8_to_windows_874 | UNICODE | WIN874 | 
| windows_1250_to_iso_8859_2 | WIN1250 | LATIN2 | 
| windows_1250_to_mic | WIN1250 | MULE_INTERNAL | 
| windows_1250_to_utf_8 | WIN1250 | UNICODE | 
| windows_1251_to_iso_8859_5 | WIN | ISO_8859_5 | 
| windows_1251_to_koi8_r | WIN | KOI8 | 
| windows_1251_to_mic | WIN | MULE_INTERNAL | 
| windows_1251_to_utf_8 | WIN | UNICODE | 
| windows_1251_to_windows_866 | WIN | ALT | 
| windows_1256_to_utf_8 | WIN1256 | UNICODE | 
| windows_866_to_iso_8859_5 | ALT | ISO_8859_5 | 
| windows_866_to_koi8_r | ALT | KOI8 | 
| windows_866_to_mic | ALT | MULE_INTERNAL | 
| windows_866_to_utf_8 | ALT | UNICODE | 
| windows_866_to_windows_1251 | ALT | WIN | 
| windows_874_to_utf_8 | WIN874 | UNICODE | 
| Notes: a. The conversion names follow a standard naming scheme: The official name of the source encoding with all non-alphanumeric characters replaced by underscores followed by _to_ followed by the equally processed destination encoding name. Therefore the names might deviate from the customary encoding names. | ||