How to Simulate SIGN Function

Puzzle of the day:

How to simulate the SIGN function in Oracle SQL by only using CEIL, FLOOR, and ABS Oracle SQL functions along with arithmetic operators? No PL/SQL.

Solution:

SIGN(x)=CEIL(x/(1+ABS(x)))+FLOOR(x/(1+ABS(x)))

In SQL, we can demonstrate it as follows:

WITH r AS (
SELECT dbms_random.VALUE(-999,999) rnd
FROM dual
CONNECT BY LEVEL<=10
UNION ALL
SELECT 0
FROM dual
)
SELECT rnd, SIGN(rnd), CEIL(rnd/(1+ABS(rnd)))+FLOOR(rnd/(1+ABS(rnd))) "MySign"
FROM r

Result:

       RND  SIGN(RND)     MySign
---------- ---------- ----------
  -519.606         -1         -1
-657.62692         -1         -1
414.625079          1          1
736.175183          1          1
268.689074          1          1
-647.12649         -1         -1
338.192233          1          1
784.780876          1          1
-529.69184         -1         -1
-596.56803         -1         -1
         0          0          0

As you can see, “MySign” column perfectly matches SIGN column.

Comment:

WITH clause is needed to generate 10 random values in the range of -999 .. +999. “0” value is added to demonstrate a special case as it is unlikely that zero will be randomly generated.

 

My Oracle Group on Facebook:

If you like this post, you may want to join my new Oracle group on Facebook: https://www.facebook.com/groups/sqlpatterns/

Would you like to read about many more tricks and puzzles?

For more tricks and cool techniques check my book “Oracle SQL Tricks and Workarounds” for instructions.

6 Solutions to Puzzle of the Week #19

Puzzle of the Week #19:

Produce the department salary report (shown below) with the following  assumptions/requirements:

  • Use Single SELECT statement only
  • DECODE and CASE functions are not allowed
  • An employee’s salary is shown in the corresponding department column (10, 20 or 30), all other department columns should contain NULLs.
  • The query should work in Oracle 11g.

Expected Result:

ENAME              10         20         30
---------- ---------- ---------- ----------
SMITH                        800
ALLEN                                  1600
WARD                                   1250
JONES                       2975
MARTIN                                 1250
BLAKE                                  2850
CLARK            2450
SCOTT                       3000
KING             5000
TURNER                                 1500
ADAMS                       1100
JAMES                                   950
FORD                        3000
MILLER           1300

Solutions:

#1: Using NULLIF, ABS, and SIGN functions

SELECT ename, NULLIF(sal * (1-ABS(SIGN(deptno-10))),0) "10",
              NULLIF(sal * (1-ABS(SIGN(deptno-20))),0) "20",
              NULLIF(sal * (1-ABS(SIGN(deptno-30))),0) "30"
FROM emp

#2: Using NULLIF and INSTR functions

SELECT ename, NULLIF(sal * INSTR(deptno, 10), 0) "10",
              NULLIF(sal * INSTR(deptno, 20), 0) "20",
              NULLIF(sal * INSTR(deptno, 30), 0) "30"
FROM emp

#3: Using NVL2 and NULLIF functions

SELECT ename, NVL2(NULLIF(deptno, 10), NULL, 1) * sal "10",
              NVL2(NULLIF(deptno, 20), NULL, 1) * sal "20",
              NVL2(NULLIF(deptno, 30), NULL, 1) * sal "30"
FROM emp

#4: Using PIVOT clause

SELECT *
FROM  (SELECT deptno, ename, sal
       FROM emp)
PIVOT (MAX(sal)
       FOR deptno IN (10, 20, 30)
      );

#5: Using Scalar SELECT statements in SELECT clause

SELECT ename,
       (SELECT sal FROM emp WHERE empno=e.empno AND deptno=10) "10",
       (SELECT sal FROM emp WHERE empno=e.empno AND deptno=20) "20",
       (SELECT sal FROM emp WHERE empno=e.empno AND deptno=30) "30"
FROM emp e;

#6: Using UNION (different sort order)

SELECT ename, sal "10", NULL "20", NULL "30"
FROM emp
WHERE deptno=10
UNION
SELECT ename, NULL, sal, NULL
FROM emp
WHERE deptno=20
UNION
SELECT ename, NULL, NULL, sal
FROM emp
WHERE deptno=30;

ENAME              10         20         30
---------- ---------- ---------- ----------
ADAMS                       1100
ALLEN                                  1600
BLAKE                                  2850
CLARK            2450
FORD                        3000
JAMES                                   950
JONES                       2975
KING             5000
MARTIN                                 1250
MILLER           1300
SCOTT                       3000
SMITH                        800
TURNER                                 1500
WARD                                   125

My Oracle Group on Facebook:

If you like this post, you may want to join my new Oracle group on Facebook: https://www.facebook.com/groups/sqlpatterns/

Would you like to read about many more tricks and puzzles?

For more tricks and cool techniques check my book “Oracle SQL Tricks and Workarounds” for instructions.