File: rexecute.xml

package info (click to toggle)
virtuoso-opensource 7.2.5.1%2Bdfsg1-0.3
  • links: PTS, VCS
  • area: main
  • in suites: bookworm
  • size: 285,240 kB
  • sloc: ansic: 641,220; sql: 490,413; xml: 269,570; java: 83,893; javascript: 79,900; cpp: 36,927; sh: 31,653; cs: 25,702; php: 12,690; yacc: 10,227; lex: 7,601; makefile: 7,129; jsp: 4,523; awk: 1,697; perl: 1,013; ruby: 1,003; python: 326
file content (471 lines) | stat: -rw-r--r-- 16,956 bytes parent folder | download | duplicates (2)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
<?xml version="1.0" encoding="ISO-8859-1"?>
<!--
 -  
 -  This file is part of the OpenLink Software Virtuoso Open-Source (VOS)
 -  project.
 -  
 -  Copyright (C) 1998-2018 OpenLink Software
 -  
 -  This project is free software; you can redistribute it and/or modify it
 -  under the terms of the GNU General Public License as published by the
 -  Free Software Foundation; only version 2 of the License, dated June 1991.
 -  
 -  This program is distributed in the hope that it will be useful, but
 -  WITHOUT ANY WARRANTY; without even the implied warranty of
 -  MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU
 -  General Public License for more details.
 -  
 -  You should have received a copy of the GNU General Public License along
 -  with this program; if not, write to the Free Software Foundation, Inc.,
 -  51 Franklin St, Fifth Floor, Boston, MA 02110-1301 USA
 -  
 -  
-->
<refentry id="fn_rexecute">
  <refmeta>
    <refentrytitle>rexecute</refentrytitle>
    <refmiscinfo>rmt</refmiscinfo>
  </refmeta>
  <refnamediv>
    <refname>rexecute</refname>
    <refpurpose>execute a SQL statement on a remote DSN</refpurpose>
  </refnamediv>
  <refsynopsisdiv>
    <funcsynopsis id="fsyn_rexecute">
      <funcprototype id="fproto_rexecute">
        <funcdef><function>rexecute</function></funcdef>
        <paramdef>in <parameter>dsn</parameter> varchar</paramdef>
        <paramdef>in <parameter>sql_stmt</parameter> varchar</paramdef>
        <paramdef>out <parameter>sql_state</parameter> varchar</paramdef>
        <paramdef>out <parameter>error_message</parameter> varchar</paramdef>
        <paramdef>in <parameter>in_params</parameter> vector</paramdef>
        <paramdef>out <parameter>num_cols</parameter> integer</paramdef>
        <paramdef>out <parameter>stmt_meta</parameter> vector</paramdef>
        <paramdef>out <parameter>result_set</parameter> vector</paramdef>
        <paramdef>out <parameter>cursor_handle</parameter> long</paramdef>
      </funcprototype>
    </funcsynopsis>
  </refsynopsisdiv>
  <refsect1 id="desc_rexecute"><title>Description</title>
    <para>This function can be used to execute SQL on a remote data source
    directly.</para>
    <para>The <parameter>result_set</parameter> parameter is useful for 
	obtaining a result-set quickly and easily.  However, if the result-set is 
	going to be large, this comes at a cost in terms of time and resources, 
	particularly memory, since Virtuoso will have to obtain all results from 
	the statement and build the result-set arrays in memory before returning 
	back to the caller.</para>
    <para>A more efficient way is to obtain a cursor handle and iterate
    through the result set one row at a time:</para>
    <simplelist>
      <member>Use <function>rexecute()</function> to get the cursor handle.</member>
      <member>Iterate over the results with <function>rnext()</function></member>
      <member>If <function>rmoreresults()</function> does not return an error or <computeroutput>SQL_NO_DATA_FOUND</computeroutput> 
      continue the loop with <function>rnext()</function>, otherwise</member>
      <member>close the cursor with <function>rclose()</function></member>
    </simplelist>
    <para>To keep Virtuoso from obtaining the whole result set from the
    remote, pass NULL as the <parameter>result_set</parameter> parameter
    when calling rexecute.</para>
    <para><function>Rexecute()</function> supports IN parameters and can also
    support INOUT and OUT parameters.  If INOUT and OUT parameters are to be used
    then cursors should not be used with this function (as the values of output
    parameters in ODBC are not guaranteed to be set before SQLMoreResults()
    returns SQL_NO_DATA_FOUND).  <function>Rexecute</function> supports INOUT and
    OUT parameters by extending the <parameter>in_params</parameter> vector 
	and requiring it to be a PL variable so values can be set back to it.</para>
	<para>Unless explicitly granted, only the DBA group is permitted to use the 
	<function>rexecute()</function> to maintain security.  Caution is required 
	here since any user granted use of <function>rexecute()</function> has 
	full control of the remote data source set-up by the DBA, however limited 
	to the overall abilities of the remote user on the remote data source.  
	Users can be granted and denied access to this function using the following 
	commands:</para>

<programlisting><![CDATA[
GRANT REXECUTE ON '<attached_dsn_name>' TO <user_name>
REVOKE REXECUTE ON '<attached_dsn_name>' FROM <user_name>
]]></programlisting>

<note><title>Note:</title>
  <para><link linkend="fn_rstmtexec"><function>rstmtexec()</function></link> provides a short-hand to this function.</para></note>

  </refsect1>
  <refsect1 id="params_rexecute"><title>Parameters</title>
    <refsect2><title>dsn</title>
      <para>The data source where the SQL statement should be executed.
      You must make sure that you have already defined the data source
      using the <function><link linkend="fn_vd_remote_data_source">
      vd_remote_data_source</link></function> function or by attaching tables from it.</para>
    </refsect2>
    <refsect2><title>sql_stmt</title>
      <para>the SQL statement to execute.</para>
    </refsect2>
    <refsect2><title>sql_state</title>
      <para>A <type>varchar</type> containing the SQL State returned from the
      remote data source.</para>
    </refsect2>
    <refsect2><title>error_message</title>
      <para>A <type>varchar</type> containing any error message returned from
      the remote.</para>
    </refsect2>
    <refsect2><title>in_params</title>
      <para>A <type>vector</type> of parameters to the statement if the
      executed statement has parameters.  IN input parameters are specified
      as literals whereas OUT and INOUT parameters are specified as vectors
      of 3 elements for OUT and 4 elements for INOUT as follows:</para>
      <simplelist>
        <member>[0] - the type of the parameter ('OUT' or 'INOUT')</member>
        <member>[1] - the datatype that the parameter is bound to on the remote</member>
        <member>[2] - the buffer length for the output parameter</member>
        <member>[3] - (INOUT only) the input value of the parameter</member>
      </simplelist>
      <para>Non-vector parameters in the in_params parameter of rexecute are
      considered IN parameters, so the rexecute remains backwards compatible.</para>
    </refsect2>
    <refsect2><title>num_cols</title>
      <para>Number of columns in the result set if the statement returned
      one.</para>
    </refsect2>
    <refsect2><title>stmt_meta</title>
      <para>A <type>vector</type> containing  result metadata, etc.
      </para>
      <table><title>The stmt_meta array</title>
        <tgroup cols="3">
	  <thead><row><entry>Element</entry><entry>Name</entry><entry>Description</entry></row></thead>
	  <tbody>
	    <row>
	      <entry>0</entry>
	      <entry>COLS</entry>
	      <entry>An array containing description of each column in the
	      result set (see table below for contents)</entry>
	    </row>
	    <row>
	      <entry>1</entry>
	      <entry>RES_AVAIL</entry>
	      <entry>An <type>integer</type> 1 indicates that results are
	      available.</entry>
	    </row>
	    <row>
	      <entry>2</entry>
	      <entry>N/A</entry>
	      <entry>Not used</entry>
	    </row>
	    <row>
	      <entry>3</entry>
	      <entry>N/A</entry>
	      <entry>Not used</entry>
	    </row>
	  </tbody>
        </tgroup>
      </table>
      <table><title>Columns array of stmt_meta</title>
        <tgroup cols="3">
	  <thead><row><entry>Element</entry><entry>Name</entry><entry>Description</entry></row></thead>
	  <tbody>
	    <row>
	      <entry>0</entry><entry>name</entry><entry>Column name</entry>
	    </row>
	    <row>
	      <entry>1</entry>
	      <entry>type</entry>
	      <entry>Column type as an internal type code corresponding,
	      but not equal to ODBC SQL type codes.</entry>
	    </row>
	    <row>
	      <entry>2</entry>
	      <entry>scale</entry>
	      <entry>column scale</entry>
	    </row>
	    <row>
	      <entry>3</entry>
	      <entry>precision</entry>
	      <entry>column precision</entry>
	    </row>
	    <row>
	      <entry>4</entry>
	      <entry>nullable</entry>
	      <entry>indicates nullable column</entry>
	    </row>
	    <row>
	      <entry>5</entry>
	      <entry>updatable</entry>
	      <entry>indicates updatable column</entry>
	    </row>
	    <row>
	      <entry>6</entry>
	      <entry>searchable</entry>
	      <entry>indicates searchable column</entry>
	    </row>
	  </tbody>
	</tgroup>
      </table>
    </refsect2>
    <refsect2><title>result_set</title>
      <para>A <type>vector</type> of vectors containing each row in the
      result set.</para>
    </refsect2>
    <refsect2><title>cursor_handle</title>
      <para>The cursor handle (<type>long</type>).</para>
    </refsect2>
  </refsect1>
  <refsect1 id="examples_rexecute">
    <title>Examples</title>
    <example id="ex_rexecute_1"><title>Remote execute example 1</title>
      <para>Remote execute, retrieving the whole result from remote at once.</para>
      <screen><![CDATA[
create procedure
test_rexecute_1 (in remote_dsn varchar)
{
  declare stmt varchar;
  declare mdta_out any;
  declare res_vec_out, param_vec any;
  declare sql_state, err_msg varchar;
  declare inx integer;
  declare num_cols_out integer;

  declare Company, Contact varchar;
  result_names (Company, Contact);

  stmt := 'SELECT CompanyName, ContactName FROM \
             Demo.Demo.Customers WHERE CompanyName BETWEEN ? and ?';
  sql_state := '00000';
  param_vec := vector ('A', 'B');

  rexecute (remote_dsn, stmt, sql_state, err_msg, param_vec,
	    num_cols_out, mdta_out, res_vec_out, NULL);



  if (sql_state <> '00000')  -- See if we got an error
    {
      signal ('ZILCH',
	      concat ('Remote execution returned ',
		      sql_state, ' ', err_msg));
    }

  -- now iterate through result set stored in res_vec_out

  inx := 0;
  while (inx < length (res_vec_out))
    {
      result (aref (aref (res_vec_out, inx), 0),
	      aref (aref (res_vec_out, inx), 1));
      inx := inx + 1;
    }

  end_result ();
}

SQL> test_rexecute_1 ('Local Virtuoso Demo');
Company                   Contact
VARCHAR                   VARCHAR
_______________________________________________________________________________

Alfreds Futterkiste       Maria Anders
Ana Trujillo Emparedados y helados  Ana Trujillo
Antonio Moreno Taquera   Antonio Moreno
Around the Horn           Thomas Hardy

4 Rows. -- 4 msec.
]]>
</screen>
    </example>
    <example id="ex_rexecute_1"><title>Remote execute example 2</title>
      <para>Remote execute, retrieving the result using returned cursor handle.</para>
      <screen><![CDATA[
create procedure
test_rexecute_2 (in remote_dsn varchar, in max_results integer)
{
  declare stmt varchar;
  declare mdta_out any;
  declare res_vec_out, param_vec any;
  declare sql_state, err_msg varchar;
  declare inx integer;
  declare num_cols_out integer;
  declare cursor_out any;

  declare Company, Contact varchar;
  result_names (Company, Contact);

  stmt := 'SELECT CompanyName, ContactName FROM \
             Demo.Demo.Customers WHERE CompanyName BETWEEN ? and ?';
  sql_state := '00000';
  param_vec := vector ('A', 'Z');

  rexecute (remote_dsn, stmt, sql_state, err_msg, param_vec,
	    num_cols_out, mdta_out, NULL, cursor_out);



  if (sql_state <> '00000')  -- See if we got an error
    {
      signal ('ZILCH',
	      concat ('Remote execution returned ',
		      sql_state, ' ', err_msg));
    }

  -- now iterate through result set with cursor

  while (0 = rnext (cursor_out, res_vec_out) and inx < max_results)
    {
      result (aref (res_vec_out, 0), aref (res_vec_out, 1));
      inx := inx + 1;
    }

  rclose (cursor_out);
  end_result ();
}

SQL> test_rexecute_2 ('Local Virtuoso Demo', 10);
Company                   Contact
VARCHAR                   VARCHAR
_______________________________________________________________________________

Alfreds Futterkiste       Maria Anders
Ana Trujillo Emparedados y helados  Ana Trujillo
Antonio Moreno Taquera   Antonio Moreno
Around the Horn           Thomas Hardy
B's Beverages             Victoria Ashworth
Berglunds snabbkp        Christina Berglund
Blauer See Delikatessen   Hanna Moos
Blondel pre et fils      Frdrique Citeaux
Bon app'                  Laurence Lebihan
Bottom-Dollar Markets     Elizabeth Lincoln

10 Rows. -- 19 msec.

]]>
</screen>
    </example>
    <example id="ex_rexecute_4"><title>Remote execute example 3</title>
      <para>Remote DBMS native SQL execution</para>
      <screen><![CDATA[
create procedure test_rexecute_3 (in remote_dsn varchar, in max_results integer)
{
    declare res_vec_out, param_vec, mdta_out, cursor_out any;
    declare url, stmt, sql_state, err_msg varchar;
    declare num_cols_out, inx, _id integer;

    result_names(_id,url);

    stmt := 'select id from mysql_pk';

    sql_state := '00000';
    param_vec := vector ('');

    rexecute (remote_dsn, stmt, sql_state, err_msg, param_vec, num_cols_out, mdta_out, NULL, cursor_out);

    _id := '';

    if (sql_state <> '00000')  -- See if we got an error
    {
      signal ('ZILCH',concat ('Remote execution returned ', sql_state, ' ', err_msg));
    }

    -- now iterate through result set stored in cursor_out
    inx := 0;
    while (0 = rnext (cursor_out, res_vec_out) and inx < max_results)
    {
      _id := aref (res_vec_out, 0);
      {
        whenever not found goto znext;
        select url into url from rdfstore_mysql where id = _id;
      }

       result(_id, url);

       if (0 = mod (inx, 5000))
       {
         log_message(sprintf ('%d rows copied, stay patient (id: %d)', inx, _id));
       }

        znext:;
        inx := inx + 1;
    }

  rclose (cursor_out);
  end_result ();
};
]]></screen>
    </example>

    <example id="ex_rexecute_2"><title>Remote procedures with OUT params.</title>
      <para>The following example demonstrates the use of OUT params using a
      sample remote procedure stored in another Virtuoso server, although this
      can be any database of course, and a local procedure that uses the
      <function>rexecute()</function> to execute it.</para>
      <screen><![CDATA[
--On remote virtuoso:
create procedure FUNCRET (in data varchar) returns varchar { return concat (data, 'Out'); };

--On local virtuoso:
create procedure call_FUNCRET (in data varchar, in DSN varchar) returns integer
{
   declare params any;
   params := vector (
              vector ('out', 'varchar', 50), -- an OUT VARCHAR parameter for the result
                                             -- 50 here means receive no more than 50 bytes of
                                             -- the output value
              data                           -- the IN parameters are passed as usual
             );
   rexecute (DSN, '{?=call FUNCRET(?)}',
            null, null,
            params); -- params should be a PL variable, as it will hold the substituted
                     -- output values for the OUT and INOUT parameters upon return.
   -- retrieve the output value of the first parameter (i.e.
   -- the function return value) and return it:
   return params[0];
};
]]></screen>
<para>
This should return as follows:
</para>
      <screen><![CDATA[
select call_FUNCRET ('abc', 'Local Virtuoso Demo');
---------------------------
abcOut
]]></screen>
    </example>
    <example id="ex_rexecute_3"><title>Remote procedures with INOUT params.</title>
      <para>As well as OUT parameters INOUT parameters can be used.  Consider
      the following variation of the above example:</para>
      <screen><![CDATA[
--On remote Virtuoso:
create procedure INOUT_PROC (inout DATA varchar)
{
   DATA := concat (DATA, 'InOut');
};

--On local Virtuoso:
create procedure call_INOUT_PROC (in DATA varchar, in DSN varchar) returns varchar
{
  declare params any;
  params := (
          vector ('inout', 'VARCHAR', 50, DATA) -- note we pass 4 element array for INOUT,
                                                -- as we need the input value for the parameter
             );
  rexecute (DSN, '{call INOUT_PROC (?)}',
                null, null,
                params);
  return params[0];
};
]]></screen>
<para>
This, when called returns:
</para>
      <screen><![CDATA[
select call_INOUT_PROC ('abc', 'Local Virtuoso Demo');
----------------------
abcInOut
]]></screen>
    </example>
  </refsect1>
  <refsect1 id="seealso_rexecute"><title>See Also</title>
    <para><link linkend="fn_rstmtexec"><function>rstmtexec()</function></link>,
	<link linkend="fn_rnext"><function>rnext()</function></link>,
    <link linkend="fn_rmoreresults"><function>rmoreresults()</function></link>,
    <link linkend="fn_rclose"><function>rclose()</function></link></para>
  </refsect1>
</refentry>