TechTip: Prevent Unintentional Deletion of Objects with RESTRICT ON DROP

SQL
Typography
  • Smaller Small Medium Big Bigger
  • Default Helvetica Segoe Georgia Times

Database tables contain your core business data, so it’s very important to protect them from accidental deletion. The RESTRICT ON DROP clause can be used to add an extra layer of protection to prevent this problem.

Generally, authorities are used to prevent the malicious or accidental deletion of database objects; however, if a trusted user has been granted the correct authorities or if a user has *ALLOBJ special authority, they still could accidentally delete important database tables, procedures, and functions. If this happens, you can try to recover your lost object by using a saved version or by replaying journal entries, but this can be very difficult and time-consuming. It is much easier to just prevent that deletion from occurring in the first place by using RESTRICT ON DROP.

The RESTRICT ON DROP attribute provides additional protection for your database objects by preventing, for all users, the drop or deletion of a database object that has the restrict attribute turned on. The RESTRICT ON DROP attribute even prevents users with *ALLOBJ special authority from being able to delete an object.

This support can be used to protect both SQL tables and database physical files from accidental deletion. Additionally, RESTRICT ON DROP support was recently expanded to also protect procedures and functions.

Tables

To create a table that restricts users from dropping it, use the WITH RESTRICT ON DROP clause.

CREATE TABLE MY_LIB.TBL1 (COL1 INT) WITH RESTRICT ON DROP;

The RESTRICT ON DROP attribute can be added to an existing table using the ALTER TABLE SQL statement. The attribute can be added to both SQL tables and DDS-created physical files.

CREATE TABLE MY_LIB.TBL2 (COL1 INT);
ALTER TABLE MY_LIB.TBL2 ADD RESTRICT ON DROP;

Once it is added, any attempt to drop the table will fail with SQL0672.

DROP TABLE MY_LIB.TBL1;
SQL State: 55035
Vendor Code: -672
Message: [SQL0672] DROP not allowed for TBL1 in MY_LIB type *FILE.

Cause: TBL1 in MY_LIB type *FILE has the RESTRICT ON DROP attribute and cannot be dropped.

The table cannot be deleted using CL commands either. A DLTF or DLTOBJ command will fail with a CPF32BF message.

CL: DLTF MY_LIB/TBL1;
CPF210F: Operation not successful for TBL1 in MY_LIB type *FILE.
CPF32BF: Object TBL1 in MY_LIB type *FILE not allowed to be deleted.

Attempting to delete the entire schema (or delete the library) will fail because objects in the library cannot be deleted.

DROP SCHEMA MY_LIB;
Message: [SQL0672] DROP not allowed for TBL1 in MY_LIB type *FILE.
Cause:   TBL1 in MY_LIB type *FILE has the RESTRICT ON DROP attribute and cannot be dropped.

CL: DLTLIB MY_LIB;
CPF32BF: Object TBL1 in MY_LIB type *FILE not allowed to be deleted.
CPF32BF: Object TBL2 in MY_LIB type *FILE not allowed to be deleted.
CPF2161: Cannot delete some objects in library MY_LIB.

If the table does need to be dropped, you can use the ALTER TABLE SQL statement to remove the RESTRICT ON DROP attribute.

ALTER TABLE MY_LIB.TBL1 DROP RESTRICT ON DROP;
ALTER TABLE MY_LIB.TBL2 DROP RESTRICT ON DROP;

Now the objects can be deleted.

DROP TABLE MY_LIB.TBL1
Statement ran successfully

CL: DLTF MY_LIB/TBL2;
CPC2191: Object TBL2 in MY_LIB type *FILE deleted.

Statement ran successfully

Procedures and Functions

The RESTRICT ON DROP attribute can also be added to procedures and functions. To create a procedure with the restrict attribute, specify the WITH RESTRICT ON DROP option on the CREATE PROCEDURE statement.

-- Create a simple procedure
CREATE PROCEDURE MY_LIB.GET_INCREASE(IN VALUE_TO_INCREASE DECIMAL(7,2),
                                     OUT NEW_VALUE DECIMAL(7,2))
  LANGUAGE SQL

    WITH RESTRICT ON DROP
BEGIN
  CASE
    WHEN VALUE_TO_INCREASE < 10000 THEN 
      SET NEW_VALUE = VALUE_TO_INCREASE * 1.2;
    ELSE SET NEW_VALUE = VALUE_TO_INCREASE * 1.1;
  END CASE;
END;

If the procedure already exists and you wish to add the attribute to a procedure, use the ALTER PROCEDURE SQL operation.

-- Alter the procedure to add restrict on drop
ALTER PROCEDURE MY_LIB.GET_INCREASE ALTER WITH RESTRICT ON DROP;

Now any attempt to drop the procedure will fail with a SQL0672 message.

DROP PROCEDURE MY_LIB.GET_INCREASE;
SQL State: 55035
Vendor Code: -672
Message: [SQL0672] DROP not allowed for GET_INCREASE in MY_LIB type *PGM.

Cause:   GET_INCREASE in MY_LIB type *PGM has the RESTRICT ON DROP attribute and cannot be dropped.

Additionally, CL commands that attempt to delete the procedure will also fail. For example, a DLTLIB will fail with a CPF32BF.

CL: DLTLIB MY_LIB;
CPF32BF: Object GET_I00001 in MY_LIB type *PGM not allowed to be deleted.
CPF210F: Operation not successful for GET_I00001 in MY_LIB type *PGM.
CPF2161: Cannot delete some objects in library MY_LIB.

To drop the restrict on drop attribute, use the ALTER PROCEDURE SQL operation again, but this time use the WITHOUT RESTRICT ON DROP option.

ALTER PROCEDURE MY_LIB.GET_INCREASE ALTER WITHOUT RESTRICT ON DROP;

Now, the procedure can be successfully deleted.

DROP PROCEDURE MY_LIB.GET_INCREASE
Statement ran successfully

Functions behave similarly to procedures. To create an SQL function, external scalar function, or external table function with the restrict attribute, specify the WITH RESTRICT ON DROP option on the CREATE FUNCTION statement. To add the restrict attribute to an already existing function, use the ALTER FUNCTION statement, specifying the ALTER WITH RESTRICT ON DROP option. To drop the restrict attribute, use the ALTER FUNCTION statement, specifying the ALTER WITHOUT RESTRICT ON DROP option.

Conclusion

The RESTRICT ON DROP statement provides an added layer of security to prevent accidental deletion of tables, functions, and procedures. This support was made available in IBM i 7.5 Level 1 for tables and IBM i 7.5 Level 4 for procedures and functions. For more information, please see https://www.ibm.com/support/pages/restrict-drop.

 

 

 

 

 

Sarah Mackenzie is a Db2 for i Senior Software Engineer. She has worked on the IBM i development team since she joined IBM in 2012. During that time, she has focused on both database and query and has worked on the design, development, and support of new enhancements for IBM i such as Temporal Tables, Db2 Mirror, and Geospatial Analytics with Watson. Sarah is also a speaker at many industry events.

BLOG COMMENTS POWERED BY DISQUS

LATEST COMMENTS

Support MC Press Online

$

Book Reviews

Resource Center

  •  

  • LANSA Business users want new applications now. Market and regulatory pressures require faster application updates and delivery into production. Your IBM i developers may be approaching retirement, and you see no sure way to fill their positions with experienced developers. In addition, you may be caught between maintaining your existing applications and the uncertainty of moving to something new.

  • The MC Resource Centers bring you the widest selection of white papers, trial software, and on-demand webcasts for you to choose from. >> Review the list of White Papers, Trial Software or On-Demand Webcast at the MC Press Resource Center. >> Add the items to yru Cart and complet he checkout process and submit

  • SB Profound WC 5536Join us for this hour-long webcast that will explore:

  • Fortra IT managers hoping to find new IBM i talent are discovering that the pool of experienced RPG programmers and operators or administrators with intimate knowledge of the operating system and the applications that run on it is small. This begs the question: How will you manage the platform that supports such a big part of your business? This guide offers strategies and software suggestions to help you plan IT staffing and resources and smooth the transition after your AS/400 talent retires. Read on to learn: