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 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681
|
<HTML>
<HEAD>
<TITLE>prguide.htm</TITLE>
<LINK REL="ToC" HREF="httoc.htm">
<LINK REL="Index" HREF="htindex.htm">
<LINK REL="Next" HREF="prguid12.htm">
<LINK REL="Previous" HREF="prguid10.htm"></HEAD>
<BODY BGCOLOR="#FFFFFF">
<P ALIGN=CENTER>
<A HREF="prguid10.htm" TARGET="_self"><IMG SRC="graprev.gif" WIDTH = 32 HEIGHT = 32 BORDER = 0 ALT="Previous Page"></A>
<A HREF="httoc.htm" TARGET="_self"><IMG SRC="gratoc.gif" WIDTH = 32 HEIGHT = 32 BORDER = 0 ALT="TOC"></A>
<A HREF="htindex.htm" TARGET="_self"><IMG SRC="graindex.gif" WIDTH = 32 HEIGHT = 32 BORDER = 0 ALT="Index"></A>
<A HREF="prguid12.htm" TARGET="_self"><IMG SRC="granext.gif" WIDTH = 32 HEIGHT = 32 BORDER = 0 ALT="Next Page"></A>
<HR ALIGN=CENTER>
<P>
<UL>
<LI>
<A HREF="#E9E12" >Using SOLID Server</A>
<UL>
<LI>
<A HREF="#E10E43" >Stored Procedures</A>
<UL>
<LI>
<A HREF="#E11E40" >Interface</A>
<UL>
<LI>
<A HREF="#E12E26" >Creating, dropping, and Calling Procedures</A></UL>
<LI>
<A HREF="#E11E41" >Access Rights</A>
<LI>
<A HREF="#E11E42" >Procedure Language Syntax</A>
<UL>
<LI>
<A HREF="#E12E27" >Example 1</A>
<LI>
<A HREF="#E12E28" >Example 2</A>
<LI>
<A HREF="#E12E29" >Example 3</A>
<LI>
<A HREF="#E12E30" >Example 4</A></UL></UL>
<LI>
<A HREF="#E10E44" >Event Alerts</A>
<UL>
<LI>
<A HREF="#E11E43" >Interface</A>
<LI>
<A HREF="#E11E44" >Access Rights</A>
<LI>
<A HREF="#E11E45" >Examples</A></UL>
<LI>
<A HREF="#E10E45" >Sequencer Objects</A>
<UL>
<LI>
<A HREF="#E11E46" >Interface</A>
<LI>
<A HREF="#E11E47" >Access Rights</A>
<LI>
<A HREF="#E11E48" >Examples</A></UL></UL></UL>
<HR ALIGN=CENTER>
<A NAME="E9E12"></A>
<H1>
<FONT FACE="Arial"><B>USING SOLID SERVER</B><A NAME="I2"></A><A NAME="I3"></A><A NAME="I4"></A></FONT></H1>
<BR>
<BLOCKQUOTE>
<P>SOLID <I>Server</I> offers a number of features that make it possible to move parts of the application logic into the database. These features include
</BLOCKQUOTE>
<UL>
<BLOCKQUOTE>
<LI>stored procedures
</BLOCKQUOTE>
<BLOCKQUOTE>
<LI>event alerts
</BLOCKQUOTE>
<BLOCKQUOTE>
<LI>sequences
</BLOCKQUOTE></UL>
<A NAME="E10E43"></A>
<H2>
<FONT FACE="Arial"><B>Stored Procedures</B><A NAME="I5"></A></FONT></H2>
<BLOCKQUOTE>
<P>Stored procedures are simple programs, or procedures, that are executed in the server. The user can create a procedure that contains several SQL statements or a whole transaction, and execute it with a single call statement. Usage of stored procedures reduces network traffic and allows more strict control to access rights and database operations.
</BLOCKQUOTE>
<A NAME="E11E40"></A>
<H3>
<FONT FACE="Arial">Interface</FONT></H3>
<BLOCKQUOTE>
<A NAME="E12E26"></A>
<H4>
<FONT>Creating, dropping, and Calling Procedures</FONT></H4>
</BLOCKQUOTE>
<BLOCKQUOTE>
<P>Procedures are created with the
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>CREATE PROCEDURE <I>name</I>
<BR><I> </I>[(<I>parameter-name data-type</I>
<BR><I> </I>[, <I>parameter-name data-type</I> ... ])]
<BR> [RETURNS (<I>parameter-name data-type</I>
<BR><I> </I>[, <I>parameter-name data-type</I> ... ])]
<BR> BEGIN <I>body</I> END;</PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<P>statement and dropped with the
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>DROP PROCEDURE <I>name</I></PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<P>statement. Procedures are called with the statement
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>CALL <I>name</I></PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<P>Procedures can take several input parameters and return a single row or several rows as a result. The resulting rows are built from specified output parameters. Procedures are thus used in ODBC in the same way as the SQL SELECT statement.
</BLOCKQUOTE>
<A NAME="E11E41"></A>
<H3>
<FONT FACE="Arial">Access Rights</FONT></H3>
<BLOCKQUOTE>
<P>Procedures are owned by the creator of the procedure. Specified access rights can be granted to other users. When the procedure is run, it has the creator's access rights to database objects.
</BLOCKQUOTE>
<A NAME="E11E42"></A>
<H3>
<FONT FACE="Arial">Procedure Language Syntax</FONT></H3>
<BLOCKQUOTE>
<P>The stored procedure syntax is a proprietary syntax modelled from SQL3 specifications and dynamic SQL. The procedure body may contain control statements and SQL statements.
</BLOCKQUOTE>
<BLOCKQUOTE>
<P>The following statements are available in the procedures:
</BLOCKQUOTE>
<TABLE >
<TR>
<TD WIDTH=240 VALIGN=top >
<BLOCKQUOTE>
<P><B>Control statement</B>
</BLOCKQUOTE></TD>
<TD WIDTH=216 VALIGN=top >
<A NAME="E7E58"></A>
<P>Description</TD>
</TR>
<TR>
<TD WIDTH=240 VALIGN=top >
<BLOCKQUOTE>
<P>set <I>variable</I> = <I>expression</I>
</BLOCKQUOTE></TD>
<TD WIDTH=216 VALIGN=top >
<A NAME="E7E59"></A>
<P>Assigns a value to a variable. The value can be either a literal value (e.g., 10 or 'text') or another variable. Parameters are considered as normal variables.</TD>
</TR>
<TR>
<TD WIDTH=240 VALIGN=top >
<BLOCKQUOTE>
<P><I>variable</I> := <I>expression</I>
</BLOCKQUOTE></TD>
<TD WIDTH=216 VALIGN=top >
<A NAME="E7E60"></A>
<P>Alternate syntax for assigning values to variables.</TD>
</TR>
<TR>
<TD WIDTH=240 VALIGN=top >
<BLOCKQUOTE>
<P>while
<BR> <I>expr</I>
<BR>loop
<BR> <I>statement-list</I>
<BR>end loop
</BLOCKQUOTE></TD>
<TD WIDTH=216 VALIGN=top >
<A NAME="E7E61"></A>
<P>Loops while expression is true.</TD>
</TR>
<TR>
<TD WIDTH=240 VALIGN=top >
<BLOCKQUOTE>
<P>leave
</BLOCKQUOTE></TD>
<TD WIDTH=216 VALIGN=top >
<A NAME="E7E62"></A>
<P>Leaves the innermost while loop and continues executing the procedure from the next statement after the keyword end loop.</TD>
</TR>
<TR>
<TD WIDTH=240 VALIGN=top >
<BLOCKQUOTE>
<P>if
<BR> <I>expr</I>
<BR>then
<BR> <I>statement-list1</I>
<BR>else
<BR> <I>statement-list2</I>
<BR>end if
</BLOCKQUOTE></TD>
<TD WIDTH=216 VALIGN=top >
<A NAME="E7E63"></A>
<P>Executes <I>statements-list1</I> if expression <I>expr</I> is true; otherwise, executes <I>statement-list2</I>.</TD>
</TR>
<TR>
<TD WIDTH=240 VALIGN=top >
<BLOCKQUOTE>
<P>if
<BR> <I>expr1</I>
<BR>then
<BR> <I>statement-list1</I>
<BR>elseif
<BR> <I>expr2</I>
<BR>then
<BR> <I>statement-list2</I>
<BR>end if
</BLOCKQUOTE></TD>
<TD WIDTH=216 VALIGN=top >
<A NAME="E7E64"></A>
<P>If <I>expr1</I> is true, executes <I>statement-list1</I>. If <I>expr2</I> is true, executes <I>statement-list2</I>. The statement can optionally contain multiple <I>elseif</I> statements and also an <I>else</I> statement.</TD>
</TR>
<TR>
<TD WIDTH=240 VALIGN=top >
<BLOCKQUOTE>
<P>return
</BLOCKQUOTE></TD>
<TD WIDTH=216 VALIGN=top >
<A NAME="E7E65"></A>
<P>Returns the current values of output parameters and exits the procedure. If a procedure has a one <I>return row</I> statement, <I>return</I> behaves like <I>return </I><I>norow</I>.</TD>
</TR>
<TR>
<TD WIDTH=240 VALIGN=top >
<BLOCKQUOTE>
<P>return sqlerror of <I>cursor-name</I>
</BLOCKQUOTE></TD>
<TD WIDTH=216 VALIGN=top >
<A NAME="E7E66"></A>
<P>Returns the sqlerror associated with the cursor and exits the procedure.</TD>
</TR>
<TR>
<TD WIDTH=240 VALIGN=top >
<BLOCKQUOTE>
<P>return row
</BLOCKQUOTE></TD>
<TD WIDTH=216 VALIGN=top >
<A NAME="E7E67"></A>
<P>Returns the current values of output parameters and continues execution. (requires SOLID <I>Server</I> Version 2.2 or later)</TD>
</TR>
<TR>
<TD WIDTH=240 VALIGN=top >
<BLOCKQUOTE>
<P>return norow
</BLOCKQUOTE></TD>
<TD WIDTH=216 VALIGN=top >
<A NAME="E7E68"></A>
<P>Returns the end of the set and exits the procedure. (requires SOLID <I>Server</I> Version 2.2 or later)</TD></TR></TABLE>
<BLOCKQUOTE>
<P>All SQL DML and DDL statements can be used in procedures. Thus, the procedure can, e.g., create tables or commit a transaction. Each SQL statement in the procedure is atomic.
</BLOCKQUOTE>
<BLOCKQUOTE>
<H4>
<FONT FACE="Arial"><B>Preparing SQL Statements</B></FONT></H4>
</BLOCKQUOTE>
<BLOCKQUOTE>
<P>The SQL statements in procedures are first prepared with the statement
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>EXEC SQL PREPARE <I>cursor</I> <I>SQL-statement</I></PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<P>The <I>cursor</I> specification is a cursor name that must be given. It can be any unique cursor name inside the transaction. Note that if the procedure is not a complete transaction, other open cursors outside the procedure may have conflicting cursor names.
</BLOCKQUOTE>
<BLOCKQUOTE>
<H4>
<FONT FACE="Arial"><B>Executing Prepared SQL Statements</B></FONT></H4>
</BLOCKQUOTE>
<BLOCKQUOTE>
<P>The <I>SQL statement</I> is executed with the statement
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>EXEC SQL EXECUTE <I>cursor </I>[<I>opt-using </I>][<I>opt-into </I>]</PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<P>The optional <I>opt-using</I> specification has the syntax
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>USING (<I>variable-list</I>)</PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<P>where <I>variable-list</I> contains a list of procedure variables or parameters separated by a comma. These variables are input parameters for the SQL statement. The SQL input parameters are marked with the standard question mark syntax in the prepare statement. If the SQL statement has no input parameters, the USING specification is ignored.
</BLOCKQUOTE>
<BLOCKQUOTE>
<P>The optional <I>opt-into</I> specification has the syntax
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>INTO (<I>variable-list</I>)</PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<P>where <I>variable-list</I> contains the variables that the column values of the SQL SELECT statement are stored into. The INTO specification is effective only for SQL SELECT statements.
</BLOCKQUOTE>
<BLOCKQUOTE>
<H4>
<FONT FACE="Arial"><B>Fetching Results</B></FONT></H4>
</BLOCKQUOTE>
<BLOCKQUOTE>
<P>Rows are fetched with the statement
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>EXEC SQL FETCH <I>cursor</I></PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<P>If the fetch completed successfully, the column values are stored into the variables defined in the <I>opt-into</I> specification.
</BLOCKQUOTE>
<BLOCKQUOTE>
<H4>
<FONT FACE="Arial"><B>Checking for Errors</B></FONT></H4>
</BLOCKQUOTE>
<BLOCKQUOTE>
<P>The result of each EXEC SQL statement executed inside a procedure body is stored into the variable SQLSUCCESS. This variable is automatically generated for every procedure. If the previous SQL statement was successful, a value one is stored into SQLSUCCESS. After a failed SQL statement, a value zero is stored into SQLSUCCESS.
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>EXEC SQL WHENEVER SQLERROR [ROLLBACK [WORK],] ABORT</PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<P>is used to decrease the need for IF NOT SQLSUCCESS THEN tests after every executed SQL statement.
</BLOCKQUOTE>
<BLOCKQUOTE>
<P>This statement can be used with SOLID <I>Server</I> Version 2.2 or later.
</BLOCKQUOTE>
<BLOCKQUOTE>
<H4>
<FONT FACE="Arial"><B>Using Transactions</B></FONT></H4>
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>EXEC SQL {COMMIT | ROLLBACK} WORK</PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<P>is used to terminate transactions.
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>EXEC SQL SET TRANSACTION {READ ONLY | READ WRITE}</PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<P>is used to control the type of transactions.
</BLOCKQUOTE>
<BLOCKQUOTE>
<H4>
<FONT FACE="Arial"><B>Using Sequencer Objects and Event Alerts</B></FONT></H4>
</BLOCKQUOTE>
<BLOCKQUOTE>
<P>See the discussion about sequencer objects and event alerts later in this chapter.
</BLOCKQUOTE>
<BLOCKQUOTE>
<A NAME="E12E27"></A>
<H4>
<FONT>Example 1</FONT></H4>
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>-- A simple calculator that also tests some control
<BR>-- statements.
<BR>
<BR>create procedure "test1(i1 integer, op char(1),
<BR> i2 integer)
<BR> returns (result varchar)
<BR>begin
<BR> declare i integer;
<BR>
<BR> set i = 10;
<BR> i := 10;
<BR>
<BR> if i <> 10 then
<BR> result := 'Error in first set';
<BR> return;
<BR> end if
<BR>
<BR> while i < 15 loop
<BR> i := i + 1;
<BR> end loop
<BR>
<BR> if i <> 15 then
<BR> result := 'Error in loop1';
<BR> return;
<BR> end if
<BR>
<BR> while i < 100 loop
<BR> if i = 20 then
<BR> leave;
<BR> end if
<BR> i := i + 1;
<BR> end loop
<BR>
if i <> 20 then
<BR> result := 'Error in loop2';
<BR> return;
<BR> end if
<BR>
<BR> if op = '+' then
<BR> result := i1 + i2;
<BR> elseif op = '-' then
<BR> result := i1 - i2;
<BR> elseif op = '*' then
<BR> result := i1 * i2;
<BR> elseif op = '/' then
<BR> result := i1 / i2;
<BR> else
<BR> result := 'Error: illegal op';
<BR> end if
<BR>end";
-- Call and result
call test1(1, '+', 4); -- result: 5
call test1; -- result: Error: illegal op</PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<A NAME="E12E28"></A>
<H4>
<FONT>Example 2</FONT></H4>
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>-- Returns the count from the system table where
<BR>-- the table id
<BR>-- is greater than the procedure input parameter
<BR>-- value.
<BR>
<BR>create procedure "test2(tableid integer)
<BR> returns (cnt integer)
<BR>begin
<BR> exec sql prepare c1 select count(*)
<BR> from sys_tables where id > ?;
<BR> exec sql execute c1 using (tableid) into (cnt);
<BR> exec sql fetch c1;
<BR>end";
-- Call and result
call test2(0); -- result: 24
call test2(10000); -- result: 0</PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<A NAME="E12E29"></A>
<H4>
<FONT>Example 3</FONT></H4>
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>-- Simple insert
<BR>
<BR>create procedure "test3(empid integer, empname varchar)
<BR> returns (succ integer)
<BR>begin
<BR> exec sql prepare c1 insert into employee
<BR> values ( ?, ?);
<BR> exec sql execute c1 using (empid, empname);
<BR>
<BR> if not sqlsuccess then
<BR> succ := 0;
<BR> else
<BR> succ := 1;
<BR> end if
<BR>end";
-- Call and result
call test3(1, 'Donald Duck'); -- result: 1</PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<A NAME="E12E30"></A>
<H4>
<FONT>Example 4</FONT></H4>
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>create table employee (id integer, name varchar);
<BR>create table employee2 (id integer, name varchar);
-- inserts a row in table employee2
create procedure "test4(empid integer, empname varchar)
<BR>returns (succ integer)
<BR>begin
<BR> exec sql prepare c4 insert into employee2
<BR> values(?, ?);
<BR> exec sql execute c4 using (empid, empname);
<BR>
<BR> if not sqlsuccess then
<BR> succ := 0;
<BR> else
<BR> succ := 1;
<BR> end if
<BR>end";
<BR>
<BR>-- inserts every row found in table employee also in
<BR>-- table employee2
create procedure "test5(empid integer, empname varchar)
<BR>returns (result integer)
<BR>begin
<BR> declare rowcount integer;
<BR> declare r1 integer;
<BR> declare r2 varchar;
<BR> declare a1 integer;
<BR>
<BR> exec sql prepare c1 select count(*) from employee
<BR> where id = ? or name = ?;
<BR> exec sql execute c1 using (empid, empname)
<BR> into ( rowcount);
<BR> exec sql fetch c1;
<BR>
<BR> exec sql prepare c2 select id, name from employee
<BR> where id = ? or name = ?;
<BR> exec sql execute c2 using (empid, empname)
<BR> into ( r1, r2);
<BR>
<BR> while
<BR> rowcount > 0
<BR> loop
<BR> exec sql fetch c2;
<BR> exec sql prepare c3 call test4(?, ?);
<BR> exec sql execute c3 using (r1, r2) into (a1);
<BR> if a1 = 0 then
<BR> exec sql rollback work;
<BR> leave;
<BR> end if
<BR> rowcount := rowcount -1;
<BR> end loop
<BR>
<BR> if rowcount = 0 then
<BR> exec sql commit work;
<BR> end if
<BR> result := rowcount;
<BR>end";
-- Call and result
call test5(1, 'Donald Duck'); -- result: 0</PRE></BLOCKQUOTE>
<A NAME="E10E44"></A>
<H2>
<FONT FACE="Arial"><B>Event Alerts</B><A NAME="I6"></A></FONT></H2>
<BLOCKQUOTE>
<P>Event alerts are used to signal an event in the database. Events are simple objects with a name. The use of event alerts removes resource consuming database polling from applications.
</BLOCKQUOTE>
<BLOCKQUOTE>
<P>The system does not automatically generate events, they must be triggered by stored procedures. Similarly the events are received in stored procedures. When an application calls a stored procedure that waits for a specific event to happen, the application is blocked until the event is triggered and received. In multithreaded environments separate threads and connections can be used to access the database during the event standstill.
</BLOCKQUOTE>
<A NAME="E11E43"></A>
<H3>
<FONT FACE="Arial">Interface</FONT></H3>
<BLOCKQUOTE>
<P>An event has a name that identifies it and a set of parameters. The name can be any user-specified alphanumeric string. An event object is created with the SQL statement
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>CREATE EVENT <I>event-name</I>
<BR> [(<I>parameter-name data-type</I>
<BR><I> </I>[<I>parameter-name data-type</I> ...])]</PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<P>The parameter list specifies parameter names and parameter types. The parameter types are normal SQL types. Events are dropped with the SQL statement
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>DROP EVENT <I>event-name</I></PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<P>Events are triggered and received inside stored procedures. Special stored procedure statements are used to trigger and receive events.
</BLOCKQUOTE>
<BLOCKQUOTE>
<P>The event is triggered with the stored procedure statement
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>POST EVENT <I>event-name</I> (<I>parameters</I>)</PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<P>Event parameters must be local variables or parameters in the stored procedure where the event is triggered. All clients that are waiting for the posted event will receive the event.
</BLOCKQUOTE>
<BLOCKQUOTE>
<P>To make a procedure wait for an event to happen, the WAIT EVENT construct is used in the stored procedure:
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>wait-event-statement ::=
<BR> WAIT EVENT
<BR> [event-specification ...]
<BR> END WAIT
event-specification ::=
<BR> WHEN <I>event-name</I> (<I>parameters</I>) BEGIN
<BR> <I>statements</I>
<BR> END EVENT</PRE></BLOCKQUOTE>
<A NAME="E11E44"></A>
<H3>
<FONT FACE="Arial">Access Rights</FONT></H3>
<BLOCKQUOTE>
<P>The creator of an event or the database administrator can grant and revoke access rights to an event. Access rights can be granted to users and roles. The select access right gives waiting access to an event. The insert access right gives triggering access to an event.
</BLOCKQUOTE>
<A NAME="E11E45"></A>
<H3>
<FONT FACE="Arial">Examples</FONT></H3>
<BLOCKQUOTE>
<PRE>-- Create test event
<BR>create event test1;
<BR>
<BR>-- Create test procedure that waits events
<BR>create procedure "event_wait
<BR>returns (result varchar)
<BR>begin
<BR>wait event
<BR> when test1 begin
<BR> result := 'receive';
<BR> return;
<BR> end event
<BR>
<BR>end wait
<BR>end";
<BR>
<BR>-- Create test procedure that generates
<BR>-- events
<BR>create procedure "event_send
<BR>returns (result varchar)
<BR>begin
<BR> result := 'send';
<BR> post event test1;
<BR>end";
-- client 1 calls event_wait procedure
<BR>call event_wait;
<BR>-- and starts waiting for the event test1
<BR>
<BR>-- client 2 calls event_send procedure
<BR>call event_send;
<BR>
<BR>-- client 2 returns
<BR>send
<BR>-- and posts event test1
<BR>
<BR>-- client 1 receives event test1 and
<BR>-- returns
<BR>receive</PRE></BLOCKQUOTE>
<A NAME="E10E45"></A>
<H2>
<FONT FACE="Arial"><B>Sequencer Objects</B><A NAME="I7"></A></FONT></H2>
<BLOCKQUOTE>
<P>A sequencer object is an object that can be used to get sequence numbers. Depending on how the sequence is created, there may or may not be holes in the sequence (the sequence can be sparse or dense).
</BLOCKQUOTE>
<BLOCKQUOTE>
<P>Dense sequences guarantee that there are no holes in the sequence numbers. The sequence number allocation is bound to the current transaction. If the transaction rolls back, also the sequence number allocations are rolled back. The drawback of dense sequences is that the sequence is locked out from other transactions until the current transaction ends.
</BLOCKQUOTE>
<BLOCKQUOTE>
<P>If there is no need for dense sequences, a sparse sequence can be used. A sparse sequence guarantees uniqueness of the returned values, but it is not bound to the current transaction. If a transaction allocates a sparse sequence number and later rolls back, the sequence number is simply lost.
</BLOCKQUOTE>
<BLOCKQUOTE>
<P>A sequence object can be used, for example, to generate invoice numbers. The advantage of using a sequence object instead of a separate table is that the sequence object is specifically fine-tuned for fast execution and requires less overhead than normal update statements.
</BLOCKQUOTE>
<BLOCKQUOTE>
<P>Both dense and sparse sequence numbers start from 1.
</BLOCKQUOTE>
<A NAME="E11E46"></A>
<H3>
<FONT FACE="Arial">Interface</FONT></H3>
<BLOCKQUOTE>
<P>Sequences are created using the CREATE SEQUENCE statement:
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>CREATE [DENSE] SEQUENCE <I>sequence-name</I></PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<P>By default, the created sequence is sparse, unless the keyword DENSE is given.
</BLOCKQUOTE>
<BLOCKQUOTE>
<P>Sequences are dropped using the DROP SEQUENCE statement:
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>DROP SEQUENCE <I>sequence-name</I></PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<P>Sequences are accessed from stored procedures. The current sequence value can be retrieved using the following stored procedure statement:
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>EXEC SEQUENCE <I>sequence-name</I>.CURRENT INTO <I>variable</I></PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<P>The new sequence value can be retrieved using the following stored procedure statement:
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>EXEC SEQUENCE <name>.NEXT INTO <variable></PRE></BLOCKQUOTE>
<BLOCKQUOTE>
<P>Sequence values can be set with the following stored procedure statement:
</BLOCKQUOTE>
<BLOCKQUOTE>
<PRE>EXEC SEQUENCE sequence-name SET VALUE USING variable</PRE></BLOCKQUOTE>
<A NAME="E11E47"></A>
<H3>
<FONT FACE="Arial">Access Rights</FONT></H3>
<BLOCKQUOTE>
<P>Select access rights are required to retrieve the current sequence value. Update access rights are required to allocate new sequence values. Sequence access rights are granted and revoked in the same way as table access rights.
</BLOCKQUOTE>
<A NAME="E11E48"></A>
<H3>
<FONT FACE="Arial">Examples</FONT></H3>
<BLOCKQUOTE>
<PRE>-- Create a dense sequence, the keyword DENSE is
<BR>-- required
<BR>CREATE DENSE SEQUENCE SPTEST6_DENSE;
<BR>-- Create a sparse sequence, by default
<BR>-- sequences are sparse
<BR>CREATE SEQUENCE SPTEST6_SPARSE;
<BR>
<BR>-- Create a procedure that retuns new
<BR>-- seqeunce values
<BR>create procedure "sptest6
<BR> returns (denseval integer, sparseval integer)
<BR>begin
<BR> exec sequence sptest6_dense.next into denseval;
<BR> exec sequence sptest6_sparse.next into sparseval;
<BR>end";
-- Call and result
<BR>
<BR>call sptest6; -- returns: 1 1
call sptest6; -- returns: 2 2</PRE><P ALIGN=CENTER>
<A HREF="prguid10.htm" TARGET="_self"><IMG SRC="graprev.gif" WIDTH = 32 HEIGHT = 32 BORDER = 0 ALT="Previous Page"></A>
<A HREF="httoc.htm" TARGET="_self"><IMG SRC="gratoc.gif" WIDTH = 32 HEIGHT = 32 BORDER = 0 ALT="TOC"></A>
<A HREF="htindex.htm" TARGET="_self"><IMG SRC="graindex.gif" WIDTH = 32 HEIGHT = 32 BORDER = 0 ALT="Index"></A>
<A HREF="prguid12.htm" TARGET="_self"><IMG SRC="granext.gif" WIDTH = 32 HEIGHT = 32 BORDER = 0 ALT="Next Page"></A>
<center><p><font SIZE=-2>Copyright © 1992-1997 Solid Information Technology Ltd All rights reserved.</font></p></center>
</BLOCKQUOTE></BODY></HTML>
|