PostgreSQL 自定义自动类型转换(CAST)

本文涉及的产品
云数据库 RDS SQL Server,基础系列 2核4GB
云数据库 RDS MySQL,集群系列 2核4GB
推荐场景:
搭建个人博客
云原生数据库 PolarDB 分布式版,标准版 2核8GB
简介:

标签

PostgreSQL , cast


背景

PostgreSQL是一个强类型数据库,因此你输入的变量、常量是什么类型,是强绑定的,例如

在调用操作符时,需要通过操作符边上的数据类型,选择对应的操作符。

在调用函数时,需要根据输入的类型,选择对应的函数。

如果类型不匹配,就会报操作符不存在,或者函数不存在的错误。

postgres=# select '1' + '1';  
ERROR:  operator is not unique: unknown + unknown  
LINE 1: select '1' + '1';  
                   ^  
HINT:  Could not choose a best candidate operator. You might need to add explicit type casts.  

那么使用起来是不是很不方便呢?

PostgreSQL开放了类型转换的接口,同时也内置了很多的自动类型转换。来简化操作。

查看目前已有的类型转换:

postgres=# \dC+  
                                                List of casts  
         Source type         |         Target type         |      Function      |   Implicit?   | Description   
-----------------------------+-----------------------------+--------------------+---------------+-------------  
 "char"                      | character                   | bpchar             | in assignment |   
 "char"                      | character varying           | text               | in assignment |   
 "char"                      | integer                     | int4               | no            |   
 "char"                      | text                        | text               | yes           |   
 abstime                     | date                        | date               | in assignment |   
 abstime                     | integer                     | (binary coercible) | no            |   
 abstime                     | time without time zone      | time               | in assignment |   
  
 ................................  
  
 timestamp without time zone | timestamp with time zone    | timestamptz        | yes           |   
 timestamp without time zone | timestamp without time zone | timestamp          | yes           |   
 xml                         | character                   | (binary coercible) | in assignment |   
 xml                         | character varying           | (binary coercible) | in assignment |   
 xml                         | text                        | (binary coercible) | in assignment |   
(246 rows)  

如果你发现有些类型转换没有内置,怎么办呢?我们可以自定义转换。

当然你也可以使用这种语法,对类型进行强制转换:

CAST(x AS typename)   
  
  or   
  
x::typename  

如何自定义类型转换(CAST)

自定义CAST的语法如下:

CREATE CAST (source_type AS target_type)  
    WITH FUNCTION function_name [ (argument_type [, ...]) ]  
    [ AS ASSIGNMENT | AS IMPLICIT ]  
  
CREATE CAST (source_type AS target_type)  
    WITHOUT FUNCTION  
    [ AS ASSIGNMENT | AS IMPLICIT ]  
  
CREATE CAST (source_type AS target_type)  
    WITH INOUT  
    [ AS ASSIGNMENT | AS IMPLICIT ]  

解释:

1、WITH FUNCTION,表示转换需要用到什么函数。

2、WITHOUT FUNCTION,表示被转换的两个类型,在数据库的存储中一致,即物理存储一致。例如text和varchar的物理存储一致。不需要转换函数。

Two types can be binary coercible,   
which means that the conversion can be performed “for free” without invoking any function.   
  
This requires that corresponding values use the same internal representation.   
  
For instance, the types text and varchar are binary coercible both ways.   
  
Binary coercibility is not necessarily a symmetric relationship.   
  
For example, the cast from xml to text can be performed for free in the present implementation,   
but the reverse direction requires a function that performs at least a syntax check.   
  
(Two types that are binary coercible both ways are also referred to as binary compatible.)  

3、WITH INOUT,表示使用内置的IO函数进行转换。每一种类型,都有INPUT 和OUTPUT函数。使用这种方法,好处是不需要重新写转换函数。

除非有特殊需求,我们建议直接使用IO函数来进行转换。

                               List of functions  
   Schema   |      Name       | Result data type | Argument data types |  Type    
------------+-----------------+------------------+---------------------+--------  
 pg_catalog | textin          | text             | cstring             | normal  
 pg_catalog | textout         | cstring          | text                | normal  
 pg_catalog | date_in         | date             | cstring             | normal  
 pg_catalog | date_out        | cstring          | date                | normal  
You can define a cast as an I/O conversion cast by using the WITH INOUT syntax.   
  
An I/O conversion cast is performed by invoking the output function of the source data type,   
and passing the resulting string to the input function of the target data type.   
  
In many common cases, this feature avoids the need to write a separate cast function for conversion.   
  
An I/O conversion cast acts the same as a regular function-based cast; only the implementation is different.  

4、AS ASSIGNMENT,表示在赋值时,自动对类型进行转换。例如字段类型为TEXT,输入的类型为INT,那么可以创建一个 cast(int as text) as ASSIGNMENT。

If the cast is marked AS ASSIGNMENT then it can be invoked implicitly when assigning a value to a column of the target data type.   
  
For example, supposing that foo.f1 is a column of type text, then:  
  
INSERT INTO foo (f1) VALUES (42);  
  
will be allowed if the cast from type integer to type text is marked AS ASSIGNMENT,   
otherwise not.   
  
(We generally use the term assignment cast to describe this kind of cast.)  

5、AS IMPLICIT,表示在表达式中,或者在赋值操作中,都对类型进行自动转换。(包含了AS ASSIGNMENT,它只对赋值进行转换)

If the cast is marked AS IMPLICIT then it can be invoked implicitly in any context,   
whether assignment or internally in an expression.   
  
(We generally use the term implicit cast to describe this kind of cast.)   
  
For example, consider this query:  
  
SELECT 2 + 4.0;  
  
The parser initially marks the constants as being of type integer and numeric respectively.   
  
There is no integer + numeric operator in the system catalogs, but there is a numeric + numeric operator.   
  
The query will therefore succeed if a cast from integer to numeric is available and is marked AS IMPLICIT —   
which in fact it is.   
  
The parser will apply the implicit cast and resolve the query as if it had been written  
  
SELECT CAST ( 2 AS numeric ) + 4.0;  

6、注意,AS IMPLICIT需要谨慎使用,为什么呢?因为操作符会涉及到多个算子,如果有多个转换,目前数据库并不知道应该选择哪个?

Now, the catalogs also provide a cast from numeric to integer.   
  
If that cast were marked AS IMPLICIT — (which it is not — )  
  
then the parser would be faced with choosing between the above interpretation and   
the alternative of casting the numeric constant to integer and applying the integer + integer operator.   
  
Lacking any knowledge of which choice to prefer, it would give up and declare the query ambiguous.   
  
The fact that only one of the two casts is implicit is the way in which we teach the parser to prefer resolution of   
a mixed numeric-and-integer expression as numeric;   
  
there is no built-in knowledge about that.  

因此,建议谨慎使用AS IMPLICIT。建议使用AS IMPLICIT的CAST应该是非失真转换转换,例如从INT转换为TEXT,或者int转换为numeric。

而失真转换,不建议使用as implicit,例如numeric转换为int。

It is wise to be conservative about marking casts as implicit.   
  
An overabundance of implicit casting paths can cause PostgreSQL to choose surprising interpretations of commands,   
or to be unable to resolve commands at all because there are multiple possible interpretations.   
  
A good rule of thumb is to make a cast implicitly invokable only for information-preserving   
transformations between types in the same general type category.   
  
For example, the cast from int2 to int4 can reasonably be implicit,   
but the cast from float8 to int4 should probably be assignment-only.   
  
Cross-type-category casts, such as text to int4, are best made explicit-only.  

注意事项 + 例子

不能嵌套转换。例子

1、将text转换为date

错误方法

create or replace function text_to_date(text) returns date as $$  
  select cast($1 as date);  
$$ language sql strict;  
  
create cast (text as date) with function text_to_date(text) as implicit;  

嵌套转换后出现死循环

postgres=# select text '2017-01-01' + 1;  
ERROR:  stack depth limit exceeded  
HINT:  Increase the configuration parameter "max_stack_depth" (currently 2048kB), after ensuring the platform's stack depth limit is adequate.  
CONTEXT:  SQL function "text_to_date" during startup  
SQL function "text_to_date" statement 1  
SQL function "text_to_date" statement 1  
SQL function "text_to_date" statement 1  
......  

正确方法

create or replace function text_to_date(text) returns date as $$          
  select to_date($1,'yyyy-mm-dd');  
$$ language sql strict;  
  
create cast (text as date) with function text_to_date(text) as implicit;  
postgres=# select text '2017-01-01' + 1;  
  ?column?    
------------  
 2017-01-02  
(1 row)  

我们还可以直接使用IO函数来转换:

postgres=# create cast (text as date) with inout as implicit;
CREATE CAST

postgres=# select text '2017-01-01' + 1;
  ?column?  
------------
 2017-01-02
(1 row)

参考

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

相关实践学习
使用PolarDB和ECS搭建门户网站
本场景主要介绍基于PolarDB和ECS实现搭建门户网站。
阿里云数据库产品家族及特性
阿里云智能数据库产品团队一直致力于不断健全产品体系,提升产品性能,打磨产品功能,从而帮助客户实现更加极致的弹性能力、具备更强的扩展能力、并利用云设施进一步降低企业成本。以云原生+分布式为核心技术抓手,打造以自研的在线事务型(OLTP)数据库Polar DB和在线分析型(OLAP)数据库Analytic DB为代表的新一代企业级云原生数据库产品体系, 结合NoSQL数据库、数据库生态工具、云原生智能化数据库管控平台,为阿里巴巴经济体以及各个行业的企业客户和开发者提供从公共云到混合云再到私有云的完整解决方案,提供基于云基础设施进行数据从处理、到存储、再到计算与分析的一体化解决方案。本节课带你了解阿里云数据库产品家族及特性。
目录
相关文章
|
关系型数据库 Go PostgreSQL
golang pgx自定义PostgreSQL类型
golang的pgx驱动提供了大约70种PostgreSQL类型支持,但还是有一些类型没有涵盖,本文介绍如何自己编写代码支持特殊的类型。
|
弹性计算 容灾 关系型数据库
PostgreSQL PITR 任意时间点恢复过程中如何手工得到recovery需要的下一个WAL文件名 - 默认情况下restore_command自动获取
标签 PostgreSQL , recovery , recovery.conf , restore_command , timeline , 时间线 , next wal , PITR , 时间点恢复 背景 PostgreSQL数据库支持PITR时间点恢复。默认情况下,只需要配置目标是时间点,resotre_command即可,PG会自动调用resotre_command去找需要的WA
1506 0
|
SQL 移动开发 关系型数据库
PostgreSQL 执行计划,成本公式解说,代价因子校准,自动跟踪SQL执行计划(三)|学习笔记
快速学习PostgreSQL 执行计划,成本公式解说,代价因子校准,自动跟踪SQL执行计划(三)
PostgreSQL 执行计划,成本公式解说,代价因子校准,自动跟踪SQL执行计划(三)|学习笔记
|
SQL 监控 关系型数据库
21 PostgreSQL 监控2 趋势监控数据收集和分析 nagios 实时监控部署和自定义监控|学习笔记(三)
快速学习21 PostgreSQL 监控2 趋势监控数据收集和分析 nagios 实时监控部署和自定义监控
300 0
21 PostgreSQL 监控2 趋势监控数据收集和分析 nagios 实时监控部署和自定义监控|学习笔记(三)
|
SQL 分布式计算 并行计算
PostgreSQL 并行计算解说 之10 - parallel 自定义并行函数(UDF)
标签 PostgreSQL , cpu 并行 , smp 并行 , 并行计算 , gpu 并行 , 并行过程支持 背景 PostgreSQL 11 优化器已经支持了非常多场合的并行。简单估计,已支持27余种场景的并行计算。 parallel seq scan parallel index scan
1689 0
|
SQL 数据可视化 关系型数据库
postgresql如何设置自动增长
postgresql如何设置自动增长
454 0
|
关系型数据库 MySQL 数据库
PostgreSQL的学习心得和知识总结(二十五)|语法级自上而下完美实现MySQL数据库的 字段默认值的自动插入更新 的实现方案
本人CSDN博主 孤傲小二~阿沐,本文《PostgreSQL的学习心得和知识总结(二十五)|语法级自上而下完美实现MySQL数据库的 字段默认值的自动插入更新 的实现方案》来自于我在CSDN的同名文档
|
弹性计算 监控 关系型数据库
PostgreSQL 双节点流复制如何同时保证可用性、可靠性(rpo,rto) - (半同步,自动降级方法实践)
标签 PostgreSQL , 同步 , 半同步 , 流复制 背景 两节点HA架构,如何做到跨机房RPO=0(可靠性维度)?同时RTO可控(可用性维度)? 半同步是一个不错的选择。 1、当只挂掉一个节点时,可以保证RPO=0。如下: 主 -> 从(挂) 主(挂) -> 从 2、当一个节点挂掉后,在另一个节点恢复并开启同步模式前,如果在此期间(
2205 0
|
弹性计算 关系型数据库 数据库
PostgreSQL 如何让心跳永远不死,支持半同步自动同步、异步升降级 - udf 心跳
标签 PostgreSQL , 同步 , 半同步 , 流复制 , 心跳 , 自动降级 , 自动升级 , dblink , 异步调用 背景 在心跳时,通过自定义UDF,实现心跳永远不被堵塞,并且支持更加当前的配置自动的进行同步、异步模式的升降级。实现半同步的功能。 UDF输入 1、优先模式(同步、异步) 2、同步等待超时时间 当优先为同步模式时,假设当前为同步配置,如果备库异常导致
1927 0
|
SQL 分布式计算 并行计算
PostgreSQL 并行计算解说 之9 - parallel 自定义并行聚合
标签 PostgreSQL , cpu 并行 , smp 并行 , 并行计算 , gpu 并行 , 并行过程支持 背景 PostgreSQL 11 优化器已经支持了非常多场合的并行。简单估计,已支持27余种场景的并行计算。 parallel seq scan parallel index scan
608 0

相关产品

  • 云原生数据库 PolarDB
  • 云数据库 RDS PostgreSQL 版