database_schema.sql 14 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350
  1. DROP TABLE IF EXISTS 'pilots';
  2. CREATE TABLE IF NOT EXISTS 'pilots' (
  3. 'pilot_id' INTEGER NOT NULL,
  4. 'lastname' TEXT NOT NULL,
  5. 'firstname' TEXT,
  6. 'alias' TEXT,
  7. 'company' TEXT,
  8. 'employeeid' TEXT,
  9. 'phone' TEXT,
  10. 'email' TEXT,
  11. PRIMARY KEY('pilot_id' AUTOINCREMENT)
  12. );
  13. DROP TABLE IF EXISTS 'tails';
  14. CREATE TABLE IF NOT EXISTS 'tails' (
  15. 'tail_id' INTEGER NOT NULL,
  16. 'registration' TEXT NOT NULL,
  17. 'company' TEXT,
  18. 'make' TEXT,
  19. 'model' TEXT,
  20. 'variant' TEXT,
  21. 'multipilot' INTEGER,
  22. 'multiengine' INTEGER,
  23. 'engineType' INTEGER,
  24. 'weightClass' INTEGER,
  25. PRIMARY KEY('tail_id' AUTOINCREMENT)
  26. );
  27. DROP TABLE IF EXISTS 'flights';
  28. CREATE TABLE IF NOT EXISTS 'flights' (
  29. 'flight_id' INTEGER NOT NULL,
  30. 'doft' NUMERIC NOT NULL,
  31. 'dept' TEXT NOT NULL,
  32. 'dest' TEXT NOT NULL,
  33. 'tofb' INTEGER NOT NULL,
  34. 'tonb' INTEGER NOT NULL,
  35. 'pic' INTEGER NOT NULL,
  36. 'acft' INTEGER NOT NULL,
  37. 'tblk' INTEGER NOT NULL,
  38. 'tSPSE' INTEGER,
  39. 'tSPME' INTEGER,
  40. 'tMP' INTEGER,
  41. 'tNIGHT' INTEGER,
  42. 'tIFR' INTEGER,
  43. 'tPIC' INTEGER,
  44. 'tPICUS' INTEGER,
  45. 'tSIC' INTEGER,
  46. 'tDUAL' INTEGER,
  47. 'tFI' INTEGER,
  48. 'tSIM' INTEGER,
  49. 'pilotFlying' INTEGER,
  50. 'toDay' INTEGER,
  51. 'toNight' INTEGER,
  52. 'ldgDay' INTEGER,
  53. 'ldgNight' INTEGER,
  54. 'autoland' INTEGER,
  55. 'secondPilot' INTEGER,
  56. 'thirdPilot' INTEGER,
  57. 'approachType' TEXT,
  58. 'flightNumber' TEXT,
  59. 'remarks' TEXT,
  60. FOREIGN KEY('pic') REFERENCES 'pilots'('pilot_id') ON DELETE RESTRICT,
  61. FOREIGN KEY('acft') REFERENCES 'tails'('tail_id') ON DELETE RESTRICT,
  62. PRIMARY KEY('flight_id' AUTOINCREMENT)
  63. );
  64. DROP TABLE IF EXISTS 'aircraft';
  65. CREATE TABLE IF NOT EXISTS 'aircraft' (
  66. 'aircraft_id' INTEGER NOT NULL,
  67. 'make' TEXT,
  68. 'model' TEXT,
  69. 'variant' TEXT,
  70. 'name' TEXT,
  71. 'iata' TEXT,
  72. 'icao' TEXT,
  73. 'multipilot' INTEGER,
  74. 'multiengine' INTEGER,
  75. 'engineType' INTEGER,
  76. 'weightClass' INTEGER,
  77. PRIMARY KEY('aircraft_id' AUTOINCREMENT)
  78. );
  79. DROP TABLE IF EXISTS 'airports';
  80. CREATE TABLE IF NOT EXISTS 'airports' (
  81. 'airport_id' INTEGER NOT NULL,
  82. 'icao' TEXT NOT NULL,
  83. 'iata' TEXT,
  84. 'name' TEXT,
  85. 'lat' REAL,
  86. 'long' REAL,
  87. 'country' TEXT,
  88. 'tzolson' TEXT,
  89. PRIMARY KEY('airport_id' AUTOINCREMENT)
  90. );
  91. DROP TABLE IF EXISTS 'currencies';
  92. CREATE TABLE IF NOT EXISTS 'currencies' (
  93. 'currency_id' INTEGER NOT NULL,
  94. 'currencyName' TEXT,
  95. 'expiryDate' NUMERIC,
  96. PRIMARY KEY('currency_id' AUTOINCREMENT)
  97. );
  98. DROP TABLE IF EXISTS 'changelog';
  99. CREATE TABLE IF NOT EXISTS 'changelog' (
  100. 'revision' INTEGER NOT NULL,
  101. 'comment' TEXT,
  102. 'date' NUMERIC,
  103. PRIMARY KEY('revision' AUTOINCREMENT)
  104. );
  105. DROP TABLE IF EXISTS 'simulators';
  106. CREATE TABLE IF NOT EXISTS 'simulators' (
  107. 'session_id' INTEGER NOT NULL,
  108. 'date' NUMERIC NOT NULL,
  109. 'totalTime' INTEGER NOT NULL,
  110. 'deviceType' TEXT NOT NULL,
  111. 'aircraftType' TEXT,
  112. 'registration' TEXT,
  113. 'remarks' TEXT,
  114. PRIMARY KEY('session_id' AUTOINCREMENT)
  115. );
  116. DROP TABLE IF EXISTS 'previousExperience';
  117. CREATE TABLE 'previousExperience' (
  118. 'tblk' INTEGER,
  119. 'tSPSE' INTEGER,
  120. 'tSPME' INTEGER,
  121. 'tMP' INTEGER,
  122. 'tNIGHT' INTEGER,
  123. 'tIFR' INTEGER,
  124. 'tPIC' INTEGER,
  125. 'tPICUS' INTEGER,
  126. 'tSIC' INTEGER,
  127. 'tDUAL' INTEGER,
  128. 'tFI' INTEGER,
  129. 'tSIM' INTEGER,
  130. 'toDay' INTEGER,
  131. 'toNight' INTEGER,
  132. 'ldgDay' INTEGER,
  133. 'ldgNight' INTEGER,
  134. 'autoland' INTEGER
  135. );
  136. DROP VIEW IF EXISTS 'viewDefault';
  137. CREATE VIEW viewDefault AS
  138. SELECT flight_id,
  139. doft as 'Date',
  140. dept AS 'Dept',
  141. printf('%02d',(tofb/60))||':'||printf('%02d',(tofb%60)) AS 'Time',
  142. dest AS 'Dest', printf('%02d',(tonb/60))||':'||printf('%02d',(tonb%60)) AS 'Time ',
  143. printf('%02d',(tblk/60))||':'||printf('%02d',(tblk%60)) AS 'Total',
  144. CASE WHEN pilot_id = 1 THEN alias ELSE lastname||', '||substr(firstname, 1, 1)||'.' END AS 'Name PIC',
  145. CASE WHEN variant IS NOT NULL THEN make||' '||model||'-'||variant ELSE make||' '||model END AS 'Type',
  146. registration AS 'Registration',
  147. FlightNumber AS 'Flight #',
  148. remarks AS 'Remarks'
  149. FROM flights
  150. INNER JOIN pilots on flights.pic = pilots.pilot_id
  151. INNER JOIN tails on flights.acft = tails.tail_id
  152. ORDER BY date DESC;
  153. DROP VIEW IF EXISTS 'viewDefaultSim';
  154. CREATE VIEW viewDefaultSim AS
  155. SELECT flight_id AS 'rowid',
  156. doft as 'Date',
  157. dept AS 'Dept',
  158. printf('%02d',(tofb/60))||':'||printf('%02d',(tofb%60)) AS 'Time',
  159. dest AS 'Dest', printf('%02d',(tonb/60))||':'||printf('%02d',(tonb%60)) AS 'Time ',
  160. printf('%02d',(tblk/60))||':'||printf('%02d',(tblk%60)) AS 'Total',
  161. CASE WHEN pilot_id = 1 THEN alias ELSE lastname||', '||substr(firstname, 1, 1)||'.' END AS 'Name PIC',
  162. CASE WHEN variant IS NOT NULL THEN make||' '||model||'-'||variant ELSE make||' '||model END AS 'Type',
  163. registration AS 'Registration',
  164. null AS 'Sim Type',
  165. null AS 'Time of Session',
  166. remarks AS 'Remarks'
  167. FROM flights
  168. INNER JOIN pilots on flights.pic = pilots.pilot_id
  169. INNER JOIN tails on flights.acft = tails.tail_id
  170. UNION
  171. SELECT (session_id * -1),
  172. date,
  173. null, null, null, null,
  174. 'SIM',
  175. null,
  176. aircraftType,
  177. registration,
  178. deviceType,
  179. printf('%02d',(totalTime/60))||':'||printf('%02d',(totalTime%60)),
  180. remarks
  181. FROM simulators
  182. ORDER BY date DESC;
  183. DROP VIEW IF EXISTS 'viewEasa';
  184. CREATE VIEW viewEasa AS SELECT flight_id,
  185. doft as 'Date',
  186. dept AS 'Dept',
  187. printf('%02d',(tofb/60))||':'||printf('%02d',(tofb%60)) AS 'Time',
  188. dest AS 'Dest',
  189. printf('%02d',(tonb/60))||':'||printf('%02d',(tonb%60)) AS 'Time ',
  190. CASE WHEN variant IS NOT NULL THEN make||' '||model||'-'||variant ELSE make||' '||model END AS 'Type',
  191. registration AS 'Registration',
  192. (SELECT printf('%02d',(tSPSE/60))||':'||printf('%02d',(tSPSE%60)) WHERE tSPSE IS NOT NULL) AS 'SP SE',
  193. (SELECT printf('%02d',(tSPME/60))||':'||printf('%02d',(tSPME%60)) WHERE tSPME IS NOT NULL) AS 'SP ME',
  194. (SELECT printf('%02d',(tMP/60))||':'||printf('%02d',(tMP%60)) WHERE tMP IS NOT NULL) AS 'MP',
  195. printf('%02d',(tblk/60))||':'||printf('%02d',(tblk%60)) AS 'Total',
  196. CASE WHEN pilot_id = 1 THEN alias ELSE lastname||', '||substr(firstname, 1, 1)||'.' END AS 'Name PIC',
  197. ldgDay AS 'L/D',
  198. ldgNight AS 'L/N',
  199. (SELECT printf('%02d',(tNight/60))||':'||printf('%02d',(tNight%60)) WHERE tNight IS NOT NULL) AS 'Night',
  200. (SELECT printf('%02d',(tIFR/60))||':'||printf('%02d',(tIFR%60)) WHERE tIFR IS NOT NULL) AS 'IFR',
  201. (SELECT printf('%02d',(tPIC/60))||':'||printf('%02d',(tPIC%60)) WHERE tPIC IS NOT NULL) AS 'PIC',
  202. (SELECT printf('%02d',(tSIC/60))||':'||printf('%02d',(tSIC%60)) WHERE tSIC IS NOT NULL) AS 'SIC',
  203. (SELECT printf('%02d',(tDual/60))||':'||printf('%02d',(tDual%60)) WHERE tDual IS NOT NULL) AS 'Dual',
  204. (SELECT printf('%02d',(tFI/60))||':'||printf('%02d',(tFI%60)) WHERE tFI IS NOT NULL) AS 'FI',
  205. remarks AS 'Remarks'
  206. FROM flights
  207. INNER JOIN pilots on flights.pic = pilots.pilot_id
  208. INNER JOIN tails on flights.acft = tails.tail_id ORDER BY date DESC;
  209. DROP VIEW IF EXISTS 'viewEasaSim';
  210. CREATE VIEW viewEasaSim AS SELECT flight_id,
  211. doft as 'Date',
  212. dept AS 'Dept',
  213. printf('%02d',(tofb/60))||':'||printf('%02d',(tofb%60)) AS 'Time',
  214. dest AS 'Dest',
  215. printf('%02d',(tonb/60))||':'||printf('%02d',(tonb%60)) AS 'Time ',
  216. CASE WHEN variant IS NOT NULL THEN make||' '||model||'-'||variant ELSE make||' '||model END AS 'Type',
  217. registration AS 'Registration',
  218. (SELECT printf('%02d',(tSPSE/60))||':'||printf('%02d',(tSPSE%60)) WHERE tSPSE IS NOT NULL) AS 'SP SE',
  219. (SELECT printf('%02d',(tSPME/60))||':'||printf('%02d',(tSPME%60)) WHERE tSPME IS NOT NULL) AS 'SP ME',
  220. (SELECT printf('%02d',(tMP/60))||':'||printf('%02d',(tMP%60)) WHERE tMP IS NOT NULL) AS 'MP',
  221. printf('%02d',(tblk/60))||':'||printf('%02d',(tblk%60)) AS 'Total',
  222. CASE WHEN pilot_id = 1 THEN alias ELSE lastname||', '||substr(firstname, 1, 1)||'.' END AS 'Name PIC',
  223. ldgDay AS 'L/D',
  224. ldgNight AS 'L/N',
  225. (SELECT printf('%02d',(tNight/60))||':'||printf('%02d',(tNight%60)) WHERE tNight IS NOT NULL) AS 'Night',
  226. (SELECT printf('%02d',(tIFR/60))||':'||printf('%02d',(tIFR%60)) WHERE tIFR IS NOT NULL) AS 'IFR',
  227. (SELECT printf('%02d',(tPIC/60))||':'||printf('%02d',(tPIC%60)) WHERE tPIC IS NOT NULL) AS 'PIC',
  228. (SELECT printf('%02d',(tSIC/60))||':'||printf('%02d',(tSIC%60)) WHERE tSIC IS NOT NULL) AS 'SIC',
  229. (SELECT printf('%02d',(tDual/60))||':'||printf('%02d',(tDual%60)) WHERE tDual IS NOT NULL) AS 'Dual',
  230. (SELECT printf('%02d',(tFI/60))||':'||printf('%02d',(tFI%60)) WHERE tFI IS NOT NULL) AS 'FI',
  231. null AS 'Sim Type',
  232. null AS 'Time of Session',
  233. remarks AS 'Remarks'
  234. FROM flights
  235. INNER JOIN pilots on flights.pic = pilots.pilot_id
  236. INNER JOIN tails on flights.acft = tails.tail_id
  237. UNION
  238. SELECT (session_id * -1),
  239. date,
  240. null, null, null, null,
  241. aircraftType,
  242. registration,
  243. null, null, null,
  244. 'SIM',
  245. null, null, null, null, null, null, null, null, null,
  246. deviceType, printf('%02d',(totalTime/60))||':'||printf('%02d',(totalTime%60)),
  247. remarks
  248. FROM simulators
  249. ORDER BY date DESC;
  250. DROP VIEW IF EXISTS 'viewSimulators';
  251. CREATE VIEW viewSimulators AS SELECT (session_id * -1),
  252. date as 'Date',
  253. registration AS 'Registration',
  254. aircraftType AS 'Aircraft Type',
  255. deviceType 'Sim Type',
  256. printf('%02d',(totalTime/60))||':'||printf('%02d',(totalTime%60)) AS 'Time of Session',
  257. remarks AS 'Remarks'
  258. FROM simulators
  259. ORDER BY date DESC;
  260. DROP VIEW IF EXISTS 'viewTails';
  261. CREATE VIEW viewTails AS
  262. SELECT tail_id AS 'ID',
  263. registration AS 'Registration',
  264. make||' '||model AS 'Type',
  265. company AS 'Company'
  266. FROM tails WHERE model IS NOT NULL AND variant IS NULL
  267. UNION
  268. SELECT tail_id AS 'ID',
  269. registration AS 'Registration',
  270. make||' '||model||'-'||variant AS 'Type',
  271. company AS 'Company'
  272. FROM tails WHERE variant IS NOT NULL;
  273. DROP VIEW IF EXISTS 'viewPilots';
  274. CREATE VIEW viewPilots AS
  275. SELECT pilot_id AS 'ID',
  276. lastname AS 'Last Name',
  277. firstname AS 'First Name',
  278. company AS 'Company'
  279. FROM pilots;
  280. DROP VIEW IF EXISTS 'viewTotals';
  281. CREATE VIEW viewTotals AS
  282. SELECT printf('%02d',CAST(SUM(tblk) AS INT)/60)||':'||printf('%02d',CAST(SUM(tblk) AS INT)%60) AS 'TOTAL',
  283. printf('%02d',CAST(SUM(tSPSE) AS INT)/60)||':'||printf('%02d',CAST(SUM(tSPSE) AS INT)%60) AS 'SP SE',
  284. printf('%02d',CAST(SUM(tSPME) AS INT)/60)||':'||printf('%02d',CAST(SUM(tSPME) AS INT)%60) AS 'SP ME',
  285. printf('%02d',CAST(SUM(tNIGHT) AS INT)/60)||':'||printf('%02d',CAST(SUM(tNIGHT) AS INT)%60) AS 'NIGHT',
  286. printf('%02d',CAST(SUM(tIFR) AS INT)/60)||':'||printf('%02d',CAST(SUM(tIFR) AS INT)%60) AS 'IFR',
  287. printf('%02d',CAST(SUM(tPIC) AS INT)/60)||':'||printf('%02d',CAST(SUM(tPIC) AS INT)%60) AS 'PIC',
  288. printf('%02d',CAST(SUM(tPICUS) AS INT)/60)||':'||printf('%02d',CAST(SUM(tPICUS) AS INT)%60) AS 'PICUS',
  289. printf('%02d',CAST(SUM(tSIC) AS INT)/60)||':'||printf('%02d',CAST(SUM(tSIC) AS INT)%60) AS 'SIC',
  290. printf('%02d',CAST(SUM(tDual) AS INT)/60)||':'||printf('%02d',CAST(SUM(tDual) AS INT)%60) AS 'DUAL',
  291. printf('%02d',CAST(SUM(tFI) AS INT)/60)||':'||printf('%02d',CAST(SUM(tFI) AS INT)%60) AS 'INSTRUCTOR',
  292. printf('%02d',CAST(SUM(tSIM) AS INT)/60)||':'||printf('%02d',CAST(SUM(tSIM) AS INT)%60) AS 'SIMULATOR',
  293. printf('%02d',CAST(SUM(tMP) AS INT)/60)||':'||printf('%02d',CAST(SUM(tMP) AS INT)%60) AS 'MultPilot',
  294. CAST(SUM(toDay) AS INT) AS 'TO Day',
  295. CAST(SUM(toNight) AS INT) AS 'TO Night',
  296. CAST(SUM(ldgDay) AS INT) AS 'LDG Day',
  297. CAST(SUM(ldgNight) AS INT) AS 'LDG Night'
  298. FROM flights;
  299. DROP VIEW IF EXISTS 'viewExport';
  300. CREATE VIEW viewExport AS
  301. SELECT flight_id,
  302. doft as 'Date',
  303. dept AS 'Dept',
  304. printf('%02d',(tofb/60))||':'||printf('%02d',(tofb%60)) AS 'Time Out',
  305. dest AS 'Dest',
  306. printf('%02d',(tonb/60))||':'||printf('%02d',(tonb%60)) AS 'Time In ',
  307. CASE WHEN variant IS NOT NULL THEN make||' '||model||'-'||variant ELSE make||' '||model END AS 'Type',
  308. registration AS 'Registration',
  309. (SELECT printf('%02d',(tSPSE/60))||':'||printf('%02d',(tSPSE%60)) WHERE tSPSE IS NOT NULL) AS 'SP SE',
  310. (SELECT printf('%02d',(tSPME/60))||':'||printf('%02d',(tSPME%60)) WHERE tSPME IS NOT NULL) AS 'SP ME',
  311. (SELECT printf('%02d',(tMP/60))||':'||printf('%02d',(tMP%60)) WHERE tMP IS NOT NULL) AS 'MP',
  312. printf('%02d',(tblk/60))||':'||printf('%02d',(tblk%60)) AS 'Total',
  313. CASE WHEN pilot_id = 1 THEN alias ELSE lastname||', '||substr(firstname, 1, 1)||'.' END AS 'Name PIC',
  314. toDay AS 'Take-Off Day',
  315. ldgDay AS 'Landings Day',
  316. toNight AS 'Take-Off Night',
  317. ldgNight AS 'Landings Night',
  318. (SELECT printf('%02d',(tNight/60))||':'||printf('%02d',(tNight%60)) WHERE tNight IS NOT NULL) AS 'Night',
  319. (SELECT printf('%02d',(tIFR/60))||':'||printf('%02d',(tIFR%60)) WHERE tIFR IS NOT NULL) AS 'IFR',
  320. (SELECT printf('%02d',(tPIC/60))||':'||printf('%02d',(tPIC%60)) WHERE tPIC IS NOT NULL) AS 'PIC',
  321. (SELECT printf('%02d',(tSIC/60))||':'||printf('%02d',(tSIC%60)) WHERE tSIC IS NOT NULL) AS 'SIC',
  322. (SELECT printf('%02d',(tDual/60))||':'||printf('%02d',(tDual%60)) WHERE tDual IS NOT NULL) AS 'Dual',
  323. (SELECT printf('%02d',(tFI/60))||':'||printf('%02d',(tFI%60)) WHERE tFI IS NOT NULL) AS 'FI',
  324. null AS 'Sim Type',
  325. null AS 'Time of Session',
  326. remarks AS 'Remarks'
  327. FROM flights
  328. INNER JOIN pilots on flights.pic = pilots.pilot_id
  329. INNER JOIN tails on flights.acft = tails.tail_id
  330. UNION
  331. SELECT (session_id * -1),
  332. date,
  333. null, null, null, null,
  334. aircraftType,
  335. registration,
  336. null, null, null,
  337. 'SIM',
  338. null, null, null, null, null, null, null, null, null, null, null,
  339. deviceType, printf('%02d',(totalTime/60))||':'||printf('%02d',(totalTime%60)),
  340. remarks
  341. FROM simulators
  342. ORDER BY date DESC;