Thread: Related tables to a view
Hi I need a function which are able to return the underlying tables to a view. If I have a view which is a selection from field1 and field2 from table1 and field1 and field2 from table2. How can I make a selection which returns the relation for the fields in a way so I am able to se which field belongs to which table. SELECT * FROM pg_views WHERE viewname='TestView' will return the schema and the definition for me. SELECT * FROM pg_class WHERE relname = 'TestView' will return some oids etc. SELECT * FROM pg_attribute JOIN pg_class ON attrelid = pg_class.oid AND pg_class.relname='TestView' will return the fields including oids etc. But I just cant find out how to find the tables for each field. I hope someone are able to help me with this problem. Regards Jan Andersen
On Mon, Dec 25, 2006 at 10:52:03PM +0100, Jan Meyland Andersen wrote: > If I have a view which is a selection from field1 and field2 from table1 > and field1 and field2 from table2. > > How can I make a selection which returns the relation for the fields in a > way so I am able to se which field belongs to which table. You could query pg_depend to find out which tables and columns the view's rewrite rule depends on but that's not as specific as what you're requesting. I'm not aware of a way to associate a particular table column with a particular view column short of parsing the view definition or rule action; doing so would have to allow for the possibility of a view column deriving its value from an arbitrarily complex expression involving multiple tables, subqueries, etc. -- Michael Fuhr
> You could query pg_depend to find out which tables and columns the > view's rewrite rule depends on but that's not as specific as what > you're requesting. I'm not aware of a way to associate a particular > table column with a particular view column short of parsing the view > definition or rule action; doing so would have to allow for the > possibility of a view column deriving its value from an arbitrarily > complex expression involving multiple tables, subqueries, etc. Yes I'm aware of the "problem" about arbitrary or scalar values but this is not a problem in this specific case. If a field or value do not have a table reference then it is not needed in the resultset. I only need those values which have a direct connection to a table. Is the only possible way then to analyse the description field in pg_view? I was hoping for a more simple way to get the needed result. Regards Jan Andersen
> You could query pg_depend to find out which tables and columns the > view's rewrite rule depends on but that's not as specific as what > you're requesting. I'm not aware of a way to associate a particular > table column with a particular view column short of parsing the view > definition or rule action; doing so would have to allow for the > possibility of a view column deriving its value from an arbitrarily > complex expression involving multiple tables, subqueries, etc. I have been thinking the problem through again, and I think I am able to solve the problem if I just know which tables the view is using. But how do I get this information from the pg_depend table? Regards Jan
Try this query select a.relname as base,a.relkind from pg_class a join pg_depend d on (a.oid = d.refobjid) join pg_class c on (d.classid = c.oid) join pg_rewrite r on (objid = r.oid) join pg_class v on (ev_class = v.oid) where a.relkind in('r', 'v') and a.relname <> v.relname and v.relname='YOUR VIEW NAME HERE' order by 1 -----Original Message----- From: pgsql-sql-owner@postgresql.org [mailto:pgsql-sql-owner@postgresql.org] On Behalf Of Jan Meyland Andersen Sent: Tuesday, December 26, 2006 3:11 PM To: Michael Fuhr Cc: Jan Meyland Andersen; pgsql-sql@postgresql.org Subject: Re: [SQL] Related tables to a view > You could query pg_depend to find out which tables and columns the > view's rewrite rule depends on but that's not as specific as what > you're requesting. I'm not aware of a way to associate a particular > table column with a particular view column short of parsing the view > definition or rule action; doing so would have to allow for the > possibility of a view column deriving its value from an arbitrarily > complex expression involving multiple tables, subqueries, etc. I have been thinking the problem through again, and I think I am able to solve the problem if I just know which tables the view is using. But how do I get this information from the pg_depend table? Regards Jan ---------------------------(end of broadcast)--------------------------- TIP 6: explain analyze is your friend
> Try this query > > > select a.relname as base,a.relkind > from > pg_class a > join pg_depend d on (a.oid = d.refobjid) > join pg_class c on (d.classid = c.oid) > join pg_rewrite r on (objid = r.oid) > join pg_class v on (ev_class = v.oid) > where a.relkind in('r', 'v') > and a.relname <> v.relname > and v.relname='YOUR VIEW NAME HERE' > order by 1 > Thanks a lot. That is exactly what I need. Regards Jan