cartodb-postgresql/scripts-available/CDB_UserTables.sql
Sandro Santilli 0082138503 Do not force DROP FUNCTION but rely on CREATE OR REPLACE
We'll bet on no old signature being left around.

Presence of an old signature would break at runtime
with a message like:
ERROR:  function CDB_UserTables() is not unique

Closes #25
2014-05-20 16:39:18 +02:00

40 lines
1.3 KiB
PL/PgSQL

-- Function returning list of cartodb user tables
--
-- The optional argument restricts the result to tables
-- of the specified access type.
--
-- Currently accepted permissions are: 'public', 'private' or 'all'
--
-- DROP FUNCTION IF EXISTS CDB_UserTables(); -- replaced by:
CREATE OR REPLACE FUNCTION CDB_UserTables(perm text DEFAULT 'all')
RETURNS SETOF information_schema.sql_identifier
AS $$
WITH usertables AS (
-- TODO: query CDB_TableMetadata for this ?
-- See http://github.com/CartoDB/cartodb/issues/254#issuecomment-26044777
SELECT table_name as t
FROM information_schema.tables
WHERE
table_type='BASE TABLE'
AND table_schema='public'
AND table_name NOT IN (
'cdb_tablemetadata',
'spatial_ref_sys'
)
), perms AS (
SELECT t, has_table_privilege('public', 'public'||'.'||t, 'SELECT') as p
FROM usertables
)
SELECT t FROM perms
WHERE p = CASE WHEN $1 = 'private' THEN false
WHEN $1 = 'public' THEN true
ELSE not p -- none
END
OR $1 = 'all'
;
$$ LANGUAGE 'sql';
-- This is a private function, so only the db owner need privileges
REVOKE ALL ON FUNCTION CDB_UserTables(text) FROM PUBLIC;
GRANT EXECUTE ON FUNCTION CDB_UserTables(text) TO ":DATABASE_USERNAME";