HomeMogDBMogDB StackUqbar
v2.0

Documentation:v2.0

Supported Versions:

Other Versions:

Type Conversion Functions

  • cast(x as y)

    Description: Converts x into the type specified by y.

    For example:

    mogdb=# SELECT cast('22-oct-1997' as timestamp);
          timestamp
    ---------------------
     1997-10-22 00:00:00
    (1 row)
  • hextoraw(string)

    Description: Converts a string in hexadecimal format into the raw format.

    Return type: raw

    For example:

    mogdb=# SELECT hextoraw('7D');
     hextoraw
    ----------
     7D
    (1 row)
  • numtoday(numeric)

    Description: Converts values of the number type into the timestamp of the specified type.

    Return type: timestamp

    For example:

    mogdb=# SELECT numtoday(2);
     numtoday
    ----------
     2 days
    (1 row)
  • pg_systimestamp()

    Description: Obtains the system timestamp.

    Return type: timestamp with time zone

    For example:

    mogdb=# SELECT pg_systimestamp();
            pg_systimestamp
    -------------------------------
     2015-10-14 11:21:28.317367+08
    (1 row)
  • rawtohex(string)

    Description: Converts a string in binary format into hexadecimal format.

    The result is the ACSII code of the input characters in hexadecimal format.

    Return type: varchar

    For example:

    mogdb=# SELECT rawtohex('1234567');
        rawtohex
    ----------------
     31323334353637
    (1 row)
  • to_char (datetime/interval [, fmt])

    Description: Converts a DATETIME or INTERVAL value of the DATE/TIMESTAMP/TIMESTAMP WITH TIME ZONE/TIMESTAMP WITH LOCAL TIME ZONE type into the VARCHAR type according to the format specified by fmt.

    • The optional parameter fmt allows for the following types: date, time, week, quarter, and century. Each type has a unique template. The templates can be combined together. Common templates include: HH, MM, SS, YYYY, MM, and DD.
    • A template may have a modification word. FM is a common modification word and is used to suppress the preceding zero or the following blank spaces.

    Return type: varchar

    For example:

    mogdb=# SELECT to_char(current_timestamp,'HH12:MI:SS');
     to_char
    ----------
     10:19:26
    (1 row)
    mogdb=# SELECT to_char(current_timestamp,'FMHH12:FMMI:FMSS');
     to_char
    ----------
     10:19:46
    (1 row)

    Table 1 Template Patterns for Date/Time Formatting

    Pattern Description
    HH hour of day (01-12)
    HH12 hour of day (01-12)
    HH24 hour of day (00-23)
    MI minute (00-59)
    SS second (00-59)
    MS millisecond (000-999)
    US microsecond (000000-999999)
    SSSS seconds past midnight (0-86399)
    AM, am, PM or pm meridiem indicator (without periods)
    A.M., a.m., P.M. or p.m. meridiem indicator (with periods)
    Y,YYY year (4 or more digits) with comma
    YYYY year (4 or more digits)
    YYY last 3 digits of year
    YY last 2 digits of year
    Y last digit of year
    IYYY ISO 8601 week-numbering year (4 or more digits)
    IYY last 3 digits of ISO 8601 week-numbering year
    IY last 2 digits of ISO 8601 week-numbering year
    I last digit of ISO 8601 week-numbering year
    BC, bc, AD or ad era indicator (without periods)
    B.C., b.c., A.D. or a.d. era indicator (with periods)
    MONTH full upper case month name (blank-padded to 9 chars)
    Month full capitalized month name (blank-padded to 9 chars)
    month full lower case month name (blank-padded to 9 chars)
    MON abbreviated upper case month name (3 chars in English, localized lengths vary)
    Mon abbreviated capitalized month name (3 chars in English, localized lengths vary)
    mon abbreviated lower case month name (3 chars in English, localized lengths vary)
    MM month number (01-12)
    DAY full upper case day name (blank-padded to 9 chars)
    Day full capitalized day name (blank-padded to 9 chars)
    day full lower case day name (blank-padded to 9 chars)
    DY abbreviated upper case day name (3 chars in English, localized lengths vary)
    Dy abbreviated capitalized day name (3 chars in English, localized lengths vary)
    dy abbreviated lower case day name (3 chars in English, localized lengths vary)
    DDD day of year (001-366)
    IDDD day of ISO 8601 week-numbering year (001-371; day 1 of the year is Monday of the first ISO week)
    DD day of month (01-31)
    D day of the week, Sunday (1) to Saturday (7)
    ID ISO 8601 day of the week, Monday (1) to Sunday (7)
    W week of month (1-5) (the first week starts on the first day of the month)
    WW week number of year (1-53) (the first week starts on the first day of the year)
    IW week number of ISO 8601 week-numbering year (01-53; the first Thursday of the year is in week 1)
    CC century (2 digits) (the twenty-first century starts on 2001-01-01)
    J Julian Day (integer days since November 24, 4714 BC at midnight UTC)
    Q quarter
    RM month in upper case Roman numerals (I-XII; I=January)
    rm month in lower case Roman numerals (i-xii; i=January)
    TZ upper case time-zone abbreviation (only supported in to_char)
    tz lower case time-zone abbreviation (only supported in to_char)
  • to_char(double precision, text)

    Description: Converts the values of the double-precision type into the strings in the specified format.

    Return type: text

    For example:

    mogdb=# SELECT to_char(125.8::real, '999D99');
     to_char
    ---------
      125.80
    (1 row)
  • to_char (integer/number[, fmt])

    Descriptions: Converts an integer or a value in floating point format into a string in specified format.

    • The optional parameter fmt allows for the following types: decimal characters, grouping characters, positive/negative sign and currency sign. Each type has a unique template. The templates can be combined together. Common templates include: 9, 0, millesimal sign (,), and decimal point (.).
    • A template can have a modification word, similar to FM. However, FM does not suppress 0 which is output according to the template.
    • Use the template X or x to convert an integer value into a string in hexadecimal format.

    Return type: varchar

    For example:

    mogdb=# SELECT to_char(1485,'9,999');
     to_char
    ---------
      1,485
    (1 row)
    mogdb=# SELECT to_char( 1148.5,'9,999.999');
      to_char
    ------------
      1,148.500
    (1 row)
    mogdb=# SELECT to_char(148.5,'990999.909');
       to_char
    -------------
        0148.500
    (1 row)
    mogdb=# SELECT to_char(123,'XXX');
     to_char
    ---------
       7B
    (1 row)
  • to_char(interval, text)

    Description: Converts the values of the time interval type into the strings in the specified format.

    Return type: text

    For example:

    mogdb=# SELECT to_char(interval '15h 2m 12s', 'HH24:MI:SS');
     to_char
    ----------
     15:02:12
    (1 row)
  • to_char(int, text)

    Description: Converts the values of the integer type into the strings in the specified format.

    Return type: text

    For example:

    mogdb=# SELECT to_char(125, '999');
     to_char
    ---------
      125
    (1 row)
  • to_char(numeric, text)

    Description: Converts the values of the numeric type into the strings in the specified format.

    Return type: text

    For example:

    mogdb=# SELECT to_char(-125.8, '999D99S');
     to_char
    ---------
     125.80-
    (1 row)
  • to_char (string)

    Description: Converts the CHAR/VARCHAR/VARCHAR2/CLOB type into the VARCHAR type.

    If this function is used to convert data of the CLOB type, and the value to be converted exceeds the value range of the target type, an error is returned.

    Return type: varchar

    For example:

    mogdb=# SELECT to_char('01110');
     to_char
    ---------
     01110
    (1 row)
  • to_char(timestamp, text)

    Description: Converts the values of the timestamp type into the strings in the specified format.

    Return type: text

    For example:

    mogdb=# SELECT to_char(current_timestamp, 'HH12:MI:SS');
     to_char
    ----------
     10:55:59
    (1 row)
  • to_clob(char/nchar/varchar/varchar2/nvarchar2/text/raw)

    Description: Convert the RAW type or text character set type CHAR/NCHAR/VARCHAR/VARCHAR2/NVARCHAR2/TEXT into the CLOB type.

    Return type: clob

    For example:

    mogdb=# SELECT to_clob('ABCDEF'::RAW(10));
     to_clob
    ---------
     ABCDEF
    (1 row)
    mogdb=# SELECT to_clob('hello111'::CHAR(15));
     to_clob
    ----------
     hello111
    (1 row)
    mogdb=# SELECT to_clob('gauss123'::NCHAR(10));
     to_clob
    ----------
     gauss123
    (1 row)
    mogdb=# SELECT to_clob('gauss234'::VARCHAR(10));
     to_clob
    ----------
     gauss234
    (1 row)
    mogdb=# SELECT to_clob('gauss345'::VARCHAR2(10));
     to_clob
    ----------
     gauss345
    (1 row)
    mogdb=# SELECT to_clob('gauss456'::NVARCHAR2(10));
     to_clob
    ----------
     gauss456
    (1 row)
    mogdb=# SELECT to_clob('World222!'::TEXT);
      to_clob
    -----------
     World222!
    (1 row)
  • to_date(text)

    Description: Converts values of the text type into the timestamp in the specified format.Currently only two types of formats are supported:

    • Format 1: Date without separators, such as 20150814, including the complete year, month, and day.
    • Format 2: Date with separator, such as 2014-08-14, the separator can be any single non-digit character.

    Return type: timestamp

    For example:

      mogdb=# SELECT to_date('2015-08-14');
             to_date
      ---------------------
       2015-08-14 00:00:00
      (1 row)
  • to_date(text, text)

    Description: Converts the values of the string type into the dates in the specified format.

    Return type: timestamp

    For example:

    mogdb=# SELECT to_date('05 Dec 2000', 'DD Mon YYYY');
           to_date
    ---------------------
     2000-12-05 00:00:00
    (1 row)
  • to_date(string, fmt)

    Description:

    Converts a string into a value of the DATE type according to the format specified by fmt.

    This function cannot support the CLOB type directly. However, a parameter of the CLOB type can be converted using implicit conversion.

    Return type: date

    For example:

    mogdb=# SELECT TO_DATE('05 Dec 2010','DD Mon YYYY');
           to_date
    ---------------------
     2010-12-05 00:00:00
    (1 row)
  • to_number ( expr [, fmt])

    Description: Converts expr into a value of the NUMBER type according to the specified format.

    For details about the type conversion formats, see [Table 1](#template patterns).

    If a hexadecimal string is converted into a decimal number, the hexadecimal string can include a maximum of 16 bytes if it is to be converted into a sign-free number.

    During the conversion from a hexadecimal string to a decimal digit, the format string cannot have a character other than x or X. Otherwise, an error is reported.

    Return type: number

    For example:

    mogdb=# SELECT to_number('12,454.8-', '99G999D9S');
     to_number
    -----------
      -12454.8
    (1 row)
  • to_number(text, text)

    Description: Converts the values of the string type into the numbers in the specified format.

    Return type: numeric

    For example:

    mogdb=# SELECT to_number('12,454.8-', '99G999D9S');
     to_number
    -----------
      -12454.8
    (1 row)
  • to_timestamp(double precision)

    Description: Converts a UNIX century into a timestamp.

    Return type: timestamp with time zone

    For example:

    mogdb=# SELECT to_timestamp(1284352323);
          to_timestamp
    ------------------------
     2010-09-13 12:32:03+08
    (1 row)
  • to_timestamp(string [,fmt])

    Description: Converts a string into a value of the timestamp type according to the format specified by fmt. When fmt is not specified, perform the conversion according to the format specified by nls_timestamp_format.

    In to_timestamp in MogDB,

    • If the input year YYYY is 0, an error will be reported.
    • If the input year YYYY is less than 0, specify SYYYY in fmt. The year with the value of n (an absolute value) BC will be output correctly.

    Characters in the fmt must match the schema for formatting the data and time. Otherwise, an error is reported.

    Return type: timestamp without time zone

    For example:

    mogdb=# SHOW nls_timestamp_format;
        nls_timestamp_format
    ----------------------------
     DD-Mon-YYYY HH:MI:SS.FF AM
    (1 row)
    
    mogdb=# SELECT to_timestamp('12-sep-2014');
        to_timestamp
    ---------------------
     2014-09-12 00:00:00
    (1 row)
    mogdb=# SELECT to_timestamp('12-Sep-10 14:10:10.123000','DD-Mon-YY HH24:MI:SS.FF');
          to_timestamp
    -------------------------
     2010-09-12 14:10:10.123
    (1 row)
    mogdb=# SELECT to_timestamp('-1','SYYYY');
          to_timestamp
    ------------------------
     0001-01-01 00:00:00 BC
    (1 row)
    mogdb=# SELECT to_timestamp('98','RR');
        to_timestamp
    ---------------------
     1998-01-01 00:00:00
    (1 row)
    mogdb=# SELECT to_timestamp('01','RR');
        to_timestamp
    ---------------------
     2001-01-01 00:00:00
    (1 row)
  • to_timestamp(text, text)

    Description: Converts values of the string type into the timestamp of the specified type.

    Return type: timestamp

    For example:

    mogdb=# SELECT to_timestamp('05 Dec 2000', 'DD Mon YYYY');
        to_timestamp
    ---------------------
     2000-12-05 00:00:00
    (1 row)

Table 2 Template patterns for numeric formatting

Schema Description
9 Value with specified digits
0 Values with leading zeros
Period (.) Decimal point
Comma (,) Group (thousand) separator
PR Negative values in angle brackets
S Sign anchored to number (uses locale)
L Currency symbol (uses locale)
D Decimal point (uses locale)
G Group separator (uses locale)
MI Minus sign in the specified position (if the number is less than 0)
PL Plus sign in the specified position (if the number is greater than 0)
SG Plus or minus sign in the specified position
RN Roman numerals (the input values are between 1 and 3999)
TH or th Ordinal number suffix
V Shifts specified number of digits (decimal)
Copyright © 2011-2024 www.enmotech.com All rights reserved.