I typically use JDev or SQLDev to see details on a table, more than just a DESCRIBE from SQL*Plus can give me anyway.
This "problem" relates to how NULL columns are displayed, both via DESCRIBE and the previously mentioned tools.
First up, my favorite, the table definition with inline constraints.
CREATE TABLE t_not_nullLet's see how it looks in a SQL Worksheet (Columns):
(
col1 VARCHAR2(30)
CONSTRAINT nn_col1_tnn NOT NULL
);
CJUSTICE@TESTING>desc t_not_nullNow I'll create a different table, this time instead of using NOT NULL, I'll use the CHECK syntax.
Name Null? Type
----------------------- -------- ----------------
COL1 NOT NULL VARCHAR2(30)
CREATE TABLE t_not_null_checkColumns:
(
col1 VARCHAR2(30)
CONSTRAINT nn_col1_tnnc CHECK ( col1 IS NOT NULL )
);
Constraints:
DESCRIBE
CJUSTICE@TESTING>desc t_not_null_checkInteresting, it doesn't show up in the "Null?" column like it did with the NOT NULL syntax used above.
Name Null? Type
----------------------- -------- ----------------
COL1 VARCHAR2(30)
Now I'll create a table with no inline constraint defined.
CREATE TABLE t_nullI know (famous last words) I can't use the NOT NULL syntax in an out-of-line constraint:
(
col1 VARCHAR2(30)
);
ALTER TABLE t_nullSo I use the CHECK syntax:
ADD CONSTRAINT nn_col1_tn NOT NULL;
ADD CONSTRAINT nn_col1_tn NOT NULL
*
ERROR at line 2:
ORA-00904: : invalid identifier
ALTER TABLE t_nullColumns:
ADD CONSTRAINT nn_col1_tn
CHECK ( col1 IS NOT NULL );
Table altered.
CJUSTICE@TESTING>desc t_nullVery odd.
Name Null? Type
----------------------- -------- ----------------
COL1 VARCHAR2(30)
Let's look at the dictionary:
SELECTInteresting, I wonder if the fact that it's not UPPERcased and in quotes?
table_name,
constraint_name,
constraint_type,
search_condition,
status
FROM user_constraints
ORDER BY table_name;
TABLE_NAME CONSTRAINT_NAME C SEARCH_CONDITION STATUS
-------------------- -------------------- - -------------------- --------
T_NOT_NULL NN_COL1_TNN C "COL1" IS NOT NULL ENABLED
T_NOT_NULL_CHECK NN_COL1_TNNC C col1 IS NOT NULL ENABLED
T_NULL NN_COL1_TN C col1 IS NOT NULL ENABLED
CJUSTICE@TESTING>DROP TABLE t_not_null_check;DESCRIBE
Table dropped.
Elapsed: 00:00:00.04
CJUSTICE@TESTING>CREATE TABLE t_not_null_check
2 (
3 col1 VARCHAR2(30)
4 CONSTRAINT nn_col1_tnnc CHECK ( "COL1" IS NOT NULL )
5 );
Table created.
CJUSTICE@TESTING>DESC T_NOT_NULL_CHECKOK, Null? is still...NULL.
Name Null? Type
----------------------- -------- ----------------
COL1 VARCHAR2(30)
CJUSTICE@TESTING>SELECTWhy is there that extra space in front of "COL1" IS NOT NULL?
2 table_name,
3 constraint_name,
4 constraint_type,
5 search_condition,
6 status
7 FROM user_constraints
8 ORDER BY table_name;
TABLE_NAME CONSTRAINT_NAME C SEARCH_CONDITION STATUS
-------------------- -------------------- - -------------------- --------
T_NOT_NULL NN_COL1_TNN C "COL1" IS NOT NULL ENABLED
T_NOT_NULL_CHECK NN_COL1_TNNC C "COL1" IS NOT NULL ENABLED
T_NULL NN_COL1_TN C col1 IS NOT NULL ENABLED
I ended my investigation there as it seems to be a waste of time. I just found it interesting that there was a difference in how you defined a NOT NULL constraint and whether or not it would show up in the DESCRIBE command. Anyone out there notice this before?
Read Part II here.
Part III (the final solution) is here.
5 comments:
Yikes!!!!
Thanks for giving me another headache to worry about...
@noons
Anything I can do to further torture my DBAs!
After your finding I think Instead of adding check constraint modify option is better approach
ALTER TABLE HR.TEST
MODIFY(A NOT NULL);
This is the exact reason why I started coercing developers at my last job to add named NOT NULL constraints rather than their ALTER add check constraint. I'm a DBA who loves a command line. Describing tables is my life :) I wonder if saying 'NOT NULL' inline sets some flag in some dictionary table (which would show up on a describe) rather than a generic CHECK constraint.
@coskan
You're right...hadn't thought of that one.
desc t_null
Name Null? Type
----------------------- -------- ----------------
COL1 VARCHAR2(30)
CJUSTICE@TESTING>ALTER TABLE T_NULL DROP CONSTRAINT nn_col1_tn;
Table altered.
CJUSTICE@TESTING>ALTER TABLE t_null MODIFY ( col1 CONSTRAINT nn_col1_tn NOT NULL );
Table altered.
CJUSTICE@TESTING>@DESC T_NULL
Name Null? Type
----------------------- -------- ----------------
COL1 NOT NULL VARCHAR2(30)
Thanks.
Post a Comment