Procedure parameters appear as a list in the CREATE PROCEDURE statement. Parameter names must conform to the rules for other database identifiers such as column names. They must have valid data types (see SQL data types), and can be prefixed with one of the keywords IN, OUT or INOUT. By default, parameters are INOUT parameters. These keywords have the following meanings:
IN The argument is an expression that provides a value to the procedure.
OUT The argument is a variable that could be given a value by the procedure.
INOUT The argument is a variable that provides a value to the procedure, and could be given a new value by the procedure.
You can assign default values to procedure parameters in the CREATE PROCEDURE statement. The default value must be a constant, which may be NULL. For example, the following procedure uses the NULL default for an IN parameter to avoid executing a query that would have no meaning:
CREATE PROCEDURE CustomerProducts( IN customer_ID INTEGER DEFAULT NULL ) RESULT ( product_ID INTEGER, quantity_ordered INTEGER ) BEGIN IF customer_ID IS NULL THEN RETURN; ELSE SELECT Products.ID, sum( SalesOrderItems.Quantity ) FROM Products, SalesOrderItems, SalesOrders WHERE SalesOrders.CustomerID = customer_ID AND SalesOrders.ID = SalesOrderItems.ID AND SalesOrderItems.ProductID = Products.ID GROUP BY Products.ID; END IF; END; |
The following statement assigns the DEFAULT NULL, and the procedure RETURNs instead of executing the query.
CALL CustomerProducts(); |
Send feedback about this page via email or DocCommentXchange | Copyright © 2008, iAnywhere Solutions, Inc. - SQL Anywhere 11.0.0 |