| 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 Function | Return Type | Description | Example | Result |
---|
string ||
string | TEXT | String concatenation
| 'EnterpriseDB' || ' 2005' | EnterpriseDB 2005 | bit_length (string) | INTEGER | Number of bits in string | bit_length('jose') | 32 | char_length (string) or character_length (string) | INTEGER | Number of characters in string
| char_length('jose') | 4 | concat (string
s1, string s2) | TEXT | String concatenation
| concat('a','b') | ab | 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_utf8) | 'EnterpriseDB' in UTF8 (Unicode, 8-bit) 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) | TEXT | Convert string to lower case | lower('TOM') | tom | octet_length (string) | INTEGER | Number of bytes in string | octet_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) | TEXT | Convert string to uppercase | upper('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 Function | Return Type | Description | Example | Result |
---|
ascii (TEXT) | INTEGER | ASCII code of the first character of the argument | ascii('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) | TEXT | Character with the given ASCII code | chr(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) | TEXT | Repeat string the specified
number of times | repeat('Gs', 4) | GsGsGsGs | replace (string TEXT,
search_string TEXT,
[replace_string] TEXT) | TEXT | Replaces 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) | TEXT | Split string on delimiter
and return the given field (counting from one)
| split_part( 'abc~@~def~@~ghi', '~@~', 2) | def | strpos (string, substring) | INT | 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
| to_ascii('Karel') | Karel | to_hex (number INTEGER
or BIGINT) | TEXT | Convert 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
| Source Encoding | Destination Encoding |
---|
ascii_to_mic | SQL_ASCII | MULE_INTERNAL | ascii_to_utf8 | SQL_ASCII | UTF8 | big5_to_euc_tw | BIG5 | EUC_TW | big5_to_mic | BIG5 | MULE_INTERNAL | big5_to_utf8 | BIG5 | UTF8 | euc_cn_to_mic | EUC_CN | MULE_INTERNAL | euc_cn_to_utf8 | EUC_CN | UTF8 | euc_jp_to_mic | EUC_JP | MULE_INTERNAL | euc_jp_to_sjis | EUC_JP | SJIS | euc_jp_to_utf8 | EUC_JP | UTF8 | euc_kr_to_mic | EUC_KR | MULE_INTERNAL | euc_kr_to_utf8 | EUC_KR | UTF8 | euc_tw_to_big5 | EUC_TW | BIG5 | euc_tw_to_mic | EUC_TW | MULE_INTERNAL | euc_tw_to_utf8 | EUC_TW | UTF8 | gb18030_to_utf8 | GB18030 | UTF8 | gbk_to_utf8 | GBK | UTF8 | iso_8859_10_to_utf8 | LATIN6 | UTF8 | iso_8859_13_to_utf8 | LATIN7 | UTF8 | iso_8859_14_to_utf8 | LATIN8 | UTF8 | iso_8859_15_to_utf8 | LATIN9 | UTF8 | iso_8859_16_to_utf8 | LATIN10 | UTF8 | iso_8859_1_to_mic | LATIN1 | MULE_INTERNAL | iso_8859_1_to_utf8 | LATIN1 | UTF8 | iso_8859_2_to_mic | LATIN2 | MULE_INTERNAL | iso_8859_2_to_utf8 | LATIN2 | UTF8 | iso_8859_2_to_windows_1250 | LATIN2 | WIN1250 | iso_8859_3_to_mic | LATIN3 | MULE_INTERNAL | iso_8859_3_to_utf8 | LATIN3 | UTF8 | iso_8859_4_to_mic | LATIN4 | MULE_INTERNAL | iso_8859_4_to_utf8 | LATIN4 | UTF8 | iso_8859_5_to_koi8_r | ISO_8859_5 | KOI8 | iso_8859_5_to_mic | ISO_8859_5 | MULE_INTERNAL | iso_8859_5_to_utf8 | ISO_8859_5 | UTF8 | iso_8859_5_to_windows_1251 | ISO_8859_5 | WIN1251 | iso_8859_5_to_windows_866 | ISO_8859_5 | WIN866 | iso_8859_6_to_utf8 | ISO_8859_6 | UTF8 | iso_8859_7_to_utf8 | ISO_8859_7 | UTF8 | iso_8859_8_to_utf8 | ISO_8859_8 | UTF8 | iso_8859_9_to_utf8 | LATIN5 | UTF8 | johab_to_utf8 | JOHAB | UTF8 | koi8_r_to_iso_8859_5 | KOI8 | ISO_8859_5 | koi8_r_to_mic | KOI8 | MULE_INTERNAL | koi8_r_to_utf8 | KOI8 | UTF8 | koi8_r_to_windows_1251 | KOI8 | WIN1251 | koi8_r_to_windows_866 | KOI8 | WIN866 | 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 | WIN1251 | mic_to_windows_866 | MULE_INTERNAL | WIN866 | sjis_to_euc_jp | SJIS | EUC_JP | sjis_to_mic | SJIS | MULE_INTERNAL | sjis_to_utf8 | SJIS | UTF8 | tcvn_to_utf8 | WIN1258 | UTF8 | uhc_to_utf8 | UHC | UTF8 | utf8_to_ascii | UTF8 | SQL_ASCII | utf8_to_big5 | UTF8 | BIG5 | utf8_to_euc_cn | UTF8 | EUC_CN | utf8_to_euc_jp | UTF8 | EUC_JP | utf8_to_euc_kr | UTF8 | EUC_KR | utf8_to_euc_tw | UTF8 | EUC_TW | utf8_to_gb18030 | UTF8 | GB18030 | utf8_to_gbk | UTF8 | GBK | utf8_to_iso_8859_1 | UTF8 | LATIN1 | utf8_to_iso_8859_10 | UTF8 | LATIN6 | utf8_to_iso_8859_13 | UTF8 | LATIN7 | utf8_to_iso_8859_14 | UTF8 | LATIN8 | utf8_to_iso_8859_15 | UTF8 | LATIN9 | utf8_to_iso_8859_16 | UTF8 | LATIN10 | utf8_to_iso_8859_2 | UTF8 | LATIN2 | utf8_to_iso_8859_3 | UTF8 | LATIN3 | utf8_to_iso_8859_4 | UTF8 | LATIN4 | utf8_to_iso_8859_5 | UTF8 | ISO_8859_5 | utf8_to_iso_8859_6 | UTF8 | ISO_8859_6 | utf8_to_iso_8859_7 | UTF8 | ISO_8859_7 | utf8_to_iso_8859_8 | UTF8 | ISO_8859_8 | utf8_to_iso_8859_9 | UTF8 | LATIN5 | utf8_to_johab | UTF8 | JOHAB | utf8_to_koi8_r | UTF8 | KOI8 | utf8_to_sjis | UTF8 | SJIS | utf8_to_tcvn | UTF8 | WIN1258 | utf8_to_uhc | UTF8 | UHC | utf8_to_windows_1250 | UTF8 | WIN1250 | utf8_to_windows_1251 | UTF8 | WIN1251 | utf8_to_windows_1252 | UTF8 | WIN1252 | utf8_to_windows_1256 | UTF8 | WIN1256 | utf8_to_windows_866 | UTF8 | WIN866 | utf8_to_windows_874 | UTF8 | WIN874 | windows_1250_to_iso_8859_2 | WIN1250 | LATIN2 | windows_1250_to_mic | WIN1250 | MULE_INTERNAL | windows_1250_to_utf8 | WIN1250 | UTF8 | windows_1251_to_iso_8859_5 | WIN1251 | ISO_8859_5 | windows_1251_to_koi8_r | WIN1251 | KOI8 | windows_1251_to_mic | WIN1251 | MULE_INTERNAL | windows_1251_to_utf8 | WIN1251 | UTF8 | windows_1251_to_windows_866 | WIN1251 | WIN866 | windows_1252_to_utf8 | WIN1252 | UTF8 | windows_1256_to_utf8 | WIN1256 | UTF8 | windows_866_to_iso_8859_5 | WIN866 | ISO_8859_5 | windows_866_to_koi8_r | WIN866 | KOI8 | windows_866_to_mic | WIN866 | MULE_INTERNAL | windows_866_to_utf8 | WIN866 | UTF8 | windows_866_to_windows_1251 | WIN866 | WIN | windows_874_to_utf8 | WIN874 | UTF8 | 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.
|
| |
---|