Press "Enter" to skip to content

FORMS_DDL in Oracle D2k

FORMS_DDL in Oracle D2k

Description
Issues dynamic SQL statements at runtime, including server-side PL/SQL and DDL.
Note: All DDL operations issue an implicit COMMIT and will end the current transaction without
allowing Form Builder to process any pending changes.

See also: Quick Trick About Using DBMS_Metadata with Forms_DDL in Oracle Forms
Syntax

FUNCTION FORMS_DDL
(statement VARCHAR2);
Built-in Type unrestricted function
Enter Query Mode yes

Parameters
statement Any string expression up to 32K:
a literal
an expression or a variable representing the text of a block of
dynamically created PL/SQL code
a DML statement or
a DDL statement

Usage Notes
Commit (or roll back) all pending changes before you issue the FORMS_DDL command. All DDL
operations issue an implicit COMMIT and will end the current transaction without allowing Form
Builder to process any pending changes, as well as losing any locks Form Builder may have acquired.
Some supplied stored procedures issue COMMIT or ROLLBACK commands as part of their logic.
Make sure all pending changes in the form are committed or rolled back before you call those built-ins.
Use the SYSTEM.FORM_STATUS variable to check whether there are pending changes in the current
form before you issue the FORMS_DDL command. (See Example 4.)

If you use FORMS_DDL to execute a valid PL/SQL block:
·  Use semicolons where appropriate.
·  Enclose the PL/SQL block in a valid BEGIN/END block structure.
·  Do not end the PL/SQL block with a slash.
·  Line breaks, while permitted, are not required.

If you use FORMS_DDL to execute a single DML or DDL statement:
·  Omit the trailing semicolon to avoid an invalid character error.
To check whether the statement issued using FORMS_DDL executed correctly, use the
FORM_SUCCESS or FORM_FAILURE Boolean functions. If the statement did not execute correctly,
check the error code and error text using DBMS_ERROR_CODE and DBMS_ERROR_TEXT. Note
that the values of DBMS_ERROR_CODE and DBMS_ERROR_TEXT are not automatically reset
following successful execution, so their values should only be examined after an error has been detected
by a call to FORM_SUCCESS or FORM_FAILURE.

FORMS_DDL restrictions
The statement you pass to FORMS_DDL may not contain bind variable references in the string, but the
values of bind variables can be concatenated into the string before passing the result to FORMS_DDL.
For example, this statement is not valid:
Forms_DDL (’Begin Update_Employee (:emp.empno); End;’);
However, this statement is valid, and would have the desired effect:
Forms_DDL (’Begin Update_Employee (’||TO_CHAR(:emp.empno)
||’);End;’);

However, you could also call a stored procedure directly, using Oracle8’s shared SQL area over multiple
executions with different values for emp.empno:
Update_Employee (:emp.empno);
SQL statements and PL/SQL blocks executed using FORMS_DDL cannot return results to Form Builder
directly. (See Example 4.)
In addition, some DDL operations cannot be performed using FORMS_DDL, such as dropping a table or
database link, if Form Builder is holding a cursor open against the object being operated upon.

FORMS_DDL examples
 

Example 1
/*
** Built-in: FORMS_DDL
** Example: The expression can be a string literal.
*/
BEGIN
Forms_DDL(’create table temp(n NUMBER)’);
IF NOT Form_Success THEN
Message (’Table Creation Failed’);
ELSE
Message (’Table Created’);
END IF;
END;

Example 2
/*
** Built-in: FORMS_DDL
** Example: The string can be an expression or variable.
** Create a table with n Number columns.
** TEMP(COL1, COL2, …, COLn).
*/

PROCEDURE Create_N_Column_Number_Table (n NUMBER) IS
my_stmt VARCHAR2(2000);
BEGIN
my_stmt := ’create table tmp(COL1 NUMBER’;
FOR I in 2..N LOOP
my_stmt := my_stmt||’,COL’||TO_CHAR(i)||’ NUMBER’;
END LOOP;
my_stmt := my_stmt||’)’;
/*
** Now, create the table…
*/

Forms_DDL(my_stmt);
IF NOT Form_Success THEN
Message (’Table Creation Failed’);
ELSE
Message (’Table Created’);
END IF;
END;

Example 3:
/*
** Built-in: FORMS_DDL
** Example: The statement parameter can be a block
** of dynamically created PL/SQL code.
*/

DECLARE
procname VARCHAR2(30);
BEGIN
IF :global.flag = ’TRUE’ THEN
procname := ’Assign_New_Employer’;
ELSE
procname := ’Update_New_Employer’;
END IF;
Forms_DDL(’Begin ’|| procname ||’; End;’);
IF NOT Form_Success THEN
Message (’Employee Maintenance Failed’);
ELSE
Message (’Employee Maintenance Successful’);
END IF;
END;

Example 4:
/*
** Built-in: FORMS_DDL
** Example: Issue the SQL statement passed in as an argument,
** and return a number representing the outcome of
** executing the SQL statement.
** A result of zero represents success.
*/

FUNCTION Do_Sql (stmt VARCHAR2, check_for_locks BOOLEAN := TRUE)
RETURN NUMBER
IS
SQL_SUCCESS CONSTANT NUMBER := 0;
BEGIN
IF stmt IS NULL THEN
Message (’DO_SQL: Passed a null statement.’);
RETURN SQL_SUCCESS;
END IF;
IF Check_For_Locks AND :System.Form_Status = ’CHANGED’ THEN
Message (’DO_SQL: Form has outstanding locks pending.’);
RETURN SQL_SUCCESS;
END IF;
Forms_DDL(stmt);
IF Form_Success THEN
RETURN SQL_SUCCESS;
ELSE
RETURN Dbms_Error_Code;
END IF;
END;