DO — execute an anonymous code block
DO [ (type
[, ...]) USING (argument
[, ...]) ] [ LANGUAGElang_name
]code
DO
executes 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
executed a single time.
With the USING
clause, the code block is treated as though it were the body of a function
with parameters, returning record
.
With prepareStatement, it can be parsed once and executed multiple times, but it is cheap to parse it.
Normally it used in ecpg.
The optional USING
clause can be written either
before or after the code block, but it can only be used for pl/sql now.
The optional LANGUAGE
clause can be written either
before or after the code block.
code
The procedural language code to be executed. This must be specified
as a string literal, just as in CREATE FUNCTION
.
Use of a dollar-quoted literal is recommended.
lang_name
The name of the procedural language the code is written in.
If omitted, the default is plpgsql
.
type
The type of the argument. the argument's mode is always inout.
argument
The argument used for executing an anonymous code block like CALL.
The procedural language to be used must already have been installed
into the current database by means of CREATE EXTENSION
.
plpgsql
is installed by default, but other languages are not.
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 executed in a transaction block, then the
procedure code cannot execute transaction control statements. Transaction
control statements are only allowed if DO
is executed in
its own transaction.
Grant 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$$;
Grant all privileges on all views in schema public
to
role webuser
by arguments in LANGUAGE pl/sql:
DO $$DECLARE r record; BEGIN FOR r IN SELECT table_schema, table_name FROM information_schema.tables WHERE table_type = $1 AND table_schema = $2 LOOP EXECUTE 'GRANT ALL ON ' || quote_ident(r.table_schema) || '.' || quote_ident(r.table_name) || ' TO webuser'; END LOOP; END$$ (text, text) USING ('VIEW', 'public') LANGUAGE plorasql;
See Section 34.5.4 for the usage in ecpg(Oracle Pro*c compatible).
There is no DO
statement in the SQL standard.