Procedures can return results to the calling environment in the parameters to the procedure.
Within a procedure, parameters and variables can be assigned values using:
The following somewhat artificial procedure returns a value in an OUT parameter assigned using a SET statement:
CREATE PROCEDURE greater( IN a INT, IN b INT, OUT c INT ) BEGIN IF a > b THEN SET c = a; ELSE SET c = b; END IF ; END; |
Single-row queries retrieve at most one row from the database. This type of query uses a SELECT statement with an INTO clause. The INTO clause follows the select list and precedes the FROM clause. It contains a list of variables to receive the value for each select list item. There must be the same number of variables as there are select list items.
When a SELECT statement executes, the server retrieves the results of the SELECT statement and places the results in the variables. If the query results contain more than one row, the server returns an error. For queries returning more than one row, you must use cursors. For information about returning more than one row from a procedure, see Returning result sets from procedures.
If the query results in no rows being selected, a warning is returned.
The following procedure returns the results of a single-row SELECT statement in the procedure parameters.
To return the number of orders placed by a given customer
Type the following:
CREATE PROCEDURE OrderCount( IN customer_ID INT, OUT Orders INT ) BEGIN SELECT COUNT(SalesOrders.ID) INTO Orders FROM Customers KEY LEFT OUTER JOIN SalesOrders WHERE Customers.ID = customer_ID; END; |
You can test this procedure in Interactive SQL using the following statements, which show the number of orders placed by the customer with ID 102:
CREATE VARIABLE orders INT; CALL OrderCount ( 102, orders ); SELECT orders; |
Send feedback about this page via email or DocCommentXchange | Copyright © 2008, iAnywhere Solutions, Inc. - SQL Anywhere 11.0.0 |