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>
134 lines
18 KiB
HTML
134 lines
18 KiB
HTML
<a name="EN-US_TOPIC_0000001233681785"></a><a name="EN-US_TOPIC_0000001233681785"></a>
|
|
|
|
<h1 class="topictitle1">Executing Dynamic Query Statements</h1>
|
|
<div id="body8662426"><p id="EN-US_TOPIC_0000001233681785__en-us_topic_0059778916_p17789840677">You can perform dynamic queries using <strong id="EN-US_TOPIC_0000001233681785__b84235270612448"><span id="EN-US_TOPIC_0000001233681785__ph209647255444">EXECUTE IMMEDIATE</span></strong> or <strong id="EN-US_TOPIC_0000001233681785__b84235270612451"><span id="EN-US_TOPIC_0000001233681785__ph740213217442">OPEN FOR</span></strong> in <span id="EN-US_TOPIC_0000001233681785__text831262245">GaussDB(DWS)</span>. <strong id="EN-US_TOPIC_0000001233681785__b84235270612551">EXECUTE IMMEDIATE</strong> dynamically executes <strong id="EN-US_TOPIC_0000001233681785__en-us_topic_0027042979_b38065422155340">SELECT</strong> statements and <strong id="EN-US_TOPIC_0000001233681785__b6143344161820">OPEN FOR</strong> combines use of cursors. If you need to store query results in a data set, use <strong id="EN-US_TOPIC_0000001233681785__en-us_topic_0027042979_b7044485155340">OPEN FOR</strong>.</p>
|
|
<div class="section" id="EN-US_TOPIC_0000001233681785__sdff23348e55940c7a6d0e544265f38bf"><h4 class="sectiontitle">EXECUTE IMMEDIATE</h4><p id="EN-US_TOPIC_0000001233681785__a3e96fe10bc45472998ed44be97e69358"><a href="#EN-US_TOPIC_0000001233681785__f5bdde6e248a14512a954fb2a0389a90c">Figure 1</a> shows the syntax diagram.</p>
|
|
<div class="fignone" id="EN-US_TOPIC_0000001233681785__f5bdde6e248a14512a954fb2a0389a90c"><a name="EN-US_TOPIC_0000001233681785__f5bdde6e248a14512a954fb2a0389a90c"></a><a name="f5bdde6e248a14512a954fb2a0389a90c"></a><span class="figcap"><b>Figure 1 </b>EXECUTE IMMEDIATE dynamic_select_clause::=</span><br><span><img id="EN-US_TOPIC_0000001233681785__ie52ac0e420a3476ab9491fc0dd1556eb" src="figure/en-us_image_0000001233681887.png"></span></div>
|
|
<p id="EN-US_TOPIC_0000001233681785__a24aeaf52d6864032b6bdd82135a70113"><a href="#EN-US_TOPIC_0000001233681785__fca15d616a3114294949e5b8ed8367c56">Figure 2</a> shows the syntax diagram for <strong id="EN-US_TOPIC_0000001233681785__en-us_topic_0085031787_b29093665165312">using_clause</strong>.</p>
|
|
<div class="fignone" id="EN-US_TOPIC_0000001233681785__fca15d616a3114294949e5b8ed8367c56"><a name="EN-US_TOPIC_0000001233681785__fca15d616a3114294949e5b8ed8367c56"></a><a name="fca15d616a3114294949e5b8ed8367c56"></a><span class="figcap"><b>Figure 2 </b>using_clause-1</span><br><span><img id="EN-US_TOPIC_0000001233681785__i794dd08f18ac499fbf6ee34b88bbc91d" src="figure/en-us_image_0000001188323818.png"></span></div>
|
|
<p id="EN-US_TOPIC_0000001233681785__a80111c55669846b18ce67f196c170d0e">The above syntax diagram is explained as follows:</p>
|
|
<ul id="EN-US_TOPIC_0000001233681785__u15cfcf82dbb5451c8918cd16e6222223"><li id="EN-US_TOPIC_0000001233681785__l15d80b6647464581b4c12bf7e7c80916"><strong id="EN-US_TOPIC_0000001233681785__b51007311501">define_variable</strong>: specifies variables to store single-line query results.</li><li id="EN-US_TOPIC_0000001233681785__l28580e1e1e60486dbbc9a79d5691c14b"><strong id="EN-US_TOPIC_0000001233681785__b161881321602">USING IN bind_argument</strong>: specifies where the variable passed to the dynamic SQL value is stored, that is, in the dynamic placeholder of <strong id="EN-US_TOPIC_0000001233681785__b1418943218015">dynamic_select_string</strong>.</li><li id="EN-US_TOPIC_0000001233681785__l3544b0e575194d258950e86158521648"><strong id="EN-US_TOPIC_0000001233681785__b13480163515815">USING OUT bind_argument</strong>: specifies where the dynamic SQL returns the value of the variable.<div class="notice" id="EN-US_TOPIC_0000001233681785__nf8783ee836bd474aa716169cda6dd94f"><span class="noticetitle"><img src="public_sys-resources/notice_3.0-en-us.png"> </span><div class="noticebody"><ul id="EN-US_TOPIC_0000001233681785__ul563015685911"><li id="EN-US_TOPIC_0000001233681785__li163096145914">In query statements, <strong id="EN-US_TOPIC_0000001233681785__b171921249161517">INTO</strong> and <strong id="EN-US_TOPIC_0000001233681785__b13798115301511">OUT</strong> cannot coexist.</li><li id="EN-US_TOPIC_0000001233681785__li493313910593">A placeholder name starts with a colon (:) followed by digits, characters, or strings, corresponding to <em id="EN-US_TOPIC_0000001233681785__i1959955515171">bind_argument</em> in the <strong id="EN-US_TOPIC_0000001233681785__b14473386185">USING</strong> clause.</li><li id="EN-US_TOPIC_0000001233681785__li35455151504"><em id="EN-US_TOPIC_0000001233681785__i4971556182118">bind_argument</em> can only be a value, variable, or expression. It cannot be a database object such as a table name, column name, and data type. That is, <em id="EN-US_TOPIC_0000001233681785__i1799456102118">bind_argument</em> cannot be used to transfer schema objects for dynamic SQL statements. If a stored procedure needs to transfer database objects through <em id="EN-US_TOPIC_0000001233681785__i15990358202118">bind_argument</em> to construct dynamic SQL statements (generally, DDL statements), you are advised to use double vertical bars (||) to concatenate <em id="EN-US_TOPIC_0000001233681785__i499205818219">dynamic_select_clause</em> with a database object.</li><li id="EN-US_TOPIC_0000001233681785__li175714131915">A dynamic PL/SQL block allows duplicate placeholders. That is, a placeholder can correspond to only one <em id="EN-US_TOPIC_0000001233681785__i15882133572118">bind_argument</em> in the <strong id="EN-US_TOPIC_0000001233681785__b1983415485212">USING</strong> clause.</li></ul>
|
|
</div></div>
|
|
</li></ul>
|
|
<p id="EN-US_TOPIC_0000001233681785__afe7fdeecfdde489eb3981d2c5dd96d46"><strong id="EN-US_TOPIC_0000001233681785__b104513261220">Example</strong></p>
|
|
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233681785__s5b2940101ab5464a8809349b84864c8a"><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></pre></div></td><td class="code"><div><pre><span></span><span class="c1">--Retrieve values from dynamic statements (INTO clause).</span>
|
|
<span class="k">DECLARE</span>
|
|
<span class="w"> </span><span class="n">staff_count</span><span class="w"> </span><span class="n">VARCHAR2</span><span class="p">(</span><span class="mi">20</span><span class="p">);</span>
|
|
<span class="k">BEGIN</span>
|
|
<span class="w"> </span><span class="k">EXECUTE</span><span class="w"> </span><span class="k">IMMEDIATE</span><span class="w"> </span><span class="s1">'select count(*) from staffs'</span>
|
|
<span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">staff_count</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">staff_count</span><span class="p">);</span>
|
|
<span class="k">END</span><span class="p">;</span>
|
|
<span class="o">/</span>
|
|
|
|
<span class="c1">--Pass and retrieve values (the INTO clause is used before the USING clause).</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">dynamic_proc</span>
|
|
<span class="k">AS</span>
|
|
<span class="w"> </span><span class="n">staff_id</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="p">:</span><span class="o">=</span><span class="w"> </span><span class="mi">200</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="n">first_name</span><span class="w"> </span><span class="n">VARCHAR2</span><span class="p">(</span><span class="mi">20</span><span class="p">);</span>
|
|
<span class="w"> </span><span class="n">salary</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="k">BEGIN</span>
|
|
<span class="w"> </span><span class="k">EXECUTE</span><span class="w"> </span><span class="k">IMMEDIATE</span><span class="w"> </span><span class="s1">'select first_name, salary from staffs where staff_id = :1'</span>
|
|
<span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">first_name</span><span class="p">,</span><span class="w"> </span><span class="n">salary</span>
|
|
<span class="w"> </span><span class="k">USING</span><span class="w"> </span><span class="k">IN</span><span class="w"> </span><span class="n">staff_id</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">first_name</span><span class="w"> </span><span class="o">||</span><span class="w"> </span><span class="s1">' '</span><span class="w"> </span><span class="o">||</span><span class="w"> </span><span class="n">salary</span><span class="p">);</span>
|
|
<span class="k">END</span><span class="p">;</span>
|
|
<span class="o">/</span>
|
|
|
|
<span class="c1">-- Invoke the stored procedure.</span>
|
|
<span class="k">CALL</span><span class="w"> </span><span class="n">dynamic_proc</span><span class="p">();</span>
|
|
|
|
<span class="c1">-- Delete 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">dynamic_proc</span><span class="p">;</span>
|
|
</pre></div></td></tr></table></div>
|
|
|
|
</div>
|
|
</div>
|
|
<div class="section" id="EN-US_TOPIC_0000001233681785__s9abc54c16f934a6c8ba64b6671c7ad98"><h4 class="sectiontitle">OPEN FOR</h4><p id="EN-US_TOPIC_0000001233681785__aa3046a97cb0943409efadaa8133dc904">Dynamic query statements can be executed by using <strong id="EN-US_TOPIC_0000001233681785__en-us_topic_0085031787_en-us_topic_0027042979_b50359127155628">OPEN FOR</strong> to open dynamic cursors.</p>
|
|
<p id="EN-US_TOPIC_0000001233681785__a15069dc7e30042bd986aa8db581c5f19">For details about the syntax, see <a href="#EN-US_TOPIC_0000001233681785__f6e232247a15f4a7d816e4748bab655ec">Figure 3</a>.</p>
|
|
<div class="fignone" id="EN-US_TOPIC_0000001233681785__f6e232247a15f4a7d816e4748bab655ec"><a name="EN-US_TOPIC_0000001233681785__f6e232247a15f4a7d816e4748bab655ec"></a><a name="f6e232247a15f4a7d816e4748bab655ec"></a><span class="figcap"><b>Figure 3 </b>open_for::=</span><br><span><img id="EN-US_TOPIC_0000001233681785__i67fede1334e144e8b81eb05fe970c2d8" src="figure/en-us_image_0000001233883451.png"></span></div>
|
|
<p id="EN-US_TOPIC_0000001233681785__a9be9174bb8d54761ab8c23db25efc5a5">Parameter description:</p>
|
|
<ul id="EN-US_TOPIC_0000001233681785__u8db47b89f7b74b3999176eee16199acf"><li id="EN-US_TOPIC_0000001233681785__l5fb71cb4fb284a7faf56c54489991eea"><strong id="EN-US_TOPIC_0000001233681785__b84235270612635">cursor_name</strong>: specifies the name of the cursor to be opened.</li><li id="EN-US_TOPIC_0000001233681785__l7c13584ac6ad4f9f9e7899b3be678bff"><strong id="EN-US_TOPIC_0000001233681785__b84235270612637">dynamic_string</strong>: specifies the dynamic query statement.</li><li id="EN-US_TOPIC_0000001233681785__l52c5a102abb245718b66b0884854df8e"><strong id="EN-US_TOPIC_0000001233681785__b84235270612650">USING </strong><em id="EN-US_TOPIC_0000001233681785__i84235269712648">value</em>: applies when a placeholder exists in dynamic_string.</li></ul>
|
|
<p id="EN-US_TOPIC_0000001233681785__aae59af030be0495aa1baf72a765fd34d">For use of cursors, see <a href="dws_04_0545.html">Cursors</a>.</p>
|
|
<p id="EN-US_TOPIC_0000001233681785__aedf59796ddbc48d59b08101575ab2f15"><strong id="EN-US_TOPIC_0000001233681785__b5629234318">Example</strong></p>
|
|
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233681785__s64347314afec4392b8a659f3fe4bf02d"><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></pre></div></td><td class="code"><div><pre><span></span><span class="k">DECLARE</span>
|
|
<span class="w"> </span><span class="n">name</span><span class="w"> </span><span class="n">VARCHAR2</span><span class="p">(</span><span class="mi">20</span><span class="p">);</span>
|
|
<span class="w"> </span><span class="n">phone_number</span><span class="w"> </span><span class="n">VARCHAR2</span><span class="p">(</span><span class="mi">20</span><span class="p">);</span>
|
|
<span class="w"> </span><span class="n">salary</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="n">sqlstr</span><span class="w"> </span><span class="n">VARCHAR2</span><span class="p">(</span><span class="mi">1024</span><span class="p">);</span>
|
|
|
|
<span class="w"> </span><span class="k">TYPE</span><span class="w"> </span><span class="n">app_ref_cur_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="c1">-- Define the cursor type.</span>
|
|
<span class="w"> </span><span class="n">my_cur</span><span class="w"> </span><span class="n">app_ref_cur_type</span><span class="p">;</span><span class="w"> </span><span class="c1">-- Define the cursor variable.</span>
|
|
<span class="w"> </span>
|
|
<span class="k">BEGIN</span>
|
|
<span class="w"> </span><span class="n">sqlstr</span><span class="w"> </span><span class="p">:</span><span class="o">=</span><span class="w"> </span><span class="s1">'select first_name,phone_number,salary from staffs</span>
|
|
<span class="s1"> where section_id = :1'</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="k">OPEN</span><span class="w"> </span><span class="n">my_cur</span><span class="w"> </span><span class="k">FOR</span><span class="w"> </span><span class="n">sqlstr</span><span class="w"> </span><span class="k">USING</span><span class="w"> </span><span class="s1">'30'</span><span class="p">;</span><span class="w"> </span><span class="c1">-- Open the cursor. using is optional.</span>
|
|
<span class="w"> </span><span class="k">FETCH</span><span class="w"> </span><span class="n">my_cur</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">name</span><span class="p">,</span><span class="w"> </span><span class="n">phone_number</span><span class="p">,</span><span class="w"> </span><span class="n">salary</span><span class="p">;</span><span class="w"> </span><span class="c1">-- Retrieve the data.</span>
|
|
<span class="w"> </span><span class="n">WHILE</span><span class="w"> </span><span class="n">my_cur</span><span class="o">%</span><span class="k">FOUND</span><span class="w"> </span><span class="n">LOOP</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">name</span><span class="o">||</span><span class="s1">'#'</span><span class="o">||</span><span class="n">phone_number</span><span class="o">||</span><span class="s1">'#'</span><span class="o">||</span><span class="n">salary</span><span class="p">);</span>
|
|
<span class="w"> </span><span class="k">FETCH</span><span class="w"> </span><span class="n">my_cur</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">name</span><span class="p">,</span><span class="w"> </span><span class="n">phone_number</span><span class="p">,</span><span class="w"> </span><span class="n">salary</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">my_cur</span><span class="p">;</span><span class="w"> </span><span class="c1">-- Close the cursor.</span>
|
|
<span class="k">END</span><span class="p">;</span>
|
|
<span class="o">/</span>
|
|
</pre></div></td></tr></table></div>
|
|
|
|
</div>
|
|
</div>
|
|
</div>
|
|
<div>
|
|
<div class="familylinks">
|
|
<div class="parentlink"><strong>Parent topic:</strong> <a href="dws_04_0527.html">Dynamic Statements</a></div>
|
|
</div>
|
|
</div>
|
|
|