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

559 行
28KB

  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>42.13. Porting from Oracle PL/SQL</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="plpgsql-development-tips.html" title="42.12. Tips for Developing in PL/pgSQL" /><link rel="next" href="pltcl.html" title="Chapter 43. PL/Tcl - Tcl Procedural Language" /></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">42.13. Porting from <span xmlns="http://www.w3.org/1999/xhtml" class="productname">Oracle</span> PL/SQL</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="plpgsql-development-tips.html" title="42.12. Tips for Developing in PL/pgSQL">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="plpgsql.html" title="Chapter 42. PL/pgSQL - SQL Procedural Language">Up</a></td><th width="60%" align="center">Chapter 42. <span xmlns="http://www.w3.org/1999/xhtml" class="application">PL/pgSQL</span> - <acronym xmlns="http://www.w3.org/1999/xhtml" class="acronym">SQL</acronym> Procedural Language</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="pltcl.html" title="Chapter 43. PL/Tcl - Tcl Procedural Language">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="PLPGSQL-PORTING"><div class="titlepage"><div><div><h2 class="title" style="clear: both">42.13. Porting from <span class="productname">Oracle</span> PL/SQL</h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="plpgsql-porting.html#id-1.8.8.15.6">42.13.1. Porting Examples</a></span></dt><dt><span class="sect2"><a href="plpgsql-porting.html#PLPGSQL-PORTING-OTHER">42.13.2. Other Things to Watch For</a></span></dt><dt><span class="sect2"><a href="plpgsql-porting.html#PLPGSQL-PORTING-APPENDIX">42.13.3. Appendix</a></span></dt></dl></div><a id="id-1.8.8.15.2" class="indexterm"></a><a id="id-1.8.8.15.3" class="indexterm"></a><p>
  3. This section explains differences between
  4. <span class="productname">PostgreSQL</span>'s <span class="application">PL/pgSQL</span>
  5. language and Oracle's <span class="application">PL/SQL</span> language,
  6. to help developers who port applications from
  7. <span class="trademark">Oracle</span>® to <span class="productname">PostgreSQL</span>.
  8. </p><p>
  9. <span class="application">PL/pgSQL</span> is similar to PL/SQL in many
  10. aspects. It is a block-structured, imperative language, and all
  11. variables have to be declared. Assignments, loops, and conditionals
  12. are similar. The main differences you should keep in mind when
  13. porting from <span class="application">PL/SQL</span> to
  14. <span class="application">PL/pgSQL</span> are:
  15. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
  16. If a name used in a SQL command could be either a column name of a
  17. table or a reference to a variable of the function,
  18. <span class="application">PL/SQL</span> treats it as a column name. This corresponds
  19. to <span class="application">PL/pgSQL</span>'s
  20. <code class="literal">plpgsql.variable_conflict</code> = <code class="literal">use_column</code>
  21. behavior, which is not the default,
  22. as explained in <a class="xref" href="plpgsql-implementation.html#PLPGSQL-VAR-SUBST" title="42.11.1. Variable Substitution">Section 42.11.1</a>.
  23. It's often best to avoid such ambiguities in the first place,
  24. but if you have to port a large amount of code that depends on
  25. this behavior, setting <code class="literal">variable_conflict</code> may be the
  26. best solution.
  27. </p></li><li class="listitem"><p>
  28. In <span class="productname">PostgreSQL</span> the function body must be written as
  29. a string literal. Therefore you need to use dollar quoting or escape
  30. single quotes in the function body. (See <a class="xref" href="plpgsql-development-tips.html#PLPGSQL-QUOTE-TIPS" title="42.12.1. Handling of Quotation Marks">Section 42.12.1</a>.)
  31. </p></li><li class="listitem"><p>
  32. Data type names often need translation. For example, in Oracle string
  33. values are commonly declared as being of type <code class="type">varchar2</code>, which
  34. is a non-SQL-standard type. In <span class="productname">PostgreSQL</span>,
  35. use type <code class="type">varchar</code> or <code class="type">text</code> instead. Similarly, replace
  36. type <code class="type">number</code> with <code class="type">numeric</code>, or use some other numeric
  37. data type if there's a more appropriate one.
  38. </p></li><li class="listitem"><p>
  39. Instead of packages, use schemas to organize your functions
  40. into groups.
  41. </p></li><li class="listitem"><p>
  42. Since there are no packages, there are no package-level variables
  43. either. This is somewhat annoying. You can keep per-session state
  44. in temporary tables instead.
  45. </p></li><li class="listitem"><p>
  46. Integer <code class="command">FOR</code> loops with <code class="literal">REVERSE</code> work
  47. differently: <span class="application">PL/SQL</span> counts down from the second
  48. number to the first, while <span class="application">PL/pgSQL</span> counts down
  49. from the first number to the second, requiring the loop bounds
  50. to be swapped when porting. This incompatibility is unfortunate
  51. but is unlikely to be changed. (See <a class="xref" href="plpgsql-control-structures.html#PLPGSQL-INTEGER-FOR" title="42.6.5.5. FOR (Integer Variant)">Section 42.6.5.5</a>.)
  52. </p></li><li class="listitem"><p>
  53. <code class="command">FOR</code> loops over queries (other than cursors) also work
  54. differently: the target variable(s) must have been declared,
  55. whereas <span class="application">PL/SQL</span> always declares them implicitly.
  56. An advantage of this is that the variable values are still accessible
  57. after the loop exits.
  58. </p></li><li class="listitem"><p>
  59. There are various notational differences for the use of cursor
  60. variables.
  61. </p></li></ul></div><p>
  62. </p><div class="sect2" id="id-1.8.8.15.6"><div class="titlepage"><div><div><h3 class="title">42.13.1. Porting Examples</h3></div></div></div><p>
  63. <a class="xref" href="plpgsql-porting.html#PGSQL-PORTING-EX1" title="Example 42.9. Porting a Simple Function from PL/SQL to PL/pgSQL">Example 42.9</a> shows how to port a simple
  64. function from <span class="application">PL/SQL</span> to <span class="application">PL/pgSQL</span>.
  65. </p><div class="example" id="PGSQL-PORTING-EX1"><p class="title"><strong>Example 42.9. Porting a Simple Function from <span class="application">PL/SQL</span> to <span class="application">PL/pgSQL</span></strong></p><div class="example-contents"><p>
  66. Here is an <span class="productname">Oracle</span> <span class="application">PL/SQL</span> function:
  67. </p><pre class="programlisting">
  68. CREATE OR REPLACE FUNCTION cs_fmt_browser_version(v_name varchar2,
  69. v_version varchar2)
  70. RETURN varchar2 IS
  71. BEGIN
  72. IF v_version IS NULL THEN
  73. RETURN v_name;
  74. END IF;
  75. RETURN v_name || '/' || v_version;
  76. END;
  77. /
  78. show errors;
  79. </pre><p>
  80. </p><p>
  81. Let's go through this function and see the differences compared to
  82. <span class="application">PL/pgSQL</span>:
  83. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
  84. The type name <code class="type">varchar2</code> has to be changed to <code class="type">varchar</code>
  85. or <code class="type">text</code>. In the examples in this section, we'll
  86. use <code class="type">varchar</code>, but <code class="type">text</code> is often a better choice if
  87. you do not need specific string length limits.
  88. </p></li><li class="listitem"><p>
  89. The <code class="literal">RETURN</code> key word in the function
  90. prototype (not the function body) becomes
  91. <code class="literal">RETURNS</code> in
  92. <span class="productname">PostgreSQL</span>.
  93. Also, <code class="literal">IS</code> becomes <code class="literal">AS</code>, and you need to
  94. add a <code class="literal">LANGUAGE</code> clause because <span class="application">PL/pgSQL</span>
  95. is not the only possible function language.
  96. </p></li><li class="listitem"><p>
  97. In <span class="productname">PostgreSQL</span>, the function body is considered
  98. to be a string literal, so you need to use quote marks or dollar
  99. quotes around it. This substitutes for the terminating <code class="literal">/</code>
  100. in the Oracle approach.
  101. </p></li><li class="listitem"><p>
  102. The <code class="literal">show errors</code> command does not exist in
  103. <span class="productname">PostgreSQL</span>, and is not needed since errors are
  104. reported automatically.
  105. </p></li></ul></div><p>
  106. </p><p>
  107. This is how this function would look when ported to
  108. <span class="productname">PostgreSQL</span>:
  109. </p><pre class="programlisting">
  110. CREATE OR REPLACE FUNCTION cs_fmt_browser_version(v_name varchar,
  111. v_version varchar)
  112. RETURNS varchar AS $$
  113. BEGIN
  114. IF v_version IS NULL THEN
  115. RETURN v_name;
  116. END IF;
  117. RETURN v_name || '/' || v_version;
  118. END;
  119. $$ LANGUAGE plpgsql;
  120. </pre><p>
  121. </p></div></div><br class="example-break" /><p>
  122. <a class="xref" href="plpgsql-porting.html#PLPGSQL-PORTING-EX2" title="Example 42.10. Porting a Function that Creates Another Function from PL/SQL to PL/pgSQL">Example 42.10</a> shows how to port a
  123. function that creates another function and how to handle the
  124. ensuing quoting problems.
  125. </p><div class="example" id="PLPGSQL-PORTING-EX2"><p class="title"><strong>Example 42.10. Porting a Function that Creates Another Function from <span class="application">PL/SQL</span> to <span class="application">PL/pgSQL</span></strong></p><div class="example-contents"><p>
  126. The following procedure grabs rows from a
  127. <code class="command">SELECT</code> statement and builds a large function
  128. with the results in <code class="literal">IF</code> statements, for the
  129. sake of efficiency.
  130. </p><p>
  131. This is the Oracle version:
  132. </p><pre class="programlisting">
  133. CREATE OR REPLACE PROCEDURE cs_update_referrer_type_proc IS
  134. CURSOR referrer_keys IS
  135. SELECT * FROM cs_referrer_keys
  136. ORDER BY try_order;
  137. func_cmd VARCHAR(4000);
  138. BEGIN
  139. func_cmd := 'CREATE OR REPLACE FUNCTION cs_find_referrer_type(v_host IN VARCHAR2,
  140. v_domain IN VARCHAR2, v_url IN VARCHAR2) RETURN VARCHAR2 IS BEGIN';
  141. FOR referrer_key IN referrer_keys LOOP
  142. func_cmd := func_cmd ||
  143. ' IF v_' || referrer_key.kind
  144. || ' LIKE ''' || referrer_key.key_string
  145. || ''' THEN RETURN ''' || referrer_key.referrer_type
  146. || '''; END IF;';
  147. END LOOP;
  148. func_cmd := func_cmd || ' RETURN NULL; END;';
  149. EXECUTE IMMEDIATE func_cmd;
  150. END;
  151. /
  152. show errors;
  153. </pre><p>
  154. </p><p>
  155. Here is how this function would end up in <span class="productname">PostgreSQL</span>:
  156. </p><pre class="programlisting">
  157. CREATE OR REPLACE PROCEDURE cs_update_referrer_type_proc() AS $func$
  158. DECLARE
  159. referrer_keys CURSOR IS
  160. SELECT * FROM cs_referrer_keys
  161. ORDER BY try_order;
  162. func_body text;
  163. func_cmd text;
  164. BEGIN
  165. func_body := 'BEGIN';
  166. FOR referrer_key IN referrer_keys LOOP
  167. func_body := func_body ||
  168. ' IF v_' || referrer_key.kind
  169. || ' LIKE ' || quote_literal(referrer_key.key_string)
  170. || ' THEN RETURN ' || quote_literal(referrer_key.referrer_type)
  171. || '; END IF;' ;
  172. END LOOP;
  173. func_body := func_body || ' RETURN NULL; END;';
  174. func_cmd :=
  175. 'CREATE OR REPLACE FUNCTION cs_find_referrer_type(v_host varchar,
  176. v_domain varchar,
  177. v_url varchar)
  178. RETURNS varchar AS '
  179. || quote_literal(func_body)
  180. || ' LANGUAGE plpgsql;' ;
  181. EXECUTE func_cmd;
  182. END;
  183. $func$ LANGUAGE plpgsql;
  184. </pre><p>
  185. Notice how the body of the function is built separately and passed
  186. through <code class="literal">quote_literal</code> to double any quote marks in it. This
  187. technique is needed because we cannot safely use dollar quoting for
  188. defining the new function: we do not know for sure what strings will
  189. be interpolated from the <code class="structfield">referrer_key.key_string</code> field.
  190. (We are assuming here that <code class="structfield">referrer_key.kind</code> can be
  191. trusted to always be <code class="literal">host</code>, <code class="literal">domain</code>, or
  192. <code class="literal">url</code>, but <code class="structfield">referrer_key.key_string</code> might be
  193. anything, in particular it might contain dollar signs.) This function
  194. is actually an improvement on the Oracle original, because it will
  195. not generate broken code when <code class="structfield">referrer_key.key_string</code> or
  196. <code class="structfield">referrer_key.referrer_type</code> contain quote marks.
  197. </p></div></div><br class="example-break" /><p>
  198. <a class="xref" href="plpgsql-porting.html#PLPGSQL-PORTING-EX3" title="Example 42.11. Porting a Procedure With String Manipulation and OUT Parameters from PL/SQL to PL/pgSQL">Example 42.11</a> shows how to port a function
  199. with <code class="literal">OUT</code> parameters and string manipulation.
  200. <span class="productname">PostgreSQL</span> does not have a built-in
  201. <code class="function">instr</code> function, but you can create one
  202. using a combination of other
  203. functions. In <a class="xref" href="plpgsql-porting.html#PLPGSQL-PORTING-APPENDIX" title="42.13.3. Appendix">Section 42.13.3</a> there is a
  204. <span class="application">PL/pgSQL</span> implementation of
  205. <code class="function">instr</code> that you can use to make your porting
  206. easier.
  207. </p><div class="example" id="PLPGSQL-PORTING-EX3"><p class="title"><strong>Example 42.11. Porting a Procedure With String Manipulation and
  208. <code class="literal">OUT</code> Parameters from <span class="application">PL/SQL</span> to
  209. <span class="application">PL/pgSQL</span></strong></p><div class="example-contents"><p>
  210. The following <span class="productname">Oracle</span> PL/SQL procedure is used
  211. to parse a URL and return several elements (host, path, and query).
  212. </p><p>
  213. This is the Oracle version:
  214. </p><pre class="programlisting">
  215. CREATE OR REPLACE PROCEDURE cs_parse_url(
  216. v_url IN VARCHAR2,
  217. v_host OUT VARCHAR2, -- This will be passed back
  218. v_path OUT VARCHAR2, -- This one too
  219. v_query OUT VARCHAR2) -- And this one
  220. IS
  221. a_pos1 INTEGER;
  222. a_pos2 INTEGER;
  223. BEGIN
  224. v_host := NULL;
  225. v_path := NULL;
  226. v_query := NULL;
  227. a_pos1 := instr(v_url, '//');
  228. IF a_pos1 = 0 THEN
  229. RETURN;
  230. END IF;
  231. a_pos2 := instr(v_url, '/', a_pos1 + 2);
  232. IF a_pos2 = 0 THEN
  233. v_host := substr(v_url, a_pos1 + 2);
  234. v_path := '/';
  235. RETURN;
  236. END IF;
  237. v_host := substr(v_url, a_pos1 + 2, a_pos2 - a_pos1 - 2);
  238. a_pos1 := instr(v_url, '?', a_pos2 + 1);
  239. IF a_pos1 = 0 THEN
  240. v_path := substr(v_url, a_pos2);
  241. RETURN;
  242. END IF;
  243. v_path := substr(v_url, a_pos2, a_pos1 - a_pos2);
  244. v_query := substr(v_url, a_pos1 + 1);
  245. END;
  246. /
  247. show errors;
  248. </pre><p>
  249. </p><p>
  250. Here is a possible translation into <span class="application">PL/pgSQL</span>:
  251. </p><pre class="programlisting">
  252. CREATE OR REPLACE FUNCTION cs_parse_url(
  253. v_url IN VARCHAR,
  254. v_host OUT VARCHAR, -- This will be passed back
  255. v_path OUT VARCHAR, -- This one too
  256. v_query OUT VARCHAR) -- And this one
  257. AS $$
  258. DECLARE
  259. a_pos1 INTEGER;
  260. a_pos2 INTEGER;
  261. BEGIN
  262. v_host := NULL;
  263. v_path := NULL;
  264. v_query := NULL;
  265. a_pos1 := instr(v_url, '//');
  266. IF a_pos1 = 0 THEN
  267. RETURN;
  268. END IF;
  269. a_pos2 := instr(v_url, '/', a_pos1 + 2);
  270. IF a_pos2 = 0 THEN
  271. v_host := substr(v_url, a_pos1 + 2);
  272. v_path := '/';
  273. RETURN;
  274. END IF;
  275. v_host := substr(v_url, a_pos1 + 2, a_pos2 - a_pos1 - 2);
  276. a_pos1 := instr(v_url, '?', a_pos2 + 1);
  277. IF a_pos1 = 0 THEN
  278. v_path := substr(v_url, a_pos2);
  279. RETURN;
  280. END IF;
  281. v_path := substr(v_url, a_pos2, a_pos1 - a_pos2);
  282. v_query := substr(v_url, a_pos1 + 1);
  283. END;
  284. $$ LANGUAGE plpgsql;
  285. </pre><p>
  286. This function could be used like this:
  287. </p><pre class="programlisting">
  288. SELECT * FROM cs_parse_url('http://foobar.com/query.cgi?baz');
  289. </pre><p>
  290. </p></div></div><br class="example-break" /><p>
  291. <a class="xref" href="plpgsql-porting.html#PLPGSQL-PORTING-EX4" title="Example 42.12. Porting a Procedure from PL/SQL to PL/pgSQL">Example 42.12</a> shows how to port a procedure
  292. that uses numerous features that are specific to Oracle.
  293. </p><div class="example" id="PLPGSQL-PORTING-EX4"><p class="title"><strong>Example 42.12. Porting a Procedure from <span class="application">PL/SQL</span> to <span class="application">PL/pgSQL</span></strong></p><div class="example-contents"><p>
  294. The Oracle version:
  295. </p><pre class="programlisting">
  296. CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id IN INTEGER) IS
  297. a_running_job_count INTEGER;
  298. BEGIN
  299. LOCK TABLE cs_jobs IN EXCLUSIVE MODE;
  300. SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NULL;
  301. IF a_running_job_count &gt; 0 THEN
  302. COMMIT; -- free lock
  303. raise_application_error(-20000,
  304. 'Unable to create a new job: a job is currently running.');
  305. END IF;
  306. DELETE FROM cs_active_job;
  307. INSERT INTO cs_active_job(job_id) VALUES (v_job_id);
  308. BEGIN
  309. INSERT INTO cs_jobs (job_id, start_stamp) VALUES (v_job_id, now());
  310. EXCEPTION
  311. WHEN dup_val_on_index THEN NULL; -- don't worry if it already exists
  312. END;
  313. COMMIT;
  314. END;
  315. /
  316. show errors
  317. </pre><p>
  318. </p><p>
  319. This is how we could port this procedure to <span class="application">PL/pgSQL</span>:
  320. </p><pre class="programlisting">
  321. CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id integer) AS $$
  322. DECLARE
  323. a_running_job_count integer;
  324. BEGIN
  325. LOCK TABLE cs_jobs IN EXCLUSIVE MODE;
  326. SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NULL;
  327. IF a_running_job_count &gt; 0 THEN
  328. COMMIT; -- free lock
  329. RAISE EXCEPTION 'Unable to create a new job: a job is currently running'; -- <span id="co.plpgsql-porting-raise"></span>(1)
  330. END IF;
  331. DELETE FROM cs_active_job;
  332. INSERT INTO cs_active_job(job_id) VALUES (v_job_id);
  333. BEGIN
  334. INSERT INTO cs_jobs (job_id, start_stamp) VALUES (v_job_id, now());
  335. EXCEPTION
  336. WHEN unique_violation THEN -- <span id="co.plpgsql-porting-exception"></span>(2)
  337. -- don't worry if it already exists
  338. END;
  339. COMMIT;
  340. END;
  341. $$ LANGUAGE plpgsql;
  342. </pre><p>
  343. </p><div class="calloutlist"><table border="0" summary="Callout list"><tr><td width="5%" valign="top" align="left"><p><a href="#co.plpgsql-porting-raise">(1)</a> </p></td><td valign="top" align="left"><p>
  344. The syntax of <code class="literal">RAISE</code> is considerably different from
  345. Oracle's statement, although the basic case <code class="literal">RAISE</code>
  346. <em class="replaceable"><code>exception_name</code></em> works
  347. similarly.
  348. </p></td></tr><tr><td width="5%" valign="top" align="left"><p><a href="#co.plpgsql-porting-exception">(2)</a> </p></td><td valign="top" align="left"><p>
  349. The exception names supported by <span class="application">PL/pgSQL</span> are
  350. different from Oracle's. The set of built-in exception names
  351. is much larger (see <a class="xref" href="errcodes-appendix.html" title="Appendix A. PostgreSQL Error Codes">Appendix A</a>). There
  352. is not currently a way to declare user-defined exception names,
  353. although you can throw user-chosen SQLSTATE values instead.
  354. </p></td></tr></table></div><p>
  355. </p></div></div><br class="example-break" /></div><div class="sect2" id="PLPGSQL-PORTING-OTHER"><div class="titlepage"><div><div><h3 class="title">42.13.2. Other Things to Watch For</h3></div></div></div><p>
  356. This section explains a few other things to watch for when porting
  357. Oracle <span class="application">PL/SQL</span> functions to
  358. <span class="productname">PostgreSQL</span>.
  359. </p><div class="sect3" id="PLPGSQL-PORTING-EXCEPTIONS"><div class="titlepage"><div><div><h4 class="title">42.13.2.1. Implicit Rollback after Exceptions</h4></div></div></div><p>
  360. In <span class="application">PL/pgSQL</span>, when an exception is caught by an
  361. <code class="literal">EXCEPTION</code> clause, all database changes since the block's
  362. <code class="literal">BEGIN</code> are automatically rolled back. That is, the behavior
  363. is equivalent to what you'd get in Oracle with:
  364. </p><pre class="programlisting">
  365. BEGIN
  366. SAVEPOINT s1;
  367. ... code here ...
  368. EXCEPTION
  369. WHEN ... THEN
  370. ROLLBACK TO s1;
  371. ... code here ...
  372. WHEN ... THEN
  373. ROLLBACK TO s1;
  374. ... code here ...
  375. END;
  376. </pre><p>
  377. If you are translating an Oracle procedure that uses
  378. <code class="command">SAVEPOINT</code> and <code class="command">ROLLBACK TO</code> in this style,
  379. your task is easy: just omit the <code class="command">SAVEPOINT</code> and
  380. <code class="command">ROLLBACK TO</code>. If you have a procedure that uses
  381. <code class="command">SAVEPOINT</code> and <code class="command">ROLLBACK TO</code> in a different way
  382. then some actual thought will be required.
  383. </p></div><div class="sect3" id="id-1.8.8.15.7.4"><div class="titlepage"><div><div><h4 class="title">42.13.2.2. <code class="command">EXECUTE</code></h4></div></div></div><p>
  384. The <span class="application">PL/pgSQL</span> version of
  385. <code class="command">EXECUTE</code> works similarly to the
  386. <span class="application">PL/SQL</span> version, but you have to remember to use
  387. <code class="function">quote_literal</code> and
  388. <code class="function">quote_ident</code> as described in <a class="xref" href="plpgsql-statements.html#PLPGSQL-STATEMENTS-EXECUTING-DYN" title="42.5.4. Executing Dynamic Commands">Section 42.5.4</a>. Constructs of the
  389. type <code class="literal">EXECUTE 'SELECT * FROM $1';</code> will not work
  390. reliably unless you use these functions.
  391. </p></div><div class="sect3" id="PLPGSQL-PORTING-OPTIMIZATION"><div class="titlepage"><div><div><h4 class="title">42.13.2.3. Optimizing <span class="application">PL/pgSQL</span> Functions</h4></div></div></div><p>
  392. <span class="productname">PostgreSQL</span> gives you two function creation
  393. modifiers to optimize execution: <span class="quote">“<span class="quote">volatility</span>”</span> (whether
  394. the function always returns the same result when given the same
  395. arguments) and <span class="quote">“<span class="quote">strictness</span>”</span> (whether the function
  396. returns null if any argument is null). Consult the <a class="xref" href="sql-createfunction.html" title="CREATE FUNCTION"><span class="refentrytitle">CREATE FUNCTION</span></a>
  397. reference page for details.
  398. </p><p>
  399. When making use of these optimization attributes, your
  400. <code class="command">CREATE FUNCTION</code> statement might look something
  401. like this:
  402. </p><pre class="programlisting">
  403. CREATE FUNCTION foo(...) RETURNS integer AS $$
  404. ...
  405. $$ LANGUAGE plpgsql STRICT IMMUTABLE;
  406. </pre><p>
  407. </p></div></div><div class="sect2" id="PLPGSQL-PORTING-APPENDIX"><div class="titlepage"><div><div><h3 class="title">42.13.3. Appendix</h3></div></div></div><p>
  408. This section contains the code for a set of Oracle-compatible
  409. <code class="function">instr</code> functions that you can use to simplify
  410. your porting efforts.
  411. </p><a id="id-1.8.8.15.8.3" class="indexterm"></a><pre class="programlisting">
  412. --
  413. -- instr functions that mimic Oracle's counterpart
  414. -- Syntax: instr(string1, string2 [, n [, m]])
  415. -- where [] denotes optional parameters.
  416. --
  417. -- Search string1, beginning at the nth character, for the mth occurrence
  418. -- of string2. If n is negative, search backwards, starting at the abs(n)'th
  419. -- character from the end of string1.
  420. -- If n is not passed, assume 1 (search starts at first character).
  421. -- If m is not passed, assume 1 (find first occurrence).
  422. -- Returns starting index of string2 in string1, or 0 if string2 is not found.
  423. --
  424. CREATE FUNCTION instr(varchar, varchar) RETURNS integer AS $$
  425. BEGIN
  426. RETURN instr($1, $2, 1);
  427. END;
  428. $$ LANGUAGE plpgsql STRICT IMMUTABLE;
  429. CREATE FUNCTION instr(string varchar, string_to_search_for varchar,
  430. beg_index integer)
  431. RETURNS integer AS $$
  432. DECLARE
  433. pos integer NOT NULL DEFAULT 0;
  434. temp_str varchar;
  435. beg integer;
  436. length integer;
  437. ss_length integer;
  438. BEGIN
  439. IF beg_index &gt; 0 THEN
  440. temp_str := substring(string FROM beg_index);
  441. pos := position(string_to_search_for IN temp_str);
  442. IF pos = 0 THEN
  443. RETURN 0;
  444. ELSE
  445. RETURN pos + beg_index - 1;
  446. END IF;
  447. ELSIF beg_index &lt; 0 THEN
  448. ss_length := char_length(string_to_search_for);
  449. length := char_length(string);
  450. beg := length + 1 + beg_index;
  451. WHILE beg &gt; 0 LOOP
  452. temp_str := substring(string FROM beg FOR ss_length);
  453. IF string_to_search_for = temp_str THEN
  454. RETURN beg;
  455. END IF;
  456. beg := beg - 1;
  457. END LOOP;
  458. RETURN 0;
  459. ELSE
  460. RETURN 0;
  461. END IF;
  462. END;
  463. $$ LANGUAGE plpgsql STRICT IMMUTABLE;
  464. CREATE FUNCTION instr(string varchar, string_to_search_for varchar,
  465. beg_index integer, occur_index integer)
  466. RETURNS integer AS $$
  467. DECLARE
  468. pos integer NOT NULL DEFAULT 0;
  469. occur_number integer NOT NULL DEFAULT 0;
  470. temp_str varchar;
  471. beg integer;
  472. i integer;
  473. length integer;
  474. ss_length integer;
  475. BEGIN
  476. IF occur_index &lt;= 0 THEN
  477. RAISE 'argument ''%'' is out of range', occur_index
  478. USING ERRCODE = '22003';
  479. END IF;
  480. IF beg_index &gt; 0 THEN
  481. beg := beg_index - 1;
  482. FOR i IN 1..occur_index LOOP
  483. temp_str := substring(string FROM beg + 1);
  484. pos := position(string_to_search_for IN temp_str);
  485. IF pos = 0 THEN
  486. RETURN 0;
  487. END IF;
  488. beg := beg + pos;
  489. END LOOP;
  490. RETURN beg;
  491. ELSIF beg_index &lt; 0 THEN
  492. ss_length := char_length(string_to_search_for);
  493. length := char_length(string);
  494. beg := length + 1 + beg_index;
  495. WHILE beg &gt; 0 LOOP
  496. temp_str := substring(string FROM beg FOR ss_length);
  497. IF string_to_search_for = temp_str THEN
  498. occur_number := occur_number + 1;
  499. IF occur_number = occur_index THEN
  500. RETURN beg;
  501. END IF;
  502. END IF;
  503. beg := beg - 1;
  504. END LOOP;
  505. RETURN 0;
  506. ELSE
  507. RETURN 0;
  508. END IF;
  509. END;
  510. $$ LANGUAGE plpgsql STRICT IMMUTABLE;
  511. </pre></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="plpgsql-development-tips.html">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="plpgsql.html">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="pltcl.html">Next</a></td></tr><tr><td width="40%" align="left" valign="top">42.12. Tips for Developing in <span class="application">PL/pgSQL</span> </td><td width="20%" align="center"><a accesskey="h" href="index.html">Home</a></td><td width="40%" align="right" valign="top"> Chapter 43. PL/Tcl - Tcl Procedural Language</td></tr></table></div></body></html>
上海开阖软件有限公司 沪ICP备12045867号-1