File: test_case_statement.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 (355 lines) | stat: -rw-r--r-- 10,900 bytes parent folder | download | duplicates (2)
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
from sqlalchemy import and_
from sqlalchemy import case
from sqlalchemy import cast
from sqlalchemy import Column
from sqlalchemy import func
from sqlalchemy import Integer
from sqlalchemy import literal_column
from sqlalchemy import select
from sqlalchemy import String
from sqlalchemy import Table
from sqlalchemy import testing
from sqlalchemy import text
from sqlalchemy.sql import column
from sqlalchemy.sql import table
from sqlalchemy.sql.sqltypes import NullType
from sqlalchemy.testing import AssertsCompiledSQL
from sqlalchemy.testing import eq_
from sqlalchemy.testing import fixtures


class CaseTest(fixtures.TablesTest, AssertsCompiledSQL):
    __dialect__ = "default"

    run_inserts = "once"
    run_deletes = "never"

    @classmethod
    def define_tables(cls, metadata):
        Table(
            "info_table",
            metadata,
            Column("pk", Integer, primary_key=True),
            Column("info", String(30)),
        )

    @classmethod
    def insert_data(cls, connection):
        info_table = cls.tables.info_table

        connection.execute(
            info_table.insert(),
            [
                {"pk": 1, "info": "pk_1_data"},
                {"pk": 2, "info": "pk_2_data"},
                {"pk": 3, "info": "pk_3_data"},
                {"pk": 4, "info": "pk_4_data"},
                {"pk": 5, "info": "pk_5_data"},
                {"pk": 6, "info": "pk_6_data"},
            ],
        )
        connection.commit()

    @testing.requires.subqueries
    def test_case(self, connection):
        info_table = self.tables.info_table

        inner = select(
            case(
                (info_table.c.pk < 3, "lessthan3"),
                (and_(info_table.c.pk >= 3, info_table.c.pk < 7), "gt3"),
            ).label("x"),
            info_table.c.pk,
            info_table.c.info,
        ).select_from(info_table)

        inner_result = connection.execute(inner).all()

        # Outputs:
        # lessthan3 1 pk_1_data
        # lessthan3 2 pk_2_data
        # gt3 3 pk_3_data
        # gt3 4 pk_4_data
        # gt3 5 pk_5_data
        # gt3 6 pk_6_data
        eq_(
            inner_result,
            [
                ("lessthan3", 1, "pk_1_data"),
                ("lessthan3", 2, "pk_2_data"),
                ("gt3", 3, "pk_3_data"),
                ("gt3", 4, "pk_4_data"),
                ("gt3", 5, "pk_5_data"),
                ("gt3", 6, "pk_6_data"),
            ],
        )

        outer = select(inner.alias("q_inner"))

        outer_result = connection.execute(outer).all()

        assert outer_result == [
            ("lessthan3", 1, "pk_1_data"),
            ("lessthan3", 2, "pk_2_data"),
            ("gt3", 3, "pk_3_data"),
            ("gt3", 4, "pk_4_data"),
            ("gt3", 5, "pk_5_data"),
            ("gt3", 6, "pk_6_data"),
        ]

        w_else = select(
            case(
                [info_table.c.pk < 3, cast(3, Integer)],
                [and_(info_table.c.pk >= 3, info_table.c.pk < 6), 6],
                else_=0,
            ).label("x"),
            info_table.c.pk,
            info_table.c.info,
        ).select_from(info_table)

        else_result = connection.execute(w_else).all()

        eq_(
            else_result,
            [
                (3, 1, "pk_1_data"),
                (3, 2, "pk_2_data"),
                (6, 3, "pk_3_data"),
                (6, 4, "pk_4_data"),
                (6, 5, "pk_5_data"),
                (0, 6, "pk_6_data"),
            ],
        )

    def test_literal_interpretation_one(self):
        """note this is modified as of #7287 to accept strings, tuples
        and other literal values as input
        where they are interpreted as bound values just like any other
        expression.

        Previously, an exception would be raised that the literal was
        ambiguous.


        """
        self.assert_compile(
            case(("x", "y")),
            "CASE WHEN :param_1 THEN :param_2 END",
            checkparams={"param_1": "x", "param_2": "y"},
        )

    def test_literal_interpretation_two(self):
        """note this is modified as of #7287 to accept strings, tuples
        and other literal values as input
        where they are interpreted as bound values just like any other
        expression.

        Previously, an exception would be raised that the literal was
        ambiguous.


        """
        self.assert_compile(
            case(
                (("x", "y"), "z"),
            ),
            "CASE WHEN :param_1 THEN :param_2 END",
            checkparams={"param_1": ("x", "y"), "param_2": "z"},
        )

    def test_literal_interpretation_two_point_five(self):
        """note this is modified as of #7287 to accept strings, tuples
        and other literal values as input
        where they are interpreted as bound values just like any other
        expression.

        Previously, an exception would be raised that the literal was
        ambiguous.


        """
        self.assert_compile(
            case(
                (12, "z"),
            ),
            "CASE WHEN :param_1 THEN :param_2 END",
            checkparams={"param_1": 12, "param_2": "z"},
        )

    def test_literal_interpretation_three(self):
        t = table("test", column("col1"))

        self.assert_compile(
            case(("x", "y"), value=t.c.col1),
            "CASE test.col1 WHEN :param_1 THEN :param_2 END",
        )
        self.assert_compile(
            case((t.c.col1 == 7, "y"), else_="z"),
            "CASE WHEN (test.col1 = :col1_1) THEN :param_1 ELSE :param_2 END",
        )

    @testing.combinations(
        (
            (lambda t: ({"x": "y"}, t.c.col1, None)),
            "CASE test.col1 WHEN :param_1 THEN :param_2 END",
        ),
        (
            (lambda t: ({"x": "y", "p": "q"}, t.c.col1, None)),
            "CASE test.col1 WHEN :param_1 THEN :param_2 "
            "WHEN :param_3 THEN :param_4 END",
        ),
        (
            (lambda t: ({t.c.col1 == 7: "x"}, None, 10)),
            "CASE WHEN (test.col1 = :col1_1) THEN :param_1 ELSE :param_2 END",
        ),
        (
            (lambda t: ({t.c.col1 == 7: "x", t.c.col1 == 10: "y"}, None, 10)),
            "CASE WHEN (test.col1 = :col1_1) THEN :param_1 "
            "WHEN (test.col1 = :col1_2) THEN :param_2 ELSE :param_3 END",
        ),
        argnames="test_case, expected",
    )
    def test_when_dicts(self, test_case, expected):
        t = table("test", column("col1"))

        when_dict, value, else_ = testing.resolve_lambda(test_case, t=t)

        self.assert_compile(
            case(when_dict, value=value, else_=else_), expected
        )

    def test_text_doesnt_explode(self, connection):
        info_table = self.tables.info_table

        for s in [
            select(
                case(
                    (info_table.c.info == "pk_4_data", text("'yes'")),
                    else_=text("'no'"),
                )
            ).order_by(info_table.c.info),
            select(
                case(
                    (
                        info_table.c.info == "pk_4_data",
                        literal_column("'yes'"),
                    ),
                    else_=literal_column("'no'"),
                )
            ).order_by(info_table.c.info),
        ]:
            eq_(
                connection.execute(s).all(),
                [("no",), ("no",), ("no",), ("yes",), ("no",), ("no",)],
            )

    def test_text_doenst_explode_even_in_whenlist(self):
        """test #7287"""
        self.assert_compile(
            case(
                (text(":case = 'upper'"), func.upper(literal_column("q"))),
                else_=func.lower(literal_column("q")),
            ),
            "CASE WHEN :case = 'upper' THEN upper(q) ELSE lower(q) END",
        )

    def testcase_with_dict(self):
        info_table = self.tables.info_table

        query = select(
            case(
                {
                    info_table.c.pk < 3: "lessthan3",
                    info_table.c.pk >= 3: "gt3",
                },
                else_="other",
            ),
            info_table.c.pk,
            info_table.c.info,
        ).select_from(info_table)
        eq_(
            query.execute().fetchall(),
            [
                ("lessthan3", 1, "pk_1_data"),
                ("lessthan3", 2, "pk_2_data"),
                ("gt3", 3, "pk_3_data"),
                ("gt3", 4, "pk_4_data"),
                ("gt3", 5, "pk_5_data"),
                ("gt3", 6, "pk_6_data"),
            ],
        )

        simple_query = (
            select(
                case(
                    {1: "one", 2: "two"}, value=info_table.c.pk, else_="other"
                ),
                info_table.c.pk,
            )
            .where(info_table.c.pk < 4)
            .select_from(info_table)
        )

        assert simple_query.execute().fetchall() == [
            ("one", 1),
            ("two", 2),
            ("other", 3),
        ]

    @testing.variation("add_else", [True, False])
    def test_type_of_case_expression_with_all_nulls(self, add_else):
        info_table = self.tables.info_table

        expr = case(
            (info_table.c.pk < 0, None),
            (info_table.c.pk > 9, None),
            else_=column("q") if add_else else None,
        )

        assert isinstance(expr.type, NullType)

    @testing.combinations(
        lambda info_table: (
            [
                # test non-None in middle of WHENS takes precedence over Nones
                (info_table.c.pk < 0, None),
                (info_table.c.pk < 5, "five"),
                (info_table.c.pk <= 9, info_table.c.pk),
                (info_table.c.pk > 9, None),
            ],
            None,
        ),
        lambda info_table: (
            # test non-None ELSE takes precedence over WHENs that are None
            [(info_table.c.pk < 0, None)],
            info_table.c.pk,
        ),
        lambda info_table: (
            # test non-None WHEN takes precedence over non-None ELSE
            [
                (info_table.c.pk < 0, None),
                (info_table.c.pk <= 9, info_table.c.pk),
                (info_table.c.pk > 9, None),
            ],
            column("q", String),
        ),
        lambda info_table: (
            # test last WHEN in list takes precedence
            [
                (info_table.c.pk < 0, String),
                (info_table.c.pk > 9, None),
                (info_table.c.pk <= 9, info_table.c.pk),
            ],
            column("q", String),
        ),
    )
    def test_type_of_case_expression(self, when_lambda):
        info_table = self.tables.info_table

        whens, else_ = testing.resolve_lambda(
            when_lambda, info_table=info_table
        )

        expr = case(*whens, else_=else_)

        assert isinstance(expr.type, Integer)