------------------------[CHANGE ID: 20171] 3/10/2016 10:11---------------- select public.dropall('f_getauditinfo','meta'); create or replace function meta.f_getauditinfo( p_tablename text ) returns table( tablename citext , tableprefix citext , columnname citext , columndescription citext , columntype integer , datatype citext , specialtype integer , foreigntable citext , foreigncolumn citext , foreignpk citext , schemaname citext ) language plpgsql stable as $$ --columntype: -- 0=Normal Audited --, 1=Primary Key --, 2=Primary Key Audited --, 3=UserColumn --, 4=Normal Encrypted Audited --, 5 = Parent Table Primary Key for lookup (Must give Foreign Table) --, 6 = Parent Table Primary Key for delete (Must give Foreign Table) --, 9=View only, used for custom audit. e.g pplan --specialtype: -- 0,null = Leave alone. -- 1=Convert int date to sql date. -- 2=Convert int time to sql time., -- 3=Status Field, --Note that when ColumnType is 3,Status field, the ForeignTable column must have the name of the search sent to F_GetDescription_Code -- 4=ForeignTable -- 5=ForeignTable, tableprefix -- 6 = Blob Column, will compare with size only -- 7 = Blob Column, will compare with hash only -- 8 = Hide declare --Error Handling-- m_funcname text = 'f_getauditinfo'; m_errmsg text; m_errcontext text; m_errdetail text; m_errhint text; m_errstate text; --Error Handling-- m_tablename citext; m_schemaname citext; m_results record; begin if p_tablename ilike '%.%' then m_schemaname = split_part(p_tablename,'.',1); m_tablename = split_part(p_tablename,'.',2); else m_schemaname = ''; m_tablename = p_tablename; end if; return query with tbl as ( select t.table_name ,t.table_schema from information_schema.tables t where t.table_schema not ilike 'pg_%' and t.table_schema not in ('information_schema','meta') and t.table_type = 'BASE TABLE' and t.table_name not in ( 'atdetail','atevent','eventlog','event_notify','async_jobs','async_broker','async_broker_stat', 'version','upgrades','upgradescript','bt_enums','strmsession','strmsessionchunk', 'upg_options','upgrade_procrun','process_act_list','server_script','generalaudit', 'imapclient_instance','async_schedule','_loginsession','atview','authsession' ) and t.table_name not ilike 'tmp\_%' and ( m_tablename::citext = t.table_name::citext or nv(m_tablename) = '' ) and ( m_schemaname::citext = t.table_schema::citext or nv(m_schemaname) = '' ) ) , cols as ( select tbl.* ,exists (select 1 from information_schema.table_constraints ct inner join information_schema.constraint_column_usage cu on cu.constraint_name = ct.constraint_name and cu.table_name = ct.table_name and cu.column_name = c.column_name where ct.table_schema = c.table_schema and ct.constraint_type = 'PRIMARY KEY' and ct.table_name = tbl.table_name ) as isPk , exists (select 1 from information_schema.table_constraints ct inner join information_schema.constraint_column_usage cu on cu.constraint_name = ct.constraint_name and cu.table_name = ct.table_name and cu.column_name = c.column_name where ct.table_schema = c.table_schema and ct.constraint_type = 'FOREIGN KEY' and ct.table_name = tbl.table_name ) as isFk ,c.column_name::text as column_name ,(case when c.data_type = 'USER-DEFINED' then c.udt_name else c.data_type end)::text as data_type ,f_tableprefix(tbl.table_name::text) as tableprefix ,0::integer as specialtype from tbl inner join information_schema.columns c on c.table_name = tbl.table_name --and c.data_type not in ('USER-DEFINED','ARRAY','geometry','geography') --,'bytea' --and c.column_name not in ('createdby','createddate','updatedby','updateddate','deletedby','deleteddate') and c.column_name not ilike '%dropped%' and c.column_name not in ('prefix','updatecnt') ), processed as ( select * --,(select from cols b where b.table_name = a.table_name) from cols a ) select distinct on (a.table_schema,a.table_name, a.column_name) a.table_name::citext as tablename ,a.tableprefix::citext as tableprefix ,a.column_name::citext as columnname ,initcap(a.column_name)::citext as columndescription ,(case when a.isPk then 2 else 0 end)::integer as columntype ,a.data_type::citext as datatype ,(case when a.data_type ilike '%bytea%' and nv(a.specialtype) not in (6,7,8) then 7 else a.specialtype end)::integer as specialtype ,''::citext as foreigntable ,''::citext as foreigncolumn ,''::citext as foreignpk ,a.table_schema::citext as schemaname from processed a where exists ( select 1 from processed a2 where a2.table_name = a.table_name and a2.table_schema = a.table_schema and a2.isPk ) and exists ( select 1 from processed a2 where a2.table_name = a.table_name and a2.table_schema = a.table_schema and a2.isPk and (a2.data_type ilike '%int%' or a2.data_type ilike '%serial%') ) order by a.table_name, a.column_name ; exception when others then GET STACKED DIAGNOSTICS m_errmsg = MESSAGE_TEXT ,m_errcontext = PG_EXCEPTION_CONTEXT ,m_errdetail = PG_EXCEPTION_DETAIL ,m_errhint = PG_EXCEPTION_HINT ,m_errstate = RETURNED_SQLSTATE; m_errmsg := get_err_msg(m_funcname, m_errmsg, m_errcontext, m_errdetail, m_errhint, m_errstate); raise '%',m_errmsg; end; $$; ---select * from meta.f_getauditinfo('syncprocess')