File: test_values.py

package info (click to toggle)
sqlalchemy 2.0.44%2Bds1-1
  • links: PTS
  • area: main
  • in suites: forky, sid
  • size: 26,740 kB
  • sloc: python: 414,900; makefile: 231; sh: 7
file content (742 lines) | stat: -rw-r--r-- 24,621 bytes parent folder | download
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
from sqlalchemy import alias
from sqlalchemy import Column
from sqlalchemy import column
from sqlalchemy import Enum
from sqlalchemy import exc
from sqlalchemy import ForeignKey
from sqlalchemy import Integer
from sqlalchemy import select
from sqlalchemy import String
from sqlalchemy import Table
from sqlalchemy import table
from sqlalchemy import testing
from sqlalchemy import true
from sqlalchemy import values
from sqlalchemy.engine import default
from sqlalchemy.sql import func
from sqlalchemy.sql.compiler import FROM_LINTING
from sqlalchemy.testing import AssertsCompiledSQL
from sqlalchemy.testing import expect_raises_message
from sqlalchemy.testing import fixtures
from sqlalchemy.testing import is_
from sqlalchemy.testing import is_not
from sqlalchemy.util import OrderedDict


class ValuesTest(fixtures.TablesTest, AssertsCompiledSQL):
    __dialect__ = default.DefaultDialect(supports_native_boolean=True)

    run_setup_bind = None

    run_create_tables = None

    @classmethod
    def define_tables(cls, metadata):
        Table(
            "people",
            metadata,
            Column("people_id", Integer, primary_key=True),
            Column("age", Integer),
            Column("name", String(30)),
        )
        Table(
            "bookcases",
            metadata,
            Column("bookcase_id", Integer, primary_key=True),
            Column(
                "bookcase_owner_id", Integer, ForeignKey("people.people_id")
            ),
            Column("bookcase_shelves", Integer),
            Column("bookcase_width", Integer),
        )
        Table(
            "books",
            metadata,
            Column("book_id", Integer, primary_key=True),
            Column(
                "bookcase_id", Integer, ForeignKey("bookcases.bookcase_id")
            ),
            Column("book_owner_id", Integer, ForeignKey("people.people_id")),
            Column("book_weight", Integer),
        )

    def test_wrong_number_of_elements(self):
        v1 = values(
            column("CaseSensitive", Integer),
            column("has spaces", String),
            name="Spaces and Cases",
        ).data([(1, "textA", 99), (2, "textB", 88)])

        with expect_raises_message(
            exc.ArgumentError,
            r"Wrong number of elements for 2-tuple: \(1, 'textA', 99\)",
        ):
            str(v1)

    @testing.fixture
    def _auto_proxy_fixture(self):
        c1 = column("q", Integer)
        c2 = column("p", Integer)
        t = table("t", c1)  # noqa: F841

        v1 = values(c1, c2).data([(1, 2), (3, 4)])

        return c1, c2, t, v1

    def test_auto_proxy_col_ownership(self, _auto_proxy_fixture):
        """test #10280"""

        c1, c2, t, v1 = _auto_proxy_fixture

        is_(c2, v1.c.p)
        is_not(c1, v1.c.q)

    def test_auto_proxy_select_c_col(self, _auto_proxy_fixture):
        """test #10280"""

        c1, c2, t, v1 = _auto_proxy_fixture
        self.assert_compile(select(t.c.q), "SELECT t.q FROM t")
        self.assert_compile(
            select(v1.c.q),
            "SELECT q FROM (VALUES (:param_1, :param_2), "
            "(:param_3, :param_4))",
            checkparams={
                "param_1": 1,
                "param_2": 2,
                "param_3": 3,
                "param_4": 4,
            },
        )

    def test_auto_proxy_select_direct_col(self, _auto_proxy_fixture):
        """test #10280"""

        c1, c2, t, v1 = _auto_proxy_fixture
        self.assert_compile(select(c1), "SELECT t.q FROM t")

        # for VALUES, the column does not have its set_parent called up front.
        # this is to make the construction of values() faster, as the values.c
        # use case is not required in order to use the construct
        self.assert_compile(select(c2), "SELECT p")

        # once we call v.c, then it's set up.
        # patch for #10280 added an extra step to make sure this works
        # even after the previous compile is called.
        # is this how it should work?  not sure, just testing how it is
        # right now
        v1.c.p

        self.assert_compile(
            select(c2),
            "SELECT p FROM (VALUES (:param_1, :param_2), "
            "(:param_3, :param_4))",
            checkparams={
                "param_1": 1,
                "param_2": 2,
                "param_3": 3,
                "param_4": 4,
            },
        )

    def test_auto_proxy_make_new_values(self, _auto_proxy_fixture):
        """test #10280"""

        c1, c2, t, v1 = _auto_proxy_fixture

        self.assert_compile(
            select(v1.c.p),
            "SELECT p FROM (VALUES (:param_1, :param_2), "
            "(:param_3, :param_4))",
            checkparams={
                "param_1": 1,
                "param_2": 2,
                "param_3": 3,
                "param_4": 4,
            },
        )

        v2 = values(c1, c2).data([(5, 6)])
        self.assert_compile(
            select(v2.c.p),
            "SELECT p FROM (VALUES (:param_1, :param_2))",
            checkparams={"param_1": 5, "param_2": 6},
        )

    def test_column_quoting(self):
        v1 = values(
            column("CaseSensitive", Integer),
            column("has spaces", String),
            column("number", Integer),
            name="Spaces and Cases",
        ).data([(1, "textA", 99), (2, "textB", 88)])
        self.assert_compile(
            select(v1),
            'SELECT "Spaces and Cases"."CaseSensitive", '
            '"Spaces and Cases"."has spaces", "Spaces and Cases".number FROM '
            "(VALUES (:param_1, :param_2, :param_3), "
            "(:param_4, :param_5, :param_6)) "
            'AS "Spaces and Cases" ("CaseSensitive", "has spaces", number)',
        )

    def test_values_in_scalar_subq(self):
        """test #9772"""

        people = self.tables.people
        table_value_constructor = values(
            Column("v1", Integer), name="tvc"
        ).data(
            [
                (people.c.people_id,),
                (people.c.age,),
                (people.c.name,),
            ]
        )

        maximum = select(func.max(table_value_constructor.c.v1))
        maximum_subquery = maximum.scalar_subquery()
        query = select(people.c.people_id, maximum_subquery)
        self.assert_compile(
            query,
            "SELECT people.people_id, "
            "(SELECT max(tvc.v1) AS max_1 FROM "
            "(VALUES (people.people_id), (people.age), (people.name)) "
            "AS tvc (v1)) AS anon_1 FROM people",
        )

    def test_values_in_select_cte_params(self):
        cte1 = select(
            values(
                column("col1", String),
                column("col2", Integer),
                name="temp_table",
            ).data([("a", 2), ("b", 3)])
        ).cte("cte1")

        cte2 = select(cte1.c.col1).where(cte1.c.col1 == "q").cte("cte2")
        stmt = select(cte2.c.col1)

        dialect = default.DefaultDialect()
        dialect.positional = True
        dialect.paramstyle = "numeric"
        self.assert_compile(
            stmt,
            "WITH cte1 AS (SELECT temp_table.col1 AS col1, "
            "temp_table.col2 AS col2 FROM (VALUES (:1, :2), (:3, :4)) AS "
            "temp_table (col1, col2)), "
            "cte2 AS "
            "(SELECT cte1.col1 AS col1 FROM cte1 WHERE cte1.col1 = :5) "
            "SELECT cte2.col1 FROM cte2",
            checkpositional=("a", 2, "b", 3, "q"),
            dialect=dialect,
        )

        self.assert_compile(
            stmt,
            "WITH cte1 AS (SELECT temp_table.col1 AS col1, "
            "temp_table.col2 AS col2 FROM (VALUES ('a', 2), ('b', 3)) "
            "AS temp_table (col1, col2)), "
            "cte2 AS "
            "(SELECT cte1.col1 AS col1 FROM cte1 WHERE cte1.col1 = 'q') "
            "SELECT cte2.col1 FROM cte2",
            literal_binds=True,
            dialect=dialect,
        )

    def test_values_in_select_cte_literal_binds(self):
        cte1 = select(
            values(
                column("col1", String),
                column("col2", Integer),
                name="temp_table",
                literal_binds=True,
            ).data([("a", 2), ("b", 3)])
        ).cte("cte1")

        cte2 = select(cte1.c.col1).where(cte1.c.col1 == "q").cte("cte2")
        stmt = select(cte2.c.col1)

        self.assert_compile(
            stmt,
            "WITH cte1 AS (SELECT temp_table.col1 AS col1, "
            "temp_table.col2 AS col2 FROM (VALUES ('a', 2), ('b', 3)) "
            "AS temp_table (col1, col2)), "
            "cte2 AS "
            "(SELECT cte1.col1 AS col1 FROM cte1 WHERE cte1.col1 = :col1_1) "
            "SELECT cte2.col1 FROM cte2",
            checkparams={"col1_1": "q"},
        )

    @testing.variation("values_named", [True, False])
    @testing.variation("cte_named", [True, False])
    @testing.variation("literal_binds", [True, False])
    @testing.variation("recursive", [True, False])
    def test_direct_cte(
        self, values_named, cte_named, literal_binds, recursive
    ):
        """test #12734"""

        cte1 = (
            values(
                column("col1", String),
                column("col2", Integer),
                literal_binds=bool(literal_binds),
                name="some name" if values_named else None,
            )
            .data([("a", 2), ("b", 3)])
            .cte("cte1" if cte_named else None, recursive=bool(recursive))
        )

        stmt = select(cte1.c.col1)

        if cte_named:
            cte_name = "cte1"
        elif values_named:
            cte_name = "some_name_1"
        else:
            cte_name = "anon_1"

        if literal_binds:
            params = "('a', 2), ('b', 3)"
        else:
            params = "(:param_1, :param_2), (:param_3, :param_4)"

        recursive_str = "RECURSIVE " if recursive else ""

        self.assert_compile(
            stmt,
            f"WITH {recursive_str}{cte_name}(col1, col2) AS "
            f"(VALUES {params}) "
            f"SELECT {cte_name}.col1 FROM {cte_name}",
            checkparams=(
                {
                    "param_1": "a",
                    "param_2": 2,
                    "param_3": "b",
                    "param_4": 3,
                }
                if not literal_binds
                else {}
            ),
        )

    def test_add_cte_one(self):
        cte1 = (
            values(
                column("col1", String),
                column("col2", Integer),
                name="some_name",
            ).data([("a", 2), ("b", 3)])
        ).add_cte(select(1).cte())

        self.assert_compile(
            cte1.select(),
            "WITH anon_1 AS (SELECT 1) "
            "SELECT some_name.col1, some_name.col2 FROM "
            "(VALUES (:param_1, :param_2), "
            "(:param_3, :param_4)) AS some_name (col1, col2)",
        )

    def test_add_cte_two(self):
        cte1 = (
            (
                values(
                    column("col1", String),
                    column("col2", Integer),
                    name="some_name",
                ).data([("a", 2), ("b", 3)])
            )
            .add_cte(select(1).cte())
            .cte()
        )

        self.assert_compile(
            cte1.select(),
            "WITH anon_1 AS (SELECT 1), some_name_1(col1, col2) AS "
            "(VALUES (:param_1, :param_2), (:param_3, :param_4)) "
            "SELECT some_name_1.col1, some_name_1.col2 FROM some_name_1",
        )

    def test_no_cte_with_lateral(self):
        values_ = (
            values(
                column("col1", String),
                column("col2", Integer),
                name="some_name",
            )
            .data([("a", 2), ("b", 3)])
            .lateral()
        )

        cte = values_.cte()

        with expect_raises_message(
            exc.CompileError,
            "Can't use a LATERAL VALUES expression inside of a CTE",
        ):
            cte.select().compile()

    @testing.fixture
    def literal_parameter_fixture(self):
        def go(literal_binds, omit=None):
            cols = [
                column("mykey", Integer),
                column("mytext", String),
                column("myint", Integer),
            ]
            if omit:
                for idx in omit:
                    cols[idx] = column(cols[idx].name)

            return values(
                *cols, name="myvalues", literal_binds=literal_binds
            ).data([(1, "textA", 99), (2, "textB", 88)])

        return go

    @testing.fixture
    def tricky_types_parameter_fixture(self):
        class SomeEnum:
            # Implements PEP 435 in the minimal fashion needed by SQLAlchemy
            __members__ = OrderedDict()

            def __init__(self, name, value, alias=None):
                self.name = name
                self.value = value
                self.__members__[name] = self
                setattr(self.__class__, name, self)
                if alias:
                    self.__members__[alias] = self
                    setattr(self.__class__, alias, self)

        one = SomeEnum("one", 1)
        two = SomeEnum("two", 2)

        class MumPyString(str):
            """some kind of string, can't imagine where such a thing might
            be found

            """

        class MumPyNumber(int):
            """some kind of int, can't imagine where such a thing might
            be found

            """

        def go(literal_binds, omit=None):
            cols = [
                column("mykey", Integer),
                column("mytext", String),
                column("myenum", Enum(SomeEnum)),
            ]
            if omit:
                for idx in omit:
                    cols[idx] = column(cols[idx].name)

            return values(
                *cols, name="myvalues", literal_binds=literal_binds
            ).data(
                [
                    (MumPyNumber(1), MumPyString("textA"), one),
                    (MumPyNumber(2), MumPyString("textB"), two),
                ]
            )

        return go

    def test_bound_parameters(self, literal_parameter_fixture):
        literal_parameter_fixture = literal_parameter_fixture(False)

        stmt = select(literal_parameter_fixture)

        self.assert_compile(
            stmt,
            "SELECT myvalues.mykey, myvalues.mytext, myvalues.myint FROM "
            "(VALUES (:param_1, :param_2, :param_3), "
            "(:param_4, :param_5, :param_6)"
            ") AS myvalues (mykey, mytext, myint)",
            checkparams={
                "param_1": 1,
                "param_2": "textA",
                "param_3": 99,
                "param_4": 2,
                "param_5": "textB",
                "param_6": 88,
            },
        )

    def test_literal_parameters(self, literal_parameter_fixture):
        literal_parameter_fixture = literal_parameter_fixture(True)

        stmt = select(literal_parameter_fixture)

        self.assert_compile(
            stmt,
            "SELECT myvalues.mykey, myvalues.mytext, myvalues.myint FROM "
            "(VALUES (1, 'textA', 99), (2, 'textB', 88)"
            ") AS myvalues (mykey, mytext, myint)",
            checkparams={},
        )

    def test_literal_parameters_not_every_type_given(
        self, literal_parameter_fixture
    ):
        literal_parameter_fixture = literal_parameter_fixture(True, omit=(1,))

        stmt = select(literal_parameter_fixture)

        self.assert_compile(
            stmt,
            "SELECT myvalues.mykey, myvalues.mytext, myvalues.myint FROM "
            "(VALUES (1, 'textA', 99), (2, 'textB', 88)"
            ") AS myvalues (mykey, mytext, myint)",
            checkparams={},
        )

    def test_use_cols_tricky_not_every_type_given(
        self, tricky_types_parameter_fixture
    ):
        literal_parameter_fixture = tricky_types_parameter_fixture(
            True, omit=(1,)
        )

        stmt = select(literal_parameter_fixture)

        with expect_raises_message(
            exc.CompileError,
            r"No literal value renderer is available for literal "
            r"value \"'textA'\" with datatype NULL",
        ):
            str(stmt)

    def test_use_cols_for_types(self, tricky_types_parameter_fixture):
        literal_parameter_fixture = tricky_types_parameter_fixture(True)

        stmt = select(literal_parameter_fixture)

        self.assert_compile(
            stmt,
            "SELECT myvalues.mykey, myvalues.mytext, myvalues.myenum FROM "
            "(VALUES (1, 'textA', 'one'), (2, 'textB', 'two')"
            ") AS myvalues (mykey, mytext, myenum)",
            checkparams={},
        )

    def test_anon_alias(self):
        people = self.tables.people
        values_ = (
            values(
                column("bookcase_id", Integer),
                column("bookcase_owner_id", Integer),
            )
            .data([(1, 1), (2, 1), (3, 2), (3, 3)])
            .alias()
        )
        stmt = select(people, values_).select_from(
            people.join(
                values_, values_.c.bookcase_owner_id == people.c.people_id
            )
        )
        self.assert_compile(
            stmt,
            "SELECT people.people_id, people.age, people.name, "
            "anon_1.bookcase_id, anon_1.bookcase_owner_id FROM people "
            "JOIN (VALUES (:param_1, :param_2), (:param_3, :param_4), "
            "(:param_5, :param_6), (:param_7, :param_8)) AS anon_1 "
            "(bookcase_id, bookcase_owner_id) "
            "ON people.people_id = anon_1.bookcase_owner_id",
        )

    def test_with_join_unnamed(self):
        people = self.tables.people
        values_ = values(
            column("column1", Integer),
            column("column2", Integer),
        ).data([(1, 1), (2, 1), (3, 2), (3, 3)])
        stmt = select(people, values_).select_from(
            people.join(values_, values_.c.column2 == people.c.people_id)
        )
        self.assert_compile(
            stmt,
            "SELECT people.people_id, people.age, people.name, column1, "
            "column2 FROM people JOIN (VALUES (:param_1, :param_2), "
            "(:param_3, :param_4), (:param_5, :param_6), "
            "(:param_7, :param_8)) "
            "ON people.people_id = column2",
            checkparams={
                "param_1": 1,
                "param_2": 1,
                "param_3": 2,
                "param_4": 1,
                "param_5": 3,
                "param_6": 2,
                "param_7": 3,
                "param_8": 3,
            },
        )

    def test_with_join_named(self):
        people = self.tables.people
        values_ = values(
            column("bookcase_id", Integer),
            column("bookcase_owner_id", Integer),
            name="bookcases",
        ).data([(1, 1), (2, 1), (3, 2), (3, 3)])
        stmt = select(people, values_).select_from(
            people.join(
                values_, values_.c.bookcase_owner_id == people.c.people_id
            )
        )
        self.assert_compile(
            stmt,
            "SELECT people.people_id, people.age, people.name, "
            "bookcases.bookcase_id, bookcases.bookcase_owner_id FROM people "
            "JOIN (VALUES (:param_1, :param_2), (:param_3, :param_4), "
            "(:param_5, :param_6), (:param_7, :param_8)) AS bookcases "
            "(bookcase_id, bookcase_owner_id) "
            "ON people.people_id = bookcases.bookcase_owner_id",
            checkparams={
                "param_1": 1,
                "param_2": 1,
                "param_3": 2,
                "param_4": 1,
                "param_5": 3,
                "param_6": 2,
                "param_7": 3,
                "param_8": 3,
            },
        )

    def test_with_aliased_join(self):
        people = self.tables.people
        values_ = (
            values(
                column("bookcase_id", Integer),
                column("bookcase_owner_id", Integer),
            )
            .data([(1, 1), (2, 1), (3, 2), (3, 3)])
            .alias("bookcases")
        )

        stmt = select(people, values_).select_from(
            people.join(
                values_, values_.c.bookcase_owner_id == people.c.people_id
            )
        )
        self.assert_compile(
            stmt,
            "SELECT people.people_id, people.age, people.name, "
            "bookcases.bookcase_id, bookcases.bookcase_owner_id FROM people "
            "JOIN (VALUES (:param_1, :param_2), (:param_3, :param_4), "
            "(:param_5, :param_6), (:param_7, :param_8)) AS bookcases "
            "(bookcase_id, bookcase_owner_id) "
            "ON people.people_id = bookcases.bookcase_owner_id",
            checkparams={
                "param_1": 1,
                "param_2": 1,
                "param_3": 2,
                "param_4": 1,
                "param_5": 3,
                "param_6": 2,
                "param_7": 3,
                "param_8": 3,
            },
        )

    def test_with_standalone_aliased_join(self):
        people = self.tables.people
        values_ = values(
            column("bookcase_id", Integer),
            column("bookcase_owner_id", Integer),
        ).data([(1, 1), (2, 1), (3, 2), (3, 3)])
        values_ = alias(values_, "bookcases")

        stmt = select(people, values_).select_from(
            people.join(
                values_, values_.c.bookcase_owner_id == people.c.people_id
            )
        )
        self.assert_compile(
            stmt,
            "SELECT people.people_id, people.age, people.name, "
            "bookcases.bookcase_id, bookcases.bookcase_owner_id FROM people "
            "JOIN (VALUES (:param_1, :param_2), (:param_3, :param_4), "
            "(:param_5, :param_6), (:param_7, :param_8)) AS bookcases "
            "(bookcase_id, bookcase_owner_id) "
            "ON people.people_id = bookcases.bookcase_owner_id",
            checkparams={
                "param_1": 1,
                "param_2": 1,
                "param_3": 2,
                "param_4": 1,
                "param_5": 3,
                "param_6": 2,
                "param_7": 3,
                "param_8": 3,
            },
        )

    def test_lateral(self):
        people = self.tables.people
        values_ = (
            values(
                column("bookcase_id", Integer),
                column("bookcase_owner_id", Integer),
                name="bookcases",
            )
            .data([(1, 1), (2, 1), (3, 2), (3, 3)])
            .lateral()
        )
        stmt = select(people, values_).select_from(
            people.join(values_, true())
        )
        self.assert_compile(
            stmt,
            "SELECT people.people_id, people.age, people.name, "
            "bookcases.bookcase_id, bookcases.bookcase_owner_id FROM people "
            "JOIN LATERAL (VALUES (:param_1, :param_2), (:param_3, :param_4), "
            "(:param_5, :param_6), (:param_7, :param_8)) AS bookcases "
            "(bookcase_id, bookcase_owner_id) "
            "ON true",
            checkparams={
                "param_1": 1,
                "param_2": 1,
                "param_3": 2,
                "param_4": 1,
                "param_5": 3,
                "param_6": 2,
                "param_7": 3,
                "param_8": 3,
            },
        )

    def test_from_linting_named(self):
        people = self.tables.people
        values_ = values(
            column("bookcase_id", Integer),
            column("bookcase_owner_id", Integer),
            name="bookcases",
        ).data([(1, 1), (2, 1), (3, 2), (3, 3)])
        stmt = select(people, values_)

        with testing.expect_warnings(
            r"SELECT statement has a cartesian product between FROM "
            r'element\(s\) "(?:bookcases|people)" and '
            r'FROM element "(?:people|bookcases)"'
        ):
            stmt.compile(linting=FROM_LINTING)

    def test_from_linting_unnamed(self):
        people = self.tables.people
        values_ = values(
            column("bookcase_id", Integer),
            column("bookcase_owner_id", Integer),
        ).data([(1, 1), (2, 1), (3, 2), (3, 3)])
        stmt = select(people, values_)

        with testing.expect_warnings(
            r"SELECT statement has a cartesian product between FROM "
            r'element\(s\) "(?:\(unnamed VALUES element\)|people)" and '
            r'FROM element "(?:people|\(unnamed VALUES element\))"'
        ):
            stmt.compile(linting=FROM_LINTING)