Runs anonymous code block as a transient anonymous function.
DO [ LANGUAGE <lang_name> ] <code>
DO
runs an anonymous code block, or in other words a transient anonymous function in a procedural language.
The code block is treated as though it were the body of a function with no parameters, returning void
. It is parsed and run a single time.
The optional LANGUAGE
clause can appear either before or after the code block.
Anonymous blocks are procedural language structures that provide the capability to create and run procedural code on the fly without persistently storing the code as database objects in the system catalogs. The concept of anonymous blocks is similar to UNIX shell scripts, which enable several manually entered commands to be grouped and run as one step. As the name implies, anonymous blocks do not have a name, and for this reason they cannot be referenced from other objects. Although built dynamically, anonymous blocks can be easily stored as scripts in the operating system files for repetitive execution.
Anonymous blocks are standard procedural language blocks. They carry the syntax and obey the rules that apply to the procedural language, including declaration and scope of variables, execution, exception handling, and language usage.
The compilation and execution of anonymous blocks are combined in one step, while a user-defined function needs to be re-defined before use each time its definition changes.
CREATE FUNCTION
command. Use of a dollar-quoted literal is recommended.
plpgsql
.
The procedural language to be used must already have been installed into the current database by means of CREATE EXTENSION
. The PL/pgSQL language is installed wih Greenplum Database and is registered by default every user-created database. The PL/Python and PL/Perl languages are installed by default, but not registered. Other languages are neither installed nor registered. The pg_language system catalog contains information about the registered languages in a database.
The user must have USAGE
privilege for the procedural language, or must be a superuser if the language is untrusted. This is the same privilege requirement as for creating a function in the language.
If DO
is run in a transaction block, then the procedure code cannot execute transaction control statements. Transaction control statements are allowed only if DO
is run in its own transaction.
Anonymous blocks do not support function volatility or EXECUTE ON
attributes.
This PL/pgSQL example grants all privileges on all views in schema public
to role webuser
:
DO $$DECLARE r record;
BEGIN
FOR r IN SELECT table_schema, table_name FROM information_schema.tables
WHERE table_type = 'VIEW' AND table_schema = 'public'
LOOP
EXECUTE 'GRANT ALL ON ' || quote_ident(r.table_schema) || '.' || quote_ident(r.table_name) || ' TO webuser';
END LOOP;
END$$;
There is no DO
statement in the SQL standard.
Parent topic: SQL Commands