8.4. String Functions and Operators

This section describes functions and operators for examining and manipulating string values. Strings in this context include values of all the types CHARACTER, VARCHAR, VARCHAR2, 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.

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 8-5. These functions are also implemented using the regular syntax for function invocation. (See Table 8-6.)

Table 8-5. SQL String Functions and Operators

FunctionReturn TypeDescriptionExampleResult
string || string TEXT String concatenation 'EnterpriseDB' || ' 2005'EnterpriseDB 2005
bit_length(string)INTEGERNumber of bits in stringbit_length('jose')32
char_length(string) or character_length(string)INTEGER Number of characters in string char_length('jose')4
convert(string using conversion_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 8-7 for available conversion names. convert('EnterpriseDB' using iso_8859_1_to_utf_8)'EnterpriseDB' in Unicode (UTF-8) encoding
instr(string, set, [start, [occurrence]])INTEGER Finds the location of a set of characters in a string, starting at position start in the string string, and looking for the first, second, third and so on occurrences of the set. instr('PETER PIPER PICKED UP A PACK OF PICKED PEPPERS','PI',1,3)33
lower(string)TEXTConvert string to lower caselower('TOM')tom
octet_length(string)INTEGERNumber of bytes in stringoctet_length('jose')4
overlay(string placing string from INTEGER [for INTEGER])TEXT Replace substring overlay('Txxxxas' placing 'hom' from 2 for 4)Thomas
substr(string, position [, count])TEXT Extract substring starting from start and going for count characters. If count is not specified, the string is clipped from the start till the end. substr('This is a test',6,2)is
trim([leading | trailing | both] [characters] from string) TEXT Remove the longest string containing only the characters (a space by default) from the start/end/both ends of the string. trim(both 'x' from 'xTomxx')Tom
ltrim(string,[set]) TEXT Removes all the characters specified in the set from the left of a given string. If set is not specified, a blank space is used as default. ltrim('abcdefghi','abc')defghi
rtrim(string,[set]) TEXT Removes all the characters specified in the set from the right of a given string. If set is not specified, a blank space is used as default. rtrim('abcdefghi','ghi')abcdef
upper(string)TEXTConvert string to uppercaseupper('tom')TOM

Additional string manipulation functions are available and are listed in Table 8-6. Some of them are used internally to implement the SQL-standard string functions listed in Table 8-5.

Table 8-6. Other String Functions

FunctionReturn TypeDescriptionExampleResult
ascii(TEXT)INTEGERASCII code of the first character of the argumentascii('x')120
btrim(string TEXT [, characters TEXT])TEXT Remove the longest string consisting only of characters in characters (a space by default) from the start and end of string. btrim('xyxtrimyyx', 'xy')trim
chr(INTEGER)TEXTCharacter with the given ASCII codechr(65)A
convert(string TEXT, [src_encoding name,] dest_encoding name) TEXT Convert string to dest_encoding. The original encoding is specified by src_encoding. If src_encoding is omitted, database encoding is assumed. convert( 'text_in_unicode', 'UNICODE', 'LATIN1')text_in_unicode represented in ISO 8859-1 encoding
decode(expr, expr1a, expr1b [,expr2a, expr2b]... [,default]) (same as argument types of expr1b, expr2b,...,default) Finds first match of expr with expr1a, expr2a, etc. When match found, returns corresponding parameter pair, expr1b, expr2b, etc. If no match found, returns default. If no match found and default not specified, returns null. decode(3, 1,'One', 2,'Two', 3,'Three', 'Not found')Three
decode(string TEXT, type TEXT) BYTEA Decode binary data from string previously encoded with encode. Parameter type is same as in encode. decode('MTIzAAE=', 'base64')123\000\001
encode(data BYTEA, type TEXT) TEXT Encode binary data to ASCII-only representation. Supported types are: base64, hex, escape. encode( '123\\000\\001', 'base64')MTIzAAE=
initcap(TEXT)TEXT Convert the first letter of each word to uppercase and the rest to lowercase. Words are sequences of alphanumeric characters separated by non-alphanumeric characters. initcap('hi THOMAS')Hi Thomas
length(string TEXT)INTEGER Number of characters in string. length('jose')4
lpad(string TEXT, length INTEGER [, fill TEXT]) TEXT Fill up the string to length length by prepending the characters fill (a space by default). If the string is already longer than length then it is truncated (on the right). lpad('hi', 5, 'xy')xyxhi
md5(string TEXT)TEXT Calculates the MD5 hash of string, returning the result in hexadecimal. md5('abc')900150983cd24fb0 d6963f7d28e17f72
nvl(expr1, expr2)(same as argument types; where both arguments are of the same datatype) If expr1 is not null, then nvl returns expr2. nvl(ename,'Unknown Employee!')
pg_client_encoding()name Current client encoding name pg_client_encoding()UNICODE
quote_ident(string text)TEXT Return 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. quote_ident('Foo bar')"Foo bar"
quote_literal(string text)TEXT Return the given string suitably quoted to be used as a string literal in an SQL statement string. Embedded quotes and backslashes are properly doubled. quote_literal( 'O\'Reilly')'O''Reilly'
repeat(string TEXT, number INTEGER)TEXTRepeat string the specified number of timesrepeat('Gs', 4)GsGsGsGs
replace(string TEXT, search_string TEXT, [replace_string] TEXT)TEXTReplaces one value in a string with another. If you do not specify a value for replace_string, the search_string value when found, is removed. replace( 'GEORGE', 'GE', 'EG')EGOREG
rpad(string TEXT, length INTEGER [, fill TEXT]) TEXT Fill up the string to length length by appending the characters fill (a space by default). If the string is already longer than length then it is truncated. rpad('hi', 5, 'xy')hixyx
split_part(string TEXT, delimiter TEXT, field INTEGER)TEXTSplit string on delimiter and return the given field (counting from one) split_part( 'abc~@~def~@~ghi', '~@~', 2)def
strpos(string, substring)TEXT Location of specified substring (same as position(substring in string), but note the reversed argument order) strpos('high', 'ig')2
to_ascii(TEXT [, encoding])TEXT Convert text to ASCII from another encoding [a] to_ascii('Karel')Karel
to_hex(number INTEGER or BIGINT)TEXTConvert number to its equivalent hexadecimal representation to_hex(2147483647)7fffffff
translate(string TEXT, from TEXT, to TEXT) TEXT Any character in string that matches a character in the from set is replaced by the corresponding character in the to set. translate('12345', '14', 'ax')a23x5
Notes:
a. The to_ascii function supports conversion from LATIN1, LATIN2, and WIN1250 only.

Table 8-7. Built-in Conversions

Conversion Name [a] Source EncodingDestination Encoding
ascii_to_micSQL_ASCIIMULE_INTERNAL
ascii_to_utf_8SQL_ASCIIUNICODE
big5_to_euc_twBIG5EUC_TW
big5_to_micBIG5MULE_INTERNAL
big5_to_utf_8BIG5UNICODE
euc_cn_to_micEUC_CNMULE_INTERNAL
euc_cn_to_utf_8EUC_CNUNICODE
euc_jp_to_micEUC_JPMULE_INTERNAL
euc_jp_to_sjisEUC_JPSJIS
euc_jp_to_utf_8EUC_JPUNICODE
euc_kr_to_micEUC_KRMULE_INTERNAL
euc_kr_to_utf_8EUC_KRUNICODE
euc_tw_to_big5EUC_TWBIG5
euc_tw_to_micEUC_TWMULE_INTERNAL
euc_tw_to_utf_8EUC_TWUNICODE
gb18030_to_utf_8GB18030UNICODE
gbk_to_utf_8GBKUNICODE
iso_8859_10_to_utf_8LATIN6UNICODE
iso_8859_13_to_utf_8LATIN7UNICODE
iso_8859_14_to_utf_8LATIN8UNICODE
iso_8859_15_to_utf_8LATIN9UNICODE
iso_8859_16_to_utf_8LATIN10UNICODE
iso_8859_1_to_micLATIN1MULE_INTERNAL
iso_8859_1_to_utf_8LATIN1UNICODE
iso_8859_2_to_micLATIN2MULE_INTERNAL
iso_8859_2_to_utf_8LATIN2UNICODE
iso_8859_2_to_windows_1250LATIN2WIN1250
iso_8859_3_to_micLATIN3MULE_INTERNAL
iso_8859_3_to_utf_8LATIN3UNICODE
iso_8859_4_to_micLATIN4MULE_INTERNAL
iso_8859_4_to_utf_8LATIN4UNICODE
iso_8859_5_to_koi8_rISO_8859_5KOI8
iso_8859_5_to_micISO_8859_5MULE_INTERNAL
iso_8859_5_to_utf_8ISO_8859_5UNICODE
iso_8859_5_to_windows_1251ISO_8859_5WIN
iso_8859_5_to_windows_866ISO_8859_5ALT
iso_8859_6_to_utf_8ISO_8859_6UNICODE
iso_8859_7_to_utf_8ISO_8859_7UNICODE
iso_8859_8_to_utf_8ISO_8859_8UNICODE
iso_8859_9_to_utf_8LATIN5UNICODE
johab_to_utf_8JOHABUNICODE
koi8_r_to_iso_8859_5KOI8ISO_8859_5
koi8_r_to_micKOI8MULE_INTERNAL
koi8_r_to_utf_8KOI8UNICODE
koi8_r_to_windows_1251KOI8WIN
koi8_r_to_windows_866KOI8ALT
mic_to_asciiMULE_INTERNALSQL_ASCII
mic_to_big5MULE_INTERNALBIG5
mic_to_euc_cnMULE_INTERNALEUC_CN
mic_to_euc_jpMULE_INTERNALEUC_JP
mic_to_euc_krMULE_INTERNALEUC_KR
mic_to_euc_twMULE_INTERNALEUC_TW
mic_to_iso_8859_1MULE_INTERNALLATIN1
mic_to_iso_8859_2MULE_INTERNALLATIN2
mic_to_iso_8859_3MULE_INTERNALLATIN3
mic_to_iso_8859_4MULE_INTERNALLATIN4
mic_to_iso_8859_5MULE_INTERNALISO_8859_5
mic_to_koi8_rMULE_INTERNALKOI8
mic_to_sjisMULE_INTERNALSJIS
mic_to_windows_1250MULE_INTERNALWIN1250
mic_to_windows_1251MULE_INTERNALWIN
mic_to_windows_866MULE_INTERNALALT
sjis_to_euc_jpSJISEUC_JP
sjis_to_micSJISMULE_INTERNAL
sjis_to_utf_8SJISUNICODE
tcvn_to_utf_8TCVNUNICODE
uhc_to_utf_8UHCUNICODE
utf_8_to_asciiUNICODESQL_ASCII
utf_8_to_big5UNICODEBIG5
utf_8_to_euc_cnUNICODEEUC_CN
utf_8_to_euc_jpUNICODEEUC_JP
utf_8_to_euc_krUNICODEEUC_KR
utf_8_to_euc_twUNICODEEUC_TW
utf_8_to_gb18030UNICODEGB18030
utf_8_to_gbkUNICODEGBK
utf_8_to_iso_8859_1UNICODELATIN1
utf_8_to_iso_8859_10UNICODELATIN6
utf_8_to_iso_8859_13UNICODELATIN7
utf_8_to_iso_8859_14UNICODELATIN8
utf_8_to_iso_8859_15UNICODELATIN9
utf_8_to_iso_8859_16UNICODELATIN10
utf_8_to_iso_8859_2UNICODELATIN2
utf_8_to_iso_8859_3UNICODELATIN3
utf_8_to_iso_8859_4UNICODELATIN4
utf_8_to_iso_8859_5UNICODEISO_8859_5
utf_8_to_iso_8859_6UNICODEISO_8859_6
utf_8_to_iso_8859_7UNICODEISO_8859_7
utf_8_to_iso_8859_8UNICODEISO_8859_8
utf_8_to_iso_8859_9UNICODELATIN5
utf_8_to_johabUNICODEJOHAB
utf_8_to_koi8_rUNICODEKOI8
utf_8_to_sjisUNICODESJIS
utf_8_to_tcvnUNICODETCVN
utf_8_to_uhcUNICODEUHC
utf_8_to_windows_1250UNICODEWIN1250
utf_8_to_windows_1251UNICODEWIN
utf_8_to_windows_1256UNICODEWIN1256
utf_8_to_windows_866UNICODEALT
utf_8_to_windows_874UNICODEWIN874
windows_1250_to_iso_8859_2WIN1250LATIN2
windows_1250_to_micWIN1250MULE_INTERNAL
windows_1250_to_utf_8WIN1250UNICODE
windows_1251_to_iso_8859_5WINISO_8859_5
windows_1251_to_koi8_rWINKOI8
windows_1251_to_micWINMULE_INTERNAL
windows_1251_to_utf_8WINUNICODE
windows_1251_to_windows_866WINALT
windows_1256_to_utf_8WIN1256UNICODE
windows_866_to_iso_8859_5ALTISO_8859_5
windows_866_to_koi8_rALTKOI8
windows_866_to_micALTMULE_INTERNAL
windows_866_to_utf_8ALTUNICODE
windows_866_to_windows_1251ALTWIN
windows_874_to_utf_8WIN874UNICODE
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.