-
Notifications
You must be signed in to change notification settings - Fork 13
/
Sample CIFP SQL queries.sql
852 lines (783 loc) · 27 KB
/
Sample CIFP SQL queries.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
-- If you feel like outputting query results to CSV:
-- sqlite3 cifp-1513.db
-- .headers on
-- .mode csv
-- .output filename.csv
--------------------------------------------------------------------------------
--Controlled airspace points
-- Needs some calculations on this data to produce GML compatible output
.headers on
.mode csv
.output controlled-airspace.csv
SELECT
AirspaceCenter
, AirspaceClassification
, AirspaceType
, BoundaryVia_1
, BoundaryVia_2
, ( CAST( ArcBearing AS REAL) / 10) as ArcBearing
, ( CAST( ArcDistance AS REAL) / 10) as ArcDistance
, ArcOriginLongitude_WGS84
, ArcOriginLatitude_WGS84
, ControlledAirspaceName
, Longitude_WGS84
, Latitude_WGS84
, LowerLimit
, UpperLimit
FROM
"primary_U_C_base_Airspace - Controlled Airspace"
AS airspace
-- WHERE
-- airspace.AirspaceCenter LIKE '%SSC%'
;
--------------------------------------------------------------------------------
-- Restrictive airspace points
-- Needs some calculations on this data to produce GML compatible output
.headers on
.mode csv
.output restrictive-airspace.csv
SELECT
RestrictiveAirspaceDesignation
, RestrictiveAirspaceName
, RestrictiveType
, NOTAM
, BoundaryVia_1
, BoundaryVia_2
, ( CAST( ArcBearing AS REAL) / 10) as ArcBearing
, ( CAST( ArcDistance AS REAL) / 10) as ArcDistance
, ArcOriginLongitude_WGS84
, ArcOriginLatitude_WGS84
, Longitude_WGS84
, Latitude_WGS84
, LowerLimit
, UpperLimit
FROM
"primary_U_R_base_Airspace - Restrictive Airspace"
AS airspace
-- WHERE
-- airspace.AirspaceCenter LIKE '%SSC%'
;
--------------------------------------------------------------------------------
--IAPs (all steps) at an airport
SELECT *
--iap.LandingFacilityIcaoIdentifier
--,iap.SIDSTARApproachIdentifier
FROM
"primary_P_F_base_Airport - Approach Procedures" AS IAP
WHERE
iap.LandingFacilityIcaoIdentifier LIKE '%RIC%'
-- and
-- iap.SIDSTARApproachIdentifier LIKE '%18%'
;
--------------------------------------------------------------------------------
--IAPs (all steps) at an airport, with the more interesting parts of each step
SELECT
iap._id
,LandingFacilityIcaoIdentifier
,SIDSTARApproachIdentifier
,TransitionIdentifier
,CAST( SequenceNumber AS REAL)
,RouteType
,FixIdentifier
,WaypointDescriptionCode1
,WaypointDescriptionCode2
,WaypointDescriptionCode3
,WaypointDescriptionCode4
,PathAndTermination
,CAST( MagneticCourse AS REAL) / 10
,CAST( Altitude_1 AS REAL)
,CAST( Altitude_2 AS REAL)
,AltitudeDescription
,CAST( Rho AS REAL) / 10
,RecommendedNavaid
,RNP
,CAST( RouteDistanceHoldingDistanceOrTime AS REAL) / 10
,VerticalAngle
,CAST (Theta AS REAL) / 10
,CAST( TransitionAltitude AS REAL)
,TurnDirection
,TurnDirectionValid
,SpeedLimit
,SpeedLimitDescription
FROM
"primary_P_F_base_Airport - Approach Procedures" AS iap
WHERE
iap.LandingFacilityIcaoIdentifier LIKE '%RIC%'
ORDER BY
SIDSTARApproachIdentifier
,RouteType
,TransitionIdentifier
,CAST( SequenceNumber AS REAL)
;
--------------------------------------------------------------------------------
---Minimum Safe Altitudes at an airport, all info
SELECT
*
FROM
"primary_P_S_base_Airport - MSA" AS msa
WHERE
--msa.LandingFacilityIcaoIdentifier LIKE '%RIC%'
msa.LandingFacilityIcaoIdentifier IN ('KART')
;
--------------------------------------------------------------------------------
-- Or just the more interesting parts of MSA
.headers on
.mode csv
.output MSA_points.csv
SELECT
msa.LandingFacilityIcaoIdentifier
,msa.MagneticTrueIndicator
,msa.MSACenter
,msa.LandingFacilityIcaoRegionCode
,msa.MSACenterIcaoRegionCode
,msa.SectionCode
,msa.SubSectionCode
,msa.MSACenterSectionCode
,msa.MSACenterSubSectionCode
,SectorAltitude_1
,SectorBearing_1
,SectorRadius_1
,SectorAltitude_2
,SectorBearing_2
,SectorRadius_2
,SectorAltitude_3
,SectorBearing_3
,SectorRadius_3
,SectorAltitude_4
,SectorBearing_4
,SectorRadius_4
,SectorAltitude_5
,SectorBearing_5
,SectorRadius_5
,SectorAltitude_6
,SectorBearing_6
,SectorRadius_6
,SectorAltitude_7
,SectorBearing_7
,SectorRadius_7
, COALESCE( term_fix.waypointLongitude_wgs84
,vhf.vorLongitude_wgs84
,ndb.ndbLongitude_wgs84
,term_ndb.ndbLongitude_wgs84
,grid.waypointLongitude_wgs84
,vhf.dmeLongitude_wgs84
,rwy.RunwayLongitude_wgs84
)
AS Longitude
, COALESCE( term_fix.waypointLatitude_wgs84
,vhf.vorLatitude_wgs84
,ndb.ndbLatitude_wgs84
,term_ndb.ndbLatitude_wgs84
,grid.waypointLatitude_wgs84
,vhf.dmeLatitude_wgs84
,rwy.RunwayLatitude_wgs84
)
AS Latitude
, 'point ('
|| COALESCE( term_fix.waypointLongitude_wgs84
,vhf.vorLongitude_wgs84
,ndb.ndbLongitude_wgs84
,term_ndb.ndbLongitude_wgs84
,grid.waypointLongitude_wgs84
,vhf.dmeLongitude_wgs84
,rwy.RunwayLongitude_wgs84
)
|| ' '
|| COALESCE( term_fix.waypointLatitude_wgs84
,vhf.vorLatitude_wgs84
,ndb.ndbLatitude_wgs84
,term_ndb.ndbLatitude_wgs84
,grid.waypointLatitude_wgs84
,vhf.dmeLatitude_wgs84
,rwy.RunwayLatitude_wgs84
)
|| ' )'
as Geometry
FROM
"primary_P_S_base_Airport - MSA" AS msa
LEFT OUTER JOIN
"primary_E_A_base_Enroute - Grid Waypoints" AS grid
ON
(msa.MSACenterSectionCode = 'E' AND msa.MSACenterSubSectionCode = 'A')
AND
msa.MSACenter = grid.waypointIdentifier
AND
msa.MSACenterIcaoRegionCode = grid.WaypointIcaoRegionCode
LEFT OUTER JOIN
"primary_P_C_base_Airport - Terminal Waypoints" AS term_fix
ON
(msa.MSACenterSectionCode = 'P' AND msa.MSACenterSubSectionCode = 'C')
AND
msa.LandingFacilityIcaoIdentifier = term_fix.RegionCode
AND
msa.MSACenter = term_fix.waypointIdentifier
AND
msa.MSACenterIcaoRegionCode = term_fix.WaypointIcaoRegionCode
LEFT OUTER JOIN
"primary_D__base_Navaid - VHF Navaid" AS vhf
ON
(msa.MSACenterSectionCode = 'D' AND msa.MSACenterSubSectionCode = '')
AND
msa.MSACenterIcaoRegionCode = vhf.VorIcaoRegionCode
AND
msa.MSACenter = vhf.vorIdentifier
LEFT OUTER JOIN
"primary_D_B_base_Navaid - NDB Navaid" AS ndb
ON
(msa.MSACenterSectionCode = 'D' AND msa.MSACenterSubSectionCode = 'B')
AND
msa.MSACenterIcaoRegionCode = ndb.NdbIcaoRegionCode
AND
msa.MSACenter = ndb.ndbIdentifier
LEFT OUTER JOIN
"primary_P_N_base_Airport - Terminal NDB" AS term_ndb
ON
(msa.MSACenterSectionCode = 'P' AND msa.MSACenterSubSectionCode = 'N')
AND
msa.MSACenterIcaoRegionCode = term_ndb.NdbIcaoRegionCode
AND
msa.MSACenter = term_ndb.ndbIdentifier
AND
msa.LandingFacilityIcaoIdentifier = term_ndb.LandingFacilityIcaoIdentifier
LEFT OUTER JOIN
"primary_P_G_base_Airport - Runways" AS rwy
ON
(msa.MSACenterSectionCode = 'P' AND msa.MSACenterSubSectionCode = 'G')
AND
msa.MSACenter = rwy.runwayIdentifier
AND
msa.LandingFacilityIcaoIdentifier = rwy.LandingFacilityIcaoIdentifier
-- WHERE
-- msa.LandingFacilityIcaoIdentifier LIKE '%RIC%'
-- msa.LandingFacilityIcaoIdentifier IN ('KART')
;
--------------------------------------------------------------------------------
--SIDs at an airport
SELECT distinct
sids.LandingFacilityIcaoIdentifier
,sids.SIDSTARApproachIdentifier
FROM
"primary_P_D_base_Airport - SIDs" AS sids
WHERE
sids.LandingFacilityIcaoIdentifier = 'KRIC'
;
--------------------------------------------------------------------------------
--STARs at an airport
SELECT DISTINCT
stars.LandingFacilityIcaoIdentifier
,stars.SIDSTARApproachIdentifier
FROM
"primary_P_E_base_Airport - STARs" AS stars
WHERE
stars.LandingFacilityIcaoIdentifier = 'KRIC'
;
--------------------------------------------------------------------------------
--IAPs at an airport
SELECT DISTINCT
iap.LandingFacilityIcaoIdentifier
,iap.SIDSTARApproachIdentifier
FROM
"primary_P_F_base_Airport - Approach Procedures" AS IAP
WHERE
iap.LandingFacilityIcaoIdentifier = 'KRIC'
;
--------------------------------------------------------------------------------
--Runways at an airport
SELECT DISTINCT
rwy.LandingFacilityIcaoIdentifier
,rwy.RunwayIdentifier
,rwy.RunwayLatitude
,rwy.RunwayLongitude
,rwy.RunwayLatitude_wgs84
,rwy.RunwayLongitude_wgs84
FROM
"primary_P_G_base_Airport - Runways" AS RWY
WHERE
rwy.LandingFacilityIcaoIdentifier = 'KRIC' ;
--------------------------------------------------------------------------------
--Longest runway's length at an airport (rwy.LongestRunway is hundreds of feet. eg 090 = 9000')
SELECT
rwy.LandingFacilityIcaoIdentifier
, rwy.LongestRunway
, CAST(rwy.LongestRunway AS REAL) * 100 AS runwayLengthInFeet
FROM
"primary_P_A_base_Airport - Reference Points" AS RWY
WHERE
rwy.LandingFacilityIcaoIdentifier IN ('KRIC', 'KDCA', 'KIAD', 'KORF') ;
--------------------------------------------------------------------------------
--NDB Navaids used for IAPs for an airport
-- Needs to be fixed to correctly use joining criteria (see MSA for example
SELECT DISTINCT
iap.FixIdentifier
,NDB.NDBLatitude
,NDB.NDBLongitude
FROM
"primary_P_F_base_Airport - Approach Procedures" AS IAP
JOIN
"primary_D_B_base_Navaid - NDB Navaid" AS NDB
ON
iap.FixIdentifier = ndb.NDBIdentifier
WHERE
airportidentifier LIKE '%RIC%' ;
--------------------------------------------------------------------------------
-- Needs to be fixed to correctly use joining criteria (see MSA for example)
--VHF Navaids used for IAPs for an airport
SELECT DISTINCT
iap.FixIdentifier
,VOR.VORLatitude
,VOR.VORLongitude
FROM
"primary_P_F_base_Airport - Approach Procedures" AS IAP
JOIN
"primary_D__base_Navaid - VHF Navaid" AS VOR
ON
iap.FixIdentifier = vor.vorIdentifier
WHERE
airportidentifier LIKE '%RIC%' ;
--------------------------------------------------------------------------------
-- Needs to be fixed to correctly use joining criteria (see MSA for example)
--Fixes used for IAPs for an airport
SELECT DISTINCT
iap.FixIdentifier
,fix.waypointLatitude
,fix.waypointLongitude
FROM
"primary_P_F_base_Airport - Approach Procedures" AS IAP
JOIN
"primary_E_A_base_Enroute - Grid Waypoints" AS FIX
ON
iap.FixIdentifier = fix.waypointIdentifier
WHERE
airportidentifier LIKE '%RIC%'
;
--------------------------------------------------------------------------------
-- Needs to be fixed to correctly use joining criteria (see MSA for example)
--Terminal waypoints used for IAPs for an airport
SELECT DISTINCT
iap.FixIdentifier
,fix.waypointLatitude
,fix.waypointLongitude
FROM
"primary_P_F_base_Airport - Approach Procedures" AS IAP
JOIN
"primary_P_C_base_Airport - Terminal Waypoints" AS FIX
ON
iap.FixIdentifier = fix.waypointIdentifier
WHERE
airportidentifier LIKE '%OFP%' ;
--------------------------------------------------------------------------------
-- Needs to be fixed to correctly use joining criteria (see MSA for example)
--Terminal waypoints used for IAPs for a heliport
SELECT DISTINCT
iap.FixIdentifier
,fix.waypointLatitude
,fix.waypointLongitude
FROM
"primary_H_F_base_Heliport - Approach Procedures" AS IAP
JOIN
"primary_E_A_base_Enroute - Grid Waypoints" AS FIX
ON
iap.FixIdentifier = fix.waypointIdentifier
WHERE
HeliportIdentifier LIKE '%RIC%' ;
--------------------------------------------------------------------------------
SELECT
--_id
--,LandingFacilityIcaoIdentifier
--,Altitude_1
--,Altitude_2
--,AltitudeDescription
--,ApchRouteQualifier1
--,ApchRouteQualifier2
--,ARCRadius
--,ATCIndicator
--,CenterFixOrTAAProcedureTurnIndicator
--,FileRecordNumber
FixIdentifier
--,MagneticCourse
--,MultipleCodeOrTAASectorIdentifier
--,PathAndTermination
--,RNP
--,RouteDistanceHoldingDistanceOrTime
--,RouteType
--,SequenceNumber
--,SIDSTARApproachIdentifier
--,SpeedLimit
--,SpeedLimitDescription
--,SubSectionCode_1
--,SubSectionCode_2
--,SubSectionCode_3
--,Theta
--,TransitionAltitude
--,TransitionIdentifier
--,TurnDirection
--,TurnDirectionValid
--,VerticalAngle
--,WaypointDescriptionCode1
--,WaypointDescriptionCode2
--,WaypointDescriptionCode3
--,WaypointDescriptionCode4
FROM
--"primary_P_F_base_Airport - Approach Procedures "
"primary_H_F_base_Heliport - Approach Procedures"
WHERE
--airportidentifier LIKE '%02p%'
heliportidentifier LIKE '%02p%'
ORDER BY
SidstarApproachIdentifier
,TransitionIdentifier
,SequenceNumber
;
--------------------------------------------------------------------------------
SELECT
*
FROM
"primary_H_F_base_Heliport - Approach Procedures"
WHERE
heliportidentifier LIKE '%02P%'
;
------------------------------------------------------------------------------
--Create lines for all procedures. Doesn't look quite right due to the fact
-- that these types of legs in the procedure don't have specific associated fixes
-- "CA" -Course to an Altitude or CA Leg.
-- Defines a specified course to a specific altitude at an unspecified position"
-- "CD" - Course to a DME Distance or CD Leg.
-- Defines a specified course to a specific DME Distance which is from a
-- specific database DME Navaid.
-- "CI" - Course to an Intercept or CI Leg.
-- Defines a specified course to intercept a subsequent leg.
-- "VA" - Heading to an Altitude termination or VA Leg.
-- Defines a specified heading to a specific Altitude termination at an
-- unspecified position.
-- "VD" - Heading to a DME Distance termination or VD Leg.
-- Defines a specified heading terminating at a specified DME Distance
-- from a specific database DME Navaid.
-- "VI" - Heading to an Intercept or VI Leg.
-- Defines a specified heading to intercept the subsequent leg at an
-- unspecified position.
-- "VR" - Heading to a Radial termination or VR Leg.
-- Defines a specified heading to a specified radial from a specific
-- database VOR Navaid.
.headers on
.mode csv
.output "iap-lines.csv"
-- .output "sid-lines.csv"
-- .output "star-lines.csv"
SELECT
procedure._id
, procedure.LandingFacilityIcaoIdentifier
, procedure.SIDSTARApproachIdentifier
, procedure.TransitionIdentifier
, procedure.LandingFacilityIcaoIdentifier
|| '.'
|| procedure.SIDSTARApproachIdentifier
|| '.'
|| procedure.TransitionIdentifier
as unique_id
, procedure.RouteType
, COALESCE( term_fix.waypointLongitude_wgs84
, vhf.vorLongitude_wgs84
, ndb.ndbLongitude_wgs84
, term_ndb.ndbLongitude_wgs84
, grid.waypointLongitude_wgs84
, vhf.dmeLongitude_wgs84
, rwy.RunwayLongitude_wgs84
)
AS Longitude
, COALESCE( term_fix.waypointLatitude_wgs84
, vhf.vorLatitude_wgs84
, ndb.ndbLatitude_wgs84
, term_ndb.ndbLatitude_wgs84
, grid.waypointLatitude_wgs84
, vhf.dmeLatitude_wgs84
, rwy.RunwayLatitude_wgs84
)
AS Latitude
, 'linestring ('
|| GROUP_CONCAT(
COALESCE( term_fix.waypointLongitude_wgs84
, vhf.vorLongitude_wgs84
, ndb.ndbLongitude_wgs84
, term_ndb.ndbLongitude_wgs84
, grid.waypointLongitude_wgs84
, vhf.dmeLongitude_wgs84
, rwy.RunwayLongitude_wgs84
)
|| ' '
|| COALESCE( term_fix.waypointLatitude_wgs84
, vhf.vorLatitude_wgs84
, ndb.ndbLatitude_wgs84
, term_ndb.ndbLatitude_wgs84
, grid.waypointLatitude_wgs84
, vhf.dmeLatitude_wgs84
, rwy.RunwayLatitude_wgs84
)
, ' , ' )
|| ' )'
AS
geometry
FROM
"primary_P_F_base_Airport - Approach Procedures" AS procedure
--, 'primary_P_E_base_Airport - STARs' AS procedure
--, 'primary_P_D_base_Airport - SIDs' AS procedure
LEFT OUTER JOIN
"primary_E_A_base_Enroute - Grid Waypoints" AS grid
ON
(procedure.FixSectionCode = 'E' AND procedure.FixSubSectionCode = 'A')
AND
procedure.FixIdentifier = grid.waypointIdentifier
AND
procedure.FixIcaoRegionCode = grid.WaypointIcaoRegionCode
LEFT OUTER JOIN
"primary_P_C_base_Airport - Terminal Waypoints" AS term_fix
ON
(procedure.FixSectionCode = 'P' AND procedure.FixSubSectionCode = 'C')
AND
procedure.LandingFacilityIcaoIdentifier = term_fix.RegionCode
AND
procedure.FixIdentifier = term_fix.waypointIdentifier
AND
procedure.FixIcaoRegionCode = term_fix.WaypointIcaoRegionCode
LEFT OUTER JOIN
"primary_D__base_Navaid - VHF Navaid" AS vhf
ON
(procedure.FixSectionCode = 'D' AND procedure.FixSubSectionCode = '')
AND
procedure.FixIcaoRegionCode = vhf.VorIcaoRegionCode
AND
procedure.FixIdentifier = vhf.vorIdentifier
LEFT OUTER JOIN
"primary_D_B_base_Navaid - NDB Navaid" AS ndb
ON
(procedure.FixSectionCode = 'D' AND procedure.FixSubSectionCode = 'B')
AND
procedure.FixIcaoRegionCode = ndb.NdbIcaoRegionCode
AND
procedure.FixIdentifier = ndb.ndbIdentifier
LEFT OUTER JOIN
"primary_P_N_base_Airport - Terminal NDB" AS term_ndb
ON
(procedure.FixSectionCode = 'P' AND procedure.FixSubSectionCode = 'N')
AND
procedure.FixIcaoRegionCode = term_ndb.NdbIcaoRegionCode
AND
procedure.FixIdentifier = term_ndb.ndbIdentifier
AND
procedure.LandingFacilityIcaoIdentifier = term_ndb.LandingFacilityIcaoIdentifier
LEFT OUTER JOIN
"primary_P_G_base_Airport - Runways" AS rwy
ON
(procedure.FixSectionCode = 'P' AND procedure.FixSubSectionCode = 'G')
AND
procedure.FixIdentifier = rwy.runwayIdentifier
AND
procedure.LandingFacilityIcaoIdentifier = rwy.LandingFacilityIcaoIdentifier
WHERE
-- procedure.LandingFacilityIcaoIdentifier LIKE '%CAE%'
-- AND
procedure.FixIdentifier IS NOT NULL
AND
(Longitude IS NOT NULL AND Longitude != '')
AND
(Latitude IS NOT NULL AND Latitude != '')
GROUP BY
unique_id
ORDER BY
CAST(procedure.SequenceNumber AS real)
;
------------------------------------------------------------------------------
-- Points associated with procedures
.headers on
.mode csv
.output "iap-points.csv"
-- .output "sid-points.csv"
-- .output "star-points.csv"
SELECT
procedure._id
, procedure.LandingFacilityIcaoIdentifier
, procedure.SIDSTARApproachIdentifier
, procedure.TransitionIdentifier
, procedure.LandingFacilityIcaoIdentifier
|| '.'
|| procedure.SIDSTARApproachIdentifier
|| '.'
|| procedure.TransitionIdentifier
as unique_id
, procedure.FixIdentifier
, procedure.SequenceNumber
, procedure.RouteType
, procedure.WaypointDescriptionCode1
, procedure.WaypointDescriptionCode2
, procedure.WaypointDescriptionCode3
, procedure.WaypointDescriptionCode4
, procedure.PathAndTermination
, procedure.MagneticCourse
, procedure.Altitude_1
, procedure.Altitude_2
, procedure.AltitudeDescription
, procedure.Rho
, procedure.RNP
, procedure.RouteDistanceHoldingDistanceOrTime
, procedure.VerticalAngle
, procedure.Theta
, procedure.TransitionAltitude
, procedure.TurnDirection
, procedure.TurnDirectionValid
, COALESCE( term_fix.waypointLongitude_wgs84
, vhf.vorLongitude_wgs84
, ndb.ndbLongitude_wgs84
, term_ndb.ndbLongitude_wgs84
, grid.waypointLongitude_wgs84
, vhf.dmeLongitude_wgs84
, rwy.RunwayLongitude_wgs84
)
AS Longitude
, COALESCE( term_fix.waypointLatitude_wgs84
, vhf.vorLatitude_wgs84
, ndb.ndbLatitude_wgs84
, term_ndb.ndbLatitude_wgs84
, grid.waypointLatitude_wgs84
, vhf.dmeLatitude_wgs84
, rwy.RunwayLatitude_wgs84
)
AS Latitude
, 'point( '
|| COALESCE( term_fix.waypointLongitude_wgs84
, vhf.vorLongitude_wgs84
, ndb.ndbLongitude_wgs84
, term_ndb.ndbLongitude_wgs84
, grid.waypointLongitude_wgs84
, vhf.dmeLongitude_wgs84
, rwy.RunwayLongitude_wgs84
)
|| ' '
|| COALESCE( term_fix.waypointLatitude_wgs84
, vhf.vorLatitude_wgs84
, ndb.ndbLatitude_wgs84
, term_ndb.ndbLatitude_wgs84
, grid.waypointLatitude_wgs84
, vhf.dmeLatitude_wgs84
, rwy.RunwayLatitude_wgs84
)
|| ' )'
AS geometry
FROM
"primary_P_F_base_Airport - Approach Procedures" AS procedure
--, 'primary_P_E_base_Airport - STARs' AS procedure
--, 'primary_P_D_base_Airport - SIDs' AS procedure
LEFT OUTER JOIN
"primary_E_A_base_Enroute - Grid Waypoints" AS grid
ON
(procedure.FixSectionCode = 'E' AND procedure.FixSubSectionCode = 'A')
AND
procedure.FixIdentifier = grid.waypointIdentifier
AND
procedure.FixIcaoRegionCode = grid.WaypointIcaoRegionCode
LEFT OUTER JOIN
"primary_P_C_base_Airport - Terminal Waypoints" AS term_fix
ON
(procedure.FixSectionCode = 'P' AND procedure.FixSubSectionCode = 'C')
AND
procedure.LandingFacilityIcaoIdentifier = term_fix.RegionCode
AND
procedure.FixIdentifier = term_fix.waypointIdentifier
AND
procedure.FixIcaoRegionCode = term_fix.WaypointIcaoRegionCode
LEFT OUTER JOIN
"primary_D__base_Navaid - VHF Navaid" AS vhf
ON
(procedure.FixSectionCode = 'D' AND procedure.FixSubSectionCode = '')
AND
procedure.FixIcaoRegionCode = vhf.VorIcaoRegionCode
AND
procedure.FixIdentifier = vhf.vorIdentifier
LEFT OUTER JOIN
"primary_D_B_base_Navaid - NDB Navaid" AS ndb
ON
(procedure.FixSectionCode = 'D' AND procedure.FixSubSectionCode = 'B')
AND
procedure.FixIcaoRegionCode = ndb.NdbIcaoRegionCode
AND
procedure.FixIdentifier = ndb.ndbIdentifier
LEFT OUTER JOIN
"primary_P_N_base_Airport - Terminal NDB" AS term_ndb
ON
(procedure.FixSectionCode = 'P' AND procedure.FixSubSectionCode = 'N')
AND
procedure.FixIcaoRegionCode = term_ndb.NdbIcaoRegionCode
AND
procedure.FixIdentifier = term_ndb.ndbIdentifier
AND
procedure.LandingFacilityIcaoIdentifier = term_ndb.LandingFacilityIcaoIdentifier
LEFT OUTER JOIN
"primary_P_G_base_Airport - Runways" AS rwy
ON
(procedure.FixSectionCode = 'P' AND procedure.FixSubSectionCode = 'G')
AND
procedure.FixIdentifier = rwy.runwayIdentifier
AND
procedure.LandingFacilityIcaoIdentifier = rwy.LandingFacilityIcaoIdentifier
WHERE
-- procedure.LandingFacilityIcaoIdentifier LIKE '%NUQ%'
-- AND
procedure.FixIdentifier IS NOT NULL
AND
(Longitude IS NOT NULL AND Longitude != '')
AND
(Latitude IS NOT NULL AND Latitude != '')
-- GROUP BY
-- unique_id
-- ORDER BY
-- CAST(procedure.SequenceNumber AS real)
;
--------------------------------------------------------------------------------
-- The set of distinct route types and qualifiers
-- and their more verbose descriptions
SELECT DISTINCT
procedure.RouteType
|| CASE
WHEN procedure.ApchRouteQualifier1 = '' THEN '_'
ELSE procedure.ApchRouteQualifier1
END
|| CASE
WHEN procedure.ApchRouteQualifier2 = '' THEN '_'
ELSE procedure.ApchRouteQualifier2
END
AS Qualifiers
, route_type.Route_Type_Description
, route_qualifier.Qualifier_1_Description
, route_qualifier2.Qualifier_2_Description
, count(*) as CountOfSteps
FROM
"primary_P_F_base_Airport - Approach Procedures" AS procedure
LEFT OUTER JOIN
"route_types" AS route_type
on
procedure.SectionCode = route_type.Section
and
procedure.SubSectionCode = route_type.SubSection
and
procedure.RouteType = route_type.type_code
LEFT OUTER JOIN
"route_qualifiers" AS route_qualifier
on
procedure.SectionCode = route_qualifier.Section
and
procedure.SubSectionCode = route_qualifier.SubSection
and
procedure.ApchRouteQualifier1 = route_qualifier.qualifier_1
LEFT OUTER JOIN
"route_qualifiers" AS route_qualifier2
on
procedure.SectionCode = route_qualifier2.Section
and
procedure.SubSectionCode = route_qualifier2.SubSection
and
procedure.ApchRouteQualifier2 = route_qualifier2.qualifier_2
group by
Qualifiers
order by
Qualifiers
--, CountOfSteps ASC
;
--------------------------------------------------------------------------------