├── .gitignore ├── .travis.yml ├── META.json ├── Makefile ├── README.md ├── all.sql ├── mysqlcompat.control ├── sql └── mysqlcompat_uninstall.sql ├── sql_bits ├── aggregate.sql ├── bit.sql ├── casts.sql ├── controlflow.sql ├── datetime.sql ├── information.sql ├── mathematical.sql ├── misc.sql ├── operators.sql └── string.sql ├── test ├── expected │ ├── datetime.out │ └── mathematical.out └── sql │ ├── datetime.sql │ └── mathematical.sql └── tools ├── README ├── makesetbld.sh └── makesetdrop.sh /.gitignore: -------------------------------------------------------------------------------- 1 | sql/mysqlcompat--0.0.2.sql 2 | sql/mysqlcompat.sql 3 | results/ 4 | regression.diffs 5 | regression.out 6 | -------------------------------------------------------------------------------- /.travis.yml: -------------------------------------------------------------------------------- 1 | sudo: required 2 | dist: trusty 3 | language: sql 4 | # addons.postgresql section: does not support multiple values :( 5 | #addons: 6 | # postgresql: 9.3 7 | env: 8 | - PG=9.5 9 | - PG=9.4 10 | - PG=9.3 11 | - PG=9.2 12 | - PG=9.1 13 | install: 14 | - sudo service postgresql stop 15 | # Optimization: only update 3rd party repos, not Ubuntu's own 16 | - sudo apt-get update -o Dir::Etc::sourcelist=/dev/null 17 | - sudo apt-get install postgresql-$PG postgresql-server-dev-$PG 18 | - sudo service postgresql start $PG 19 | script: 20 | - pg_lsclusters 21 | - psql postgres -xA -c 'select version()' 22 | - make 23 | - sudo make install 24 | - make installcheck || (cat regression.diffs && false) 25 | -------------------------------------------------------------------------------- /META.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "mysqlcompat", 3 | "abstract": "MySQL compatibility functions", 4 | "description": "A reimplemenation of as many MySQL functions as possible in PostgreSQL, as an aid to porting", 5 | "version": "0.0.7", 6 | "release_status": "stable", 7 | 8 | "maintainer": "Marc G Fournier ", 9 | "generated_by": "Marc G Fournier ", 10 | "license": "unrestricted", 11 | "provides": { 12 | "mysqlcompat": { 13 | "abstract": "MySQL compatibility functions", 14 | "file": "all.sql", 15 | "version": "0.0.7" 16 | } 17 | }, 18 | "resources": { 19 | "bugtracker": { 20 | "web": "https://github.com/2ndQuadrant/mysqlcompat/issues" 21 | }, 22 | "repository": { 23 | "url": "https://github.com/2ndQuadrant/mysqlcompat.git", 24 | "web": "https://github.com/2ndQuadrant/mysqlcompat", 25 | "type": "git" 26 | } 27 | }, 28 | "meta-spec": { 29 | "version": "1.0.0", 30 | "url": "http://pgxn.org/meta/spec.txt" 31 | }, 32 | "tags": [ 33 | "mysql", 34 | "compatibility", 35 | "conversion", 36 | "functions", 37 | "2ndQuadrant" 38 | ] 39 | } 40 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | EXTENSION = mysqlcompat 2 | EXTVERSION = $(shell grep default_version $(EXTENSION).control | \ 3 | sed -e "s/default_version[[:space:]]*=[[:space:]]*'\([^']*\)'/\1/") 4 | 5 | DATA = $(filter-out $(wildcard sql/*--*.sql),$(wildcard sql/*.sql)) 6 | #DOCS = $(wildcard doc/*.md) 7 | TESTS = $(wildcard test/sql/*.sql) 8 | REGRESS = $(patsubst test/sql/%.sql,%,$(TESTS)) 9 | REGRESS_OPTS = --inputdir=test --load-language=plpgsql 10 | #MODULES = $(patsubst %.c,%,$(wildcard src/*.c)) 11 | PG_CONFIG = pg_config 12 | PG91 = $(shell $(PG_CONFIG) --version | grep -qE " 8\.| 9\.0" && echo no || echo yes) 13 | 14 | SQL_BITS = $(wildcard sql_bits/*.sql) 15 | 16 | sql/$(EXTENSION).sql: $(SQL_BITS) 17 | cat $^ > $@ 18 | 19 | EXTRA_CLEAN += sql/$(EXTENSION).sql 20 | 21 | ifeq ($(PG91),yes) 22 | all: sql/$(EXTENSION)--$(EXTVERSION).sql 23 | 24 | sql/$(EXTENSION)--$(EXTVERSION).sql: sql/$(EXTENSION).sql 25 | cp $< $@ 26 | 27 | DATA = $(wildcard sql/*--*.sql) sql/$(EXTENSION)--$(EXTVERSION).sql 28 | EXTRA_CLEAN += sql/$(EXTENSION)--$(EXTVERSION).sql 29 | endif 30 | 31 | PGXS := $(shell $(PG_CONFIG) --pgxs) 32 | include $(PGXS) 33 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | MySQL Compatibility Functions 2 | ============================= 3 | 4 | Authors: Chris Kings-Lynne, Gavin Sherry & Others 5 | 6 | Contributors: Michael Fuhr, Robert Treat, Marti Raudsepp 7 | 8 | Current maintainer: Marc G Fournier 9 | 10 | Development of this extension is sponsored by [2ndQuadrant](https://2ndquadrant.com) 11 | 12 | Introduction 13 | ------------ 14 | 15 | This project is a collection of functions, aggregates, 16 | operators and casts that make PostgreSQL mimic MySQL as 17 | closely as possible. 18 | 19 | To use the project, you can either find and install the 20 | few functions that you need, or run all the .sql files 21 | to install the complete compatibility environment. 22 | 23 | This can be an immense time-saver when porting large applications 24 | that rely heavily on certain MySQL functions. 25 | 26 | Versions of PostgreSQL supported 27 | -------------------------------- 28 | 29 | This package has been tested on PostgreSQL 8.2.x through 9.5.x 30 | 31 | Installation 32 | ------------ 33 | 34 | First, you must have created a database in PostgreSQL. 35 | 36 | Then, a few of the functions are written in the PL/PgSQL 37 | language handler. If you use these functions you need 38 | to install that handler, like this: 39 | 40 | createlang plpgsql 41 | 42 | Next, load any (or all) of the .sql files into that 43 | database, eg: 44 | 45 | psql -f all.sql 46 | 47 | Or, to install a particular subset of functions: 48 | 49 | psql -f sql_bits/datetime.sql 50 | 51 | Or, if you only want to install a particular function, just 52 | copy and paste it into psql directly, taking care to install any 53 | of the function's listed dependencies. 54 | 55 | You will see a series of CREATE (and other) tags 56 | that indicates each successful command. Read any 57 | other messages that appear as they may be errors. 58 | 59 | Alternatively, you can execute the SQL scripts via 60 | a GUI tool such as pgAdmin (www.pgadmin.org) or 61 | phpPgAdmin (phppgadmin.sf.net). 62 | 63 | Uninstall 64 | --------- 65 | 66 | The mysqlcompat_uninstall.sql script contains drop commands for every object in 67 | this library. To drop everything for example, run: 68 | 69 | psql -f sql/mysqlcompat_uninstall.sql 70 | 71 | Then, if you have no further need for the PL/PgSQL language handler 72 | you can drop it as follows: 73 | 74 | droplang plpgsql 75 | 76 | Usage 77 | ----- 78 | 79 | If you have followed the installation notes above, then 80 | all the MySQL compatibility functions, operators and 81 | aggregates will be installed in the public schema of your 82 | database. This means you can use them without any special 83 | qualification. 84 | 85 | Here are some examples: 86 | 87 | ``` 88 | SELECT true && false; 89 | => f 90 | ``` 91 | 92 | ``` 93 | SELECT format(1234.432, 4); 94 | => 1,234.4320 95 | ``` 96 | 97 | General Compatibility Notes 98 | --------------------------- 99 | 100 | In some cases (obviously) MySQL is just too different 101 | from PostgreSQL to allow re-implementation of features. 102 | 103 | This usually happens when a MySQL feature would require 104 | changing the PostgreSQL SQL grammar. 105 | 106 | Any function name that begins with '_' in this library 107 | is a "private" function that should not be called directly. 108 | 109 | Here is a list of major incompatibilities: 110 | 111 | * Boolean vs. Integer 112 | 113 | MySQL has no boolean type, and instead it uses the integer 114 | values 0 and 1 as boolean results. PostgreSQL has a true 115 | boolean type and it can accept 0, 1, true, false, 't' or 'f' 116 | as values. However, by default all boolean values are SHOWN 117 | as either 't' or 'f'. 118 | 119 | Since PostgreSQL already has most of MySQL's logical operators 120 | (eg. OR, AND, etc.) which all return 't' or 'f' to mean true or 121 | false, then there isn't much point returning 0 or 1 for the 122 | two or three logical operators that this library implements. 123 | This is just something you need to deal with during porting. 124 | 125 | Tip: PostgreSQL includes a boolean to integer explicit cast, eg: 126 | 127 | ``` 128 | SELECT true::integer + 1; 129 | => 2 130 | ``` 131 | 132 | * Time vs. Interval 133 | 134 | MySQL has no interval type, and hence often confuses 'time' 135 | with 'interval'. For example, '123:13:56' is a valid interval 136 | but is an invalid time. 137 | 138 | This library uses the PostgreSQL interval type for many of the 139 | MySQL functions that require or return times. In general 140 | this won't make any difference. 141 | 142 | * Intervals 143 | 144 | In MySQL, intervals are not quoted, eg: 145 | 146 | SELECT ADDDATE('1998-01-02', INTERVAL 31 DAY); 147 | 148 | In PostgreSQL the 31 DAY part needs to be quoted: 149 | 150 | SELECT ADDDATE('1998-01-02', INTERVAL '31 DAY'); 151 | 152 | * Missing operators 153 | 154 | XOR, DIV and MOD named operators cannot be implemented. Use #, / (with integer casts) and % instead. 155 | 156 | * Case-sensitive strings 157 | 158 | All PostgreSQL strings are case-sensitive. All MySQL strings are 159 | case-insensitive by default. Any functions in this library that 160 | implement string comparison use CASE-SENSITIVE comparison, just 161 | like all the other PostgreSQL string functions. 162 | 163 | * Failure to find overloaded functions 164 | 165 | In some cases (due to the way PostgreSQL works) you will need 166 | to add explicit casts to some function calls. An explicit cast 167 | looks like this: 168 | 169 | SELECT ADDTIME('01:00:00.999999'::interval, '02:00:00.999998'); 170 | 171 | -------------------------------------------------------------------------------- /all.sql: -------------------------------------------------------------------------------- 1 | \i sql_bits/aggregate.sql 2 | \i sql_bits/bit.sql 3 | \i sql_bits/casts.sql 4 | \i sql_bits/controlflow.sql 5 | \i sql_bits/datetime.sql 6 | \i sql_bits/information.sql 7 | \i sql_bits/mathematical.sql 8 | \i sql_bits/misc.sql 9 | \i sql_bits/operators.sql 10 | \i sql_bits/string.sql 11 | -------------------------------------------------------------------------------- /mysqlcompat.control: -------------------------------------------------------------------------------- 1 | # mysqlcompat extension 2 | comment = 'MySQL compatibility functions' 3 | default_version = '0.0.7' 4 | module_pathname = '$libdir/mysqlcompat' 5 | relocatable = true 6 | -------------------------------------------------------------------------------- /sql/mysqlcompat_uninstall.sql: -------------------------------------------------------------------------------- 1 | DROP CAST (time with time zone AS integer); 2 | DROP CAST (timestamp with time zone AS bigint); 3 | DROP CAST (timestamp without time zone AS bigint); 4 | DROP CAST (time without time zone AS integer); 5 | DROP CAST (interval AS bigint); 6 | DROP CAST (date AS integer); 7 | DROP OPERATOR || (boolean, boolean); 8 | DROP OPERATOR <=> (anyelement, anyelement); 9 | DROP OPERATOR && (boolean, boolean); 10 | DROP AGGREGATE group_concat(text); 11 | DROP AGGREGATE bit_xor(bigint); 12 | DROP FUNCTION yearweek(date); 13 | DROP FUNCTION yearweek(qdate date, "mode" integer); 14 | DROP FUNCTION "year"(date); 15 | DROP FUNCTION weekofyear(date); 16 | DROP FUNCTION weekday(date); 17 | DROP FUNCTION week(date); 18 | DROP FUNCTION week(date, integer); 19 | DROP FUNCTION utc_timestamp(); 20 | DROP FUNCTION utc_time(); 21 | DROP FUNCTION utc_date(); 22 | DROP FUNCTION unix_timestamp(timestamp without time zone); 23 | DROP FUNCTION unix_timestamp(); 24 | DROP FUNCTION unhex(text); 25 | DROP FUNCTION ucase(text); 26 | DROP FUNCTION "truncate"(numeric, integer); 27 | DROP FUNCTION to_days(date); 28 | DROP FUNCTION timestampadd(text, integer, timestamp without time zone); 29 | DROP FUNCTION timediff(time without time zone, time without time zone); 30 | DROP FUNCTION timediff(timestamp without time zone, timestamp without time zone); 31 | DROP FUNCTION time_to_sec(interval); 32 | DROP FUNCTION time_format(interval, text); 33 | DROP FUNCTION system_user(); 34 | DROP FUNCTION sysdate(); 35 | DROP FUNCTION subtime(interval, interval); 36 | DROP FUNCTION subtime(timestamp without time zone, interval); 37 | DROP FUNCTION substring_index(text, text, integer); 38 | DROP FUNCTION subdate(timestamp without time zone, integer); 39 | DROP FUNCTION subdate(timestamp without time zone, interval); 40 | DROP FUNCTION strcmp(text, text); 41 | DROP FUNCTION str_to_date(text, text); 42 | DROP FUNCTION space(integer); 43 | DROP FUNCTION soundex(text); 44 | DROP FUNCTION sleep(double precision); 45 | DROP FUNCTION "second"(interval); 46 | DROP FUNCTION sec_to_time(bigint); 47 | DROP FUNCTION "schema"(); 48 | DROP FUNCTION "right"(text, integer); 49 | DROP FUNCTION reverse(text); 50 | DROP FUNCTION rand(integer); 51 | DROP FUNCTION rand(); 52 | DROP FUNCTION "quote"(text); 53 | DROP FUNCTION quarter(date); 54 | DROP FUNCTION period_diff(integer, integer); 55 | DROP FUNCTION period_add(integer, integer); 56 | DROP FUNCTION ord(text); 57 | DROP FUNCTION oct(integer); 58 | DROP FUNCTION monthname(date); 59 | DROP FUNCTION "month"(date); 60 | DROP FUNCTION "minute"(time without time zone); 61 | DROP FUNCTION mid(text, integer, integer); 62 | DROP FUNCTION microsecond(time without time zone); 63 | DROP FUNCTION maketime(integer, integer, integer); 64 | DROP FUNCTION makedate(integer, integer); 65 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text); 66 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text); 67 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text); 68 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text); 69 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text); 70 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text); 71 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text); 72 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text); 73 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text); 74 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text); 75 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text); 76 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text); 77 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text); 78 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text); 79 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text); 80 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text); 81 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text); 82 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text); 83 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text); 84 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text); 85 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text); 86 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text); 87 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text); 88 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text, text); 89 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text, text); 90 | DROP FUNCTION make_set(bigint, text, text, text, text, text, text); 91 | DROP FUNCTION make_set(bigint, text, text, text, text, text); 92 | DROP FUNCTION make_set(bigint, text, text, text, text); 93 | DROP FUNCTION make_set(bigint, text, text, text); 94 | DROP FUNCTION make_set(bigint, text, text); 95 | DROP FUNCTION make_set(bigint, text); 96 | DROP FUNCTION log2(numeric); 97 | DROP FUNCTION log10(numeric); 98 | DROP FUNCTION locate(text, text); 99 | DROP FUNCTION locate(text, text, integer); 100 | DROP FUNCTION "left"(text, integer); 101 | DROP FUNCTION lcase(text); 102 | DROP FUNCTION last_insert_id(); 103 | DROP FUNCTION last_day(timestamp without time zone); 104 | DROP FUNCTION instr(text, text); 105 | DROP FUNCTION "insert"(text, integer, integer, text); 106 | DROP FUNCTION inet_ntoa(bigint); 107 | DROP FUNCTION inet_aton(text); 108 | DROP FUNCTION ifnull(anyelement, anyelement); 109 | DROP FUNCTION "if"(boolean, anyelement, anyelement); 110 | DROP FUNCTION "hour"(interval); 111 | DROP FUNCTION hex(text); 112 | DROP FUNCTION hex(bigint); 113 | DROP FUNCTION hex(integer); 114 | DROP FUNCTION get_format(text, text); 115 | DROP FUNCTION from_unixtime(bigint, text); 116 | DROP FUNCTION from_unixtime(bigint); 117 | DROP FUNCTION from_days(integer); 118 | DROP FUNCTION format(numeric, integer); 119 | DROP FUNCTION find_in_set(text, text); 120 | DROP FUNCTION field(text, text, text, text, text); 121 | DROP FUNCTION field(text, text, text, text); 122 | DROP FUNCTION field(text, text, text); 123 | DROP FUNCTION export_set(bigint, text, text); 124 | DROP FUNCTION export_set(bigint, text, text, text); 125 | DROP FUNCTION export_set(bigint, text, text, text, integer); 126 | DROP FUNCTION elt(integer, text, text, text, text); 127 | DROP FUNCTION elt(integer, text, text, text); 128 | DROP FUNCTION elt(integer, text, text); 129 | DROP FUNCTION dayofyear(date); 130 | DROP FUNCTION dayofweek(date); 131 | DROP FUNCTION dayofmonth(date); 132 | DROP FUNCTION dayname(date); 133 | DROP FUNCTION "day"(date); 134 | DROP FUNCTION datediff(date, date); 135 | DROP FUNCTION date_sub(timestamp without time zone, interval); 136 | DROP FUNCTION date_format(timestamp without time zone, text); 137 | DROP FUNCTION date_add(timestamp without time zone, interval); 138 | DROP FUNCTION "database"(); 139 | DROP FUNCTION curtime(); 140 | DROP FUNCTION curdate(); 141 | DROP FUNCTION crc32(text); 142 | DROP FUNCTION convert_tz(timestamp without time zone, text, text); 143 | DROP FUNCTION conv(text, integer, integer); 144 | DROP FUNCTION conv(integer, integer, integer); 145 | DROP FUNCTION connection_id(); 146 | DROP FUNCTION concat_ws(text, text, text, text); 147 | DROP FUNCTION concat_ws(text, text, text); 148 | DROP FUNCTION concat_ws(text, text); 149 | DROP FUNCTION concat(text, text, text); 150 | DROP FUNCTION concat(text, text); 151 | DROP FUNCTION concat(text); 152 | DROP FUNCTION collation(text); 153 | DROP FUNCTION coercibility(text); 154 | DROP FUNCTION coercibility(name); 155 | DROP FUNCTION charset(text); 156 | DROP FUNCTION bit_count(bigint); 157 | DROP FUNCTION bin(bigint); 158 | DROP FUNCTION benchmark(integer, text); 159 | DROP FUNCTION atan(double precision, double precision); 160 | DROP FUNCTION addtime(interval, interval); 161 | DROP FUNCTION addtime(timestamp without time zone, interval); 162 | DROP FUNCTION adddate(timestamp without time zone, integer); 163 | DROP FUNCTION adddate(timestamp without time zone, interval); 164 | DROP FUNCTION _week_mode("mode" integer); 165 | DROP FUNCTION _todec(text, integer); 166 | DROP FUNCTION _timestamp_to_bigint(timestamp without time zone); 167 | DROP FUNCTION _timestamp_to_bigint(timestamp with time zone); 168 | DROP FUNCTION _time_to_integer(time without time zone); 169 | DROP FUNCTION _time_to_integer(time with time zone); 170 | DROP FUNCTION _soundexcode(character); 171 | DROP FUNCTION _or(boolean, boolean); 172 | DROP FUNCTION _null_safe_cmp(anyelement, anyelement); 173 | DROP FUNCTION _make_set(bigint, text[]); 174 | DROP FUNCTION _interval_to_bigint(interval); 175 | DROP FUNCTION _group_concat(text, text); 176 | DROP FUNCTION _date_to_integer(date); 177 | DROP FUNCTION _calc_weekday(qdate date, sundayfirst boolean); 178 | DROP FUNCTION _calc_week(qdate date, behavior integer); 179 | DROP FUNCTION _calc_days_in_year("year" integer); 180 | DROP FUNCTION _bit_xor(bigint, bigint); 181 | DROP FUNCTION _and(boolean, boolean); 182 | -------------------------------------------------------------------------------- /sql_bits/aggregate.sql: -------------------------------------------------------------------------------- 1 | -- BIT_XOR 2 | -- Note: only works for integers and bigints 3 | CREATE OR REPLACE FUNCTION _bit_xor(bigint, bigint) 4 | RETURNS bigint AS $$ 5 | SELECT $1 # COALESCE($2, 0) 6 | $$ IMMUTABLE LANGUAGE SQL; 7 | 8 | CREATE AGGREGATE bit_xor ( 9 | BASETYPE = bigint, 10 | SFUNC = _bit_xor, 11 | STYPE = bigint, 12 | INITCOND = 0 13 | ); 14 | 15 | -- GROUP_CONCAT() 16 | -- Note: only supports the comma separator 17 | -- Note: For DISTINCT and ORDER BY a subquery is required 18 | CREATE OR REPLACE FUNCTION _group_concat(text, text) 19 | RETURNS text AS $$ 20 | SELECT CASE 21 | WHEN $2 IS NULL THEN $1 22 | WHEN $1 IS NULL THEN $2 23 | ELSE $1 operator(pg_catalog.||) ',' operator(pg_catalog.||) $2 24 | END 25 | $$ IMMUTABLE LANGUAGE SQL; 26 | 27 | CREATE AGGREGATE group_concat ( 28 | BASETYPE = text, 29 | SFUNC = _group_concat, 30 | STYPE = text 31 | ); 32 | 33 | -------------------------------------------------------------------------------- /sql_bits/bit.sql: -------------------------------------------------------------------------------- 1 | -- BIT_COUNT() 2 | CREATE OR REPLACE FUNCTION bit_count(bigint) 3 | RETURNS integer AS $$ 4 | SELECT pg_catalog.length(pg_catalog.replace(pg_catalog.ltrim(pg_catalog.textin(pg_catalog.bit_out($1::bit(64))), '0'), '0', '')); 5 | $$ IMMUTABLE STRICT LANGUAGE SQL; 6 | -------------------------------------------------------------------------------- /sql_bits/casts.sql: -------------------------------------------------------------------------------- 1 | -- TIME TO INTEGER 2 | CREATE OR REPLACE FUNCTION _time_to_integer(time with time zone) 3 | RETURNS integer AS $$ 4 | SELECT 5 | EXTRACT(HOUR FROM $1)::integer * 10000 6 | + EXTRACT(MINUTE FROM $1)::integer * 100 7 | + EXTRACT(SECONDS FROM $1)::integer 8 | $$ IMMUTABLE STRICT LANGUAGE SQL; 9 | 10 | CREATE CAST (time with time zone AS integer) 11 | WITH FUNCTION _time_to_integer (time with time zone) 12 | AS IMPLICIT; 13 | 14 | CREATE OR REPLACE FUNCTION _time_to_integer(time without time zone) 15 | RETURNS integer AS $$ 16 | SELECT 17 | EXTRACT(HOUR FROM $1)::integer * 10000 18 | + EXTRACT(MINUTE FROM $1)::integer * 100 19 | + EXTRACT(SECONDS FROM $1)::integer 20 | $$ IMMUTABLE STRICT LANGUAGE SQL; 21 | 22 | CREATE CAST (time without time zone AS integer) 23 | WITH FUNCTION _time_to_integer (time without time zone) 24 | AS IMPLICIT; 25 | 26 | -- DATE TO INTEGER 27 | -- Note: requires explicit casts in some cases 28 | CREATE OR REPLACE FUNCTION _date_to_integer(date) 29 | RETURNS integer AS $$ 30 | SELECT 31 | EXTRACT(YEAR FROM $1)::integer * 10000 32 | + EXTRACT(MONTH FROM $1)::integer * 100 33 | + EXTRACT(DAY FROM $1)::integer 34 | $$ IMMUTABLE STRICT LANGUAGE SQL; 35 | 36 | CREATE CAST (date AS integer) 37 | WITH FUNCTION _date_to_integer (date) 38 | AS IMPLICIT; 39 | 40 | -- TIMESTAMP TO BIGINT 41 | -- Depends on: _time_to_integer and _date_to_integer 42 | CREATE OR REPLACE FUNCTION _timestamp_to_bigint(timestamp with time zone) 43 | RETURNS bigint AS $$ 44 | SELECT _date_to_integer($1::date)::bigint * 1000000 + _time_to_integer($1::time) 45 | $$ IMMUTABLE STRICT LANGUAGE SQL; 46 | 47 | CREATE CAST (timestamp with time zone AS bigint) 48 | WITH FUNCTION _timestamp_to_bigint (timestamp with time zone) 49 | AS IMPLICIT; 50 | 51 | CREATE OR REPLACE FUNCTION _timestamp_to_bigint(timestamp without time zone) 52 | RETURNS bigint AS $$ 53 | SELECT _date_to_integer($1::date)::bigint * 1000000 + _time_to_integer($1::time) 54 | $$ IMMUTABLE STRICT LANGUAGE SQL; 55 | 56 | CREATE CAST (timestamp without time zone AS bigint) 57 | WITH FUNCTION _timestamp_to_bigint (timestamp without time zone) 58 | AS IMPLICIT; 59 | 60 | -- INTERVAL TO BIGINT 61 | CREATE OR REPLACE FUNCTION _interval_to_bigint(interval) 62 | RETURNS bigint AS $$ 63 | SELECT 64 | EXTRACT(YEAR FROM $1)::bigint * 10000000000 65 | + EXTRACT(MONTH FROM $1)::bigint * 100000000 66 | + EXTRACT(DAY FROM $1)::bigint * 1000000 67 | + EXTRACT(HOUR FROM $1)::bigint * 10000 68 | + EXTRACT(MINUTE FROM $1)::bigint * 100 69 | + EXTRACT(SECONDS FROM $1)::bigint 70 | $$ IMMUTABLE STRICT LANGUAGE SQL; 71 | 72 | CREATE CAST (interval AS bigint) 73 | WITH FUNCTION _interval_to_bigint (interval) 74 | AS IMPLICIT; 75 | 76 | -------------------------------------------------------------------------------- /sql_bits/controlflow.sql: -------------------------------------------------------------------------------- 1 | -- IF 2 | -- Warning: still requires casts in some instances 3 | CREATE OR REPLACE FUNCTION if(boolean, anyelement, anyelement) 4 | RETURNS anyelement AS ' 5 | SELECT CASE WHEN $1 THEN $2 ELSE $3 END 6 | ' IMMUTABLE LANGUAGE SQL; 7 | 8 | -- IFNULL 9 | -- Warning: still requires casts in some instances 10 | CREATE OR REPLACE FUNCTION ifnull(anyelement, anyelement) 11 | RETURNS anyelement AS ' 12 | SELECT COALESCE($1, $2) 13 | ' IMMUTABLE LANGUAGE SQL; 14 | 15 | -------------------------------------------------------------------------------- /sql_bits/datetime.sql: -------------------------------------------------------------------------------- 1 | -- ADDDATE() 2 | -- Note: passing in the interval is different 3 | CREATE OR REPLACE FUNCTION adddate(timestamp without time zone, interval) 4 | RETURNS timestamp without time zone AS $$ 5 | SELECT $1 + $2 6 | $$ IMMUTABLE STRICT LANGUAGE SQL; 7 | 8 | CREATE OR REPLACE FUNCTION adddate(timestamp without time zone, integer) 9 | RETURNS timestamp without time zone AS $$ 10 | SELECT $1 + (INTERVAL '1 day' * $2) 11 | $$ IMMUTABLE STRICT LANGUAGE SQL; 12 | 13 | -- ADDTIME() 14 | -- Note: requires casting if you install both versions 15 | CREATE OR REPLACE FUNCTION addtime(timestamp without time zone, interval) 16 | RETURNS timestamp without time zone AS $$ 17 | SELECT $1 + $2 18 | $$ IMMUTABLE STRICT LANGUAGE SQL; 19 | 20 | CREATE OR REPLACE FUNCTION addtime(interval, interval) 21 | RETURNS interval AS $$ 22 | SELECT $1 + $2 23 | $$ IMMUTABLE STRICT LANGUAGE SQL; 24 | 25 | -- CONVERT_TZ() 26 | CREATE OR REPLACE FUNCTION convert_tz(timestamp without time zone, text, text) 27 | RETURNS timestamp without time zone AS $$ 28 | SELECT CASE 29 | WHEN POSITION(':' IN $3) = 0 THEN 30 | ($1 operator(pg_catalog.||) ' ' operator(pg_catalog.||) $2)::timestamp with time zone AT TIME ZONE $3 31 | ELSE 32 | ($1 operator(pg_catalog.||) ' ' operator(pg_catalog.||) $2)::timestamp with time zone AT TIME ZONE $3::interval 33 | END 34 | $$ IMMUTABLE STRICT LANGUAGE SQL; 35 | 36 | -- CURDATE() 37 | CREATE OR REPLACE FUNCTION curdate() 38 | RETURNS date AS $$ 39 | SELECT CURRENT_DATE 40 | $$ VOLATILE LANGUAGE SQL; 41 | 42 | -- CURTIME() 43 | CREATE OR REPLACE FUNCTION curtime() 44 | RETURNS time without time zone AS $$ 45 | SELECT LOCALTIME(0) 46 | $$ VOLATILE LANGUAGE SQL; 47 | 48 | -- DATEDIFF() 49 | CREATE OR REPLACE FUNCTION datediff(date, date) 50 | RETURNS integer AS $$ 51 | SELECT $1 - $2 52 | $$ IMMUTABLE STRICT LANGUAGE SQL; 53 | 54 | -- DATE_ADD() 55 | CREATE OR REPLACE FUNCTION date_add(timestamp without time zone, interval) 56 | RETURNS timestamp without time zone AS $$ 57 | SELECT $1 + $2 58 | $$ IMMUTABLE STRICT LANGUAGE SQL; 59 | 60 | -- DATE_FORMAT() 61 | CREATE OR REPLACE FUNCTION date_format(timestamp without time zone, text) 62 | RETURNS text AS $$ 63 | DECLARE 64 | i int := 1; 65 | temp text := ''; 66 | c text; 67 | n text; 68 | res text; 69 | BEGIN 70 | WHILE i <= pg_catalog.length($2) LOOP 71 | -- Look at current character 72 | c := SUBSTRING ($2 FROM i FOR 1); 73 | -- If it's a '%' and not the last character then process it as a placeholder 74 | IF c = '%' AND i != pg_catalog.length($2) THEN 75 | n := SUBSTRING ($2 FROM (i + 1) FOR 1); 76 | SELECT INTO res CASE 77 | WHEN n = 'a' THEN pg_catalog.to_char($1, 'Dy') 78 | WHEN n = 'b' THEN pg_catalog.to_char($1, 'Mon') 79 | WHEN n = 'c' THEN pg_catalog.to_char($1, 'FMMM') 80 | WHEN n = 'D' THEN pg_catalog.to_char($1, 'FMDDth') 81 | WHEN n = 'd' THEN pg_catalog.to_char($1, 'DD') 82 | WHEN n = 'e' THEN pg_catalog.to_char($1, 'FMDD') 83 | WHEN n = 'f' THEN pg_catalog.to_char($1, 'US') 84 | WHEN n = 'H' THEN pg_catalog.to_char($1, 'HH24') 85 | WHEN n = 'h' THEN pg_catalog.to_char($1, 'HH12') 86 | WHEN n = 'I' THEN pg_catalog.to_char($1, 'HH12') 87 | WHEN n = 'i' THEN pg_catalog.to_char($1, 'MI') 88 | WHEN n = 'j' THEN pg_catalog.to_char($1, 'DDD') 89 | WHEN n = 'k' THEN pg_catalog.to_char($1, 'FMHH24') 90 | WHEN n = 'l' THEN pg_catalog.to_char($1, 'FMHH12') 91 | WHEN n = 'M' THEN pg_catalog.to_char($1, 'FMMonth') 92 | WHEN n = 'm' THEN pg_catalog.to_char($1, 'MM') 93 | WHEN n = 'p' THEN pg_catalog.to_char($1, 'AM') 94 | WHEN n = 'r' THEN pg_catalog.to_char($1, 'HH12:MI:SS AM') 95 | WHEN n = 'S' THEN pg_catalog.to_char($1, 'SS') 96 | WHEN n = 's' THEN pg_catalog.to_char($1, 'SS') 97 | WHEN n = 'T' THEN pg_catalog.to_char($1, 'HH24:MI:SS') 98 | WHEN n = 'U' THEN pg_catalog.lpad(week($1::date, 0)::text, 2, '0') 99 | WHEN n = 'u' THEN pg_catalog.lpad(week($1::date, 1)::text, 2, '0') 100 | WHEN n = 'V' THEN pg_catalog.lpad(week($1::date, 2)::text, 2, '0') 101 | WHEN n = 'v' THEN pg_catalog.lpad(week($1::date, 3)::text, 2, '0') 102 | WHEN n = 'W' THEN pg_catalog.to_char($1, 'FMDay') 103 | WHEN n = 'w' THEN EXTRACT(DOW FROM $1)::text 104 | WHEN n = 'X' THEN pg_catalog.lpad(((_calc_week($1::date, _week_mode(2)))[2])::text, 4, '0') 105 | WHEN n = 'x' THEN pg_catalog.lpad(((_calc_week($1::date, _week_mode(3)))[2])::text, 4, '0') 106 | WHEN n = 'Y' THEN pg_catalog.to_char($1, 'YYYY') 107 | WHEN n = 'y' THEN pg_catalog.to_char($1, 'YY') 108 | WHEN n = '%' THEN pg_catalog.to_char($1, '%') 109 | ELSE NULL 110 | END; 111 | temp := temp operator(pg_catalog.||) res; 112 | i := i + 2; 113 | ELSE 114 | -- Otherwise just append the character to the string 115 | temp = temp operator(pg_catalog.||) c; 116 | i := i + 1; 117 | END IF; 118 | END LOOP; 119 | RETURN temp; 120 | END 121 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 122 | 123 | -- DATE_SUB() 124 | CREATE OR REPLACE FUNCTION date_sub(timestamp without time zone, interval) 125 | RETURNS timestamp without time zone AS $$ 126 | SELECT $1 - $2 127 | $$ IMMUTABLE STRICT LANGUAGE SQL; 128 | 129 | -- DAY() 130 | CREATE OR REPLACE FUNCTION day(date) 131 | RETURNS integer AS $$ 132 | SELECT EXTRACT(DAY FROM DATE($1))::integer 133 | $$ IMMUTABLE STRICT LANGUAGE SQL; 134 | 135 | -- DAYNAME() 136 | CREATE OR REPLACE FUNCTION dayname(date) 137 | RETURNS text AS $$ 138 | SELECT pg_catalog.to_char($1, 'FMDay') 139 | $$ IMMUTABLE STRICT LANGUAGE SQL; 140 | 141 | -- FROM_DAYS() 142 | CREATE OR REPLACE FUNCTION from_days(integer) 143 | RETURNS date AS $$ 144 | SELECT ('0001-01-01 BC'::date + $1 * INTERVAL '1 day')::date 145 | $$ IMMUTABLE STRICT LANGUAGE SQL; 146 | 147 | -- FROM_UNIXTIME() 148 | -- Returns local time? Is this actually the same as MySQL? 149 | -- Depends on: DATE_FORMAT() 150 | CREATE OR REPLACE FUNCTION from_unixtime(bigint) 151 | RETURNS timestamp without time zone AS $$ 152 | SELECT pg_catalog.to_timestamp($1)::timestamp without time zone 153 | $$ IMMUTABLE STRICT LANGUAGE SQL; 154 | 155 | CREATE OR REPLACE FUNCTION from_unixtime(bigint, text) 156 | RETURNS text AS $$ 157 | SELECT date_format(from_unixtime($1), $2) 158 | $$ IMMUTABLE STRICT LANGUAGE SQL; 159 | 160 | -- GET_FORMAT() 161 | -- Note that first parameter needs to be quoted in this version 162 | CREATE OR REPLACE FUNCTION get_format(text, text) 163 | RETURNS text AS $$ 164 | SELECT CASE 165 | WHEN $1 ILIKE 'DATE' THEN 166 | CASE WHEN $2 ILIKE 'USA' THEN '%m.%d.%Y' 167 | WHEN $2 ILIKE 'JIS' OR $2 ILIKE 'ISO' THEN '%Y-%m-%d' 168 | WHEN $2 ILIKE 'EUR' THEN '%d.%m.%Y' 169 | WHEN $2 ILIKE 'INTERNAL' THEN '%Y%m%d' 170 | ELSE NULL 171 | END 172 | WHEN $1 ILIKE 'DATETIME' THEN 173 | CASE WHEN $2 ILIKE 'USA' OR $2 ILIKE 'EUR' THEN '%Y-%m-%d-%H.%i.%s' 174 | WHEN $2 ILIKE 'JIS' OR $2 ILIKE 'ISO' THEN '%Y-%m-%d %H:%i:%s' 175 | WHEN $2 ILIKE 'INTERNAL' THEN '%Y%m%d%H%i%s' 176 | ELSE NULL 177 | END 178 | WHEN $1 ILIKE 'TIME' THEN 179 | CASE WHEN $2 ILIKE 'USA' THEN '%h:%i:%s %p' 180 | WHEN $2 ILIKE 'JIS' OR $2 ILIKE 'ISO' THEN '%H:%i:%s' 181 | WHEN $2 ILIKE 'EUR' THEN 'H.%i.%S' 182 | WHEN $2 ILIKE 'INTERNAL' THEN '%H%i%s' 183 | ELSE NULL 184 | END 185 | ELSE 186 | NULL 187 | END 188 | $$ IMMUTABLE STRICT LANGUAGE SQL; 189 | 190 | -- LAST_DAY() 191 | -- Note that for illegal timestamps this function raises an error, 192 | -- whereas under MySQL it returns NULL 193 | CREATE OR REPLACE FUNCTION last_day(timestamp) 194 | RETURNS date AS $$ 195 | SELECT CASE 196 | WHEN EXTRACT(MONTH FROM $1) = 12 THEN 197 | (((EXTRACT(YEAR FROM $1) + 1) operator(pg_catalog.||) '-01-01')::date - INTERVAL '1 day')::date 198 | ELSE 199 | ((EXTRACT(YEAR FROM $1) operator(pg_catalog.||) '-' operator(pg_catalog.||) (EXTRACT(MONTH FROM $1) + 1) operator(pg_catalog.||) '-01')::date - INTERVAL '1 day')::date 200 | END 201 | $$ IMMUTABLE STRICT LANGUAGE SQL; 202 | 203 | -- MAKEDATE() 204 | CREATE OR REPLACE FUNCTION makedate(integer, integer) 205 | RETURNS date AS $$ 206 | SELECT CASE WHEN $2 > 0 THEN 207 | (($1 operator(pg_catalog.||) '-01-01')::date + ($2 - 1) * INTERVAL '1 day')::date 208 | ELSE 209 | NULL 210 | END 211 | $$ IMMUTABLE STRICT LANGUAGE SQL; 212 | 213 | -- MAKETIME() 214 | CREATE OR REPLACE FUNCTION maketime(integer, integer, integer) 215 | RETURNS interval AS $$ 216 | SELECT ($1 operator(pg_catalog.||) ':' operator(pg_catalog.||) $2 operator(pg_catalog.||) ':' operator(pg_catalog.||) $3)::interval 217 | $$ IMMUTABLE STRICT LANGUAGE SQL; 218 | 219 | -- MONTHNAME() 220 | CREATE OR REPLACE FUNCTION monthname(date) 221 | RETURNS text AS $$ 222 | SELECT pg_catalog.to_char($1, 'FMMonth') 223 | $$ IMMUTABLE STRICT LANGUAGE SQL; 224 | 225 | -- NOW() 226 | -- Part of base PostgreSQL 227 | 228 | -- PERIOD_ADD() 229 | CREATE OR REPLACE FUNCTION period_add(integer, integer) 230 | RETURNS text AS $$ 231 | DECLARE 232 | period text; 233 | base date; 234 | baseyear integer; 235 | BEGIN 236 | IF pg_catalog.length($1) < 4 THEN 237 | period := pg_catalog.lpad($1, 4, 0); 238 | ELSIF pg_catalog.length($1) = 5 THEN 239 | period := pg_catalog.lpad($1, 6, 0); 240 | ELSE 241 | period := $1; 242 | END IF; 243 | 244 | IF pg_catalog.length(period) = 4 THEN 245 | baseyear := SUBSTRING(period FROM 1 FOR 2); 246 | IF baseyear BETWEEN 70 AND 99 THEN 247 | baseyear := baseyear + 1900; 248 | ELSE 249 | baseyear := baseyear + 2000; 250 | END IF; 251 | base := (baseyear operator(pg_catalog.||) '-' operator(pg_catalog.||) SUBSTRING(period FROM 3) operator(pg_catalog.||) '-01')::date; 252 | ELSIF pg_catalog.length(period) = 6 THEN 253 | base := (SUBSTRING(period FROM 1 FOR 4) operator(pg_catalog.||) '-' operator(pg_catalog.||) SUBSTRING(period FROM 5) operator(pg_catalog.||) '-01')::date; 254 | ELSE 255 | RETURN NULL; 256 | END IF; 257 | 258 | base := base + (INTERVAL '1 month' * $2); 259 | RETURN pg_catalog.lpad(EXTRACT(YEAR FROM base), 4, '0') operator(pg_catalog.||) pg_catalog.lpad(EXTRACT(MONTH FROM base), 2, '0'); 260 | END 261 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 262 | 263 | -- PERIOD_DIFF() 264 | CREATE OR REPLACE FUNCTION period_diff(integer, integer) 265 | RETURNS integer AS $$ 266 | DECLARE 267 | baseyear integer; 268 | period1 text; 269 | period2 text; 270 | months1 integer; 271 | months2 integer; 272 | BEGIN 273 | IF pg_catalog.length($1) < 4 THEN 274 | period1 := pg_catalog.lpad($1, 4, 0); 275 | ELSIF pg_catalog.length($1) = 5 THEN 276 | period1 := pg_catalog.lpad($1, 6, 0); 277 | ELSE 278 | period1 := $1; 279 | END IF; 280 | 281 | IF pg_catalog.length(period1) = 4 THEN 282 | baseyear := SUBSTRING(period1 FROM 1 FOR 2); 283 | IF baseyear BETWEEN 70 AND 99 THEN 284 | baseyear := baseyear + 1900; 285 | ELSE 286 | baseyear := baseyear + 2000; 287 | END IF; 288 | months1 := baseyear * 12 + SUBSTRING(period1 FROM 3)::integer; 289 | ELSIF pg_catalog.length(period1) = 6 THEN 290 | months1 := SUBSTRING(period1 FROM 1 FOR 4)::integer * 12 + SUBSTRING(period1 FROM 5)::integer; 291 | ELSE 292 | RETURN NULL; 293 | END IF; 294 | 295 | IF pg_catalog.length($2) < 4 THEN 296 | period2 := pg_catalog.lpad($2, 4, 0); 297 | ELSIF pg_catalog.length($2) = 5 THEN 298 | period2 := pg_catalog.lpad($2, 6, 0); 299 | ELSE 300 | period2 := $2; 301 | END IF; 302 | 303 | IF pg_catalog.length(period2) = 4 THEN 304 | baseyear := SUBSTRING(period2 FROM 1 FOR 2); 305 | IF baseyear BETWEEN 70 AND 99 THEN 306 | baseyear := baseyear + 1900; 307 | ELSE 308 | baseyear := baseyear + 2000; 309 | END IF; 310 | months2 := baseyear * 12 + SUBSTRING(period2 FROM 3)::integer; 311 | ELSIF pg_catalog.length(period2) = 6 THEN 312 | months2 := SUBSTRING(period2 FROM 1 FOR 4)::integer * 12 + SUBSTRING(period2 FROM 5)::integer; 313 | ELSE 314 | RETURN NULL; 315 | END IF; 316 | 317 | RETURN months1 - months2; 318 | END 319 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 320 | 321 | -- SEC_TO_TIME() 322 | CREATE OR REPLACE FUNCTION sec_to_time(bigint) 323 | RETURNS interval AS $$ 324 | SELECT $1 * INTERVAL '1 second' 325 | $$ IMMUTABLE STRICT LANGUAGE SQL; 326 | 327 | -- STR_TO_DATE() 328 | -- Note: Doesn't handle weeks of years yet and will return different results 329 | -- to MySQL if you pass in an invalid timestamp 330 | CREATE OR REPLACE FUNCTION str_to_date(text, text) 331 | RETURNS timestamp without time zone AS $$ 332 | DECLARE 333 | i int := 1; 334 | temp text := ''; 335 | c text; 336 | n text; res text; 337 | BEGIN 338 | WHILE i <= pg_catalog.length($2) LOOP 339 | -- Look at current character 340 | c := SUBSTRING ($2 FROM i FOR 1); 341 | -- If it's a '%' and not the last character then process it as a placeholder 342 | IF c = '%' AND i != pg_catalog.length($2) THEN 343 | n := SUBSTRING ($2 FROM (i + 1) FOR 1); 344 | SELECT INTO res CASE 345 | WHEN n = 'a' THEN 'Dy' 346 | WHEN n = 'b' THEN 'Mon' 347 | WHEN n = 'c' THEN 'FMMM' 348 | WHEN n = 'D' THEN 'FMDDth' 349 | WHEN n = 'd' THEN 'DD' 350 | WHEN n = 'e' THEN 'FMDD' 351 | WHEN n = 'f' THEN 'US' 352 | WHEN n = 'H' THEN 'HH24' 353 | WHEN n = 'h' THEN 'HH12' 354 | WHEN n = 'I' THEN 'HH12' 355 | WHEN n = 'i' THEN 'MI' 356 | WHEN n = 'j' THEN 'DDD' 357 | WHEN n = 'k' THEN 'FMHH24' 358 | WHEN n = 'l' THEN 'FMHH12' 359 | WHEN n = 'M' THEN 'FMMonth' 360 | WHEN n = 'm' THEN 'MM' 361 | WHEN n = 'p' THEN 'AM' 362 | WHEN n = 'r' THEN 'HH12:MI:SS AM' 363 | WHEN n = 'S' THEN 'SS' 364 | WHEN n = 's' THEN 'SS' 365 | WHEN n = 'T' THEN 'HH24:MI:SS' 366 | WHEN n = 'U' THEN '?' 367 | WHEN n = 'u' THEN '?' 368 | WHEN n = 'V' THEN '?' 369 | WHEN n = 'v' THEN '?' 370 | WHEN n = 'W' THEN 'FMDay' 371 | WHEN n = 'w' THEN '?' 372 | WHEN n = 'X' THEN '?' 373 | WHEN n = 'x' THEN '?' 374 | WHEN n = 'Y' THEN 'YYYY' 375 | WHEN n = 'y' THEN 'YY' 376 | WHEN n = '%' THEN '%' 377 | ELSE NULL 378 | END; 379 | temp := temp operator(pg_catalog.||) res; 380 | i := i + 2; 381 | ELSE 382 | -- Otherwise just append the character to the string 383 | temp = temp operator(pg_catalog.||) c; 384 | i := i + 1; 385 | END IF; 386 | END LOOP; 387 | RETURN pg_catalog.to_timestamp($1, temp)::timestamp without time zone; 388 | END 389 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 390 | 391 | -- SUBDATE() 392 | -- Note: passing in the interval is different 393 | CREATE OR REPLACE FUNCTION subdate(timestamp without time zone, interval) 394 | RETURNS timestamp without time zone AS $$ 395 | SELECT $1 - $2 396 | $$ IMMUTABLE STRICT LANGUAGE SQL; 397 | 398 | CREATE OR REPLACE FUNCTION subdate(timestamp without time zone, integer) 399 | RETURNS timestamp without time zone AS $$ 400 | SELECT $1 - (INTERVAL '1 day' * $2) 401 | $$ IMMUTABLE STRICT LANGUAGE SQL; 402 | 403 | -- SUBTIME 404 | -- Note: requires casting if you install both versions 405 | CREATE OR REPLACE FUNCTION subtime(timestamp without time zone, interval) 406 | RETURNS timestamp without time zone AS $$ 407 | SELECT $1 - $2 408 | $$ IMMUTABLE STRICT LANGUAGE SQL; 409 | 410 | CREATE OR REPLACE FUNCTION subtime(interval, interval) 411 | RETURNS interval AS $$ 412 | SELECT $1 - $2 413 | $$ IMMUTABLE STRICT LANGUAGE SQL; 414 | 415 | -- SYSDATE() 416 | CREATE OR REPLACE FUNCTION sysdate() 417 | RETURNS timestamp without time zone AS $$ 418 | SELECT pg_catalog.timeofday()::timestamp(0) without time zone 419 | $$ VOLATILE LANGUAGE SQL; 420 | 421 | -- TIME() 422 | -- Not possible to implement 423 | 424 | -- TIMEDIFF() 425 | -- Note: requires casting if you install both versions 426 | CREATE OR REPLACE FUNCTION timediff(timestamp without time zone, timestamp without time zone) 427 | RETURNS interval AS $$ 428 | SELECT $1 - $2 429 | $$ IMMUTABLE STRICT LANGUAGE SQL; 430 | 431 | CREATE OR REPLACE FUNCTION timediff(time without time zone, time without time zone) 432 | RETURNS interval AS $$ 433 | SELECT $1 - $2 434 | $$ IMMUTABLE STRICT LANGUAGE SQL; 435 | 436 | -- TIMESTAMP() 437 | -- Not possible to implement 438 | 439 | -- TIMESTAMPADD() 440 | -- Note that first parameter needs to be quoted in this version 441 | CREATE OR REPLACE FUNCTION timestampadd(text, integer, timestamp without time zone) 442 | RETURNS timestamp without time zone AS $$ 443 | SELECT $3 + ($2 operator(pg_catalog.||) ' ' operator(pg_catalog.||) $1)::interval 444 | $$ IMMUTABLE STRICT LANGUAGE SQL; 445 | 446 | -- TIMESTAMPDIFF() 447 | -- Note that first parameter needs to be quoted in this version 448 | 449 | -- TIME_FORMAT() 450 | CREATE OR REPLACE FUNCTION time_format(interval, text) 451 | RETURNS text AS $$ 452 | DECLARE 453 | i int := 1; 454 | temp text := ''; 455 | c text; 456 | n text; 457 | res text; 458 | BEGIN 459 | WHILE i <= pg_catalog.length($2) LOOP 460 | -- Look at current character 461 | c := SUBSTRING ($2 FROM i FOR 1); 462 | -- If it's a '%' and not the last character then process it as a placeholder 463 | IF c = '%' AND i != pg_catalog.length($2) THEN 464 | n := SUBSTRING ($2 FROM (i + 1) FOR 1); 465 | SELECT INTO res CASE 466 | WHEN n = 'a' THEN '0' 467 | WHEN n = 'b' THEN '0' 468 | WHEN n = 'c' THEN '0' 469 | WHEN n = 'D' THEN '0' 470 | WHEN n = 'd' THEN '0' 471 | WHEN n = 'e' THEN '0' 472 | WHEN n = 'f' THEN pg_catalog.to_char($1, 'US') 473 | WHEN n = 'H' THEN pg_catalog.to_char($1, 'HH24') 474 | WHEN n = 'h' THEN pg_catalog.lpad(pg_catalog.to_char($1, 'HH12')::integer % 12, 2, '0') 475 | WHEN n = 'I' THEN pg_catalog.lpad(pg_catalog.to_char($1, 'HH12')::integer % 12, 2, '0') 476 | WHEN n = 'i' THEN pg_catalog.to_char($1, 'MI') 477 | WHEN n = 'j' THEN '0' 478 | WHEN n = 'k' THEN pg_catalog.to_char($1, 'FMHH24') 479 | WHEN n = 'l' THEN (pg_catalog.to_char($1, 'FMHH12')::integer % 12)::text 480 | WHEN n = 'M' THEN '0' 481 | WHEN n = 'm' THEN '0' 482 | WHEN n = 'p' THEN pg_catalog.to_char($1, 'AM') 483 | WHEN n = 'r' THEN pg_catalog.lpad(pg_catalog.to_char($1, 'HH12')::integer % 12, 2, '0') 484 | operator(pg_catalog.||) 485 | pg_catalog.to_char($1, ':MI:SS ') 486 | operator(pg_catalog.||) 487 | CASE WHEN pg_catalog.to_char($1, 'FMHH24')::integer <= 11 THEN 'AM' ELSE 'PM' END 488 | WHEN n = 'S' THEN pg_catalog.to_char($1, 'SS') 489 | WHEN n = 's' THEN pg_catalog.to_char($1, 'SS') 490 | WHEN n = 'T' THEN pg_catalog.to_char($1, 'HH24:MI:SS') 491 | WHEN n = 'U' THEN '0' 492 | WHEN n = 'u' THEN '0' 493 | WHEN n = 'V' THEN '0' 494 | WHEN n = 'v' THEN '0' 495 | WHEN n = 'W' THEN '0' 496 | WHEN n = 'w' THEN '0' 497 | WHEN n = 'X' THEN '0' 498 | WHEN n = 'x' THEN '0' 499 | WHEN n = 'Y' THEN '0' 500 | WHEN n = 'y' THEN '0' 501 | WHEN n = '%' THEN pg_catalog.to_char($1, '%') 502 | ELSE NULL 503 | END; 504 | temp := temp operator(pg_catalog.||) res; 505 | i := i + 2; 506 | ELSE 507 | -- Otherwise just append the character to the string 508 | temp = temp operator(pg_catalog.||) c; 509 | i := i + 1; 510 | END IF; 511 | END LOOP; 512 | RETURN temp; 513 | END 514 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 515 | 516 | -- TIME_TO_SEC() 517 | CREATE OR REPLACE FUNCTION time_to_sec(interval) 518 | RETURNS bigint AS $$ 519 | SELECT (EXTRACT(HOURS FROM $1) * 3600 520 | + EXTRACT(MINUTES FROM $1) * 60 521 | + EXTRACT(SECONDS FROM $1))::bigint 522 | $$ IMMUTABLE STRICT LANGUAGE SQL; 523 | 524 | -- TO_DAYS() 525 | -- XXX: Haven't done integer variant 526 | CREATE OR REPLACE FUNCTION to_days(date) 527 | RETURNS integer AS $$ 528 | SELECT $1 - '0001-01-01 BC'::date 529 | $$ IMMUTABLE STRICT LANGUAGE SQL; 530 | 531 | -- UNIX_TIMESTAMP() 532 | CREATE OR REPLACE FUNCTION unix_timestamp() 533 | RETURNS bigint AS $$ 534 | SELECT EXTRACT(EPOCH FROM LOCALTIMESTAMP)::bigint 535 | $$ VOLATILE LANGUAGE SQL; 536 | 537 | -- XXX: This gives wrong answers? Time zones? 538 | CREATE OR REPLACE FUNCTION unix_timestamp(timestamp without time zone) 539 | RETURNS bigint AS $$ 540 | SELECT EXTRACT(EPOCH FROM $1)::bigint 541 | $$ VOLATILE LANGUAGE SQL; 542 | 543 | -- UTC_DATE() 544 | CREATE OR REPLACE FUNCTION utc_date() 545 | RETURNS date AS $$ 546 | SELECT (CURRENT_TIMESTAMP AT TIME ZONE 'UTC')::date 547 | $$ VOLATILE LANGUAGE SQL; 548 | 549 | -- UTC_TIME() 550 | CREATE OR REPLACE FUNCTION utc_time() 551 | RETURNS time(0) AS $$ 552 | SELECT (CURRENT_TIMESTAMP AT TIME ZONE 'UTC')::time(0) 553 | $$ VOLATILE LANGUAGE SQL; 554 | 555 | -- UTC_TIMESTAMP() 556 | CREATE OR REPLACE FUNCTION utc_timestamp() 557 | RETURNS timestamp(0) AS $$ 558 | SELECT (CURRENT_TIMESTAMP AT TIME ZONE 'UTC')::timestamp(0) 559 | $$ VOLATILE LANGUAGE SQL; 560 | 561 | -- WEEK() 562 | CREATE OR REPLACE FUNCTION _week_mode(mode integer) 563 | RETURNS integer AS $$ 564 | DECLARE 565 | _WEEK_MONDAY_FIRST CONSTANT integer := 1; 566 | _WEEK_FIRST_WEEKDAY CONSTANT integer := 4; 567 | week_format integer := mode & 7; 568 | BEGIN 569 | IF (week_format & _WEEK_MONDAY_FIRST) = 0 THEN 570 | week_format := week_format # _WEEK_FIRST_WEEKDAY; 571 | END IF; 572 | 573 | RETURN week_format; 574 | END; 575 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 576 | 577 | CREATE OR REPLACE FUNCTION _calc_weekday(qdate date, sundayfirst boolean) 578 | RETURNS integer AS $$ 579 | BEGIN 580 | RETURN (EXTRACT(DOW FROM qdate)::integer + CASE WHEN sundayfirst THEN 0 ELSE 6 END) % 7; 581 | END; 582 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 583 | 584 | CREATE OR REPLACE FUNCTION _calc_days_in_year(year integer) 585 | RETURNS integer AS $$ 586 | BEGIN 587 | IF (year & 3) = 0 AND ((year % 100) <> 0 OR (year % 400) = 0 AND year <> 0) THEN 588 | RETURN 366; 589 | ELSE 590 | RETURN 365; 591 | END IF; 592 | END; 593 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 594 | 595 | CREATE OR REPLACE FUNCTION _calc_week(qdate anyelement, behavior integer) 596 | RETURNS integer[] AS $$ 597 | DECLARE 598 | _WEEK_MONDAY_FIRST CONSTANT integer := 1; 599 | _WEEK_YEAR CONSTANT integer := 2; 600 | _WEEK_FIRST_WEEKDAY CONSTANT integer := 4; 601 | qyear integer := EXTRACT(YEAR FROM qdate); 602 | qmonth integer := EXTRACT(MONTH FROM qdate); 603 | qday integer := EXTRACT(DAY FROM qdate); 604 | daynr integer := EXTRACT(DOY FROM qdate); 605 | yday1 date := pg_catalog.date_trunc('year', qdate); 606 | first_daynr integer := 1; 607 | monday_first boolean := (behavior & _WEEK_MONDAY_FIRST) <> 0; 608 | week_year boolean := (behavior & _WEEK_YEAR) <> 0; 609 | first_weekday boolean := (behavior & _WEEK_FIRST_WEEKDAY) <> 0; 610 | weekday integer := _calc_weekday(yday1, NOT monday_first); 611 | days integer; 612 | BEGIN 613 | IF qmonth = 1 AND qday <= 7 - weekday THEN 614 | IF (NOT week_year) AND ((first_weekday AND weekday <> 0) OR (NOT first_weekday AND weekday >= 4)) THEN 615 | RETURN array[0, qyear]; 616 | END IF; 617 | 618 | week_year := true; 619 | qyear := qyear - 1; 620 | days := _calc_days_in_year(qyear); 621 | first_daynr := first_daynr - days; 622 | weekday := (weekday + 53 * 7 - days) % 7; 623 | END IF; 624 | 625 | IF (first_weekday AND weekday <> 0) OR (NOT first_weekday AND weekday >= 4) THEN 626 | days := daynr - (first_daynr + (7 - weekday)); 627 | ELSE 628 | days := daynr - (first_daynr - weekday); 629 | END IF; 630 | 631 | IF week_year AND days >= 52 * 7 THEN 632 | weekday := (weekday + _calc_days_in_year(qyear)) % 7; 633 | IF (NOT first_weekday AND weekday < 4) OR (first_weekday AND weekday = 0) THEN 634 | qyear := qyear + 1; 635 | RETURN array[1, qyear]; 636 | END IF; 637 | END IF; 638 | 639 | RETURN array[days / 7 + 1, qyear]; 640 | END; 641 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 642 | 643 | -- YEARWEEK() 644 | CREATE OR REPLACE FUNCTION yearweek(qdate date, mode integer) 645 | RETURNS integer AS $$ 646 | DECLARE 647 | _WEEK_YEAR CONSTANT integer := 2; 648 | a integer[] := _calc_week(qdate, _week_mode(mode | _WEEK_YEAR)); 649 | week integer := a[1]; 650 | year integer := a[2]; 651 | BEGIN 652 | RETURN week + year * 100; 653 | END; 654 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 655 | 656 | CREATE OR REPLACE FUNCTION yearweek(date) 657 | RETURNS integer AS $$ 658 | SELECT yearweek($1, 0); 659 | $$ IMMUTABLE STRICT LANGUAGE SQL; 660 | 661 | -- 662 | -- is_datetime: used to determine if value passed to polymorphic 663 | -- function is a valid date/time value 664 | -- 665 | 666 | CREATE OR REPLACE FUNCTION is_datetime ( anyelement ) 667 | RETURNS BOOLEAN AS $$ 668 | DECLARE d date; 669 | t TIMESTAMP; 670 | tz TIMESTAMPTZ; 671 | BEGIN 672 | d = $1::DATE; 673 | RETURN TRUE; 674 | EXCEPTION WHEN others THEN 675 | BEGIN 676 | t = $1::TIMESTAMP; 677 | RETURN TRUE; 678 | EXCEPTION WHEN others THEN 679 | BEGIN 680 | tz = $1::TIMESTAMPTZ; 681 | RETURN TRUE; 682 | EXCEPTION WHEN others THEN 683 | RETURN FALSE; 684 | END; 685 | END; 686 | END; 687 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 688 | 689 | -- 690 | -- Polymorphic functions to allow one function 691 | -- to handle date / timestamp / timestamptz types 692 | -- 693 | 694 | -- WEEKDAY() 695 | CREATE OR REPLACE FUNCTION weekday( anyelement ) 696 | RETURNS integer AS $$ 697 | BEGIN 698 | IF is_datetime ( $1 ) THEN 699 | CASE WHEN EXTRACT(DOW FROM $1)::integer = 0 THEN 700 | RETURN 6; 701 | ELSE 702 | RETURN EXTRACT(DOW FROM $1)::integer - 1; 703 | END CASE; 704 | END IF; 705 | RAISE EXCEPTION 'Invalid date / time value --> %', $1; 706 | END; 707 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 708 | 709 | -- YEAR() 710 | CREATE OR REPLACE FUNCTION year( anyelement ) 711 | RETURNS integer AS $$ 712 | BEGIN 713 | IF is_datetime ( $1 ) THEN 714 | RETURN EXTRACT(YEAR FROM $1)::integer; 715 | END IF; 716 | RAISE EXCEPTION 'Invalid date / time value --> %', $1; 717 | END; 718 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 719 | 720 | -- MONTH() 721 | CREATE OR REPLACE FUNCTION month( anyelement ) 722 | RETURNS integer AS $$ 723 | BEGIN 724 | IF is_datetime ( $1 ) THEN 725 | RETURN EXTRACT(MONTH FROM DATE($1))::integer; 726 | END IF; 727 | RAISE EXCEPTION 'Invalid date / time value --> %', $1; 728 | END; 729 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 730 | 731 | -- DAYOFMONTH() 732 | CREATE OR REPLACE FUNCTION dayofmonth( anyelement ) 733 | RETURNS integer AS $$ 734 | BEGIN 735 | IF is_datetime ( $1 ) THEN 736 | RETURN EXTRACT(DAY FROM DATE($1))::integer; 737 | END IF; 738 | RAISE EXCEPTION 'Invalid date / time value --> %', $1; 739 | END; 740 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 741 | 742 | -- DAYOFWEEK() 743 | CREATE OR REPLACE FUNCTION dayofweek( anyelement ) 744 | RETURNS integer AS $$ 745 | BEGIN 746 | IF is_datetime ( $1 ) THEN 747 | RETURN EXTRACT(DOW FROM DATE($1))::integer + 1; 748 | END IF; 749 | RAISE EXCEPTION 'Invalid date / time value --> %', $1; 750 | END; 751 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 752 | 753 | -- DAYOFYEAR() 754 | CREATE OR REPLACE FUNCTION dayofyear( anyelement ) 755 | RETURNS integer AS $$ 756 | BEGIN 757 | IF is_datetime ( $1 ) THEN 758 | RETURN EXTRACT(DOY FROM DATE($1))::integer; 759 | END IF; 760 | RAISE EXCEPTION 'Invalid date / time value --> %', $1; 761 | END; 762 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 763 | 764 | -- HOUR() 765 | CREATE OR REPLACE FUNCTION hour( anyelement ) 766 | RETURNS integer AS $$ 767 | BEGIN 768 | IF is_datetime ( $1 ) THEN 769 | RETURN EXTRACT (HOUR FROM $1)::integer; 770 | END IF; 771 | RAISE EXCEPTION 'Invalid date / time value --> %', $1; 772 | END; 773 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 774 | 775 | -- MICROSECOND() 776 | CREATE OR REPLACE FUNCTION microsecond( anyelement ) 777 | RETURNS integer AS $$ 778 | BEGIN 779 | IF is_datetime ( $1 ) THEN 780 | RETURN (EXTRACT(MICROSECONDS FROM $1))::integer % 1000000; 781 | END IF; 782 | RAISE EXCEPTION 'Invalid date / time value --> %', $1; 783 | END; 784 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 785 | 786 | -- MINUTE() 787 | CREATE OR REPLACE FUNCTION minute( anyelement ) 788 | RETURNS integer AS $$ 789 | BEGIN 790 | IF is_datetime ( $1 ) THEN 791 | RETURN EXTRACT(MINUTES FROM $1)::integer; 792 | END IF; 793 | RAISE EXCEPTION 'Invalid date / time value --> %', $1; 794 | END; 795 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 796 | 797 | -- QUARTER() 798 | CREATE OR REPLACE FUNCTION quarter( anyelement ) 799 | RETURNS integer AS $$ 800 | BEGIN 801 | IF is_datetime ( $1 ) THEN 802 | RETURN EXTRACT(QUARTER FROM DATE($1))::integer; 803 | END IF; 804 | RAISE EXCEPTION 'Invalid date / time value --> %', $1; 805 | END; 806 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 807 | 808 | -- SECOND() 809 | CREATE OR REPLACE FUNCTION second( anyelement ) 810 | RETURNS integer AS $$ 811 | BEGIN 812 | IF is_datetime ( $1 ) THEN 813 | RETURN EXTRACT(SECONDS FROM $1)::integer; 814 | END IF; 815 | RAISE EXCEPTION 'Invalid date / time value --> %', $1; 816 | END; 817 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 818 | 819 | CREATE OR REPLACE FUNCTION week( anyelement, integer ) 820 | RETURNS integer AS $$ 821 | BEGIN 822 | IF is_datetime ( $1 ) THEN 823 | RETURN (_calc_week($1, _week_mode($2)))[1]; 824 | END IF; 825 | RAISE EXCEPTION 'Invalid date / time value --> %', $1; 826 | END; 827 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 828 | 829 | CREATE OR REPLACE FUNCTION week( anyelement ) 830 | RETURNS integer AS $$ 831 | BEGIN 832 | IF is_datetime ( $1 ) THEN 833 | RETURN week($1, 0); 834 | END IF; 835 | RAISE EXCEPTION 'Invalid date / time value --> %', $1; 836 | END; 837 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 838 | 839 | -- WEEKOFYEAR() 840 | CREATE OR REPLACE FUNCTION weekofyear( anyelement ) 841 | RETURNS integer AS $$ 842 | BEGIN 843 | IF is_datetime ( $1 ) THEN 844 | RETURN week($1, 3); 845 | END IF; 846 | RAISE EXCEPTION 'Invalid date / time value --> %', $1; 847 | END; 848 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 849 | -------------------------------------------------------------------------------- /sql_bits/information.sql: -------------------------------------------------------------------------------- 1 | -- BENCHMARK() 2 | -- Note: This version requires the expression to be quoted. 3 | -- Note: To show query times in psql, run \timing first 4 | -- Example: SELECT BENCHMARK(100000, $$ length('hello') $$); 5 | CREATE OR REPLACE FUNCTION benchmark(integer, text) 6 | RETURNS integer AS $$ 7 | BEGIN 8 | FOR i IN 1..$1 LOOP 9 | EXECUTE 'SELECT ' || $2; 10 | END LOOP; 11 | RETURN 0; 12 | END; 13 | $$ STRICT LANGUAGE PLPGSQL; 14 | 15 | -- CHARSET() 16 | -- This is a bit dodgy as it just returns the database encoding 17 | CREATE OR REPLACE FUNCTION charset(text) 18 | RETURNS text AS $$ 19 | SELECT pg_catalog.lower(setting) from pg_catalog.pg_settings where name='server_encoding' 20 | $$ IMMUTABLE LANGUAGE SQL; 21 | 22 | -- COERCIBILITY() 23 | -- This is a bit dodgy as PostgreSQL does not support collations 24 | -- Note: This is MySQL 5.0 compatible 25 | CREATE OR REPLACE FUNCTION coercibility(name) 26 | RETURNS integer AS $$ 27 | SELECT 3 28 | $$ IMMUTABLE LANGUAGE SQL; 29 | 30 | CREATE OR REPLACE FUNCTION coercibility(text) 31 | RETURNS integer AS $$ 32 | SELECT CASE 33 | WHEN $1 IS NULL THEN 5 34 | ELSE 2 35 | END 36 | $$ IMMUTABLE LANGUAGE SQL; 37 | 38 | -- COLLATION() 39 | -- In PostgreSQL 9.1 and earlier, just return the database collation 40 | -- In 9.2 COLLATION is a reserved keyword, so this function cannot provide 41 | -- compatbility anyway. Please use COLLATION FOR(x) instead of COLLATION(x) 42 | -- 43 | -- Not sure why this calls lower() -- collation names are case sensitive in Postgres 44 | CREATE OR REPLACE FUNCTION "collation"(text) 45 | RETURNS text AS $$ 46 | SELECT pg_catalog.lower(setting) from pg_catalog.pg_settings where name='lc_collate' 47 | $$ IMMUTABLE LANGUAGE SQL; 48 | 49 | -- CONNECTION_ID() 50 | CREATE OR REPLACE FUNCTION connection_id() 51 | RETURNS integer AS $$ 52 | SELECT pg_catalog.pg_backend_pid() 53 | $$ IMMUTABLE LANGUAGE SQL; 54 | 55 | -- DATABASE() 56 | CREATE OR REPLACE FUNCTION database() 57 | RETURNS text AS $$ 58 | SELECT pg_catalog.current_database()::text 59 | $$ IMMUTABLE LANGUAGE SQL; 60 | 61 | -- FOUND_ROWS() 62 | -- Not possible to implement 63 | 64 | -- LAST_INSERT_ID() 65 | -- Note: only works in 8.1 66 | -- Note: Not possible to implement last_insert_id(val) 67 | CREATE OR REPLACE FUNCTION last_insert_id() 68 | RETURNS bigint AS $$ 69 | SELECT pg_catalog.lastval() 70 | $$ VOLATILE LANGUAGE SQL; 71 | 72 | -- ROW_COUNT() 73 | -- Not possible to implement 74 | 75 | -- SCHEMA() 76 | -- XXX: Should this be an alias to database() like in mysql? 77 | CREATE OR REPLACE FUNCTION schema() 78 | RETURNS text AS $$ 79 | SELECT pg_catalog.current_schema()::text 80 | $$ VOLATILE LANGUAGE SQL; 81 | 82 | -- SESSION_USER() 83 | -- Cannot be implemented 84 | 85 | -- SYSTEM_USER() 86 | CREATE OR REPLACE FUNCTION system_user() 87 | RETURNS text AS $$ 88 | SELECT SESSION_USER::text 89 | $$ VOLATILE LANGUAGE SQL; 90 | 91 | -- USER() 92 | -- Cannot be implemented 93 | -------------------------------------------------------------------------------- /sql_bits/mathematical.sql: -------------------------------------------------------------------------------- 1 | -- ATAN2() 2 | -- Two parameter alias of atan2 3 | CREATE OR REPLACE FUNCTION atan(double precision, double precision) 4 | RETURNS double precision AS $$ 5 | SELECT pg_catalog.atan2($1, $2) 6 | $$ IMMUTABLE STRICT LANGUAGE SQL; 7 | 8 | -- CRC32() 9 | CREATE OR REPLACE FUNCTION crc32(text) 10 | RETURNS bigint AS $$ 11 | DECLARE 12 | -- crc look up table 13 | -- based on the polynomial: 14 | -- x^32+x^26+x^23+x^22+x^16+x^12+x^11+x^10+x^8+x^7+x^5+x^4+x^2+x+1 15 | 16 | crc_lu bigint[256] := ARRAY[0, 1996959894, 3993919788, 2567524794, 17 | 124634137, 1886057615, 3915621685, 2657392035, 249268274, 2044508324, 18 | 3772115230, 2547177864, 162941995, 2125561021, 3887607047, 2428444049, 19 | 498536548, 1789927666, 4089016648, 2227061214, 450548861, 1843258603, 20 | 4107580753, 2211677639, 325883990, 1684777152, 4251122042, 21 | 2321926636, 335633487, 1661365465, 4195302755, 2366115317, 22 | 997073096, 1281953886, 3579855332, 2724688242, 1006888145, 23 | 1258607687, 3524101629, 2768942443, 901097722, 1119000684, 24 | 3686517206, 2898065728, 853044451, 1172266101, 3705015759, 25 | 2882616665, 651767980, 1373503546, 3369554304, 3218104598, 26 | 565507253, 1454621731, 3485111705, 3099436303, 671266974, 27 | 1594198024, 3322730930, 2970347812, 795835527, 1483230225, 28 | 3244367275, 3060149565, 1994146192, 31158534, 2563907772, 29 | 4023717930, 1907459465, 112637215, 2680153253, 3904427059, 30 | 2013776290, 251722036, 2517215374, 3775830040, 2137656763, 31 | 141376813, 2439277719, 3865271297, 1802195444, 476864866, 32 | 2238001368, 4066508878, 1812370925, 453092731, 2181625025, 33 | 4111451223, 1706088902, 314042704, 2344532202, 4240017532, 34 | 1658658271, 366619977, 2362670323, 4224994405, 1303535960, 35 | 984961486, 2747007092, 3569037538, 1256170817, 1037604311, 36 | 2765210733, 3554079995, 1131014506, 879679996, 2909243462, 37 | 3663771856, 1141124467, 855842277, 2852801631, 3708648649, 38 | 1342533948, 654459306, 3188396048, 3373015174, 1466479909, 39 | 544179635, 3110523913, 3462522015, 1591671054, 702138776, 40 | 2966460450, 3352799412, 1504918807, 783551873, 3082640443, 41 | 3233442989, 3988292384, 2596254646, 62317068, 1957810842, 42 | 3939845945, 2647816111, 81470997, 1943803523, 3814918930, 43 | 2489596804, 225274430, 2053790376, 3826175755, 2466906013, 44 | 167816743, 2097651377, 4027552580, 2265490386, 503444072, 45 | 1762050814, 4150417245, 2154129355, 426522225, 1852507879, 46 | 4275313526, 2312317920, 282753626, 1742555852, 4189708143, 47 | 2394877945, 397917763, 1622183637, 3604390888, 2714866558, 48 | 953729732, 1340076626, 3518719985, 2797360999, 1068828381, 49 | 1219638859, 3624741850, 2936675148, 906185462, 1090812512, 50 | 3747672003, 2825379669, 829329135, 1181335161, 3412177804, 51 | 3160834842, 628085408, 1382605366, 3423369109, 3138078467, 52 | 570562233, 1426400815, 3317316542, 2998733608, 733239954, 53 | 1555261956, 3268935591, 3050360625, 752459403, 1541320221, 54 | 2607071920, 3965973030, 1969922972, 40735498, 2617837225, 55 | 3943577151, 1913087877, 83908371, 2512341634, 3803740692, 56 | 2075208622, 213261112, 2463272603, 3855990285, 2094854071, 57 | 198958881, 2262029012, 4057260610, 1759359992, 534414190, 58 | 2176718541, 4139329115, 1873836001, 414664567, 2282248934, 59 | 4279200368, 1711684554, 285281116, 2405801727, 4167216745, 60 | 1634467795, 376229701, 2685067896, 3608007406, 1308918612, 61 | 956543938, 2808555105, 3495958263, 1231636301, 1047427035, 62 | 2932959818, 3654703836, 1088359270, 936918000, 2847714899, 63 | 3736837829, 1202900863, 817233897, 3183342108, 3401237130, 64 | 1404277552, 615818150, 3134207493, 3453421203, 1423857449, 65 | 601450431, 3009837614, 3294710456, 1567103746, 711928724, 66 | 3020668471, 3272380065, 1510334235, 755167117]; 67 | crc bigint := 4294967295; -- must use bigint, because we don't have 68 | -- an unsigned int32 69 | len int; 70 | data ALIAS FOR $1; 71 | tmp bigint; 72 | pos int := 1; 73 | c text; 74 | d bigint; 75 | BEGIN 76 | len = pg_catalog.length(data); 77 | WHILE len >= pos LOOP 78 | c := SUBSTRING(data FROM pos FOR 1); 79 | d := pg_catalog.ascii(c); 80 | pos = pos + 1; 81 | tmp = (crc # d) & 255; 82 | crc = crc_lu[tmp + 1] # (crc >> 8); 83 | END LOOP; 84 | crc := crc # 4294967295; 85 | RETURN crc; 86 | END 87 | $$ IMMUTABLE STRICT LANGUAGE plpgsql; 88 | 89 | -- FORMAT() 90 | -- FIXME: Only handles numbers with integer part up to 21 digits 91 | -- 92 | -- MySQL has some bugs with long numbers, but they're not worth replicating: 93 | -- format(9999999999999999999999999999999999999999999999999999999999999999, 10) 94 | -- --> last group has four nines! 95 | -- format(9999999999999999999999999999999999999999999999999999999999999999999999999, 1); 96 | -- --> last group has five nines and no decmial zero 97 | CREATE OR REPLACE FUNCTION format(numeric, integer) 98 | RETURNS text AS $$ 99 | SELECT pg_catalog.to_char(pg_catalog.round($1, $2), 'FM999,999,999,999,999,999,990' 100 | operator(pg_catalog.||) 101 | case when $2 > 0 then 102 | '.' operator(pg_catalog.||) pg_catalog.repeat('0', $2) 103 | else '' end) 104 | $$ IMMUTABLE STRICT LANGUAGE SQL; 105 | 106 | -- LN(), LOG() 107 | -- Not reimplemented but note that PostgreSQL has an error on -ve values, 108 | -- but MySQL just returns NULL. 109 | 110 | -- LOG2() 111 | CREATE OR REPLACE FUNCTION log2(numeric) 112 | RETURNS numeric AS $$ 113 | SELECT CASE WHEN $1 > 0 THEN pg_catalog.log(2, $1) ELSE NULL END 114 | $$ IMMUTABLE STRICT LANGUAGE SQL; 115 | 116 | -- LOG10() 117 | CREATE OR REPLACE FUNCTION log10(numeric) 118 | RETURNS numeric AS $$ 119 | SELECT CASE WHEN $1 > 0 THEN pg_catalog.log(10, $1) ELSE NULL END 120 | $$ IMMUTABLE STRICT LANGUAGE SQL; 121 | 122 | -- MOD() 123 | -- PostgreSQL has all MOD usage the same as MySQL EXCEPT this will not work: 124 | -- 125 | -- SELECT 29 MOD 9; 126 | 127 | -- RAND() 128 | CREATE OR REPLACE FUNCTION rand() RETURNS double precision AS $$ 129 | SELECT pg_catalog.random() 130 | $$ VOLATILE LANGUAGE SQL; 131 | 132 | CREATE OR REPLACE FUNCTION rand(integer) RETURNS double precision AS $$ 133 | SELECT pg_catalog.setseed($1); 134 | SELECT pg_catalog.random() 135 | $$ VOLATILE LANGUAGE SQL; 136 | 137 | -- SQRT() 138 | -- Not reimplemented but note that PostgreSQL has an error on -ve values, 139 | -- but MySQL just returns NULL. 140 | 141 | -- TRUNCATE() 142 | CREATE OR REPLACE FUNCTION truncate(numeric, integer) 143 | RETURNS numeric AS $$ 144 | SELECT pg_catalog.trunc($1, $2) 145 | $$ IMMUTABLE STRICT LANGUAGE SQL; 146 | 147 | -------------------------------------------------------------------------------- /sql_bits/misc.sql: -------------------------------------------------------------------------------- 1 | -- INET_ATON() 2 | -- Credit: Michael Fuhr 3 | CREATE OR REPLACE FUNCTION inet_aton(text) 4 | RETURNS bigint AS $$ 5 | DECLARE 6 | a text[]; 7 | b text[4]; 8 | up int; 9 | family int; 10 | i int; 11 | BEGIN 12 | IF position(':' in $1) > 0 THEN 13 | family = 6; 14 | ELSE 15 | family = 4; 16 | END IF; 17 | -- mysql doesn't support IPv6 yet, it seems 18 | IF family = 6 THEN 19 | RETURN NULL; 20 | END IF; 21 | a = pg_catalog.string_to_array($1, '.'); 22 | up = array_upper(a, 1); 23 | IF up = 4 THEN 24 | -- nothing to do 25 | b = a; 26 | ELSIF up = 3 THEN 27 | -- 127.1.2 = 127.1.0.2 28 | b = array[a[1], a[2], '0', a[3]]; 29 | ELSIF up = 2 THEN 30 | -- 127.1 = 127.0.0.1 31 | b = array[a[1], '0', '0', a[2]]; 32 | ELSIF up = 1 THEN 33 | -- 127 = 0.0.0.127 34 | b = array['0', '0', '0', a[1]]; 35 | END IF; 36 | i = 1; 37 | -- handle 127..1 38 | WHILE i <= 4 LOOP 39 | IF length(b[i]) = 0 THEN 40 | b[i] = '0'; 41 | END IF; 42 | i = i + 1; 43 | END LOOP; 44 | RETURN (b[1]::bigint << 24) | (b[2]::bigint << 16) | 45 | (b[3]::bigint << 8) | b[4]::bigint; 46 | END 47 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 48 | 49 | -- INET_NTOA() 50 | -- done in SQL to take advantage of inlining 51 | CREATE OR REPLACE FUNCTION inet_ntoa(bigint) 52 | RETURNS text AS $$ 53 | SELECT CASE WHEN $1 > 4294967295 THEN NULL ELSE 54 | ((($1::bigint >> 24) % 256) + 256) % 256 operator(pg_catalog.||) '.' operator(pg_catalog.||) 55 | ((($1::bigint >> 16) % 256) + 256) % 256 operator(pg_catalog.||) '.' operator(pg_catalog.||) 56 | ((($1::bigint >> 8) % 256) + 256) % 256 operator(pg_catalog.||) '.' operator(pg_catalog.||) 57 | ((($1::bigint ) % 256) + 256) % 256 END; 58 | $$ IMMUTABLE STRICT LANGUAGE SQL; 59 | 60 | -- SLEEP() 61 | CREATE OR REPLACE FUNCTION sleep(float) 62 | RETURNS integer AS $$ 63 | BEGIN 64 | IF $1 > 0 THEN 65 | WHILE pg_catalog.timeofday()::timestamp < (current_timestamp + interval '1 second' * $1) LOOP 66 | -- Do nothing 67 | END LOOP; 68 | END IF; 69 | RETURN 0; 70 | END 71 | $$ STRICT VOLATILE LANGUAGE PLPGSQL; 72 | -------------------------------------------------------------------------------- /sql_bits/operators.sql: -------------------------------------------------------------------------------- 1 | -- <=> NULL SAFE COMPARISON 2 | -- Note: needs casts in some circumstances 3 | CREATE OR REPLACE FUNCTION _null_safe_cmp(anyelement, anyelement) 4 | RETURNS boolean AS ' 5 | SELECT NOT ($1 IS DISTINCT FROM $2) 6 | ' IMMUTABLE LANGUAGE SQL; 7 | 8 | CREATE OPERATOR <=> ( 9 | PROCEDURE = _null_safe_cmp, 10 | LEFTARG = anyelement, 11 | RIGHTARG = anyelement 12 | ); 13 | 14 | -- && 15 | -- XXX: MySQL version has wacky null behaviour 16 | CREATE FUNCTION _and(boolean, boolean) 17 | RETURNS boolean AS $$ 18 | SELECT $1 AND $2 19 | $$ IMMUTABLE STRICT LANGUAGE SQL; 20 | 21 | CREATE OPERATOR && ( 22 | leftarg = boolean, 23 | rightarg = boolean, 24 | procedure = _and, 25 | commutator = && 26 | ); 27 | 28 | -- || 29 | -- XXX: MySQL version has wacky null behaviour 30 | -- This replaces the SQL standard || concatenation operator 31 | CREATE FUNCTION _or(boolean, boolean) 32 | RETURNS boolean AS $$ 33 | SELECT $1 OR $2 34 | $$ IMMUTABLE STRICT LANGUAGE SQL; 35 | 36 | CREATE OPERATOR || ( 37 | leftarg = boolean, 38 | rightarg = boolean, 39 | procedure = _or, 40 | commutator = || 41 | ); 42 | -------------------------------------------------------------------------------- /sql_bits/string.sql: -------------------------------------------------------------------------------- 1 | -- BIN() 2 | CREATE OR REPLACE FUNCTION bin(bigint) 3 | RETURNS text AS $$ 4 | SELECT pg_catalog.ltrim(pg_catalog.textin(pg_catalog.bit_out($1::bit(64))), '0'); 5 | $$ IMMUTABLE STRICT LANGUAGE SQL; 6 | 7 | -- CHAR() 8 | -- Not implemented 9 | 10 | -- COMPRESS 11 | -- Not implemented 12 | 13 | -- CONCAT 14 | CREATE OR REPLACE FUNCTION concat(text) 15 | RETURNS text AS $$ 16 | SELECT $1 17 | $$ IMMUTABLE STRICT LANGUAGE SQL; 18 | 19 | CREATE OR REPLACE FUNCTION concat(text, text) 20 | RETURNS text AS $$ 21 | SELECT $1 operator(pg_catalog.||) $2 22 | $$ IMMUTABLE STRICT LANGUAGE SQL; 23 | 24 | CREATE OR REPLACE FUNCTION concat(text, text, text) 25 | RETURNS text AS $$ 26 | SELECT $1 operator(pg_catalog.||) $2 operator(pg_catalog.||) $3 27 | $$ IMMUTABLE STRICT LANGUAGE SQL; 28 | 29 | -- CONCAT_WS 30 | -- Note: fails in this case: select concat_ws(',', 'First name', null); 31 | CREATE OR REPLACE FUNCTION concat_ws(text, text) 32 | RETURNS text AS $$ 33 | SELECT CASE 34 | WHEN $1 IS NULL THEN NULL 35 | ELSE $2 36 | END 37 | $$ IMMUTABLE LANGUAGE SQL; 38 | 39 | CREATE OR REPLACE FUNCTION concat_ws(text, text, text) 40 | RETURNS text AS $$ 41 | SELECT CASE 42 | WHEN $1 IS NULL THEN NULL 43 | ELSE 44 | coalesce($2 operator(pg_catalog.||) $1, '') operator(pg_catalog.||) coalesce($3, '') 45 | END 46 | $$ IMMUTABLE LANGUAGE SQL; 47 | 48 | CREATE OR REPLACE FUNCTION concat_ws(text, text, text, text) 49 | RETURNS text AS $$ 50 | SELECT CASE 51 | WHEN $1 IS NULL THEN NULL 52 | ELSE 53 | coalesce($2 operator(pg_catalog.||) $1, '') operator(pg_catalog.||) coalesce($3 operator(pg_catalog.||) $1, '') operator(pg_catalog.||) coalesce($4, '') 54 | END 55 | $$ IMMUTABLE LANGUAGE SQL; 56 | 57 | -- CONV() 58 | -- Credit: Gavin Sherry 59 | create or replace function _todec(text, int) 60 | returns int as $$ 61 | declare 62 | num int := 0; 63 | hex text := '0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZ'; 64 | pos int := 0; 65 | chr text; 66 | numin alias for $1; 67 | base alias for $2; 68 | begin 69 | if numin isnull or base isnull then 70 | return null; 71 | end if; 72 | for i in 1 .. pg_catalog.length(numin) loop 73 | pos := pg_catalog.abs(position(pg_catalog.upper(substring(numin from i for 1)) in hex) - 1); 74 | num := num * base + pos; 75 | end loop; 76 | return num; 77 | end$$ 78 | language plpgsql 79 | RETURNS NULL ON NULL INPUT 80 | IMMUTABLE; 81 | 82 | create or replace function conv(int, int, int) 83 | returns text as 84 | $$ 85 | declare 86 | res text := ''; 87 | hex text := '0123456789ABCDEFGHIJLMNOPQRSTUVWXYZ'; 88 | num int; 89 | tmp int; 90 | tmp2 text; 91 | numin text; 92 | tobase int; 93 | isneg bool := false; 94 | numin_p ALIAS FOR $1; 95 | frombase ALIAS FOR $2; 96 | tobase_p ALIAS FOR $3; 97 | begin 98 | if numin_p < 0 and tobase_p < 0 then 99 | isneg := true; 100 | numin := numin_p::integer * -1; 101 | tobase := tobase_p * -1; 102 | else 103 | numin := numin_p; 104 | tobase := tobase_p; 105 | end if; 106 | 107 | if numin isnull OR frombase isnull OR tobase ISNULL then 108 | return NULL; 109 | elsif frombase < 0 OR frombase > 36 then 110 | return NULL; 111 | elsif tobase < 0 OR tobase > 36 then 112 | return NULL; 113 | end if; 114 | 115 | if frombase <> 10 then 116 | num := _todec(numin, frombase); 117 | else 118 | num := numin::int; 119 | end if; 120 | 121 | loop 122 | tmp := num % tobase + 1; 123 | res := substring( hex from tmp for 1 ) operator(pg_catalog.||) res; 124 | num := num/tobase; 125 | if num = 0 then 126 | exit; 127 | end if; 128 | end loop; 129 | if isneg then 130 | return '-' operator(pg_catalog.||) res; 131 | else 132 | return res; 133 | end if; 134 | end 135 | $$ 136 | language plpgsql 137 | RETURNS NULL ON NULL INPUT 138 | IMMUTABLE; 139 | 140 | create or replace function conv(text, int, int) 141 | returns text as 142 | $$ 143 | declare 144 | res text := ''; 145 | hex text := '0123456789ABCDEFGHIJLMNOPQRSTUVWXYZ'; 146 | num int; 147 | tmp int; 148 | tmp2 text; 149 | numin text; 150 | tobase int; 151 | isneg bool := false; 152 | numin_p ALIAS FOR $1; 153 | frombase ALIAS FOR $2; 154 | tobase_p ALIAS FOR $3; 155 | begin 156 | if numin_p < '0' and tobase_p < 0 then 157 | isneg := true; 158 | numin := numin_p::integer * -1; 159 | tobase := tobase_p * -1; 160 | else 161 | numin := numin_p; 162 | tobase := tobase_p; 163 | end if; 164 | 165 | if numin isnull OR frombase isnull OR tobase ISNULL then 166 | return NULL; 167 | elsif frombase < 0 OR frombase > 36 then 168 | return NULL; 169 | elsif tobase < 0 OR tobase > 36 then 170 | return NULL; 171 | end if; 172 | 173 | if frombase <> 10 then 174 | num := _todec(numin, frombase); 175 | else 176 | num := numin::int; 177 | end if; 178 | 179 | loop 180 | tmp := num % tobase + 1; 181 | res := substring( hex from tmp for 1 ) operator(pg_catalog.||) res; 182 | num := num/tobase; 183 | if num = 0 then 184 | exit; 185 | end if; 186 | end loop; 187 | if isneg then 188 | return '-' operator(pg_catalog.||) res; 189 | else 190 | return res; 191 | end if; 192 | end 193 | $$ 194 | language plpgsql 195 | RETURNS NULL ON NULL INPUT 196 | IMMUTABLE; 197 | 198 | -- ELT() 199 | CREATE OR REPLACE FUNCTION elt(integer, text, text) 200 | RETURNS text AS $$ 201 | SELECT CASE 202 | WHEN $1 < 1 OR $1 > 2 THEN NULL 203 | WHEN $1 = 1 THEN $2 204 | ELSE $3 205 | END 206 | $$ IMMUTABLE LANGUAGE SQL; 207 | 208 | CREATE OR REPLACE FUNCTION elt(integer, text, text, text) 209 | RETURNS text AS $$ 210 | SELECT CASE 211 | WHEN $1 < 1 OR $1 > 3 THEN NULL 212 | WHEN $1 = 1 THEN $2 213 | WHEN $1 = 2 THEN $3 214 | ELSE $4 215 | END 216 | $$ IMMUTABLE LANGUAGE SQL; 217 | 218 | CREATE OR REPLACE FUNCTION elt(integer, text, text, text, text) 219 | RETURNS text AS $$ 220 | SELECT CASE 221 | WHEN $1 < 1 OR $1 > 4 THEN NULL 222 | WHEN $1 = 1 THEN $2 223 | WHEN $1 = 2 THEN $3 224 | WHEN $1 = 3 THEN $4 225 | ELSE $5 226 | END 227 | $$ IMMUTABLE LANGUAGE SQL; 228 | 229 | -- REVERSE() 230 | CREATE OR REPLACE FUNCTION reverse(text) 231 | RETURNS text AS $$ 232 | DECLARE 233 | temp TEXT; 234 | count INTEGER; 235 | BEGIN 236 | temp := ''; 237 | count := pg_catalog.length($1); 238 | FOR i IN REVERSE count..1 LOOP 239 | temp := temp operator(pg_catalog.||) substring($1 from i for 1); 240 | END LOOP; 241 | RETURN temp; 242 | END; 243 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 244 | 245 | -- EXPORT_SET() 246 | -- Depends on: BIN() and REVERSE() 247 | -- XXX: WILL fail if $2 is '0' 248 | CREATE OR REPLACE FUNCTION export_set(bigint, text, text, text, integer) 249 | RETURNS text AS $$ 250 | SELECT pg_catalog.rtrim(pg_catalog.replace(pg_catalog.replace(reverse(pg_catalog.lpad(bin($1), $5, '0')), '1', $2 operator(pg_catalog.||) $4), '0', $3 operator(pg_catalog.||) $4), $4) 251 | $$ IMMUTABLE STRICT LANGUAGE SQL; 252 | 253 | CREATE OR REPLACE FUNCTION export_set(bigint, text, text, text) 254 | RETURNS text AS $$ 255 | SELECT export_set($1, $2, $3, $4, 64) 256 | $$ IMMUTABLE STRICT LANGUAGE SQL; 257 | 258 | CREATE OR REPLACE FUNCTION export_set(bigint, text, text) 259 | RETURNS text AS $$ 260 | SELECT export_set($1, $2, $3, ',', 64) 261 | $$ IMMUTABLE STRICT LANGUAGE SQL; 262 | 263 | -- FIELD() 264 | CREATE OR REPLACE FUNCTION field(anyelement , VARIADIC anyarray ) RETURNS INTEGER AS $$ 265 | SELECT i 266 | FROM generate_subscripts($2, 1) AS i 267 | WHERE $2[i] IS NOT DISTINCT FROM $1 268 | $$ LANGUAGE SQL; 269 | 270 | CREATE OR REPLACE FUNCTION field(bigint, VARIADIC anyarray ) RETURNS INTEGER AS $$ 271 | SELECT i 272 | FROM generate_subscripts($2, 1) AS i 273 | WHERE $2[i] IS NOT DISTINCT FROM $1 274 | $$ LANGUAGE SQL; 275 | 276 | -- FIND_IN_SET() 277 | CREATE OR REPLACE FUNCTION find_in_set(text, text) 278 | RETURNS integer AS $$ 279 | DECLARE 280 | list text[]; 281 | len integer; 282 | BEGIN 283 | IF $2 = '' THEN 284 | RETURN 0; 285 | END IF; 286 | list := pg_catalog.string_to_array($2, ','); 287 | len := pg_catalog.array_upper(list, 1); 288 | FOR i IN 1..len LOOP 289 | IF list[i] = $1 THEN 290 | RETURN i; 291 | END IF; 292 | END LOOP; 293 | RETURN 0; 294 | END; 295 | $$ STRICT IMMUTABLE LANGUAGE PLPGSQL; 296 | 297 | -- HEX() 298 | CREATE OR REPLACE FUNCTION hex(integer) 299 | RETURNS text AS $$ 300 | SELECT pg_catalog.upper(pg_catalog.to_hex($1)) 301 | $$ IMMUTABLE STRICT LANGUAGE SQL; 302 | 303 | CREATE OR REPLACE FUNCTION hex(bigint) 304 | RETURNS text AS $$ 305 | SELECT pg_catalog.upper(pg_catalog.to_hex($1)) 306 | $$ IMMUTABLE STRICT LANGUAGE SQL; 307 | 308 | CREATE OR REPLACE FUNCTION hex(text) 309 | RETURNS text AS $$ 310 | DECLARE 311 | len integer; 312 | temp text; 313 | BEGIN 314 | len := pg_catalog.length($1); 315 | temp := ''; 316 | FOR i IN 1..len LOOP 317 | temp := temp operator(pg_catalog.||) pg_catalog.to_hex(pg_catalog.ascii(SUBSTRING($1 FROM i FOR 1))); 318 | END LOOP; 319 | RETURN pg_catalog.upper(temp); 320 | END; 321 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 322 | 323 | -- FORMAT() 324 | -- See: mathematical.sql 325 | 326 | -- INSERT() 327 | CREATE OR REPLACE FUNCTION insert(text, integer, integer, text) 328 | RETURNS text AS $$ 329 | SELECT CASE 330 | WHEN NOT $2 BETWEEN 1 AND pg_catalog.length($1) THEN $1 331 | ELSE overlay($1 placing $4 from $2 for $3) 332 | END 333 | $$ IMMUTABLE STRICT LANGUAGE SQL; 334 | 335 | -- INSTR() 336 | CREATE OR REPLACE FUNCTION instr(text, text) 337 | RETURNS integer AS $$ 338 | SELECT POSITION($2 IN $1) 339 | $$ IMMUTABLE STRICT LANGUAGE SQL; 340 | 341 | -- LCASE() 342 | CREATE OR REPLACE FUNCTION lcase(text) 343 | RETURNS text AS $$ 344 | SELECT pg_catalog.lower($1) 345 | $$ IMMUTABLE STRICT LANGUAGE SQL; 346 | 347 | -- LEFT() 348 | CREATE OR REPLACE FUNCTION left(text, integer) 349 | RETURNS text AS $$ 350 | SELECT substring($1 FOR $2); 351 | $$ IMMUTABLE STRICT LANGUAGE SQL; 352 | 353 | -- LOAD_FILE() 354 | -- Not implemented 355 | 356 | -- LOCATE() 357 | CREATE OR REPLACE FUNCTION locate(text, text, integer) 358 | RETURNS integer AS $$ 359 | SELECT POSITION($1 IN SUBSTRING ($2 FROM $3)) + $3 - 1 360 | $$ IMMUTABLE STRICT LANGUAGE SQL; 361 | 362 | CREATE OR REPLACE FUNCTION locate(text, text) 363 | RETURNS integer AS $$ 364 | SELECT locate($1, $2, 1) 365 | $$ IMMUTABLE STRICT LANGUAGE SQL; 366 | 367 | -- MAKE_SET() 368 | -- routine to make make_set() easier 369 | -- note: since arrays do not support NULLs until 8.2, we cannot 370 | -- handle NULL arguments to make_set() 371 | -- note: we only support 32 arguments to make_set() as PostgreSQL 372 | -- does not support arbitary argument lists 373 | CREATE OR REPLACE FUNCTION _make_set(bigint, text[]) 374 | RETURNS text AS $$ 375 | DECLARE 376 | up int; 377 | i int = 1; 378 | ret text = ''; 379 | dat ALIAS FOR $2; 380 | found bool = false; 381 | mask bigint = 1; 382 | BEGIN 383 | up = array_upper($2, 1); 384 | IF up > 31 THEN 385 | RAISE EXCEPTION 'maximum array size exceeded'; 386 | RETURN NULL; 387 | END IF; 388 | WHILE i <= up LOOP 389 | IF $1 & mask <> 0 THEN 390 | IF found = false THEN 391 | found = true; 392 | ELSE 393 | ret = ret operator(pg_catalog.||) ','; 394 | END IF; 395 | ret = ret operator(pg_catalog.||) dat[i]; 396 | END IF; 397 | i = i + 1; 398 | mask = mask << 1; 399 | END LOOP; 400 | RETURN ret; 401 | END; 402 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 403 | 404 | 405 | CREATE OR REPLACE FUNCTION make_set(bigint, text) 406 | RETURNS text AS $$ 407 | DECLARE 408 | a text[]; 409 | BEGIN 410 | a = ARRAY[$2]; 411 | RETURN _make_set($1, a); 412 | END; 413 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 414 | 415 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text) 416 | RETURNS text AS $$ 417 | DECLARE 418 | a text[]; 419 | BEGIN 420 | a = ARRAY[$2, $3]; 421 | RETURN _make_set($1, a); 422 | END; 423 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 424 | 425 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text) 426 | RETURNS text AS $$ 427 | DECLARE 428 | a text[]; 429 | BEGIN 430 | a = ARRAY[$2, $3, $4]; 431 | RETURN _make_set($1, a); 432 | END; 433 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 434 | 435 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text) 436 | RETURNS text AS $$ 437 | DECLARE 438 | a text[]; 439 | BEGIN 440 | a = ARRAY[$2, $3, $4, $5]; 441 | RETURN _make_set($1, a); 442 | END; 443 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 444 | 445 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text) 446 | RETURNS text AS $$ 447 | DECLARE 448 | a text[]; 449 | BEGIN 450 | a = ARRAY[$2, $3, $4, $5, $6]; 451 | RETURN _make_set($1, a); 452 | END; 453 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 454 | 455 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text) 456 | RETURNS text AS $$ 457 | DECLARE 458 | a text[]; 459 | BEGIN 460 | a = ARRAY[$2, $3, $4, $5, $6, $7]; 461 | RETURN _make_set($1, a); 462 | END; 463 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 464 | 465 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text) 466 | RETURNS text AS $$ 467 | DECLARE 468 | a text[]; 469 | BEGIN 470 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8]; 471 | RETURN _make_set($1, a); 472 | END; 473 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 474 | 475 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text) 476 | RETURNS text AS $$ 477 | DECLARE 478 | a text[]; 479 | BEGIN 480 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9]; 481 | RETURN _make_set($1, a); 482 | END; 483 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 484 | 485 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text) 486 | RETURNS text AS $$ 487 | DECLARE 488 | a text[]; 489 | BEGIN 490 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10]; 491 | RETURN _make_set($1, a); 492 | END; 493 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 494 | 495 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text) 496 | RETURNS text AS $$ 497 | DECLARE 498 | a text[]; 499 | BEGIN 500 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11]; 501 | RETURN _make_set($1, a); 502 | END; 503 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 504 | 505 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text) 506 | RETURNS text AS $$ 507 | DECLARE 508 | a text[]; 509 | BEGIN 510 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12]; 511 | RETURN _make_set($1, a); 512 | END; 513 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 514 | 515 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text) 516 | RETURNS text AS $$ 517 | DECLARE 518 | a text[]; 519 | BEGIN 520 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13]; 521 | RETURN _make_set($1, a); 522 | END; 523 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 524 | 525 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text) 526 | RETURNS text AS $$ 527 | DECLARE 528 | a text[]; 529 | BEGIN 530 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14]; 531 | RETURN _make_set($1, a); 532 | END; 533 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 534 | 535 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text) 536 | RETURNS text AS $$ 537 | DECLARE 538 | a text[]; 539 | BEGIN 540 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15]; 541 | RETURN _make_set($1, a); 542 | END; 543 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 544 | 545 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text) 546 | RETURNS text AS $$ 547 | DECLARE 548 | a text[]; 549 | BEGIN 550 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16]; 551 | RETURN _make_set($1, a); 552 | END; 553 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 554 | 555 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text) 556 | RETURNS text AS $$ 557 | DECLARE 558 | a text[]; 559 | BEGIN 560 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17]; 561 | RETURN _make_set($1, a); 562 | END; 563 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 564 | 565 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text) 566 | RETURNS text AS $$ 567 | DECLARE 568 | a text[]; 569 | BEGIN 570 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18]; 571 | RETURN _make_set($1, a); 572 | END; 573 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 574 | 575 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text) 576 | RETURNS text AS $$ 577 | DECLARE 578 | a text[]; 579 | BEGIN 580 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18, $19]; 581 | RETURN _make_set($1, a); 582 | END; 583 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 584 | 585 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text) 586 | RETURNS text AS $$ 587 | DECLARE 588 | a text[]; 589 | BEGIN 590 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18, $19, $20]; 591 | RETURN _make_set($1, a); 592 | END; 593 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 594 | 595 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text) 596 | RETURNS text AS $$ 597 | DECLARE 598 | a text[]; 599 | BEGIN 600 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18, $19, $20, $21]; 601 | RETURN _make_set($1, a); 602 | END; 603 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 604 | 605 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text) 606 | RETURNS text AS $$ 607 | DECLARE 608 | a text[]; 609 | BEGIN 610 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18, $19, $20, $21, $22]; 611 | RETURN _make_set($1, a); 612 | END; 613 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 614 | 615 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text) 616 | RETURNS text AS $$ 617 | DECLARE 618 | a text[]; 619 | BEGIN 620 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18, $19, $20, $21, $22, $23]; 621 | RETURN _make_set($1, a); 622 | END; 623 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 624 | 625 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text) 626 | RETURNS text AS $$ 627 | DECLARE 628 | a text[]; 629 | BEGIN 630 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18, $19, $20, $21, $22, $23, $24]; 631 | RETURN _make_set($1, a); 632 | END; 633 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 634 | 635 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text) 636 | RETURNS text AS $$ 637 | DECLARE 638 | a text[]; 639 | BEGIN 640 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18, $19, $20, $21, $22, $23, $24, $25]; 641 | RETURN _make_set($1, a); 642 | END; 643 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 644 | 645 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text) 646 | RETURNS text AS $$ 647 | DECLARE 648 | a text[]; 649 | BEGIN 650 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18, $19, $20, $21, $22, $23, $24, $25, $26]; 651 | RETURN _make_set($1, a); 652 | END; 653 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 654 | 655 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text) 656 | RETURNS text AS $$ 657 | DECLARE 658 | a text[]; 659 | BEGIN 660 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18, $19, $20, $21, $22, $23, $24, $25, $26, $27]; 661 | RETURN _make_set($1, a); 662 | END; 663 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 664 | 665 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text) 666 | RETURNS text AS $$ 667 | DECLARE 668 | a text[]; 669 | BEGIN 670 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18, $19, $20, $21, $22, $23, $24, $25, $26, $27, $28]; 671 | RETURN _make_set($1, a); 672 | END; 673 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 674 | 675 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text) 676 | RETURNS text AS $$ 677 | DECLARE 678 | a text[]; 679 | BEGIN 680 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18, $19, $20, $21, $22, $23, $24, $25, $26, $27, $28, $29]; 681 | RETURN _make_set($1, a); 682 | END; 683 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 684 | 685 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text) 686 | RETURNS text AS $$ 687 | DECLARE 688 | a text[]; 689 | BEGIN 690 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18, $19, $20, $21, $22, $23, $24, $25, $26, $27, $28, $29, $30]; 691 | RETURN _make_set($1, a); 692 | END; 693 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 694 | 695 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text) 696 | RETURNS text AS $$ 697 | DECLARE 698 | a text[]; 699 | BEGIN 700 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18, $19, $20, $21, $22, $23, $24, $25, $26, $27, $28, $29, $30, $31]; 701 | RETURN _make_set($1, a); 702 | END; 703 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 704 | 705 | CREATE OR REPLACE FUNCTION make_set(bigint, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text, text) 706 | RETURNS text AS $$ 707 | DECLARE 708 | a text[]; 709 | BEGIN 710 | a = ARRAY[$2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18, $19, $20, $21, $22, $23, $24, $25, $26, $27, $28, $29, $30, $31, $32]; 711 | RETURN _make_set($1, a); 712 | END; 713 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 714 | 715 | -- MID() 716 | CREATE OR REPLACE FUNCTION mid(text, integer, integer) 717 | RETURNS text AS $$ 718 | SELECT pg_catalog.substring($1, $2, $3) 719 | $$ IMMUTABLE STRICT LANGUAGE SQL; 720 | 721 | -- OCT() 722 | -- Depends on: CONV() 723 | CREATE OR REPLACE FUNCTION oct(integer) 724 | RETURNS text AS $$ 725 | SELECT conv($1, 10, 8) 726 | $$ IMMUTABLE STRICT LANGUAGE SQL; 727 | 728 | -- OCTET_LENGTH() 729 | -- not reimplemented 730 | 731 | -- ORD() 732 | -- Note: Does not support multibyte 733 | CREATE OR REPLACE FUNCTION ord(text) 734 | RETURNS integer AS $$ 735 | SELECT pg_catalog.ascii($1) 736 | $$ IMMUTABLE STRICT LANGUAGE SQL; 737 | 738 | -- QUOTE() 739 | CREATE OR REPLACE FUNCTION quote(text) 740 | RETURNS text AS $$ 741 | SELECT CASE 742 | WHEN $1 IS NULL THEN 'NULL' 743 | ELSE pg_catalog.quote_literal($1) 744 | END 745 | $$ IMMUTABLE LANGUAGE SQL; 746 | 747 | -- REVERSE() 748 | -- See above. Needed by EXPORT_SET(). 749 | 750 | -- RIGHT() 751 | CREATE OR REPLACE FUNCTION right(text, integer) 752 | RETURNS text AS $$ 753 | SELECT substring($1 FROM pg_catalog.length($1) + 1 - $2); 754 | $$ IMMUTABLE STRICT LANGUAGE SQL; 755 | 756 | -- SOUNDEX() 757 | -- Thanks to Fredrik Olsson for the original soundex() function. 758 | CREATE OR REPLACE FUNCTION _soundexcode(char(1)) 759 | RETURNS char(1) AS $$ 760 | SELECT COALESCE( 761 | (ARRAY['0', '1', '2', '3', '0', 762 | '1', '2', '0', '0', '2', 763 | '2', '4', '5', '5', '0', 764 | '1', '2', '6', '2', '3', 765 | '0', '1', '0', '2', '0', '2'])[pg_catalog.ascii($1) - 64], 766 | '0'); 767 | $$ IMMUTABLE STRICT LANGUAGE SQL; 768 | 769 | CREATE OR REPLACE FUNCTION soundex(text) RETURNS text AS $$ 770 | DECLARE 771 | a_text alias for $1; 772 | l_text text; 773 | l_lchr char(1); 774 | l_chr char(1); 775 | l_ret text; 776 | BEGIN 777 | l_text := pg_catalog.upper(trim(both from a_text)); 778 | IF l_text = '' THEN 779 | RETURN '0000'; 780 | END IF; 781 | l_chr := substring(l_text FOR 1); 782 | l_ret := l_chr; 783 | l_text := substring(l_text FROM 2); 784 | WHILE (l_text <> '') LOOP 785 | l_lchr := l_chr; 786 | l_chr := substring(l_text FOR 1); 787 | l_text := substring(l_text FROM 2); 788 | IF (pg_catalog.ascii(l_chr) BETWEEN 65 AND 90) AND 789 | (_soundexcode(l_chr) <> _soundexcode(l_lchr)) THEN 790 | IF _soundexcode(l_chr) <> '0' THEN 791 | l_ret := l_ret operator(pg_catalog.||) _soundexcode(l_chr); 792 | END IF; 793 | END IF; 794 | END LOOP; 795 | IF pg_catalog.length(l_ret) < 4 THEN 796 | l_ret := rpad(l_ret, 4, '0'); 797 | END IF; 798 | RETURN l_ret; 799 | END; 800 | $$ IMMUTABLE STRICT LANGUAGE plpgsql; 801 | 802 | -- SPACE() 803 | CREATE OR REPLACE FUNCTION space(integer) 804 | RETURNS text AS $$ 805 | SELECT pg_catalog.repeat(' ', $1) 806 | $$ IMMUTABLE STRICT LANGUAGE SQL; 807 | 808 | -- SUBSTRING_INDEX() 809 | CREATE OR REPLACE FUNCTION substring_index(text, text, integer) 810 | RETURNS text AS $$ 811 | DECLARE 812 | tokens text[]; 813 | BEGIN 814 | tokens := pg_catalog.string_to_array($1, $2); 815 | 816 | IF $3 >= 0 THEN 817 | RETURN pg_catalog.array_to_string(tokens[1:$3], $2); 818 | ELSE 819 | RETURN pg_catalog.array_to_string(tokens[($3 * -1):pg_catalog.array_upper(tokens, 1)], $2); 820 | END IF; 821 | END; 822 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 823 | 824 | -- STRCMP() 825 | -- Note: comparison is case-sensitive 826 | CREATE OR REPLACE FUNCTION strcmp(text, text) 827 | RETURNS integer AS $$ 828 | SELECT CASE 829 | WHEN $1 = $2 THEN 0 830 | WHEN $1 < $2 THEN -1 831 | ELSE 1 832 | END 833 | $$ IMMUTABLE STRICT LANGUAGE SQL; 834 | 835 | -- UCASE() 836 | CREATE OR REPLACE FUNCTION ucase(text) 837 | RETURNS text AS $$ 838 | SELECT pg_catalog.upper($1) 839 | $$ IMMUTABLE STRICT LANGUAGE SQL; 840 | 841 | -- UNCOMPRESS() 842 | -- Not implemented. 843 | 844 | -- UNHEX() 845 | -- Depends on: CONV() 846 | CREATE OR REPLACE FUNCTION unhex(text) 847 | RETURNS text AS $$ 848 | DECLARE 849 | len integer := pg_catalog.length($1); 850 | temp text := ''; 851 | i int := 1; 852 | BEGIN 853 | WHILE i <= len LOOP 854 | temp := temp operator(pg_catalog.||) pg_catalog.chr(conv(substring($1 from i for 2), 16, 10)::integer); 855 | i := i + 2; 856 | END LOOP; 857 | RETURN temp; 858 | END; 859 | $$ IMMUTABLE STRICT LANGUAGE PLPGSQL; 860 | -------------------------------------------------------------------------------- /test/expected/datetime.out: -------------------------------------------------------------------------------- 1 | \set ECHO none 2 | SELECT to_days('0001-01-01'); 3 | to_days 4 | --------- 5 | 366 6 | (1 row) 7 | 8 | SELECT from_days(1); 9 | from_days 10 | --------------- 11 | 01-02-0001 BC 12 | (1 row) 13 | 14 | SELECT to_days('2011-08-15'); 15 | to_days 16 | --------- 17 | 734729 18 | (1 row) 19 | 20 | SELECT from_days(734729); 21 | from_days 22 | ------------ 23 | 08-15-2011 24 | (1 row) 25 | 26 | SELECT from_days(to_days(now()::date)) = now()::date; 27 | ?column? 28 | ---------- 29 | t 30 | (1 row) 31 | 32 | ROLLBACK; 33 | -------------------------------------------------------------------------------- /test/expected/mathematical.out: -------------------------------------------------------------------------------- 1 | \set ECHO none 2 | SELECT format(10000.01, 0); 3 | format 4 | -------- 5 | 10,000 6 | (1 row) 7 | 8 | SELECT format(10000.01, 2); 9 | format 10 | ----------- 11 | 10,000.01 12 | (1 row) 13 | 14 | SELECT format(0.01, 1); 15 | format 16 | -------- 17 | 0.0 18 | (1 row) 19 | 20 | SELECT format(0, 3); 21 | format 22 | -------- 23 | 0.000 24 | (1 row) 25 | 26 | SELECT format(9.95, 1); 27 | format 28 | -------- 29 | 10.0 30 | (1 row) 31 | 32 | SELECT format(9.94999999, 1); 33 | format 34 | -------- 35 | 9.9 36 | (1 row) 37 | 38 | ROLLBACK; 39 | -------------------------------------------------------------------------------- /test/sql/datetime.sql: -------------------------------------------------------------------------------- 1 | \set ECHO none 2 | BEGIN; 3 | \i sql_bits/datetime.sql 4 | \set ECHO all 5 | 6 | SELECT to_days('0001-01-01'); 7 | SELECT from_days(1); 8 | SELECT to_days('2011-08-15'); 9 | SELECT from_days(734729); 10 | SELECT from_days(to_days(now()::date)) = now()::date; 11 | 12 | ROLLBACK; 13 | -------------------------------------------------------------------------------- /test/sql/mathematical.sql: -------------------------------------------------------------------------------- 1 | \set ECHO none 2 | BEGIN; 3 | \i sql_bits/mathematical.sql 4 | \set ECHO all 5 | 6 | SELECT format(10000.01, 0); 7 | SELECT format(10000.01, 2); 8 | SELECT format(0.01, 1); 9 | SELECT format(0, 3); 10 | SELECT format(9.95, 1); 11 | SELECT format(9.94999999, 1); 12 | 13 | ROLLBACK; 14 | -------------------------------------------------------------------------------- /tools/README: -------------------------------------------------------------------------------- 1 | This directory contains development tools for the mysqlcompat project. They 2 | are not intended to be used by users. 3 | -------------------------------------------------------------------------------- /tools/makesetbld.sh: -------------------------------------------------------------------------------- 1 | arr() 2 | { 3 | l=$1 4 | j=1; 5 | found=0; 6 | echo -n "a = ARRAY[" 7 | while [ $j -le $l ] 8 | do 9 | if [ $found -eq 0 ] 10 | then 11 | found=1; 12 | else 13 | echo -n ", " 14 | fi 15 | echo -n "\$" 16 | echo -n $[$j + 1] 17 | j=$[$j + 1] 18 | done 19 | echo "];" 20 | } 21 | 22 | arg() 23 | { 24 | l=$1 25 | j=1; 26 | found=0; 27 | while [ $j -le $l ] 28 | do 29 | if [ $found -eq 0 ] 30 | then 31 | found=1; 32 | else 33 | echo -n ", " 34 | fi 35 | echo -n "text" 36 | j=$[$j + 1] 37 | done 38 | } 39 | 40 | i=1 41 | while [ $i -lt 32 ] 42 | do 43 | echo -n "CREATE OR REPLACE FUNCTION make_set(bigint, "; 44 | arg $i 45 | echo ")" 46 | echo "RETURNS text AS \$\$" 47 | echo " DECLARE" 48 | echo " a text[];" 49 | echo " BEGIN" 50 | echo -n " "; 51 | arr $i 52 | echo "RETURN _make_set(\$1, a);" 53 | echo "END;" 54 | echo "\$\$ IMMUTABLE STRICT LANGUAGE PLPGSQL;" 55 | echo "" 56 | i=$[$i + 1]; 57 | done 58 | -------------------------------------------------------------------------------- /tools/makesetdrop.sh: -------------------------------------------------------------------------------- 1 | arr() 2 | { 3 | l=$1 4 | j=1; 5 | found=0; 6 | echo -n "a = ARRAY[" 7 | while [ $j -le $l ] 8 | do 9 | if [ $found -eq 0 ] 10 | then 11 | found=1; 12 | else 13 | echo -n ", " 14 | fi 15 | echo -n "\$" 16 | echo -n $[$j + 1] 17 | j=$[$j + 1] 18 | done 19 | echo "];" 20 | } 21 | 22 | arg() 23 | { 24 | l=$1 25 | j=1; 26 | found=0; 27 | while [ $j -le $l ] 28 | do 29 | if [ $found -eq 0 ] 30 | then 31 | found=1; 32 | else 33 | echo -n ", " 34 | fi 35 | echo -n "text" 36 | j=$[$j + 1] 37 | done 38 | } 39 | 40 | i=1 41 | while [ $i -lt 32 ] 42 | do 43 | echo -n "DROP FUNCTION make_set(bigint, "; 44 | arg $i 45 | echo ");" 46 | i=$[$i + 1]; 47 | done 48 | --------------------------------------------------------------------------------