forked from docs/doc-exports
Reviewed-by: Pruthi, Vineet <vineet.pruthi@t-systems.com> Co-authored-by: Lu, Huayi <luhuayi@huawei.com> Co-committed-by: Lu, Huayi <luhuayi@huawei.com>
244 lines
32 KiB
HTML
244 lines
32 KiB
HTML
<a name="EN-US_TOPIC_0000001188323724"></a><a name="EN-US_TOPIC_0000001188323724"></a>
|
|
|
|
<h1 class="topictitle1">Explicit Cursor</h1>
|
|
<div id="body8662426"><p id="EN-US_TOPIC_0000001188323724__a2077bd8aac264c75bb09f6b34ed94897">An explicit cursor is used to process query statements, particularly when the query results contain multiple records.</p>
|
|
<div class="section" id="EN-US_TOPIC_0000001188323724__sc2c87118c2334ff683ae39758925a1ca"><h4 class="sectiontitle">Procedure</h4><p id="EN-US_TOPIC_0000001188323724__aa901389d769147a5a0ec019b11bc1806">An explicit cursor performs the following six PL/SQL steps to process query statements:</p>
|
|
<ol id="EN-US_TOPIC_0000001188323724__o23d2ed078b5247e5b12d7e2716bc34f5"><li id="EN-US_TOPIC_0000001188323724__l5abc584a3e5048cfaf59c7c91fd0c8c4"><span><strong id="EN-US_TOPIC_0000001188323724__en-us_topic_0027042965_b4487581116250">Define a static cursor:</strong> Define a cursor name and its corresponding <strong id="EN-US_TOPIC_0000001188323724__en-us_topic_0027042965_b122911516250">SELECT</strong> statement.</span><p><p id="EN-US_TOPIC_0000001188323724__a709a008d6ab9499cacf4c9cc48d4871c"><a href="#EN-US_TOPIC_0000001188323724__f5ebd05f39359414695fc9535d74c7e54">Figure 1</a> shows the syntax diagram for defining a static cursor.</p>
|
|
<div class="fignone" id="EN-US_TOPIC_0000001188323724__f5ebd05f39359414695fc9535d74c7e54"><a name="EN-US_TOPIC_0000001188323724__f5ebd05f39359414695fc9535d74c7e54"></a><a name="f5ebd05f39359414695fc9535d74c7e54"></a><span class="figcap"><b>Figure 1 </b>static_cursor_define::=</span><br><span><img id="EN-US_TOPIC_0000001188323724__id792b95cd8c445b1bb9c63b7a061bb1f" src="figure/en-us_image_0000001188323814.jpg"></span></div>
|
|
<p id="EN-US_TOPIC_0000001188323724__adcddbeaec4664b60b441da462a08cd6a">Parameter description:</p>
|
|
<ul id="EN-US_TOPIC_0000001188323724__u529c9d6985a64d91b00d742de4438b81"><li id="EN-US_TOPIC_0000001188323724__l8373cf3d03d24dbe92e18442ed63c275"><strong id="EN-US_TOPIC_0000001188323724__b77431845153512">cursor_name</strong>: defines a cursor name.</li><li id="EN-US_TOPIC_0000001188323724__lf3a2178ed12542e39ae329a3e86bd8f9"><strong id="EN-US_TOPIC_0000001188323724__en-us_topic_0040044845_en-us_topic_0027042965_b38965658162531">parameter</strong>: specifies cursor parameters. Only input parameters are allowed in the following format:<pre class="screen" id="EN-US_TOPIC_0000001188323724__s145a94a39e42447d9651f235286d8f85">parameter_name datatype</pre>
|
|
</li><li id="EN-US_TOPIC_0000001188323724__l4b07c5a4df764f9c98d6e7fb2251c141"><strong id="EN-US_TOPIC_0000001188323724__en-us_topic_0027042965_b18915382162531">select_statement</strong>: specifies a query statement.</li></ul>
|
|
<div class="note" id="EN-US_TOPIC_0000001188323724__n6fd0ae29e0fb496aa86f6952bbb9f87f"><img src="public_sys-resources/note_3.0-en-us.png"><span class="notetitle"> </span><div class="notebody"><p id="EN-US_TOPIC_0000001188323724__a6ff428b45d494f449d0a84f597f21b33">The system automatically determines whether the cursor can be used for backward fetches based on the execution plan.</p>
|
|
</div></div>
|
|
<p id="EN-US_TOPIC_0000001188323724__a799bf9be40f54260ad3e17bd6b162c9d"><strong id="EN-US_TOPIC_0000001188323724__en-us_topic_0027042965_b45239090162551">Define a dynamic cursor:</strong> Define a <strong id="EN-US_TOPIC_0000001188323724__en-us_topic_0027042965_b4498629162551">ref</strong> cursor, which means that the cursor can be opened dynamically by a set of static SQL statements. Define the type of the <strong id="EN-US_TOPIC_0000001188323724__b46631174118">ref</strong> cursor first and then the cursor variable of this cursor type. Dynamically bind a <strong id="EN-US_TOPIC_0000001188323724__en-us_topic_0027042965_b40487669162551">SELECT</strong> statement through <strong id="EN-US_TOPIC_0000001188323724__en-us_topic_0027042965_b28844706162551">OPEN FOR</strong> when the cursor is opened.</p>
|
|
<p id="EN-US_TOPIC_0000001188323724__af30fee19df2a4fdd89754ee3a218eaa4"><a href="#EN-US_TOPIC_0000001188323724__fe28df92329334de2a2590c78cfd4cd7f">Figure 2</a> and <a href="#EN-US_TOPIC_0000001188323724__f685eab9d29d6492d9f48bf7f5f39c966">Figure 3</a> show the syntax diagrams for defining a dynamic cursor.</p>
|
|
<div class="fignone" id="EN-US_TOPIC_0000001188323724__fe28df92329334de2a2590c78cfd4cd7f"><a name="EN-US_TOPIC_0000001188323724__fe28df92329334de2a2590c78cfd4cd7f"></a><a name="fe28df92329334de2a2590c78cfd4cd7f"></a><span class="figcap"><b>Figure 2 </b>cursor_typename::=</span><br><span><img id="EN-US_TOPIC_0000001188323724__i22ca260213224d1bad421a631a1d737b" src="figure/en-us_image_0000001233563391.png"></span></div>
|
|
<p id="EN-US_TOPIC_0000001188323724__aa42adb3edf2e44ddbfc775964bec457b"><span id="EN-US_TOPIC_0000001188323724__text1142613520">GaussDB(DWS)</span> supports the dynamic cursor type <strong id="EN-US_TOPIC_0000001188323724__en-us_topic_0058965691_en-us_topic_0027042965_b40069257162644">sys_refcursor</strong>. A function or stored procedure can use the <strong id="EN-US_TOPIC_0000001188323724__en-us_topic_0058965691_en-us_topic_0027042965_b25078994162644">sys_refcursor</strong> parameter to pass on or pass out the cursor result set. A function can return <strong id="EN-US_TOPIC_0000001188323724__en-us_topic_0058965691_en-us_topic_0027042965_b24384362162644">sys_refcursor</strong> to return the cursor result set.</p>
|
|
<div class="fignone" id="EN-US_TOPIC_0000001188323724__f685eab9d29d6492d9f48bf7f5f39c966"><a name="EN-US_TOPIC_0000001188323724__f685eab9d29d6492d9f48bf7f5f39c966"></a><a name="f685eab9d29d6492d9f48bf7f5f39c966"></a><span class="figcap"><b>Figure 3 </b>dynamic_cursor_define::=</span><br><span><img id="EN-US_TOPIC_0000001188323724__ie0e60dec09574a0a9866e411d6d043cd" src="figure/en-us_image_0000001233563389.png"></span></div>
|
|
</p></li><li id="EN-US_TOPIC_0000001188323724__l11b278de36b54d2b942de6ae4df102a7"><span><strong id="EN-US_TOPIC_0000001188323724__en-us_topic_0027042965_b15797801162726">Open the static cursor:</strong> Execute the <strong id="EN-US_TOPIC_0000001188323724__en-us_topic_0027042965_b7962488162726">SELECT</strong> statement corresponding to the cursor. The query result is placed in the work area and the pointer directs to the head of the work area to identify the cursor result set. If the cursor query statement contains the <strong id="EN-US_TOPIC_0000001188323724__en-us_topic_0027042965_b4553529162726">FOR UPDATE</strong> option, the <strong id="EN-US_TOPIC_0000001188323724__en-us_topic_0027042965_b40981767162726">OPEN</strong> statement locks the data row corresponding to the cursor result set in the database table.</span><p><p id="EN-US_TOPIC_0000001188323724__a491c815bb48047c99915d924a46ff557"><a href="#EN-US_TOPIC_0000001188323724__f01b830e0c0dd439ab274074b6799fc00">Figure 4</a> shows the syntax diagram for opening a static cursor.</p>
|
|
<div class="fignone" id="EN-US_TOPIC_0000001188323724__f01b830e0c0dd439ab274074b6799fc00"><a name="EN-US_TOPIC_0000001188323724__f01b830e0c0dd439ab274074b6799fc00"></a><a name="f01b830e0c0dd439ab274074b6799fc00"></a><span class="figcap"><b>Figure 4 </b>open_static_cursor::=</span><br><span><img id="EN-US_TOPIC_0000001188323724__i72c59d8e440047f9b713d181a0080482" src="figure/en-us_image_0000001188163838.png"></span></div>
|
|
<p id="EN-US_TOPIC_0000001188323724__adbcd49e861844750ae4f50208652b07a"><strong id="EN-US_TOPIC_0000001188323724__en-us_topic_0027042965_b6174312716282">Open the dynamic cursor:</strong> Use the <strong id="EN-US_TOPIC_0000001188323724__en-us_topic_0027042965_b1881723916282">OPEN FOR</strong> statement to open the dynamic cursor and the SQL statement is dynamically bound.</p>
|
|
<p id="EN-US_TOPIC_0000001188323724__a93f505aa2fc04b13854ab91631bf62a5"><a href="#EN-US_TOPIC_0000001188323724__f0dba806a4d8f42e0a7faef4fb03bfa57">Figure 5</a> shows the syntax diagram for opening a dynamic cursor.</p>
|
|
<div class="fignone" id="EN-US_TOPIC_0000001188323724__f0dba806a4d8f42e0a7faef4fb03bfa57"><a name="EN-US_TOPIC_0000001188323724__f0dba806a4d8f42e0a7faef4fb03bfa57"></a><a name="f0dba806a4d8f42e0a7faef4fb03bfa57"></a><span class="figcap"><b>Figure 5 </b>open_dynamic_cursor::=</span><br><span><img id="EN-US_TOPIC_0000001188323724__i8cca6e4a495e4454a07c4099a4558ef6" src="figure/en-us_image_0000001233681883.png"></span></div>
|
|
<p id="EN-US_TOPIC_0000001188323724__ae5e97f3540c74e9fb2330f6c59cb87c4">A PL/SQL program cannot use the <strong id="EN-US_TOPIC_0000001188323724__b0396144510163">OPEN</strong> statement to repeatedly open a cursor.</p>
|
|
</p></li><li id="EN-US_TOPIC_0000001188323724__led7adeef7a41467cb695a5e98a01152f"><span><strong id="EN-US_TOPIC_0000001188323724__b16586191041718">Fetch cursor data</strong>: Retrieve data rows in the result set and place them in specified output variables.</span><p><p id="EN-US_TOPIC_0000001188323724__ad8c9527b79bc43d882b679c77be5d075"><a href="#EN-US_TOPIC_0000001188323724__f5214e8d3c1564810bdecfe35843913f4">Figure 6</a> shows the syntax diagram for fetching cursor data.</p>
|
|
<div class="fignone" id="EN-US_TOPIC_0000001188323724__f5214e8d3c1564810bdecfe35843913f4"><a name="EN-US_TOPIC_0000001188323724__f5214e8d3c1564810bdecfe35843913f4"></a><a name="f5214e8d3c1564810bdecfe35843913f4"></a><span class="figcap"><b>Figure 6 </b>fetch_cursor::=</span><br><span><img id="EN-US_TOPIC_0000001188323724__i392f901d1e9642beade830529874170f" src="figure/en-us_image_0000001233681881.png"></span></div>
|
|
</p></li><li id="EN-US_TOPIC_0000001188323724__l73929d9d5ee140448b02d7596ecf1624"><span>Process the record.</span></li><li id="EN-US_TOPIC_0000001188323724__lcee0622e69b04954b627819cf3c93a3e"><span>Continue to process until the active set has no record.</span></li><li id="EN-US_TOPIC_0000001188323724__lde811d568ed84394a4264af870c5b216"><span><strong id="EN-US_TOPIC_0000001188323724__b4739185216170">Close the cursor</strong>: When fetching and finishing the data in the cursor result set, close the cursor immediately to release system resources used by the cursor and invalidate the work area of the cursor so that the <strong id="EN-US_TOPIC_0000001188323724__b174513527175">FETCH</strong> statement cannot be used to fetch data any more. A closed cursor can be reopened using the <strong id="EN-US_TOPIC_0000001188323724__b1514813574205">OPEN</strong> statement.</span><p><p id="EN-US_TOPIC_0000001188323724__a18efe9ca042c4967a5990bd222afae44"><a href="#EN-US_TOPIC_0000001188323724__f0629b4efb62e44a7911972faf2b359e9">Figure 7</a> shows the syntax diagram for closing a cursor.</p>
|
|
<div class="fignone" id="EN-US_TOPIC_0000001188323724__f0629b4efb62e44a7911972faf2b359e9"><a name="EN-US_TOPIC_0000001188323724__f0629b4efb62e44a7911972faf2b359e9"></a><a name="f0629b4efb62e44a7911972faf2b359e9"></a><span class="figcap"><b>Figure 7 </b>close_cursor::=</span><br><span><img id="EN-US_TOPIC_0000001188323724__i055da9e30ed94f0ebd50d7d2eaf23319" src="figure/en-us_image_0000001188323812.jpg"></span></div>
|
|
</p></li></ol>
|
|
</div>
|
|
<div class="section" id="EN-US_TOPIC_0000001188323724__s9a19930bca204959bb9a67ca72ef649b"><h4 class="sectiontitle">Attributes</h4><p id="EN-US_TOPIC_0000001188323724__acbb6f6f194d84daa9f3dfdef29703d2a">Cursor attributes are used to control program procedures or learn about program status. When a DML statement is executed, the PL/SQL opens a built-in cursor and processes its result. A cursor is a memory segment for maintaining query results. It is opened when a DML statement is executed and closed when the execution is finished. An explicit cursor has the following attributes:</p>
|
|
<ul id="EN-US_TOPIC_0000001188323724__u153e33c9e4a140768473d33fba382341"><li id="EN-US_TOPIC_0000001188323724__l7a15c4620d9c414e9493b89e5338757a"><strong id="EN-US_TOPIC_0000001188323724__b13203164416264">%FOUND</strong>: Boolean attribute, which returns <strong id="EN-US_TOPIC_0000001188323724__b72041344192611">TRUE</strong> if the last fetch returns a row.</li><li id="EN-US_TOPIC_0000001188323724__l80350df4936648ce81effb1e05acee0f"><strong id="EN-US_TOPIC_0000001188323724__b17979185113269">%NOTFOUND</strong>: Boolean attribute, which works opposite to the <strong id="EN-US_TOPIC_0000001188323724__b1979165192620">%FOUND</strong> attribute.</li><li id="EN-US_TOPIC_0000001188323724__l0cf76bd5ff904f47a730d16921573968"><strong id="EN-US_TOPIC_0000001188323724__b13438138202718">%ISOPEN</strong>: Boolean attribute, which returns <strong id="EN-US_TOPIC_0000001188323724__b11444985273">TRUE</strong> if the cursor has been opened.</li><li id="EN-US_TOPIC_0000001188323724__la897e7305bc54d12acd47afb1dcade72"><strong id="EN-US_TOPIC_0000001188323724__b87111123202711">%ROWCOUNT</strong>: numeric attribute, which returns the number of records fetched from the cursor.</li></ul>
|
|
</div>
|
|
<div class="section" id="EN-US_TOPIC_0000001188323724__s694106b127be4e8ab3cfeb49818362bf"><h4 class="sectiontitle">Examples</h4><div class="p" id="EN-US_TOPIC_0000001188323724__ad613d8e28e484fd98d38b5ac44b50435"><div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188323724__sa58c89507ef849eda3abe6d41ba6475d"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal"> 1</span>
|
|
<span class="normal"> 2</span>
|
|
<span class="normal"> 3</span>
|
|
<span class="normal"> 4</span>
|
|
<span class="normal"> 5</span>
|
|
<span class="normal"> 6</span>
|
|
<span class="normal"> 7</span>
|
|
<span class="normal"> 8</span>
|
|
<span class="normal"> 9</span>
|
|
<span class="normal">10</span>
|
|
<span class="normal">11</span>
|
|
<span class="normal">12</span>
|
|
<span class="normal">13</span>
|
|
<span class="normal">14</span>
|
|
<span class="normal">15</span>
|
|
<span class="normal">16</span>
|
|
<span class="normal">17</span>
|
|
<span class="normal">18</span>
|
|
<span class="normal">19</span>
|
|
<span class="normal">20</span>
|
|
<span class="normal">21</span>
|
|
<span class="normal">22</span>
|
|
<span class="normal">23</span>
|
|
<span class="normal">24</span>
|
|
<span class="normal">25</span>
|
|
<span class="normal">26</span>
|
|
<span class="normal">27</span>
|
|
<span class="normal">28</span>
|
|
<span class="normal">29</span>
|
|
<span class="normal">30</span>
|
|
<span class="normal">31</span>
|
|
<span class="normal">32</span>
|
|
<span class="normal">33</span>
|
|
<span class="normal">34</span>
|
|
<span class="normal">35</span>
|
|
<span class="normal">36</span>
|
|
<span class="normal">37</span>
|
|
<span class="normal">38</span>
|
|
<span class="normal">39</span>
|
|
<span class="normal">40</span>
|
|
<span class="normal">41</span>
|
|
<span class="normal">42</span>
|
|
<span class="normal">43</span>
|
|
<span class="normal">44</span>
|
|
<span class="normal">45</span>
|
|
<span class="normal">46</span></pre></div></td><td class="code"><div><pre><span></span><span class="c1">-- Specify the method for passing cursor parameters:</span>
|
|
<span class="k">CREATE</span><span class="w"> </span><span class="k">OR</span><span class="w"> </span><span class="k">REPLACE</span><span class="w"> </span><span class="k">PROCEDURE</span><span class="w"> </span><span class="n">cursor_proc1</span><span class="p">()</span>
|
|
<span class="k">AS</span><span class="w"> </span>
|
|
<span class="k">DECLARE</span>
|
|
<span class="w"> </span><span class="n">DEPT_NAME</span><span class="w"> </span><span class="nb">VARCHAR</span><span class="p">(</span><span class="mi">100</span><span class="p">);</span>
|
|
<span class="w"> </span><span class="n">DEPT_LOC</span><span class="w"> </span><span class="nb">NUMBER</span><span class="p">(</span><span class="mi">4</span><span class="p">);</span>
|
|
<span class="w"> </span><span class="c1">-- Define a cursor:</span>
|
|
<span class="w"> </span><span class="k">CURSOR</span><span class="w"> </span><span class="n">C1</span><span class="w"> </span><span class="k">IS</span><span class="w"> </span>
|
|
<span class="w"> </span><span class="k">SELECT</span><span class="w"> </span><span class="n">section_name</span><span class="p">,</span><span class="w"> </span><span class="n">place_id</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">sections</span><span class="w"> </span><span class="k">WHERE</span><span class="w"> </span><span class="n">section_id</span><span class="w"> </span><span class="o"><=</span><span class="w"> </span><span class="mi">50</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="k">CURSOR</span><span class="w"> </span><span class="n">C2</span><span class="p">(</span><span class="n">sect_id</span><span class="w"> </span><span class="nb">INTEGER</span><span class="p">)</span><span class="w"> </span><span class="k">IS</span>
|
|
<span class="w"> </span><span class="k">SELECT</span><span class="w"> </span><span class="n">section_name</span><span class="p">,</span><span class="w"> </span><span class="n">place_id</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">sections</span><span class="w"> </span><span class="k">WHERE</span><span class="w"> </span><span class="n">section_id</span><span class="w"> </span><span class="o"><=</span><span class="w"> </span><span class="n">sect_id</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="k">TYPE</span><span class="w"> </span><span class="n">CURSOR_TYPE</span><span class="w"> </span><span class="k">IS</span><span class="w"> </span><span class="k">REF</span><span class="w"> </span><span class="k">CURSOR</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="n">C3</span><span class="w"> </span><span class="n">CURSOR_TYPE</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="n">SQL_STR</span><span class="w"> </span><span class="nb">VARCHAR</span><span class="p">(</span><span class="mi">100</span><span class="p">);</span>
|
|
<span class="k">BEGIN</span>
|
|
<span class="w"> </span><span class="k">OPEN</span><span class="w"> </span><span class="n">C1</span><span class="p">;</span><span class="c1">-- Open the cursor:</span>
|
|
<span class="w"> </span><span class="n">LOOP</span>
|
|
<span class="w"> </span><span class="c1">-- Fetch data from the cursor:</span>
|
|
<span class="w"> </span><span class="k">FETCH</span><span class="w"> </span><span class="n">C1</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">DEPT_NAME</span><span class="p">,</span><span class="w"> </span><span class="n">DEPT_LOC</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="n">EXIT</span><span class="w"> </span><span class="k">WHEN</span><span class="w"> </span><span class="n">C1</span><span class="o">%</span><span class="n">NOTFOUND</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="n">DBMS_OUTPUT</span><span class="p">.</span><span class="n">PUT_LINE</span><span class="p">(</span><span class="n">DEPT_NAME</span><span class="o">||</span><span class="s1">'---'</span><span class="o">||</span><span class="n">DEPT_LOC</span><span class="p">);</span>
|
|
<span class="w"> </span><span class="k">END</span><span class="w"> </span><span class="n">LOOP</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="k">CLOSE</span><span class="w"> </span><span class="n">C1</span><span class="p">;</span><span class="c1">-- Close the cursor.</span>
|
|
|
|
<span class="w"> </span><span class="k">OPEN</span><span class="w"> </span><span class="n">C2</span><span class="p">(</span><span class="mi">10</span><span class="p">);</span>
|
|
<span class="w"> </span><span class="n">LOOP</span>
|
|
<span class="w"> </span><span class="k">FETCH</span><span class="w"> </span><span class="n">C2</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">DEPT_NAME</span><span class="p">,</span><span class="w"> </span><span class="n">DEPT_LOC</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="n">EXIT</span><span class="w"> </span><span class="k">WHEN</span><span class="w"> </span><span class="n">C2</span><span class="o">%</span><span class="n">NOTFOUND</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="n">DBMS_OUTPUT</span><span class="p">.</span><span class="n">PUT_LINE</span><span class="p">(</span><span class="n">DEPT_NAME</span><span class="o">||</span><span class="s1">'---'</span><span class="o">||</span><span class="n">DEPT_LOC</span><span class="p">);</span>
|
|
<span class="w"> </span><span class="k">END</span><span class="w"> </span><span class="n">LOOP</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="k">CLOSE</span><span class="w"> </span><span class="n">C2</span><span class="p">;</span>
|
|
<span class="w"> </span>
|
|
<span class="w"> </span><span class="n">SQL_STR</span><span class="w"> </span><span class="p">:</span><span class="o">=</span><span class="w"> </span><span class="s1">'SELECT section_name, place_id FROM sections WHERE section_id <= :DEPT_NO;'</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="k">OPEN</span><span class="w"> </span><span class="n">C3</span><span class="w"> </span><span class="k">FOR</span><span class="w"> </span><span class="n">SQL_STR</span><span class="w"> </span><span class="k">USING</span><span class="w"> </span><span class="mi">50</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="n">LOOP</span>
|
|
<span class="w"> </span><span class="k">FETCH</span><span class="w"> </span><span class="n">C3</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">DEPT_NAME</span><span class="p">,</span><span class="w"> </span><span class="n">DEPT_LOC</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="n">EXIT</span><span class="w"> </span><span class="k">WHEN</span><span class="w"> </span><span class="n">C3</span><span class="o">%</span><span class="n">NOTFOUND</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="n">DBMS_OUTPUT</span><span class="p">.</span><span class="n">PUT_LINE</span><span class="p">(</span><span class="n">DEPT_NAME</span><span class="o">||</span><span class="s1">'---'</span><span class="o">||</span><span class="n">DEPT_LOC</span><span class="p">);</span>
|
|
<span class="w"> </span><span class="k">END</span><span class="w"> </span><span class="n">LOOP</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="k">CLOSE</span><span class="w"> </span><span class="n">C3</span><span class="p">;</span>
|
|
<span class="k">END</span><span class="p">;</span>
|
|
<span class="o">/</span>
|
|
|
|
<span class="k">CALL</span><span class="w"> </span><span class="n">cursor_proc1</span><span class="p">();</span>
|
|
|
|
<span class="k">DROP</span><span class="w"> </span><span class="k">PROCEDURE</span><span class="w"> </span><span class="n">cursor_proc1</span><span class="p">;</span>
|
|
</pre></div></td></tr></table></div>
|
|
|
|
</div>
|
|
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188323724__s249bcca094d7465ea3340b62a4191729"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal"> 1</span>
|
|
<span class="normal"> 2</span>
|
|
<span class="normal"> 3</span>
|
|
<span class="normal"> 4</span>
|
|
<span class="normal"> 5</span>
|
|
<span class="normal"> 6</span>
|
|
<span class="normal"> 7</span>
|
|
<span class="normal"> 8</span>
|
|
<span class="normal"> 9</span>
|
|
<span class="normal">10</span>
|
|
<span class="normal">11</span>
|
|
<span class="normal">12</span>
|
|
<span class="normal">13</span>
|
|
<span class="normal">14</span>
|
|
<span class="normal">15</span>
|
|
<span class="normal">16</span>
|
|
<span class="normal">17</span>
|
|
<span class="normal">18</span>
|
|
<span class="normal">19</span>
|
|
<span class="normal">20</span>
|
|
<span class="normal">21</span>
|
|
<span class="normal">22</span>
|
|
<span class="normal">23</span>
|
|
<span class="normal">24</span>
|
|
<span class="normal">25</span>
|
|
<span class="normal">26</span>
|
|
<span class="normal">27</span></pre></div></td><td class="code"><div><pre><span></span><span class="c1">-- Increase the salary of employees whose salary is lower than CNY3000 by CNY500:</span>
|
|
<span class="k">CREATE</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="n">staffs_t1</span><span class="w"> </span><span class="k">AS</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="n">staffs</span><span class="p">;</span>
|
|
|
|
<span class="k">CREATE</span><span class="w"> </span><span class="k">OR</span><span class="w"> </span><span class="k">REPLACE</span><span class="w"> </span><span class="k">PROCEDURE</span><span class="w"> </span><span class="n">cursor_proc2</span><span class="p">()</span>
|
|
<span class="k">AS</span><span class="w"> </span>
|
|
<span class="k">DECLARE</span>
|
|
<span class="w"> </span><span class="n">V_EMPNO</span><span class="w"> </span><span class="nb">NUMBER</span><span class="p">(</span><span class="mi">6</span><span class="p">);</span>
|
|
<span class="w"> </span><span class="n">V_SAL</span><span class="w"> </span><span class="nb">NUMBER</span><span class="p">(</span><span class="mi">8</span><span class="p">,</span><span class="mi">2</span><span class="p">);</span>
|
|
<span class="w"> </span><span class="k">CURSOR</span><span class="w"> </span><span class="k">C</span><span class="w"> </span><span class="k">IS</span><span class="w"> </span><span class="k">SELECT</span><span class="w"> </span><span class="n">staff_id</span><span class="p">,</span><span class="w"> </span><span class="n">salary</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">staffs_t1</span><span class="p">;</span><span class="w"> </span>
|
|
<span class="k">BEGIN</span>
|
|
<span class="w"> </span><span class="k">OPEN</span><span class="w"> </span><span class="k">C</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="n">LOOP</span>
|
|
<span class="w"> </span><span class="k">FETCH</span><span class="w"> </span><span class="k">C</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">V_EMPNO</span><span class="p">,</span><span class="w"> </span><span class="n">V_SAL</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="n">EXIT</span><span class="w"> </span><span class="k">WHEN</span><span class="w"> </span><span class="k">C</span><span class="o">%</span><span class="n">NOTFOUND</span><span class="p">;</span><span class="w"> </span>
|
|
<span class="w"> </span><span class="k">IF</span><span class="w"> </span><span class="n">V_SAL</span><span class="o"><=</span><span class="mi">3000</span><span class="w"> </span><span class="k">THEN</span>
|
|
<span class="w"> </span><span class="k">UPDATE</span><span class="w"> </span><span class="n">staffs_t1</span><span class="w"> </span><span class="k">SET</span><span class="w"> </span><span class="n">salary</span><span class="w"> </span><span class="o">=</span><span class="n">salary</span><span class="w"> </span><span class="o">+</span><span class="w"> </span><span class="mi">500</span><span class="w"> </span><span class="k">WHERE</span><span class="w"> </span><span class="n">staff_id</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">V_EMPNO</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="k">END</span><span class="w"> </span><span class="k">IF</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="k">END</span><span class="w"> </span><span class="n">LOOP</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="k">CLOSE</span><span class="w"> </span><span class="k">C</span><span class="p">;</span>
|
|
<span class="k">END</span><span class="p">;</span><span class="w"> </span>
|
|
<span class="o">/</span>
|
|
|
|
<span class="k">CALL</span><span class="w"> </span><span class="n">cursor_proc2</span><span class="p">();</span>
|
|
|
|
<span class="c1">-- Drop the stored procedure:</span>
|
|
<span class="k">DROP</span><span class="w"> </span><span class="k">PROCEDURE</span><span class="w"> </span><span class="n">cursor_proc2</span><span class="p">;</span>
|
|
<span class="k">DROP</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="n">staffs_t1</span><span class="p">;</span>
|
|
</pre></div></td></tr></table></div>
|
|
|
|
</div>
|
|
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188323724__s46775a243491448f92dbc63c686665b4"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal"> 1</span>
|
|
<span class="normal"> 2</span>
|
|
<span class="normal"> 3</span>
|
|
<span class="normal"> 4</span>
|
|
<span class="normal"> 5</span>
|
|
<span class="normal"> 6</span>
|
|
<span class="normal"> 7</span>
|
|
<span class="normal"> 8</span>
|
|
<span class="normal"> 9</span>
|
|
<span class="normal">10</span>
|
|
<span class="normal">11</span>
|
|
<span class="normal">12</span>
|
|
<span class="normal">13</span>
|
|
<span class="normal">14</span>
|
|
<span class="normal">15</span>
|
|
<span class="normal">16</span>
|
|
<span class="normal">17</span>
|
|
<span class="normal">18</span>
|
|
<span class="normal">19</span>
|
|
<span class="normal">20</span>
|
|
<span class="normal">21</span>
|
|
<span class="normal">22</span>
|
|
<span class="normal">23</span>
|
|
<span class="normal">24</span>
|
|
<span class="normal">25</span></pre></div></td><td class="code"><div><pre><span></span><span class="c1">-- Use function parameters of the SYS_REFCURSOR type:</span>
|
|
<span class="k">CREATE</span><span class="w"> </span><span class="k">OR</span><span class="w"> </span><span class="k">REPLACE</span><span class="w"> </span><span class="k">PROCEDURE</span><span class="w"> </span><span class="n">proc_sys_ref</span><span class="p">(</span><span class="n">O</span><span class="w"> </span><span class="k">OUT</span><span class="w"> </span><span class="n">SYS_REFCURSOR</span><span class="p">)</span>
|
|
<span class="k">IS</span><span class="w"> </span>
|
|
<span class="n">C1</span><span class="w"> </span><span class="n">SYS_REFCURSOR</span><span class="p">;</span><span class="w"> </span>
|
|
<span class="k">BEGIN</span><span class="w"> </span>
|
|
<span class="k">OPEN</span><span class="w"> </span><span class="n">C1</span><span class="w"> </span><span class="k">FOR</span><span class="w"> </span><span class="k">SELECT</span><span class="w"> </span><span class="n">section_ID</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">sections</span><span class="w"> </span><span class="k">ORDER</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="n">section_ID</span><span class="p">;</span><span class="w"> </span>
|
|
<span class="n">O</span><span class="w"> </span><span class="p">:</span><span class="o">=</span><span class="w"> </span><span class="n">C1</span><span class="p">;</span><span class="w"> </span>
|
|
<span class="k">END</span><span class="p">;</span><span class="w"> </span>
|
|
<span class="o">/</span>
|
|
|
|
<span class="k">DECLARE</span><span class="w"> </span>
|
|
<span class="n">C1</span><span class="w"> </span><span class="n">SYS_REFCURSOR</span><span class="p">;</span><span class="w"> </span>
|
|
<span class="n">TEMP</span><span class="w"> </span><span class="nb">NUMBER</span><span class="p">(</span><span class="mi">4</span><span class="p">);</span><span class="w"> </span>
|
|
<span class="k">BEGIN</span><span class="w"> </span>
|
|
<span class="n">proc_sys_ref</span><span class="p">(</span><span class="n">C1</span><span class="p">);</span><span class="w"> </span>
|
|
<span class="n">LOOP</span><span class="w"> </span>
|
|
<span class="w"> </span><span class="k">FETCH</span><span class="w"> </span><span class="n">C1</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">TEMP</span><span class="p">;</span><span class="w"> </span>
|
|
<span class="w"> </span><span class="n">DBMS_OUTPUT</span><span class="p">.</span><span class="n">PUT_LINE</span><span class="p">(</span><span class="n">C1</span><span class="o">%</span><span class="n">ROWCOUNT</span><span class="p">);</span>
|
|
<span class="w"> </span><span class="n">EXIT</span><span class="w"> </span><span class="k">WHEN</span><span class="w"> </span><span class="n">C1</span><span class="o">%</span><span class="n">NOTFOUND</span><span class="p">;</span><span class="w"> </span>
|
|
<span class="k">END</span><span class="w"> </span><span class="n">LOOP</span><span class="p">;</span><span class="w"> </span>
|
|
<span class="k">END</span><span class="p">;</span><span class="w"> </span>
|
|
<span class="o">/</span>
|
|
|
|
<span class="c1">-- Drop the stored procedure:</span>
|
|
<span class="k">DROP</span><span class="w"> </span><span class="k">PROCEDURE</span><span class="w"> </span><span class="n">proc_sys_ref</span><span class="p">;</span>
|
|
</pre></div></td></tr></table></div>
|
|
|
|
</div>
|
|
</div>
|
|
</div>
|
|
</div>
|
|
<div>
|
|
<div class="familylinks">
|
|
<div class="parentlink"><strong>Parent topic:</strong> <a href="dws_04_0545.html">Cursors</a></div>
|
|
</div>
|
|
</div>
|
|
|