Export generator 4: Difference between revisions
No edit summary |
|||
Line 1,255: | Line 1,255: | ||
GROUP BY resource.id</sql> | GROUP BY resource.id</sql> | ||
==Flight between | ==Flight between date== | ||
Following variables are needed: | Following variables are needed: | ||
*startDate (Type : Datetime) | *startDate (Type : Datetime) |
Revision as of 18:43, 8 October 2024
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.
Business field
For more flexibility, business field can be defined by the user.
Two business field types are available:
- "external parameters" of following types:
- Date
- Date and time
- Month
- Text string
- Time
- Whole number
- Year
- database parameters (dbObject::something or dbObjectMulti::something Value type) advanced options to access to the database field
Business field creation
- Go to Menu Admin > Reports > Custom reports > Business 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::Person) 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.
Business field creation examples
We create a new business field for the current year:
- Name: $year
- Label: Year
- Value type: Year
Parameter Year must be filled in Reports/View form before to call the query (by default current year is filled when you call the page)
We create a new business field to list the reservation of a resource:
- Name: $resourceId
- Label: Resource
- Value type: dbObject::Resource
Then in Admin/Reports we create a new query labeled "Aircraft booking" with the following query: <syntaxhighlight lang="sql">SELECT * FROM booking WHERE booking.resource_id=$resourceId</sql> To use this report, we just have to select a "Resource" in the Reports/View form, to check "Resource 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: <syntaxhighlight lang="sql">SELECT * FROM `variable_value` WHERE variable_id=1 ORDER BY start_date DESC LIMIT 1</sql>
Return a user list telling if each user has a profile A, B, C, etc.
<syntaxhighlight lang="sql">SELECT
person.first_name, person.last_name, IF(person.profile & 1, 'Yes', 'No') AS 'Profile A', IF(person.profile & 2, 'Yes', 'No') AS 'Profile B', IF(person.profile & 4, 'Yes', 'No') AS 'Profile C'
FROM person WHERE activated=1;</sql>
Return the whole content of a given table
Example with table "profile" <syntaxhighlight lang="sql">SELECT * FROM profile;</sql>
This type of SELECT does not work within OpenFlyers to access restricted table like the person table
Test valid entries
For business 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) :
<syntaxhighlight lang="sql">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
)</sql>
French administration Examples
Flight hours total on instruction with specific activity type/profile
Requirement:
- Variable $activityTypeId of dbOjectMulti::ActivityType value type
- Variable $profileId of dbOjectMulti::Profile value type
- Variable $year of Year value type
<syntaxhighlight lang="sql">SELECT tmp_flight.activity_type_name AS 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 flightWithActivityType.activity_type_id, flightWithActivityType.activity_type_name, flightWithActivityType.duration, resource_type.category FROM ( SELECT flight.id, flight.duration, flight.aircraft_id, activity_type.id AS activity_type_id, activity_type.name AS activity_type_name FROM flight LEFT JOIN activity_type ON flight.activity_type_id&activity_type.id WHERE YEAR(flight.start_date)=$year AND flight.airborne=0 AND ( activity_type.id IN ($activityTypeId) OR IN ($activityTypeId) ) ) AS flightWithActivityType LEFT JOIN flight_pilot ON (flight_pilot.flight_id=flightWithActivityType.id AND flight_pilot.num=1) LEFT JOIN ( SELECT person.* FROM person LEFT JOIN profile ON person.profile&profile.id WHERE ( profile.id IN ($profileId) OR IN ($profileId) ) AND person.activated=1 GROUP BY person.id ) AS personWithProfile ON (personWithProfile.id=flight_pilot.pilot_id) LEFT JOIN resource ON (resource.id=flightWithActivityType.aircraft_id) LEFT JOIN resource_type ON (resource_type.id=resource.resource_type_id) WHERE personWithProfile.id IS NOT NULL
) AS tmp_flight GROUP BY tmp_flight.activity_type_id</sql>
Flight hours total on non-instruction with specific activity type/profile
Requirement:
- Variable $activityTypeId of dbOjectMulti::ActivityType value type
- Variable $profileId of dbOjectMulti::Profile value type
- Variable $year of Year value type
<syntaxhighlight lang="sql">SELECT tmp_flight.activity_type_name AS 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 flightWithActivityType.activity_type_id, flightWithActivityType.activity_type_name, flightWithActivityType.duration, resource_type.category FROM ( SELECT flight.id, flight.duration, flight.aircraft_id, activity_type.id AS activity_type_id, activity_type.name AS activity_type_name FROM flight LEFT JOIN activity_type ON flight.activity_type_id&activity_type.id WHERE YEAR(flight.start_date)=$year AND flight.airborne=0 AND ( activity_type.id IN ($activityTypeId) OR IN ($activityTypeId) ) AND flight.id NOT IN (SELECT flight_id FROM flight_pilot WHERE num=1) ) AS flightWithActivityType LEFT JOIN flight_pilot ON (flight_pilot.flight_id=flightWithActivityType.id AND flight_pilot.num=0) LEFT JOIN ( SELECT person.* FROM person LEFT JOIN profile ON person.profile&profile.id WHERE ( profile.id IN ($profileId) OR IN ($profileId) ) AND person.activated=1 GROUP BY person.id ) AS personWithProfile ON (personWithProfile.id=flight_pilot.pilot_id) LEFT JOIN resource ON (resource.id=flightWithActivityType.aircraft_id) LEFT JOIN resource_type ON (resource_type.id=resource.resource_type_id) WHERE personWithProfile.id IS NOT NULL
) AS tmp_flight GROUP BY tmp_flight.activity_type_id</sql>
Users with a specific validity without expiration date
- Variable $validityId should be defined first and should be of dbOjectMulti::ValidityType value type.
<syntaxhighlight lang="sql">SELECT person.first_name, person.last_name, validity_type.name AS 'Validite' FROM validity LEFT JOIN validity_type ON validity.validity_type_id=validity_type.id LEFT JOIN person ON person.id=validity.person_id WHERE ( validity_type_id IN ($validityTypeId) OR '-' IN ($validityTypeId) )
AND expire_date IS NULL AND person.activated=1</sql>
Number of landings at the base airfield
<syntaxhighlight lang="sql">SELECT only_base.sum AS _tr(FLIGHT_LANDING_NUMBER_WITH_TAKEOFF_AND_LANDING_AT_THE_BASE), all_landing.sum AS _tr(REPORT_NUMBER_LANDING_BASED_AIRFIELD) FROM (SELECT SUM(flight.landing_number) AS sum FROM flight, structure WHERE ( flight.departure_icao_id = structure.icao ) AND ( flight.arrival_icao_id = structure.icao ) AND YEAR(start_date) = $year) AS only_base,
(SELECT SUM(flight.landing_number) AS sum FROM flight, structure WHERE ( flight.arrival_icao_id = structure.icao ) AND YEAR(start_date) = $year) AS all_landing;</sql>
Number of movements on based airfield
- Variable $year should be defined first and should be of Year value type.
<syntaxhighlight lang="sql">SELECT SUM(movement) AS 'Movement' FROM (
SELECT COUNT(*) AS movement FROM flight, structure WHERE ( ( flight.departure_icao_id != structure.icao ) OR( flight.arrival_icao_id != structure.icao ) ) AND( flight.departure_icao_id != structure.icao ) AND YEAR(start_date) = $year UNION SELECT SUM(landing_number) * 2 AS movement FROM flight, structure WHERE YEAR(flight.start_date) = $year AND flight.departure_icao_id = structure.icao AND flight.arrival_icao_id = structure.icao
) AS tmp_movement</sql>
Number of movements on based airfield on specific profile
- Variable $profileId should be defined first and should be of dbOjectMulti::Profile value type.
- Variable $year should be defined first and should be of Year value type.
<syntaxhighlight lang="sql">SELECT SUM(movement) AS 'Movement'
FROM ( SELECT COUNT(*) AS movement FROM structure, flight LEFT JOIN flight_pilot ON (flight_pilot.flight_id=flight.id) LEFT JOIN ( SELECT person.* FROM person LEFT JOIN profile ON person.profile&profile.id WHERE ( profile.id IN ($profileId) OR IN ($profileId) ) AND person.activated=1 GROUP BY person.id ) AS personWithProfile ON (personWithProfile.id=flight_pilot.pilot_id AND flight_pilot.num=0) WHERE ( ( flight.departure_icao_id != structure.icao) OR ( flight.arrival_icao_id != structure.icao) ) AND ( flight.departure_icao_id != structure.icao) AND YEAR(flight.start_date) = 2019 AND personWithProfile.id IS NOT NULL UNION
SELECT SUM(flight.landing_number)*2 AS movement
FROM structure, flight LEFT JOIN flight_pilot ON (flight_pilot.flight_id=flight.id) LEFT JOIN ( SELECT person.* FROM person LEFT JOIN profile ON person.profile&profile.id WHERE ( profile.id IN ($profileId) OR IN ($profileId) ) AND person.activated=1 GROUP BY person.id ) AS personWithProfile ON (personWithProfile.id=flight_pilot.pilot_id AND flight_pilot.num=0) WHERE YEAR(flight.start_date) = $year AND flight.departure_icao_id = structure.icao AND flight.arrival_icao_id = structure.icao AND personWithProfile.id IS NOT NULL ) AS tmp_movement</sql>
Number of take-off and landings on based airfield on specific profile
- Variable $profileId should be defined first and should be of dbOjectMulti::Profile value type.
- Variable $year should be defined first and should be of Year value type.
<syntaxhighlight lang="sql">SELECT SUM(flight.landing_number) * 2 AS 'Movement' FROM structure, flight LEFT JOIN flight_pilot ON ( flight_pilot.flight_id = flight.id ) LEFT JOIN (
SELECT person.* FROM person LEFT JOIN profile ON person.profile & profile.id WHERE (profile.id IN($profileId) OR '-' IN($profileId)) AND person.activated = 1 GROUP BY person.id
) AS personWithProfile ON ( personWithProfile.id = flight_pilot.pilot_id AND flight_pilot.num = 0 ) WHERE personWithProfile.id IS NOT NULL AND YEAR(flight.start_date) = $year AND flight.departure_icao_id = structure.icao AND flight.arrival_icao_id = structure.icao</sql>
List of movements on based airfield
<syntaxhighlight lang="sql">SELECT location.icao_name AS ICAO, location.name AS NAME, COUNT(location.icao_name) AS nb_flight FROM structure, flight LEFT JOIN location ON flight.departure_icao_id = location.icao_name WHERE ( flight.departure_icao_id = structure.icao ) OR( flight.arrival_icao_id = structure.icao ) AND departure_icao_id != arrival_icao_id AND YEAR(start_date) = $year GROUP BY icao_name ORDER BY nb_flight DESC </sql>
User flying without validity
<syntaxhighlight lang="sql">SELECT
CONCAT(person.last_name, ' ', person.first_name) AS _tr(PILOT), validity_type.name AS _tr(VALIDITY)
FROM flight_type_mandatory_validity_type LEFT JOIN activity_type ON activity_type.id = flight_type_mandatory_validity_type.activity_type_id LEFT JOIN flight ON flight.activity_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 AND validity.is_current_validity = 1 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 AND validity_type.activated = 1
GROUP BY person.id, validity_type.id ORDER BY `_tr(PILOT)`, validity_type.name</sql>
List of pilots who have flown less than X hours during last Y days
<syntaxhighlight lang="sql">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</sql>
List of pilots who have flown less than X hours during last Y days on aircraft type Z
<syntaxhighlight lang="sql"> 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</sql>
Pilots without flight in the last X months
- Variable $numberMonth should be defined first and should be of integer value type.
<syntaxhighlight lang="sql">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($numberMonth=, 1, $numberMonth*30) DAY AND NOW() GROUP BY person2.id HAVING SUM(f.duration)/600 > 0
) ORDER BY person.last_name, person.first_name</sql>
Total user per age profile validity: Number of men, women over and under X years for profile P, validity V up to date for year A
- Variable $age should be of integer value type.
- Variable $profileId should be of dbOjectMulti::Profile value type.
- Variable $validityTypeId should be of dbObjectMulti::validityType value type.
- Variable $year should be of Year value type.
<syntaxhighlight lang="sql">SELECT
IF( personWithProfile.sex=0, _tr(SEX_MALE_INITIAL), IF( personWithProfile.sex=1, _tr(SEX_FEMALE_INITIAL), _tr(UNDEFINED)) ) AS _tr(SEX), IF( ( $year - YEAR(birthdate) >= $age ) , _tr(YES), _tr(NO)) AS _tr(ADULT), COUNT(DISTINCT personWithProfile.id) AS _tr(NUMBER)
FROM (
SELECT person.* FROM person LEFT JOIN profile ON person.profile&profile.id WHERE ( profile.id IN ($profileId) OR '-' IN ($profileId) ) AND person.activated=1
) AS personWithProfile LEFT JOIN validity ON personWithProfile.id = validity.person_id AND validity.is_current_validity = 1 LEFT JOIN validity_type ON (validity_type.id=validity.validity_type_id) WHERE ((validity_type.id IN ($validityTypeId) AND validity.expire_date >= '$year-12-31') OR '-' IN ($validityTypeId))
AND validity_type.activated = 1
GROUP BY `_tr(SEX)`, `_tr(ADULT)`</sql>
Number of landings per pilot, per resource
<syntaxhighlight lang="sql">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</sql>
Flight hours without up to date validities
- Variable $year
<syntaxhighlight lang="sql">SELECT
DATE_FORMAT(start_date, '%d %m %Y' ) AS _tr(DATE), CONCAT(person.last_name, ' ', person.first_name) AS _tr(FULL_NAME), IF ( (SELECT COUNT(*) FROM flight_pilot AS tmp_flight_pilot WHERE flight_pilot.flight_id=tmp_flight_pilot.flight_id AND tmp_flight_pilot.num=1)=0, 'Solo', 'DC' ) AS DC, resource.name AS _tr(RESOURCE), sexa2HoursMinute(duration) AS _tr(DURATION), activity_type.name AS _tr(ACTIVITY_TYPE), validity_type.name AS _tr(VALIDITY)
FROM flight LEFT JOIN flight_type_mandatory_validity_type ON flight_type_mandatory_validity_type.activity_type_id & flight.activity_type_id LEFT JOIN flight_pilot ON flight.id = flight_pilot.flight_id LEFT JOIN person ON flight_pilot.pilot_id = person.id LEFT JOIN validity_type ON flight_type_mandatory_validity_type.validity_type_id = validity_type.id LEFT JOIN validity ON flight_type_mandatory_validity_type.validity_type_id = validity.validity_type_id AND validity.is_current_validity = 1 LEFT JOIN resource ON flight.aircraft_id = resource.id LEFT JOIN activity_type ON flight_type_mandatory_validity_type.activity_type_id = activity_type.id WHERE YEAR(start_date) = $year
AND flight_pilot.num = 0 AND validity_type.time_limitation=1 AND validity.person_id = flight_pilot.pilot_id AND flight.start_date > validity.expire_date AND person.activated = 1 AND validity_type.activated = 1
ORDER BY flight.start_date, `_tr(FULL_NAME)`, validity_type.name</sql>
Number of men, women over and under 21 years for profile X, validity Y up to date for year Z
- Variable $age should be of integer value type.
- Variable $profileId should be of dbOjectMulti::Profile value type.
- Variable $validityTypeId should be of dbObjectMulti::validityType value type.
- Variable $year should be of Year value type.
<syntaxhighlight lang="sql">SELECT
IF( person.sex=0, 'Male', IF( person.sex=1, 'Female', 'Undefined') ) AS 'Sex', IF( ( $year - YEAR(birthdate) >= '$age' ) , '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' AND validity.expire_date >= '$year-12-31') OR '-'='$validityTypeId' )
GROUP BY Sex, Adult</sql>
Total hours by activities and resource categories for an instructor for one year
- Variable $personId should be defined first and should be of dbOjectMulti::Person value type.
- Variable $year should be defined first and should be of Year value type.
<syntaxhighlight lang="sql">SELECT tmp_flight.activity_type_name AS name,
sexa2HoursMinute(SUM(IF(category=1, duration, 0))) AS _tr(AIRCRAFT_CATEGORY), sexa2HoursMinute(SUM(IF(category=18, duration, 0))) AS _tr(HELICOPTER_CATEGORY), sexa2HoursMinute(SUM(IF(category=19, duration, 0))) AS _tr(GLIDER_CATEGORY), sexa2HoursMinute(SUM(IF(category=17, duration, 0))) AS _tr(ULTRA_LIGHT_CATEGORY), sexa2HoursMinute(SUM(IF(category=9, duration, 0))) AS _tr(CLASSROOM_CATEGORY)
FROM (
SELECT flightWithActivityType.activity_type_id, flightWithActivityType.activity_type_name, flightWithActivityType.duration, resource_type.category FROM ( SELECT flight.id, flight.duration, flight.aircraft_id, activity_type.id AS activity_type_id, activity_type.name AS activity_type_name FROM flight LEFT JOIN activity_type ON flight.activity_type_id&activity_type.id LEFT JOIN flight_pilot ON (flight_pilot.flight_id=flight.id AND flight_pilot.num=1) WHERE YEAR(flight.start_date)=$year AND flight.airborne=0 AND flight_pilot.pilot_id=$personId ) AS flightWithActivityType LEFT JOIN resource ON (resource.id=flightWithActivityType.aircraft_id) LEFT JOIN resource_type ON (resource_type.id=resource.resource_type_id)
) AS tmp_flight GROUP BY tmp_flight.activity_type_id</sql>
Validity year young specific profile: Total of youngs/adults with specific profile
- Variable $profileId should be defined first and should be of dbOjectMulti::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.
<syntaxhighlight lang="sql">SELECT
validity_type.name AS '_tr(VALIDITY)', SUM( IF( ( $year - YEAR(personWithProfile.birthdate) < 21 ), 1, 0 ) ) AS '_tr(YOUNG)', SUM( IF( ( $year - YEAR(personWithProfile.birthdate) >= 21 ), 1, 0 ) ) AS '_tr(ADULT)'
FROM validity_type LEFT JOIN validity ON validity.validity_type_id = validity_type.id AND validity.is_current_validity = 1 LEFT JOIN (
SELECT person.* FROM person LEFT JOIN profile ON person.profile&profile.id WHERE ( profile.id IN ($profileId) OR '-' IN ($profileId) ) AND person.activated=1 GROUP BY person.id
) AS personWithProfile ON (validity.person_id=personWithProfile.id) WHERE YEAR(validity.grant_date)=$year
AND personWithProfile.id IS NOT NULL AND validity_type.activated = 1
GROUP BY validity_type.id ORDER BY validity_type.name</sql>
Validities obtained in the year
- Variable $validityId should be defined first and should be of dbOjectMulti::ValidityType value type.
- 21 value is the age limit to be young. Should be changed according local rules
<syntaxhighlight lang="sql">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 IN ($validityTypeId) OR '-' IN ($validityTypeId) ) AND person.activated=1
ORDER BY last_name, first_name</sql>
Visited airfields
<syntaxhighlight lang="sql">SELECT location.icao_name AS ICAO, location.name AS NAME, COUNT(location.icao_name) AS Visit FROM structure, flight LEFT JOIN location ON ( flight.departure_icao_id = location.icao_name ) WHERE ( ( flight.departure_icao_id != structure.icao ) OR ( flight.arrival_icao_id != structure.icao ) ) AND YEAR(start_date) = $year GROUP BY location.icao_name ORDER BY Visit DESC</sql>
Visited outsider airfield
<syntaxhighlight lang="sql">SELECT location.icao_name AS ICAO, location.name AS Name, COUNT(location.icao_name) AS nb_visite FROM structure, flight LEFT JOIN location ON ( flight.departure_icao_id = location.icao_name ) WHERE ( ( flight.departure_icao_id !=structure.icao ) OR( flight.arrival_icao_id !=structure.icao ) ) AND YEAR(start_date) = $year GROUP BY location.icao_name ORDER BY nb_visite DESC</sql>
Young from this year
<syntaxhighlight lang="sql">SELECT
CONCAT( '[LINK=index.php[QUESTION_MARK]menuAction=admin_add_modify_user&menuParameter=',person.id,'&menuParameterBis=last_name&menuParameter3=', LEFT(person.last_name, 1),']', person.id, '[/LINK]' ) AS _tr(ID), person.first_name AS _tr(FIRST_NAME), person.last_name AS _tr(LAST_NAME), DATE_FORMAT(birthdate ,'%m-%d-%Y') AS _tr(USER_BIRTHDATE), IF ( sex = 0, _tr(SEX_MALE), _tr(SEX_FEMALE) ) AS _tr(USER_SEX)
FROM person WHERE ($year-YEAR(birthdate))<=$age AND activated=1</sql>
Accounting exports
Bookings
Booking
- Variable $endDate of Date and time value type.
- Variable $startDate of Date and time value type.
- Variable $personId of dbObject::Person value type.
- Variable $resourceId of dbObject::Resource value type.
<syntaxhighlight lang="sql">[OF_DYNAMIC_SQL] SELECT CONCAT( 'SELECT booking.id AS _tr(ID), DATE_FORMAT(booking.start_date, \'%Y-%m-%d %H:%i\') AS _tr(START_DATE), DATE_FORMAT(booking.end_date, \'%Y-%m-%d %H:%i\') AS _tr(END_DATE), (
SELECT GROUP_CONCAT( activity_type.name SEPARATOR \', \') FROM booking_activity_type LEFT JOIN activity_type ON (booking_activity_type.activity_type_id = activity_type.id) WHERE booking_activity_type.booking_id=booking.id
) AS _tr(ACTIVITY_TYPE), resource.name AS _tr(RESOURCE), left_booking_person.full_name AS _tr(LEFT_PLACE), left_booking_person.email AS tr(EMAIL), left_booking_person.cellPhone AS _tr(PHONE), left_booking_person.birthDate AS _tr(BIRTHDATE), right_booking_person.full_name AS _tr(RIGHT_PLACE),
', IFNULL(GROUP_CONCAT( CONCAT( ' (SELECT business_field_content.content FROM business_field_content WHERE booking.id=business_field_content.category_id AND business_field_content.business_field_id=', business_field.id, ' LIMIT 1) AS \, REPLACE(business_field.label, '\, '\\\), '\ ) ORDER BY business_field.order_num
), '\'_\), ' FROM booking LEFT JOIN booking_resource ON (booking.id=booking_resource.booking_id) LEFT JOIN resource ON (resource.id=booking_resource.resource_id) LEFT JOIN (
SELECT booking_person.booking_id, booking_person.person_id, CONCAT(person.last_name, \' \', person.first_name) AS full_name,
person.email AS email, person.cell_phone AS cellPhone, person.birthdate AS birthDate
FROM booking_person LEFT JOIN person ON (person.id=booking_person.person_id) WHERE booking_person.place_num=0 AND person.activated=1
) AS left_booking_person ON (booking.id=left_booking_person.booking_id) LEFT JOIN (
SELECT booking_person.booking_id, booking_person.person_id, CONCAT(person.last_name, \' \', person.first_name) AS full_name FROM booking_person LEFT JOIN person ON (person.id=booking_person.person_id) WHERE booking_person.place_num=1 AND person.activated=1
) AS right_booking_person ON (booking.id=right_booking_person.booking_id) WHERE booking.start_date >= $startDate AND booking.end_date < $endDate
AND (booking_resource.resource_id=$resourceId OR \'\'=$resourceId) AND ( left_booking_person.person_id=$personId OR right_booking_person.person_id=$personId OR \'\'=$personId )
ORDER BY booking.start_date, booking.end_date' ) FROM business_field WHERE business_field.category='BOOKING' AND business_field.user_access_mode!=2</sql>
Cumulated maintenance hours on a period
Following extrafields are needed :
- startDate (Type : Date)
- endDate (Type : Date or DateTime)
<syntaxhighlight lang="sql">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</sql>
Maintenance hours per resource on a period
Following extrafields are needed :
- startDate (Type : Date)
- endDate (Type : Date or DateTime)
<syntaxhighlight lang="sql">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</sql>
Booking for maintenance ordered by resource and date with name of the responsible
<syntaxhighlight lang="sql">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</sql>
Flight time management
Flight hours total and last recorded counters to the date X
- Variable $endDate should be of Datetime value type.
<syntaxhighlight lang="sql">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</sql>
Flight hours per month
<syntaxhighlight lang="sql">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</sql>
Flight hours total over a 12 months period
<syntaxhighlight lang="sql">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</sql>
Flights hours total per aircraft per year
<syntaxhighlight lang="sql">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</sql>
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.
<syntaxhighlight lang="sql">SELECT aircraft_id AS _tr(IDENT), resource.name AS _tr(RESOURCE_NAME),
sexa2HoursMinute( SUM( IF( MONTH(start_date)=1, duration, 0 ) ) ) AS _tr(MONTH_JAN_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=2, duration, 0 ) ) ) AS _tr(MONTH_FEB_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=3, duration, 0 ) ) ) AS _tr(MONTH_MAR_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=4, duration, 0 ) ) ) AS _tr(MONTH_APR_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=5, duration, 0 ) ) ) AS _tr(MONTH_MAY_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=6, duration, 0 ) ) ) AS _tr(MONTH_JUN_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=7, duration, 0 ) ) ) AS _tr(MONTH_JUL_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=8, duration, 0 ) ) ) AS _tr(MONTH_AUG_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=9, duration, 0 ) ) ) AS _tr(MONTH_SEP_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=10, duration, 0 ) ) ) AS _tr(MONTH_OCT_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=11, duration, 0 ) ) ) AS _tr(MONTH_NOV_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=12, duration, 0 ) ) ) AS _tr(MONTH_DEC_ABBR), sexa2HoursMinute( SUM( duration ) ) AS _tr(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.activity_type_id & $activityTypeId OR =$activityTypeId)
GROUP BY resource.id</sql>
Flights hours total per aircraft, per year and per month (for a given type of activity and profile)
- 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.
- Variable $occupiedSeat represent the seat number of the person in the flight, can have following values (0: left place, 1: right place, : both)
- Variable $profileId of dbOjectMulti::Profile value type
<syntaxhighlight lang="sql">SELECT aircraft_id AS _tr(IDENT), resourceName AS _tr(RESOURCE_NAME), profileName as _tr(PROFILE),
sexa2HoursMinute( SUM( IF( MONTH(start_date)=1, duration, 0 ) ) ) AS _tr(MONTH_JAN_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=2, duration, 0 ) ) ) AS _tr(MONTH_FEB_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=3, duration, 0 ) ) ) AS _tr(MONTH_MAR_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=4, duration, 0 ) ) ) AS _tr(MONTH_APR_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=5, duration, 0 ) ) ) AS _tr(MONTH_MAY_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=6, duration, 0 ) ) ) AS _tr(MONTH_JUN_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=7, duration, 0 ) ) ) AS _tr(MONTH_JUL_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=8, duration, 0 ) ) ) AS _tr(MONTH_AUG_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=9, duration, 0 ) ) ) AS _tr(MONTH_SEP_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=10, duration, 0 ) ) ) AS _tr(MONTH_OCT_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=11, duration, 0 ) ) ) AS _tr(MONTH_NOV_ABBR), sexa2HoursMinute( SUM( IF( MONTH(start_date)=12, duration, 0 ) ) ) AS _tr(MONTH_DEC_ABBR), sexa2HoursMinute( SUM( duration ) ) AS _tr(SUM)
FROM ( SELECT flight.aircraft_id, resource.name AS resourceName, flight.duration, flight.start_date, profile.name AS profileName FROM flight LEFT JOIN flight_pilot ON flight_pilot.flight_id=flight.id LEFT JOIN person ON person.id=flight_pilot.pilot_id LEFT JOIN profile ON person.profile&profile.id 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.activity_type_id & $activityTypeId OR =$activityTypeId) AND ( profile.id IN ($profileId) OR '-' IN ($profileId) ) AND (IF((('$occupiedSeat'=0) OR ('$occupiedSeat'=)), 0, -1) = flight_pilot.num
OR IF((('$occupiedSeat'=1) OR ('$occupiedSeat'=)), 1, -1) = flight_pilot.num)
AND person.activated=1 GROUP BY resourceName, profileName, flight.id ) AS flightTmp GROUP BY resourceName, profileName</sql>
Flight hours total per pilot
<syntaxhighlight lang="sql">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</sql>
Flight hours total per pilot per profile
<syntaxhighlight lang="sql">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</sql>
Total Flight hours per pilot with total
Following extrafields are needed
- year (Type : Year)
- month (Type : Integer) OR startDate and endDate (Type : Date)
- $occupiedSeat (Type : Integer)
- profileId (Type : dbObjectMulti::Profile)
This report is useful for a group of pilots from a common customer (like DGAC in France)
<syntaxhighlight lang="sql">SELECT CONCAT(person.last_name,' ',person.first_name) AS _tr(FULL_NAME), CONCAT(FLOOR(SUM( flight.duration )/600),':',TIME_FORMAT(SEC_TO_TIME((SUM( flight.duration )/600 - FLOOR(SUM( flight.duration )/600))*3600),'%i')) AS _tr(TOTAL_FLIGHT_TIME), SUM(account_entry.debit) - SUM(account_entry.credit) AS _tr(TOTAL_AMOUNT_ACTIVITIES) FROM flight RIGHT JOIN flight_pilot ON flight_pilot.flight_id=flight.id
AND (IF((($occupiedSeat=0) OR ($occupiedSeat=)), 0, -1) = flight_pilot.num OR IF((($occupiedSeat=1) OR ($occupiedSeat=)), 1, -1) = flight_pilot.num)
RIGHT JOIN person ON person.id=flight_pilot.pilot_id RIGHT JOIN profile ON profile.id&person.profile
AND ( profile.id IN ($profileId) OR '-' IN ($profileId) )
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 (account.category = 11 OR account.category = 2) GROUP BY person.id</sql>
Flight hours per instructor, month (for a flight type)
Following extrafields are needed :
- year (Type : Year)
- activityTypeId (Type : dbObject::FlightType)
<syntaxhighlight lang="sql">SELECT
CONCAT(UPPER(person.last_name), ' ', person.first_name) AS _tr(LAST_NAME), (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 = person.id AND flight_pilot.num = 1 AND ( flight.activity_type_id & $activityTypeId != 0 OR =$activityTypeId ) ) AS _tr(MONTH_JANUARY), (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 = person.id AND flight_pilot.num = 1 AND ( flight.activity_type_id & $activityTypeId != 0 OR =$activityTypeId ) ) AS _tr(MONTH_FEBRUARY), (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 = person.id AND flight_pilot.num = 1 AND ( flight.activity_type_id & $activityTypeId != 0 OR =$activityTypeId ) ) AS _tr(MONTH_MARCH), (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 = person.id AND flight_pilot.num = 1 AND ( flight.activity_type_id & $activityTypeId != 0 OR =$activityTypeId ) ) AS _tr(MONTH_APRIL), (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 = person.id AND flight_pilot.num = 1 AND ( flight.activity_type_id & $activityTypeId != 0 OR =$activityTypeId ) ) AS _tr(MONTH_MAY), (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 = person.id AND flight_pilot.num = 1 AND ( flight.activity_type_id & $activityTypeId != 0 OR =$activityTypeId ) ) AS _tr(MONTH_JUN), (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 = person.id AND flight_pilot.num = 1 AND ( flight.activity_type_id & $activityTypeId != 0 OR =$activityTypeId ) ) AS _tr(MONTH_JULY), (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 = person.id AND flight_pilot.num = 1 AND ( flight.activity_type_id & $activityTypeId != 0 OR =$activityTypeId ) ) AS _tr(MONTH_AUGUST), (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 = person.id AND flight_pilot.num = 1 AND ( flight.activity_type_id & $activityTypeId != 0 OR =$activityTypeId ) ) AS _tr(MONTH_SEPTEMBER), (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 = person.id AND flight_pilot.num = 1 AND ( flight.activity_type_id & $activityTypeId != 0 OR =$activityTypeId ) ) AS _tr(MONTH_OCTOBER), (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 = person.id AND flight_pilot.num = 1 AND ( flight.activity_type_id & $activityTypeId != 0 OR =$activityTypeId ) ) AS _tr(MONTH_NOVEMBER), (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 = person.id AND flight_pilot.num = 1 AND ( flight.activity_type_id & $activityTypeId != 0 OR =$activityTypeId ) ) AS _tr(MONTH_DECEMBER), sexa2HoursMinute( SUM( duration ) ) AS _tr(TOTAL)
FROM flight LEFT JOIN flight_pilot fp ON fp.flight_id = flight.id LEFT JOIN person ON person.id=fp.pilot_id WHERE flight.airborne=0
AND person.activated=1 AND fp.num = 1 AND YEAR( start_date ) = $year AND ( flight.activity_type_id & $activityTypeId OR =$activityTypeId )
GROUP BY person.id</sql>
Flights hours following nationality
<SQL>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</SQL>
Flights hours total per flight type per month
<syntaxhighlight lang="sql">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.activity_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</sql>
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 dbOjectMulti::Profile value type.
- Variable $year should be defined first and should be of Year value type.
<syntaxhighlight lang="sql">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 profile ON person.profile&profile.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 ( profile.id IN ($profileId) OR '-' IN ($profileId) ) AND person.activated=1 GROUP BY flight.id
) AS tmp_stat GROUP BY Sex, Young, Instruction WITH ROLLUP</sql>
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 <syntaxhighlight lang="sql">SELECT flight.aircraft_id AS Num, name AS Immat,
( SELECT CONCAT( FLOOR(SUM(flight.duration) / 600), ':', TIME_FORMAT( SEC_TO_TIME( ( SUM(flight.duration) / 600 - FLOOR(SUM(flight.duration) / 600) ) * 3600 ), '%i' ) ) FROM flight WHERE YEAR(flight.start_date) = $year AND MONTH(flight.start_date) = 1 AND flight.aircraft_id = Num AND flight.departure_icao_id = flight.arrival_icao_id AND flight.duration < 90 * 600 ) AS Janv, ( SELECT CONCAT( FLOOR(SUM(flight.duration) / 600), ':', TIME_FORMAT( SEC_TO_TIME( ( SUM(flight.duration) / 600 - FLOOR(SUM(flight.duration) / 600) ) * 3600 ), '%i' ) ) FROM flight WHERE YEAR(flight.start_date) = $year AND MONTH(flight.start_date) = 2 AND flight.aircraft_id = Num AND flight.departure_icao_id = flight.arrival_icao_id AND flight.duration < 90 * 600 ) AS Fevr, ( SELECT CONCAT( FLOOR(SUM(flight.duration) / 600), ':', TIME_FORMAT( SEC_TO_TIME( ( SUM(flight.duration) / 600 - FLOOR(SUM(flight.duration) / 600) ) * 3600 ), '%i' ) ) FROM flight WHERE YEAR(flight.start_date) = $year AND MONTH(flight.start_date) = 3 AND flight.aircraft_id = Num AND flight.departure_icao_id = flight.arrival_icao_id AND flight.duration < 90 * 600 ) AS Mars, ( SELECT CONCAT( FLOOR(SUM(flight.duration) / 600), ':', TIME_FORMAT( SEC_TO_TIME( ( SUM(flight.duration) / 600 - FLOOR(SUM(flight.duration) / 600) ) * 3600 ), '%i' ) ) FROM flight WHERE YEAR(flight.start_date) = $year AND MONTH(flight.start_date) = 4 AND flight.aircraft_id = Num AND flight.departure_icao_id = flight.arrival_icao_id AND flight.duration < 90 * 600 ) AS Avri, ( SELECT CONCAT( FLOOR(SUM(flight.duration) / 600), ':', TIME_FORMAT( SEC_TO_TIME( ( SUM(flight.duration) / 600 - FLOOR(SUM(flight.duration) / 600) ) * 3600 ), '%i' ) ) FROM flight WHERE YEAR(flight.start_date) = $year AND MONTH(flight.start_date) = 5 AND flight.aircraft_id = Num AND flight.departure_icao_id = flight.arrival_icao_id AND flight.duration < 90 * 600 ) AS Mai, ( SELECT CONCAT( FLOOR(SUM(flight.duration) / 600), ':', TIME_FORMAT( SEC_TO_TIME( ( SUM(flight.duration) / 600 - FLOOR(SUM(flight.duration) / 600) ) * 3600 ), '%i' ) ) FROM flight WHERE YEAR(flight.start_date) = $year AND MONTH(flight.start_date) = 6 AND flight.aircraft_id = Num AND flight.departure_icao_id = flight.arrival_icao_id AND flight.duration < 90 * 600 ) AS Juin, ( SELECT CONCAT( FLOOR(SUM(flight.duration) / 600), ':', TIME_FORMAT( SEC_TO_TIME( ( SUM(flight.duration) / 600 - FLOOR(SUM(flight.duration) / 600) ) * 3600 ), '%i' ) ) FROM flight WHERE YEAR(flight.start_date) = $year AND MONTH(flight.start_date) = 7 AND flight.aircraft_id = Num AND flight.departure_icao_id = flight.arrival_icao_id AND flight.duration < 90 * 600 ) AS Juil, ( SELECT CONCAT( FLOOR(SUM(flight.duration) / 600), ':', TIME_FORMAT( SEC_TO_TIME( ( SUM(flight.duration) / 600 - FLOOR(SUM(flight.duration) / 600) ) * 3600 ), '%i' ) ) FROM flight WHERE YEAR(flight.start_date) = $year AND MONTH(flight.start_date) = 8 AND flight.aircraft_id = Num AND flight.departure_icao_id = flight.arrival_icao_id AND flight.duration < 90 * 600 ) AS Aout, ( SELECT CONCAT( FLOOR(SUM(flight.duration) / 600), ':', TIME_FORMAT( SEC_TO_TIME( ( SUM(flight.duration) / 600 - FLOOR(SUM(flight.duration) / 600) ) * 3600 ), '%i' ) ) FROM flight WHERE YEAR(flight.start_date) = $year AND MONTH(flight.start_date) = 9 AND flight.aircraft_id = Num AND flight.departure_icao_id = flight.arrival_icao_id AND flight.duration < 90 * 600 ) AS Sept, ( SELECT CONCAT( FLOOR(SUM(flight.duration) / 600), ':', TIME_FORMAT( SEC_TO_TIME( ( SUM(flight.duration) / 600 - FLOOR(SUM(flight.duration) / 600) ) * 3600 ), '%i' ) ) FROM flight WHERE YEAR(flight.start_date) = $year AND MONTH(flight.start_date) = 10 AND flight.aircraft_id = Num AND flight.departure_icao_id = flight.arrival_icao_id AND flight.duration < 90 * 600 ) AS Octo, ( SELECT CONCAT( FLOOR(SUM(flight.duration) / 600), ':', TIME_FORMAT( SEC_TO_TIME( ( SUM(flight.duration) / 600 - FLOOR(SUM(flight.duration) / 600) ) * 3600 ), '%i' ) ) FROM flight WHERE YEAR(flight.start_date) = $year AND MONTH(flight.start_date) = 11 AND flight.aircraft_id = Num AND flight.departure_icao_id = flight.arrival_icao_id AND flight.duration < 90 * 600 ) AS Nove, ( SELECT CONCAT( FLOOR(SUM(flight.duration) / 600), ':', TIME_FORMAT( SEC_TO_TIME( ( SUM(flight.duration) / 600 - FLOOR(SUM(flight.duration) / 600) ) * 3600 ), '%i' ) ) FROM flight WHERE YEAR(flight.start_date) = $year AND MONTH(flight.start_date) = 12 AND flight.aircraft_id = Num AND flight.departure_icao_id = flight.arrival_icao_id AND flight.duration < 90 * 600 ) AS Dece, CONCAT( FLOOR(SUM(duration) / 600), ':', TIME_FORMAT( SEC_TO_TIME( ( SUM(flight.duration) / 600 - FLOOR(SUM(flight.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(flight.start_date) = $year AND flight.departure_icao_id = flight.arrival_icao_id AND flight.duration < 90 * 600 GROUP BY resource.id</sql>
Computation of non-"local flight" time per month
<syntaxhighlight lang="sql">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</sql>
Stats all flight hours per month per year
<syntaxhighlight lang="sql">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</sql>
Flight hours per activity type between date
- 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.
<syntaxhighlight lang="sql">[OF_DYNAMIC_SQL] SELECT CONCAT(
'SELECT resource.name AS _tr(RESOURCE_NAME), ', GROUP_CONCAT( CONCAT( 'sexa2HoursMinute( SUM( IF( tmp_flight.activity_type_id & ', activity_type.id, ', tmp_flight.duration, 0 ) ) )', ' AS ', QUOTE(activity_type.name) ) ), ', sexa2HoursMinute( SUM( tmp_flight.duration ) ) AS _tr(ALL_ACTIVITY_TYPES) FROM resource INNER JOIN ( SELECT flight.aircraft_id, flight.activity_type_id, duration FROM flight WHERE flight.start_date >= $startDate AND flight.start_date <= $endDate AND flight.airborne = 0 ) AS tmp_flight ON (resource.id=tmp_flight.aircraft_id) GROUP BY resource.id'
) FROM activity_type WHERE activity_type.activated=1</sql>
Flight reports
Activities summary for a person on the right place for a given month
Requirement:
- Variable $year of Year value type
- Variable $month of Month value type
- Variable $personId of dbOjectMulti::Person value type
<syntaxhighlight lang="sql">SELECT $month AS Mois, CONCAT(left_person.last_name, ' ', left_person.first_name) AS 'Personne en première place', activity_type.name AS 'Type d\'activité', sexa2HoursMinute( SUM( IFNULL(duration, 0) ) ) AS 'Durée' FROM flight LEFT JOIN activity_type ON (flight.activity_type_id & activity_type.id) LEFT JOIN flight_pilot AS left_place ON (flight.id=left_place.flight_id AND left_place.num=0) LEFT JOIN person AS left_person ON (left_place.pilot_id=left_person.id) LEFT JOIN flight_pilot AS right_place ON (flight.id=right_place.flight_id AND right_place.num=1) WHERE YEAR(flight.start_date)=$year
AND MONTH(flight.start_date)=$month AND (right_place.pilot_id=$personId OR '-'=right_place.pilot_id='$personId')
GROUP BY left_person.id, activity_type.id ORDER BY left_person.last_name, left_person.first_name, activity_type.name</sql>
Aircraft(s) which no flight were done for at least 30 day(s)
<syntaxhighlight lang="sql">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</sql>
Flight between date
Following variables are needed:
- startDate (Type : Datetime)
- endDate (Type : Datetime)
<syntaxhighlight lang="sql">[OF_DYNAMIC_SQL] SELECT CONCAT( 'SELECT
flight.id AS _tr(ID), IF(flight.validated=1, _tr(YES), _tr(NO)) AS _tr(VALIDATED), flight.start_date AS _tr(START_DATE), resource.name AS _tr(RESOURCE), ( SELECT CONCAT(UPPER(tmp_person.last_name), \' \', tmp_person.first_name) FROM flight_pilot AS tmp_flight_pilot LEFT JOIN person AS tmp_person ON tmp_flight_pilot.pilot_id = tmp_person.id WHERE tmp_flight_pilot.flight_id = flight.id AND tmp_flight_pilot.num = 0 ) AS _tr(LEFT_PLACE), ( SELECT CONCAT(UPPER(tmp_person.last_name), \' \', tmp_person.first_name) FROM flight_pilot AS tmp_flight_pilot LEFT JOIN person AS tmp_person ON tmp_flight_pilot.pilot_id = tmp_person.id WHERE tmp_flight_pilot.flight_id = flight.id AND tmp_flight_pilot.num = 1 ) AS _tr(RIGHT_PLACE), ( SELECT GROUP_CONCAT( activity_type.name SEPARATOR \', \') FROM flight AS tmp_flight LEFT JOIN activity_type ON (tmp_flight.activity_type_id & activity_type.id) WHERE flight.id=tmp_flight.id ) AS _tr(ACTIVITY_TYPE), ( SELECT location.name FROM location WHERE location.icao_name=flight.departure_icao_id ) AS _tr(DEPARTURE), ( SELECT location.name FROM location WHERE location.icao_name=flight.arrival_icao_id ) AS _tr(ARRIVAL), flight.landing_number AS _tr(FLIGHT_LANDING_NUMBER), flight.people_onboard AS _tr(FLIGHT_PEOPLE_ON_BOARD), sexa2HoursMinute(flight.counter_departure) AS _tr(FLIGHT_COUNTER_DEPARTURE), sexa2HoursMinute(flight.counter_arrival) AS _tr(FLIGHT_COUNTER_ARRIVAL), sexa2HoursMinute(flight.duration) AS _tr(DURATION_IN_HOURS_AND_MINUTES), sexa2HoursHundredths(flight.duration) AS _tr(DURATION_IN_HOURS_AND_HUNDREDTHS),', IFNULL(GROUP_CONCAT( CONCAT( IF(business_field.value_type LIKE ('dbObject::Person%'), ' (SELECT CONCAT (UPPER(tmp_person.last_name), \' \', tmp_person.first_name) FROM business_field_content RIGHT JOIN business_field ON (business_field.id=business_field_content.business_field_id) RIGHT JOIN person AS tmp_person ON (tmp_person.id=business_field_content.content) WHERE business_field_content.category_id=flight.id AND business_field_content.business_field_id=', ' (SELECT GROUP_CONCAT(business_field_content.content SEPARATOR \', \') FROM business_field_content RIGHT JOIN business_field ON (business_field.id=business_field_content.business_field_id) WHERE business_field_content.category_id=flight.id AND business_field_content.business_field_id='), business_field.id, ') AS \, REPLACE(business_field.label, '\, '\\\), '\ ) ), '\'_\), ',( SELECT SUM(account_entry.debit) - SUM(account_entry.credit) FROM account_entry RIGHT JOIN account ON (account.id=account_entry.account_id AND (account.category = 11 OR account.category = 2)) WHERE account_entry.flow_id = flight_account_entry.account_entry_id ) AS _tr(AMOUNT)
FROM flight LEFT JOIN resource ON resource.id = flight.aircraft_id LEFT JOIN flight_account_entry ON flight_account_entry.flight_id = flight.id WHERE flight.start_date >= $startDate AND flight.start_date <= $endDate ORDER BY flight.start_date; ' ) FROM business_field WHERE business_field.category='FLIGHT' </sql>
Flight log book
<syntaxhighlight lang="sql">SELECT
DATE_FORMAT(start_date, '%d/%m/%Y %H:%i') AS _tr(START_DATE), resource.name AS _tr(RESOURCE), CONCAT(last_name, ' ', first_name) AS _tr(LEFT_PLACE), ( SELECT CONCAT(person.last_name, ' ', person.first_name) AS _tr(RIGHT_PLACE) FROM flight_pilot AS tmp2_flight_pilot LEFT JOIN person ON person.id=tmp2_flight_pilot.pilot_id WHERE tmp2_flight_pilot.flight_id=flight_pilot.flight_id AND tmp2_flight_pilot.num=1 ) AS _tr(RIGHT_PLACE), IF ( (SELECT COUNT(*) FROM flight_pilot AS tmp_flight_pilot WHERE tmp_flight_pilot.flight_id=flight_pilot.flight_id AND tmp_flight_pilot.num=1)=0, 'S', 'D' ) AS 'Solo / DC', sexa2HoursMinute(flight.duration) AS _tr(DURATION), ( SELECT GROUP_CONCAT( activity_type.name SEPARATOR ', ') FROM flight AS tmp_flight LEFT JOIN activity_type ON (tmp_flight.activity_type_id & activity_type.id) WHERE tmp_flight.id=flight.id ) AS _tr(ACTIVITY_TYPE), flight.departure_icao_id AS _tr(DEPARTURE), flight.arrival_icao_id AS _tr(ARRIVAL), flight.landing_number AS _tr(FLIGHT_LANDING_NUMBER), flight.people_onboard AS _tr(FLIGHT_PEOPLE_ON_BOARD), business_field_comment.content AS _tr(COMMENT) FROM flight_pilot LEFT JOIN flight ON flight_pilot.flight_id=flight.id LEFT JOIN activity_type ON (activity_type.id & flight.activity_type_id) LEFT JOIN person ON person.id=flight_pilot.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.business_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 flight_pilot.num=0 AND flight.airborne=0 GROUP BY flight.id ORDER BY CONCAT(last_name, ' ', first_name), start_date</sql>
Flights which have landed elsewhere than the base field
Variable $icao shall be defined (dbObject:Location) <syntaxhighlight lang="sql">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, flight.departure_icao_id AS Départ, flight.arrival_icao_id 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 WHERE flight_pilot.num = 0 AND( flight.departure_icao_id LIKE $icao OR flight.arrival_icao_id LIKE $icao ) GROUP BY flight.id </sql>
Flights with mechanic remark
Following variables are needed:
- Business field $maintenanceUserComment should be defined first and should be of Text multi line value type and Flight category.
- Business field $mechanicAnswer should be defined first and should be of Text multi line value type and Flight category.
- Business field $resourceId should be defined first and should be of dbObject::Resource value type and Report category.
- Business field $numberMonth should be defined first and should be of integer value type and Report category.
<syntaxhighlight lang="sql">SELECT CONCAT(
'[LINK=index.php[QUESTION_MARK]menuAction=flight_record&menuParameter=', flight.id, '&menuParameterBis=flight_resource_logbook&menuParameter3=1]', flight.start_date, '[/LINK]' ) AS _tr(DATE), resource.name AS _tr(RESOURCE), sexa2HoursMinute(flight.duration) AS _tr(DURATION), person.last_name AS Nom, person.first_name AS _tr(FIRST_NAME), departure_location.icao_name AS _tr(DEPARTURE), arrival_location.icao_name AS _tr(ARRIVAL), maintenanceUserComment.content AS _tr(REMARK), mechanicAnswer.content AS _tr(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 departure_location ON departure_location.icao_name = flight.departure_icao_id LEFT JOIN location AS arrival_location ON arrival_location.icao_name = flight.arrival_icao_id LEFT JOIN business_field_content AS maintenanceUserComment ON maintenanceUserComment.category_id = flight.id LEFT JOIN business_field_content AS mechanicAnswer ON mechanicAnswer.category_id = flight.id WHERE flight_pilot.num = 0
AND maintenanceUserComment.business_field_id =( SELECT business_field.id FROM business_field WHERE ( business_field.variable = "maintenanceUserComment" ) ) AND mechanicAnswer.business_field_id =( SELECT business_field.id FROM business_field WHERE ( business_field.variable = "mechanicAnswer" ) ) AND ( maintenanceUserComment.content <> "" OR mechanicAnswer.content <> "" ) AND start_date > DATE_SUB( NOW(), INTERVAL $numberMonth MONTH) AND ( (resource.id = $resourceId) OR($resourceId < '1') )
GROUP BY flight.id ORDER BY resource.name, start_date DESC </sql>
Flight with their location code (ICAO)
<syntaxhighlight lang="sql">SELECT flight.* FROM flight</sql>
Flight hours total per person
Following variables are needed:
- Variable $endDate of Date and time value type.
- Variable $startDate of Date and time value type.
<syntaxhighlight lang="sql">SELECT
CONCAT(person.last_name,' ',person.first_name) AS _tr(LAST_NAME), sexa2HoursMinute( SUM( IFNULL( Solo.sum_duration, 0 ) ) ) AS _tr(ALONE), sexa2HoursMinute( SUM( IFNULL( DC.sum_duration, 0 ) ) ) AS _tr(LEGEND_INSTRUCTION), sexa2HoursMinute( SUM( IFNULL( Solo.sum_duration, 0 ) ) + SUM( IFNULL( DC.sum_duration, 0 ) ) ) AS _tr(TOTAL) FROM person LEFT JOIN ( SELECT pilot_id, IF ( (SELECT COUNT(*) FROM flight_pilot flight_pilot_2 WHERE flight_pilot_2.flight_id=flight_pilot_1.flight_id AND flight_pilot_2.num=1)=0, 'Solo', 'DC' ) AS Solo_DC, SUM(flight.duration) AS sum_duration FROM flight_pilot flight_pilot_1 LEFT JOIN flight ON flight_pilot_1.flight_id=flight.id WHERE flight.airborne=0 AND flight.start_date >= $startDate AND flight.start_date <= $endDate AND flight_pilot_1.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 flight_pilot_2 WHERE flight_pilot_2.flight_id=flight_pilot_1.flight_id AND flight_pilot_2.num=1)=0, 'Solo', 'DC' ) AS Solo_DC, SUM(flight.duration) AS sum_duration FROM flight_pilot flight_pilot_1 LEFT JOIN flight ON flight_pilot_1.flight_id=flight.id WHERE flight.airborne=0 AND flight.start_date >= $startDate AND flight.start_date <= $endDate AND flight_pilot_1.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</sql>
Fuel/Oil reports
Hourly consumption
Unit is: unit of the tank per hour <SQL>SELECT
resource_name AS '_tr(REPORT_RESOURCE)', 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 '_tr(TANK)', CAST(SUM(IF (month_num=1, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0)) AS DECIMAL(10,2) ) AS '_tr(MONTH_JAN_ABBR)', CAST(SUM(IF (month_num=2, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0)) AS DECIMAL(10,2) ) AS '_tr(MONTH_FEB_ABBR)', CAST(SUM(IF (month_num=3, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0)) AS DECIMAL(10,2) ) AS '_tr(MONTH_MAR_ABBR)', CAST(SUM(IF (month_num=4, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0)) AS DECIMAL(10,2) ) AS '_tr(MONTH_APR_ABBR)', CAST(SUM(IF (month_num=5, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0)) AS DECIMAL(10,2) ) AS '_tr(MONTH_MAY_ABBR)', CAST(SUM(IF (month_num=6, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0)) AS DECIMAL(10,2) ) AS '_tr(MONTH_JUN_ABBR)', CAST(SUM(IF (month_num=7, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0)) AS DECIMAL(10,2) ) AS '_tr(MONTH_JUL_ABBR)', CAST(SUM(IF (month_num=8, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0)) AS DECIMAL(10,2) ) AS '_tr(MONTH_AUG_ABBR)', CAST(SUM(IF (month_num=9, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0)) AS DECIMAL(10,2) ) AS '_tr(MONTH_SEP_ABBR)', CAST(SUM(IF (month_num=10, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0)) AS DECIMAL(10,2) ) AS '_tr(MONTH_OCT_ABBR)', CAST(SUM(IF (month_num=11, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0)) AS DECIMAL(10,2) ) AS '_tr(MONTH_NOV_ABBR)', CAST(SUM(IF (month_num=12, IF (flight_time >0 ,quantity/flight_time*600 , 0), 0)) AS DECIMAL(10,2) ) AS '_tr(MONTH_DEC_ABBR)', CAST(SUM(quantity)/(SELECT SUM(duration) FROM flight WHERE aircraft_id = resource_id AND YEAR (start_date) = $year)*600 AS DECIMAL(10,2) ) AS '_tr(ANNUAL_AVERAGE)'
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</SQL>
Monthly refueling by resource type
<syntaxhighlight lang="sql">SELECT
aircraft_type_name AS _tr(RESOURCE_TYPE), tank_label AS _tr(TANK), SUM(IF (month_num=1, quantity, 0)) AS Janu, SUM(IF (month_num=2, quantity, 0)) AS Febr, SUM(IF (month_num=3, quantity, 0)) AS Marc, SUM(IF (month_num=4, quantity, 0)) AS Apri, SUM(IF (month_num=5, quantity, 0)) AS May, SUM(IF (month_num=6, quantity, 0)) AS June, SUM(IF (month_num=7, quantity, 0)) AS July, SUM(IF (month_num=8, quantity, 0)) AS Augu, SUM(IF (month_num=9, quantity, 0)) AS Sept, SUM(IF (month_num=10, quantity, 0)) AS Octo, SUM(IF (month_num=11, quantity, 0)) AS Nove, SUM(IF (month_num=12, quantity, 0)) AS Dece, SUM(quantity) AS _tr(QUANTITY)
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</sql>
Fuel/Oil sum for each aircraft
Unit is: unit of the tank <SQL>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, SUM(IF (month_num=1, quantity, 0)) AS Janu, SUM(IF (month_num=2, quantity, 0)) AS Febr, SUM(IF (month_num=3, quantity, 0)) AS Marc, SUM(IF (month_num=4, quantity, 0)) AS Apri, SUM(IF (month_num=5, quantity, 0)) AS May, SUM(IF (month_num=6, quantity, 0)) AS June, SUM(IF (month_num=7, quantity, 0)) AS July, SUM(IF (month_num=8, quantity, 0)) AS Augu, SUM(IF (month_num=9, quantity, 0)) AS Sept, SUM(IF (month_num=10, quantity, 0)) AS Octo, SUM(IF (month_num=11, quantity, 0)) AS Nove, SUM(IF (month_num=12, quantity, 0)) AS Dece, SUM(quantity) AS SUM, 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</SQL>
Total refuelings by resource over a year
<syntaxhighlight lang="sql">SELECT resource.name AS _tr(RESOURCE), tank.label AS _tr(TANK), SUM( quantity ) AS _tr(QUANTITY) 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</sql>
Total refuelings by resource type over a year
<syntaxhighlight lang="sql">SELECT resource_type.name AS _tr(RESOURCE_TYPE), tank.label AS _tr(TANK), SUM( quantity ) AS _tr(QUANTITY) 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</sql>
Error message queries
Flight without account movement
<SQL>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</SQL>
movement without an account
<SQL>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'</SQL>