```sql CREATE TABLE "flights" ( "flight_id" INTEGER NOT NULL, "doft" NUMERIC NOT NULL, "dept" TEXT NOT NULL, "dest" TEXT NOT NULL, "tofb" INTEGER NOT NULL, "tonb" INTEGER NOT NULL, "pic" INTEGER NOT NULL, "acft" INTEGER NOT NULL, "tblk" INTEGER NOT NULL, "tSPSE" INTEGER, "tSPME" INTEGER, "tMP" INTEGER, "tNIGHT" INTEGER, "tIFR" INTEGER, "tPIC" INTEGER, "tPICUS" INTEGER, "tSIC" INTEGER, "tDUAL" INTEGER, "tFI" INTEGER, "tSIM" INTEGER, "pilotFlying" INTEGER, "toDay" INTEGER, "toNight" INTEGER, "ldgDay" INTEGER, "ldgNight" INTEGER, "autoland" INTEGER, "secondPilot" INTEGER, "thirdPilot" INTEGER, "approachType" TEXT, "flightNumber" TEXT, "remarks" TEXT, PRIMARY KEY("flight_id" AUTOINCREMENT), FOREIGN KEY("acft") REFERENCES "tails"("tail_id") ON DELETE RESTRICT, FOREIGN KEY("pic") REFERENCES "pilots"("pilot_id") ON DELETE RESTRICT ); ```
| field | value | description | |---------|-----------------|--------------| | `tSPSE` | INTEGER | Time (minutes) single pilot single engine | | `tSPME` | INTEGER | Time (minutes) single pilot multi engine | | `tMP` | INTEGER | Time (minutes) single pilot single engine | | `tNIGHT` | INTEGER | Time (minutes) Night flying time | | `tIFR` | INTEGER | Time (minutes) flown under Instrument Flight Rules | | `tPIC` | INTEGER | Time (minutes) flown as Pilot-in-Command | | `tPICUS` | INTEGER | Time (minutes) flown as Pilot-in-Command under supervision | | `tSIC` | INTEGER | Time (minutes) flown as Second-in-Command (Co-Pilot) | | `tDUAL` | INTEGER | Time (minutes) flown as training received | | `tFI` | INTEGER | Time (minutes) flown as Flight Instructor | | `tSIM` | INTEGER | Time (minutes) of Simulator Training (currently not implemented) | | `pilotFlying` | INTEGER | Whether the user acted as Pilot Flying (`1`) or Pilot Monitoring (`0`) | | `toDay` | INTEGER | Number of take-offs during day time | | `toNight` | INTEGER | Number of take-offs during night time | | `ldgDay` | INTEGER | Number of landings during day time | | `ldgNight` | INTEGER | Number of landings during night time | | `autoland` | INTEGER | Number of autolands | | `secondPilot` | INTEGER | The second pilot of the flight. This is a [foreign key](https://sqlite.org/foreignkeys.html) referencing pilots.pilot_id | | `thirdPilot` | INTEGER | The third pilot of the flight. This is a [foreign key](https://sqlite.org/foreignkeys.html) referencing pilots.pilot_id | | `approachType` | INTEGER | The type of Approach flown | | `flightNumber` | INTEGER | The flight number. The airline prefix can be set in the settings dialog | | `remarks` | INTEGER | Remarks and endorsements |
```sql CREATE TABLE "pilots" ( "pilot_id" INTEGER NOT NULL, "lastname" TEXT NOT NULL, "firstname" TEXT, "alias" TEXT, "company" TEXT, "employeeid" TEXT, "phone" TEXT, "email" TEXT, "displayname" TEXT, PRIMARY KEY("pilot_id" AUTOINCREMENT) ); ```
| field | value | description | |---------|-----------------|--------------| | `firstname` | TEXT | The first name(s) of the pilot | `alias` | TEXT | An alias, nick-name, call-sign, etc. | `company` | TEXT | Company | `employeeid` | TEXT | Employee ID or crew code | `phone` | TEXT | Phone number | `email` | TEXT | eMail-Adress
![example](https://raw.githubusercontent.com/fiffty-50/openpilotlog/develop/screenshots/pilots_table.png)
```sql CREATE TABLE tails (" " tail_id INTEGER NOT NULL," " registration TEXT NOT NULL," " company TEXT," " make TEXT," " model TEXT," " variant TEXT," " multipilot INTEGER," " multiengine INTEGER," " engineType INTEGER," " weightClass INTEGER," " PRIMARY KEY(tail_id AUTOINCREMENT)" ")"; ```
| field | value | description | example | |---------|-----------------|--------------|---------| | `company` | TEXT | The company the aircraft belongs to | `PANAM` | `make` | TEXT | The [manufacturer](https://en.wikipedia.org/wiki/List_of_aircraft_manufacturers_by_ICAO_name) of the aircraft | `Boeing` | `model` | TEXT | The model of the aircraft | `747` | `variant` | TEXT | The variant of the aircroft | `400` | `multipilot` | INTEGER | Whether the aircraft is certified for multi-pilot operations. | `1` | `multiengine` | INTEGER | Whether the aircraft is multi-engine | `1` | `engineType` | INTEGER | Engine Type, see below | `3` | `weightClass` | INTEGER | [Weight Category](https://www.skybrary.aero/index.php/ICAO_Wake_Turbulence_Category), see below | `2` Sqlite does not have a boolean data type, but 'multiengine' and 'multipilot' could be seen as such: ``` multiengine = 0 == singleengine = 1 multipilot = 0 == singlepilot = 1 ``` engineType is categorized as: ``` 0 = unpowered 1 = piston Engine 2 = Turboprop 3 = Jet ``` weightClass is categorized as: ``` 0 = light 1 = medium 2 = heavy 3 = super ```
```sql CREATE TABLE airports airport_id INTEGER NOT NULL, icao TEXT NOT NULL, iata TEXT, name TEXT, lat REAL, long REAL, country TEXT, alt INTEGER, utcoffset INTEGER, tzolson TEXT, PRIMARY KEY(airport_id AUTOINCREMENT) ); ```
```sql CREATE TABLE aircraft ( aircraft_id INTEGER NOT NULL, make TEXT, model TEXT, variant TEXT, name TEXT, iata TEXT, icao TEXT, multipilot INTEGER, multiengine INTEGER, engineType INTEGER, weightClass INTEGER, PRIMARY KEY(aircraft_id AUTOINCREMENT) ); ```
```sql CREATE VIEW viewDefault AS SELECT flight_id, doft as 'Date', dept AS 'Dept', printf('%02d',(tofb/60))||':'||printf('%02d',(tofb%60)) AS 'Time', dest AS 'Dest', printf('%02d',(tonb/60))||':'||printf('%02d',(tonb%60)) AS 'Time ', printf('%02d',(tblk/60))||':'||printf('%02d',(tblk%60)) AS 'Total', CASE WHEN pilot_id = 1 THEN alias ELSE piclastname||', '||substr(picfirstname, 1, 1)||'.' END AS 'Name PIC', make||' '||model||'-'||variant AS 'Type', registration AS 'Registration', FlightNumber AS 'Flight #', Remarks FROM flights INNER JOIN pilots on flights.pic = pilots.pilot_id INNER JOIN tails on flights.acft = tails.tail_id ORDER BY date DESC ```
![example](https://raw.githubusercontent.com/fiffty-50/openpilotlog/develop/screenshots/default_view_system_theme.png)
```sql CREATE VIEW viewEASA AS SELECT flight_id, doft as 'Date', dept AS 'Dept', printf('%02d',(tofb/60))||':'||printf('%02d',(tofb%60)) AS 'Time', dest AS 'Dest', printf('%02d',(tonb/60))||':'||printf('%02d',(tonb%60)) AS 'Time ', make||' '||model||'-'||variant AS 'Type', registration AS 'Registration', (SELECT printf('%02d',(tSPSE/60))||':'||printf('%02d',(tSPSE%60)) WHERE tSPSE IS NOT "") AS 'SP SE', (SELECT printf('%02d',(tSPME/60))||':'||printf('%02d',(tSPME%60)) WHERE tSPME IS NOT "") AS 'SP ME', (SELECT printf('%02d',(tMP/60))||':'||printf('%02d',(tMP%60)) WHERE tMP IS NOT "") AS 'MP', printf('%02d',(tblk/60))||':'||printf('%02d',(tblk%60)) AS 'Total', CASE WHEN pilot_id = 1 THEN alias ELSE piclastname||', '||substr(picfirstname, 1, 1)||'.' END AS 'Name PIC', ldgDay AS 'L/D', ldgNight AS 'L/N', (SELECT printf('%02d',(tNight/60))||':'||printf('%02d',(tNight%60)) WHERE tNight IS NOT "") AS 'Night', (SELECT printf('%02d',(tIFR/60))||':'||printf('%02d',(tIFR%60)) WHERE tIFR IS NOT "") AS 'IFR', (SELECT printf('%02d',(tPIC/60))||':'||printf('%02d',(tPIC%60)) WHERE tPIC IS NOT "") AS 'PIC', (SELECT printf('%02d',(tSIC/60))||':'||printf('%02d',(tSIC%60)) WHERE tSIC IS NOT "") AS 'SIC', (SELECT printf('%02d',(tDual/60))||':'||printf('%02d',(tDual%60)) WHERE tDual IS NOT "") AS 'Dual', (SELECT printf('%02d',(tFI/60))||':'||printf('%02d',(tFI%60)) WHERE tFI IS NOT "") AS 'FI', Remarks FROM flights INNER JOIN pilots on flights.pic = pilots.pilot_id INNER JOIN tails on flights.acft = tails.tail_id ORDER BY date DESC ```
![example](https://raw.githubusercontent.com/fiffty-50/openpilotlog/develop/screenshots/easaView_dark_theme.png)