Export generator 4

Revision as of 15:35, 27 March 2017 by Jcheng (Talk | contribs) (Pilots without flight in the last 3 months)

Jump to: navigation, search

Contents

Introduction

The goal of this page is to propose a list of statistic generation queries (SQL).

Do not forget to read the OpenFlyers SQL stored functions and procedures page.

Please note that you can make "public" a report, ie. allows standard users to see and interact with it.

Extra field

For more flexibility, extra field can be defined per the user

Two extra field types are available:

  • "external parameters" of following types:
    • Whole number
    • Text string
    • Date
    • Time
    • Date and time
  • database parameters (dbObject::something Value type) advanced options to access at the database field

Extra Field creation

  • Go to Menu Admin > Reports > Structure > Extra Field(s)

In the bottom line add

  • Fill the name field with a name that will be use within the SQL queries (prefixed with the $ character)
  • Fill the label field with a name used to describe the parameter as you want it to appear within the export query form.
  • Choose a Value type (the most common are at the beginning of the list).
  • Click on "Add"

Then within your SQL query, you may add this parameter which will be replace by the value chosen by the user filling the export form.

If you define a parameter as a database parameters (for example dbObject::Authentication) then the form will display a combo with the list of users and your parameter will be replace by the id integer of the chosen person.

Extra Field creation examples

We create a new extra field for the current year:

  • Name: $year
  • Label: Year
  • Value type: Year

Parameter Year must be fill in Reports/Structure/View form before to call the query (by default current year is filled when you call the page)

We create a new extra field to list the reservation of an aircraft:

  • Name: $aircraftId
  • Label: Aircraft
  • Value type: dbObject::Aircraft

Then in Admin/Reports/Structure/Criteria we create a new query labeled "Aircraft booking" with the following query:

SELECT * FROM booking WHERE booking.aircraft_id=$aircraftId

To use this report, we just have to select a "Aircraft" in the Reports/Structure/View form, to check "Aircraft booking" then to click on "View"

SQL tips and tricks

Return only last entry

Example with last entry from variable #1 in variable_value table:

SELECT * FROM `variable_value` WHERE variable_id=1 ORDER BY start_date DESC  LIMIT 1

Test valid entries

For extra fields that are text inputs, any entry can be submitted and added to SQL query. In order to test valid entries, it is recommended to use the IF statement in the WHERE statement.

Per example, $occupiedSeat can have following values (0, 1 or NULL) :

SELECT *
FROM flight_pilot
WHERE 
(
    IF((('$occupiedSeat'=0)OR('$occupiedSeat'='')), 0, -1) = flight_pilot.num
    OR IF((('$occupiedSeat'=1)OR('$occupiedSeat'='')), 1, -1) = flight_pilot.num
)

French administration Examples

Flight type : Flight hours total on instruction with specific profile

  • Variable $activityTypeId should be defined first and should be of dbOject::ActivityType value type.
  • Variable $profileId should be defined first and should be of dbOject::Profile value type.
  • Variable $year should be defined first and should be of Year value type.
SELECT name,
       sexa2HoursMinute(SUM(IF(category=1, duration, 0))) AS 'Avion',
       sexa2HoursMinute(SUM(IF(category=18, duration, 0))) AS 'Hélicoptère',
       sexa2HoursMinute(SUM(IF(category=19, duration, 0))) AS 'Planeur',
       sexa2HoursMinute(SUM(IF(category=17, duration, 0))) AS 'ULM'
FROM (
    SELECT
        activity_type.id,
        activity_type.name,
        flight.duration,
        resource_type.category
    FROM flight
    LEFT JOIN activity_type ON (flight.flight_type_id & activity_type.id)
    LEFT JOIN flight_pilot ON (flight_pilot.flight_id=flight.id AND flight_pilot.num=1)
    LEFT JOIN person ON (person.id=flight_pilot.pilot_id)
    LEFT JOIN resource ON (resource.id=flight.aircraft_id)
    LEFT JOIN resource_type ON (resource_type.id=resource.resource_type_id)
    WHERE YEAR(flight.start_date)=$year
      AND (activity_type.id='$activityTypeId' OR '-'='$activityTypeId')
      AND person.activated=1
      AND (person.profile & '$profileId' OR '-'='$profileId')
) AS tmp_flight
GROUP BY id

Flight type : Flight hours total on non-instruction with specific profile

  • Variable $activityTypeId should be defined first and should be of dbOject::ActivityType value type.
  • Variable $profileId should be defined first and should be of dbOject::Profile value type.
  • Variable $year should be defined first and should be of Year value type.
SELECT name,
       sexa2HoursMinute(SUM(IF(category=1, duration, 0))) AS 'Avion',
       sexa2HoursMinute(SUM(IF(category=18, duration, 0))) AS 'Hélicoptère',
       sexa2HoursMinute(SUM(IF(category=19, duration, 0))) AS 'Planeur',
       sexa2HoursMinute(SUM(IF(category=17, duration, 0))) AS 'ULM'
FROM (
    SELECT
        activity_type.id,
        activity_type.name,
        flight.duration,
        resource_type.category
    FROM flight
    LEFT JOIN activity_type ON (flight.flight_type_id & activity_type.id)
    LEFT JOIN flight_pilot ON (flight_pilot.flight_id=flight.id AND flight_pilot.num=0)
    LEFT JOIN person ON (person.id=flight_pilot.pilot_id)
    LEFT JOIN resource ON (resource.id=flight.aircraft_id)
    LEFT JOIN resource_type ON (resource_type.id=resource.resource_type_id)
    WHERE YEAR(flight.start_date)=$year
      AND (activity_type.id='$activityTypeId' OR '-'='$activityTypeId')
      AND flight.id NOT IN (SELECT flight_id FROM flight_pilot WHERE num=1)
      AND person.activated=1
      AND (person.profile & '$profileId' OR '-'='$profileId')
) AS tmp_flight
GROUP BY id

Users with a specific validity without expiration date

  • Variable $validityId should be defined first and should be of dbOject::ValidityType value type.
SELECT person.first_name, person.last_name FROM validity
LEFT JOIN person ON person.id=validity.person_id
WHERE validity_type_id=$validityTypeId AND expire_date IS NULL AND person.activated=1

Number of movements on based airfield

  • Variable $year should be defined first and should be of Year value type.
SELECT SUM(movement) AS 'Movement'
FROM
(
    SELECT COUNT(*) AS movement
    FROM flight
    LEFT JOIN location ON (flight.departure_location_id = location.id)
    WHERE (
            ( flight.departure_location_id != (SELECT ap2.id FROM location ap2, club c WHERE ap2.icao_name = c.icao) )
            OR
            ( flight.arrival_location_id != (SELECT ap2.id FROM location ap2, club c WHERE ap2.icao_name = c.icao) )
        )
        AND ( location.id != (SELECT ap2.id FROM location ap2, club c WHERE ap2.icao_name = c.icao) )
        AND YEAR( start_date ) = $year
    UNION
    SELECT SUM(landing_number)*2 AS movement
    FROM flight
    LEFT JOIN (
        SELECT location.id
        FROM location
        LEFT JOIN club ON location.icao_name=club.icao
        WHERE club.id IS NOT NULL
        LIMIT 1
    ) AS structure_icao ON (flight.departure_location_id=structure_icao.id AND flight.arrival_location_id=structure_icao.id)
    WHERE YEAR(flight.start_date) = $year
      AND structure_icao.id IS NOT NULL
) AS tmp_movement

Number of movements on based airfield on specific profile

  • Variable $profileId should be defined first and should be of dbOject::Profile value type.
  • Variable $year should be defined first and should be of Year value type.
SELECT SUM(movement) AS 'Movement'
FROM
(
    SELECT COUNT(*) AS movement
    FROM flight
    LEFT JOIN location ON (flight.departure_location_id = location.id)
    LEFT JOIN flight_pilot ON (flight_pilot.flight_id=flight.id)
    LEFT JOIN person ON (person.id=flight_pilot.pilot_id AND flight_pilot.num=0)
    WHERE (
            ( flight.departure_location_id != (SELECT ap2.id FROM location ap2, club c WHERE ap2.icao_name = c.icao) )
            OR
            ( flight.arrival_location_id != (SELECT ap2.id FROM location ap2, club c WHERE ap2.icao_name = c.icao) )
        )
        AND ( location.id != (SELECT ap2.id FROM location ap2, club c WHERE ap2.icao_name = c.icao) )
        AND person.activated=1
        AND (person.profile & '$profileId' OR '-'='$profileId')
        AND YEAR(flight.start_date) = $year
    UNION
    SELECT SUM(landing_number)*2 AS movement
    FROM flight
    LEFT JOIN (
        SELECT location.id
        FROM location
        LEFT JOIN club ON location.icao_name=club.icao
        WHERE club.id IS NOT NULL
        LIMIT 1
    ) AS structure_icao ON (flight.departure_location_id=structure_icao.id AND flight.arrival_location_id=structure_icao.id)
    LEFT JOIN flight_pilot ON (flight_pilot.flight_id=flight.id)
    LEFT JOIN person ON (person.id=flight_pilot.pilot_id AND flight_pilot.num=0)
    WHERE person.activated=1
      AND (person.profile & '$profileId' OR '-'='$profileId')
      AND YEAR(flight.start_date) = $year
      AND structure_icao.id IS NOT NULL
) AS tmp_movement

Visited airfields

SELECT location.icao_name AS ICAO, location.name AS Name, COUNT(location.icao_name) AS nb_visite
FROM flight
LEFT JOIN location ON (flight.departure_location_id = location.id)
WHERE (
        ( flight.departure_location_id != (SELECT ap2.id FROM location ap2, club c WHERE ap2.icao_name = c.icao) )
        OR
        ( flight.arrival_location_id != (SELECT ap2.id FROM location ap2, club c WHERE ap2.icao_name = c.icao) )
    )
    AND YEAR( start_date ) = $year
GROUP BY icao_name
ORDER BY nb_visite DESC

Number of take-off and landings on based airfield

SELECT SUM( landing_number )*2 AS nb_mouvement 
FROM flight f, club c 
WHERE ( f.departure_location_id = (SELECT ap2.id FROM location ap2, club c WHERE ap2.icao_name = c.icao))
  AND (f.arrival_location_id  = (SELECT ap2.id FROM location ap2, club c WHERE ap2.icao_name = c.icao)) 
  AND YEAR( start_date ) = $year

Number of take-off and landings on based airfield on specific profile

  • Variable $profileId should be defined first and should be of dbOject::Profile value type.
  • Variable $year should be defined first and should be of Year value type.
SELECT SUM(landing_number)*2 AS 'Movement'
FROM flight
LEFT JOIN (
    SELECT location.id
    FROM location
    LEFT JOIN club ON location.icao_name=club.icao
    WHERE club.id IS NOT NULL
    LIMIT 1
) AS structure_icao ON (flight.departure_location_id=structure_icao.id AND flight.arrival_location_id=structure_icao.id)
LEFT JOIN flight_pilot ON (flight_pilot.flight_id=flight.id)
LEFT JOIN person ON (person.id=flight_pilot.pilot_id AND flight_pilot.num=0)
WHERE person.activated=1
  AND (person.profile & '$profileId' OR '-'='$profileId')
  AND YEAR(flight.start_date) = $year
  AND structure_icao.id IS NOT NULL

List of movements on based airfield

SELECT resource.name, DATE_FORMAT(flight.start_date, '%d %m %Y' ) AS Date, sum(landing_number) AS 'Nb Att'
FROM flight
LEFT JOIN resource ON resource.id = flight.aircraft_id
WHERE ( flight.departure_location_id = (SELECT ap2.id FROM location ap2, club c WHERE ap2.icao_name = c.icao))
  AND (flight.arrival_location_id  = (SELECT ap2.id FROM location ap2, club c WHERE ap2.icao_name = c.icao)) 
  AND YEAR( start_date ) = $year
GROUP BY date,name

Pilots who have flown without required validity

SELECT CONCAT(person.last_name, ' ', person.first_name) AS pilot, validity_type.name AS 'Validity'
FROM flight_type_mandatory_validity_type
LEFT JOIN activity_type ON activity_type.id = flight_type_mandatory_validity_type.flight_type_id
LEFT JOIN flight ON flight.flight_type_id & activity_type.id
LEFT JOIN resource ON resource.id = flight.aircraft_id
LEFT JOIN resource_type ON resource.resource_type_id = resource_type.id
LEFT JOIN aircraft_type_validity_type ON resource_type.id = aircraft_type_validity_type.aircraft_type_id
LEFT JOIN flight_pilot ON flight.id = flight_pilot.flight_id
LEFT JOIN person ON person.id = flight_pilot.pilot_id
LEFT JOIN validity_type ON (validity_type.id = flight_type_mandatory_validity_type.validity_type_id OR validity_type.id = aircraft_type_validity_type.validity_type_id)
LEFT JOIN validity ON (validity_type.id=validity.validity_type_id AND person.id=validity.person_id)
WHERE flight.airborne = 0
  AND validity_type.id IS NOT NULL
  AND validity_type.experience_formula IS NULL
  AND validity.validity_type_id IS NULL
  AND person.activated=1
GROUP BY person.id, validity_type.id
ORDER BY pilot, validity_type.name

List of pilots who have flown less than X hours during last Y days

SELECT CONCAT(au.last_name, ' ', au.first_name) AS pilot, TIME_FORMAT( SEC_TO_TIME( SUM(f.duration)*6 ), '%H:%i' ) AS total_time
FROM flight AS f
RIGHT JOIN flight_pilot AS fp ON fp.flight_id=f.id
LEFT JOIN aircraft AS ai ON ai.id = f.aircraft_id
LEFT JOIN person AS au ON fp.pilot_id = au.id
WHERE f.airborne = 0
  AND start_date BETWEEN NOW() - INTERVAL Y DAY AND NOW()
GROUP BY au.id
HAVING SUM(f.duration)/600 < X
ORDER BY pilot

List of pilots who have flown less than X hours during last Y days on aircraft type Z

 
SELECT CONCAT(au.last_name, ' ', au.first_name) AS pilot, TIME_FORMAT( SEC_TO_TIME( SUM(f.duration)*6 ), '%H:%i' ) AS total_time
FROM flight AS f
RIGHT JOIN flight_pilot AS fp ON fp.flight_id=f.id
LEFT JOIN resource AS ai ON ai.id = f.aircraft_id
LEFT JOIN resource_type AS at ON ai.resource_type_id = at.id
LEFT JOIN person AS au ON fp.pilot_id = au.id
WHERE f.airborne = 0
  AND start_date BETWEEN NOW() - INTERVAL Y DAY AND NOW()
  AND at.id IN ( Z1, Z2, Z3, Z... )
GROUP BY au.id
HAVING SUM(f.duration)/600 <= X
ORDER BY pilot

Pilots without flight in the last 3 months

  • Variable $month should be defined first and should be of integer value type.
SELECT 
    person.last_name, person.first_name,
    IFNULL((SELECT CONCAT(DATE_FORMAT( f1.start_date, '%d/%m/%Y' ),' ', resource.name,' Duration: ', 
               TIME_FORMAT(SEC_TO_TIME(f1.duration*6 ) ,'%H h %i'))
            FROM flight AS f1
            LEFT JOIN flight_pilot AS fp ON fp.flight_id=f1.id 
            LEFT JOIN resource ON resource.id=f1.aircraft_id
            WHERE fp.pilot_id=person.id 
            ORDER BY f1.start_date DESC LIMIT 1),'UNKNOWN') AS 'Last flight'
FROM person
WHERE person.activated=1
AND person.id NOT IN (
    SELECT person2.id
    FROM flight AS f
    LEFT JOIN flight_pilot AS fp ON fp.flight_id=f.id
    LEFT JOIN person AS person2 ON person2.id=fp.pilot_id
    WHERE f.airborne = 0 AND f.start_date BETWEEN NOW() - INTERVAL IF($month='', 1, $month*30) DAY AND NOW()
    GROUP BY person2.id HAVING SUM(f.duration)/600 > 0
)
ORDER BY person.last_name, person.first_name

Number of landings per pilot, per resource

SELECT last_name as "Last_name", first_name as "First_name",
 
(IF(DATE(valid.grant_date) < date(NOW()),'B', 'E')) as 'S',
 
-- (IF(DATE(valid.grant_date) < date(NOW()),valid_typ.name, 'Eleve')) as 'S2',
 
(SELECT SUM(landing_number) FROM flight
LEFT JOIN flight_pilot ON flight_pilot.flight_id = flight.id
WHERE flight_pilot.pilot_id = a.id 
AND flight.start_date BETWEEN NOW() - INTERVAL 3 MONTH AND NOW()) AS atterrissages,
 
(SELECT SUM(landing_number) FROM flight
LEFT JOIN flight_pilot ON flight_pilot.flight_id = flight.id
WHERE flight_pilot.pilot_id = a.id 
-- AND flight.aircraft_id = 1
AND flight.aircraft_id = 18
AND flight.start_date BETWEEN NOW() - INTERVAL 3 MONTH AND NOW()) AS KT,
 
(SELECT SUM(landing_number) FROM flight
LEFT JOIN flight_pilot ON flight_pilot.flight_id = flight.id
WHERE flight_pilot.pilot_id = a.id 
-- AND flight.aircraft_id = 10 
AND flight.aircraft_id = 2
AND flight.start_date BETWEEN NOW() - INTERVAL 3 MONTH AND NOW()) AS QR,
 
(SELECT SUM(landing_number) FROM flight
LEFT JOIN flight_pilot ON flight_pilot.flight_id = flight.id
WHERE flight_pilot.pilot_id = a.id 
-- AND flight.aircraft_id = 2
AND flight.aircraft_id = 3
AND flight.start_date BETWEEN NOW() - INTERVAL 3 MONTH AND NOW()) AS KH,
 
(SELECT SUM(landing_number) FROM flight
LEFT JOIN flight_pilot ON flight_pilot.flight_id = flight.id
WHERE flight_pilot.pilot_id = a.id 
-- AND flight.aircraft_id = 3
AND flight.aircraft_id = 4
AND flight.start_date BETWEEN NOW() - INTERVAL 3 MONTH AND NOW()) AS XF,
 
(SELECT SUM(landing_number) FROM flight
LEFT JOIN flight_pilot ON flight_pilot.flight_id = flight.id
WHERE flight_pilot.pilot_id = a.id 
AND (flight.aircraft_id = 2 OR flight.aircraft_id = 3 OR flight.aircraft_id = 4 OR flight.aircraft_id = 18)
AND flight.start_date BETWEEN NOW() - INTERVAL 3 MONTH AND NOW()) AS DR400,
 
(SELECT SUM(landing_number) FROM flight
LEFT JOIN flight_pilot ON flight_pilot.flight_id = flight.id
WHERE flight_pilot.pilot_id = a.id 
AND flight.aircraft_id = 23
AND flight.start_date BETWEEN NOW() - INTERVAL 3 MONTH AND NOW()) AS DR500,
 
(SELECT SUM(landing_number) FROM flight
LEFT JOIN flight_pilot ON flight_pilot.flight_id = flight.id
WHERE flight_pilot.pilot_id = a.id 
AND flight.aircraft_id = 8
AND flight.start_date BETWEEN NOW() - INTERVAL 3 MONTH AND NOW()) AS 'MC-IP',
 
(SELECT SUM(landing_number) FROM flight
LEFT JOIN flight_pilot ON flight_pilot.flight_id = flight.id
WHERE flight_pilot.pilot_id = a.id 
AND flight.aircraft_id = 21
AND flight.start_date BETWEEN NOW() - INTERVAL 3 MONTH AND NOW()) AS 'CAP10-DL'
 
FROM person a
 
LEFT JOIN profile AS p1 ON (a.profile & p1.id)
LEFT JOIN validity valid ON valid.person_id = a.id
LEFT JOIN validity_type valid_typ ON valid_typ.id = valid.validity_type_id
 
WHERE YEAR(grant_date) >= YEAR(NOW())
AND a.activated=1 AND p1.name='Pilot' 
 
GROUP BY last_name, first_name
ORDER BY last_name

Flight hours without up to date validities

SELECT DATE_FORMAT(start_date, '%d %m %Y' ) AS DATE,last_name AS Nom,
first_name AS Prénom, 
IF ((SELECT COUNT(*) 
    FROM flight_pilot fp2 
    WHERE fp2.flight_id=fp.flight_id AND fp2.num=1)=0, 'Solo', 'DC') AS DC,
resource.name AS Immat,
CONCAT(FLOOR( duration /600),
    ':',
    TIME_FORMAT(SEC_TO_TIME(( duration /600 - FLOOR( duration /600))*3600),'%i')) AS Tdv,
activity_type.name AS Type_Vol,
vt.name AS Qualif
FROM flight
LEFT JOIN flight_type_mandatory_validity_type fq ON fq.flight_type_id & flight.flight_type_id 
LEFT JOIN flight_pilot fp ON fp.flight_id = flight.id
LEFT JOIN person p ON p.id = fp.pilot_id
LEFT JOIN validity_type vt ON vt.id = fq.validity_type_id 
LEFT JOIN validity v ON v.validity_type_id = fq.validity_type_id 
LEFT JOIN resource ON resource.id = flight.aircraft_id
LEFT JOIN activity_type ON activity_type.id = fq.flight_type_id 
WHERE YEAR(start_date) = $year AND fp.num = 0 AND v.person_id = fp.pilot_id AND flight.start_date > v.expire_date AND p.activated=1
ORDER BY Nom

Number of men, women over and under 21 years for profile X, validity Y up to date for year Z

  • Variable $profileId should be of dbOject::Profile value type.
  • Variable $validityTypeId should be of dbObject::validityType value type.
  • Variable $year should be of Year value type.
SELECT
    IF( person.sex=0, 'Male', IF( person.sex=1, 'Female', 'Undefined') ) AS 'Sex',
    IF( ( $year - YEAR(birthdate) >= 21 ) , 'Yes', 'No') AS 'Adult',
    COUNT(DISTINCT person.id) AS NUMBER  
FROM person
LEFT JOIN validity ON (person.id=validity.person_id)
LEFT JOIN validity_type ON (validity_type.id=validity.validity_type_id)
WHERE activated=1
  AND (profile & '$profileId' OR '-'='$profileId')
  AND (validity_type.id='$validityTypeId' OR '-'='$validityTypeId')
  AND validity.expire_date >= '$year-12-31'
GROUP BY Sex, Adult

Validities in the year : Total of youngs/adults with specific profile

  • Variable $profileId should be defined first and should be of dbOject::Profile value type.
  • Variable $year should be defined first and should be of Year value type.
  • Note: "21" is the limit of age to categorize a young and adult person. Change it according to your need.
SELECT 
    validity_type.name AS 'Validity',
    SUM( IF( ( $year - YEAR(person.birthdate) < 21 ), 1, 0 ) ) AS 'Young',
    SUM( IF( ( $year - YEAR(person.birthdate) >= 21 ), 1, 0 ) ) AS 'Adult'
FROM validity_type
LEFT JOIN validity ON (validity.validity_type_id=validity_type.id)
LEFT JOIN person ON (person.id=validity.person_id)
WHERE YEAR(validity.grant_date)=$year
  AND person.activated=1
  AND (person.profile & '$profileId' OR '-'='$profileId')
GROUP BY validity_type.id
ORDER BY validity_type.name

Validities obtained in the year

  • Variable $validityId should be defined first and should be of dbOject::ValidityType value type.
  • 21 value is the age limit to be young. Should be changed according local rules
SELECT 
    last_name AS Last_name, 
    first_name AS First_name, 
    IF( ( $year - YEAR( birthdate ) >= 21) , 'No', 'Yes') AS Young,
    IF( person.sex=0, 'Male', IF( person.sex=1, 'Female', 'Undefined') ) AS 'Sex', DATE_FORMAT( grant_date, '%d/%m/%Y' ) AS Date, validity_type.name AS 'Validity'
FROM person 
LEFT JOIN validity ON person_id=person.id 
LEFT JOIN validity_type ON validity_type.id=validity.validity_type_id
WHERE YEAR(grant_date)=$year AND (validity_type.id = $validityTypeId)
  AND person.activated=1
ORDER BY last_name, first_name

Accounting

Booking

Cumulated maintenance hours on a period

Following extrafields are needed :

  • startDate (Type : Date)
  • endDate (Type : Date or DateTime)
SELECT IF(LEAST('$startDate' + INTERVAL 366 DAY, '$endDate') <> '$endDate', ' Attention la date de fin retenue correspond à la date de début + 366 jours', '') AS 'Ressource', '' AS 'Duree de maintenance en heures', '' AS 'Duree en jours'
UNION ALL
SELECT resource.name AS 'Ressource', SUM(TIMESTAMPDIFF(HOUR,booking.start_date, booking.end_date)), SUM(TIMESTAMPDIFF(DAY,booking.start_date, booking.end_date))
FROM booking
LEFT JOIN booking_activity_type ON booking.id=booking_activity_type.booking_id
LEFT JOIN activity_type ON activity_type.id=booking_activity_type.activity_type_id
LEFT JOIN booking_resource ON booking.id=booking_resource.booking_id
LEFT JOIN resource ON resource.id = booking_resource.resource_id
LEFT JOIN log ON log.field_value=booking.id
LEFT JOIN journal ON journal.id=log.journal_id
WHERE activity_type.name='Maintenance'
  AND (log.action='INSERT')
  AND (log.table_name='booking')
  AND (log.field_name='id')
  AND (booking.start_date >= '$startDate')
  AND (booking.start_date <= LEAST('$startDate' + INTERVAL 366 DAY, '$endDate'))
GROUP BY resource.id
ORDER BY 1

Maintenance hours per resource on a period

Following extrafields are needed :

  • startDate (Type : Date)
  • endDate (Type : Date or DateTime)
SELECT IF(LEAST('$startDate' + INTERVAL 366 DAY, '$endDate') <> '$endDate', ' Attention la date de fin retenue correspond à la date de début + 366 jours', '') AS 'Ressource', '' AS 'Date debut maintenance', '' AS 'Date fin maintenance', '' AS 'Duree de maintenance en heures', '' AS 'Duree en jours'
UNION ALL
SELECT resource.name, booking.start_date AS 'Date debut maintenance', booking.end_date, TIMESTAMPDIFF(HOUR,booking.start_date, booking.end_date),  TIMESTAMPDIFF(DAY,booking.start_date, booking.end_date)
FROM booking
LEFT JOIN booking_activity_type ON booking.id=booking_activity_type.booking_id
LEFT JOIN activity_type ON activity_type.id=booking_activity_type.activity_type_id
LEFT JOIN booking_resource ON booking.id=booking_resource.booking_id
LEFT JOIN resource ON resource.id = booking_resource.resource_id
LEFT JOIN log ON log.field_value=booking.id
LEFT JOIN journal ON journal.id=log.journal_id
WHERE activity_type.name='Maintenance'
  AND (log.action='INSERT')
  AND (log.TABLE_NAME='booking')
  AND (log.field_name='id')
  AND (booking.start_date >= '$startDate')
  AND (booking.start_date <= LEAST('$startDate' + INTERVAL 366 DAY, '$endDate'))
ORDER BY 1, 2

Bbooking for maintenance ordered by resource and date with name of the responsible

SELECT resource.name AS 'Resource name', booking.start_date AS 'Start date', TIMESTAMPDIFF(HOUR,booking.start_date, booking.end_date) AS 'booking duration', person.first_name AS 'First name', person.last_name AS 'Last name'
FROM booking
LEFT JOIN booking_activity_type ON booking.id=booking_activity_type.booking_id
LEFT JOIN activity_type ON activity_type.id=booking_activity_type.activity_type_id
LEFT JOIN booking_resource ON booking.id=booking_resource.booking_id
LEFT JOIN resource ON resource.id = booking_resource.resource_id
LEFT JOIN log ON log.field_value=booking.id
LEFT JOIN journal ON journal.id=log.journal_id
LEFT JOIN person ON person.name=journal.login
WHERE activity_type.name='Maintenance'
  AND (log.action='INSERT')
  AND (log.TABLE_NAME='booking')
  AND (log.field_name='id')
  AND YEAR(booking.start_date) = $year
  AND person.activated=1
ORDER BY resource.name, booking.start_date

Flight time management

Flight hours total and last recorded counters to the date X

  • Variable $endDate should be of Datetime value type.
SELECT resource.name, sexa2HoursMinute( SUM(duration) + aircraft.ref_hours ) AS 'Total heures', sexa2HoursMinute( MAX(counter_arrival) ) AS 'Dernier compteur'
FROM flight
LEFT JOIN resource ON (resource.id=flight.aircraft_id)
LEFT JOIN aircraft ON (aircraft.id=resource.id)
WHERE flight.start_date <= '$endDate'
  AND resource.activated=1
GROUP BY resource.id
ORDER BY resource.name

Flight hours per month

SELECT MONTH( start_date) AS months, CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) AS Total 
FROM flight 
LEFT JOIN aircraft ON aircraft.id = flight.aircraft_id 
WHERE YEAR(start_date) = $year 
GROUP BY months

Flight hours total over a 12 months period

SELECT 
    CONCAT(last_name,' ',first_name) AS 'Person', 
    IF (( SELECT 
            COUNT(*) 
          FROM flight_pilot fp2 
          WHERE fp2.flight_id=fp.flight_id AND fp2.num=1)=0,
      'Solo',
      'double') AS Solo_DC, 
    CONCAT(FLOOR(SUM( flight.duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( flight.duration )/600 - FLOOR(SUM( flight.duration )/600))*3600),'%i')) AS Total 
  FROM flight_pilot fp 
  LEFT JOIN flight ON fp.flight_id=flight.id 
  LEFT JOIN person a ON a.id=fp.pilot_id 
  WHERE start_date > DATE_SUB(NOW(), INTERVAL 1 YEAR)  AND fp.num=0 
  GROUP BY Person, Solo_DC

Flights hours total per aircraft per year

SELECT 
    name AS Callsign, 
    YEAR( start_date ) AS Year, 
    CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) AS Total 
  FROM flight 
    LEFT JOIN resource ON resource.id = flight.aircraft_id 
  WHERE YEAR(start_date) = $year AND airborne = 0 
  GROUP BY name 
  UNION 
  SELECT 
    "Total", 
    $year AS year, 
    CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) AS Total      
  FROM flight 
  WHERE YEAR(start_date) = $year AND airborne = 0 
  GROUP BY year

Flights hours total per aircraft per year and per month (for an activity type)

  • Variable $activityTypeId should be defined first and should be of dbOject::ActivityType value type.
  • Variable $year should be defined first and should be of Year value type.
SELECT aircraft_id AS Num, resource.name, 
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=1, duration, 0 ) ) ) AS Janu,
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=2, duration, 0 ) ) ) AS Febr,
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=3, duration, 0 ) ) ) AS Marc,
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=4, duration, 0 ) ) ) AS Apri,
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=5, duration, 0 ) ) ) AS May,
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=6, duration, 0 ) ) ) AS June,
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=7, duration, 0 ) ) ) AS July,
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=8, duration, 0 ) ) ) AS Augu,
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=9, duration, 0 ) ) ) AS Sept,
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=10, duration, 0 ) ) ) AS Octo,
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=11, duration, 0 ) ) ) AS Nove,
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=12, duration, 0 ) ) ) AS Dece,
    sexa2HoursMinute( SUM( duration ) ) AS SUM 
FROM flight
LEFT JOIN aircraft ON aircraft.id = flight.aircraft_id
LEFT JOIN resource ON resource.id = aircraft.id
WHERE YEAR(start_date)= $year AND airborne = 0
  AND (flight.flight_type_id & '$activityTypeId' OR '-'='$activityTypeId')
GROUP BY resource.id
UNION 
SELECT  "Sum per","month", 
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=1, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=2, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=3, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=4, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=5, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=6, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=7, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=8, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=9, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=10, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=11, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)=12, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( duration ) ) AS Total
FROM flight
LEFT JOIN aircraft ON aircraft.id = flight.aircraft_id
LEFT JOIN resource ON resource.id = aircraft.id
WHERE YEAR(start_date)= $year AND airborne = 0 
  AND (flight.flight_type_id & '$activityTypeId' OR '-'='$activityTypeId')
UNION 
SELECT  "Cumulative","per month", 
    sexa2HoursMinute( SUM( IF( MONTH(start_date)<=1, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)<=2, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)<=3, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)<=4, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)<=5, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)<=6, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)<=7, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)<=8, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)<=9, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)<=10, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)<=11, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( IF( MONTH(start_date)<=12, duration, 0 ) ) ),
    sexa2HoursMinute( SUM( duration ) ) AS Total
FROM flight
LEFT JOIN aircraft ON aircraft.id = flight.aircraft_id
LEFT JOIN resource ON resource.id = aircraft.id
WHERE YEAR(start_date)= $year AND airborne = 0
  AND (flight.flight_type_id & '$activityTypeId' OR '-'='$activityTypeId')

Flight hours total per pilot

SELECT
    CONCAT(last_name,' ',first_name) AS Nom,
    sexa2HoursMinute( SUM( IFNULL( Solo.sum_duration, 0 ) ) ) AS 'Solo',
    sexa2HoursMinute( SUM( IFNULL( DC.sum_duration, 0 ) ) ) AS 'Double',
    sexa2HoursMinute( SUM( IFNULL( Solo.sum_duration, 0 ) ) + SUM( IFNULL( DC.sum_duration, 0 ) ) ) AS 'Total'
FROM person
LEFT JOIN (
    SELECT 
        pilot_id,
        IF (
            (SELECT COUNT(*) FROM flight_pilot fp2 WHERE fp2.flight_id=fp.flight_id AND fp2.num=1)=0,
            'Solo',
            'DC'
        ) AS Solo_DC,
        SUM(flight.duration) AS sum_duration
    FROM flight_pilot fp 
    LEFT JOIN flight ON fp.flight_id=flight.id
    WHERE flight.airborne=0 AND YEAR(start_date) = $year AND fp.num=0 
    GROUP BY pilot_id, Solo_DC
) AS Solo ON person.id=Solo.pilot_id AND Solo.Solo_DC='Solo'
LEFT JOIN (
    SELECT 
        pilot_id,
        IF (
            (SELECT COUNT(*) FROM flight_pilot fp2 WHERE fp2.flight_id=fp.flight_id AND fp2.num=1)=0,
            'Solo',
            'DC'
        ) AS Solo_DC,
        SUM(flight.duration) AS sum_duration
    FROM flight_pilot fp 
    LEFT JOIN flight ON fp.flight_id=flight.id
    WHERE flight.airborne=0 AND YEAR(start_date) = $year AND fp.num=0 
    GROUP BY pilot_id, Solo_DC
) AS DC ON person.id=DC.pilot_id AND DC.Solo_DC='DC'
WHERE (Solo.pilot_id IS NOT NULL OR DC.pilot_id IS NOT NULL)
  AND person.activated=1
GROUP BY person.id
ORDER BY Nom

Flight hours total per pilot per profile

SELECT
    profile.name AS Profil,
    CONCAT(last_name,' ',first_name) AS Nom,
    IF (( SELECT
            COUNT(*)
          FROM flight_pilot fp2
          WHERE fp2.flight_id=fp.flight_id AND fp2.num=1)=0,
        'Solo',
        'double') AS Solo_DC,
    sexa2HoursMinute( SUM( flight.duration ) ) AS Total
  FROM flight_pilot fp
  LEFT JOIN flight ON fp.flight_id=flight.id
  LEFT JOIN person ON person.id=fp.pilot_id
  LEFT JOIN profile ON (person.profile & profile.id)
  WHERE flight.airborne=0 AND YEAR( start_date ) = $year AND fp.num=0
  GROUP BY Profil, Nom, Solo_DC

Total Flight hours per pilot with total duration and total amount

Following extrafields are needed

  • year (Type : Year)
  • month (Type : Integer) OR startDate and endDate (Type : Date)
  • $occupiedSeat (Type : Integer)
  • profileId (Type : dbObject::Profile)

This report is useful for a group of pilots from a common customer (like DGAC in France)

SELECT CONCAT(person.last_name,' ',person.first_name) AS Nom_et_prenom_pilotes,
CONCAT(FLOOR(SUM( flight_list.duree )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( flight_list.duree )/600 - FLOOR(SUM( flight_list.duree )/600))*3600),'%i')) AS nombre_hdv_effectuees,
SUM(flight_list.montant) AS montant_total_des_vols 
FROM person
JOIN
(SELECT person.id AS person_id, flight.id AS vol, flight.duration AS duree, SUM(account_entry.debit)-SUM(account_entry.credit) AS montant FROM person
LEFT JOIN flight_pilot ON flight_pilot.pilot_id=person.id
LEFT JOIN flight ON flight.id=flight_pilot.flight_id
LEFT JOIN flight_account_entry ON flight_account_entry.flight_id = flight.id
LEFT JOIN account_entry ON account_entry.flow_id = flight_account_entry.account_entry_id
LEFT JOIN account ON account.id=account_entry.account_id
WHERE '$startDate' <= flight.start_date AND flight.start_date <= '$endDate'
    AND (IF((('$occupiedSeat'=0)OR('$occupiedSeat'='')), 0, -1) = flight_pilot.num
    OR IF((('$occupiedSeat'=1)OR('$occupiedSeat'='')), 1, -1) = flight_pilot.num)
        AND person.profile&$profileId AND (account.category = 11 OR account.category = 2)
GROUP BY flight.id) AS flight_list ON flight_list.person_id=person.id
GROUP BY person.id

Flight hours per instructor, month (for a flight type)

Following extrafields are needed :

  • year (Type : Year)
  • activityTypeId (Type : dbObject::FlightType)
SELECT 
    UPPER(last_name) AS Nom,
    first_name AS Prénom,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 1 AND flight_pilot.pilot_id = a.id AND flight_pilot.num = 1 AND ( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Janv,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 2 AND flight_pilot.pilot_id = a.id AND flight_pilot.num = 1 AND ( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Fevr,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 3 AND flight_pilot.pilot_id = a.id AND flight_pilot.num = 1 AND ( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Mars,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 4 AND flight_pilot.pilot_id = a.id AND flight_pilot.num = 1 AND ( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Avri,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 5 AND flight_pilot.pilot_id = a.id AND flight_pilot.num = 1 AND ( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Mai,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 6 AND flight_pilot.pilot_id = a.id AND flight_pilot.num = 1 AND ( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Juin,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 7 AND flight_pilot.pilot_id = a.id AND flight_pilot.num = 1 AND ( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Juil,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 8 AND flight_pilot.pilot_id = a.id AND flight_pilot.num = 1 AND ( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Aout,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 9 AND flight_pilot.pilot_id = a.id AND flight_pilot.num = 1 AND ( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Sept,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 10 AND flight_pilot.pilot_id = a.id AND flight_pilot.num = 1 AND ( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Oct,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 11 AND flight_pilot.pilot_id = a.id AND flight_pilot.num = 1 AND ( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Nov,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 12 AND flight_pilot.pilot_id = a.id AND flight_pilot.num = 1 AND ( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Dece,
    sexa2HoursMinute( SUM( duration ) ) AS Total
FROM flight 
LEFT JOIN flight_pilot fp ON fp.flight_id = flight.id 
LEFT JOIN person a ON a.id=fp.pilot_id 
WHERE flight.airborne=0
  AND a.activated=1
  AND fp.num = 1 
  AND YEAR( start_date ) = $year  
  AND ( flight.flight_type_id & '$activityTypeId' OR '-'='$activityTypeId' )
GROUP BY a.id
 
UNION
 
SELECT  "Sum per","month",
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 1 AND flight_pilot.num = 1 AND( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Janv,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 2 AND flight_pilot.num = 1 AND( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Fevr,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 3 AND flight_pilot.num = 1 AND( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Mars,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 4 AND flight_pilot.num = 1 AND( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Avri,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 5 AND flight_pilot.num = 1 AND( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Mai,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 6 AND flight_pilot.num = 1 AND( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Juin,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 7 AND flight_pilot.num = 1 AND( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Juil,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 8 AND flight_pilot.num = 1 AND( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Aout,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 9 AND flight_pilot.num = 1 AND( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Sept,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 10 AND flight_pilot.num = 1 AND( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Oct,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 11 AND flight_pilot.num = 1 AND( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Nov,
    (SELECT sexa2HoursMinute( SUM( duration ) ) FROM flight INNER JOIN flight_pilot ON flight_pilot.flight_id = flight.id WHERE YEAR(start_date)= $year AND MONTH(start_date)= 12 AND flight_pilot.num = 1 AND( flight.flight_type_id & '$activityTypeId' != 0 OR '-'='$activityTypeId' ) ) AS Dece,
    sexa2HoursMinute( SUM( duration ) ) AS Total
FROM flight 
LEFT JOIN flight_pilot fp ON fp.flight_id = flight.id
LEFT JOIN person a ON a.id=fp.pilot_id 
WHERE flight.airborne=0
  AND a.activated=1
  AND fp.num = 1
  AND YEAR( start_date ) = $year  
  AND ( flight.flight_type_id & '$activityTypeId' OR '-'='$activityTypeId' )

Flights hours following nationality

SELECT  
     nationality.label, 
     CONCAT(FLOOR(SUM( flight.duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( flight.duration )/600 -   FLOOR(SUM( flight.duration )/600))*3600),'%i')) AS Total 
   FROM flight , flight_pilot fp, person a, nationality
   WHERE flight.id = fp.flight_id
     AND fp.pilot_id = a.id
     AND a.nationality = nationality.code
   GROUP BY nationality.code

Flights hours total per flight type per month

SELECT 
    activity_type.name AS Type_vol,
    flight_pilot_DC.DC,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 1, duration, 0 ) ) ) AS Janu,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 2, duration, 0 ) ) ) AS Febr,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 3, duration, 0 ) ) ) AS Marc,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 4, duration, 0 ) ) ) AS Apri,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 5, duration, 0 ) ) ) AS May,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 6, duration, 0 ) ) ) AS June,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 7, duration, 0 ) ) ) AS July,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 8, duration, 0 ) ) ) AS Augu,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 9, duration, 0 ) ) ) AS Sept,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 10, duration, 0 ) ) ) AS Octo,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 11, duration, 0 ) ) ) AS Nove,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 12, duration, 0 ) ) ) AS Dece,
    sexa2HoursMinute( SUM( duration ) ) AS Total
FROM flight
LEFT JOIN activity_type ON activity_type.id & flight.flight_type_id
LEFT JOIN (
    SELECT flight_id, IF( MAX(num) = 1, 'Double', 'Solo' ) AS DC
    FROM flight_pilot
    WHERE flight_pilot.num <= 1
    GROUP BY flight_id
) AS flight_pilot_DC ON flight.id=flight_pilot_DC.flight_id
WHERE YEAR(start_date) = $year
  AND airborne = 0
GROUP BY activity_type.id, flight_pilot_DC.DC
HAVING (Name <> 'Instruction' OR flight_pilot_DC.DC <> 'Double')
ORDER BY order_num ASC, DC DESC

Flights hours : less than 21 years, more than 21 years, male, female, for a given profile

  • Variable $profileId should be defined first and should be of dbOject::Profile value type.
  • Variable $year should be defined first and should be of Year value type.
SELECT Sex, Young, Instruction,
       sexa2HoursMinute(SUM(IF(category=1, duration, 0))) AS 'Avion',
       sexa2HoursMinute(SUM(IF(category=18, duration, 0))) AS 'Hélicoptère',
       sexa2HoursMinute(SUM(IF(category=19, duration, 0))) AS 'Planeur',
       sexa2HoursMinute(SUM(IF(category=17, duration, 0))) AS 'ULM'
FROM (
    SELECT
        IF( person.sex=0, 'Male', IF( person.sex=1, 'Female', 'Undefined') ) AS 'Sex',
        IF( ( $year - YEAR( birthdate ) >= 21) , 'No', 'Yes') AS Young,
        IF ((SELECT COUNT(*) FROM flight_pilot fp2 WHERE fp2.flight_id=fp.flight_id AND fp2.num=1)=0, 'Solo', 'Instruction') AS Instruction,
        flight.duration,
        resource_type.category
        FROM flight_pilot fp
    LEFT JOIN flight ON fp.flight_id=flight.id
    LEFT JOIN person ON person.id=fp.pilot_id
    LEFT JOIN resource ON (resource.id=flight.aircraft_id)
    LEFT JOIN resource_type ON (resource_type.id=resource.resource_type_id)
    WHERE YEAR( start_date )=$year AND fp.num=0 AND flight.airborne = 0 AND (person.profile & '$profileId' OR '-'='$profileId') AND person.activated=1
) AS tmp_stat
GROUP BY Sex, Young, Instruction WITH ROLLUP

Computation of flight time per month of "local flight"

"Local flight" is defined as a flight less than 1h30 and with the same departure and destination

SELECT  aircraft_id AS Num, name AS Immat, 
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 1 AND aircraft_id = Num AND departure_location_id = arrival_location_id AND duration < 90*600) AS Janv,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 2 AND aircraft_id = Num AND departure_location_id = arrival_location_id AND duration < 90*600) AS Fevr,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 3 AND aircraft_id = Num AND departure_location_id = arrival_location_id AND duration < 90*600) AS Mars,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 4 AND aircraft_id = Num AND departure_location_id = arrival_location_id AND duration < 90*600) AS Avri,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 5 AND aircraft_id = Num AND departure_location_id = arrival_location_id AND duration < 90*600) AS Mai,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 6 AND aircraft_id = Num AND departure_location_id = arrival_location_id AND duration < 90*600) AS Juin,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 7 AND aircraft_id = Num AND departure_location_id = arrival_location_id AND duration < 90*600) AS Juil,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 8 AND aircraft_id = Num AND departure_location_id = arrival_location_id AND duration < 90*600) AS Aout,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 9 AND aircraft_id = Num AND departure_location_id = arrival_location_id AND duration < 90*600) AS Sept,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 10 AND aircraft_id = Num AND departure_location_id = arrival_location_id AND duration < 90*600) AS Octo,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 11 AND aircraft_id = Num AND departure_location_id = arrival_location_id AND duration < 90*600) AS Nove,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 12 AND aircraft_id = Num ) AS Dece,
    CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) AS Total 
FROM flight
LEFT JOIN aircraft ON aircraft.id = flight.aircraft_id 
LEFT JOIN resource ON resource.id = aircraft.id
WHERE YEAR(start_date)= $year AND departure_location_id = arrival_location_id AND duration < 90*600
GROUP BY resource.id

Computation of non-"local flight" time per month

SELECT  aircraft_id AS Num, name AS Immat, 
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 1 AND aircraft_id = Num AND ((departure_location_id = arrival_location_id AND duration >= 90*600) OR departure_location_id <> arrival_location_id)) AS Janv,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 2 AND aircraft_id = Num AND ((departure_location_id = arrival_location_id AND duration >= 90*600) OR departure_location_id <> arrival_location_id)) AS Fevr,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 3 AND aircraft_id = Num AND ((departure_location_id = arrival_location_id AND duration >= 90*600) OR departure_location_id <> arrival_location_id)) AS Mars,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 4 AND aircraft_id = Num AND ((departure_location_id = arrival_location_id AND duration >= 90*600) OR departure_location_id <> arrival_location_id)) AS Avri,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 5 AND aircraft_id = Num AND ((departure_location_id = arrival_location_id AND duration >= 90*600) OR departure_location_id <> arrival_location_id)) AS Mai,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 6 AND aircraft_id = Num AND ((departure_location_id = arrival_location_id AND duration >= 90*600) OR departure_location_id <> arrival_location_id)) AS Juin,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 7 AND aircraft_id = Num AND ((departure_location_id = arrival_location_id AND duration >= 90*600) OR departure_location_id <> arrival_location_id)) AS Juil,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 8 AND aircraft_id = Num AND ((departure_location_id = arrival_location_id AND duration >= 90*600) OR departure_location_id <> arrival_location_id)) AS Aout,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 9 AND aircraft_id = Num AND ((departure_location_id = arrival_location_id AND duration >= 90*600) OR departure_location_id <> arrival_location_id)) AS Sept,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 10 AND aircraft_id = Num AND ((departure_location_id = arrival_location_id AND duration >= 90*600) OR departure_location_id <> arrival_location_id)) AS Octo,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 11 AND aircraft_id = Num AND ((departure_location_id = arrival_location_id AND duration >= 90*600) OR departure_location_id <> arrival_location_id)) AS Nove,
    (SELECT 
        CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) 
    FROM flight 
    WHERE YEAR(start_date)= $year AND MONTH(start_date)= 12 AND aircraft_id = Num AND ((departure_location_id = arrival_location_id AND duration >= 90*600) OR departure_location_id <> arrival_location_id)) AS Dece,
    CONCAT(FLOOR(SUM( duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( duration )/600 - FLOOR(SUM( duration )/600))*3600),'%i')) AS Total 
FROM flight
LEFT JOIN aircraft ON aircraft.id = flight.aircraft_id 
LEFT JOIN resource ON resource.id = aircraft.id
WHERE YEAR(start_date)= $year AND ((departure_location_id = arrival_location_id AND duration >= 90*600) OR departure_location_id <> arrival_location_id)
GROUP BY resource.id

Stats all flight hours per month per year

SELECT YEAR(start_date) AS Year, 'Monthly' AS Type,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 1, duration, 0 ) ) ) AS Janu,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 2, duration, 0 ) ) ) AS Febr,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 3, duration, 0 ) ) ) AS Marc,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 4, duration, 0 ) ) ) AS Apri,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 5, duration, 0 ) ) ) AS May,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 6, duration, 0 ) ) ) AS June,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 7, duration, 0 ) ) ) AS July,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 8, duration, 0 ) ) ) AS Augu,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 9, duration, 0 ) ) ) AS Sept,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 10, duration, 0 ) ) ) AS Octo,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 11, duration, 0 ) ) ) AS Nove,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) = 12, duration, 0 ) ) ) AS Dece,
    sexa2HoursMinute( SUM( duration ) ) AS Total
FROM flight
LEFT JOIN resource ON resource.id = flight.aircraft_id
GROUP BY Year
UNION
SELECT YEAR(start_date) AS Year, 'Accumulation' AS Type,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) <= 1, duration, 0 ) ) ) AS Janu,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) <= 2, duration, 0 ) ) ) AS Febr,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) <= 3, duration, 0 ) ) ) AS Marc,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) <= 4, duration, 0 ) ) ) AS Apri,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) <= 5, duration, 0 ) ) ) AS May,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) <= 6, duration, 0 ) ) ) AS June,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) <= 7, duration, 0 ) ) ) AS July,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) <= 8, duration, 0 ) ) ) AS Augu,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) <= 9, duration, 0 ) ) ) AS Sept,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) <= 10, duration, 0 ) ) ) AS Octo,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) <= 11, duration, 0 ) ) ) AS Nove,
    sexa2HoursMinute( SUM( IF( MONTH(start_date) <= 12, duration, 0 ) ) ) AS Dece,
    sexa2HoursMinute( SUM( duration ) ) AS Total
FROM flight
LEFT JOIN resource ON resource.id = flight.aircraft_id
GROUP BY Year
ORDER BY Type DESC, Year

Flight hours total per resource per flight type between two dates

  • Variable $startDate should be defined first and should be of Date and time value type.
  • Variable $endDate should be defined first and should be of Date and time value type.
[OF_DYNAMIC_SQL]
SELECT CONCAT(
    'SELECT resource.name AS Nom, ',
    GROUP_CONCAT(
        CONCAT(
            'sexa2HoursMinute( SUM( IF( tmp_flight.flight_type_id=',
            activity_type.id,
            ', tmp_flight.total_duration, 0 ) ) )',
            ' AS \'',
            activity_type.name,
            '\''
        )
    ),
    ', sexa2HoursMinute( SUM( tmp_flight.total_duration ) ) AS Total
    FROM resource
    LEFT JOIN
    (
        SELECT flight.aircraft_id, activity_type.id AS flight_type_id, SUM(duration) as total_duration
        FROM flight
        LEFT JOIN activity_type ON (flight.flight_type_id & activity_type.id)
        WHERE flight.start_date >= \'$startDate\' AND flight.start_date <= \'$endDate\' AND flight.airborne = 0
        GROUP BY flight.aircraft_id, activity_type.id
    ) AS tmp_flight ON (resource.id=tmp_flight.aircraft_id)
    WHERE tmp_flight.aircraft_id IS NOT NULL
    GROUP BY resource.id
    UNION
    SELECT \'Total\', ',
    GROUP_CONCAT(
        CONCAT(
            'sexa2HoursMinute( SUM( IF( tmp_flight.flight_type_id=',
            activity_type.id,
            ', tmp_flight.total_duration, 0 ) ) )',
            ' AS \'',
            activity_type.name,
            '\''
        )
    ),
    ', sexa2HoursMinute( SUM( tmp_flight.total_duration ) ) AS Total
    FROM resource
    LEFT JOIN
    (
        SELECT flight.aircraft_id, activity_type.id AS flight_type_id, SUM(duration) as total_duration
        FROM flight
        LEFT JOIN activity_type ON (flight.flight_type_id & activity_type.id)
        WHERE flight.start_date >= \'$startDate\' AND flight.start_date <= \'$endDate\' AND flight.airborne = 0
        GROUP BY flight.aircraft_id, activity_type.id
    ) AS tmp_flight ON (resource.id=tmp_flight.aircraft_id)
    WHERE tmp_flight.aircraft_id IS NOT NULL
    ORDER BY 1'
)
FROM activity_type
WHERE activity_type.activated=1

Flight reports

Aircraft(s) which no flight were done for at least 30 day(s)

SELECT resource.id, resource.name
FROM flight
LEFT JOIN resource ON resource.id = flight.aircraft_id
WHERE start_date < ( NOW() - INTERVAL 30 DAY )
  AND physical=1 AND activated=1
GROUP BY resource.id

Detailed flight between two dates

Following extrafields are needed

  • startDate and endDate (Type : Date)
  • profileId (Type : dbObject::Profile)
  • occupiedSeat (Type : Integer)

This report is useful for a group of pilots from a common customer (like french administration DGAC).

SELECT 
    (
        SELECT CONCAT(last_name,' ',first_name)
        FROM person
        LEFT JOIN flight_pilot ON flight_pilot.pilot_id=person.id
        WHERE flight_pilot.flight_id=flight.id AND flight_pilot.num=0
        GROUP BY flight.id
    ) AS Left_seat_Pilot_name,
    (
        SELECT CONCAT(last_name,' ',first_name)
        FROM person
        LEFT JOIN flight_pilot ON flight_pilot.pilot_id=person.id
        WHERE flight_pilot.flight_id=flight.id AND flight_pilot.num=1
        GROUP BY flight.id
    ) AS Right_seat_Pilot_name,
    flight.start_date,
    resource.name AS resource,
    CONCAT(FLOOR(flight.duration/600),':',TIME_FORMAT(SEC_TO_TIME((flight.duration /600 - FLOOR(flight.duration/600))*3600),'%i')) AS flight_duration,
    (
        SELECT GROUP_CONCAT( flight_type.name SEPARATOR ', ')
        FROM flight AS f2
        LEFT JOIN flight_type ON (f2.flight_type_id & flight_type.id)
        WHERE f2.id=flight.id
    ) AS Flight_types,
    flight.landing_number,
    SUM(account_entry.debit)-SUM(account_entry.credit) AS amount,
    flight.comments
    FROM person
    LEFT JOIN flight_pilot ON flight_pilot.pilot_id=person.id
    LEFT JOIN flight ON flight.id=flight_pilot.flight_id
    LEFT JOIN flight_account_entry ON flight_account_entry.flight_id = flight.id
    LEFT JOIN account_entry ON account_entry.flow_id = flight_account_entry.account_entry_id
    LEFT JOIN account ON account.id=account_entry.account_id
    LEFT JOIN resource ON resource.id = flight.aircraft_id
    WHERE '$startDate' <= flight.start_date AND flight.start_date <= '$endDate'
    AND (IF((('$occupiedSeat'=0)OR('$occupiedSeat'='')), 0, -1) = flight_pilot.num
    OR IF((('$occupiedSeat'=1)OR('$occupiedSeat'='')), 1, -1) = flight_pilot.num)
        AND person.profile&$profileId AND (account.category = 11 OR account.category = 2)
    GROUP BY flight.id

Detailed flight per month

Following extrafields are needed

  • year (Type : Year)
  • month (Type : Integer)
  • profileId (Type : dbObject::Profile)
  • occupiedSeat (Type : Integer)

This report is useful for a group of pilots from a common customer (like french administration DGAC).

SELECT 
    (
        SELECT CONCAT(last_name,' ',first_name)
        FROM person
        LEFT JOIN flight_pilot ON flight_pilot.pilot_id=person.id
        WHERE flight_pilot.flight_id=flight.id AND flight_pilot.num=0
        GROUP BY flight.id
    ) AS Left_seat_Pilot_name,
    (
        SELECT CONCAT(last_name,' ',first_name)
        FROM person
        LEFT JOIN flight_pilot ON flight_pilot.pilot_id=person.id
        WHERE flight_pilot.flight_id=flight.id AND flight_pilot.num=1
        GROUP BY flight.id
    ) AS Right_seat_Pilot_name,
    flight.start_date,
    resource.name AS resource,
    CONCAT(FLOOR(flight.duration/600),':',TIME_FORMAT(SEC_TO_TIME((flight.duration /600 - FLOOR(flight.duration/600))*3600),'%i')) AS flight_duration,
    (
        SELECT GROUP_CONCAT( activity_type.name SEPARATOR ', ')
        FROM flight AS f2
        LEFT JOIN activity_type ON (f2.flight_type_id & activity_type.id)
        WHERE f2.id=flight.id
    ) AS Flight_types,
    flight.landing_number,
    SUM(account_entry.debit)-SUM(account_entry.credit) AS amount,
    business_field_comment.content AS comments
FROM person
LEFT JOIN flight_pilot ON flight_pilot.pilot_id=person.id
LEFT JOIN flight ON flight.id=flight_pilot.flight_id
LEFT JOIN flight_account_entry ON flight_account_entry.flight_id = flight.id
LEFT JOIN account_entry ON account_entry.flow_id = flight_account_entry.account_entry_id
LEFT JOIN account ON account.id=account_entry.account_id
LEFT JOIN resource ON resource.id = flight.aircraft_id
LEFT JOIN (
    SELECT business_field_content.category_id, business_field_content.content
    FROM business_field_content
    LEFT JOIN business_field ON (business_field.id=business_field_content.extra_field_id)
    WHERE business_field.variable='activityComment'
) AS business_field_comment ON (business_field_comment.category_id=flight.id)
WHERE YEAR(flight.start_date)=$year
      AND MONTH(flight.start_date)='$month'
      AND (IF((('$occupiedSeat'=0)OR('$occupiedSeat'='')), 0, -1) = flight_pilot.num
      OR IF((('$occupiedSeat'=1)OR('$occupiedSeat'='')), 1, -1) = flight_pilot.num)
        AND person.profile&'$profileId' AND (account.category = 11 OR account.category = 2)
GROUP BY flight.id

Flight between two dates

Following variables are needed:

  • startDate (Type : Datetime)
  • endDate (Type : Datetime)
SELECT f.start_date, r.name, 
CONCAT(UPPER(p.last_name),' ',p.first_name) AS Pilot,
    ( 
        SELECT CONCAT(UPPER(p2.last_name), ' ', p2.first_name)
        FROM flight_pilot AS fp2
        LEFT JOIN person AS p2 ON fp2.pilot_id = p2.id
        WHERE fp2.flight_id = f.id AND fp2.num = 1
    ) AS Instructor,
    (
        SELECT GROUP_CONCAT( activity_type.name SEPARATOR ', ')
        FROM flight
        LEFT JOIN activity_type ON (flight.flight_type_id & activity_type.id)
        WHERE flight.id=f.id
    ) AS Flight_types,
    (
        SELECT location.name
        FROM location
        WHERE location.id=f.departure_location_id
    ) AS departure_location,
    (
        SELECT location.name
        FROM location
        WHERE location.id=f.arrival_location_id
    ) AS arrival_location,
    f.landing_number AS landing_number,
CONCAT(FLOOR( f.duration/600),':',TIME_FORMAT(SEC_TO_TIME((f.duration/600 - FLOOR(f.duration/600))*3600),'%i')) AS duration
FROM flight AS f
LEFT JOIN resource AS r ON r.id = f.aircraft_id
LEFT JOIN flight_pilot AS fp ON fp.flight_id = f.id
LEFT JOIN person AS p ON fp.pilot_id = p.id
WHERE f.start_date >= '$startDate' AND f.start_date <= '$endDate' AND fp.num = 0

Flight log book

SELECT 
    DATE_FORMAT(start_date, '%d/%m/%Y') AS DATE,
    CONCAT(last_name, ' ', first_name) AS Membre,
    resource.name AS Appareil,
    IF ( (SELECT COUNT(*) FROM flight_pilot fp2 WHERE fp2.flight_id=fp.flight_id AND fp2.num=1)=0, 'S', 'D' ) AS Solo_DC,
    (
        SELECT CONCAT(person.last_name, ' ', person.first_name) AS Instructeur
        FROM flight_pilot fp3 
        LEFT JOIN person ON person.id=fp3.pilot_id
        WHERE fp3.flight_id=fp.flight_id AND fp3.num=1
    ) AS Instructeur,
    CONCAT(FLOOR(flight.duration /600),':',TIME_FORMAT(SEC_TO_TIME(( flight.duration /600 - FLOOR( flight.duration /600))*3600),'%i')) AS Durée,
    activity_type.name AS 'Type de vol',
    flight.landing_number,
    business_field_comment.content AS comments
FROM flight_pilot fp 
LEFT JOIN flight ON fp.flight_id=flight.id
LEFT JOIN activity_type ON (activity_type.id & flight.flight_type_id)
LEFT JOIN person ON person.id=fp.pilot_id
LEFT JOIN resource ON resource.id = flight.aircraft_id
LEFT JOIN (
    SELECT business_field_content.category_id, business_field_content.content
    FROM business_field_content
    LEFT JOIN business_field ON (business_field.id=business_field_content.extra_field_id)
    WHERE business_field.variable='activityComment'
) AS business_field_comment ON (business_field_comment.category_id=flight.id)
WHERE YEAR( start_date ) = $year
  AND fp.num=0
ORDER BY Membre, start_date

Flights which have landed elsewhere than the base field

Variable $icao shall be defined (dbObject:Location)

 
SELECT DATE_FORMAT(flight.start_date,'%d/%m/%Y') AS Date, resource.name AS immatriculation, 
    CONCAT(FLOOR( duration/600),':',TIME_FORMAT(SEC_TO_TIME((duration/600 - FLOOR(duration/600))*3600),'%i')) AS Durée,
    person.last_name AS Nom, person.first_name AS Prénom,
    l1.icao_name AS Départ,
    l2.icao_name AS Arrivée
FROM flight 
LEFT JOIN resource ON resource.id = flight.aircraft_id
LEFT JOIN flight_pilot ON flight_pilot.flight_id = flight.id 
LEFT JOIN person ON person.id = flight_pilot.pilot_id 
LEFT JOIN location AS l1 ON l1.id = flight.departure_location_id
LEFT JOIN location AS l2 ON l2.id = flight.arrival_location_id
WHERE flight_pilot.num = 0 AND (
    l1.icao_name LIKE '$icao'  OR 
    l2.icao_name LIKE '$icao')
GROUP BY flight.id
 

Flights with a remark in one or two additional entries

  • Extra field $maintenanceUserComment should be defined first and should be of Text multi line value type and Flight category.
  • Extra field $mechanicAnswer should be defined first and should be of Text multi line value type and Flight category.
SELECT flight.start_date, resource.name AS Callsign, 
    CONCAT(FLOOR( duration/600),':',TIME_FORMAT(SEC_TO_TIME((duration/600 - FLOOR(duration/600))*3600), "%i")) AS Duration,
    person.last_name AS Nom, person.first_name AS "First name",
    l1.icao_name AS "Departure",
    l2.icao_name AS "Arrival",
    maintenanceUserComment.content AS "User remark",
    mechanicAnswer.content AS "Maintenance answer"
FROM flight 
LEFT JOIN resource ON resource.id = flight.aircraft_id
LEFT JOIN flight_pilot ON flight_pilot.flight_id = flight.id 
LEFT JOIN person ON person.id = flight_pilot.pilot_id 
LEFT JOIN location AS l1 ON l1.id = flight.departure_location_id
LEFT JOIN location AS l2 ON l2.id = flight.arrival_location_id
LEFT JOIN extra_field_content AS maintenanceUserComment ON maintenanceUserComment.category_id = flight.id
LEFT JOIN extra_field_content AS mechanicAnswer ON mechanicAnswer.category_id = flight.id
WHERE flight_pilot.num = 0
AND maintenanceUserComment.extra_field_id = (SELECT extra_field.id FROM extra_field WHERE (extra_field.variable = "maintenanceUserComment"))
AND mechanicAnswer.extra_field_id = (SELECT extra_field.id FROM extra_field WHERE (extra_field.variable = "mechanicAnswer"))
AND (maintenanceUserComment.content <> "" OR mechanicAnswer.content <> "")
AND start_date>DATE_SUB( NOW(), INTERVAL 3 MONTH )
GROUP BY flight.id;

Flight with their location code (ICAO)

SELECT flight.*, L1.icao_name AS departure_location, L2.icao_name AS arrival_location
FROM flight
LEFT JOIN location AS L1 ON flight.departure_location_id = L1.id
LEFT JOIN location AS L2 ON flight.arrival_location_id = L2.id

Fuel/Oil reports

Fuel/Oil consumption

Unit is: unit of the tank per hour

SELECT
    resource_name AS CallSign,
    CASE tank_type
        WHEN 1 THEN "AVGAS"
        WHEN 2 THEN "JET A1"
        WHEN 3 THEN "Oil"
        WHEN 4 THEN "SP95"
        WHEN 5 THEN "SP98"
        WHEN 6 THEN "GAZOLE"
    END AS Tank,
    formatDecimal( CAST(SUM(IF (month_num=1, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0)) AS DECIMAL(10,2) ) ) AS Janu,
    formatDecimal( CAST(SUM(IF (month_num=2, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0)) AS DECIMAL(10,2) ) ) AS Febr,
    formatDecimal( CAST(SUM(IF (month_num=3, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0))  AS DECIMAL(10,2) ) ) AS Marc,
    formatDecimal( CAST(SUM(IF (month_num=4, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0))  AS DECIMAL(10,2) ) ) AS Apri,
    formatDecimal( CAST(SUM(IF (month_num=5, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0))  AS DECIMAL(10,2) ) ) AS May,
    formatDecimal( CAST(SUM(IF (month_num=6, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0))  AS DECIMAL(10,2) ) ) AS June,
    formatDecimal( CAST(SUM(IF (month_num=7, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0))  AS DECIMAL(10,2) ) ) AS July,
    formatDecimal( CAST(SUM(IF (month_num=8, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0))  AS DECIMAL(10,2) ) ) AS Augu,
    formatDecimal( CAST(SUM(IF (month_num=9, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0))  AS DECIMAL(10,2) ) ) AS Sept,
    formatDecimal( CAST(SUM(IF (month_num=10, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0))  AS DECIMAL(10,2) ) ) AS Octo,
    formatDecimal( CAST(SUM(IF (month_num=11, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0))  AS DECIMAL(10,2) ) ) AS Nove,
    formatDecimal( CAST(SUM(IF (month_num=12, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0))  AS DECIMAL(10,2) ) ) AS Dece,
    formatDecimal( CAST(SUM(quantity)/(SELECT SUM(duration) FROM flight WHERE aircraft_id = resource.id AND YEAR (start_date) = $year)*600  AS DECIMAL(10,2) ) )  AS Sum
FROM
    (SELECT resource.name AS resource_name,
        resource.id AS resource_id,
        tank.tank_type_id AS tank_type,
        flight_tank_qty.quantity  AS quantity,
        MONTH(flight.start_date) AS month_num,
        (SELECT sum(flight.duration) FROM flight WHERE aircraft_id = resource_id AND YEAR(flight.start_date) = $year AND MONTH(flight.start_date) = month_num ) AS flight_time
    FROM tank
    LEFT JOIN flight_tank_qty ON flight_tank_qty.tank_id = tank.id
    LEFT JOIN flight ON flight.id = flight_tank_qty.flight_id
    LEFT JOIN resource ON resource.id = flight.aircraft_id
    WHERE YEAR(flight.start_date) = $year
) AS my_table
GROUP BY resource_name, tank_type

Fuel/Oil quantities per tank and aircraft type

SELECT
    aircraft_type_name AS CallSign, tank_label AS Tank,
    formatDecimal( SUM(IF (month_num=1, quantity, 0)) ) AS Janu,
    formatDecimal( SUM(IF (month_num=2, quantity, 0)) ) AS Febr,
    formatDecimal( SUM(IF (month_num=3, quantity, 0)) ) AS Marc,
    formatDecimal( SUM(IF (month_num=4, quantity, 0)) ) AS Apri,
    formatDecimal( SUM(IF (month_num=5, quantity, 0)) ) AS May,
    formatDecimal( SUM(IF (month_num=6, quantity, 0)) ) AS June,
    formatDecimal( SUM(IF (month_num=7, quantity, 0)) ) AS July,
    formatDecimal( SUM(IF (month_num=8, quantity, 0)) ) AS Augu,
    formatDecimal( SUM(IF (month_num=9, quantity, 0)) ) AS Sept,
    formatDecimal( SUM(IF (month_num=10, quantity, 0)) ) AS Octo,
    formatDecimal( SUM(IF (month_num=11, quantity, 0)) ) AS Nove,
    formatDecimal( SUM(IF (month_num=12, quantity, 0)) ) AS Dece,
    formatDecimal( SUM(quantity) ) AS Sum
FROM
(
    SELECT resource_type.id AS aircraft_type_id,
           resource_type.name AS aircraft_type_name,
           tank.id AS tank_id, tank.label AS tank_label,
           CAST( flight_tank_qty.quantity AS DECIMAL(10,2) ) AS quantity,
           MONTH(flight.start_date) AS month_num
    FROM tank
    LEFT JOIN resource_type ON ( resource_type.id = tank.aircraft_type_id )
    LEFT JOIN flight_tank_qty ON ( tank.id = flight_tank_qty.tank_id )
    LEFT JOIN flight ON (flight.id = flight_tank_qty.flight_id)
    WHERE YEAR(flight.start_date) = $year
) AS my_table
GROUP BY aircraft_type_id, tank_id

Fuel/Oil sum for each aircraft

Unit is: unit of the tank

SELECT
    resource_name AS CallSign,
    CASE tank_type
        WHEN 1 THEN "AVGAS"
        WHEN 2 THEN "JET A1"
        WHEN 3 THEN "Oil"
        WHEN 4 THEN "SP95"
        WHEN 5 THEN "SP98"
        WHEN 6 THEN "GAZOLE"
    END AS Tank,
    formatDecimal( SUM(IF (month_num=1, quantity, 0)) ) AS Janu,
    formatDecimal( SUM(IF (month_num=2, quantity, 0)) ) AS Febr,
    formatDecimal( SUM(IF (month_num=3, quantity, 0)) ) AS Marc,
    formatDecimal( SUM(IF (month_num=4, quantity, 0)) ) AS Apri,
    formatDecimal( SUM(IF (month_num=5, quantity, 0)) ) AS May,
    formatDecimal( SUM(IF (month_num=6, quantity, 0)) ) AS June,
    formatDecimal( SUM(IF (month_num=7, quantity, 0)) ) AS July,
    formatDecimal( SUM(IF (month_num=8, quantity, 0)) ) AS Augu,
    formatDecimal( SUM(IF (month_num=9, quantity, 0)) ) AS Sept,
    formatDecimal( SUM(IF (month_num=10, quantity, 0)) ) AS Octo,
    formatDecimal( SUM(IF (month_num=11, quantity, 0)) ) AS Nove,
    formatDecimal( SUM(IF (month_num=12, quantity, 0)) ) AS Dece,
    formatDecimal( SUM(quantity) ) AS Sum,
    formatDecimal( CAST(SUM(quantity)/(SELECT SUM(duration) FROM flight WHERE aircraft_id = resource_id AND YEAR (start_date) = $year)*600  AS DECIMAL(10,2) ) ) AS Consumption
FROM
    (SELECT resource.name AS resource_name,
        resource.id AS resource_id,
        tank.tank_type_id AS tank_type,
        CAST( flight_tank_qty.quantity AS DECIMAL(10,2) ) AS quantity,
        MONTH(flight.start_date) AS month_num
    FROM tank
    LEFT JOIN flight_tank_qty ON flight_tank_qty.tank_id = tank.id
    LEFT JOIN flight ON flight.id = flight_tank_qty.flight_id
    LEFT JOIN resource ON resource.id = flight.aircraft_id
    WHERE YEAR(flight.start_date) = $year
) AS my_table
GROUP BY resource_name, tank_type

Total tank quantity for each tank and for each aircraft

SELECT resource.name AS aircraft_callsign, tank.label AS tank_label, formatDecimal( SUM( quantity ) ) AS total_qty
FROM tank
LEFT JOIN resource_type ON ( resource_type.id = tank.aircraft_type_id )
LEFT JOIN flight_tank_qty ON ( tank.id = flight_tank_qty.tank_id )
LEFT JOIN flight ON (flight.id = flight_tank_qty.flight_id)
LEFT JOIN resource ON (flight.aircraft_id = resource.id)
WHERE YEAR(flight.start_date) = $year
GROUP BY resource.id, tank_type_id

Total tank quantity for each tank and for each aircraft type

SELECT resource_type.name AS aircraft_type, tank.label AS tank_label, formatDecimal( SUM( quantity ) ) AS total_qty
FROM tank
LEFT JOIN resource_type ON ( resource_type.id = tank.aircraft_type_id )
LEFT JOIN flight_tank_qty ON ( tank.id = flight_tank_qty.tank_id )
LEFT JOIN flight ON (flight.id = flight_tank_qty.flight_id)
WHERE YEAR(flight.start_date) = $year
GROUP BY aircraft_type_id, tank_type_id

Error message queries

Flight without account movement

SELECT 
DATE_FORMAT(flight.start_date,'%d/%m/%Y' ) AS Date,
TIME_FORMAT(flight.start_date,'%H:%i' ) AS Time,
resource.name AS Callsign,
person.last_name AS Lastname,
person.first_name AS Firstname,
CONCAT(FLOOR( flight.duration /600),':',
TIME_FORMAT(SEC_TO_TIME(( flight.duration/600 - FLOOR( flight.duration /600))*3600),'%i'))
AS FlightTime
FROM flight 
LEFT JOIN flight_account_entry ON flight.id=flight_account_entry.flight_id
LEFT JOIN resource ON resource.id=flight.aircraft_id
LEFT JOIN flight_pilot ON flight_pilot.flight_id=flight.id
LEFT JOIN person ON person.id=flight_pilot.pilot_id
WHERE
flight_account_entry.account_entry_id IS NULL
AND flight.airborne=0
AND flight_pilot.num=0

movement without an account

SELECT id,flow_id,account_date,credit,debit,payment_description,comments FROM account_entry WHERE account_id is null
SELECT id,flow_id,account_date,credit,debit,payment_description,comments FROM account_entry WHERE flow_id = 'xxxxxx'

Users

Users exports SQL queries.