Thread: BUG: value in information_schema.parameters.parameter_default is always NULL for roles t
BUG: value in information_schema.parameters.parameter_default is always NULL for roles t
From
Vedran Bilopavlović
Date:
A program produces the wrong output for any given input:
Values in table information_schema.parameters, column parameter_default, are always NULL only for roles that are not superuser.
The same column returns the correct values for superuser roles.
There is a workaround by using pg_proc table:
select
unnest(proargnames[pronargs-pronargdefaults+1:pronargs] )optargnames,
unnest(string_to_array(pg_get_expr(proargdefaults, 0)::text,',')) optargdefaults
from
pg_catalog.pg_proc
where
proname = 'proc name'
unnest(proargnames[pronargs-pronargdefaults+1:pronargs] )optargnames,
unnest(string_to_array(pg_get_expr(proargdefaults, 0)::text,',')) optargdefaults
from
pg_catalog.pg_proc
where
proname = 'proc name'
However, this approach relies on CSV parsing and will return wrong results when the parameter default contains a comma.
--
Re: BUG: value in information_schema.parameters.parameter_default is always NULL for roles t
From
Tom Lane
Date:
=?UTF-8?Q?Vedran_Bilopavlovi=C4=87?= <vbilopav@gmail.com> writes: > Values in table *information_schema.parameters*, column *parameter_default*, > are always NULL only for roles that are not superuser. I see no bug there. The manual defines parameter_default as The default expression of the parameter, or null if none or if the function is not owned by a currently enabled role. A superuser is considered to own everything, but for mere-mortal roles a result would only appear for functions you own. The SQL implementation of the view appears to match this definition: CASE WHEN pg_has_role(proowner, 'USAGE') THEN pg_get_function_arg_default(p_oid, (ss.x).n) ELSE NULL END You could certainly quibble with the value of hiding the information when it's readily available from our system catalogs --- but this is a SQL-standard-defined view so we implement it as the standard says, and this is what the standard says it should do. > There is a workaround by using pg_proc table: I'd recommend using something from the pg_get_function*() family. regards, tom lane