As my title, I have the following code:
SELECT * FROM de.Department WHERE de.flag = 1 AND de.DepartmentNum IN (10,4) AND de.status IN (0,-1,100) AND datediff('dd',de.datequit,'30-SEP-19') > 9
The datediff function make my query run very slow(16s for 11 records), and cost also very high(~43k).
Here is my datediff function code
create or replace FUNCTION DATEDIFF ( P_TYPE_DATE IN VARCHAR2 , P_START_DATE IN TIMESTAMP , P_END_DATE IN TIMESTAMP ) RETURN NUMBER AS v_Result NUMBER := -1; BEGIN IF P_TYPE_DATE IS NOT NULL AND P_START_DATE IS NOT NULL AND P_END_DATE IS NOT NULL THEN CASE UPPER(P_TYPE_DATE) WHEN 'DD' THEN RETURN ROUND(TRUNC(P_END_DATE,'DD') - TRUNC(P_START_DATE,'DD'),0); WHEN 'HH' THEN RETURN ROUND((TRUNC(P_END_DATE,'HH') - TRUNC(P_START_DATE,'HH')) * 24,0); WHEN 'MI' THEN RETURN ROUND((TRUNC(P_END_DATE,'MI') - TRUNC(P_START_DATE,'MI')) * 24 * 60,0); WHEN 'SS' THEN RETURN ROUND((TRUNC(P_END_DATE,'MI') - TRUNC(P_START_DATE,'MI')) * 24 * 60 * 60 + extract(second from (P_END_DATE - P_START_DATE)),0); ELSE RETURN NULL; END CASE; END IF; RETURN NULL; EXCEPTION WHEN OTHERS THEN raise_application_error(-20001,'An error was encountered - '||SQLCODE||' -ERROR- '||SQLERRM); END DATEDIFF;
I used SELECT * because I want to get almost column in Department table, so it no more change if I SELECT some columns which I need.
Can I re-write to improve performance and cost?
Mayny thanks!
Advertisement
Answer
I created a function named datediff as a datediff function in SQL, sir
Don’t use custom functions as they prevent Oracle from using an index on the column; instead just compare the column to the static values:
SELECT * FROM Department WHERE flag = 1 AND DepartmentNum IN (10,4) AND status IN (0,-1,100) AND datequit > DATE '2019-09-30' + INTERVAL '9' DAY
or
AND datequit > DATE '2019-09-30' + NUMTODSINTERVAL( 9, 'DAY' )
or
AND datequit > DATE '2019-09-30' + 9
Here is my datediff function code
... WHEN 'DD' THEN RETURN ROUND(TRUNC(P_END_DATE,'DD') - TRUNC(P_START_DATE,'DD'),0); ...
If you want to do an equivalent comparison to using TRUNC
to ignore the time components then change from using greater-than comparison to using greater-than-or-equal-to and add one time unit (day in your example) to the expected difference. For example:
SELECT * FROM Department WHERE flag = 1 AND DepartmentNum IN (10,4) AND status IN (0,-1,100) AND datequit >= DATE '2019-09-30' + INTERVAL '10' DAY