PostgreSQL Oracle 兼容性之 - 字符串 q quote 逃脱符号

4 minute read

背景

Oracle,当需要在字符串中包含单引号时,我们需要输入一对单引号。

例如

SQL> select 'Hello, I''m digoal.' from dual;  
  
'HELLO,I''MDIGOAL.  
------------------  
Hello, I'm digoal.  

使用q quote的写法,可以将quote内部的字符串原样输出,避免写多个单引号带来的困惑。

q'c text-to-be-quoted c' c is a single character (called the quote delimiter).   
With the ?quote operator? apostrophes don't have to  
 be doubled:   
  
SQL> select q'#Oracle's quote operator#' from dual;  
Q'#ORACLE'SQUOTEOPERATO  
-----------------------  
Oracle's quote operator  
  
  
SQL> select q'(Hello I'm digoal.)' from dual;  
  
Q'(HELLOI'MDIGOAL  
-----------------  
Hello I'm digoal.  

PostgreSQL q quote

https://www.postgresql.org/docs/10/static/sql-syntax-lexical.html

使用成对双$即可,或者$tag$成对。

例子:

postgres=# select 'Hello, I''m digoal';  
     ?column?        
-------------------  
 Hello, I'm digoal  
(1 row)  
  
postgres=# select $$Hello, I'm digoal$$;  
     ?column?        
-------------------  
 Hello, I'm digoal  
(1 row)  
  
postgres=# select $abc$Hello, I'm digoal$abc$;  
     ?column?        
-------------------  
 Hello, I'm digoal  
(1 row)  

更多PostgreSQL高级quote

关键字quote与字符串quote

                               List of functions  
   Schema   |      Name      | Result data type | Argument data types |  Type    
------------+----------------+------------------+---------------------+--------  
 pg_catalog | quote_ident    | text             | text                | normal  
 pg_catalog | quote_literal  | text             | anyelement          | normal  
 pg_catalog | quote_literal  | text             | text                | normal  
 pg_catalog | quote_nullable | text             | anyelement          | normal  
 pg_catalog | quote_nullable | text             | text                | normal  
(5 rows)  

1、关键字(例如表名、字段、库名等对象名),自动封装双引号。

postgres=# select quote_ident('Tbl');  
 quote_ident   
-------------  
 "Tbl"  
(1 row)  

2、字符串,自动封装单引号。(输入NULL,返回空)

postgres=# select quote_literal('hello, i''m digoal');  
    quote_literal       
----------------------  
 'hello, i''m digoal'  
(1 row)  
  
postgres=# select quote_literal(null);  
 quote_literal   
---------------  
   
(1 row)  

3、识别空字符串,并返回NULL字符串。

  
postgres=# select quote_nullable(null);  
 quote_nullable   
----------------  
 NULL  
(1 row)  
  
postgres=# select quote_nullable('hello, i''m digoal');  
    quote_nullable      
----------------------  
 'hello, i''m digoal'  
(1 row)  

格式化字符串

https://www.postgresql.org/docs/10/static/functions-string.html#FUNCTIONS-STRING-FORMAT

postgres=# \df format  
                           List of functions  
   Schema   |  Name  | Result data type | Argument data types  |  Type    
------------+--------+------------------+----------------------+--------  
 pg_catalog | format | text             | text                 | normal  
 pg_catalog | format | text             | text, VARIADIC "any" | normal  
(2 rows)  

The function format produces output formatted according to a format string, in a style similar to the C function sprintf.

format(formatstr text [, 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$ where n is the index of the argument to print. Index 1 means the first argument after formatstr. If the position is 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 the width field 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 *n$ to use the 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 length abs(width).

type (required)

The type of format conversion to use to produce the format specifier’s output. The following types are supported:

  • s formats the argument value as a simple string. A null value is treated as an empty string.

  • I treats the argument value as an SQL identifier, double-quoting it if necessary. It is an error for the value to be null (equivalent to quote_ident).

  • L quotes the argument value as an SQL literal. A null value is displayed as the string NULL, without quotes (equivalent to quote_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', E'C:\\Program Files');  
Result: INSERT INTO locations VALUES(E'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 https://www.postgresql.org/docs/10/static/plpgsql-statements.html#PLPGSQL-QUOTE-LITERAL-EXAMPLE .

format常用于PLPGSQL,生成动态SQL。

unicode、ESCAPE

《PostgreSQL 转义、UNICODE、与SQL注入》

参考

https://www.postgresql.org/docs/10/static/sql-syntax-lexical.html

https://www.postgresql.org/docs/10/static/functions-string.html#FUNCTIONS-STRING-FORMAT

Flag Counter

digoal’s 大量PostgreSQL文章入口