PostgreSQL Oracle 兼容性之 - REMAINDER
背景
在PostgreSQL数据库中常用的取余函数为mod,Oracle另外还提供了一个取余的函数remainder,它与mod的区别在于,mod取余时用了floor处理,而remainder使用round处理。
算法
1. mod
PG & Oracle mod
mod(x,y) = x - trunc(x/y)*y
经典 mod
mod(x,y) = x - y * FLOOR(x/y)
2. remainder
remainder(x,y) = x - y * ROUND(x/y)
REMAINDER(n2, n1)
REMAINDER returns the remainder of n2 divided by n1.
This function takes as arguments any numeric datatype or any nonnumeric datatype that can be implicitly converted to a numeric datatype.
Oracle determines the argument with the highest numeric precedence, implicitly converts the remaining arguments to that datatype, and returns that datatype.
The MOD function is similar to REMAINDER except that it uses FLOOR in its formula, whereas REMAINDER uses ROUND.
-
If n1 = 0 or m2 = infinity, then Oracle returns
An error if the arguments are of type NUMBER
NaN if the arguments are BINARY_FLOAT or BINARY_DOUBLE. -
If n1 != 0, then the remainder is n2 - (n1*N) where N is the integer nearest n2/n1.
If n2 is a floating-point number, and if the remainder is 0, then the sign of the remainder is the sign of n2.
Remainders of 0 are unsigned for NUMBER values.
PostgreSQL remainder
了解算法之后,PG就很容易实现remainder的函数了。
postgres=# create or replace function remainder(int8,int8) returns int8 as $$
select ($1 - $2 * round($1::numeric/$2::numeric))::int8 ;
$$ language sql strict;
CREATE FUNCTION
postgres=# create or replace function remainder(int4,int4) returns int4 as $$
select ($1 - $2 * round($1::numeric/$2::numeric))::int4 ;
$$ language sql strict;
CREATE FUNCTION
postgres=# create or replace function remainder(int2,int2) returns int2 as $$
select ($1 - $2 * round($1::numeric/$2::numeric))::int2 ;
$$ language sql strict;
CREATE FUNCTION
postgres=# create or replace function remainder(numeric,numeric) returns numeric as $$
select ($1 - $2 * round($1/$2)) ;
$$ language sql strict;
CREATE FUNCTION
验证结果
postgres=# select remainder(-11,4);
remainder
-----------
1
(1 row)
postgres=# select mod(-11,4);
mod
-----
-3
(1 row)
参考
http://docs.oracle.com/cd/B19306_01/server.102/b14200/functions133.htm
http://docs.oracle.com/cd/B19306_01/server.102/b14200/functions088.htm