loading..
Ðóññêèé    English
18:42

Grouping of time intervals

P. Voynov

This work is the conversion of Itsik Ben-Gun article in appliance to the educational database “Aeroflot”.

Only one of the types of solution, which are considered in the said article, will be applied here.

Let's consider the following task:

For every company to determine time intervals, when there is any plane of the company in the air.
  Extra restrictions:
    - A flight is carried on in case at least one ticket would have been sold;
    - It's considered that during the take-off and the landing a plane is in the air.

We'll need the following information for work: a company identifier, date-time of take-off and landing of the plane.

Note: for briefness and convenience of apprehension, I'll create views, which will be used during the solving of the task. We should mention that thereafter it will be easy to “develop” the got solution in one “select”.

So.

vw_trip view

  1. CREATE VIEW dbo.vw_trip
  2. AS
  3. SELECT DISTINCT id_comp,
  4. dt_out = date + time_out,
  5. dt_in = date + time_in + CASE WHEN time_out > time_in THEN 1 ELSE 0 END
  6. FROM trip t JOIN
  7. pass_in_trip pt ON t.trip_no = pt.trip_no

The main difficulty of the solution lies in the fact that we don't know how many flights can organize a continuous time interval, during which there is at least one plane of the company in the air(in prospect an ”interval”).

To find the beginning of the “interval” we will use such a fact: the beginning of the “interval” coincides with the plane's take-off, if at this moment there is no other plane of the company in the air. Or, in other words, the beginning of the “interval” coincides with the plane's take-off, if there is no other flights of the company, which had already started, but have not landed yet.

vw_dt_start view

  1. CREATE VIEW dbo.vw_dt_start
  2. AS
  3. SELECT DISTINCT id_comp, dt_out
  4. FROM vw_trip t
  5. WHERE NOT EXISTS( SELECT 1
  6. FROM vw_trip
  7. WHERE id_comp = t.id_comp AND
  8. dt_out < t.dt_out AND
  9. dt_in > = t.dt_out
  10. )

Explanation:

dt_out < t.dt_out - the strict inequality, not to be checked the considered flight;

dt_in > = t.dt_out - the non-strict inequality; we also check the situation, when one plane takes off, and the other one is landing at this time (“interval” isn't broken);

DISTINCT - we remove the duplicating of the records in case of simultaneous take-off of two or more planes.

The time of the “interval's” ending is found by the analogous way.

vw_dt_end view

  1. CREATE VIEW dbo.vw_dt_end
  2. AS
  3. SELECT DISTINCT id_comp, dt_in
  4. FROM vw_trip t
  5. WHERE NOT EXISTS(SELECT 1
  6. FROM vw_trip
  7. WHERE id_comp = t.id_comp AND
  8. dt_out <= t.dt_in AND
  9. dt_in > t.dt_in
  10.  
  11. )

Now to connect the times of the beginning and the ending of the “intervals” is rest. As intervals don't intersect, we may confirm that the time of the “interval's” ending – is a minimal time of all vw_dt_end.dt_in that exceed the considered time of the “interval's” beginning.

vw_result view

  1. CREATE VIEW dbo.vw_result
  2. AS
  3. SELECT name_comp = (SELECT [name]
  4. FROM company
  5. WHERE id_comp = vw_dt_start.id_comp
  6. )
  7. vw_dt_start.dt_out, dt_in = MIN(vw_dt_end.dt_in)
  8. FROM vw_dt_start JOIN
  9. vw_dt_end ON vw_dt_start.id_comp = vw_dt_end.id_comp AND
  10. vw_dt_start.dt _out < vw_dt_end.dt_in
  11. GROUP BY vw_dt_start.id_comp, vw_dt_start.dt_out

The reader is offered to solve this problem without use of views (i.e. to construct the solution in the form of single SELECT statement).

Tags
aggregate functions Airport ALL AND AS keyword ASCII AVG Battles Bezhaev Bismarck C.J.Date calculated columns Cartesian product CASE cast CHAR CHARINDEX Chebykin check constraint classes COALESCE common table expressions comparison predicates Computer firm CONSTRAINT CONVERT correlated subqueries COUNT CROSS APPLY CTE data type conversion data types database schema DATEADD DATEDIFF DATENAME DATEPART DATETIME date_time functions DDL DEFAULT DEFAULT VALUES DELETE DISTINCT DML duplicates edge equi-join EXCEPT exercise (-2) More tags
The book was updated
several days ago
©SQL-EX,2008 [Evolution] [Feedback] [About] [Links] [Team]
All right reserved.