loading..
Русский    English
09:04

Exercise #57 page 1

For every class that has not less than 3 ships in the database determine the number of ships of this class sunk in the battles, if any. Output: class and the number of the sunken ships.

This exercise is somewhat similar to the exercise 56, i.e. here it is possible to suppose the same mistakes in calculation of the number of sunken ships. However the situation is also aggravated with definition of the total number of the ships in a class. Let's consider the solution that the check system doesn't accept. 

Exercise 3.13.1

Console
Execute
  1. SELECT c.class, SUM(outc)
  2. FROM Classes c LEFT JOIN
  3. Ships s ON c.class = s.class LEFT JOIN
  4. (SELECT ship, 1 outc
  5. FROM Outcomes
  6. WHERE result = 'sunk') o ON s.name = o.ship OR
  7. c.class = o.ship
  8. GROUP BY c.class
  9. HAVING COUNT(*) > 2 AND
  10. SUM(outc) IS NOT NULL;

The first left join gives all classes repeating so many times as the number of ships available in the Ships table. If any class doesn't have ships in this table, it will be noted one time, and it gives us an opportunity to consider the leading ships of the class in the Outcomes table, if any. 

Next, one left join is being worked out with the set of sunken ships on the predicate

  1. ON s.name = o.ship OR c.class = o.ship

In the calculating column 1 is being inserted, if the name of the sunken ship coincides either with the name of the ship, or with the name of the class from the set had been got earlier. So, here we do try to consider the leading (head) ships.

Finally, the grouping by the classes with selection by the number of ships (rows) in the class is being worked out, and the sum of the sunken ships (units in the column “outs”) is being calculated. Author of this solution offers the rational way to calculate in one grouping both the total number of ships, and the quantity of the sunken ships in the class. The predicate, 

  1. SUM(outc) IS NOT NULL
in accordance with the terms of the task, removes from the result such classes that don't have any sunken ships. 

Those who read the analysis of the previous tasks, have already guessed, what the problem is. That's right, the problem is in the predicate of the second join. But not only in this.
в этом.

Let's consider the next variant of data. Let for some class class_N in the Ships table we have two ships: ship_1 and ship_2. Besides, in the Outcomes table there is the sunken ship ship_1 and survived the leading ship – class_N.

The first join gives: 

Class Ship
Class_N ship_1
Class_N ship_2

We work out the second join: 

Class ship outs
Class_N ship_1 1
Class_N ship_2 NULL

In the result this class will not get into the resulting set at all, because the condition COUNT(*) > 2 won't be held, but actually there are three ships. The reason of the mistake lies in the fact that we perform the join only on the sunken ships, simultaneously counting the total number of ships.

Now let's change a little data in the example. And let the leading ship class_N to be also sunk. Then the result of the join is: 

class ship outs
class_N ship_1 1
class_N ship_2 NULL
class_N ship_1 1
class_N ship_2 1

The last two rows will be got in the result of joining the row of the sunken leading ship, as the predicate c.class=o.ship gives “true”. So, instead of one row for the leading ship we get a row for every ship of the class from the Ships table. Totally, instead of 

class outs
class_N 2
we have

class outs
class_N 3

You may try to correct this solution or to use another way on the basis of the inner join and union.

As it will seem surprising, but three absolutely different solutions presented below contain the same mistake, at least, they return the same result on the checking database of a site.

Bookmark and Share
Pages 1 2
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
month ago
©SQL-EX,2008 [Evolution] [Feedback] [About] [Links] [Team]
All right reserved.