summaryrefslogtreecommitdiffstats
path: root/doc/src/sgml/html/ecpg-commands.html
blob: f70a5fa6dfaa1b2dc324c4b5b4ea8df4903cd27a (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
<?xml version="1.0" encoding="UTF-8" standalone="no"?>
<!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>36.3. Running SQL Commands</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets Vsnapshot" /><link rel="prev" href="ecpg-connect.html" title="36.2. Managing Database Connections" /><link rel="next" href="ecpg-variables.html" title="36.4. Using Host Variables" /></head><body id="docContent" class="container-fluid col-10"><div class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">36.3. Running SQL Commands</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="ecpg-connect.html" title="36.2. Managing Database Connections">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="ecpg.html" title="Chapter 36. ECPG — Embedded SQL in C">Up</a></td><th width="60%" align="center">Chapter 36. <span class="application">ECPG</span> — Embedded <acronym class="acronym">SQL</acronym> in C</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 15.4 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="ecpg-variables.html" title="36.4. Using Host Variables">Next</a></td></tr></table><hr /></div><div class="sect1" id="ECPG-COMMANDS"><div class="titlepage"><div><div><h2 class="title" style="clear: both">36.3. Running SQL Commands</h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="ecpg-commands.html#ECPG-EXECUTING">36.3.1. Executing SQL Statements</a></span></dt><dt><span class="sect2"><a href="ecpg-commands.html#ECPG-CURSORS">36.3.2. Using Cursors</a></span></dt><dt><span class="sect2"><a href="ecpg-commands.html#ECPG-TRANSACTIONS">36.3.3. Managing Transactions</a></span></dt><dt><span class="sect2"><a href="ecpg-commands.html#ECPG-PREPARED">36.3.4. Prepared Statements</a></span></dt></dl></div><p>
   Any SQL command can be run from within an embedded SQL application.
   Below are some examples of how to do that.
  </p><div class="sect2" id="ECPG-EXECUTING"><div class="titlepage"><div><div><h3 class="title">36.3.1. Executing SQL Statements</h3></div></div></div><p>
   Creating a table:
</p><pre class="programlisting">
EXEC SQL CREATE TABLE foo (number integer, ascii char(16));
EXEC SQL CREATE UNIQUE INDEX num1 ON foo(number);
EXEC SQL COMMIT;
</pre><p>
  </p><p>
   Inserting rows:
</p><pre class="programlisting">
EXEC SQL INSERT INTO foo (number, ascii) VALUES (9999, 'doodad');
EXEC SQL COMMIT;
</pre><p>
  </p><p>
   Deleting rows:
</p><pre class="programlisting">
EXEC SQL DELETE FROM foo WHERE number = 9999;
EXEC SQL COMMIT;
</pre><p>
  </p><p>
   Updates:
</p><pre class="programlisting">
EXEC SQL UPDATE foo
    SET ascii = 'foobar'
    WHERE number = 9999;
EXEC SQL COMMIT;
</pre><p>
  </p><p>
   <code class="literal">SELECT</code> statements that return a single result
   row can also be executed using
   <code class="literal">EXEC SQL</code> directly.  To handle result sets with
   multiple rows, an application has to use a cursor;
   see <a class="xref" href="ecpg-commands.html#ECPG-CURSORS" title="36.3.2. Using Cursors">Section 36.3.2</a> below.  (As a special case, an
   application can fetch multiple rows at once into an array host
   variable; see <a class="xref" href="ecpg-variables.html#ECPG-VARIABLES-ARRAYS" title="36.4.4.3.1. Arrays">Section 36.4.4.3.1</a>.)
  </p><p>
   Single-row select:
</p><pre class="programlisting">
EXEC SQL SELECT foo INTO :FooBar FROM table1 WHERE ascii = 'doodad';
</pre><p>
  </p><p>
   Also, a configuration parameter can be retrieved with the
   <code class="literal">SHOW</code> command:
</p><pre class="programlisting">
EXEC SQL SHOW search_path INTO :var;
</pre><p>
  </p><p>
   The tokens of the form
   <code class="literal">:<em class="replaceable"><code>something</code></em></code> are
   <em class="firstterm">host variables</em>, that is, they refer to
   variables in the C program.  They are explained in <a class="xref" href="ecpg-variables.html" title="36.4. Using Host Variables">Section 36.4</a>.
  </p></div><div class="sect2" id="ECPG-CURSORS"><div class="titlepage"><div><div><h3 class="title">36.3.2. Using Cursors</h3></div></div></div><p>
   To retrieve a result set holding multiple rows, an application has
   to declare a cursor and fetch each row from the cursor.  The steps
   to use a cursor are the following: declare a cursor, open it, fetch
   a row from the cursor, repeat, and finally close it.
  </p><p>
   Select using cursors:
</p><pre class="programlisting">
EXEC SQL DECLARE foo_bar CURSOR FOR
    SELECT number, ascii FROM foo
    ORDER BY ascii;
EXEC SQL OPEN foo_bar;
EXEC SQL FETCH foo_bar INTO :FooBar, DooDad;
...
EXEC SQL CLOSE foo_bar;
EXEC SQL COMMIT;
</pre><p>
  </p><p>
   For more details about declaring a cursor, see <a class="xref" href="ecpg-sql-declare.html" title="DECLARE">DECLARE</a>; for more details about fetching rows from a
   cursor, see <a class="xref" href="sql-fetch.html" title="FETCH"><span class="refentrytitle">FETCH</span></a>.
  </p><div class="note"><h3 class="title">Note</h3><p>
     The ECPG <code class="command">DECLARE</code> command does not actually
     cause a statement to be sent to the PostgreSQL backend.  The
     cursor is opened in the backend (using the
     backend's <code class="command">DECLARE</code> command) at the point when
     the <code class="command">OPEN</code> command is executed.
    </p></div></div><div class="sect2" id="ECPG-TRANSACTIONS"><div class="titlepage"><div><div><h3 class="title">36.3.3. Managing Transactions</h3></div></div></div><p>
   In the default mode, statements are committed only when
   <code class="command">EXEC SQL COMMIT</code> is issued. The embedded SQL
   interface also supports autocommit of transactions (similar to
   <span class="application">psql</span>'s default behavior) via the <code class="option">-t</code>
   command-line option to <code class="command">ecpg</code> (see <a class="xref" href="app-ecpg.html" title="ecpg"><span class="refentrytitle"><span class="application">ecpg</span></span></a>) or via the <code class="literal">EXEC SQL SET AUTOCOMMIT TO
   ON</code> statement. In autocommit mode, each command is
   automatically committed unless it is inside an explicit transaction
   block. This mode can be explicitly turned off using <code class="literal">EXEC
   SQL SET AUTOCOMMIT TO OFF</code>.
  </p><p>
    The following transaction management commands are available:

    </p><div class="variablelist"><dl class="variablelist"><dt><span class="term"><code class="literal">EXEC SQL COMMIT</code></span></dt><dd><p>
        Commit an in-progress transaction.
       </p></dd><dt><span class="term"><code class="literal">EXEC SQL ROLLBACK</code></span></dt><dd><p>
        Roll back an in-progress transaction.
       </p></dd><dt><span class="term"><code class="literal">EXEC SQL PREPARE TRANSACTION </code><em class="replaceable"><code>transaction_id</code></em></span></dt><dd><p>
        Prepare the current transaction for two-phase commit.
       </p></dd><dt><span class="term"><code class="literal">EXEC SQL COMMIT PREPARED </code><em class="replaceable"><code>transaction_id</code></em></span></dt><dd><p>
        Commit a transaction that is in prepared state.
       </p></dd><dt><span class="term"><code class="literal">EXEC SQL ROLLBACK PREPARED </code><em class="replaceable"><code>transaction_id</code></em></span></dt><dd><p>
        Roll back a transaction that is in prepared state.
       </p></dd><dt><span class="term"><code class="literal">EXEC SQL SET AUTOCOMMIT TO ON</code></span></dt><dd><p>
        Enable autocommit mode.
       </p></dd><dt><span class="term"><code class="literal">EXEC SQL SET AUTOCOMMIT TO OFF</code></span></dt><dd><p>
        Disable autocommit mode.  This is the default.
       </p></dd></dl></div><p>
   </p></div><div class="sect2" id="ECPG-PREPARED"><div class="titlepage"><div><div><h3 class="title">36.3.4. Prepared Statements</h3></div></div></div><p>
    When the values to be passed to an SQL statement are not known at
    compile time, or the same statement is going to be used many
    times, then prepared statements can be useful.
   </p><p>
    The statement is prepared using the
    command <code class="literal">PREPARE</code>.  For the values that are not
    known yet, use the
    placeholder <span class="quote"><span class="quote"><code class="literal">?</code></span></span>:
</p><pre class="programlisting">
EXEC SQL PREPARE stmt1 FROM "SELECT oid, datname FROM pg_database WHERE oid = ?";
</pre><p>
   </p><p>
    If a statement returns a single row, the application can
    call <code class="literal">EXECUTE</code> after
    <code class="literal">PREPARE</code> to execute the statement, supplying the
    actual values for the placeholders with a <code class="literal">USING</code>
    clause:
</p><pre class="programlisting">
EXEC SQL EXECUTE stmt1 INTO :dboid, :dbname USING 1;
</pre><p>
   </p><p>
    If a statement returns multiple rows, the application can use a
    cursor declared based on the prepared statement.  To bind input
    parameters, the cursor must be opened with
    a <code class="literal">USING</code> clause:
</p><pre class="programlisting">
EXEC SQL PREPARE stmt1 FROM "SELECT oid,datname FROM pg_database WHERE oid &gt; ?";
EXEC SQL DECLARE foo_bar CURSOR FOR stmt1;

/* when end of result set reached, break out of while loop */
EXEC SQL WHENEVER NOT FOUND DO BREAK;

EXEC SQL OPEN foo_bar USING 100;
...
while (1)
{
    EXEC SQL FETCH NEXT FROM foo_bar INTO :dboid, :dbname;
    ...
}
EXEC SQL CLOSE foo_bar;
</pre><p>
   </p><p>
    When you don't need the prepared statement anymore, you should
    deallocate it:
</p><pre class="programlisting">
EXEC SQL DEALLOCATE PREPARE <em class="replaceable"><code>name</code></em>;
</pre><p>
   </p><p>
    For more details about <code class="literal">PREPARE</code>,
    see <a class="xref" href="ecpg-sql-prepare.html" title="PREPARE">PREPARE</a>. Also
    see <a class="xref" href="ecpg-dynamic.html" title="36.5. Dynamic SQL">Section 36.5</a> for more details about using
    placeholders and input parameters.
   </p></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="ecpg-connect.html" title="36.2. Managing Database Connections">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="ecpg.html" title="Chapter 36. ECPG — Embedded SQL in C">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="ecpg-variables.html" title="36.4. Using Host Variables">Next</a></td></tr><tr><td width="40%" align="left" valign="top">36.2. Managing Database Connections </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 15.4 Documentation">Home</a></td><td width="40%" align="right" valign="top"> 36.4. Using Host Variables</td></tr></table></div></body></html>