10 Oracle SQL features you probably didn’t know
I can not guarantee that you never heared of this. But the majority of developers doesn’t know or doesn’t seem to know. And honestly – most of this information is fairly useless – and mostly harmless.
10. Why we have the CONCAT function
There is a concat function that can be used instead of the concat operator ||.
Nobody uses that! But there is a reason why it exists.
This is from the 8.1.7 Oracle documention
On most platforms, the concatenation operator is two solid vertical bars, as shown in Table 3-3. However, some IBM platforms use broken vertical bars for this operator. When moving SQL script files between systems having different character sets, such as between ASCII and EBCDIC, vertical bars might not be translated into the vertical bar required by the target Oracle environment. Oracle provides the
CONCAT
character function as an alternative to the vertical bar operator for cases when it is difficult or impossible to control translation performed by operating system or network utilities. Use this function in applications that will be moved between environments with differing character sets.
So we do have this function, because in the past this || was not consistent over all the different platforms using different character sets. Since nobody seems to use IBM EBCDIC anymore, there is no real need to use the CONCAT function.
9. select UNIQUE
Instead of doing a SELECT DISTINCT you can do SELECT UNIQUE.
But you shouldn’t. None of them. Forget I mentioned this.
Ok here is an example.
Example
select unique e.deptno from scott.emp e;
DEPTNO
-----
30
20
10
It is also possible to do SELECT COUNT(UNIQUE …) . Not sure when that one was introduced, but it seems to work now.
Sven says: “SELECT DISTINCT|UNIQUE should be considered a bug in real production code.”
I have yet to find an example where SELECT DISTINCT is needed. More likely there is a bug in the data model or missing joins in the where clause. GROUP BY or sometimes EXISTS are the better long term alternatives.
Using SELECT DISTINCT is absolutly fine for developer ad-hoc queries.
I feel this whole concept is a bit inconsistent. 12c introduced the new approximation function APPROX_COUNT_DISTINCT, but there is no APPROX_COUNT_UNIQUE!
8. there is an ANSI datatype DATE
The ANSI datatype DATE does not hold any time information (no hours, minutes, seconds). That is what the ANSI datatype TIME is for. Oracle does not officially know these two datatypes.
However:
Purpose
EXTRACT
extracts and returns the value of a specified datetime field from a datetime or interval expression. Theexpr
can be any expression that evaluates to a datetime or interval data type compatible with the requested field:
- If
YEAR
orMONTH
is requested, thenexpr
must evaluate to an expression of data typeDATE
,TIMESTAMP
,TIMESTAMP
WITH
TIME
ZONE
,TIMESTAMP
WITH
LOCAL
TIME
ZONE
, orINTERVAL
YEAR
TO
MONTH
.- If
DAY
is requested, thenexpr
must evaluate to an expression of data typeDATE
,TIMESTAMP
,TIMESTAMP
WITH
TIME
ZONE
,TIMESTAMP
WITH
LOCAL
TIME
ZONE
, orINTERVAL
DAY
TO
SECOND
.- If
HOUR
,MINUTE
, orSECOND
is requested, thenexpr
must evaluate to an expression of data typeTIMESTAMP
,TIMESTAMP
WITH
TIME
ZONE
,TIMESTAMP
WITH
LOCAL
TIME
ZONE
, orINTERVAL
DAY
TO
SECOND
.DATE
is not valid here, because Oracle Database treats it as ANSIDATE
data type, which has no time fields.- If
TIMEZONE_HOUR
,TIMEZONE_MINUTE
,TIMEZONE_ABBR
,TIMEZONE_REGION
, orTIMEZONE_OFFSET
is requested, thenexpr
must evaluate to an expression of data typeTIMESTAMP
WITH
TIME
ZONE
orTIMESTAMP
WITH
LOCAL
TIME
ZONE
.
So essentially the doc says, that EXTRACT uses an ANSI DATE as an expression input.
Proof
select extract(day from sysdate) from dual; 21 select extract(second from sysdate) from dual; ORA-30076: invalid extract field for extract source select extract(second from systimestamp) from dual; 4.823
The error appears, because sysdate is kind of converted into a ANSI DATE and this does not hold time information.
Problem is: We just can not use this ANSI date type for normal activities.
Alternative for the ANSI date: TRUNC(datetime). In 12c as a virtual column.
Problem solved. ✔
7. group by ()
You can group by an empty parenthesis. Or let’s call it group by the FULL SET. This is in fact useful in some very specific cases.
It gives us the ability to get a NO_DATA_FOUND error if there is no data at all. Oracle guarantees that an aggregation select without a group by will always return a record. GROUP BY () can be added if you want to change this default behaviour on purpose.
Example
Let’s say we want to count how many employees are in one specific department.
select count(e.empno) emp# from scott.dept d left join scott.emp e on e.deptno=d.deptno where d.dname = 'OPERATIONS'; EMP# ---- 0
Since there are no employees in operations, this returns 0. This is correct and the information I want.
More specifically this query returns one row, but the e.empno is null and therefore is not counted. Count(*) would have returned 1!
But if we use a department name that does not even exists, then this will also return 0.
select count(e.empno) emp# from scott.dept d left join scott.emp e on e.deptno=d.deptno where d.dname = 'FANCY_CLOUD_SPACE'; EMP# ---- 0
Not correct! In this case I prefer to get a no data found error.
Grouping on the full set gives us this option.
select count(e.empno) emp# from scott.dept d left join scott.emp e on e.deptno=d.deptno where d.dname = 'FANCY_CLOUD_SPACE' group by (); no rows found.
Btw: the SQL Developer syntax (pre-)parser identifies that () as an syntax error. But it will execute it successfully.
I have to admit, that in this case it would be much better to group by the department. But maybe it would be possible to get the count for multiple departments using an IN list. Then the group on department level would not help much.
Btw: GROUP BY NULL does the same thing, and might be less confusing for some developers. I personally prefere GROUP BY () because the () also is used in GROUPING_SETS.
6. + vs. –
In some edge cases using a different operator (+|-) leads to disturbing results.
Example: Substracting a tiny number from 1 does not equal 1. But adding a tiny number from 1 does equal 1!
This is expected behaviour…
Wat? Why do we get a result?!
The solution is simple. We overstepped the maximum precision of the number datatype when doing the addition. Max precision is 38 digits. The addition would require a precision of 39. Instead the result is rounded (or truncated) to a precision of 38 digits, which happens to equal 1. The substraction result still is in the 38 precision range and therefore exact (very slightly less than 1).
Don’t confuse precision with maximum value! Precision is the number of different digits that we can store. This can then be moved by an exponent to the left or right for very large or very small values.
To put this into perspective
That precision is so extremly high, that we have major troubles visualizing it. So here is a comparsion. The comparison data comes from this hugely interesting site: http://money.visualcapitalist.com/all-of-the-worlds-money-and-markets-in-one-visualization/
The complete monetary assets in the whole word is estimated about 80 trillion $ (broad money=coins, banknotes, savings accounts, time deposits, …). That is a 80,000,000,000,000 or an 8 with 13 zeros at the end or 8e13 in scientific exponential notation.
select 8e13 from dual;
Considering all the national and private debts is even higher. Here we reach about 200 trillion $.
And if we consider derivates (=high risk gambles) then the high estimations go as far as 1.2 quadrillion $. That is a 1 followed by 24 more digits (mostly zeros) or 1.2e24.
Since all this is expressed in dollars, we can increase the number even further by chooseing a different currency. For example the Nepalease Rupee is worth a little less than 0.01 dollar. So all the worlds derivatees could be expressed in Nepalease Rupees using a number as big as 1.2e26.
That means using a number with a precision of 38 we can easily express all the money in the world including derivates up to the very last Nepalease Rupee. And we still have only used 2/3rds of the maximum available precision. Or to say it differently. If we duplicate the planet Earth 1,000,000,000,000 (1 trillion) times – we could still give the exact amount of money on all planets in Napalease Rupees up to the very last Rupee using the number datatype.
That’s quite impressive!
Btw. The biggest number that can be expressed using the NUMBER datatype is 999…(38 9’s) x10125 . Which is way way bigger than anything we discussed so far.
5. instead of IN we can use = ANY
select 'TRUE' from dual where 1 = ANY (1,2,3,4,5)
TRUE
There are several similar unusual “replacement” options.
e.g.
- instead of != we can also use ^=.
- NOT IN is the same as != ALL
- SOME is a synonym for ANY – but only in sql!
- <=LEAST | >=GREATEST can be replaced by <|>= ALL
- >=LEAST | <=GREATEST can be replaced by >|<= SOME
I expect that SOME people do know about these operators, since questions about them are part of the SQL expert exam. So from ALL experts who took the exam at LEAST the few who passed should know SOMEthing about ANY.
The last replacement differs how NULL values are treated. In theory there could be cases where this comes in handy. I so far never had such an encounter.
Example
with testdata as (select 1 a, 2 b, 3 c, 4 d from dual union all select 5 a, 4 b, 3 c, 2 d from dual union all select 1 a, null b, 2 c, null d from dual union all select null a, null b, null c, null d from dual) select * from testdata where 3 >= LEAST(a,b,c,d);
A B C D ------- 1 2 3 4 5 4 3 2
with testdata as (select 1 a, 2 b, 3 c, 4 d from dual union all select 5 a, 4 b, 3 c, 2 d from dual union all select 1 a, null b, 2 c, null d from dual union all select null a, null b, null c, null d from dual) select * from testdata where 3 >= ANY(a,b,c,d);
A B C D ------- 1 2 3 4 5 4 3 2 1 - 2 -
4. external table on multiple files
External tables can load multiple files at once! As long as they have the same structure of cause. So here is an example.
CREATE TABLE EXT_DUMMY
(
"RECORDTYPE" VARCHAR2(100 BYTE),
"COL1" VARCHAR2(100 BYTE),
"COL2" VARCHAR2(100 BYTE)
)
ORGANIZATION EXTERNAL
(
TYPE ORACLE_LOADER DEFAULT DIRECTORY "IMPORT_BAD_FILE"
ACCESS PARAMETERS (
records delimited BY newline
FIELDS TERMINATED BY ';'
MISSING FIELD VALUES ARE NULL
( RECORDTYPE CHAR
, COL1 CHAR
, COL2 CHAR
)
)
LOCATION ( 'Testfile1.txt, Testfile2.txt' )
)
reject limit 10
;
When we then do a select on the external table, we will see the data from both files.
We can also switch the external table to a different file.
alter table EXT_DUMMY location ('Testfile3.txt' )
For the experts: We can use the ROWID to find out which file was used to load a specific record. Special thanks go to OTN-forum member Odie_63 who found this solution. More info in this old OTN forum thread.
with ext_loc as (
select position-1 as pos
, name as filename
from sys.external_location$
where obj# = ( select object_id
from user_objects
where object_name = 'EXT_DUMMY' )
)
select x.filename,
t.*
from EXT_DUMMY t
join ext_loc x
on x.pos = to_number(regexp_substr(dump(t.rowid,10,9,1),'\d+$'))
;
It’s a very clever piece of software. Essentially it extracts the filenumber from the rowid, looks up the file number in the data dictionary and combines that with our data set.
This select was done in a 10g database. In 12c we can probably use dbms_rowid to do the same, instead of regexp_substr(dump(rowid)).
3. insert default values
We can insert into a table using the “default” keyword to force default behaviour for this column.
Example
-- setup create table swe_default_test (col1 varchar2(10) not null, col2 varchar2(10) default 'TEST' not null ); Table SWE_DEFAULT_TEST created. -- test insert into swe_default_test (col1) values ('X'); 1 row inserted. insert into swe_default_test (col1,col2) values ('X',null); ORA-01400: cannot insert NULL into ("MYUSER"."SWE_DEFAULT_TEST"."COL2") insert into swe_default_test (col1,col2) values ('X',default); 1 row inserted. -- double check select * from swe_default_test; COL1 COL2 ---------- ---------- X TEST X TEST -- cleanup drop table swe_default_test; Table SWE_DEFAULT_TEST dropped.
In 12c we now have a new and I think better option to do the same. The default column can be defined additionally with “ON NULL”. Which has the effect, that inserting a NULL value, will lead to using the default value instead. Of cause the “default” keyword still works too.
-- setup create table swe_default_test12c (col1 varchar2(10) not null, col2 varchar2(10) default on null 'TEST' not null ); Table SWE_DEFAULT_TEST12C created. -- test insert into swe_default_test12c (col1,col2) values ('X',null); 1 row inserted. insert into swe_default_test12c (col1,col2) values ('X',default); 1 row inserted. -- doublecheck select * from swe_default_test12c; COL1 COL2 ---------- ---------- X TEST X TEST -- cleanup drop table swe_default_test12c; Table SWE_DEFAULT_TEST12C dropped.
As we can see both cases now work. The one using a NULL value and also useing the DEFAULT keyword.
This new 12c “default on null” feature can be used to replace the typical BEFORE ROW INSERT trigger. More info how to do this in Sequence and Audit columns with Apex 5 and 12c
2. (1,2) = ((1,2))
We can compare expression lists using the = operator. But the right side of the comparison needs an extra set of parenthesis.
select 'TRUE' checked from dual where (1,2,3,4,5) = ((1,2,3,4,5));
CHECKED ------- TRUE
This is just a shorthand form of
1=1 and 2=2 and 3=3 and 4=4 and 5=5
If we do not use the second set of parenthesis on the right hand side of the comparison, then we get an error.
select 'TRUE' checked from dual where (1,2,3,4,5) = (1,2,3,4,5) ;
ORA-00920: invalid relational operator
This is documented. Although a tiny bit difficult to read in the syntax diagrams.
See: SQL Reference – Simple Comparison
1. DUAL is a real table
Although there are some special optimizations in various tools, dual is a real table residing in the sys schema.
select owner, table_name from dba_tables where table_name = 'DUAL';
OWNER TABLE_NAME ---------------- SYS DUAL
In older database versions it was possible to do an insert into the DUAL table.
Warning! This is extremly dangerous. It will probably break ALL applications in your database.
insert into dual values ('Y');
select mysequence.nextval into v_id from dual;
TOO_MANY_ROWS error!
And nobody captures the TOO_MANY_ROWS exception for selects from dual.
Btw: A working safety mechanism is to add rownum = 1 to your query.
select mysequence.nextval into v_id from dual where rownum = 1;
Fortunately manipulating DUAL does not work anymore in recent versions of the database. I think 12c introduced it. Not even DBAs have the privs anymore to do this.
ORA-01031: insufficient privileges
*Cause: An attempt was made to perform a database operation without
the necessary privileges.
0. The Oracle SQL Syntax is documented!
Bam! There you have it! You wouldn’t have thought that. Well, you are not alone. So many developers seem to have no clue that this exists or where it exists.
When googeling use “oracle 12c doc” or “oracle 12.2 SQL ref” in front of your search term. It helps to find the proper pages.
Special thanks go out to Stefanie R., who gave me the idea for this blog post!
why does
raises ORA-00937 ?
we would have to use
instead
Hi Matthias,
that is a very interesting example. I believe this could be a bug. Since the subquery is independend from the group it is allowed in general.
The group by () just proves that is how it should be able to work.
In case of the missing group clause it seems as if the checking mechanism for the select part works somehow differently (wrongly?).
Especially because of the subquery.
And eventually leads to the error “ORA-00937: not a single-group group function”.
If we check the docs then there seems to be something missing:
https://docs.oracle.com/database/121/SQLRF/functions003.htm#SQLRF20035
The doc does not specify how expressions (=subqueries) are handled if the GROUP BY clause is omited.
Regards
Sven
That’s because by doing (select 5 from dual) , there is an aggregation expected as it thinks you’re introducing a new data set. In which set some sort of aggregation is needed. If you did
with n as (select level as n from dual connect by level <= 10)
select max(n) * 5 from n, it would be seen differently
Thank you for this interesting summary. I like 2 and may start using this to short the ON in joins.
In 5, you list alternative syntax that you say is from the SQL expert exam. I would want to know the advantages (and disadvantages) of using alternative syntax before encouraging its use. An expert IMHO is someone that uses the most commonly known syntax that does the job equally as well. I’ve run into folks that use REGEXP_REPLACE when a plain REPLACE would do just because they like regular expressions, wasting not only developer time, but machine time as well.
Hi pnosko,
in 5 i mention the operators ANY|SOME|ALL . Those are part of the SQL Syntax. They are also part of the SQL Expert Exam.
However I would not recommend to use them. There is usually no need to do so. It will just confuse other developers.
This is different with regular expressions. REGEX are now part of every programming language (SQL included). Every developer should be quite comfortable with them. Very often you can express a complex string analysis with a simple regexp. Do it! Even if you are not yet familiar with regexp, then try it.
But I totally agree with you. If a simple replace is all that is needed then use that and not the regex.
In general: There are several language parts in SQL that I feel every developer should know. Regular expressions, analytic functions, nls-dependent conversions, json functions would be on the top of my list. ANY|SOME operators not.
Regards
Sven
Thanks, Sven. I think we’re pretty much in agreement. I’ve been writing code since the late 70s and my goal now is to remember where syntax is documented rather than memorizing syntax of infrequently used functions. I have used REGEXP_REPLACE in Oracle, but it’s a lookup for me and some amount of trial and error. One should stick with REPLACE when it does the job because it’s a lot more efficient.
Reblogged this on simple. and commented:
svenweller!
[…] my previous blog posts about 10 Oracle SQL features you might not know and “10 Oracle plsql things you probably didn’t know” raised quite some interest, I […]
Keep working ,remarkable job!