Permalink
Browse files

add pg_catalog_get_defs extension (pg_get_typedef writtein by the ill…

…ustrious RhodiumToad)
  • Loading branch information...
erichanson committed Feb 8, 2019
1 parent c3a7f51 commit 85744a7d14d32b0467562a1e4d2121ae184097bb
@@ -97,10 +97,12 @@ select bundle.tracked_row_add('org.aquameta.core.endpoint', row_id) from bundle.

select bundle.stage_row_add('org.aquameta.core.endpoint', (row_id::meta.schema_id).name, (row_id::meta.relation_id).name, 'id', (row_id).pk_value) from bundle.tracked_row_added where bundle_id=(select id from bundle.bundle where name='org.aquameta.core.endpoint');

/*
select bundle.commit('org.aquameta.core.endpoint','initial import');
drop extension endpoint;
drop schema endpoint;
select bundle.checkout((select head_commit_id from bundle.bundle where name='org.aquameta.core.endpoint'));
*/
@@ -144,6 +144,7 @@ sudo -u postgres psql -c "create extension if not exists plv8" aquameta

# create aquameta core extensions
echo "Installing core Aquameta extensions..."
sudo -u postgres psql -c "create extension pg_catalog_get_defs schema pg_catalog" aquameta
sudo -u postgres psql -c "create extension meta" aquameta
sudo -u postgres psql -c "create extension bundle" aquameta
sudo -u postgres psql -c "create extension filesystem" aquameta
@@ -0,0 +1,29 @@
BSD 3-Clause License

Copyright (c) 2019, Aquameta Labs
All rights reserved.

Redistribution and use in source and binary forms, with or without
modification, are permitted provided that the following conditions are met:

* Redistributions of source code must retain the above copyright notice, this
list of conditions and the following disclaimer.

* Redistributions in binary form must reproduce the above copyright notice,
this list of conditions and the following disclaimer in the documentation
and/or other materials provided with the distribution.

* Neither the name of the copyright holder nor the names of its
contributors may be used to endorse or promote products derived from
this software without specific prior written permission.

THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS"
AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE
IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE
DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE LIABLE
FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL
DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR
SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER
CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY,
OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE
OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.
@@ -0,0 +1,11 @@
EXTENSION = pg_catalog_get_defs
EXTVERSION = 0.1.0
DATA = $(EXTENSION)--$(EXTVERSION).sql
PG_CONFIG = pg_config

$(EXTENSION)--$(EXTVERSION).sql: $(sort $(filter-out $(wildcard *--*.sql),$(wildcard *.sql)))

cat $^ > $@

PGXS := $(shell $(PG_CONFIG) --pgxs)
include $(PGXS)
@@ -0,0 +1,2 @@
# pg_catalog_get_defs
PostgreSQL Extension providing the not-yet-implemented pg_catalog.get_*def functions
@@ -0,0 +1,2 @@
comment = 'Provides the missing pg_catalog.get_*def() functions'
default_version = '0.1.0'
@@ -0,0 +1,186 @@
-- written by RhodiumToad on IRC in one hour :)

create or replace function get_typedef_enum(oid) returns text
language plpgsql
as $$
declare
defn text;
begin
select into defn
format('CREATE TYPE %s AS ENUM (%s)',
$1::regtype,
string_agg(quote_literal(enumlabel), ', '
order by enumsortorder))
from pg_enum
where enumtypid = $1;
return defn;
end;
$$;

create or replace function get_typedef_composite(oid) returns text
language plpgsql
as $$
declare
defn text;
begin
select into defn
format('CREATE TYPE %s AS (%s)',
$1::regtype,
string_agg(coldef, ', ' order by attnum))
from (select a.attnum,
format('%I %s%s',
a.attname,
format_type(a.atttypid, a.atttypmod),
case when a.attcollation <> ct.typcollation
then format(' COLLATE %I ', co.collname)
else ''
end) as coldef
from pg_type t
join pg_attribute a on a.attrelid=t.typrelid
join pg_type ct on ct.oid=a.atttypid
left join pg_collation co on co.oid=a.attcollation
where t.oid = $1
and a.attnum > 0
and not a.attisdropped) s;
return defn;
end;
$$;

create or replace function get_typedef_domain(oid) returns text
language plpgsql
as $$
declare
defn text;
begin
select into defn
format('CREATE DOMAIN %s AS %s%s%s',
$1::regtype,
basetype,
case when defval is not null then ' ' else '' end,
coalesce(defval, ''))
from (select format_type(t.typbasetype, t.typtypmod) as basetype,
pg_get_expr(t.typdefaultbin, 0) as defval
from pg_type t
where t.oid = $1) s;
return defn;
end;
$$;

create or replace function get_typedef_range(oid) returns text
language plpgsql
as $$
declare
defn text;
begin
select into defn
format('CREATE TYPE %s AS RANGE (%s)',
$1::regtype,
string_agg(format('%s = %s', propname, propval),', '
order by keypos)
filter (where propval is not null))
from (select v.keypos, v.propname, v.propval
from pg_range r
join pg_type st on st.oid=r.rngsubtype
join pg_opclass opc on opc.oid=r.rngsubopc
join pg_namespace n on n.oid=opc.opcnamespace
left join pg_collation co on co.oid=r.rngcollation
join lateral (values (1, 'SUBTYPE', format_type(r.rngsubtype, NULL)),
(2, 'SUBTYPE_OPCLASS', case when not opc.opcdefault
then format('%I.%I',
n.nspname,
opc.opcname)
end),
(3, 'COLLATION', case when r.rngcollation <> st.typcollation
then quote_ident(co.collname)
end),
(4, 'CANONICAL', nullif(r.rngcanonical::oid,0)::regproc::text),
(5, 'SUBTYPE_DIFF', nullif(r.rngsubdiff::oid,0)::regproc::text))
as v(keypos,propname,propval)
on true
where r.rngtypid = $1) s;
return defn;
end;
$$;


create or replace function get_typedef_base(oid) returns text
language plpgsql
as $$
declare
defn text;
begin
select into defn
format('CREATE TYPE %s AS (%s)',
$1::regtype,
string_agg(format('%s = %s', propname, propval),', '
order by keypos)
filter (where propval is not null))
from (select v.keypos, v.propname, v.propval
from pg_type t
join lateral
(values
(1, 'INPUT', t.typinput::text),
(2, 'OUTPUT', t.typoutput::text),
(3, 'RECEIVE', nullif(t.typreceive,0)::regproc::text),
(4, 'SEND', nullif(t.typsend,0)::regproc::text),
(5, 'TYPMOD_IN', nullif(t.typmodin,0)::regproc::text),
(6, 'TYPMOD_OUT', nullif(t.typmodout,0)::regproc::text),
(7, 'ANALYZE', nullif(t.typanalyze,0)::regproc::text),
(8, 'INTERNALLENGTH', case when t.typlen = -1
then 'VARIABLE'
else t.typlen::text
end),
(9, 'PASSEDBYVALUE', nullif(t.typbyval,false)::text),
(10, 'ALIGNMENT', case t.typalign
when 'd' then 'double'
when 'i' then 'int4'
when 's' then 'int2'
when 'c' then 'char'
end),
(11, 'STORAGE', case t.typstorage
when 'p' then 'plain'
when 'm' then 'main'
when 'e' then 'external'
when 'x' then 'extended'
end),
(12, 'CATEGORY', quote_literal(t.typcategory)),
(13, 'PREFERRED', nullif(t.typispreferred,false)::text),
(14, 'DEFAULT', case when t.typdefaultbin is not null
then pg_get_expr(t.typdefaultbin, 0)
end),
(15, 'ELEMENT', nullif(t.typelem,0)::regtype::text),
(16, 'DELIMITER', nullif(t.typdelim,',')::text),
(17, 'COLLATABLE', case when t.typcollation <> 0 then 'true' end))
as v(keypos,propname,propval)
on true
where t.oid = $1) s;
return defn;
end;
$$;

create function get_typedef(typid oid) returns text
language plpgsql
as $$
declare
r record;
begin
select into r * from pg_type where oid = typid;
if not found then
raise exception 'unknown type oid %', typid;
end if;
case r.typtype
when 'b' then return get_typedef_base(typid);
when 'd' then return get_typedef_domain(typid);
when 'c' then return get_typedef_composite(typid);
when 'e' then return get_typedef_enum(typid);
when 'r' then return get_typedef_range(typid);
when 'p' then
if not r.typisdefined then
return format('CREATE TYPE %s', typid::regtype);
end if;
raise exception 'type % is a pseudotype', typid::regtype;
else
raise exception 'type % has unknown typtype %', typid::regtype, r.typtype;
end case;
end;
$$;

0 comments on commit 85744a7

Please sign in to comment.