Support generation of DDL for tables in Greenplum DB. Fixes #2261

pull/3/head
Atira Odhner 2017-03-23 11:40:06 +00:00 committed by Dave Page
parent 0ba0b25290
commit 77007996ed
38 changed files with 800 additions and 176 deletions

View File

@ -0,0 +1,34 @@
SELECT 'attacl' as deftype, COALESCE(gt.rolname, 'PUBLIC') grantee, g.rolname grantor, array_agg(privilege_type) as privileges, array_agg(is_grantable) as grantable
FROM
(SELECT
d.grantee, d.grantor, d.is_grantable,
CASE d.privilege_type
WHEN 'CONNECT' THEN 'c'
WHEN 'CREATE' THEN 'C'
WHEN 'DELETE' THEN 'd'
WHEN 'EXECUTE' THEN 'X'
WHEN 'INSERT' THEN 'a'
WHEN 'REFERENCES' THEN 'x'
WHEN 'SELECT' THEN 'r'
WHEN 'TEMPORARY' THEN 'T'
WHEN 'TRIGGER' THEN 't'
WHEN 'TRUNCATE' THEN 'D'
WHEN 'UPDATE' THEN 'w'
WHEN 'USAGE' THEN 'U'
ELSE 'UNKNOWN'
END AS privilege_type
FROM
(SELECT attacl
FROM pg_attribute att
WHERE att.attrelid = {{tid}}::oid
AND att.attnum = {{clid}}::int
) acl,
(SELECT (d).grantee AS grantee, (d).grantor AS grantor, (d).is_grantable
AS is_grantable, (d).privilege_type AS privilege_type FROM (SELECT
aclexplode(attacl) as d FROM pg_attribute att
WHERE att.attrelid = {{tid}}::oid
AND att.attnum = {{clid}}::int) a) d
) d
LEFT JOIN pg_catalog.pg_roles g ON (d.grantor = g.oid)
LEFT JOIN pg_catalog.pg_roles gt ON (d.grantee = gt.oid)
GROUP BY g.rolname, gt.rolname

View File

@ -0,0 +1,45 @@
SELECT att.attname as name, att.*, def.*, pg_catalog.pg_get_expr(def.adbin, def.adrelid) AS defval,
CASE WHEN att.attndims > 0 THEN 1 ELSE 0 END AS isarray,
format_type(ty.oid,NULL) AS typname,
format_type(ty.oid,att.atttypmod) AS displaytypname,
tn.nspname as typnspname, et.typname as elemtypname,
ty.typstorage AS defaultstorage, cl.relname, na.nspname,
concat(quote_ident(na.nspname) ,'.', quote_ident(cl.relname)) AS parent_tbl,
att.attstattarget, description, cs.relname AS sername,
ns.nspname AS serschema,
(SELECT count(1) FROM pg_type t2 WHERE t2.typname=ty.typname) > 1 AS isdup,
indkey, coll.collname, nspc.nspname as collnspname , attoptions,
-- Start pgAdmin4, added to save time on client side parsing
CASE WHEN length(coll.collname) > 0 AND length(nspc.nspname) > 0 THEN
concat(quote_ident(nspc.nspname),'.',quote_ident(coll.collname))
ELSE '' END AS collspcname,
CASE WHEN strpos(format_type(ty.oid,att.atttypmod), '.') > 0 THEN
split_part(format_type(ty.oid,att.atttypmod), '.', 2)
ELSE format_type(ty.oid,att.atttypmod) END AS cltype,
-- End pgAdmin4
EXISTS(SELECT 1 FROM pg_constraint WHERE conrelid=att.attrelid AND contype='f' AND att.attnum=ANY(conkey)) As is_fk,
(SELECT array_agg(provider || '=' || label) FROM pg_seclabels sl1 WHERE sl1.objoid=att.attrelid AND sl1.objsubid=att.attnum) AS seclabels,
(CASE WHEN (att.attnum < 1) THEN true ElSE false END) AS is_sys_column
FROM pg_attribute att
JOIN pg_type ty ON ty.oid=atttypid
JOIN pg_namespace tn ON tn.oid=ty.typnamespace
JOIN pg_class cl ON cl.oid=att.attrelid
JOIN pg_namespace na ON na.oid=cl.relnamespace
LEFT OUTER JOIN pg_type et ON et.oid=ty.typelem
LEFT OUTER JOIN pg_attrdef def ON adrelid=att.attrelid AND adnum=att.attnum
LEFT OUTER JOIN pg_description des ON (des.objoid=att.attrelid AND des.objsubid=att.attnum AND des.classoid='pg_class'::regclass)
LEFT OUTER JOIN (pg_depend JOIN pg_class cs ON classid='pg_class'::regclass AND objid=cs.oid AND cs.relkind='S') ON refobjid=att.attrelid AND refobjsubid=att.attnum
LEFT OUTER JOIN pg_namespace ns ON ns.oid=cs.relnamespace
LEFT OUTER JOIN pg_index pi ON pi.indrelid=att.attrelid AND indisprimary
LEFT OUTER JOIN pg_collation coll ON att.attcollation=coll.oid
LEFT OUTER JOIN pg_namespace nspc ON coll.collnamespace=nspc.oid
WHERE att.attrelid = {{tid}}::oid
{% if clid %}
AND att.attnum = {{clid}}::int
{% endif %}
{### To show system objects ###}
{% if not show_sys_objects %}
AND att.attnum > 0
{% endif %}
AND att.attisdropped IS FALSE
ORDER BY att.attnum

View File

@ -1,34 +1 @@
SELECT 'attacl' as deftype, COALESCE(gt.rolname, 'PUBLIC') grantee, g.rolname grantor, array_agg(privilege_type) as privileges, array_agg(is_grantable) as grantable
FROM
(SELECT
d.grantee, d.grantor, d.is_grantable,
CASE d.privilege_type
WHEN 'CONNECT' THEN 'c'
WHEN 'CREATE' THEN 'C'
WHEN 'DELETE' THEN 'd'
WHEN 'EXECUTE' THEN 'X'
WHEN 'INSERT' THEN 'a'
WHEN 'REFERENCES' THEN 'x'
WHEN 'SELECT' THEN 'r'
WHEN 'TEMPORARY' THEN 'T'
WHEN 'TRIGGER' THEN 't'
WHEN 'TRUNCATE' THEN 'D'
WHEN 'UPDATE' THEN 'w'
WHEN 'USAGE' THEN 'U'
ELSE 'UNKNOWN'
END AS privilege_type
FROM
(SELECT attacl
FROM pg_attribute att
WHERE att.attrelid = {{tid}}::oid
AND att.attnum = {{clid}}::int
) acl,
(SELECT (d).grantee AS grantee, (d).grantor AS grantor, (d).is_grantable
AS is_grantable, (d).privilege_type AS privilege_type FROM (SELECT
aclexplode(attacl) as d FROM pg_attribute att
WHERE att.attrelid = {{tid}}::oid
AND att.attnum = {{clid}}::int) a) d
) d
LEFT JOIN pg_catalog.pg_roles g ON (d.grantor = g.oid)
LEFT JOIN pg_catalog.pg_roles gt ON (d.grantee = gt.oid)
GROUP BY g.rolname, gt.rolname
SELECT NULL LIMIT 0

View File

@ -4,21 +4,14 @@ SELECT att.attname as name, att.*, def.*, pg_catalog.pg_get_expr(def.adbin, def.
format_type(ty.oid,att.atttypmod) AS displaytypname,
tn.nspname as typnspname, et.typname as elemtypname,
ty.typstorage AS defaultstorage, cl.relname, na.nspname,
concat(quote_ident(na.nspname) ,'.', quote_ident(cl.relname)) AS parent_tbl,
quote_ident(na.nspname) || '.' || quote_ident(cl.relname) AS parent_tbl,
att.attstattarget, description, cs.relname AS sername,
ns.nspname AS serschema,
(SELECT count(1) FROM pg_type t2 WHERE t2.typname=ty.typname) > 1 AS isdup,
indkey, coll.collname, nspc.nspname as collnspname , attoptions,
-- Start pgAdmin4, added to save time on client side parsing
CASE WHEN length(coll.collname) > 0 AND length(nspc.nspname) > 0 THEN
concat(quote_ident(nspc.nspname),'.',quote_ident(coll.collname))
ELSE '' END AS collspcname,
CASE WHEN strpos(format_type(ty.oid,att.atttypmod), '.') > 0 THEN
split_part(format_type(ty.oid,att.atttypmod), '.', 2)
ELSE format_type(ty.oid,att.atttypmod) END AS cltype,
-- End pgAdmin4
indkey, NULL as attoptions,
format_type(ty.oid,att.atttypmod) AS cltype,
EXISTS(SELECT 1 FROM pg_constraint WHERE conrelid=att.attrelid AND contype='f' AND att.attnum=ANY(conkey)) As is_fk,
(SELECT array_agg(provider || '=' || label) FROM pg_seclabels sl1 WHERE sl1.objoid=att.attrelid AND sl1.objsubid=att.attnum) AS seclabels,
NULL AS seclabels,
(CASE WHEN (att.attnum < 1) THEN true ElSE false END) AS is_sys_column
FROM pg_attribute att
JOIN pg_type ty ON ty.oid=atttypid
@ -31,8 +24,6 @@ FROM pg_attribute att
LEFT OUTER JOIN (pg_depend JOIN pg_class cs ON classid='pg_class'::regclass AND objid=cs.oid AND cs.relkind='S') ON refobjid=att.attrelid AND refobjsubid=att.attnum
LEFT OUTER JOIN pg_namespace ns ON ns.oid=cs.relnamespace
LEFT OUTER JOIN pg_index pi ON pi.indrelid=att.attrelid AND indisprimary
LEFT OUTER JOIN pg_collation coll ON att.attcollation=coll.oid
LEFT OUTER JOIN pg_namespace nspc ON coll.collnamespace=nspc.oid
WHERE att.attrelid = {{tid}}::oid
{% if clid %}
AND att.attnum = {{clid}}::int

View File

@ -0,0 +1,47 @@
import os
import sys
from pgadmin.utils.driver import DriverRegistry
from regression.python_test_utils.template_helper import file_as_template
DriverRegistry.load_drivers()
from pgadmin.utils.route import BaseTestGenerator
from regression import test_utils
if sys.version_info[0] >= 3:
long = int
class TestColumnAcl(BaseTestGenerator):
def runTest(self):
""" When there are no permissions on the column, it returns an empty result """
with test_utils.Database(self.server) as (connection, database_name):
test_utils.create_table(self.server, database_name, "test_table")
cursor = connection.cursor()
cursor.execute("SELECT pg_class.oid as table_id, "
"pg_attribute.attnum as column_id "
"FROM pg_class join pg_attribute on attrelid=pg_class.oid "
"where pg_class.relname='test_table'"
" and pg_attribute.attname = 'some_column'")
table_id, column_id = cursor.fetchone()
if connection.server_version < 90100:
self.versions_to_test = ['default']
else:
self.versions_to_test = ['9.1_plus']
for version in self.versions_to_test:
template_file = os.path.join(os.path.dirname(__file__), "..", version, "acl.sql")
template = file_as_template(template_file)
public_schema_id = 2200
sql = template.render(scid=public_schema_id,
tid=table_id,
clid=column_id
)
cursor = connection.cursor()
cursor.execute(sql)
fetch_result = cursor.fetchall()
self.assertEqual(0, len(fetch_result))

View File

@ -0,0 +1,56 @@
##########################################################################
#
# pgAdmin 4 - PostgreSQL Tools
#
# Copyright (C) 2013 - 2017, The pgAdmin Development Team
# This software is released under the PostgreSQL Licence
#
##########################################################################
import os
import sys
from pgadmin.utils.driver import DriverRegistry
from regression.python_test_utils.template_helper import file_as_template
DriverRegistry.load_drivers()
from pgadmin.utils.route import BaseTestGenerator
from regression import test_utils
if sys.version_info[0] >= 3:
long = int
class TestColumnProperties(BaseTestGenerator):
def runTest(self):
""" This tests that column properties are returned"""
with test_utils.Database(self.server) as (connection, database_name):
test_utils.create_table(self.server, database_name, "test_table")
cursor = connection.cursor()
cursor.execute("SELECT oid FROM pg_class where relname='test_table'")
table_id = cursor.fetchone()[0]
if connection.server_version < 90100:
self.versions_to_test = ['default']
else:
self.versions_to_test = ['9.1_plus']
for version in self.versions_to_test:
template_file = os.path.join(os.path.dirname(__file__), "..", version, "properties.sql")
template = file_as_template(template_file)
public_schema_id = 2200
sql = template.render(scid=public_schema_id,
tid=table_id
)
cursor = connection.cursor()
cursor.execute(sql)
fetch_result = cursor.fetchall()
first_row = {}
for index, description in enumerate(cursor.description):
first_row[description.name] = fetch_result[0][index]
self.assertEqual('some_column', first_row['name'])
self.assertEqual('character varying', first_row['cltype'])
self.assertEqual(2, len(fetch_result))

View File

@ -0,0 +1,31 @@
SELECT ct.oid,
conname as name,
condeferrable,
condeferred,
confupdtype,
confdeltype,
CASE confmatchtype
WHEN 's' THEN FALSE
WHEN 'f' THEN TRUE
END AS confmatchtype,
conkey,
confkey,
confrelid,
nl.nspname as fknsp,
cl.relname as fktab,
nr.nspname as refnsp,
cr.relname as reftab,
description as comment,
NOT convalidated as convalidated
FROM pg_constraint ct
JOIN pg_class cl ON cl.oid=conrelid
JOIN pg_namespace nl ON nl.oid=cl.relnamespace
JOIN pg_class cr ON cr.oid=confrelid
JOIN pg_namespace nr ON nr.oid=cr.relnamespace
LEFT OUTER JOIN pg_description des ON (des.objoid=ct.oid AND des.classoid='pg_constraint'::regclass)
WHERE contype='f' AND
conrelid = {{tid}}::oid
{% if cid %}
AND ct.oid = {{cid}}::oid
{% endif %}
ORDER BY conname

View File

@ -1,4 +1,6 @@
SELECT ct.oid,
SELECT
FALSE as convalidated,
ct.oid,
conname as name,
condeferrable,
condeferred,
@ -15,8 +17,7 @@ SELECT ct.oid,
cl.relname as fktab,
nr.nspname as refnsp,
cr.relname as reftab,
description as comment,
NOT convalidated as convalidated
description as comment
FROM pg_constraint ct
JOIN pg_class cl ON cl.oid=conrelid
JOIN pg_namespace nl ON nl.oid=cl.relnamespace

View File

@ -0,0 +1,54 @@
##########################################################################
#
# pgAdmin 4 - PostgreSQL Tools
#
# Copyright (C) 2013 - 2017, The pgAdmin Development Team
# This software is released under the PostgreSQL Licence
#
##########################################################################
import os
import sys
from pgadmin.utils.driver import DriverRegistry
from regression.python_test_utils.template_helper import file_as_template
DriverRegistry.load_drivers()
from pgadmin.utils.route import BaseTestGenerator
from regression import test_utils
if sys.version_info[0] >= 3:
long = int
class TestColumnForeignKeyGetConstraintCols(BaseTestGenerator):
def runTest(self):
""" When there are no foreign key properties on the column, it returns an empty result """
with test_utils.Database(self.server) as (connection, database_name):
test_utils.create_table(self.server, database_name, "test_table")
cursor = connection.cursor()
cursor.execute("SELECT pg_class.oid as table_id, "
"pg_attribute.attnum as column_id "
"FROM pg_class join pg_attribute on attrelid=pg_class.oid "
"where pg_class.relname='test_table'"
" and pg_attribute.attname = 'some_column'")
table_id, column_id = cursor.fetchone()
if connection.server_version < 90100:
self.versions_to_test = ['default']
else:
self.versions_to_test = ['9.1_plus']
for version in self.versions_to_test:
template_file = os.path.join(os.path.dirname(__file__), "..", version, "properties.sql")
template = file_as_template(template_file)
sql = template.render(
tid=table_id,
cid=column_id)
cursor = connection.cursor()
cursor.execute(sql)
fetch_result = cursor.fetchall()
self.assertEqual(0, len(fetch_result))

View File

@ -0,0 +1,46 @@
{### SQL to fetch privileges for tablespace ###}
SELECT 'relacl' as deftype, COALESCE(gt.rolname, 'PUBLIC') grantee, g.rolname grantor,
array_agg(privilege_type) as privileges, array_agg(is_grantable) as grantable
FROM
(SELECT
d.grantee, d.grantor, d.is_grantable,
CASE d.privilege_type
WHEN 'CONNECT' THEN 'c'
WHEN 'CREATE' THEN 'C'
WHEN 'DELETE' THEN 'd'
WHEN 'EXECUTE' THEN 'X'
WHEN 'INSERT' THEN 'a'
WHEN 'REFERENCES' THEN 'x'
WHEN 'SELECT' THEN 'r'
WHEN 'TEMPORARY' THEN 'T'
WHEN 'TRIGGER' THEN 't'
WHEN 'TRUNCATE' THEN 'D'
WHEN 'UPDATE' THEN 'w'
WHEN 'USAGE' THEN 'U'
ELSE 'UNKNOWN'
END AS privilege_type
FROM
(SELECT rel.relacl
FROM pg_class rel
LEFT OUTER JOIN pg_tablespace spc on spc.oid=rel.reltablespace
LEFT OUTER JOIN pg_constraint con ON con.conrelid=rel.oid AND con.contype='p'
LEFT OUTER JOIN pg_class tst ON tst.oid = rel.reltoastrelid
LEFT JOIN pg_type typ ON rel.reloftype=typ.oid
WHERE rel.relkind IN ('r','s','t') AND rel.relnamespace = {{ scid }}::oid
AND rel.oid = {{ tid }}::oid
) acl,
(SELECT (d).grantee AS grantee, (d).grantor AS grantor, (d).is_grantable
AS is_grantable, (d).privilege_type AS privilege_type FROM (SELECT
aclexplode(rel.relacl) as d
FROM pg_class rel
LEFT OUTER JOIN pg_tablespace spc on spc.oid=rel.reltablespace
LEFT OUTER JOIN pg_constraint con ON con.conrelid=rel.oid AND con.contype='p'
LEFT OUTER JOIN pg_class tst ON tst.oid = rel.reltoastrelid
LEFT JOIN pg_type typ ON rel.reloftype=typ.oid
WHERE rel.relkind IN ('r','s','t') AND rel.relnamespace = {{ scid }}::oid
AND rel.oid = {{ tid }}::oid
) a) d
) d
LEFT JOIN pg_catalog.pg_roles g ON (d.grantor = g.oid)
LEFT JOIN pg_catalog.pg_roles gt ON (d.grantee = gt.oid)
GROUP BY g.rolname, gt.rolname

View File

@ -0,0 +1,69 @@
SELECT rel.oid, rel.relname AS name, rel.reltablespace AS spcoid,rel.relacl AS relacl_str,
(CASE WHEN length(spc.spcname) > 0 THEN spc.spcname ELSE
(SELECT sp.spcname FROM pg_database dtb
JOIN pg_tablespace sp ON dtb.dattablespace=sp.oid
WHERE dtb.oid = {{ did }}::oid)
END) as spcname,
(select nspname FROM pg_namespace WHERE oid = {{scid}}::oid ) as schema,
pg_get_userbyid(rel.relowner) AS relowner, rel.relhasoids,
rel.relhassubclass, rel.reltuples, des.description, con.conname, con.conkey,
EXISTS(select 1 FROM pg_trigger
JOIN pg_proc pt ON pt.oid=tgfoid AND pt.proname='logtrigger'
JOIN pg_proc pc ON pc.pronamespace=pt.pronamespace AND pc.proname='slonyversion'
WHERE tgrelid=rel.oid) AS isrepl,
(SELECT count(*) FROM pg_trigger WHERE tgrelid=rel.oid AND tgisinternal = FALSE) AS triggercount,
(SELECT ARRAY(SELECT CASE WHEN (nspname NOT LIKE E'pg\_%') THEN
quote_ident(nspname)||'.'||quote_ident(c.relname)
ELSE quote_ident(c.relname) END AS inherited_tables
FROM pg_inherits i
JOIN pg_class c ON c.oid = i.inhparent
JOIN pg_namespace n ON n.oid=c.relnamespace
WHERE i.inhrelid = rel.oid ORDER BY inhseqno)) AS coll_inherits,
(SELECT count(*)
FROM pg_inherits i
JOIN pg_class c ON c.oid = i.inhparent
JOIN pg_namespace n ON n.oid=c.relnamespace
WHERE i.inhrelid = rel.oid) AS inherited_tables_cnt,
(CASE WHEN rel.relpersistence = 'u' THEN true ELSE false END) AS relpersistence,
substring(array_to_string(rel.reloptions, ',') FROM 'fillfactor=([0-9]*)') AS fillfactor,
(CASE WHEN (substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)') = 'true')
THEN true ELSE false END) AS autovacuum_enabled,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_vacuum_threshold=([0-9]*)') AS autovacuum_vacuum_threshold,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_vacuum_scale_factor=([0-9]*[.][0-9]*)') AS autovacuum_vacuum_scale_factor,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_analyze_threshold=([0-9]*)') AS autovacuum_analyze_threshold,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_analyze_scale_factor=([0-9]*[.][0-9]*)') AS autovacuum_analyze_scale_factor,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_vacuum_cost_delay=([0-9]*)') AS autovacuum_vacuum_cost_delay,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_vacuum_cost_limit=([0-9]*)') AS autovacuum_vacuum_cost_limit,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_freeze_min_age=([0-9]*)') AS autovacuum_freeze_min_age,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_freeze_max_age=([0-9]*)') AS autovacuum_freeze_max_age,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_freeze_table_age=([0-9]*)') AS autovacuum_freeze_table_age,
(CASE WHEN (substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)') = 'true')
THEN true ELSE false END) AS toast_autovacuum_enabled,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_vacuum_threshold=([0-9]*)') AS toast_autovacuum_vacuum_threshold,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_vacuum_scale_factor=([0-9]*[.][0-9]*)') AS toast_autovacuum_vacuum_scale_factor,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_analyze_threshold=([0-9]*)') AS toast_autovacuum_analyze_threshold,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_analyze_scale_factor=([0-9]*[.][0-9]*)') AS toast_autovacuum_analyze_scale_factor,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_vacuum_cost_delay=([0-9]*)') AS toast_autovacuum_vacuum_cost_delay,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_vacuum_cost_limit=([0-9]*)') AS toast_autovacuum_vacuum_cost_limit,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_freeze_min_age=([0-9]*)') AS toast_autovacuum_freeze_min_age,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_freeze_max_age=([0-9]*)') AS toast_autovacuum_freeze_max_age,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_freeze_table_age=([0-9]*)') AS toast_autovacuum_freeze_table_age,
array_to_string(rel.reloptions, ',') AS table_vacuum_settings_str,
array_to_string(tst.reloptions, ',') AS toast_table_vacuum_settings_str,
rel.reloptions AS reloptions, tst.reloptions AS toast_reloptions, rel.reloftype, typ.typname,
(CASE WHEN rel.reltoastrelid = 0 THEN false ELSE true END) AS hastoasttable,
-- Added for pgAdmin4
(CASE WHEN (substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)'))::boolean THEN true ELSE false END) AS autovacuum_custom,
(CASE WHEN (substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)'))::boolean AND rel.reltoastrelid != 0 THEN true ELSE false END) AS toast_autovacuum,
(SELECT array_agg(provider || '=' || label) FROM pg_seclabels sl1 WHERE sl1.objoid=rel.oid AND sl1.objsubid=0) AS seclabels,
(CASE WHEN rel.oid <= {{ datlastsysoid}}::oid THEN true ElSE false END) AS is_sys_table
FROM pg_class rel
LEFT OUTER JOIN pg_tablespace spc on spc.oid=rel.reltablespace
LEFT OUTER JOIN pg_description des ON (des.objoid=rel.oid AND des.objsubid=0 AND des.classoid='pg_class'::regclass)
LEFT OUTER JOIN pg_constraint con ON con.conrelid=rel.oid AND con.contype='p'
LEFT OUTER JOIN pg_class tst ON tst.oid = rel.reltoastrelid
LEFT JOIN pg_type typ ON rel.reloftype=typ.oid
WHERE rel.relkind IN ('r','s','t') AND rel.relnamespace = {{ scid }}::oid
{% if tid %} AND rel.oid = {{ tid }}::oid {% endif %}
ORDER BY rel.relname;

View File

@ -1,46 +1,35 @@
{### SQL to fetch privileges for tablespace ###}
SELECT 'relacl' as deftype, COALESCE(gt.rolname, 'PUBLIC') grantee, g.rolname grantor,
SELECT 'relacl' as deftype, privileges_information.grantee, privileges_information.grantor,
array_agg(privilege_type) as privileges, array_agg(is_grantable) as grantable
FROM
(SELECT
d.grantee, d.grantor, d.is_grantable,
CASE d.privilege_type
WHEN 'CONNECT' THEN 'c'
WHEN 'CREATE' THEN 'C'
WHEN 'DELETE' THEN 'd'
WHEN 'EXECUTE' THEN 'X'
WHEN 'INSERT' THEN 'a'
WHEN 'REFERENCES' THEN 'x'
WHEN 'SELECT' THEN 'r'
WHEN 'TEMPORARY' THEN 'T'
WHEN 'TRIGGER' THEN 't'
WHEN 'TRUNCATE' THEN 'D'
WHEN 'UPDATE' THEN 'w'
WHEN 'USAGE' THEN 'U'
ELSE 'UNKNOWN'
END AS privilege_type
FROM
(SELECT rel.relacl
FROM pg_class rel
LEFT OUTER JOIN pg_tablespace spc on spc.oid=rel.reltablespace
LEFT OUTER JOIN pg_constraint con ON con.conrelid=rel.oid AND con.contype='p'
LEFT OUTER JOIN pg_class tst ON tst.oid = rel.reltoastrelid
LEFT JOIN pg_type typ ON rel.reloftype=typ.oid
WHERE rel.relkind IN ('r','s','t') AND rel.relnamespace = {{ scid }}::oid
AND rel.oid = {{ tid }}::oid
) acl,
(SELECT (d).grantee AS grantee, (d).grantor AS grantor, (d).is_grantable
AS is_grantable, (d).privilege_type AS privilege_type FROM (SELECT
aclexplode(rel.relacl) as d
FROM pg_class rel
LEFT OUTER JOIN pg_tablespace spc on spc.oid=rel.reltablespace
LEFT OUTER JOIN pg_constraint con ON con.conrelid=rel.oid AND con.contype='p'
LEFT OUTER JOIN pg_class tst ON tst.oid = rel.reltoastrelid
LEFT JOIN pg_type typ ON rel.reloftype=typ.oid
WHERE rel.relkind IN ('r','s','t') AND rel.relnamespace = {{ scid }}::oid
AND rel.oid = {{ tid }}::oid
) a) d
) d
LEFT JOIN pg_catalog.pg_roles g ON (d.grantor = g.oid)
LEFT JOIN pg_catalog.pg_roles gt ON (d.grantee = gt.oid)
GROUP BY g.rolname, gt.rolname
from (
SELECT
acls.grantee, acls.grantor, CASE WHEN acls.is_grantable = 'YES' THEN TRUE ELSE FALSE END as is_grantable,
CASE acls.privilege_type
WHEN 'CONNECT' THEN 'c'
WHEN 'CREATE' THEN 'C'
WHEN 'DELETE' THEN 'd'
WHEN 'EXECUTE' THEN 'X'
WHEN 'INSERT' THEN 'a'
WHEN 'REFERENCES' THEN 'x'
WHEN 'SELECT' THEN 'r'
WHEN 'TEMPORARY' THEN 'T'
WHEN 'TRIGGER' THEN 't'
WHEN 'TRUNCATE' THEN 'D'
WHEN 'UPDATE' THEN 'w'
WHEN 'USAGE' THEN 'U'
ELSE 'UNKNOWN'
END AS privilege_type
FROM
(SELECT rel.relacl, rel.relname
FROM pg_class rel
LEFT OUTER JOIN pg_tablespace spc on spc.oid=rel.reltablespace
LEFT OUTER JOIN pg_constraint con ON con.conrelid=rel.oid AND con.contype='p'
LEFT OUTER JOIN pg_class tst ON tst.oid = rel.reltoastrelid
WHERE rel.relkind IN ('r','s','t') AND rel.relnamespace = {{ scid }}::oid
AND rel.oid = {{ tid }}::OID
) rel
LEFT JOIN information_schema.table_privileges acls ON (table_name = rel.relname)
) as privileges_information
GROUP BY privileges_information.grantee,privileges_information.grantor
ORDER BY privileges_information.grantee

View File

@ -1,69 +1,74 @@
SELECT rel.oid, rel.relname AS name, rel.reltablespace AS spcoid,rel.relacl AS relacl_str,
(CASE WHEN length(spc.spcname) > 0 THEN spc.spcname ELSE
(SELECT sp.spcname FROM pg_database dtb
JOIN pg_tablespace sp ON dtb.dattablespace=sp.oid
WHERE dtb.oid = {{ did }}::oid)
END) as spcname,
(select nspname FROM pg_namespace WHERE oid = {{scid}}::oid ) as schema,
pg_get_userbyid(rel.relowner) AS relowner, rel.relhasoids,
rel.relhassubclass, rel.reltuples, des.description, con.conname, con.conkey,
EXISTS(select 1 FROM pg_trigger
JOIN pg_proc pt ON pt.oid=tgfoid AND pt.proname='logtrigger'
JOIN pg_proc pc ON pc.pronamespace=pt.pronamespace AND pc.proname='slonyversion'
WHERE tgrelid=rel.oid) AS isrepl,
(SELECT count(*) FROM pg_trigger WHERE tgrelid=rel.oid AND tgisinternal = FALSE) AS triggercount,
(SELECT ARRAY(SELECT CASE WHEN (nspname NOT LIKE E'pg\_%') THEN
quote_ident(nspname)||'.'||quote_ident(c.relname)
ELSE quote_ident(c.relname) END AS inherited_tables
FROM pg_inherits i
JOIN pg_class c ON c.oid = i.inhparent
JOIN pg_namespace n ON n.oid=c.relnamespace
WHERE i.inhrelid = rel.oid ORDER BY inhseqno)) AS coll_inherits,
(SELECT count(*)
FROM pg_inherits i
JOIN pg_class c ON c.oid = i.inhparent
JOIN pg_namespace n ON n.oid=c.relnamespace
WHERE i.inhrelid = rel.oid) AS inherited_tables_cnt,
(CASE WHEN rel.relpersistence = 'u' THEN true ELSE false END) AS relpersistence,
substring(array_to_string(rel.reloptions, ',') FROM 'fillfactor=([0-9]*)') AS fillfactor,
(CASE WHEN (substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)') = 'true')
THEN true ELSE false END) AS autovacuum_enabled,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_vacuum_threshold=([0-9]*)') AS autovacuum_vacuum_threshold,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_vacuum_scale_factor=([0-9]*[.][0-9]*)') AS autovacuum_vacuum_scale_factor,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_analyze_threshold=([0-9]*)') AS autovacuum_analyze_threshold,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_analyze_scale_factor=([0-9]*[.][0-9]*)') AS autovacuum_analyze_scale_factor,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_vacuum_cost_delay=([0-9]*)') AS autovacuum_vacuum_cost_delay,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_vacuum_cost_limit=([0-9]*)') AS autovacuum_vacuum_cost_limit,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_freeze_min_age=([0-9]*)') AS autovacuum_freeze_min_age,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_freeze_max_age=([0-9]*)') AS autovacuum_freeze_max_age,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_freeze_table_age=([0-9]*)') AS autovacuum_freeze_table_age,
(CASE WHEN (substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)') = 'true')
THEN true ELSE false END) AS toast_autovacuum_enabled,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_vacuum_threshold=([0-9]*)') AS toast_autovacuum_vacuum_threshold,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_vacuum_scale_factor=([0-9]*[.][0-9]*)') AS toast_autovacuum_vacuum_scale_factor,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_analyze_threshold=([0-9]*)') AS toast_autovacuum_analyze_threshold,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_analyze_scale_factor=([0-9]*[.][0-9]*)') AS toast_autovacuum_analyze_scale_factor,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_vacuum_cost_delay=([0-9]*)') AS toast_autovacuum_vacuum_cost_delay,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_vacuum_cost_limit=([0-9]*)') AS toast_autovacuum_vacuum_cost_limit,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_freeze_min_age=([0-9]*)') AS toast_autovacuum_freeze_min_age,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_freeze_max_age=([0-9]*)') AS toast_autovacuum_freeze_max_age,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_freeze_table_age=([0-9]*)') AS toast_autovacuum_freeze_table_age,
array_to_string(rel.reloptions, ',') AS table_vacuum_settings_str,
array_to_string(tst.reloptions, ',') AS toast_table_vacuum_settings_str,
rel.reloptions AS reloptions, tst.reloptions AS toast_reloptions, rel.reloftype, typ.typname,
(CASE WHEN rel.reltoastrelid = 0 THEN false ELSE true END) AS hastoasttable,
-- Added for pgAdmin4
(CASE WHEN (substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)'))::boolean THEN true ELSE false END) AS autovacuum_custom,
(CASE WHEN (substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)'))::boolean AND rel.reltoastrelid != 0 THEN true ELSE false END) AS toast_autovacuum,
SELECT *,
(CASE when pre_coll_inherits is NULL then ARRAY[]::varchar[] else pre_coll_inherits END) as coll_inherits
FROM (
SELECT rel.oid, rel.relname AS name, rel.reltablespace AS spcoid,rel.relacl AS relacl_str,
(CASE WHEN length(spc.spcname) > 0 THEN spc.spcname ELSE
(SELECT sp.spcname FROM pg_database dtb
JOIN pg_tablespace sp ON dtb.dattablespace=sp.oid
WHERE dtb.oid = {{ did }}::oid)
END) as spcname,
(select nspname FROM pg_namespace WHERE oid = {{scid}}::oid ) as schema,
pg_get_userbyid(rel.relowner) AS relowner, rel.relhasoids,
rel.relhassubclass, rel.reltuples, des.description, con.conname, con.conkey,
EXISTS(select 1 FROM pg_trigger
JOIN pg_proc pt ON pt.oid=tgfoid AND pt.proname='logtrigger'
JOIN pg_proc pc ON pc.pronamespace=pt.pronamespace AND pc.proname='slonyversion'
WHERE tgrelid=rel.oid) AS isrepl,
(SELECT count(*) FROM pg_trigger WHERE tgrelid=rel.oid) AS triggercount,
(SELECT ARRAY(SELECT CASE WHEN (nspname NOT LIKE E'pg\_%') THEN
quote_ident(nspname)||'.'||quote_ident(c.relname)
ELSE quote_ident(c.relname) END AS inherited_tables
FROM pg_inherits i
JOIN pg_class c ON c.oid = i.inhparent
JOIN pg_namespace n ON n.oid=c.relnamespace
WHERE i.inhrelid = rel.oid ORDER BY inhseqno)) AS pre_coll_inherits,
(SELECT count(*)
FROM pg_inherits i
JOIN pg_class c ON c.oid = i.inhparent
JOIN pg_namespace n ON n.oid=c.relnamespace
WHERE i.inhrelid = rel.oid) AS inherited_tables_cnt,
false AS relpersistence,
substring(array_to_string(rel.reloptions, ',') FROM 'fillfactor=([0-9]*)') AS fillfactor,
(CASE WHEN (substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)') = 'true')
THEN true ELSE false END) AS autovacuum_enabled,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_vacuum_threshold=([0-9]*)') AS autovacuum_vacuum_threshold,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_vacuum_scale_factor=([0-9]*[.][0-9]*)') AS autovacuum_vacuum_scale_factor,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_analyze_threshold=([0-9]*)') AS autovacuum_analyze_threshold,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_analyze_scale_factor=([0-9]*[.][0-9]*)') AS autovacuum_analyze_scale_factor,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_vacuum_cost_delay=([0-9]*)') AS autovacuum_vacuum_cost_delay,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_vacuum_cost_limit=([0-9]*)') AS autovacuum_vacuum_cost_limit,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_freeze_min_age=([0-9]*)') AS autovacuum_freeze_min_age,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_freeze_max_age=([0-9]*)') AS autovacuum_freeze_max_age,
substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_freeze_table_age=([0-9]*)') AS autovacuum_freeze_table_age,
(CASE WHEN (substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)') = 'true')
THEN true ELSE false END) AS toast_autovacuum_enabled,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_vacuum_threshold=([0-9]*)') AS toast_autovacuum_vacuum_threshold,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_vacuum_scale_factor=([0-9]*[.][0-9]*)') AS toast_autovacuum_vacuum_scale_factor,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_analyze_threshold=([0-9]*)') AS toast_autovacuum_analyze_threshold,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_analyze_scale_factor=([0-9]*[.][0-9]*)') AS toast_autovacuum_analyze_scale_factor,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_vacuum_cost_delay=([0-9]*)') AS toast_autovacuum_vacuum_cost_delay,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_vacuum_cost_limit=([0-9]*)') AS toast_autovacuum_vacuum_cost_limit,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_freeze_min_age=([0-9]*)') AS toast_autovacuum_freeze_min_age,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_freeze_max_age=([0-9]*)') AS toast_autovacuum_freeze_max_age,
substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_freeze_table_age=([0-9]*)') AS toast_autovacuum_freeze_table_age,
array_to_string(rel.reloptions, ',') AS table_vacuum_settings_str,
array_to_string(tst.reloptions, ',') AS toast_table_vacuum_settings_str,
rel.reloptions AS reloptions, tst.reloptions AS toast_reloptions, NULL AS reloftype, NULL AS typname,
(CASE WHEN rel.reltoastrelid = 0 THEN false ELSE true END) AS hastoasttable,
-- Added for pgAdmin4
(CASE WHEN (substring(array_to_string(rel.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)'))::boolean THEN true ELSE false END) AS autovacuum_custom,
(CASE WHEN (substring(array_to_string(tst.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)'))::boolean AND rel.reltoastrelid != 0 THEN true ELSE false END) AS toast_autovacuum,
(SELECT array_agg(provider || '=' || label) FROM pg_seclabels sl1 WHERE sl1.objoid=rel.oid AND sl1.objsubid=0) AS seclabels,
(CASE WHEN rel.oid <= {{ datlastsysoid}}::oid THEN true ElSE false END) AS is_sys_table
FROM pg_class rel
LEFT OUTER JOIN pg_tablespace spc on spc.oid=rel.reltablespace
LEFT OUTER JOIN pg_description des ON (des.objoid=rel.oid AND des.objsubid=0 AND des.classoid='pg_class'::regclass)
LEFT OUTER JOIN pg_constraint con ON con.conrelid=rel.oid AND con.contype='p'
LEFT OUTER JOIN pg_class tst ON tst.oid = rel.reltoastrelid
LEFT JOIN pg_type typ ON rel.reloftype=typ.oid
WHERE rel.relkind IN ('r','s','t') AND rel.relnamespace = {{ scid }}::oid
{% if tid %} AND rel.oid = {{ tid }}::oid {% endif %}
ORDER BY rel.relname;
ARRAY[]::varchar[] AS seclabels,
(CASE WHEN rel.oid <= {{ datlastsysoid}}::oid THEN true ElSE false END) AS is_sys_table
FROM pg_class rel
LEFT OUTER JOIN pg_tablespace spc on spc.oid=rel.reltablespace
LEFT OUTER JOIN pg_description des ON (des.objoid=rel.oid AND des.objsubid=0 AND des.classoid='pg_class'::regclass)
LEFT OUTER JOIN pg_constraint con ON con.conrelid=rel.oid AND con.contype='p'
LEFT OUTER JOIN pg_class tst ON tst.oid = rel.reltoastrelid
WHERE rel.relkind IN ('r','s','t') AND rel.relnamespace = {{ scid }}
{% if tid %} AND rel.oid = {{ tid }}::oid {% endif %}
) AS TableInformation
ORDER BY name

View File

@ -0,0 +1,61 @@
##########################################################################
#
# pgAdmin 4 - PostgreSQL Tools
#
# Copyright (C) 2013 - 2017, The pgAdmin Development Team
# This software is released under the PostgreSQL Licence
#
##########################################################################
import os
import sys
from pgadmin.utils.driver import DriverRegistry
from regression.python_test_utils.template_helper import file_as_template
DriverRegistry.load_drivers()
from pgadmin.utils.route import BaseTestGenerator
from regression import test_utils
if sys.version_info[0] >= 3:
long = int
class TestTablesAcl(BaseTestGenerator):
def runTest(self):
""" This tests that when there are permissions set up on the table, acl query returns the permissions"""
with test_utils.Database(self.server) as (connection, database_name):
test_utils.create_table(self.server, database_name, "test_table")
cursor = connection.cursor()
cursor.execute("GRANT SELECT ON test_table TO PUBLIC")
cursor = connection.cursor()
cursor.execute("SELECT oid FROM pg_class WHERE relname='test_table'")
table_id = cursor.fetchone()[0]
if connection.server_version < 90100:
self.versions_to_test = ['default']
else:
self.versions_to_test = ['9.1_plus']
for version in self.versions_to_test:
template_file = os.path.join(os.path.dirname(__file__), "..", version, "acl.sql")
template = file_as_template(template_file)
public_schema_id = 2200
sql = template.render(scid=public_schema_id,
tid=table_id)
cursor = connection.cursor()
cursor.execute(sql)
fetch_result = cursor.fetchall()
public_acls = filter(lambda (acl): acl[1] == 'PUBLIC', fetch_result)
self.assertEqual(len(public_acls), 1)
new_acl_map = dict(zip(map(lambda (column): column.name, cursor.description), public_acls[0]))
self.assertEqual('PUBLIC', new_acl_map['grantee'])
self.assertEqual(self.server['username'], new_acl_map['grantor'])
self.assertEqual('relacl', new_acl_map['deftype'])
self.assertEqual(['r'], new_acl_map['privileges'])
self.assertEqual([False], new_acl_map['grantable'])

View File

@ -1,3 +1,12 @@
##########################################################################
#
# pgAdmin 4 - PostgreSQL Tools
#
# Copyright (C) 2013 - 2017, The pgAdmin Development Team
# This software is released under the PostgreSQL Licence
#
##########################################################################
import os
import sys

View File

@ -0,0 +1,72 @@
##########################################################################
#
# pgAdmin 4 - PostgreSQL Tools
#
# Copyright (C) 2013 - 2017, The pgAdmin Development Team
# This software is released under the PostgreSQL Licence
#
##########################################################################
import os
import sys
from pgadmin.utils.driver import DriverRegistry
from regression.python_test_utils.template_helper import file_as_template
DriverRegistry.load_drivers()
from pgadmin.utils.route import BaseTestGenerator
from regression import test_utils
if sys.version_info[0] >= 3:
long = int
class TestTablesProperties(BaseTestGenerator):
def runTest(self):
""" This tests that all applicable sql template versions can fetch some ddl """
with test_utils.Database(self.server) as (connection, database_name):
test_utils.create_table(self.server, database_name, "test_table")
cursor = connection.cursor()
cursor.execute(u"""
SELECT
db.oid as did, datlastsysoid
FROM
pg_database db
WHERE db.datname = '{0}'""".format(database_name)
)
database_id, last_system_oid = cursor.fetchone()
cursor = connection.cursor()
cursor.execute("SELECT oid FROM pg_class where relname='test_table'")
table_id = cursor.fetchone()[0]
if connection.server_version < 90100:
self.versions_to_test = ['default']
else:
self.versions_to_test = ['9.1_plus']
for version in self.versions_to_test:
template_file = os.path.join(os.path.dirname(__file__), "..", version, "properties.sql")
template = file_as_template(template_file)
public_schema_id = 2200
sql = template.render(scid=public_schema_id,
did=database_id,
datlastsysoid=last_system_oid,
tid=table_id
)
cursor = connection.cursor()
cursor.execute(sql)
fetch_result = cursor.fetchone()
first_row = {}
for index, description in enumerate(cursor.description):
first_row[description.name] = fetch_result[index]
self.assertEqual('test_table', first_row['name'])
# triggercount is sometimes returned as a string for some reason
self.assertEqual(0, long(first_row['triggercount']))
self.assertEqual(None, first_row['typname'])
self.assertEqual([], first_row['coll_inherits'])

View File

@ -0,0 +1,5 @@
SELECT t.oid
FROM pg_trigger t
WHERE NOT tgisinternal
AND tgrelid = {{tid}}::OID
AND tgname = {{data.name|qtLiteral}};

View File

@ -0,0 +1,9 @@
SELECT t.oid, t.tgname as name, (CASE WHEN tgenabled = 'O' THEN true ElSE false END) AS is_enable_trigger
FROM pg_trigger t
WHERE NOT tgisinternal
AND tgrelid = {{tid}}::OID
{% if trid %}
AND t.oid = {{trid}}::OID
{% endif %}
ORDER BY tgname;

View File

@ -1,5 +1,4 @@
SELECT t.oid
FROM pg_trigger t
WHERE NOT tgisinternal
AND tgrelid = {{tid}}::OID
WHERE tgrelid = {{tid}}::OID
AND tgname = {{data.name|qtLiteral}};

View File

@ -1,7 +1,6 @@
SELECT t.oid, t.tgname as name, (CASE WHEN tgenabled = 'O' THEN true ElSE false END) AS is_enable_trigger
FROM pg_trigger t
WHERE NOT tgisinternal
AND tgrelid = {{tid}}::OID
WHERE tgrelid = {{tid}}::OID
{% if trid %}
AND t.oid = {{trid}}::OID
{% endif %}

View File

@ -0,0 +1,60 @@
##########################################################################
#
# pgAdmin 4 - PostgreSQL Tools
#
# Copyright (C) 2013 - 2017, The pgAdmin Development Team
# This software is released under the PostgreSQL Licence
#
##########################################################################
import os
import sys
import jinja2
from pgadmin.utils.driver import DriverRegistry
from regression.python_test_utils.template_helper import file_as_template
DriverRegistry.load_drivers()
from pgadmin.utils.route import BaseTestGenerator
from regression import test_utils
if sys.version_info[0] >= 3:
long = int
class TestTriggerGetOid(BaseTestGenerator):
def runTest(self):
""" When there are no permissions on the column, it returns an empty result """
with test_utils.Database(self.server) as (connection, database_name):
test_utils.create_table(self.server, database_name, "test_table")
cursor = connection.cursor()
cursor.execute("SELECT pg_class.oid as table_id, "
"pg_attribute.attnum as column_id "
"FROM pg_class join pg_attribute on attrelid=pg_class.oid "
"where pg_class.relname='test_table'"
" and pg_attribute.attname = 'some_column'")
table_id, column_id = cursor.fetchone()
if connection.server_version < 90100:
self.versions_to_test = ['default']
else:
self.versions_to_test = ['9.1_plus']
for version in self.versions_to_test:
template_file = os.path.join(os.path.dirname(__file__), "..", version, "get_oid.sql")
jinja2.filters.FILTERS['qtLiteral'] = lambda value: "NULL"
template = file_as_template(template_file)
sql = template.render(data={'name': None},
tid=table_id
)
cursor = connection.cursor()
cursor.execute(sql)
fetch_result = cursor.fetchall()
self.assertEqual(0, len(fetch_result))

View File

@ -0,0 +1,51 @@
##########################################################################
#
# pgAdmin 4 - PostgreSQL Tools
#
# Copyright (C) 2013 - 2017, The pgAdmin Development Team
# This software is released under the PostgreSQL Licence
#
##########################################################################
import os
import sys
from pgadmin.utils.driver import DriverRegistry
from regression.python_test_utils.template_helper import file_as_template
DriverRegistry.load_drivers()
from pgadmin.utils.route import BaseTestGenerator
from regression import test_utils
if sys.version_info[0] >= 3:
long = int
class TestTriggerNodes(BaseTestGenerator):
def runTest(self):
""" When there are no triggers, it returns an empty result """
with test_utils.Database(self.server) as (connection, database_name):
test_utils.create_table(self.server, database_name, "test_table")
cursor = connection.cursor()
cursor.execute("SELECT pg_class.oid AS table_id "
"FROM pg_class "
"WHERE pg_class.relname='test_table'")
table_id = cursor.fetchone()[0]
if connection.server_version < 90100:
self.versions_to_test = ['default']
else:
self.versions_to_test = ['9.1_plus']
for version in self.versions_to_test:
template_file = os.path.join(os.path.dirname(__file__), "..", version, "nodes.sql")
template = file_as_template(template_file)
sql = template.render(tid=table_id)
cursor = connection.cursor()
cursor.execute(sql)
fetch_result = cursor.fetchall()
self.assertEqual(0, len(fetch_result))

View File

@ -101,7 +101,8 @@ class PgadminPage:
ActionChains(self.driver).send_keys(field_content).perform()
def click_tab(self, tab_name):
self.find_by_xpath("//*[contains(@class,'wcPanelTab') and contains(.,'" + tab_name + "')]").click()
self.find_by_xpath("//*[contains(@class,'wcTabTop')]//*[contains(@class,'wcPanelTab') "
"and contains(.,'" + tab_name + "')]").click()
def wait_for_input_field_content(self, field_name, content):
def input_field_has_content(driver):

View File

@ -0,0 +1,19 @@
from jinja2 import BaseLoader
from jinja2 import Environment
class SimpleTemplateLoader(BaseLoader):
""" This class pretends to load whatever file content it is initialized with"""
def __init__(self, file_content):
self.file_content = file_content
def get_source(self, *args):
return self.file_content, "fake-file-name", True
def file_as_template(file_path):
"""This method returns a jinja template for the given filepath """
file_content = open(file_path, 'r').read()
env = Environment(loader=SimpleTemplateLoader(file_content))
template = env.get_template("")
return template

View File

@ -145,7 +145,7 @@ def create_table(server, db_name, table_name):
old_isolation_level = connection.isolation_level
connection.set_isolation_level(0)
pg_cursor = connection.cursor()
pg_cursor.execute('''CREATE TABLE "%s" (name VARCHAR, value NUMERIC)''' % table_name)
pg_cursor.execute('''CREATE TABLE "%s" (some_column VARCHAR, value NUMERIC)''' % table_name)
pg_cursor.execute('''INSERT INTO "%s" VALUES ('Some-Name', 6)''' % table_name)
connection.set_isolation_level(old_isolation_level)
connection.commit()
@ -164,7 +164,7 @@ def create_table(server, db_name, table_name):
old_isolation_level = connection.isolation_level
connection.set_isolation_level(0)
pg_cursor = connection.cursor()
pg_cursor.execute('''CREATE TABLE "%s" (name VARCHAR, value NUMERIC)''' % table_name)
pg_cursor.execute('''CREATE TABLE "%s" (some_column VARCHAR, value NUMERIC)''' % table_name)
pg_cursor.execute('''INSERT INTO "%s" VALUES ('Some-Name', 6)''' % table_name)
connection.set_isolation_level(old_isolation_level)
connection.commit()
@ -177,11 +177,16 @@ def drop_database(connection, database_name):
"""This function used to drop the database"""
if database_name not in ["postgres", "template1", "template0"]:
pg_cursor = connection.cursor()
pg_cursor.execute(
"SELECT pg_terminate_backend(pg_stat_activity.pid) FROM pg_stat_activity "
"WHERE pg_stat_activity.datname ='%s' and pid <> pg_backend_pid();" % database_name
)
if connection.server_version >= 90100:
pg_cursor.execute(
"SELECT pg_terminate_backend(pg_stat_activity.pid) FROM pg_stat_activity "
"WHERE pg_stat_activity.datname ='%s' AND pid <> pg_backend_pid();" % database_name
)
else:
pg_cursor.execute(
"SELECT pg_cancel_backend(procpid) FROM pg_stat_activity " \
"WHERE pg_stat_activity.datname ='%s' AND current_query='<IDLE>';" % database_name
)
pg_cursor.execute("SELECT * FROM pg_database db WHERE"
" db.datname='%s'" % database_name)
if pg_cursor.fetchall():
@ -424,7 +429,6 @@ class Database:
connection.cursor().execute(...)
"""
def __init__(self, server):
self.name = None
self.server = server