|
| 1 | +# Create And Execute SQL Statements With \gexec |
| 2 | + |
| 3 | +The [`\gexec` |
| 4 | +meta-command](https://www.postgresql.org/docs/current/app-psql.html#APP-PSQL-META-COMMAND-GEXEC) |
| 5 | +is a variation of the [`\g` |
| 6 | +meta-command](https://www.postgresql.org/docs/current/app-psql.html#APP-PSQL-META-COMMAND-G), |
| 7 | +both of which can be used in a `psql` session. Whereas the `\g` command sends |
| 8 | +the current query in the buffer to the PostgreSQL server for execution, the |
| 9 | +`\gexec` command first sends the query to the server for execution and then |
| 10 | +executes each row of the result as its own SQL statement. |
| 11 | + |
| 12 | +This is both a bit absurd and powerful. And a bit unnecessary considering all |
| 13 | +of the scripting capabilities with anything from bash to any language with a |
| 14 | +SQL client library. |
| 15 | + |
| 16 | +Nevertheless, let's take a look at a contrived example of how it works. Here, |
| 17 | +we have a SQL statement that does some string concatenation based off values in |
| 18 | +an array. This results in three separate `create schema` statements. |
| 19 | + |
| 20 | +```sql |
| 21 | +> select |
| 22 | + 'create schema if not exists schema_' || letter || ';' |
| 23 | + from unnest(array['a', 'b', 'c']) as letter |
| 24 | + \gexec |
| 25 | + |
| 26 | +CREATE SCHEMA |
| 27 | +CREATE SCHEMA |
| 28 | +CREATE SCHEMA |
| 29 | + |
| 30 | +> \dn |
| 31 | + List of schemas |
| 32 | + Name | Owner |
| 33 | +----------+------------------- |
| 34 | + public | pg_database_owner |
| 35 | + schema_a | postgres |
| 36 | + schema_b | postgres |
| 37 | + schema_c | postgres |
| 38 | +(4 rows) |
| 39 | +``` |
| 40 | + |
| 41 | +Three new schemas get created which we can inspect with `\dn`. |
| 42 | + |
| 43 | +Notice, if we simply execute the primary statement, we can see the intermediate |
| 44 | +result that `\gexec` will subsequently execute. |
| 45 | + |
| 46 | +```sql |
| 47 | +> select |
| 48 | + 'create schema if not exists schema_' || letter || ';' |
| 49 | + from unnest(array['a', 'b', 'c']) as letter |
| 50 | + \g |
| 51 | + |
| 52 | + ?column? |
| 53 | +--------------------------------------- |
| 54 | + create schema if not exists schema_a; |
| 55 | + create schema if not exists schema_b; |
| 56 | + create schema if not exists schema_c; |
| 57 | +(3 rows) |
| 58 | +``` |
0 commit comments