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>
82 lines
8.5 KiB
HTML
82 lines
8.5 KiB
HTML
<a name="EN-US_TOPIC_0000001188482198"></a><a name="EN-US_TOPIC_0000001188482198"></a>
|
|
|
|
<h1 class="topictitle1">Dynamically Calling Stored Procedures</h1>
|
|
<div id="body8662426"><p id="EN-US_TOPIC_0000001188482198__en-us_topic_0059778625_p81885420719">This section describes how to dynamically call store procedures. You must use anonymous statement blocks to package stored procedures or statement blocks and append <strong id="EN-US_TOPIC_0000001188482198__en-us_topic_0027042945_b630144016112">IN</strong> and <strong id="EN-US_TOPIC_0000001188482198__a14410a605d65473c86355db2f38214b9">OUT</strong> behind the <strong id="EN-US_TOPIC_0000001188482198__ac2e6ba05b5a44edf838c9dc125e895ef">EXECUTE IMMEDIATE...USING</strong> statement to input and output parameters.</p>
|
|
<div class="section" id="EN-US_TOPIC_0000001188482198__sa94d3ae53a7349b7ab6da46433e84562"><h4 class="sectiontitle">Syntax</h4><p id="EN-US_TOPIC_0000001188482198__a988c8a7b0f2b426bb418724a855124a4"><a href="#EN-US_TOPIC_0000001188482198__fd10dcc31d2a145cab7c077a74e08a456">Figure 1</a> shows the syntax diagram.</p>
|
|
<div class="fignone" id="EN-US_TOPIC_0000001188482198__fd10dcc31d2a145cab7c077a74e08a456"><a name="EN-US_TOPIC_0000001188482198__fd10dcc31d2a145cab7c077a74e08a456"></a><a name="fd10dcc31d2a145cab7c077a74e08a456"></a><span class="figcap"><b>Figure 1 </b>call_procedure::=</span><br><span><img id="EN-US_TOPIC_0000001188482198__i8575f310304f41b28358abf15f9e5fa5" src="figure/en-us_image_0000001233563359.png"></span></div>
|
|
<p id="EN-US_TOPIC_0000001188482198__a4ceb061ed5544e1ebb33fdfddc256ba4"><a href="#EN-US_TOPIC_0000001188482198__f26eaef86e5e1488c92f4579266153d2f">Figure 2</a> shows the syntax diagram for <strong id="EN-US_TOPIC_0000001188482198__b29093665165312">using_clause</strong>.</p>
|
|
<div class="fignone" id="EN-US_TOPIC_0000001188482198__f26eaef86e5e1488c92f4579266153d2f"><a name="EN-US_TOPIC_0000001188482198__f26eaef86e5e1488c92f4579266153d2f"></a><a name="f26eaef86e5e1488c92f4579266153d2f"></a><span class="figcap"><b>Figure 2 </b>using_clause-3</span><br><span><img id="EN-US_TOPIC_0000001188482198__i990998edc42d491d803e3f963fcbfb51" src="figure/en-us_image_0000001188482336.png"></span></div>
|
|
<p id="EN-US_TOPIC_0000001188482198__a829f22969559473198daf9c4740856af">The above syntax diagram is explained as follows:</p>
|
|
<ul id="EN-US_TOPIC_0000001188482198__u99aaabc7110c4fd686708deeb6e46da0"><li id="EN-US_TOPIC_0000001188482198__l01cb1c412c2a4cafadda0d8c7f86cf16"><strong id="EN-US_TOPIC_0000001188482198__en-us_topic_0027042945_b274569801625">CALL procedure_name</strong>: calls the stored procedure.</li><li id="EN-US_TOPIC_0000001188482198__l4d8a0362b1144450ad70df40305b222a"><strong id="EN-US_TOPIC_0000001188482198__a8f23d0ae868f4c99930fc0671666c22e">[:placeholder1,:placeholder2,...]</strong>: specifies the placeholder list of the stored procedure parameters. The numbers of the placeholders and the parameters are the same.</li><li id="EN-US_TOPIC_0000001188482198__l7736e416ff9847da91d3f1d85d3e18ea"><strong id="EN-US_TOPIC_0000001188482198__a8698de8f85154e2e9901417e55f1c93d">USING [IN|OUT|IN OUT]bind_argument</strong>: specifies where the variable passed to the stored procedure parameter value is stored. The modifiers in front of <strong id="EN-US_TOPIC_0000001188482198__ab478573de86e41ad99483fd4dc40651e">bind_argument</strong> and of the corresponding parameter are the same.</li></ul>
|
|
</div>
|
|
<div class="section" id="EN-US_TOPIC_0000001188482198__sb5be704bdc5b45ffb56e6e8031a9ce42"><h4 class="sectiontitle">Examples</h4><div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188482198__s76436f2b4ef04572bca491de0fef2641"><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></pre></div></td><td class="code"><div><pre><span></span><span class="c1">--Create the stored procedure proc_add:</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_add</span>
|
|
<span class="p">(</span>
|
|
<span class="w"> </span><span class="n">param1</span><span class="w"> </span><span class="k">in</span><span class="w"> </span><span class="nb">INTEGER</span><span class="p">,</span>
|
|
<span class="w"> </span><span class="n">param2</span><span class="w"> </span><span class="k">out</span><span class="w"> </span><span class="nb">INTEGER</span><span class="p">,</span>
|
|
<span class="w"> </span><span class="n">param3</span><span class="w"> </span><span class="k">in</span><span class="w"> </span><span class="nb">INTEGER</span>
|
|
<span class="p">)</span>
|
|
<span class="k">AS</span>
|
|
<span class="k">BEGIN</span>
|
|
<span class="w"> </span><span class="n">param2</span><span class="p">:</span><span class="o">=</span><span class="w"> </span><span class="n">param1</span><span class="w"> </span><span class="o">+</span><span class="w"> </span><span class="n">param3</span><span class="p">;</span>
|
|
<span class="k">END</span><span class="p">;</span>
|
|
<span class="o">/</span>
|
|
|
|
<span class="k">DECLARE</span>
|
|
<span class="w"> </span><span class="n">input1</span><span class="w"> </span><span class="nb">INTEGER</span><span class="p">:</span><span class="o">=</span><span class="mi">1</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="n">input2</span><span class="w"> </span><span class="nb">INTEGER</span><span class="p">:</span><span class="o">=</span><span class="mi">2</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="k">statement</span><span class="w"> </span><span class="n">VARCHAR2</span><span class="p">(</span><span class="mi">200</span><span class="p">);</span>
|
|
<span class="w"> </span><span class="n">param2</span><span class="w"> </span><span class="nb">INTEGER</span><span class="p">;</span>
|
|
<span class="k">BEGIN</span>
|
|
<span class="w"> </span><span class="c1">--Declare the call statement:</span>
|
|
<span class="w"> </span><span class="k">statement</span><span class="w"> </span><span class="p">:</span><span class="o">=</span><span class="w"> </span><span class="s1">'call proc_add(:col_1, :col_2, :col_3)'</span><span class="p">;</span>
|
|
<span class="w"> </span><span class="c1">--Execute the statement:</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="k">statement</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">input1</span><span class="p">,</span><span class="w"> </span><span class="k">OUT</span><span class="w"> </span><span class="n">param2</span><span class="p">,</span><span class="w"> </span><span class="k">IN</span><span class="w"> </span><span class="n">input2</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="s1">'result is: '</span><span class="o">||</span><span class="n">to_char</span><span class="p">(</span><span class="n">param2</span><span class="p">));</span>
|
|
<span class="k">END</span><span class="p">;</span>
|
|
<span class="o">/</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">proc_add</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>
|
|
|