gooderp18绿色标准版
您最多选择25个主题 主题必须以字母或数字开头,可以包含连字符 (-),并且长度不得超过35个字符

880 行
44KB

  1. <?xml version="1.0" encoding="UTF-8" standalone="no"?>
  2. <!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>35.4. Using Host Variables</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 V1.79.1" /><link rel="prev" href="ecpg-commands.html" title="35.3. Running SQL Commands" /><link rel="next" href="ecpg-dynamic.html" title="35.5. Dynamic SQL" /></head><body><div xmlns="http://www.w3.org/TR/xhtml1/transitional" class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">35.4. Using Host Variables</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="ecpg-commands.html" title="35.3. Running SQL Commands">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="ecpg.html" title="Chapter 35. ECPG - Embedded SQL in C">Up</a></td><th width="60%" align="center">Chapter 35. <span xmlns="http://www.w3.org/1999/xhtml" class="application">ECPG</span> - Embedded <acronym xmlns="http://www.w3.org/1999/xhtml" class="acronym">SQL</acronym> in C</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 12.4 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="ecpg-dynamic.html" title="35.5. Dynamic SQL">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="ECPG-VARIABLES"><div class="titlepage"><div><div><h2 class="title" style="clear: both">35.4. Using Host Variables</h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="ecpg-variables.html#ECPG-VARIABLES-OVERVIEW">35.4.1. Overview</a></span></dt><dt><span class="sect2"><a href="ecpg-variables.html#ECPG-DECLARE-SECTIONS">35.4.2. Declare Sections</a></span></dt><dt><span class="sect2"><a href="ecpg-variables.html#ECPG-RETRIEVING">35.4.3. Retrieving Query Results</a></span></dt><dt><span class="sect2"><a href="ecpg-variables.html#ECPG-VARIABLES-TYPE-MAPPING">35.4.4. Type Mapping</a></span></dt><dt><span class="sect2"><a href="ecpg-variables.html#ECPG-VARIABLES-NONPRIMITIVE-SQL">35.4.5. Handling Nonprimitive SQL Data Types</a></span></dt><dt><span class="sect2"><a href="ecpg-variables.html#ECPG-INDICATORS">35.4.6. Indicators</a></span></dt></dl></div><p>
  3. In <a class="xref" href="ecpg-commands.html" title="35.3. Running SQL Commands">Section 35.3</a> you saw how you can execute SQL
  4. statements from an embedded SQL program. Some of those statements
  5. only used fixed values and did not provide a way to insert
  6. user-supplied values into statements or have the program process
  7. the values returned by the query. Those kinds of statements are
  8. not really useful in real applications. This section explains in
  9. detail how you can pass data between your C program and the
  10. embedded SQL statements using a simple mechanism called
  11. <em class="firstterm">host variables</em>. In an embedded SQL program we
  12. consider the SQL statements to be <em class="firstterm">guests</em> in the C
  13. program code which is the <em class="firstterm">host language</em>. Therefore
  14. the variables of the C program are called <em class="firstterm">host
  15. variables</em>.
  16. </p><p>
  17. Another way to exchange values between PostgreSQL backends and ECPG
  18. applications is the use of SQL descriptors, described
  19. in <a class="xref" href="ecpg-descriptors.html" title="35.7. Using Descriptor Areas">Section 35.7</a>.
  20. </p><div class="sect2" id="ECPG-VARIABLES-OVERVIEW"><div class="titlepage"><div><div><h3 class="title">35.4.1. Overview</h3></div></div></div><p>
  21. Passing data between the C program and the SQL statements is
  22. particularly simple in embedded SQL. Instead of having the
  23. program paste the data into the statement, which entails various
  24. complications, such as properly quoting the value, you can simply
  25. write the name of a C variable into the SQL statement, prefixed by
  26. a colon. For example:
  27. </p><pre class="programlisting">
  28. EXEC SQL INSERT INTO sometable VALUES (:v1, 'foo', :v2);
  29. </pre><p>
  30. This statement refers to two C variables named
  31. <code class="varname">v1</code> and <code class="varname">v2</code> and also uses a
  32. regular SQL string literal, to illustrate that you are not
  33. restricted to use one kind of data or the other.
  34. </p><p>
  35. This style of inserting C variables in SQL statements works
  36. anywhere a value expression is expected in an SQL statement.
  37. </p></div><div class="sect2" id="ECPG-DECLARE-SECTIONS"><div class="titlepage"><div><div><h3 class="title">35.4.2. Declare Sections</h3></div></div></div><p>
  38. To pass data from the program to the database, for example as
  39. parameters in a query, or to pass data from the database back to
  40. the program, the C variables that are intended to contain this
  41. data need to be declared in specially marked sections, so the
  42. embedded SQL preprocessor is made aware of them.
  43. </p><p>
  44. This section starts with:
  45. </p><pre class="programlisting">
  46. EXEC SQL BEGIN DECLARE SECTION;
  47. </pre><p>
  48. and ends with:
  49. </p><pre class="programlisting">
  50. EXEC SQL END DECLARE SECTION;
  51. </pre><p>
  52. Between those lines, there must be normal C variable declarations,
  53. such as:
  54. </p><pre class="programlisting">
  55. int x = 4;
  56. char foo[16], bar[16];
  57. </pre><p>
  58. As you can see, you can optionally assign an initial value to the variable.
  59. The variable's scope is determined by the location of its declaring
  60. section within the program.
  61. You can also declare variables with the following syntax which implicitly
  62. creates a declare section:
  63. </p><pre class="programlisting">
  64. EXEC SQL int i = 4;
  65. </pre><p>
  66. You can have as many declare sections in a program as you like.
  67. </p><p>
  68. The declarations are also echoed to the output file as normal C
  69. variables, so there's no need to declare them again. Variables
  70. that are not intended to be used in SQL commands can be declared
  71. normally outside these special sections.
  72. </p><p>
  73. The definition of a structure or union also must be listed inside
  74. a <code class="literal">DECLARE</code> section. Otherwise the preprocessor cannot
  75. handle these types since it does not know the definition.
  76. </p></div><div class="sect2" id="ECPG-RETRIEVING"><div class="titlepage"><div><div><h3 class="title">35.4.3. Retrieving Query Results</h3></div></div></div><p>
  77. Now you should be able to pass data generated by your program into
  78. an SQL command. But how do you retrieve the results of a query?
  79. For that purpose, embedded SQL provides special variants of the
  80. usual commands <code class="command">SELECT</code> and
  81. <code class="command">FETCH</code>. These commands have a special
  82. <code class="literal">INTO</code> clause that specifies which host variables
  83. the retrieved values are to be stored in.
  84. <code class="command">SELECT</code> is used for a query that returns only
  85. single row, and <code class="command">FETCH</code> is used for a query that
  86. returns multiple rows, using a cursor.
  87. </p><p>
  88. Here is an example:
  89. </p><pre class="programlisting">
  90. /*
  91. * assume this table:
  92. * CREATE TABLE test1 (a int, b varchar(50));
  93. */
  94. EXEC SQL BEGIN DECLARE SECTION;
  95. int v1;
  96. VARCHAR v2;
  97. EXEC SQL END DECLARE SECTION;
  98. ...
  99. EXEC SQL SELECT a, b INTO :v1, :v2 FROM test;
  100. </pre><p>
  101. So the <code class="literal">INTO</code> clause appears between the select
  102. list and the <code class="literal">FROM</code> clause. The number of
  103. elements in the select list and the list after
  104. <code class="literal">INTO</code> (also called the target list) must be
  105. equal.
  106. </p><p>
  107. Here is an example using the command <code class="command">FETCH</code>:
  108. </p><pre class="programlisting">
  109. EXEC SQL BEGIN DECLARE SECTION;
  110. int v1;
  111. VARCHAR v2;
  112. EXEC SQL END DECLARE SECTION;
  113. ...
  114. EXEC SQL DECLARE foo CURSOR FOR SELECT a, b FROM test;
  115. ...
  116. do
  117. {
  118. ...
  119. EXEC SQL FETCH NEXT FROM foo INTO :v1, :v2;
  120. ...
  121. } while (...);
  122. </pre><p>
  123. Here the <code class="literal">INTO</code> clause appears after all the
  124. normal clauses.
  125. </p></div><div class="sect2" id="ECPG-VARIABLES-TYPE-MAPPING"><div class="titlepage"><div><div><h3 class="title">35.4.4. Type Mapping</h3></div></div></div><p>
  126. When ECPG applications exchange values between the PostgreSQL
  127. server and the C application, such as when retrieving query
  128. results from the server or executing SQL statements with input
  129. parameters, the values need to be converted between PostgreSQL
  130. data types and host language variable types (C language data
  131. types, concretely). One of the main points of ECPG is that it
  132. takes care of this automatically in most cases.
  133. </p><p>
  134. In this respect, there are two kinds of data types: Some simple
  135. PostgreSQL data types, such as <code class="type">integer</code>
  136. and <code class="type">text</code>, can be read and written by the application
  137. directly. Other PostgreSQL data types, such
  138. as <code class="type">timestamp</code> and <code class="type">numeric</code> can only be
  139. accessed through special library functions; see
  140. <a class="xref" href="ecpg-variables.html#ECPG-SPECIAL-TYPES" title="35.4.4.2. Accessing Special Data Types">Section 35.4.4.2</a>.
  141. </p><p>
  142. <a class="xref" href="ecpg-variables.html#ECPG-DATATYPE-HOSTVARS-TABLE" title="Table 35.1. Mapping Between PostgreSQL Data Types and C Variable Types">Table 35.1</a> shows which PostgreSQL
  143. data types correspond to which C data types. When you wish to
  144. send or receive a value of a given PostgreSQL data type, you
  145. should declare a C variable of the corresponding C data type in
  146. the declare section.
  147. </p><div class="table" id="ECPG-DATATYPE-HOSTVARS-TABLE"><p class="title"><strong>Table 35.1. Mapping Between PostgreSQL Data Types and C Variable Types</strong></p><div class="table-contents"><table class="table" summary="Mapping Between PostgreSQL Data Types and C Variable Types" border="1"><colgroup><col /><col /></colgroup><thead><tr><th>PostgreSQL data type</th><th>Host variable type</th></tr></thead><tbody><tr><td><code class="type">smallint</code></td><td><code class="type">short</code></td></tr><tr><td><code class="type">integer</code></td><td><code class="type">int</code></td></tr><tr><td><code class="type">bigint</code></td><td><code class="type">long long int</code></td></tr><tr><td><code class="type">decimal</code></td><td><code class="type">decimal</code><a href="#ftn.ECPG-DATATYPE-TABLE-FN" class="footnote"><sup class="footnote" id="ECPG-DATATYPE-TABLE-FN">[a]</sup></a></td></tr><tr><td><code class="type">numeric</code></td><td><code class="type">numeric</code><a href="ecpg-variables.html#ftn.ECPG-DATATYPE-TABLE-FN" class="footnoteref"><sup class="footnoteref">[a]</sup></a></td></tr><tr><td><code class="type">real</code></td><td><code class="type">float</code></td></tr><tr><td><code class="type">double precision</code></td><td><code class="type">double</code></td></tr><tr><td><code class="type">smallserial</code></td><td><code class="type">short</code></td></tr><tr><td><code class="type">serial</code></td><td><code class="type">int</code></td></tr><tr><td><code class="type">bigserial</code></td><td><code class="type">long long int</code></td></tr><tr><td><code class="type">oid</code></td><td><code class="type">unsigned int</code></td></tr><tr><td><code class="type">character(<em class="replaceable"><code>n</code></em>)</code>, <code class="type">varchar(<em class="replaceable"><code>n</code></em>)</code>, <code class="type">text</code></td><td><code class="type">char[<em class="replaceable"><code>n</code></em>+1]</code>, <code class="type">VARCHAR[<em class="replaceable"><code>n</code></em>+1]</code></td></tr><tr><td><code class="type">name</code></td><td><code class="type">char[NAMEDATALEN]</code></td></tr><tr><td><code class="type">timestamp</code></td><td><code class="type">timestamp</code><a href="ecpg-variables.html#ftn.ECPG-DATATYPE-TABLE-FN" class="footnoteref"><sup class="footnoteref">[a]</sup></a></td></tr><tr><td><code class="type">interval</code></td><td><code class="type">interval</code><a href="ecpg-variables.html#ftn.ECPG-DATATYPE-TABLE-FN" class="footnoteref"><sup class="footnoteref">[a]</sup></a></td></tr><tr><td><code class="type">date</code></td><td><code class="type">date</code><a href="ecpg-variables.html#ftn.ECPG-DATATYPE-TABLE-FN" class="footnoteref"><sup class="footnoteref">[a]</sup></a></td></tr><tr><td><code class="type">boolean</code></td><td><code class="type">bool</code><a href="#ftn.id-1.7.5.10.7.5.2.2.17.2.2" class="footnote"><sup class="footnote" id="id-1.7.5.10.7.5.2.2.17.2.2">[b]</sup></a></td></tr><tr><td><code class="type">bytea</code></td><td><code class="type">char *</code>, <code class="type">bytea[<em class="replaceable"><code>n</code></em>]</code></td></tr></tbody><tbody class="footnotes"><tr><td colspan="2"><div id="ftn.ECPG-DATATYPE-TABLE-FN" class="footnote"><p><a href="#ECPG-DATATYPE-TABLE-FN" class="para"><sup class="para">[a] </sup></a>This type can only be accessed through special library functions; see <a class="xref" href="ecpg-variables.html#ECPG-SPECIAL-TYPES" title="35.4.4.2. Accessing Special Data Types">Section 35.4.4.2</a>.</p></div><div id="ftn.id-1.7.5.10.7.5.2.2.17.2.2" class="footnote"><p><a href="#id-1.7.5.10.7.5.2.2.17.2.2" class="para"><sup class="para">[b] </sup></a>declared in <code class="filename">ecpglib.h</code> if not native</p></div></td></tr></tbody></table></div></div><br class="table-break" /><div class="sect3" id="ECPG-CHAR"><div class="titlepage"><div><div><h4 class="title">35.4.4.1. Handling Character Strings</h4></div></div></div><p>
  148. To handle SQL character string data types, such
  149. as <code class="type">varchar</code> and <code class="type">text</code>, there are two
  150. possible ways to declare the host variables.
  151. </p><p>
  152. One way is using <code class="type">char[]</code>, an array
  153. of <code class="type">char</code>, which is the most common way to handle
  154. character data in C.
  155. </p><pre class="programlisting">
  156. EXEC SQL BEGIN DECLARE SECTION;
  157. char str[50];
  158. EXEC SQL END DECLARE SECTION;
  159. </pre><p>
  160. Note that you have to take care of the length yourself. If you
  161. use this host variable as the target variable of a query which
  162. returns a string with more than 49 characters, a buffer overflow
  163. occurs.
  164. </p><p>
  165. The other way is using the <code class="type">VARCHAR</code> type, which is a
  166. special type provided by ECPG. The definition on an array of
  167. type <code class="type">VARCHAR</code> is converted into a
  168. named <code class="type">struct</code> for every variable. A declaration like:
  169. </p><pre class="programlisting">
  170. VARCHAR var[180];
  171. </pre><p>
  172. is converted into:
  173. </p><pre class="programlisting">
  174. struct varchar_var { int len; char arr[180]; } var;
  175. </pre><p>
  176. The member <code class="structfield">arr</code> hosts the string
  177. including a terminating zero byte. Thus, to store a string in
  178. a <code class="type">VARCHAR</code> host variable, the host variable has to be
  179. declared with the length including the zero byte terminator. The
  180. member <code class="structfield">len</code> holds the length of the
  181. string stored in the <code class="structfield">arr</code> without the
  182. terminating zero byte. When a host variable is used as input for
  183. a query, if <code class="literal">strlen(arr)</code>
  184. and <code class="structfield">len</code> are different, the shorter one
  185. is used.
  186. </p><p>
  187. <code class="type">VARCHAR</code> can be written in upper or lower case, but
  188. not in mixed case.
  189. </p><p>
  190. <code class="type">char</code> and <code class="type">VARCHAR</code> host variables can
  191. also hold values of other SQL types, which will be stored in
  192. their string forms.
  193. </p></div><div class="sect3" id="ECPG-SPECIAL-TYPES"><div class="titlepage"><div><div><h4 class="title">35.4.4.2. Accessing Special Data Types</h4></div></div></div><p>
  194. ECPG contains some special types that help you to interact easily
  195. with some special data types from the PostgreSQL server. In
  196. particular, it has implemented support for the
  197. <code class="type">numeric</code>, <code class="type">decimal</code>, <code class="type">date</code>, <code class="type">timestamp</code>,
  198. and <code class="type">interval</code> types. These data types cannot usefully be
  199. mapped to primitive host variable types (such
  200. as <code class="type">int</code>, <code class="type">long long int</code>,
  201. or <code class="type">char[]</code>), because they have a complex internal
  202. structure. Applications deal with these types by declaring host
  203. variables in special types and accessing them using functions in
  204. the pgtypes library. The pgtypes library, described in detail
  205. in <a class="xref" href="ecpg-pgtypes.html" title="35.6. pgtypes Library">Section 35.6</a> contains basic functions to deal
  206. with those types, such that you do not need to send a query to
  207. the SQL server just for adding an interval to a time stamp for
  208. example.
  209. </p><p>
  210. The follow subsections describe these special data types. For
  211. more details about pgtypes library functions,
  212. see <a class="xref" href="ecpg-pgtypes.html" title="35.6. pgtypes Library">Section 35.6</a>.
  213. </p><div class="sect4" id="id-1.7.5.10.7.7.4"><div class="titlepage"><div><div><h5 class="title">35.4.4.2.1. timestamp, date</h5></div></div></div><p>
  214. Here is a pattern for handling <code class="type">timestamp</code> variables
  215. in the ECPG host application.
  216. </p><p>
  217. First, the program has to include the header file for the
  218. <code class="type">timestamp</code> type:
  219. </p><pre class="programlisting">
  220. #include &lt;pgtypes_timestamp.h&gt;
  221. </pre><p>
  222. </p><p>
  223. Next, declare a host variable as type <code class="type">timestamp</code> in
  224. the declare section:
  225. </p><pre class="programlisting">
  226. EXEC SQL BEGIN DECLARE SECTION;
  227. timestamp ts;
  228. EXEC SQL END DECLARE SECTION;
  229. </pre><p>
  230. </p><p>
  231. And after reading a value into the host variable, process it
  232. using pgtypes library functions. In following example, the
  233. <code class="type">timestamp</code> value is converted into text (ASCII) form
  234. with the <code class="function">PGTYPEStimestamp_to_asc()</code>
  235. function:
  236. </p><pre class="programlisting">
  237. EXEC SQL SELECT now()::timestamp INTO :ts;
  238. printf("ts = %s\n", PGTYPEStimestamp_to_asc(ts));
  239. </pre><p>
  240. This example will show some result like following:
  241. </p><pre class="screen">
  242. ts = 2010-06-27 18:03:56.949343
  243. </pre><p>
  244. </p><p>
  245. In addition, the DATE type can be handled in the same way. The
  246. program has to include <code class="filename">pgtypes_date.h</code>, declare a host variable
  247. as the date type and convert a DATE value into a text form using
  248. <code class="function">PGTYPESdate_to_asc()</code> function. For more details about the
  249. pgtypes library functions, see <a class="xref" href="ecpg-pgtypes.html" title="35.6. pgtypes Library">Section 35.6</a>.
  250. </p></div><div class="sect4" id="ECPG-TYPE-INTERVAL"><div class="titlepage"><div><div><h5 class="title">35.4.4.2.2. interval</h5></div></div></div><p>
  251. The handling of the <code class="type">interval</code> type is also similar
  252. to the <code class="type">timestamp</code> and <code class="type">date</code> types. It
  253. is required, however, to allocate memory for
  254. an <code class="type">interval</code> type value explicitly. In other words,
  255. the memory space for the variable has to be allocated in the
  256. heap memory, not in the stack memory.
  257. </p><p>
  258. Here is an example program:
  259. </p><pre class="programlisting">
  260. #include &lt;stdio.h&gt;
  261. #include &lt;stdlib.h&gt;
  262. #include &lt;pgtypes_interval.h&gt;
  263. int
  264. main(void)
  265. {
  266. EXEC SQL BEGIN DECLARE SECTION;
  267. interval *in;
  268. EXEC SQL END DECLARE SECTION;
  269. EXEC SQL CONNECT TO testdb;
  270. EXEC SQL SELECT pg_catalog.set_config('search_path', '', false); EXEC SQL COMMIT;
  271. in = PGTYPESinterval_new();
  272. EXEC SQL SELECT '1 min'::interval INTO :in;
  273. printf("interval = %s\n", PGTYPESinterval_to_asc(in));
  274. PGTYPESinterval_free(in);
  275. EXEC SQL COMMIT;
  276. EXEC SQL DISCONNECT ALL;
  277. return 0;
  278. }
  279. </pre><p>
  280. </p></div><div class="sect4" id="ECPG-TYPE-NUMERIC-DECIMAL"><div class="titlepage"><div><div><h5 class="title">35.4.4.2.3. numeric, decimal</h5></div></div></div><p>
  281. The handling of the <code class="type">numeric</code>
  282. and <code class="type">decimal</code> types is similar to the
  283. <code class="type">interval</code> type: It requires defining a pointer,
  284. allocating some memory space on the heap, and accessing the
  285. variable using the pgtypes library functions. For more details
  286. about the pgtypes library functions,
  287. see <a class="xref" href="ecpg-pgtypes.html" title="35.6. pgtypes Library">Section 35.6</a>.
  288. </p><p>
  289. No functions are provided specifically for
  290. the <code class="type">decimal</code> type. An application has to convert it
  291. to a <code class="type">numeric</code> variable using a pgtypes library
  292. function to do further processing.
  293. </p><p>
  294. Here is an example program handling <code class="type">numeric</code>
  295. and <code class="type">decimal</code> type variables.
  296. </p><pre class="programlisting">
  297. #include &lt;stdio.h&gt;
  298. #include &lt;stdlib.h&gt;
  299. #include &lt;pgtypes_numeric.h&gt;
  300. EXEC SQL WHENEVER SQLERROR STOP;
  301. int
  302. main(void)
  303. {
  304. EXEC SQL BEGIN DECLARE SECTION;
  305. numeric *num;
  306. numeric *num2;
  307. decimal *dec;
  308. EXEC SQL END DECLARE SECTION;
  309. EXEC SQL CONNECT TO testdb;
  310. EXEC SQL SELECT pg_catalog.set_config('search_path', '', false); EXEC SQL COMMIT;
  311. num = PGTYPESnumeric_new();
  312. dec = PGTYPESdecimal_new();
  313. EXEC SQL SELECT 12.345::numeric(4,2), 23.456::decimal(4,2) INTO :num, :dec;
  314. printf("numeric = %s\n", PGTYPESnumeric_to_asc(num, 0));
  315. printf("numeric = %s\n", PGTYPESnumeric_to_asc(num, 1));
  316. printf("numeric = %s\n", PGTYPESnumeric_to_asc(num, 2));
  317. /* Convert decimal to numeric to show a decimal value. */
  318. num2 = PGTYPESnumeric_new();
  319. PGTYPESnumeric_from_decimal(dec, num2);
  320. printf("decimal = %s\n", PGTYPESnumeric_to_asc(num2, 0));
  321. printf("decimal = %s\n", PGTYPESnumeric_to_asc(num2, 1));
  322. printf("decimal = %s\n", PGTYPESnumeric_to_asc(num2, 2));
  323. PGTYPESnumeric_free(num2);
  324. PGTYPESdecimal_free(dec);
  325. PGTYPESnumeric_free(num);
  326. EXEC SQL COMMIT;
  327. EXEC SQL DISCONNECT ALL;
  328. return 0;
  329. }
  330. </pre><p>
  331. </p></div><div class="sect4" id="id-1.7.5.10.7.7.7"><div class="titlepage"><div><div><h5 class="title">35.4.4.2.4. bytea</h5></div></div></div><p>
  332. The handling of the <code class="type">bytea</code> type is similar to
  333. that of <code class="type">VARCHAR</code>. The definition on an array of type
  334. <code class="type">bytea</code> is converted into a named struct for every
  335. variable. A declaration like:
  336. </p><pre class="programlisting">
  337. bytea var[180];
  338. </pre><p>
  339. is converted into:
  340. </p><pre class="programlisting">
  341. struct bytea_var { int len; char arr[180]; } var;
  342. </pre><p>
  343. The member <code class="structfield">arr</code> hosts binary format
  344. data. It can also handle <code class="literal">'\0'</code> as part of
  345. data, unlike <code class="type">VARCHAR</code>.
  346. The data is converted from/to hex format and sent/received by
  347. ecpglib.
  348. </p><div class="note"><h3 class="title">Note</h3><p>
  349. <code class="type">bytea</code> variable can be used only when
  350. <a class="xref" href="runtime-config-client.html#GUC-BYTEA-OUTPUT">bytea_output</a> is set to <code class="literal">hex</code>.
  351. </p></div></div></div><div class="sect3" id="ECPG-VARIABLES-NONPRIMITIVE-C"><div class="titlepage"><div><div><h4 class="title">35.4.4.3. Host Variables with Nonprimitive Types</h4></div></div></div><p>
  352. As a host variable you can also use arrays, typedefs, structs, and
  353. pointers.
  354. </p><div class="sect4" id="ECPG-VARIABLES-ARRAYS"><div class="titlepage"><div><div><h5 class="title">35.4.4.3.1. Arrays</h5></div></div></div><p>
  355. There are two use cases for arrays as host variables. The first
  356. is a way to store some text string in <code class="type">char[]</code>
  357. or <code class="type">VARCHAR[]</code>, as
  358. explained in <a class="xref" href="ecpg-variables.html#ECPG-CHAR" title="35.4.4.1. Handling Character Strings">Section 35.4.4.1</a>. The second use case is to
  359. retrieve multiple rows from a query result without using a
  360. cursor. Without an array, to process a query result consisting
  361. of multiple rows, it is required to use a cursor and
  362. the <code class="command">FETCH</code> command. But with array host
  363. variables, multiple rows can be received at once. The length of
  364. the array has to be defined to be able to accommodate all rows,
  365. otherwise a buffer overflow will likely occur.
  366. </p><p>
  367. Following example scans the <code class="literal">pg_database</code>
  368. system table and shows all OIDs and names of the available
  369. databases:
  370. </p><pre class="programlisting">
  371. int
  372. main(void)
  373. {
  374. EXEC SQL BEGIN DECLARE SECTION;
  375. int dbid[8];
  376. char dbname[8][16];
  377. int i;
  378. EXEC SQL END DECLARE SECTION;
  379. memset(dbname, 0, sizeof(char)* 16 * 8);
  380. memset(dbid, 0, sizeof(int) * 8);
  381. EXEC SQL CONNECT TO testdb;
  382. EXEC SQL SELECT pg_catalog.set_config('search_path', '', false); EXEC SQL COMMIT;
  383. /* Retrieve multiple rows into arrays at once. */
  384. EXEC SQL SELECT oid,datname INTO :dbid, :dbname FROM pg_database;
  385. for (i = 0; i &lt; 8; i++)
  386. printf("oid=%d, dbname=%s\n", dbid[i], dbname[i]);
  387. EXEC SQL COMMIT;
  388. EXEC SQL DISCONNECT ALL;
  389. return 0;
  390. }
  391. </pre><p>
  392. This example shows following result. (The exact values depend on
  393. local circumstances.)
  394. </p><pre class="screen">
  395. oid=1, dbname=template1
  396. oid=11510, dbname=template0
  397. oid=11511, dbname=postgres
  398. oid=313780, dbname=testdb
  399. oid=0, dbname=
  400. oid=0, dbname=
  401. oid=0, dbname=
  402. </pre><p>
  403. </p></div><div class="sect4" id="ECPG-VARIABLES-STRUCT"><div class="titlepage"><div><div><h5 class="title">35.4.4.3.2. Structures</h5></div></div></div><p>
  404. A structure whose member names match the column names of a query
  405. result, can be used to retrieve multiple columns at once. The
  406. structure enables handling multiple column values in a single
  407. host variable.
  408. </p><p>
  409. The following example retrieves OIDs, names, and sizes of the
  410. available databases from the <code class="literal">pg_database</code>
  411. system table and using
  412. the <code class="function">pg_database_size()</code> function. In this
  413. example, a structure variable <code class="varname">dbinfo_t</code> with
  414. members whose names match each column in
  415. the <code class="literal">SELECT</code> result is used to retrieve one
  416. result row without putting multiple host variables in
  417. the <code class="literal">FETCH</code> statement.
  418. </p><pre class="programlisting">
  419. EXEC SQL BEGIN DECLARE SECTION;
  420. typedef struct
  421. {
  422. int oid;
  423. char datname[65];
  424. long long int size;
  425. } dbinfo_t;
  426. dbinfo_t dbval;
  427. EXEC SQL END DECLARE SECTION;
  428. memset(&amp;dbval, 0, sizeof(dbinfo_t));
  429. EXEC SQL DECLARE cur1 CURSOR FOR SELECT oid, datname, pg_database_size(oid) AS size FROM pg_database;
  430. EXEC SQL OPEN cur1;
  431. /* when end of result set reached, break out of while loop */
  432. EXEC SQL WHENEVER NOT FOUND DO BREAK;
  433. while (1)
  434. {
  435. /* Fetch multiple columns into one structure. */
  436. EXEC SQL FETCH FROM cur1 INTO :dbval;
  437. /* Print members of the structure. */
  438. printf("oid=%d, datname=%s, size=%lld\n", dbval.oid, dbval.datname, dbval.size);
  439. }
  440. EXEC SQL CLOSE cur1;
  441. </pre><p>
  442. </p><p>
  443. This example shows following result. (The exact values depend on
  444. local circumstances.)
  445. </p><pre class="screen">
  446. oid=1, datname=template1, size=4324580
  447. oid=11510, datname=template0, size=4243460
  448. oid=11511, datname=postgres, size=4324580
  449. oid=313780, datname=testdb, size=8183012
  450. </pre><p>
  451. </p><p>
  452. Structure host variables <span class="quote">“<span class="quote">absorb</span>”</span> as many columns
  453. as the structure as fields. Additional columns can be assigned
  454. to other host variables. For example, the above program could
  455. also be restructured like this, with the <code class="varname">size</code>
  456. variable outside the structure:
  457. </p><pre class="programlisting">
  458. EXEC SQL BEGIN DECLARE SECTION;
  459. typedef struct
  460. {
  461. int oid;
  462. char datname[65];
  463. } dbinfo_t;
  464. dbinfo_t dbval;
  465. long long int size;
  466. EXEC SQL END DECLARE SECTION;
  467. memset(&amp;dbval, 0, sizeof(dbinfo_t));
  468. EXEC SQL DECLARE cur1 CURSOR FOR SELECT oid, datname, pg_database_size(oid) AS size FROM pg_database;
  469. EXEC SQL OPEN cur1;
  470. /* when end of result set reached, break out of while loop */
  471. EXEC SQL WHENEVER NOT FOUND DO BREAK;
  472. while (1)
  473. {
  474. /* Fetch multiple columns into one structure. */
  475. EXEC SQL FETCH FROM cur1 INTO :dbval, :size;
  476. /* Print members of the structure. */
  477. printf("oid=%d, datname=%s, size=%lld\n", dbval.oid, dbval.datname, size);
  478. }
  479. EXEC SQL CLOSE cur1;
  480. </pre><p>
  481. </p></div><div class="sect4" id="id-1.7.5.10.7.8.5"><div class="titlepage"><div><div><h5 class="title">35.4.4.3.3. Typedefs</h5></div></div></div><p>
  482. Use the <code class="literal">typedef</code> keyword to map new types to already
  483. existing types.
  484. </p><pre class="programlisting">
  485. EXEC SQL BEGIN DECLARE SECTION;
  486. typedef char mychartype[40];
  487. typedef long serial_t;
  488. EXEC SQL END DECLARE SECTION;
  489. </pre><p>
  490. Note that you could also use:
  491. </p><pre class="programlisting">
  492. EXEC SQL TYPE serial_t IS long;
  493. </pre><p>
  494. This declaration does not need to be part of a declare section.
  495. </p></div><div class="sect4" id="id-1.7.5.10.7.8.6"><div class="titlepage"><div><div><h5 class="title">35.4.4.3.4. Pointers</h5></div></div></div><p>
  496. You can declare pointers to the most common types. Note however
  497. that you cannot use pointers as target variables of queries
  498. without auto-allocation. See <a class="xref" href="ecpg-descriptors.html" title="35.7. Using Descriptor Areas">Section 35.7</a>
  499. for more information on auto-allocation.
  500. </p><p>
  501. </p><pre class="programlisting">
  502. EXEC SQL BEGIN DECLARE SECTION;
  503. int *intp;
  504. char **charp;
  505. EXEC SQL END DECLARE SECTION;
  506. </pre><p>
  507. </p></div></div></div><div class="sect2" id="ECPG-VARIABLES-NONPRIMITIVE-SQL"><div class="titlepage"><div><div><h3 class="title">35.4.5. Handling Nonprimitive SQL Data Types</h3></div></div></div><p>
  508. This section contains information on how to handle nonscalar and
  509. user-defined SQL-level data types in ECPG applications. Note that
  510. this is distinct from the handling of host variables of
  511. nonprimitive types, described in the previous section.
  512. </p><div class="sect3" id="id-1.7.5.10.8.3"><div class="titlepage"><div><div><h4 class="title">35.4.5.1. Arrays</h4></div></div></div><p>
  513. Multi-dimensional SQL-level arrays are not directly supported in ECPG.
  514. One-dimensional SQL-level arrays can be mapped into C array host
  515. variables and vice-versa. However, when creating a statement ecpg does
  516. not know the types of the columns, so that it cannot check if a C array
  517. is input into a corresponding SQL-level array. When processing the
  518. output of a SQL statement, ecpg has the necessary information and thus
  519. checks if both are arrays.
  520. </p><p>
  521. If a query accesses <span class="emphasis"><em>elements</em></span> of an array
  522. separately, then this avoids the use of arrays in ECPG. Then, a
  523. host variable with a type that can be mapped to the element type
  524. should be used. For example, if a column type is array of
  525. <code class="type">integer</code>, a host variable of type <code class="type">int</code>
  526. can be used. Also if the element type is <code class="type">varchar</code>
  527. or <code class="type">text</code>, a host variable of type <code class="type">char[]</code>
  528. or <code class="type">VARCHAR[]</code> can be used.
  529. </p><p>
  530. Here is an example. Assume the following table:
  531. </p><pre class="programlisting">
  532. CREATE TABLE t3 (
  533. ii integer[]
  534. );
  535. testdb=&gt; SELECT * FROM t3;
  536. ii
  537. -------------
  538. {1,2,3,4,5}
  539. (1 row)
  540. </pre><p>
  541. The following example program retrieves the 4th element of the
  542. array and stores it into a host variable of
  543. type <code class="type">int</code>:
  544. </p><pre class="programlisting">
  545. EXEC SQL BEGIN DECLARE SECTION;
  546. int ii;
  547. EXEC SQL END DECLARE SECTION;
  548. EXEC SQL DECLARE cur1 CURSOR FOR SELECT ii[4] FROM t3;
  549. EXEC SQL OPEN cur1;
  550. EXEC SQL WHENEVER NOT FOUND DO BREAK;
  551. while (1)
  552. {
  553. EXEC SQL FETCH FROM cur1 INTO :ii ;
  554. printf("ii=%d\n", ii);
  555. }
  556. EXEC SQL CLOSE cur1;
  557. </pre><p>
  558. This example shows the following result:
  559. </p><pre class="screen">
  560. ii=4
  561. </pre><p>
  562. </p><p>
  563. To map multiple array elements to the multiple elements in an
  564. array type host variables each element of array column and each
  565. element of the host variable array have to be managed separately,
  566. for example:
  567. </p><pre class="programlisting">
  568. EXEC SQL BEGIN DECLARE SECTION;
  569. int ii_a[8];
  570. EXEC SQL END DECLARE SECTION;
  571. EXEC SQL DECLARE cur1 CURSOR FOR SELECT ii[1], ii[2], ii[3], ii[4] FROM t3;
  572. EXEC SQL OPEN cur1;
  573. EXEC SQL WHENEVER NOT FOUND DO BREAK;
  574. while (1)
  575. {
  576. EXEC SQL FETCH FROM cur1 INTO :ii_a[0], :ii_a[1], :ii_a[2], :ii_a[3];
  577. ...
  578. }
  579. </pre><p>
  580. </p><p>
  581. Note again that
  582. </p><pre class="programlisting">
  583. EXEC SQL BEGIN DECLARE SECTION;
  584. int ii_a[8];
  585. EXEC SQL END DECLARE SECTION;
  586. EXEC SQL DECLARE cur1 CURSOR FOR SELECT ii FROM t3;
  587. EXEC SQL OPEN cur1;
  588. EXEC SQL WHENEVER NOT FOUND DO BREAK;
  589. while (1)
  590. {
  591. /* WRONG */
  592. EXEC SQL FETCH FROM cur1 INTO :ii_a;
  593. ...
  594. }
  595. </pre><p>
  596. would not work correctly in this case, because you cannot map an
  597. array type column to an array host variable directly.
  598. </p><p>
  599. Another workaround is to store arrays in their external string
  600. representation in host variables of type <code class="type">char[]</code>
  601. or <code class="type">VARCHAR[]</code>. For more details about this
  602. representation, see <a class="xref" href="arrays.html#ARRAYS-INPUT" title="8.15.2. Array Value Input">Section 8.15.2</a>. Note that
  603. this means that the array cannot be accessed naturally as an
  604. array in the host program (without further processing that parses
  605. the text representation).
  606. </p></div><div class="sect3" id="id-1.7.5.10.8.4"><div class="titlepage"><div><div><h4 class="title">35.4.5.2. Composite Types</h4></div></div></div><p>
  607. Composite types are not directly supported in ECPG, but an easy workaround is possible.
  608. The
  609. available workarounds are similar to the ones described for
  610. arrays above: Either access each attribute separately or use the
  611. external string representation.
  612. </p><p>
  613. For the following examples, assume the following type and table:
  614. </p><pre class="programlisting">
  615. CREATE TYPE comp_t AS (intval integer, textval varchar(32));
  616. CREATE TABLE t4 (compval comp_t);
  617. INSERT INTO t4 VALUES ( (256, 'PostgreSQL') );
  618. </pre><p>
  619. The most obvious solution is to access each attribute separately.
  620. The following program retrieves data from the example table by
  621. selecting each attribute of the type <code class="type">comp_t</code>
  622. separately:
  623. </p><pre class="programlisting">
  624. EXEC SQL BEGIN DECLARE SECTION;
  625. int intval;
  626. varchar textval[33];
  627. EXEC SQL END DECLARE SECTION;
  628. /* Put each element of the composite type column in the SELECT list. */
  629. EXEC SQL DECLARE cur1 CURSOR FOR SELECT (compval).intval, (compval).textval FROM t4;
  630. EXEC SQL OPEN cur1;
  631. EXEC SQL WHENEVER NOT FOUND DO BREAK;
  632. while (1)
  633. {
  634. /* Fetch each element of the composite type column into host variables. */
  635. EXEC SQL FETCH FROM cur1 INTO :intval, :textval;
  636. printf("intval=%d, textval=%s\n", intval, textval.arr);
  637. }
  638. EXEC SQL CLOSE cur1;
  639. </pre><p>
  640. </p><p>
  641. To enhance this example, the host variables to store values in
  642. the <code class="command">FETCH</code> command can be gathered into one
  643. structure. For more details about the host variable in the
  644. structure form, see <a class="xref" href="ecpg-variables.html#ECPG-VARIABLES-STRUCT" title="35.4.4.3.2. Structures">Section 35.4.4.3.2</a>.
  645. To switch to the structure, the example can be modified as below.
  646. The two host variables, <code class="varname">intval</code>
  647. and <code class="varname">textval</code>, become members of
  648. the <code class="structname">comp_t</code> structure, and the structure
  649. is specified on the <code class="command">FETCH</code> command.
  650. </p><pre class="programlisting">
  651. EXEC SQL BEGIN DECLARE SECTION;
  652. typedef struct
  653. {
  654. int intval;
  655. varchar textval[33];
  656. } comp_t;
  657. comp_t compval;
  658. EXEC SQL END DECLARE SECTION;
  659. /* Put each element of the composite type column in the SELECT list. */
  660. EXEC SQL DECLARE cur1 CURSOR FOR SELECT (compval).intval, (compval).textval FROM t4;
  661. EXEC SQL OPEN cur1;
  662. EXEC SQL WHENEVER NOT FOUND DO BREAK;
  663. while (1)
  664. {
  665. /* Put all values in the SELECT list into one structure. */
  666. EXEC SQL FETCH FROM cur1 INTO :compval;
  667. printf("intval=%d, textval=%s\n", compval.intval, compval.textval.arr);
  668. }
  669. EXEC SQL CLOSE cur1;
  670. </pre><p>
  671. Although a structure is used in the <code class="command">FETCH</code>
  672. command, the attribute names in the <code class="command">SELECT</code>
  673. clause are specified one by one. This can be enhanced by using
  674. a <code class="literal">*</code> to ask for all attributes of the composite
  675. type value.
  676. </p><pre class="programlisting">
  677. ...
  678. EXEC SQL DECLARE cur1 CURSOR FOR SELECT (compval).* FROM t4;
  679. EXEC SQL OPEN cur1;
  680. EXEC SQL WHENEVER NOT FOUND DO BREAK;
  681. while (1)
  682. {
  683. /* Put all values in the SELECT list into one structure. */
  684. EXEC SQL FETCH FROM cur1 INTO :compval;
  685. printf("intval=%d, textval=%s\n", compval.intval, compval.textval.arr);
  686. }
  687. ...
  688. </pre><p>
  689. This way, composite types can be mapped into structures almost
  690. seamlessly, even though ECPG does not understand the composite
  691. type itself.
  692. </p><p>
  693. Finally, it is also possible to store composite type values in
  694. their external string representation in host variables of
  695. type <code class="type">char[]</code> or <code class="type">VARCHAR[]</code>. But that
  696. way, it is not easily possible to access the fields of the value
  697. from the host program.
  698. </p></div><div class="sect3" id="id-1.7.5.10.8.5"><div class="titlepage"><div><div><h4 class="title">35.4.5.3. User-Defined Base Types</h4></div></div></div><p>
  699. New user-defined base types are not directly supported by ECPG.
  700. You can use the external string representation and host variables
  701. of type <code class="type">char[]</code> or <code class="type">VARCHAR[]</code>, and this
  702. solution is indeed appropriate and sufficient for many types.
  703. </p><p>
  704. Here is an example using the data type <code class="type">complex</code> from
  705. the example in <a class="xref" href="xtypes.html" title="37.13. User-Defined Types">Section 37.13</a>. The external string
  706. representation of that type is <code class="literal">(%f,%f)</code>,
  707. which is defined in the
  708. functions <code class="function">complex_in()</code>
  709. and <code class="function">complex_out()</code> functions
  710. in <a class="xref" href="xtypes.html" title="37.13. User-Defined Types">Section 37.13</a>. The following example inserts the
  711. complex type values <code class="literal">(1,1)</code>
  712. and <code class="literal">(3,3)</code> into the
  713. columns <code class="literal">a</code> and <code class="literal">b</code>, and select
  714. them from the table after that.
  715. </p><pre class="programlisting">
  716. EXEC SQL BEGIN DECLARE SECTION;
  717. varchar a[64];
  718. varchar b[64];
  719. EXEC SQL END DECLARE SECTION;
  720. EXEC SQL INSERT INTO test_complex VALUES ('(1,1)', '(3,3)');
  721. EXEC SQL DECLARE cur1 CURSOR FOR SELECT a, b FROM test_complex;
  722. EXEC SQL OPEN cur1;
  723. EXEC SQL WHENEVER NOT FOUND DO BREAK;
  724. while (1)
  725. {
  726. EXEC SQL FETCH FROM cur1 INTO :a, :b;
  727. printf("a=%s, b=%s\n", a.arr, b.arr);
  728. }
  729. EXEC SQL CLOSE cur1;
  730. </pre><p>
  731. This example shows following result:
  732. </p><pre class="screen">
  733. a=(1,1), b=(3,3)
  734. </pre><p>
  735. </p><p>
  736. Another workaround is avoiding the direct use of the user-defined
  737. types in ECPG and instead create a function or cast that converts
  738. between the user-defined type and a primitive type that ECPG can
  739. handle. Note, however, that type casts, especially implicit
  740. ones, should be introduced into the type system very carefully.
  741. </p><p>
  742. For example,
  743. </p><pre class="programlisting">
  744. CREATE FUNCTION create_complex(r double, i double) RETURNS complex
  745. LANGUAGE SQL
  746. IMMUTABLE
  747. AS $$ SELECT $1 * complex '(1,0')' + $2 * complex '(0,1)' $$;
  748. </pre><p>
  749. After this definition, the following
  750. </p><pre class="programlisting">
  751. EXEC SQL BEGIN DECLARE SECTION;
  752. double a, b, c, d;
  753. EXEC SQL END DECLARE SECTION;
  754. a = 1;
  755. b = 2;
  756. c = 3;
  757. d = 4;
  758. EXEC SQL INSERT INTO test_complex VALUES (create_complex(:a, :b), create_complex(:c, :d));
  759. </pre><p>
  760. has the same effect as
  761. </p><pre class="programlisting">
  762. EXEC SQL INSERT INTO test_complex VALUES ('(1,2)', '(3,4)');
  763. </pre><p>
  764. </p></div></div><div class="sect2" id="ECPG-INDICATORS"><div class="titlepage"><div><div><h3 class="title">35.4.6. Indicators</h3></div></div></div><p>
  765. The examples above do not handle null values. In fact, the
  766. retrieval examples will raise an error if they fetch a null value
  767. from the database. To be able to pass null values to the database
  768. or retrieve null values from the database, you need to append a
  769. second host variable specification to each host variable that
  770. contains data. This second host variable is called the
  771. <em class="firstterm">indicator</em> and contains a flag that tells
  772. whether the datum is null, in which case the value of the real
  773. host variable is ignored. Here is an example that handles the
  774. retrieval of null values correctly:
  775. </p><pre class="programlisting">
  776. EXEC SQL BEGIN DECLARE SECTION;
  777. VARCHAR val;
  778. int val_ind;
  779. EXEC SQL END DECLARE SECTION:
  780. ...
  781. EXEC SQL SELECT b INTO :val :val_ind FROM test1;
  782. </pre><p>
  783. The indicator variable <code class="varname">val_ind</code> will be zero if
  784. the value was not null, and it will be negative if the value was
  785. null.
  786. </p><p>
  787. The indicator has another function: if the indicator value is
  788. positive, it means that the value is not null, but it was
  789. truncated when it was stored in the host variable.
  790. </p><p>
  791. If the argument <code class="literal">-r no_indicator</code> is passed to
  792. the preprocessor <code class="command">ecpg</code>, it works in
  793. <span class="quote">“<span class="quote">no-indicator</span>”</span> mode. In no-indicator mode, if no
  794. indicator variable is specified, null values are signaled (on
  795. input and output) for character string types as empty string and
  796. for integer types as the lowest possible value for type (for
  797. example, <code class="symbol">INT_MIN</code> for <code class="type">int</code>).
  798. </p></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="ecpg-commands.html">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="ecpg.html">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="ecpg-dynamic.html">Next</a></td></tr><tr><td width="40%" align="left" valign="top">35.3. Running SQL Commands </td><td width="20%" align="center"><a accesskey="h" href="index.html">Home</a></td><td width="40%" align="right" valign="top"> 35.5. Dynamic SQL</td></tr></table></div></body></html>
上海开阖软件有限公司 沪ICP备12045867号-1