File: 06_with_table_expression.t

package info (click to toggle)
libsql-abstract-more-perl 1.43-1
  • links: PTS, VCS
  • area: main
  • in suites: forky, sid, trixie
  • size: 260 kB
  • sloc: perl: 1,037; makefile: 2
file content (242 lines) | stat: -rw-r--r-- 7,176 bytes parent folder | download | duplicates (3)
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
use strict;
use warnings;
no warnings 'qw';

use SQL::Abstract::More;

use Test::More;
use SQL::Abstract::Test import => [qw/is_same_sql_bind/];

my $sqla = SQL::Abstract::More->new;
my ($sql, @bind, $join);


# NOTE: test cases below are inspired from the SQLite documentation for WITH clauses :
# https://sqlite.org/lang_with.html


# simple graph retrieval
($sql, @bind) = $sqla->with_recursive(
  -table     => 'nodes',
  -columns   => [qw/x/],
  -as_select => {-from      => 'DUAL',
                 -columns   => [qw/59/],
                 -union_all => [-from    => [-join => qw/edge {bb=x} nodes/],
                                -columns => [qw/aa/],
                              ],
                },
 )->select(
   -columns => 'x',
   -from    => 'nodes',
  );
is_same_sql_bind(
  $sql, \@bind,
  q{WITH RECURSIVE nodes(x) AS (          SELECT 59 FROM DUAL
                                UNION ALL SELECT aa FROM edge INNER JOIN nodes ON edge.bb=nodes.x)
    SELECT x FROM nodes},
  [],
  "1-branch graph retrieval",
  );



# graph retrieval with 2 branches
($sql, @bind) = $sqla->with_recursive(
  -table     => 'nodes',
  -columns   => [qw/x/],
  -as_select => {-from      => 'DUAL',
                 -columns   => [qw/59/],
                 -union_all => [-from    => [-join => qw/edge {bb=x} nodes/],
                                -columns => [qw/aa/],
                                -union_all => [-from  => [-join => qw/edge {aa=x} nodes/],
                                               -columns => [qw/bb/]],
                              ],
                },
 )->select(
   -columns => 'x',
   -from    => 'nodes',
  );
is_same_sql_bind(
  $sql, \@bind,
  q{WITH RECURSIVE nodes(x) AS (          SELECT 59 FROM DUAL
                                UNION ALL SELECT aa FROM edge INNER JOIN nodes ON edge.bb=nodes.x
                                UNION ALL SELECT bb FROM edge INNER JOIN nodes ON edge.aa=nodes.x)
    SELECT x FROM nodes},
  [],
  "2-branch graph retrieval",
  );


# several table expressions in the same WITH statement
($sql, @bind) = $sqla->with_recursive(
  [ -table     => 'parent_of',
    -columns   => [qw/name parent/],
    -as_select => {-columns => [qw/name mom/],
                   -from    => 'family',
                   -where   => {age => {'>' => 16.1}},
                   -union   => [-columns => [qw/name dad/],
                                -where   => {age => {'>' => 16.2}},
                                -from    => 'family']},
   ],
  [ -table     => 'ancestor_of_alice',
    -columns   => [qw/name/],
    -as_select => {-columns => [qw/parent/],
                   -from    => 'parent_of',
                   -where   => {name => 'Alice'},
                   -union_all => [-columns => [qw/parent/],
                                    -from => [qw/-join parent_of {name} ancestor_of_alice/]],
               },
   ],
  )->select(
   -columns => 'family.name',
   -from    => [qw/-join ancestor_of_alice {name} family/],
   -where   => {died                     => undef},
   -order_by => 'born',
  );

is_same_sql_bind(
  $sql, \@bind,
  q{WITH RECURSIVE
     parent_of(name, parent) AS
       (SELECT name, mom FROM family WHERE age > ?
        UNION SELECT name, dad FROM family WHERE age > ?),
     ancestor_of_alice(name) AS
       (SELECT parent FROM parent_of WHERE name = ?
        UNION ALL
        SELECT parent FROM parent_of INNER JOIN ancestor_of_alice USING(name))
    SELECT family.name FROM ancestor_of_alice INNER JOIN family USING(name)
      WHERE died IS NULL
      ORDER BY born},
  [16.1, 16.2, 'Alice'],
  "several CTEs in the same WITH clause",
  );

# auxiliary data for insert / update / delete
my $sqla2 = $sqla->with_recursive(
  -table     => 'nodes',
  -columns   => [qw/x/],
  -as_select => {-from      => 'DUAL',
                 -columns   => [qw/59/],
                 -union_all => [-from    => [-join => qw/edge {bb=x} nodes/],
                                -columns => [qw/aa/],
                              ],
                },
 );




# insert
($sql, @bind) = $sqla2->insert(
  -into    => "edge",
  -columns => ['aa'],
  -select  => {-columns => 'x', -from => "nodes"},
 );
is_same_sql_bind(
  $sql, \@bind,
  q{WITH RECURSIVE nodes(x) AS (          SELECT 59 FROM DUAL
                                UNION ALL SELECT aa FROM edge INNER JOIN nodes ON edge.bb=nodes.x)
    INSERT INTO edge(aa) SELECT x FROM nodes},
  [],
  "insert",
  );


# update
my @subquery = $sqla->select(-columns => 'x', -from => "nodes");
($sql, @bind) = $sqla2->update(
  -table  => "edge",
  -set    => {foo => "bar"},
  -where  => {aa => {-in => \\@subquery}}
 );
is_same_sql_bind(
  $sql, \@bind,
  q{WITH RECURSIVE nodes(x) AS (          SELECT 59 FROM DUAL
                                UNION ALL SELECT aa FROM edge INNER JOIN nodes ON edge.bb=nodes.x)
    UPDATE edge SET foo = ? 
    WHERE aa IN (SELECT x FROM nodes)},
  ["bar"],
  "update",
  );


# delete
($sql, @bind) = $sqla2->delete(
  -from  => "edge",
  -where  => {aa => {-in => \\@subquery}}
 );
is_same_sql_bind(
  $sql, \@bind,
  q{WITH RECURSIVE nodes(x) AS (          SELECT 59 FROM DUAL
                                UNION ALL SELECT aa FROM edge INNER JOIN nodes ON edge.bb=nodes.x)
    DELETE FROM edge
    WHERE aa IN (SELECT x FROM nodes)},
  [],
  "delete",
  );



# -final_clause -- example with an Oracle CYCLE clause
($sql, @bind) = $sqla->with_recursive(
  -table     => 'nodes',
  -columns   => [qw/x/],
  -as_select => {-from      => 'DUAL',
                 -columns   => [qw/59/],
                 -union_all => [-from    => [-join => qw/edge {bb=x} nodes/],
                                -columns => [qw/aa/],
                              ],
                },
  -final_clause => "CYCLE x SET is_cycle TO '1' DEFAULT '0'",
 )->select(
   -columns => 'x',
   -from    => 'nodes',
  );
is_same_sql_bind(
  $sql, \@bind,
  q{WITH RECURSIVE nodes(x) AS (          SELECT 59 FROM DUAL
                                UNION ALL SELECT aa FROM edge INNER JOIN nodes ON edge.bb=nodes.x)
                            CYCLE x SET is_cycle TO '1' DEFAULT '0'
    SELECT x FROM nodes},
  [],
  "-final_clause",
  );


# disable WITH in subqueries -- UNION
($sql, @bind) = $sqla2->select(
  -columns => [qw/a b/],
  -from    => "Foo",
  -union   => [-columns => [qw/c d/],
               -from    => 'Bar']
 );
is_same_sql_bind(
  $sql, \@bind,
  q{WITH RECURSIVE nodes(x) AS (          SELECT 59 FROM DUAL
                                UNION ALL SELECT aa FROM edge INNER JOIN nodes ON edge.bb=nodes.x)
    SELECT a, b FROM Foo UNION SELECT c, d FROM Bar},
  [],
  "subquery - union"
);


# disable WITH in subqueries -- GROUP BY
($sql, @bind) = $sqla2->select(
  -columns => [qw/a count(*)/],
  -from     => "Foo",
  -group_by => "a",
  -having   => {"count(*)" => {">" => 1}},
 );
is_same_sql_bind(
  $sql, \@bind,
  q{WITH RECURSIVE nodes(x) AS (          SELECT 59 FROM DUAL
                                UNION ALL SELECT aa FROM edge INNER JOIN nodes ON edge.bb=nodes.x)
    SELECT a, count(*) FROM Foo GROUP BY a HAVING count(*) > ?},
  [1],
  "subquery - group by"
);


done_testing();