The CREATE TABLE PROCEDURE data description statement stores the definition of a table procedure in the SQL catalog. You can refer to the table procedure in SQL SELECT, INSERT, UPDATE and DELETE statements just as you would a table. These references result in CA IDMS calls to the corresponding external routine. Although such routines can perform any action, you use them typically to manipulate data stored in some other organization (for example, in a non-SQL-defined database or in a set of VSAM files).
You use the formal parameters of a table procedure definition like the columns of a table during a procedure invocation. You can input values in and return them from the table procedure using column-like syntax.
The CREATE TABLE PROCEDURE statement is a CA IDMS extension of the SQL standard.
To issue a CREATE TABLE PROCEDURE statement, you must own the schema in which the table procedure is being defined or hold the CREATE privilege on the named table procedure.
►►─── CREATE TABLE PROCEDURE ─┬───────────────┬─ table-procedure-identifier ──► └─ schema-name. ┘ ┌──────────── , ────────┐ ►─── ( ─▼─ parameter-definition ┴ ) EXTERNAL NAME external-routine-name ─────► ►────┬─────────────────────────────────┬─┬──────────────────────────┬────────► └─── ESTIMATED ROWS row-count ────┘ └─ ESTIMATED IOS io-count ─┘ ►────┬───────────────┬───────────────────────────────────────────────────────► ├─ USER MODE ◄──┤ └─ SYSTEM MODE ─┘ ►────┬──────────────────────────────────────┬────────────────────────────────► └─ LOCAL WORK AREA ── local-stge-size ─┘ ►────┬────────────────────────────────────────────────────────┬──────────────► └─ GLOBAL WORK AREA ── global-stge-size ──┬──────────────┤ └─ KEY key-id ─┘ ►────┬───────────────────────────────────────────────────────────────┬───────► └─ TRANSACTION SHARING ───────────────────┬─ ON ───────┬────────┘ ├─ OFF ──────┤ └─ DEFAULT ◄─┘ ►────┬───────────────────────────────────────────────────────────────┬───────► └─ DEFAULT DATABASE ────────────────────┬ NULL ◄───┬───────────┘ └─CURRENT──┘ ►────┬───────────────────────────────────────────┬───────────────────────────►◄ └── TIMESTAMP timestamp-value ─────────────┘
Expansion of parameter-definition
►►─── parameter-name ── data-type ─┬────────────────┬─────────────────────────►◄ └─ WITH DEFAULT ─┘
Specifies the 1- to 18-character name of the table procedure you are creating. table-procedure-identifier must:
Specifies the schema name qualifier to be associated with the table procedure. Schema-name must identify a schema defined in the dictionary. If you do not specify a schema-name, it defaults to:
Defines a parameter to be associated with the table procedure. Parameters are passed to the table procedure in the order they are specified. The list of parameters must be enclosed in parentheses. Multiple parameter definitions must be separated by commas.
Expanded syntax for parameter-definition is shown immediately following the CREATE TABLE PROCEDURE syntax. Descriptions for these parameters are located at the end of this section.
Specifies the one- to eight-character name of the program which is called to process references to the table procedure.
Specifies an integer value, in the range 0 through 2,147,483,647, representing the average number of rows returned by the table procedure for a given set of input parameters.
Specifies an integer value, in the range 0 through 2,147,483,647, representing the average number of disk accesses generated by the table procedure for a given set of input parameters.
Specifies the table procedure should execute as a user-mode application program within CA IDMS. This is the default value unless SYSTEM MODE is specified.
Specifies the table procedure should execute as a system mode application program. To execute in system mode, the program must be fully reentrant and be written in either:
Specifies an integer, in the range 0 through 32767, which represents the size, in bytes, of a local storage area which is allocated by CA IDMS at runtime and passed to the table procedure on each invocation.
CA IDMS allocates a local storage area on the first call to a table procedure for each SQL statement within a transaction or for a set of SQL statements which are related through reference to the same cursor (OPEN, FETCH, CLOSE, positioned UPDATE, and DELETE statements are related through a cursor). The same local storage area is passed to the table procedure for all calls for one statement or related statements. When the SQL statement has completed execution or when the cursor is closed, the local work area is released.
Note: If you do not code a LOCAL WORK AREA clause, the default local storage size is 1024 bytes.
Specifies an integer, in the range 0 through 32767, representing the size, in bytes, of the global storage area that CA IDMS allocates at runtime and passes to the table procedure on each invocation.
CA IDMS allocates a global storage area once within a transaction and retains it until the transaction terminates.
Specifies the one- to four-character identifier for the global storage area. CA IDMS passes the same piece of global storage within a transaction to all SQL routines that have the same global storage key.
If you do not specify a storage key, CA IDMS allocates each table procedure its own global storage area, which is not used for any other routine within the transaction.
Specifies whether transaction sharing should be enabled for database sessions started by the table procedure. If transaction sharing is enabled for a procedure's database session, it will share the current SQL session's transaction.
Specifies that transaction sharing should be enabled
Specifies that transaction sharing should be disabled.
Specifies that the transaction sharing setting that is in effect when the table procedure is invoked should be retained.
Specifies whether a default database should be established for database sessions started by the table procedure.
Specifies that no default database should be established.
Specifies that the database to which the SQL session is connected should become the default for any database session started by the table procedure.
Specifies the value of the synchronization stamp to be assigned to the table procedure. Timestamp-value must be a valid external representation of a timestamp.
Parameters for Expansion of parameter-definition
Specifies a 1- to 32-character name of a parameter to be passed to the table procedure. Parameter-name must:
All parameters are implicitly nullable. Input parameters can be assigned NULL as a parameter value and output parameters can return NULL.
Defines the data type for the named parameter. For expanded data-type syntax, see Expansion of Data-type.
Directs CA IDMS to pass a default value for the named parameter if no value for the parameter is specified.
The default value for a parameter is based on its data type:
|
Column data type |
Default value |
|---|---|
|
CHARACTER |
Blanks |
|
VARCHAR |
A character string literal with a length of zero (that is, '') |
|
GRAPHIC |
Double-byte blanks |
|
VARGRAPHIC |
A double-byte character string literal with a length of zero |
|
DATE |
The value in the CURRENT DATE special register |
|
TIME |
The value in the CURRENT TIME special register |
|
TIMESTAMP |
The value in the CURRENT TIMESTAMP special register |
|
All numeric data types |
0 (zero) |
Influencing Join Strategies
CA IDMS uses estimated row and I/O counts in determining the cost of joining a table procedure with other tables, views, or table procedures. To determine the optimal access strategy, CA IDMS examines different sequences for retrieving information. By providing the estimated row and I/O counts for the table procedure and for each access key used by the table procedure, CA IDMS can select the optimal access strategy.
In determining the cost of a specific access strategy, CA IDMS uses estimates provided in CREATE TABLE PROCEDURE unless input values are available for each of the parameters included in a key. If values are available for each of these parameters, CA IDMS uses the estimates specified in the CREATE KEY statement instead of those specified in CREATE TABLE PROCEDURE.
Specifying a Synchronization Stamp
When defining or altering a table procedure, you can specify a value for its synchronization stamp. You should use care when doing so because the purpose of the stamp is to enable the detection of discrepancies between an entity and its definition. If explicitly specified, you must set the synchronization stamp to a new value following a change so that the change is detectable by the runtime system.
If not specified, the synchronization stamp is automatically set to the current date and time.
The following CREATE TABLE PROCEDURE statement defines a table procedure.
create table procedure emp.org (top_key unsigned numeric(4), level smallint, mgr_id unsigned numeric(4), mgr_lname char(25) emp_id unsigned numeric (4), emp_lname char(25) start_date DATE, structure_code char(2)) external name procorgu local work area 800 global work area 600 KEY EMP estimated rows 100 estimated ios 50;
|
Copyright © 2014 CA.
All rights reserved.
|
|