summaryrefslogtreecommitdiff
path: root/mysql-test/t/cte_recursive.test
blob: aacafcb73ece209dfbe3f022c2316a793d1b09e3 (plain)
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
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
1228
1229
1230
1231
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
1250
1251
1252
1253
1254
1255
1256
1257
1258
1259
1260
1261
1262
1263
1264
1265
1266
1267
1268
1269
1270
1271
1272
1273
1274
1275
1276
1277
1278
1279
1280
1281
1282
1283
1284
1285
1286
1287
1288
1289
1290
1291
1292
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
1311
1312
1313
1314
1315
1316
1317
1318
1319
1320
1321
1322
1323
1324
1325
1326
1327
1328
1329
1330
1331
1332
1333
1334
1335
1336
1337
1338
1339
1340
1341
1342
1343
1344
1345
1346
1347
1348
1349
1350
1351
1352
1353
1354
1355
1356
1357
1358
1359
1360
1361
1362
1363
1364
1365
1366
1367
1368
1369
1370
1371
1372
1373
1374
1375
1376
1377
1378
1379
1380
1381
1382
1383
1384
1385
1386
1387
1388
1389
1390
1391
1392
1393
1394
1395
1396
1397
1398
1399
1400
1401
1402
1403
1404
1405
1406
1407
1408
1409
1410
1411
1412
1413
1414
1415
1416
1417
1418
1419
1420
1421
1422
1423
1424
1425
1426
1427
1428
1429
1430
1431
1432
1433
1434
1435
1436
1437
1438
1439
1440
1441
1442
1443
1444
1445
1446
1447
1448
1449
1450
1451
1452
1453
1454
1455
1456
1457
1458
1459
1460
1461
1462
1463
1464
1465
1466
1467
1468
1469
1470
1471
1472
1473
1474
1475
1476
1477
1478
1479
1480
1481
1482
1483
1484
1485
1486
1487
1488
1489
1490
1491
1492
1493
1494
1495
1496
1497
1498
1499
1500
1501
1502
1503
1504
1505
1506
1507
1508
1509
1510
1511
1512
1513
1514
1515
1516
1517
1518
1519
create table t1 (a int, b varchar(32));
insert into t1 values
(4,'aaaa' ), (7,'bb'), (1,'ccc'), (4,'dd');
insert into t1 values
(3,'eee'), (7,'bb'), (1,'fff'), (4,'ggg');

--ERROR ER_UNACCEPTABLE_MUTUAL_RECURSION
with recursive
t as 
(
  select * from t1 where t1.b >= 'c'
  union
  select * from r
),
r as
(
  select * from t
  union
  select t1.* from t1,r where r.a+1 = t1.a
)
select * from r;


--ERROR ER_UNACCEPTABLE_MUTUAL_RECURSION
with recursive
a1(a,b) as
(select * from t1 where t1.a>3
union
select * from b1 where b1.a >3
union
select * from c1 where c1.a>3),
b1(a,b) as
(select * from a1 where a1.b > 'ccc'
union
select * from c1 where c1.b > 'ddd'),
c1(a,b) as
(select * from a1 where a1.a<6 and a1.b< 'zz'
union
select * from b1 where b1.b > 'auu')
select * from c1; 

drop table t1;


--echo # WITH RECURSIVE vs just WITH

create table t1 (a int);
insert into t1 values
  (0), (1), (2), (3), (4);
create table t2 (a int);
insert into t2 values
  (1), (2), (3), (4), (5);


--echo # just WITH : s refers to t defined after s
--ERROR ER_NO_SUCH_TABLE
with 
 s(a) as (select t.a + 10 from t),
 t(a) as (select t1.a from t1)
select * from s;

--echo # WITH RECURSIVE: s refers to t defined after s
with recursive 
 s(a) as (select t.a + 10 from t),
 t(a) as (select t1.a from t1)
select * from s;

--echo # just WITH : defined t1 is non-recursive and uses base tables t1,t2
with
t1 as
(
select a  from t2 where t2.a=3
union
select t2.a from t1,t2 where t1.a+1=t2.a
)
select * from t1;

explain
with
t1 as
(
select a  from t2 where t2.a=3
union
select t2.a from t1,t2 where t1.a+1=t2.a
)
select * from t1;


--echo #WITH RECURSIVE : defined t1 is recursive and uses only base table t2
with recursive
t1 as
(
select a  from t2 where t2.a=3
union
select t2.a from t1,t2 where t1.a+1=t2.a
)
select * from t1;

explain
with recursive
t1 as
(
select a  from t2 where t2.a=3
union
select t2.a from t1,t2 where t1.a+1=t2.a
)
select * from t1;
    
--echo # just WITH : types of t1 columns are determined by all parts of union 

create view v1 as
with
t1 as
(
select a  from t2 where t2.a=3
union
select t2.a+1 from t1,t2 where t1.a=t2.a
)
select * from t1;

show columns from v1;


--echo # WITH RECURSIVE : types of t1 columns are determined by anchor parts 

create view v2 as
with recursive
t1 as
(
select a  from t2 where t2.a=3
union
select t2.a+1 from t1,t2 where t1.a=t2.a
)
select * from t1;

show columns from v2;

drop view v1,v2;

drop table t1,t2;


create table  folks(id int, name char(32), dob date, father int, mother int);

insert into folks values
(100, 'Me', '2000-01-01', 20, 30),
(20, 'Dad', '1970-02-02', 10, 9),
(30, 'Mom', '1975-03-03', 8, 7),
(10, 'Grandpa Bill', '1940-04-05', null, null),
(9, 'Grandma Ann', '1941-10-15', null, null),
(25, 'Uncle Jim', '1968-11-18', 8, 7),
(98, 'Sister Amy', '2001-06-20', 20, 30),
(7, 'Grandma Sally', '1943-08-23', null, 6),
(8, 'Grandpa Ben', '1940-10-21', null, null),
(6, 'Grandgrandma Martha', '1923-05-17', null, null),
(67, 'Cousin Eddie', '1992-02-28', 25, 27),
(27, 'Auntie Melinda', '1971-03-29', null, null); 

--echo # simple recursion with one anchor and one recursive select
--echo # the anchor is the first select in the specification 
with recursive 
ancestors
as
(
  select *
    from folks
      where name = 'Me' and dob = '2000-01-01'
  union 
  select p.id, p.name, p.dob, p.father, p.mother
    from folks as p, ancestors AS a
      where p.id = a.father or p.id = a.mother
)
select * from ancestors;

--echo # simple recursion with one anchor and one recursive select
--echo # the anchor is the last select in the specification 
with recursive 
ancestors
as
(
  select p.*
    from folks as p, ancestors AS a
      where p.id = a.father or p.id = a.mother
  union
  select *
    from folks
      where name = 'Me' and dob = '2000-01-01'
)
select * from ancestors;

--echo # simple recursion with one anchor and one recursive select
--echo # the anchor is the first select in the specification 
with recursive
ancestors
as
(
  select *
    from folks
      where name = 'Cousin Eddie'
  union 
  select p.*
    from folks as p, ancestors as a
      where p.id = a.father or p.id = a.mother
)
select * from ancestors;

--echo # simple recursion with or in anchor and or in recursive part 
with recursive
ancestors
as
(
  select *
    from  folks
      where name = 'Me' or name='Sister Amy'
   union 
   select  p.*
     from folks as p, ancestors as a
       where p.id = a.father or p.id = a.mother
)
select * from ancestors;

--echo # two recursive definition, one uses another
with recursive 
prev_gen
as
(
  select folks.*
    from folks, prev_gen
      where folks.id=prev_gen.father or folks.id=prev_gen.mother
  union
  select * 
    from folks
      where name='Me'
),
ancestors
as
(
  select *
    from folks
      where name='Me'
  union 
  select *
    from ancestors
  union
    select *
     from prev_gen
)
select ancestors.name, ancestors.dob from ancestors;

--echo # recursive definition with two attached non-recursive
with recursive 
ancestors(id,name,dob)
as
(
  with 
  father(child_id,id,name,dob)
  as
  (
    select folks.id, f.id, f.name, f.dob
      from folks, folks f
        where folks.father=f.id 
        
  ),
  mother(child_id,id,name,dob)
  as
  (
    select folks.id, m.id, m.name, m.dob
      from folks, folks m
        where folks.mother=m.id 
        
  )  
  select folks.id, folks.name, folks.dob
    from folks
      where name='Me'
  union 
  select f.id, f.name, f.dob
    from ancestors a, father f
      where f.child_id=a.id
  union 
  select m.id, m.name, m.dob
    from ancestors a, mother m
      where m.child_id=a.id
  
)
select ancestors.name, ancestors.dob from ancestors;

--echo # simple recursion with one anchor and one recursive select
--echo # the anchor is the first select in the specification 
with recursive
descendants
as
(
  select *
    from folks
      where name = 'Grandpa Bill'
  union 
  select folks.*
    from folks, descendants as d
      where d.id=folks.father or d.id=folks.mother
)
select * from descendants;

--echo # simple recursion with one anchor and one recursive select
--echo # the anchor is the first select in the specification 
with recursive
descendants
as
(
  select *
    from folks
      where name = 'Grandma Sally'
  union 
  select folks.*
    from folks, descendants as d
      where d.id=folks.father or d.id=folks.mother
)
select * from descendants;


--echo # simple recursive table used three times in the main query
with recursive
ancestors
as
(
  select *
    from folks 
      where name = 'Me' and dob = '2000-01-01'
  union
  select p.*   
    from folks as p, ancestors AS a   
      where p.id = a.father OR p.id = a.mother
)
select *
  from ancestors t1, ancestors t2 
    where exists (select * from ancestors a 
                  where a.father=t1.id AND a.mother=t2.id);


--echo # simple recursive table used three times in the main query
with 
ancestor_couples(husband, h_dob, wife, w_dob)
as
(
with recursive 
ancestors
as
(
  select *
    from folks 
       where name = 'Me'
  union
  select p.*   
    from folks as p, ancestors AS a   
      where p.id = a.father OR p.id = a.mother
)
select t1.name, t1.dob, t2.name, t2.dob
  from ancestors t1, ancestors t2 
    where exists (select * from ancestors a 
                    where a.father=t1.id AND a.mother=t2.id)
)
select * from ancestor_couples;


--echo # simple recursion with two selects in recursive part
with recursive
ancestors
as
(
  select *
    from folks 
      where name = 'Me'
  union 
  select p.*
    from folks as p, ancestors as fa
      where p.id = fa.father
  union
  select p.*
    from folks as p, ancestors as ma
      where p.id = ma.mother
)
select * from ancestors;


--echo # mutual recursion with renaming
with recursive
ancestor_couples(h_id, h_name, h_dob, h_father, h_mother,
                 w_id, w_name, w_dob, w_father, w_mother)
as
(
  select h.*, w.*
    from folks h, folks w,  coupled_ancestors a
      where a.father = h.id AND a.mother = w.id
  union
  select h.*, w.*
    from folks v, folks h, folks w
      where v.name = 'Me' and
            (v.father = h.id AND v.mother= w.id)
),
coupled_ancestors (id, name, dob, father, mother)
as
(
  select h_id, h_name, h_dob, h_father, h_mother
    from ancestor_couples
  union
  select w_id, w_name, w_dob, w_father, w_mother
    from ancestor_couples
)
select h_name, h_dob, w_name, w_dob
  from ancestor_couples;


--echo # mutual recursion with union all
with recursive
ancestor_couples(h_id, h_name, h_dob, h_father, h_mother,
                 w_id, w_name, w_dob, w_father, w_mother)
as
(
  select h.*, w.*
    from folks h, folks w,  coupled_ancestors a
      where a.father = h.id AND a.mother = w.id
  union 
  select h.*, w.*
    from folks v, folks h, folks w
      where v.name = 'Me' and
            (v.father = h.id AND v.mother= w.id)
),
coupled_ancestors (id, name, dob, father, mother)
as
(
  select h_id, h_name, h_dob, h_father, h_mother
    from ancestor_couples
  union all
  select w_id, w_name, w_dob, w_father, w_mother
    from ancestor_couples
)
select h_name, h_dob, w_name, w_dob
  from ancestor_couples;


--echo # mutual recursion with renaming
with recursive
ancestor_couples(h_id, h_name, h_dob, h_father, h_mother,
                 w_id, w_name, w_dob, w_father, w_mother)
as
(
  select h.*, w.*
    from folks h, folks w,  coupled_ancestors a
      where a.father = h.id AND a.mother = w.id
  union
  select h.*, w.*
    from folks v, folks h, folks w
      where v.name = 'Me' and
            (v.father = h.id AND v.mother= w.id)
),
coupled_ancestors (id, name, dob, father, mother)
as
(
  select h_id, h_name, h_dob, h_father, h_mother
    from ancestor_couples
  union
  select w_id, w_name, w_dob, w_father, w_mother
    from ancestor_couples
)
select h_name, h_dob, w_name, w_dob
  from ancestor_couples;


--echo # mutual recursion with union all
with recursive
ancestor_couples(h_id, h_name, h_dob, h_father, h_mother,
                 w_id, w_name, w_dob, w_father, w_mother)
as
(
  select h.*, w.*
    from folks h, folks w,  coupled_ancestors a
      where a.father = h.id AND a.mother = w.id
),
coupled_ancestors (id, name, dob, father, mother)
as
(
  select * 
    from folks 
      where name = 'Me'
  union all
  select h_id, h_name, h_dob, h_father, h_mother
    from ancestor_couples
  union all
  select w_id, w_name, w_dob, w_father, w_mother
    from ancestor_couples
)
select h_name, h_dob, w_name, w_dob
  from ancestor_couples;

--echo # mutual recursion with one select in the first definition
with recursive
ancestor_couple_ids(h_id, w_id)
as
(
  select a.father, a.mother
    from coupled_ancestors a
      where a.father is not null and a.mother is not null
),
coupled_ancestors (id, name, dob, father, mother)
as
(
  select * 
    from folks 
      where name = 'Me'
  union all
  select p.*
    from folks p, ancestor_couple_ids fa
      where p.id = fa.h_id
  union all
  select p.*
    from folks p, ancestor_couple_ids ma
      where p.id = ma.w_id
)
select *
  from ancestor_couple_ids;


--echo # join of a mutually recursive table with base tables
with recursive
ancestor_couple_ids(h_id, w_id)
as
(
  select a.father, a.mother
    from coupled_ancestors a
      where a.father is not null and a.mother is not null
),
coupled_ancestors (id, name, dob, father, mother)
as
(
  select * 
    from folks 
      where name = 'Me'
  union all
  select p.*
    from folks p, ancestor_couple_ids fa
      where p.id = fa.h_id
  union all
  select p.*
    from folks p, ancestor_couple_ids ma
      where p.id = ma.w_id
)
select h.name, h.dob, w.name, w.dob
  from ancestor_couple_ids c, folks h, folks w
    where c.h_id = h.id and c.w_id= w.id;


--echo # join of two mutually recursive tables
with recursive
ancestor_couple_ids(h_id, w_id)
as
(
  select a.father, a.mother
    from coupled_ancestors a
      where a.father is not null and a.mother is not null
),
coupled_ancestors (id, name, dob, father, mother)
as
(
  select * 
    from folks 
      where name = 'Me'
  union all
  select p.*
    from folks p, ancestor_couple_ids fa
      where p.id = fa.h_id
  union all
  select p.*
    from folks p, ancestor_couple_ids ma
      where p.id = ma.w_id
)
select h.name, h.dob, w.name, w.dob
  from ancestor_couple_ids c, coupled_ancestors h, coupled_ancestors w
    where c.h_id = h.id and c.w_id= w.id;

explain extended
with recursive
ancestor_couple_ids(h_id, w_id)
as
(
  select a.father, a.mother
    from coupled_ancestors a
      where a.father is not null and a.mother is not null
),
coupled_ancestors (id, name, dob, father, mother)
as
(
  select * 
    from folks 
      where name = 'Me'
  union all
  select p.*
    from folks p, ancestor_couple_ids fa
      where p.id = fa.h_id
  union all
  select p.*
    from folks p, ancestor_couple_ids ma
      where p.id = ma.w_id
)
select h.name, h.dob, w.name, w.dob
  from ancestor_couple_ids c, coupled_ancestors h, coupled_ancestors w
    where c.h_id = h.id and c.w_id= w.id;


--echo # simple mutual recursion
with recursive
ancestor_couple_ids(h_id, w_id)
as
(
  select a.father, a.mother
    from coupled_ancestors a
),
coupled_ancestors (id, name, dob, father, mother)
as
(
  select * 
    from folks 
      where name = 'Me'
  union all
  select p.*
    from folks p, ancestor_couple_ids fa
      where p.id = fa.h_id
  union all
  select p.*
    from folks p, ancestor_couple_ids ma
      where p.id = ma.w_id
)
select *
  from ancestor_couple_ids;


--echo # join of two mutually recursive tables
with recursive
ancestor_couple_ids(h_id, w_id)
as
(
  select a.father, a.mother
    from coupled_ancestors a
),
coupled_ancestors (id, name, dob, father, mother)
as
(
  select * 
    from folks 
      where name = 'Me'
  union all
  select p.*
    from folks p, ancestor_couple_ids fa
      where p.id = fa.h_id
  union all
  select p.*
    from folks p, ancestor_couple_ids ma
      where p.id = ma.w_id
)
select h.name, h.dob, w.name, w.dob
  from ancestor_couple_ids c, coupled_ancestors h, coupled_ancestors w
    where c.h_id = h.id and c.w_id= w.id;


--echo # execution of prepared query using a recursive table
prepare stmt1 from "
with recursive 
ancestors
as
(
  select *
    from folks
      where name = 'Me' and dob = '2000-01-01'
  union 
  select p.id, p.name, p.dob, p.father, p.mother
    from folks as p, ancestors AS a
      where p.id = a.father or p.id = a.mother
)
select * from ancestors;
";

execute stmt1;
execute stmt1;

deallocate prepare stmt1;


--echo # view using a recursive table
create view v1 as
with recursive 
ancestors
as
(
  select *
    from folks
      where name = 'Me' and dob = '2000-01-01'
  union 
  select p.id, p.name, p.dob, p.father, p.mother
    from folks as p, ancestors AS a
      where p.id = a.father or p.id = a.mother
)
select * from ancestors;

show create view v1;

select * from v1;

create view v2 as
with recursive
ancestors
as
(
  select *
    from folks 
      where name = 'Me'
  union 
  select p.*
    from folks as p, ancestors as fa
      where p.id = fa.father
  union
  select p.*
    from folks as p, ancestors as ma
      where p.id = ma.mother
)
select * from ancestors;

show create view v2;

select * from v2;

drop view v1,v2;


explain extended
with recursive 
ancestors
as
(
  select *
    from folks
      where name = 'Me' and dob = '2000-01-01'
  union 
  select p.id, p.name, p.dob, p.father, p.mother
    from folks as p, ancestors AS a
      where p.id = a.father or p.id = a.mother
)
select * from ancestors;


--echo # recursive spec with two anchor selects and two recursive ones 
with recursive
ancestor_ids (id)
as
(
  select father from folks where name = 'Me'
  union
  select mother from folks where name = 'Me'
  union
  select father from folks, ancestor_ids a  where folks.id = a.id
  union
  select mother from folks, ancestor_ids a  where folks.id = a.id
),
ancestors 
as
(
  select p.* from folks as p, ancestor_ids as a
    where p.id = a.id
)
select * from ancestors;


--echo # recursive spec using union all 
with recursive
ancestors
as
(
  select *
    from folks 
      where name = 'Me'
  union all
  select p.*
    from folks as p, ancestors as fa
      where p.id = fa.father
  union all
  select p.*
    from folks as p, ancestors as ma
      where p.id = ma.mother
)
select * from ancestors;


--ERROR ER_NOT_STANDARDS_COMPLIANT_RECURSIVE
with recursive
ancestor_ids (id, generation)
as
(
  select father, 1 from folks where name = 'Me' and  father is not null
  union all
  select mother, 1 from folks where name = 'Me' and  mother is not null
  union all
  select father, fa.generation+1 from folks, ancestor_ids fa
    where folks.id = fa.id and (father not in (select id from ancestor_ids))
  union all
  select mother, ma.generation+1 from folks, ancestor_ids ma
    where folks.id = ma.id and (mother not in (select id from ancestor_ids))
)
select generation, name from ancestor_ids a, folks
  where a.id = folks.id;

set standards_compliant_cte=0;

--ERROR ER_WITH_COL_WRONG_LIST
with recursive
ancestor_ids (id, generation)
as
(
  select father from folks where name = 'Me' and  father is not null
  union all
  select mother from folks where name = 'Me' and  mother is not null
  union all
  select father, fa.generation+1 from folks, ancestor_ids fa
    where folks.id = fa.id and (father not in (select id from ancestor_ids))
  union all
  select mother, ma.generation+1 from folks, ancestor_ids ma
    where folks.id = ma.id and (mother not in (select id from ancestor_ids))
)
select generation, name from ancestor_ids a, folks
  where a.id = folks.id;

with recursive
ancestor_ids (id, generation)
as
(
  select father, 1 from folks where name = 'Me' and  father is not null
  union all
  select mother, 1 from folks where name = 'Me' and  mother is not null
  union all
  select father, fa.generation+1 from folks, ancestor_ids fa
    where folks.id = fa.id and father is not null and
          (father not in (select id from ancestor_ids))
  union all
  select mother, ma.generation+1 from folks, ancestor_ids ma
    where folks.id = ma.id and mother is not null and
          (mother not in (select id from ancestor_ids))
)
select generation, name from ancestor_ids a, folks
  where a.id = folks.id;

set standards_compliant_cte=1;

--ERROR ER_NOT_STANDARDS_COMPLIANT_RECURSIVE
with recursive
coupled_ancestor_ids (id)
as
(
  select father from folks where name = 'Me' and father is not null
  union 
  select mother from folks where name = 'Me' and mother is not null
  union
  select n.father 
    from folks, coupled_ancestor_ids fa, coupled_ancestor_ids ma, folks n
      where folks.father = fa.id and folks.mother = ma.id and
            (fa.id = n.id or ma.id = n.id) and
            n.father is not null and n.mother is not null 
  union
  select n.mother 
    from folks, coupled_ancestor_ids fa, coupled_ancestor_ids ma, folks n
      where folks.father = fa.id and folks.mother = ma.id and 
            (fa.id = n.id or ma.id = n.id) and 
            n.father is not null and n.mother is not null 
)
select p.* from coupled_ancestor_ids a, folks p
  where a.id = p.id;

set statement standards_compliant_cte=0 for
with recursive
coupled_ancestor_ids (id)
as
(
  select father from folks where name = 'Me' and father is not null
  union 
  select mother from folks where name = 'Me' and mother is not null
  union
  select n.father 
    from folks, coupled_ancestor_ids fa, coupled_ancestor_ids ma, folks n
      where folks.father = fa.id and folks.mother = ma.id and
            (fa.id = n.id or ma.id = n.id) and
            n.father is not null and n.mother is not null 
  union
  select n.mother 
    from folks, coupled_ancestor_ids fa, coupled_ancestor_ids ma, folks n
      where folks.father = fa.id and folks.mother = ma.id and 
            (fa.id = n.id or ma.id = n.id) and 
            n.father is not null and n.mother is not null 
)
select p.* from coupled_ancestor_ids a, folks p
  where a.id = p.id;

--ERROR ER_NOT_STANDARDS_COMPLIANT_RECURSIVE
with recursive
ancestor_ids (id)
as
(
  select father from folks where name = 'Me'
  union
  select mother from folks where name = 'Me'
  union
  select father from folks left join ancestor_ids a on folks.id = a.id
  union
  select mother from folks left join ancestor_ids a on folks.id = a.id
),
ancestors 
as
(
  select p.* from folks as p, ancestor_ids as a
    where p.id = a.id
)
select * from ancestors;

set statement standards_compliant_cte=0 for
with recursive
ancestor_ids (id)
as
(
  select father from folks where name = 'Me'
  union
  select mother from folks where name = 'Me'
  union
  select father from folks left join ancestor_ids a on folks.id = a.id
  union
  select mother from folks left join ancestor_ids a on folks.id = a.id
),
ancestors 
as
(
  select p.* from folks as p, ancestor_ids as a
    where p.id = a.id
)
select * from ancestors;

with recursive
ancestor_ids (id, generation)
as
(
  select father, 1 from folks where name = 'Me'
  union
  select mother, 1 from folks where name = 'Me'
  union
  select father, a.generation+1 from folks, ancestor_ids a
    where folks.id = a.id
  union
  select mother, a.generation+1 from folks, ancestor_ids a
    where folks.id = a.id
),
ancestors 
as
(
  select generation, name from folks as p, ancestor_ids as a
    where p.id = a.id
)
select * from ancestors;

--ERROR ER_NOT_STANDARDS_COMPLIANT_RECURSIVE
with recursive
ancestor_ids (id, generation)
as
(
  select father, 1 from folks where name = 'Me'
  union
  select mother, 1 from folks where name = 'Me'
  union
  select max(father), max(a.generation)+1 from folks, ancestor_ids a
    where folks.id = a.id
      group by a.generation
  union
  select max(mother), max(a.generation)+1 from folks, ancestor_ids a
    where folks.id = a.id
      group by a.generation
),
ancestors 
as
(
  select generation, name from folks as p, ancestor_ids as a
    where p.id = a.id
)
select * from ancestors;

set statement standards_compliant_cte=0 for
with recursive
ancestor_ids (id, generation)
as
(
  select father, 1 from folks where name = 'Me'
  union
  select mother, 1 from folks where name = 'Me'
  union
  select max(father), a.generation+1 from folks, ancestor_ids a
    where folks.id = a.id
      group by a.generation
  union
  select max(mother), a.generation+1 from folks, ancestor_ids a
    where folks.id = a.id
      group by a.generation
),
ancestors 
as
(
  select generation, name from folks as p, ancestor_ids as a
    where p.id = a.id
)
select * from ancestors;

set statement max_recursive_iterations=1 for
with recursive
ancestor_ids (id, generation)
as
(
  select father, 1 from folks where name = 'Me'
  union
  select mother, 1 from folks where name = 'Me'
  union
  select father, a.generation+1 from folks, ancestor_ids a
    where folks.id = a.id
  union
  select mother, a.generation+1 from folks, ancestor_ids a
    where folks.id = a.id
),
ancestors 
as
(
  select generation, name from folks as p, ancestor_ids as a
    where p.id = a.id
)
select * from ancestors;

--echo # query with recursive tables using key access

alter table folks add primary key (id);

explain
with recursive
ancestors
as
(
  select *
    from folks 
      where name = 'Me'
  union 
  select p.*
    from folks as p, ancestors as fa
      where p.id = fa.father
  union
  select p.*
    from folks as p, ancestors as ma
      where p.id = ma.mother
)
select * from ancestors;


with recursive
ancestors
as
(
  select *
    from folks 
      where name = 'Me'
  union 
  select p.*
    from folks as p, ancestors as fa
      where p.id = fa.father
  union
  select p.*
    from folks as p, ancestors as ma
      where p.id = ma.mother
)
select * from ancestors;


--echo #
--echo # EXPLAIN FORMAT=JSON on a query where one recursive CTE uses another:
--echo #
explain 
with recursive 
prev_gen
as
(
  select folks.*
    from folks, prev_gen
      where folks.id=prev_gen.father or folks.id=prev_gen.mother
  union
  select * 
    from folks
      where name='Me'
),
ancestors
as
(
  select *
    from folks
      where name='Me'
  union 
  select *
    from ancestors
  union
    select *
     from prev_gen
)
select ancestors.name, ancestors.dob from ancestors;

explain FORMAT=JSON
with recursive 
prev_gen
as
(
  select folks.*
    from folks, prev_gen
      where folks.id=prev_gen.father or folks.id=prev_gen.mother
  union
  select * 
    from folks
      where name='Me'
),
ancestors
as
(
  select *
    from folks
      where name='Me2'
  union 
  select *
    from ancestors where id < 234
  union
    select *
     from prev_gen where id < 345
)
select ancestors.name, ancestors.dob from ancestors;

--echo #
explain format=json
with recursive
ancestor_couples(h_id, h_name, h_dob, h_father, h_mother,
                 w_id, w_name, w_dob, w_father, w_mother)
as
(
  select h.*, w.*
    from folks h, folks w,  coupled_ancestors a
      where a.father = h.id AND a.mother = w.id
  union 
  select h.*, w.*
    from folks v, folks h, folks w
      where v.name = 'Me' and
            (v.father = h.id AND v.mother= w.id)
),
coupled_ancestors (id, name, dob, father, mother)
as
(
  select h_id, h_name, h_dob, h_father, h_mother
    from ancestor_couples
  union all
  select w_id, w_name, w_dob, w_father, w_mother
    from ancestor_couples
)
select h_name, h_dob, w_name, w_dob
  from ancestor_couples;


create table my_ancestors
with recursive
ancestor_ids (id)
as
(
  select father from folks where name = 'Me'
  union
  select mother from folks where name = 'Me'
  union
  select father from folks, ancestor_ids a  where folks.id = a.id
  union
  select mother from folks, ancestor_ids a  where folks.id = a.id
)
select p.* from folks as p, ancestor_ids as a where p.id = a.id;

select * from my_ancestors;

delete from my_ancestors;

insert into my_ancestors 
with recursive
ancestor_ids (id)
as
(
  select father from folks where name = 'Me'
  union
  select mother from folks where name = 'Me'
  union
  select father from folks, ancestor_ids a  where folks.id = a.id
  union
  select mother from folks, ancestor_ids a  where folks.id = a.id
)
select p.* from folks as p, ancestor_ids as a where p.id = a.id;

select * from my_ancestors;

drop table my_ancestors;

--echo #
--echo # MDEV-10883: execution of prepared statement from SELECT
--echo #             with recursive CTE that renames columns
--echo #

prepare stmt from"
with recursive
ancestor_ids (id)
as
(
  select father from folks where name = 'Me'
  union
  select mother from folks where name = 'Me'
  union
  select father from folks, ancestor_ids a  where folks.id = a.id
  union
  select mother from folks, ancestor_ids a  where folks.id = a.id
)
select p.* from folks as p, ancestor_ids as a where p.id = a.id;
";
execute stmt;
deallocate prepare stmt;

--echo #
--echo # MDEV-10881: execution of prepared statement from
--echo #             CREATE ... SELECT, INSERT ... SELECT       
--echo #

prepare stmt from"
create table my_ancestors
with recursive
ancestor_ids (id)
as
(
  select father from folks where name = 'Me'
  union
  select mother from folks where name = 'Me'
  union
  select father from folks, ancestor_ids a  where folks.id = a.id
  union
  select mother from folks, ancestor_ids a  where folks.id = a.id
)
select p.* from folks as p, ancestor_ids as a where p.id = a.id;
";
execute stmt;
deallocate prepare stmt;
select * from my_ancestors;

delete from my_ancestors;

prepare stmt from"
insert into my_ancestors
with recursive
ancestor_ids (id)
as
(
  select father from folks where name = 'Me'
  union
  select mother from folks where name = 'Me'
  union
  select father from folks, ancestor_ids a  where folks.id = a.id
  union
  select mother from folks, ancestor_ids a  where folks.id = a.id
)
select p.* from folks as p, ancestor_ids as a where p.id = a.id;
";
execute stmt;
deallocate prepare stmt;
select * from my_ancestors;

drop table my_ancestors;

--echo #
--echo # MDEV-10933: WITH clause together with SELECT in parenthesis
--echo #             CREATE SELECT      
--echo #

create table my_ancestors
(
with recursive
ancestor_ids (id)
as
(
  select father from folks where name = 'Me'
  union
  select mother from folks where name = 'Me'
  union
  select father from folks, ancestor_ids a  where folks.id = a.id
  union
  select mother from folks, ancestor_ids a  where folks.id = a.id
)
select p.* from folks as p, ancestor_ids as a where p.id = a.id
);
select * from my_ancestors;
drop table my_ancestors;

drop table folks;

--echo #
--echo # MDEV-10372: [bb-10.2-mdev9864 tree] EXPLAIN with recursive CTE enters endless recursion
--echo #
create table t1(a int);
insert into t1 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
 
explain format=json 
with recursive t as (select a from t1 union select a+10 from t where a < 1000) 
select  * from t;

drop table t1;


--echo #
--echo # MDEV-10737: recursive union with several anchors at the end
--echo #

WITH RECURSIVE cte(n) AS
  ( SELECT n+1 FROM cte WHERE n < 5 UNION SELECT 1 UNION SELECT 1 )
SELECT * FROM cte;

--echo #
--echo # MDEV-10736: recursive definition with anchor over a table with blob
--echo #

CREATE TABLE t1 (f VARCHAR(1024));
WITH RECURSIVE cte(f) AS
  (SELECT t1.f FROM t1 UNION ALL SELECT cte.f FROM cte) 
SELECT * FROM cte as t;
DROP TABLE t1;

--echo #
--echo # MDEV-10899: mergeable derived in the spec of recursive CTE
--echo #

create table t1 (a int);
insert into t1 values
  (0), (1), (2), (3), (4);
create table t2 (a int);
insert into t2 values
  (1), (2), (3), (4), (5);

with recursive
t1 as
(
select x.a from (select a from t2 where t2.a=3) x
union
select t2.a from t1,t2 where t1.a+1=t2.a
)
select * from t1;

explain
with recursive
t1 as
(
select x.a from (select a from t2 where t2.a=3) x
union
select t2.a from t1,t2 where t1.a+1=t2.a
)
select * from t1;

drop table t1,t2;

--echo #
--echo # MDEV-11278: non-mergeable view in the spec of recursive CTE
--echo #

create table t1 (a int);
insert into t1 values
  (0), (1), (2), (3), (4);
create table t2 (a int);
insert into t2 values
  (1), (2), (3), (4), (5);

create view v1 as
  select a from t2 where a < 3
  union
  select a from t2 where a > 4; 

with recursive
t1 as
(
select a from v1 where a=1 
union
select v1.a from t1,v1 where t1.a+1=v1.a
)
select * from t1;

drop view v1;
drop table t1,t2;


--echo #
--echo # MDEV-11259: recursive CTE with concatenation operation
--echo #

DROP TABLE IF EXISTS edges;
CREATE TABLE edges(
  a int(10) unsigned NOT NULL,
  b int(10) unsigned NOT NULL,
  PRIMARY KEY (a,b),
  KEY b(b)
);

INSERT INTO edges
  VALUES (1,3),(2,1),(2,4),(3,4),(3,5),(3,6),(4,7),(5,1),(5,6),(6,1);

DROP TABLE IF EXISTS edges2;
CREATE VIEW edges2 (a, b) AS 
 SELECT a, b FROM edges   UNION ALL   SELECT b, a FROM edges;

--sorted_result
WITH RECURSIVE transitive_closure(a, b, distance, path_string) AS
( SELECT a, b, 1 AS distance,
   concat(a, '.', b, '.') AS path_string
  FROM edges
 
  UNION ALL
 
  SELECT tc.a, e.b, tc.distance + 1,
  concat(tc.path_string, e.b, '.') AS path_string
  FROM edges AS e
    JOIN transitive_closure AS tc
      ON e.a = tc.b
  WHERE tc.path_string NOT LIKE concat('%', e.b, '.%')
)
SELECT * FROM transitive_closure
ORDER BY a, b, distance;

--sorted_result
WITH RECURSIVE transitive_closure(a, b, distance, path_string) AS
( SELECT a, b, 1 AS distance,
         concat(a, '.', b, '.') AS path_string
  FROM edges
 WHERE a = 1 -- source
 
  UNION ALL
 
  SELECT tc.a, e.b, tc.distance + 1,
         concat(tc.path_string, e.b, '.') AS path_string
  FROM edges AS e
  JOIN transitive_closure AS tc ON e.a = tc.b
 WHERE tc.path_string NOT LIKE concat('%', e.b, '.%')
)
  SELECT * FROM transitive_closure
   WHERE b = 6 -- destination
ORDER BY a, b, distance;

--sorted_result
WITH RECURSIVE transitive_closure(a, b, distance, path_string) AS
( SELECT  a, b, 1 AS distance,
          concat(a, '.', b, '.') AS path_string
  FROM edges2
 
  UNION ALL
 
  SELECT tc.a, e.b, tc.distance + 1,
  concat(tc.path_string, e.b, '.') AS path_string
  FROM edges2 AS e
    JOIN transitive_closure AS tc ON e.a = tc.b
  WHERE tc.path_string NOT LIKE concat('%', e.b, '.%')
)
SELECT * FROM transitive_closure
ORDER BY a, b, distance;

--sorted_result
WITH RECURSIVE transitive_closure(a, b, distance, path_string)
AS
( SELECT a, b, 1 AS distance,
         concat(a, '.', b, '.') AS path_string
  FROM edges2
 
  UNION ALL
 
  SELECT tc.a, e.b, tc.distance + 1,
         concat(tc.path_string, e.b, '.') AS path_string
  FROM edges2 AS e
  JOIN transitive_closure AS tc ON e.a = tc.b
 WHERE tc.path_string NOT LIKE concat('%', e.b, '.%')
)
SELECT a, b, min(distance) AS dist FROM transitive_closure
GROUP BY a, b
ORDER BY a, dist, b;

DROP VIEW edges2;
DROP TABLE edges;


--echo #
--echo # MDEV-11674: recursive CTE table that cannot be stored
--echo #             in a heap table
--echo #

create table t1 (id int, test_data varchar(36));

insert into t1(id, test_data)
select id, test_data
    from (
        with recursive data_generator(id, test_data) as (
                select 1 as id, uuid() as test_data
                union all
                select id + 1, uuid() from data_generator where id < 150000
            )
        select * from data_generator
    ) as a;

drop table t1;

--echo #
--echo # MDEV-10773: ANALYZE for query with recursive CTE
--echo #

--replace_regex /"r_total_time_ms": [0-9]*[.]?[0-9]*(e[-+]?[0-9]+)?/"r_total_time_ms": "REPLACED"/
analyze format=json 
with recursive src(counter) as 
(select 1 
 union 
 select counter+1 from src where counter<10
) select * from src;