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>
89 lines
10 KiB
HTML
89 lines
10 KiB
HTML
<a name="EN-US_TOPIC_0000001233883339"></a><a name="EN-US_TOPIC_0000001233883339"></a>
|
|
|
|
<h1 class="topictitle1">Executing Dynamic Non-query Statements</h1>
|
|
<div id="body8662426"><div class="section" id="EN-US_TOPIC_0000001233883339__s595541c5fdae4869b8fcb8072332e816"><h4 class="sectiontitle">Syntax</h4><p id="EN-US_TOPIC_0000001233883339__ae17cf4c0448b435fa6d9c39db97eca30"><a href="#EN-US_TOPIC_0000001233883339__ff22be8f7560147fb8e4d56af6224d63c">Figure 1</a> shows the syntax diagram.</p>
|
|
<div class="fignone" id="EN-US_TOPIC_0000001233883339__ff22be8f7560147fb8e4d56af6224d63c"><a name="EN-US_TOPIC_0000001233883339__ff22be8f7560147fb8e4d56af6224d63c"></a><a name="ff22be8f7560147fb8e4d56af6224d63c"></a><span class="figcap"><b>Figure 1 </b>noselect::=</span><br><span><img id="EN-US_TOPIC_0000001233883339__i19189125c0e6428ebf196b235013032e" src="figure/en-us_image_0000001188163842.png"></span></div>
|
|
<p id="EN-US_TOPIC_0000001233883339__a216cffc1d2f84a5d98c1face9b06309e"><a href="#EN-US_TOPIC_0000001233883339__f0f94a40afad6436aa7bdec9de6505226">Figure 2</a> shows the syntax diagram for <strong id="EN-US_TOPIC_0000001233883339__b29093665165312">using_clause</strong>.</p>
|
|
<div class="fignone" id="EN-US_TOPIC_0000001233883339__f0f94a40afad6436aa7bdec9de6505226"><a name="EN-US_TOPIC_0000001233883339__f0f94a40afad6436aa7bdec9de6505226"></a><a name="f0f94a40afad6436aa7bdec9de6505226"></a><span class="figcap"><b>Figure 2 </b>using_clause-2</span><br><span><img id="EN-US_TOPIC_0000001233883339__ic7e8cb31910c4a71832a517b25c16842" src="figure/en-us_image_0000001233761959.png"></span></div>
|
|
<p id="EN-US_TOPIC_0000001233883339__a19f014cd391d40108263027d7d49544b">The above syntax diagram is explained as follows:</p>
|
|
<p id="EN-US_TOPIC_0000001233883339__p73359492167"><strong id="EN-US_TOPIC_0000001233883339__b1125715319235">USING IN bind_argument</strong> is used to specify the variable that transfers values to dynamic SQL statements. It is used when a placeholder exists in <strong id="EN-US_TOPIC_0000001233883339__b123908169264">dynamic_noselect_string</strong>. That is, a placeholder is replaced by the corresponding <em id="EN-US_TOPIC_0000001233883339__i129891310172718">bind_argument</em> when a dynamic SQL statement is executed. Note that <em id="EN-US_TOPIC_0000001233883339__i672354182715">bind_argument</em> can only be a value, variable, or expression, and cannot be a database object such as a table name, column name, and data type. If a stored procedure needs to transfer database objects through <em id="EN-US_TOPIC_0000001233883339__i1220321382512">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_0000001233883339__i520451362511">dynamic_select_clause</em> with a database object. In addition, a dynamic PL/SQL block allows duplicate placeholders. That is, a placeholder can correspond to only one <em id="EN-US_TOPIC_0000001233883339__i829074019280">bind_argument</em>.</p>
|
|
</div>
|
|
<div class="section" id="EN-US_TOPIC_0000001233883339__s18647be897004d87bc8620a575d46ad4"><h4 class="sectiontitle">Examples</h4><div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233883339__s992ba70b616c464f805de6eeaccf95e5"><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></pre></div></td><td class="code"><div><pre><span></span><span class="c1">-- Create a table:</span>
|
|
<span class="k">CREATE</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="n">sections_t1</span>
|
|
<span class="p">(</span>
|
|
<span class="w"> </span><span class="n">section</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="p">,</span>
|
|
<span class="w"> </span><span class="n">section_name</span><span class="w"> </span><span class="n">VARCHAR2</span><span class="p">(</span><span class="mi">30</span><span class="p">),</span>
|
|
<span class="w"> </span><span class="n">manager_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="n">place_id</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="p">)</span><span class="w"> </span>
|
|
<span class="n">DISTRIBUTE</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="n">hash</span><span class="p">(</span><span class="n">manager_id</span><span class="p">);</span>
|
|
|
|
<span class="c1">--Declare a variable:</span>
|
|
<span class="k">DECLARE</span><span class="w"> </span>
|
|
<span class="w"> </span><span class="n">section</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="p">:</span><span class="o">=</span><span class="w"> </span><span class="mi">280</span><span class="p">;</span><span class="w"> </span>
|
|
<span class="w"> </span><span class="n">section_name</span><span class="w"> </span><span class="n">VARCHAR2</span><span class="p">(</span><span class="mi">30</span><span class="p">)</span><span class="w"> </span><span class="p">:</span><span class="o">=</span><span class="w"> </span><span class="s1">'Info support'</span><span class="p">;</span><span class="w"> </span>
|
|
<span class="w"> </span><span class="n">manager_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">103</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="n">place_id</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="p">:</span><span class="o">=</span><span class="w"> </span><span class="mi">1400</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="n">new_colname</span><span class="w"> </span><span class="n">VARCHAR2</span><span class="p">(</span><span class="mi">10</span><span class="p">)</span><span class="w"> </span><span class="p">:</span><span class="o">=</span><span class="w"> </span><span class="s1">'sec_name'</span><span class="p">;</span>
|
|
<span class="k">BEGIN</span><span class="w"> </span>
|
|
<span class="c1">-- Execute the query:</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">'insert into sections_t1 values(:1, :2, :3, :4)'</span><span class="w"> </span>
|
|
<span class="w"> </span><span class="k">USING</span><span class="w"> </span><span class="n">section</span><span class="p">,</span><span class="w"> </span><span class="n">section_name</span><span class="p">,</span><span class="w"> </span><span class="n">manager_id</span><span class="p">,</span><span class="n">place_id</span><span class="p">;</span><span class="w"> </span>
|
|
<span class="c1">-- Execute the query (duplicate placeholders):</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">'insert into sections_t1 values(:1, :2, :3, :1)'</span><span class="w"> </span>
|
|
<span class="w"> </span><span class="k">USING</span><span class="w"> </span><span class="n">section</span><span class="p">,</span><span class="w"> </span><span class="n">section_name</span><span class="p">,</span><span class="w"> </span><span class="n">manager_id</span><span class="p">;</span><span class="w"> </span>
|
|
<span class="c1">-- Run the ALTER statement. (You are advised to use double vertical bars (||) to concatenate the dynamic DDL statement with a database object.)</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">'alter table sections_t1 rename section_name to '</span><span class="w"> </span><span class="o">||</span><span class="w"> </span><span class="n">new_colname</span><span class="p">;</span>
|
|
<span class="k">END</span><span class="p">;</span><span class="w"> </span>
|
|
<span class="o">/</span>
|
|
|
|
<span class="c1">-- Query data:</span>
|
|
<span class="k">SELECT</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">sections_t1</span><span class="p">;</span>
|
|
|
|
<span class="c1">--Delete the table.</span>
|
|
<span class="k">DROP</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="n">sections_t1</span><span class="p">;</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>
|
|
|