I have two tables:- emp_info,emp_attendance

Table structure:

Emp_Info
   empid

    Requires Free Membership to View

int, empname varchar(50)

Emp_Attendance
   empid int, emp_day datetime

The emp_attendance has the entries of dates for all the employees when they are present like:

Empid    emp_day
101        1-1-2012
101        1-2-2012
101        1-4-2012 //Note: third date is missing as the employee is absent
101        1-5-2012  
102        1-1-2012
102        1-3-2012 //Note: Here employee 102 is absent on date 2

I want all the list of employees with their absent dates.

The thing you're missing is a DATE table to generate all dates in a given range.

Some folks build an actual table and populate it with every calendar date from, say, the beginning of their business (or business industry) to some fixed future date (when I suppose they believe they'll be out of business or they expect to completely rewrite their application anyway).

However, it's simpler and makes more sense to create a virtual table. Pipelined functions are perfect for this kind of problem.

Any function has to return an actual SQL datatype; Oracle allows us to define suitable schema-level objects to fulfill this requirement for more complex situations.

We need a collection type for a pipelined function to return. This can be simply a collection of DATE:

CREATE OR REPLACE TYPE nt_date IS TABLE OF DATE;
/

My function will return this collection type.

CREATE OR REPLACE FUNCTION generate_dates(
 p_from IN DATE
,p_to IN DATE)
RETURN nt_date PIPELINED
IS
 -- normalize inputs to be as-of midnight
 v_from DATE := TRUNC(NVL(p_from, SYSDATE));
 v_to DATE := TRUNC(NVL(p_to, SYSDATE));
BEGIN
 LOOP
   EXIT WHEN v_from > v_to;
   PIPE ROW (v_from);
   v_from := v_from + 1; -- next calendar day
 END LOOP;
 RETURN;
END generate_dates;
/

Let’s test this first:

-- so we can see the time too
ALTER SESSION SET NLS_DATE_FORMAT='DD-MON-YYYY HH24:MI:SS';

SELECT *
FROM TABLE(generate_dates(SYSDATE, SYSDATE));

COLUMN_VALUE
--------------------
08-JAN-2012 00:00:00

Notice the system-generated name of the column is COLUMN_VALUE. If you prefer being able to provide your own name, then create an object type first, and base your collection on that instead.

CREATE OR REPLACE TYPE obj_date IS OBJECT (
 date_val DATE
);
/

CREATE OR REPLACE TYPE nt_date IS TABLE OF obj_date;
/

CREATE OR REPLACE FUNCTION generate_dates(
 p_from IN DATE
,p_to IN DATE)
RETURN nt_date PIPELINED
IS
 -- normalize inputs to be as-of midnight
 v_from DATE := TRUNC(NVL(p_from, SYSDATE));
 v_to DATE := TRUNC(NVL(p_to, SYSDATE));
BEGIN
 LOOP
   EXIT WHEN v_from > v_to;
   PIPE ROW (obj_date(v_from));
   v_from := v_from + 1; -- next calendar day
 END LOOP;
 RETURN;
END generate_dates;
/

Note the PIPE ROW command now needs to return the object type, not a scalar type.

SELECT *
FROM TABLE(generate_dates(SYSDATE, SYSDATE));

DATE_VAL
--------------------
08-JAN-2012 00:00:00

A few more test cases are in order…

SELECT *
FROM TABLE(generate_dates(SYSDATE, SYSDATE-1));

no rows selected

SELECT *
FROM TABLE(generate_dates(SYSDATE, SYSDATE+3));

DATE_VAL
--------------------
08-JAN-2012 00:00:00
09-JAN-2012 00:00:00
10-JAN-2012 00:00:00
11-JAN-2012 00:00:00

SELECT *
FROM TABLE(generate_dates(SYSDATE, NULL));

DATE_VAL
--------------------
08-JAN-2012 00:00:00

Without the NVL, the function would never break out of the loop.

Now we can get back to your actual problem. You want to find those dates for which no record is found in your attendance table. Let’s build the tables and populate them…

CREATE TABLE emp_info(
 empid INTEGER
,empname VARCHAR2(50)
);

CREATE TABLE emp_attendance(
 empid INTEGER
,emp_day DATE
);

INSERT INTO emp_info (empid, empname) VALUES (101, 'Dan Clamage');
INSERT INTO emp_info (empid, empname) VALUES (102, 'Ronak Khandelwal');

INSERT INTO emp_attendance (empid, emp_day) VALUES (101, DATE '2012-01-01');
INSERT INTO emp_attendance (empid, emp_day) VALUES (101, DATE '2012-01-02');
INSERT INTO emp_attendance (empid, emp_day) VALUES (101, DATE '2012-01-04');
INSERT INTO emp_attendance (empid, emp_day) VALUES (101, DATE '2012-01-05');

INSERT INTO emp_attendance (empid, emp_day) VALUES (102, DATE '2012-01-01');
INSERT INTO emp_attendance (empid, emp_day) VALUES (102, DATE '2012-01-03');

COMMIT;

For date literal values, I prefer using the ANSI standard format.

What you’re looking for is the set of all potential attendance dates for each employee, minus the set of actual attendance dates. SQL works with sets of data, so it’s straightforward to describe each set.

Let’s see the first set…

-- potential attendance dates for each employee in a given range
SELECT ei.empid, gd.date_val
FROM emp_info ei
CROSS JOIN
TABLE(generate_dates(DATE '2012-01-01', DATE '2012-01-05')) gd
ORDER BY ei.empid, gd.date_val;

    EMPID DATE_VAL
---------- --------------------
      101 01-JAN-2012 00:00:00
      101 02-JAN-2012 00:00:00
      101 03-JAN-2012 00:00:00
      101 04-JAN-2012 00:00:00
      101 05-JAN-2012 00:00:00
      102 01-JAN-2012 00:00:00
      102 02-JAN-2012 00:00:00
      102 03-JAN-2012 00:00:00
      102 04-JAN-2012 00:00:00
      102 05-JAN-2012 00:00:00

10 rows selected.

Note the cross join computes the Cartesian Product of the two sets. This potentially will return a huge number of rows. You wouldn’t want to run this for thousands of employees for several years.

Now for their actual attendance…

-- actual attendance dates for each employee in a given range
SELECT ei.empid, ea.emp_day
FROM emp_info ei
INNER JOIN emp_attendance ea
ON ea.empid = ei.empid
WHERE ea.emp_day BETWEEN DATE '2012-01-01' AND DATE '2012-01-05'
ORDER BY ei.empid, ea.emp_day;

    EMPID EMP_DAY
---------- --------------------
      101 01-JAN-2012 00:00:00
      101 02-JAN-2012 00:00:00
      101 04-JAN-2012 00:00:00
      101 05-JAN-2012 00:00:00
      102 01-JAN-2012 00:00:00
      102 03-JAN-2012 00:00:00

6 rows selected.

Let’s subtract the latter set from the former set…

SELECT ei.empid, gd.date_val
FROM emp_info ei
CROSS JOIN
TABLE(generate_dates(DATE '2012-01-01', DATE '2012-01-05')) gd
MINUS
SELECT ei.empid, ea.emp_day
FROM emp_info ei
INNER JOIN emp_attendance ea
ON ea.empid = ei.empid
WHERE ea.emp_day BETWEEN DATE '2012-01-01' AND DATE '2012-01-05'
ORDER BY 1, 2;

    EMPID DATE_VAL
---------- --------------------
      101 03-JAN-2012 00:00:00
      102 02-JAN-2012 00:00:00
      102 04-JAN-2012 00:00:00
      102 05-JAN-2012 00:00:00

Note empid 101 is absent on the day you mentioned, and that empid 102 is absent on not just date 2 as you indicated, but also the 4th and 5th. It’s important to make sure we’re comparing the same timeframe in both sets.

If you want their actual names, you can put all this in an inline view and join it back to the emp_info table.

SELECT i.empid, i.empname, a.absent
FROM emp_info i
INNER JOIN
 (SELECT ei.empid, gd.date_val absent
  FROM emp_info ei
  CROSS JOIN
  TABLE(generate_dates(DATE '2012-01-01', DATE '2012-01-05')) gd
  MINUS
  SELECT ei.empid, ea.emp_day
  FROM emp_info ei
  INNER JOIN emp_attendance ea
  ON ea.empid = ei.empid
  WHERE ea.emp_day BETWEEN DATE '2012-01-01' AND DATE '2012-01-05') a
ON a.empid = i.empid
ORDER BY i.empid, a.absent;

    EMPID EMPNAME                                            ABSENT
---------- -------------------------------------------------- --------------------
      101 Dan Clamage                                        03-JAN-2012 00:00:00
      102 Ronak Khandelwal                                   02-JAN-2012 00:00:00
      102 Ronak Khandelwal                                   04-JAN-2012 00:00:00
      102 Ronak Khandelwal                                   05-JAN-2012 00:00:00

This was first published in January 2012

There are Comments. Add yours.

 
TIP: Want to include a code block in your comment? Use <pre> or <code> tags around the desired text. Ex: <code>insert code</code>

REGISTER or login:

Forgot Password?
By submitting you agree to receive email from TechTarget and its partners. If you reside outside of the United States, you consent to having your personal data transferred to and processed in the United States. Privacy
Sort by: OldestNewest

Forgot Password?

No problem! Submit your e-mail address below. We'll send you an email containing your password.

Your password has been sent to: