The DROP statement drops an object. Objects that are directly
or indirectly dependent on that object may also be dropped.
This statement can be embedded in an application program or issued interactively.
It is an executable statement that can be dynamically prepared.
To drop a table, view, index, alias, or package, the privileges held by
the authorization ID of the statement must include at least one of the following:
- The following system authorities:
- The system authorities of *OBJOPR and *OBJEXIST on the object to be dropped
- If the object is a table or view, the system authorities of *OBJOPR and
*OBJEXIST on any views, indexes, and logical files that are dependent on that
table or view
- The system authority *EXECUTE on the library that contains the object
to be dropped
- Administrative authority
To drop a schema, the privileges held by the authorization ID of the statement
must include at least one of the following:
- The following system authorities:
- The system authorities of *OBJEXIST, *OBJOPR, *EXECUTE, and *READ on the
library to be dropped.
- The system authorities of *OBJOPR and *OBJEXIST on all objects in the
schema and *OBJOPR and *OBJEXIST on any views, indexes and logical files that
are dependent on tables and views in the schema.
- Any additional authorities required to delete other object types that
exist in the schema. For example, *OBJMGT to the data dictionary if the schema
contains a data dictionary, and some system data authority to the journal
receiver. For more information, see the iSeries Security
Reference
book.
- Administrative authority
To drop a distinct type, the privileges held by the authorization ID of the statement
must include at least one of the following:
- The following system authorities:
- The system authorities of *OBJOPR and *OBJEXIST on the distinct type to be dropped
- The system authority *EXECUTE on the library that contains the distinct type to
be dropped
- The DELETE privilege on the SYSTYPES, SYSPARMS, and SYSROUTINES catalog
tables, and
- The system authority *EXECUTE on library QSYS2
- Administrative authority
To drop a function, the privileges held by the authorization ID of the
statement must include at least one of the following:
- The following system authorities:
- For SQL functions, the system authority *OBJEXIST on the service program
object associated with the function, and
- The DELETE privilege on the SYSFUNCS, SYSPARMS, and SYSROUTINEDEP
catalog tables, and
- The system authority *EXECUTE on library QSYS2
- Administrative authority
To drop a procedure, the privileges held by the authorization ID of the
statement must include at least one of the following:
- The following system authorities:
- For SQL procedures, the system authority *OBJEXIST on the program object
associated with the procedure, and
- The DELETE privilege on the SYSPROCS, SYSPARMS, and SYSROUTINEDEP
catalog tables, and
- The system authority *EXECUTE on library QSYS2
- Administrative authority
To drop a sequence, the privileges held by the authorization ID of the
statement must include at least one of the following:
- The following system authorities:
- The system authority *OBJEXIST on the data area associated with the sequence,
and
- The system authority *EXECUTE on the library that contains
the sequence to be dropped
- The DELETE privilege on the SYSSEQOBJECTS catalog table, and
- The system authority *EXECUTE on library QSYS2, and
- *USE to the Delete Data Area (DLTDTAARA) command
- Administrative authority
To drop a trigger, the privileges held by the authorization ID of the statement
must include at least one of the following:
- The following privileges:
- The system authority *USE to the Remove Physical File Trigger (RMVPFTRG)
command, and
- For the subject table or view of the trigger:
- The ALTER privilege to the subject table or view, and
- The system authority *EXECUTE on the library containing the subject table
or view,
- If the trigger being dropped is an SQL trigger:
- The system authority *OBJEXIST on the trigger program object, and
- The system authority *EXECUTE on the library containing the trigger.
- Administrative authority
For information on the system authorities corresponding to SQL privileges,
see Corresponding System Authorities When Checking Privileges to a Table or View.
>>-DROP--+-ALIAS--alias-name---------------------------------------------------+-><
| .-DISTINCT-. |
+-+----------+--TYPE--distinct-type-name--+----------+----------------+
| +-RESTRICT-+ |
| '-CASCADE--' |
+-+-+-FUNCTION-+--function-name--+------------------------------+-+---+
| | '-ROUTINE--' '-(--+--------------------+--)-' | |
| | | .-,--------------. | | |
| | | V | | | |
| | '---parameter-type-+-' | |
| '-SPECIFIC--+-FUNCTION-+--specific-name-------------------------' |
| '-ROUTINE--' |
+-INDEX--index-name---------------------------------------------------+
+-PACKAGE--package-name--+-------------------------+------------------+
| | .-VERSION-. | |
| '-+---------+--version-id-' |
+-+-+-PROCEDURE-+--procedure-name--+------------------------------+-+-+
| | '-ROUTINE---' '-(--+--------------------+--)-' | |
| | | .-,--------------. | | |
| | | V | | | |
| | '---parameter-type-+-' | |
| '-SPECIFIC--+-PROCEDURE-+--specific-name--------------------------' |
| '-ROUTINE---' |
+-SCHEMA--schema-name--+----------+-----------------------------------+
| +-RESTRICT-+ |
| '-CASCADE--' |
| .-RESTRICT-. |
+-SEQUENCE--sequence-name--+----------+-------------------------------+
+-TABLE--table-name--+----------+-------------------------------------+
| +-RESTRICT-+ |
| '-CASCADE--' |
+-TRIGGER--trigger-name-----------------------------------------------+
'-VIEW--view-name--+----------+---------------------------------------'
+-RESTRICT-+
'-CASCADE--'
parameter-type:
|----data-type--+------------+----------------------------------|
'-AS LOCATOR-'
data-type:
|--+-built-in-type------+---------------------------------------|
'-distinct-type-name-'
built-in-type:
|--+-+---SMALLINT---+----------------------------------------------------------------------------------------------+--|
| +-+-INTEGER-+--+ |
| | '-INT-----' | |
| '---BIGINT-----' |
| .-(5,0)----------------------------. |
+-+-+-DECIMAL-+-+--+----------------------------------+---------------------------------------------------------+
| | '-DEC-----' | '-(--+------------------------+--)-' |
| '-NUMERIC-----' '-integer--+-----------+-' |
| '-, integer-' |
| .-(53)----------. |
+-+-FLOAT--+---------------+-+----------------------------------------------------------------------------------+
| | '-(--integer--)-' | |
| +-REAL---------------------+ |
| | .-PRECISION-. | |
| '-DOUBLE--+-----------+----' |
| .-(1)---------------. |
+-+-+-+-CHARACTER-+--+-------------------+--------------+--+----------------+---------------------------------+-+
| | | '-CHAR------' '-(--+---------+--)-' | +-FOR BIT DATA---+ | |
| | | '-integer-' | +-FOR SBCS DATA--+ | |
| | '---+-+-CHARACTER-+--VARYING-+--(--+---------+--)---' +-FOR MIXED DATA-+ | |
| | | '-CHAR------' | '-integer-' '-CCSID--integer-' | |
| | '-VARCHAR----------------' | |
| | .-(1M)---------------------. | |
| '-----+-+-CHARACTER-+--LARGE OBJECT-+------+--------------------------+--+----------------+--+------------+-' |
| | '-CHAR------' | '-(--+---------+--+---+--)-' +-FOR SBCS DATA--+ '-AS LOCATOR-' |
| '-CLOB------------------------' '-integer-' +-K-+ +-FOR MIXED DATA-+ |
| +-M-+ '-CCSID--integer-' |
| '-G-' |
| .-(1)---------------. |
+-+-+---GRAPHIC----+-------------------+---------+--+----------------+-----------+------------------------------+
| | | '-(--+---------+--)-' | '-CCSID--integer-' | |
| | | '-integer-' | | |
| | '---+-VARGRAPHIC------+--(--+---------+--)---' | |
| | '-GRAPHIC VARYING-' '-integer-' | |
| | .-(1M)---------------------. | |
| '---DBCLOB----+--------------------------+--+----------------+--+------------+-' |
| '-(--+---------+--+---+--)-' '-CCSID--integer-' '-AS LOCATOR-' |
| '-integer-' +-K-+ |
| +-M-+ |
| '-G-' |
| .-(1)---------------. |
+-+-+-BINARY--+-------------------+---------+---------------------------------+---------------------------------+
| | | '-(--+---------+--)-' | | |
| | | '-integer-' | | |
| | '-+-BINARY VARYING-+--(--+---------+--)-' | |
| | '-VARBINARY------' '-integer-' | |
| | .-(1M)---------------------. | |
| '---+-BLOB----------------+----+--------------------------+--+------------+-' |
| '-BINARY LARGE OBJECT-' '-(--+---------+--+---+--)-' '-AS LOCATOR-' |
| '-integer-' +-K-+ |
| +-M-+ |
| '-G-' |
+-+---DATE-----------------+------------------------------------------------------------------------------------+
| | .-(--0--)-. | |
| +-TIME--+---------+------+ |
| | .-(--6--)-. | |
| '-TIMESTAMP--+---------+-' |
| .-(200)-------------. |
+---DATALINK--+-------------------+--+----------------+---------------------------------------------------------+
| '-(--+---------+--)-' '-CCSID--integer-' |
| '-integer-' |
'---ROWID-------------------------------------------------------------------------------------------------------'
- ALIAS alias-name
- Identifies the alias that is to be dropped. The alias-name must identify an alias that exists at the current server.
The specified alias is deleted from the schema. Dropping an alias has no effect
on any constraint, view, or materialized query that was defined using the
alias. An alias can be dropped whether or not it is referenced in a function,
package, procedure, program, or trigger.
- DISTINCT TYPE distinct-type-name
- Identifies the distinct type that is to be dropped. The distinct-type-name must
identify a distinct type that exists at the current server. The specified type is
deleted from the schema.
- Neither CASCADE nor RESTRICT
- Specifies that the type cannot be dropped if any constraints, indexes,
sequences, tables, and views reference the type.
For every procedure or
function R that has parameters or a return value of the type being
dropped, or a reference to the type being dropped, the following DROP statement
is effectively executed:
DROP ROUTINE R
For every trigger T that references the type being dropped, the
following DROP statement is effectively executed:
DROP TRIGGER T
It is possible that this statement would cascade
to drop dependent functions or procedures. If all of these functions or procedures
are in the list to be dropped because of a dependency on the distinct type, the drop
of the distinct type will succeed.
- CASCADE
- Specifies that the type will be dropped even if it is referenced in
a constraint, function, index, procedure, sequence, table, trigger, or view.
All constraints, functions, indexes, procedures, sequences, tables, triggers,
and views that reference the type are dropped.
- RESTRICT
- Specifies that the type cannot be dropped if it is referenced in a constraint,
function (other than a function that was created when the type was created),
index, procedure, sequence, table, trigger, or view.
- FUNCTION or SPECIFIC FUNCTION
- Identifies the function that is to be dropped. The function must exist
at the current server and it must be a function that was defined with the
CREATE FUNCTION statement. The particular function can be identified by its
name, function signature, or specific name.
Functions implicitly generated
by the CREATE DISTINCT TYPE statement cannot be dropped using the DROP statement.
They are implicitly dropped when the distinct type is dropped.
The function
cannot be dropped if another function is dependent on it. A function is dependent
on another function if it was identified in the SOURCE clause of the CREATE
FUNCTION statement. A function can be dropped whether or not it is referenced
in a function, package, procedure, program, trigger, or view.
The specified
function is dropped from the schema. All privileges on the user-defined function
are also dropped. If this is an SQL function or sourced function, the service
program (*SRVPGM) associated with the function is also dropped. If this is
an external function, the information that was saved in the program or service
program specified on the CREATE FUNCTION statement is removed from the object.
- FUNCTION function-name
- Identifies the function by its name. The function-name must identify exactly one function. The function may have any number
of parameters defined for it. If there is more than one function of the specified
name in the specified or implicit schema, an error is returned.
- FUNCTION function-name (parameter-type, ...)
- Identifies the function by its function signature, which uniquely identifies
the function. The function-name (parameter-type, ...) must identify a function with the specified function signature. The
specified parameters must match the data types in the corresponding position
that were specified when the function was created. The number of data types,
and the logical concatenation of the data types is used to identify the specific
function instance which is to be dropped. Synonyms for data types are considered
a match.
If function-name () is specified, the function identified
must have zero parameters.
- function-name
- Identifies the name of the function.
- (parameter-type, ...)
- Identifies the parameters of the function.
If an unqualified distinct
type name is specified, the database manager searches the SQL path to resolve the schema
name for the distinct type.
For data types that have a length, precision,
or scale attribute, use one of the following:
- Empty parentheses indicate that the database manager ignores the attribute when determining
whether the data types match. For example, DEC() will be considered a match
for a parameter of a function defined with a data type of DEC(7,2). However,
FLOAT cannot be specified with empty parenthesis because its parameter value
indicates a specific data type (REAL or DOUBLE).
- If a specific value for a length, precision, or scale attribute is specified,
the value must exactly match the value that was specified (implicitly or explicitly)
in the CREATE FUNCTION statement. If the data type is FLOAT, the precision
does not have to exactly match the value that was specified because matching
is based on the data type (REAL or DOUBLE).
- If length, precision, or scale is not explicitly specified, and empty
parentheses are not specified, the default attributes of the data type are
implied. The implicit length must exactly match the value that was specified
(implicitly or explicitly) in the CREATE FUNCTION statement.
Specifying the FOR DATA clause or CCSID clause is optional. Omission
of either clause indicates that the database manager ignores the attribute when determining
whether the data types match. If either clause is specified, it must match
the value that was implicitly or explicitly specified in the CREATE FUNCTION
statement.
- AS LOCATOR
- Specifies that the function is defined to receive a locator for this
parameter. If AS LOCATOR is specified, the data type must be a LOB or a distinct
type based on a LOB.
- SPECIFIC FUNCTION specific-name
- Identifies the function by its specific name. The specific-name must identify a specific function that exists at the current
server.
- INDEX index-name
- Identifies the index that is to be dropped. The index-name must identify an index that exists at the current server.
The specified index is dropped from the schema. An index can be dropped whether
or not it is referenced in a function, package, procedure, program, or trigger.
- PACKAGE package-name
- Identifies the package that is to be dropped. The package-name must identify a package that exists at the current server.
The specified package is dropped from the schema. All privileges on the package
are also dropped.
A package can be dropped whether or not it is referenced
in a function, package, procedure, program, or trigger.
- VERSION version-id
- version-id is the version identifier that was assigned to the
package when it was created. If version-id is not specified, a null
string is used as the version identifier.
- PROCEDURE or SPECIFIC PROCEDURE
- Identifies the procedure that is to be dropped. The procedure-name must identify a procedure that exists at the current server.
The specified procedure is dropped from the schema. All privileges on the
procedure are also dropped. If this is an SQL procedure, the program (*PGM)
associated with the procedure is also dropped. If this is an external procedure,
the information that was saved in the program specified on the CREATE PROCEDURE
statement is removed from the object.
A procedure can be dropped whether
or not it is referenced in a function, package, procedure, program, trigger,
or view.
- PROCEDURE procedure-name
- Identifies the procedure by its name. The procedure-name must identify exactly one procedure. The procedure may have any number
of parameters defined for it. If there is more than one procedure of the specified
name in the specified or implicit schema, an error is returned.
- PROCEDURE procedure-name (parameter-type, ...)
- Identifies the procedure by its procedure signature, which uniquely
identifies the procedure. The procedure-name (parameter-type,
...) must identify a procedure with the specified procedure signature.
The specified parameters must match the data types in the corresponding position
that were specified when the procedure was created. The number of data types,
and the logical concatenation of the data types is used to identify the specific
procedure instance which is to be dropped. Synonyms for data types are considered
a match.
If procedure-name () is specified, the procedure identified
must have zero parameters.
- procedure-name
- Identifies the name of the procedure.
- (parameter-type, ...)
- Identifies the parameters of the procedure.
If an unqualified distinct
type name is specified, the database manager searches the SQL path to resolve the schema
name for the distinct type.
For data types that have a length, precision,
or scale attribute, use one of the following:
- Empty parentheses indicate that the database manager ignores the attribute when determining
whether the data types match. For example, DEC() will be considered a match
for a parameter of a procedure defined with a data type of DEC(7,2). However,
FLOAT cannot be specified with empty parenthesis because its parameter value
indicates a specific data type (REAL or DOUBLE).
- If a specific value for a length, precision, or scale attribute is specified,
the value must exactly match the value that was specified (implicitly or explicitly)
in the CREATE PROCEDURE statement. If the data type is FLOAT, the precision
does not have to exactly match the value that was specified because matching
is based on the data type (REAL or DOUBLE).
- If length, precision, or scale is not explicitly specified, and empty
parentheses are not specified, the default attributes of the data type are
implied. The implicit length must exactly match the value that was specified
(implicitly or explicitly) in the CREATE PROCEDURE statement.
Specifying the FOR DATA clause or CCSID clause is optional. Omission
of either clause indicates that the database manager ignores the attribute when determining
whether the data types match. If either clause is specified, it must match
the value that was implicitly or explicitly specified in the CREATE PROCEDURE
statement.
- AS LOCATOR
- Specifies that the procedure is defined to receive a locator for this
parameter. If AS LOCATOR is specified, the data type must be a LOB or a distinct
type based on a LOB.
- SPECIFIC PROCEDURE specific-name
- Identifies the procedure by its specific name. The specific-name must identify a specific procedure that exists at the current
server.
- SCHEMA schema-name
- Identifies the schema that is to be dropped. The schema-name must identify a schema that exists at the current server.
The specified schema is dropped. Each object in the schema is dropped as if
the appropriate DROP statement was executed with the specified drop option
(CASCADE, RESTRICT, or neither). See the DROP description of these object
types for information on the handling of objects dependent on these objects.
DROP SCHEMA is only valid when the commit level is *NONE.
- Neither CASCADE nor RESTRICT
- Specifies that the schema will be dropped even if it is referenced in
a function, package, procedure, program, table, or trigger in another schema.
- CASCADE
- Specifies that any objects in the schema and any triggers that reference
the schema will be dropped.
- RESTRICT
- Specifies that the schema cannot be dropped if it is referenced in an
SQL trigger in another schema or if the schema contains any SQL objects other
than catalog views, the journal, and journal receiver.
- SEQUENCE sequence-name
- Identifies the sequence that is to be dropped. The sequence-name must identify a sequence that exists at the current server.
- RESTRICT
- Specifies that the sequence cannot be dropped if it is referenced in
an SQL trigger, function, or procedure.
- TABLE table-name
- Identifies the table that is to be dropped. The table-name must identify a base table that exists at the current server,
but must not identify a catalog table.
The specified table is dropped from
the schema. All privileges, constraints, indexes, and triggers on the table
are also dropped.
Any aliases that reference the specified table are
not dropped.
- Neither CASCADE nor RESTRICT
- Specifies that the table will be dropped even if it is referenced
in a constraint, index, trigger, view, or materialized query table. All indexes,
views, and materialized query tables that reference the table are dropped
even if the authorization ID of the statement does not explicitly have privileges
to those objects.
- CASCADE
- Specifies that the table will be dropped even if it is referenced
in a constraint, index, trigger, view, or materialized query table. All constraints,
indexes, triggers, views, and materialized query tables that reference the
table are dropped even if the authorization ID of the statement does not explicitly
have privileges to those objects.
- RESTRICT
- Specifies that the table cannot be dropped if it is referenced in a
constraint, index, trigger, view, or materialized query table.
- TRIGGER trigger-name
- Identifies the trigger that is to be dropped. The trigger-name must identify a trigger that exists at the current server.
The specified trigger is dropped from the schema. If the trigger is an SQL
trigger, the program object associated with the trigger is also deleted from
the schema.
If trigger-name specifies
an INSTEAD OF trigger on a view, another trigger may depend on that trigger
through an update against the view.
- VIEW view-name
- Identifies the view that is to be dropped. The view-name must identify a view that exists at the current server, but must not
identify a catalog view.
The specified view is dropped from
the schema. When a view is dropped, all privileges and triggers on that view
are dropped.
- Neither CASCADE nor RESTRICT
- Specifies that the view will be dropped even if it is referenced in
a trigger, materialized query table, or another view. All views and materialized
query tables that reference the view are dropped.
- CASCADE
- Specifies that the view will be dropped even if it is referenced in
a trigger, materialized query table, or another view. All triggers, materialized
query tables, and views that reference the view are dropped.
- RESTRICT
- Specifies that the view cannot be dropped if it is referenced in a trigger,
materialized query table, or another view.
Drop effects: Whenever an object is dropped, its
description is dropped from the catalog. If the object is referenced in a
function, package, procedure, program, or trigger; any access plans that reference
the object are implicitly prepared again when the access plan is next used.
If the object does not exist at that time, an error is returned.
Syntax alternatives: The following keywords are synonyms
supported for compatibility to prior releases. These keywords are non-standard
and should not be used:
- The keyword SYNONYM can be used as a synonym for ALIAS.
- The keyword DATA can be used as a synonym for DISTINCT.
- The keyword PROGRAM can be used as a synonym for PACKAGE.
- The keyword COLLECTION can be used as a synonym for SCHEMA.
Example 1: Drop your table named MY_IN_TRAY.
Do not allow the drop if any views or indexes are created over this table.
DROP TABLE MY_IN_TRAY RESTRICT
Example 2: Drop your view named MA_PROJ.
DROP VIEW MA_PROJ
Example 3: Drop the package named PERS.PACKA.
DROP PACKAGE PERS.PACKA
Example 4: Drop the distinct type DOCUMENT, if
it is not currently in use:
DROP DISTINCT TYPE DOCUMENT RESTRICT
Example 5: Assume that you are SMITH and that ATOMIC_WEIGHT
is the only function with that name in schema CHEM. Drop ATOMIC_WEIGHT.
DROP FUNCTION CHEM.ATOMIC_WEIGHT RESTRICT
Example 6: Drop CENTER, using the function signature
to identify the function instance to be dropped.
DROP FUNCTION CENTER (INTEGER, FLOAT) RESTRICT
Example 7: Assume that you are SMITH and that you
created another function named CENTER, which you gave the specific name FOCUS97,
in schema JOHNSON. Drop CENTER, using the specific name to identify the function
instance to be dropped.
DROP SPECIFIC FUNCTION JOHNSON.FOCUS97
Example 8: Assume that you are SMITH and that stored
procedure OSMOSIS is in schema BIOLOGY. Drop OSMOSIS.
DROP PROCEDURE BIOLOGY.OSMOSIS
Example 9: Assume that you are SMITH and that trigger
BONUS is in your schema. Drop BONUS.
DROP TRIGGER BONUS
[ Top of Page | Previous Page | Next Page | Contents |
Index ]