Обсуждение: Deleting Functions
Folks, I am using PGSQL do do all of my schema changes, but have run into a problem. I need to be able to DROP all of the USER FUNCTIONS that are defined in a schema. The problem is that I do not know the names of all of the functions and parameters. I know that I could use '\df' and then use perl or some other scripting language to parse this, but I need to be able to perform this action on multiple platforms (without rewriting the process for each platform). I have written a script that incorporates '\df' and appropriate parsing to perform this action for LINUX and it works fine/lasts a long time. I need to make this more transparent so it will run on all platforms (in particular windows). I know that in the past (version 7) there was a way to drop the functions by directly accessing some of the system tables. The question/problem is that we have updated to version 8.1 and need the same functionality. Any help or directions would be greatly appreciated. Thanks Scott.
Scott,
I use the following query with psql \o option. Change the schema name from public to whatever. I am sure you could
put
this into a plpgsql function using execute as well.
Jim
\o drops.sql
select 'drop function ' || nspname || '.' || proname || '(' || pg_catalog.oidvectortypes(p.proargtypes) || ');' from
pg_proc p join pg_namespace b on (p.pronamespace=b.oid) where nspname='public';
\o
\!vi drops.sql # <<remove the fluff from the query
\i drops.sql
---------- Original Message -----------
From: Scott Petersen <scottpetersen@softhome.net>
To: pgsql-sql@postgresql.org
Sent: Wed, 23 Aug 2006 13:29:12 -0600
Subject: [SQL] Deleting Functions
> Folks,
>
> I am using PGSQL do do all of my schema changes, but have run into a
> problem. I need to be able to DROP all of the USER FUNCTIONS that are
> defined in a schema. The problem is that I do not know the names of all
> of the functions and parameters. I know that I could use '\df' and then
> use perl or some other scripting language to parse this, but I need to
> be able to perform this action on multiple platforms (without rewriting
> the process for each platform).
>
> I have written a script that incorporates '\df' and appropriate parsing
> to perform this action for LINUX and it works fine/lasts a long time. I
> need to make this more transparent so it will run on all platforms (in
> particular windows).
>
> I know that in the past (version 7) there was a way to drop the
> functions by directly accessing some of the system tables. The
> question/problem is that we have updated to version 8.1 and need the
> same functionality.
>
> Any help or directions would be greatly appreciated.
>
> Thanks Scott.
>
> ---------------------------(end of broadcast)---------------------------
> TIP 6: explain analyze is your friend
------- End of Original Message -------
"Jim Buttafuoco" <jim@contactbda.com> writes:
> select 'drop function ' || nspname || '.' || proname || '(' || pg_catalog.oidvectortypes(p.proargtypes) || ');' from
> pg_proc p join pg_namespace b on (p.pronamespace=b.oid) where nspname='public';
Seems like you could do that more easily with regprocedure:
select 'drop function ' || p.oid::regprocedure || ';' from
pg_proc p join pg_namespace b on (p.pronamespace=b.oid) where nspname='public';
[ tries it ... ] ... except that there's no regprocedure-to-text cast.
How annoying :-(
regards, tom lane
Thanks for those who responded. It works fine and lasts a long time.
The following script does NOT require any editing. It simply executes
and works.
\pset format unaligned
\pset fieldsep ''
\pset footer
\t
\o drops.sql
select 'drop function ' || nspname || '.' || proname || '(' ||
pg_catalog.oidvectortypes(p.proargtypes) || ') CASCADE;' from
pg_proc p join pg_namespace b on (p.pronamespace=b.oid) where
nspname='public';
\o
\i drops.sql
Scott.
Jim Buttafuoco wrote:
> Scott,
>
> I use the following query with psql \o option. Change the schema name from public to whatever. I am sure you could
put
> this into a plpgsql function using execute as well.
>
>
> Jim
>
> \o drops.sql
> select 'drop function ' || nspname || '.' || proname || '(' || pg_catalog.oidvectortypes(p.proargtypes) || ');' from
> pg_proc p join pg_namespace b on (p.pronamespace=b.oid) where nspname='public';
> \o
> \!vi drops.sql # <<remove the fluff from the query
> \i drops.sql
>
>
>
>
>