Source

sqlalchemy / test / sql / test_quote.py

  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
from sqlalchemy import *
from sqlalchemy import sql, schema
from sqlalchemy.sql import compiler
from sqlalchemy.testing import fixtures, AssertsCompiledSQL
from sqlalchemy import testing


class QuoteTest(fixtures.TestBase, AssertsCompiledSQL):
    __dialect__ = 'default'

    @classmethod
    def setup_class(cls):
        # TODO: figure out which databases/which identifiers allow special
        # characters to be used, such as: spaces, quote characters,
        # punctuation characters, set up tests for those as well.

        global table1, table2
        metadata = MetaData(testing.db)

        table1 = Table('WorstCase1', metadata,
            Column('lowercase', Integer, primary_key=True),
            Column('UPPERCASE', Integer),
            Column('MixedCase', Integer),
            Column('ASC', Integer, key='a123'))
        table2 = Table('WorstCase2', metadata,
            Column('desc', Integer, primary_key=True, key='d123'),
            Column('Union', Integer, key='u123'),
            Column('MixedCase', Integer))

        table1.create()
        table2.create()

    def teardown(self):
        table1.delete().execute()
        table2.delete().execute()

    @classmethod
    def teardown_class(cls):
        table1.drop()
        table2.drop()

    def test_reflect(self):
        meta2 = MetaData(testing.db)
        t2 = Table('WorstCase1', meta2, autoload=True, quote=True)
        assert 'lowercase' in t2.c
        assert 'UPPERCASE' in t2.c
        assert 'MixedCase' in t2.c
        assert 'ASC' in t2.c

    def test_basic(self):
        table1.insert().execute(
            {'lowercase': 1, 'UPPERCASE': 2, 'MixedCase': 3, 'a123': 4},
            {'lowercase': 2, 'UPPERCASE': 2, 'MixedCase': 3, 'a123': 4},
            {'lowercase': 4, 'UPPERCASE': 3, 'MixedCase': 2, 'a123': 1})
        table2.insert().execute(
            {'d123': 1, 'u123': 2, 'MixedCase': 3},
            {'d123': 2, 'u123': 2, 'MixedCase': 3},
            {'d123': 4, 'u123': 3, 'MixedCase': 2})

        columns = [
            table1.c.lowercase,
            table1.c.UPPERCASE,
            table1.c.MixedCase,
            table1.c.a123
        ]
        result = select(columns).execute().fetchall()
        assert(result == [(1, 2, 3, 4), (2, 2, 3, 4), (4, 3, 2, 1)])

        columns = [
            table2.c.d123,
            table2.c.u123,
            table2.c.MixedCase
        ]
        result = select(columns).execute().fetchall()
        assert(result == [(1, 2, 3), (2, 2, 3), (4, 3, 2)])

    def test_use_labels(self):
        table1.insert().execute(
            {'lowercase': 1, 'UPPERCASE': 2, 'MixedCase': 3, 'a123': 4},
            {'lowercase': 2, 'UPPERCASE': 2, 'MixedCase': 3, 'a123': 4},
            {'lowercase': 4, 'UPPERCASE': 3, 'MixedCase': 2, 'a123': 1})
        table2.insert().execute(
            {'d123': 1, 'u123': 2, 'MixedCase': 3},
            {'d123': 2, 'u123': 2, 'MixedCase': 3},
            {'d123': 4, 'u123': 3, 'MixedCase': 2})

        columns = [
            table1.c.lowercase,
            table1.c.UPPERCASE,
            table1.c.MixedCase,
            table1.c.a123
        ]
        result = select(columns, use_labels=True).execute().fetchall()
        assert(result == [(1, 2, 3, 4), (2, 2, 3, 4), (4, 3, 2, 1)])

        columns = [
            table2.c.d123,
            table2.c.u123,
            table2.c.MixedCase
        ]
        result = select(columns, use_labels=True).execute().fetchall()
        assert(result == [(1, 2, 3), (2, 2, 3), (4, 3, 2)])

    @testing.crashes('oracle', 'FIXME: unknown, verify not fails_on')
    @testing.requires.subqueries
    def test_labels(self):
        """test the quoting of labels.

        If labels aren't quoted, a query in postgresql in particular will
        fail since it produces:

        SELECT
            LaLa.lowercase, LaLa."UPPERCASE", LaLa."MixedCase", LaLa."ASC"
        FROM (
            SELECT DISTINCT
                "WorstCase1".lowercase AS lowercase,
                "WorstCase1"."UPPERCASE" AS UPPERCASE,
                "WorstCase1"."MixedCase" AS MixedCase,
                "WorstCase1"."ASC" AS ASC
            FROM "WorstCase1"
        ) AS LaLa

        where the "UPPERCASE" column of "LaLa" doesn't exist.
        """

        x = table1.select(distinct=True).alias('LaLa').select().scalar()
        self.assert_compile(
            table1.select(distinct=True).alias('LaLa').select(),
            'SELECT '
                '"LaLa".lowercase, '
                '"LaLa"."UPPERCASE", '
                '"LaLa"."MixedCase", '
                '"LaLa"."ASC" '
            'FROM ('
                'SELECT DISTINCT '
                    '"WorstCase1".lowercase AS lowercase, '
                    '"WorstCase1"."UPPERCASE" AS "UPPERCASE", '
                    '"WorstCase1"."MixedCase" AS "MixedCase", '
                    '"WorstCase1"."ASC" AS "ASC" '
                'FROM "WorstCase1"'
            ') AS "LaLa"'
        )

    def test_lower_case_names(self):
        # Create table with quote defaults
        metadata = MetaData()
        t1 = Table('t1', metadata,
            Column('col1', Integer),
            schema='foo')

        # Note that the names are not quoted b/c they are all lower case
        result = 'CREATE TABLE foo.t1 (col1 INTEGER)'
        self.assert_compile(schema.CreateTable(t1), result)

        # Create the same table with quotes set to True now
        metadata = MetaData()
        t1 = Table('t1', metadata,
            Column('col1', Integer, quote=True),
            schema='foo', quote=True, quote_schema=True)

        # Note that the names are now quoted
        result = 'CREATE TABLE "foo"."t1" ("col1" INTEGER)'
        self.assert_compile(schema.CreateTable(t1), result)

    def test_upper_case_names(self):
        # Create table with quote defaults
        metadata = MetaData()
        t1 = Table('TABLE1', metadata,
            Column('COL1', Integer),
            schema='FOO')

        # Note that the names are quoted b/c they are not all lower case
        result = 'CREATE TABLE "FOO"."TABLE1" ("COL1" INTEGER)'
        self.assert_compile(schema.CreateTable(t1), result)

        # Create the same table with quotes set to False now
        metadata = MetaData()
        t1 = Table('TABLE1', metadata,
            Column('COL1', Integer, quote=False),
            schema='FOO', quote=False, quote_schema=False)

        # Note that the names are now unquoted
        result = 'CREATE TABLE FOO.TABLE1 (COL1 INTEGER)'
        self.assert_compile(schema.CreateTable(t1), result)

    def test_mixed_case_names(self):
        # Create table with quote defaults
        metadata = MetaData()
        t1 = Table('Table1', metadata,
            Column('Col1', Integer),
            schema='Foo')

        # Note that the names are quoted b/c they are not all lower case
        result = 'CREATE TABLE "Foo"."Table1" ("Col1" INTEGER)'
        self.assert_compile(schema.CreateTable(t1), result)

        # Create the same table with quotes set to False now
        metadata = MetaData()
        t1 = Table('Table1', metadata,
            Column('Col1', Integer, quote=False),
            schema='Foo', quote=False, quote_schema=False)

        # Note that the names are now unquoted
        result = 'CREATE TABLE Foo.Table1 (Col1 INTEGER)'
        self.assert_compile(schema.CreateTable(t1), result)

    def test_numeric_initial_char(self):
        # Create table with quote defaults
        metadata = MetaData()
        t1 = Table('35table', metadata,
            Column('25column', Integer),
            schema='45schema')

        # Note that the names are quoted b/c the initial
        # character is in ['$','0', '1' ... '9']
        result = 'CREATE TABLE "45schema"."35table" ("25column" INTEGER)'
        self.assert_compile(schema.CreateTable(t1), result)

        # Create the same table with quotes set to False now
        metadata = MetaData()
        t1 = Table('35table', metadata,
            Column('25column', Integer, quote=False),
            schema='45schema', quote=False, quote_schema=False)

        # Note that the names are now unquoted
        result = 'CREATE TABLE 45schema.35table (25column INTEGER)'
        self.assert_compile(schema.CreateTable(t1), result)

    def test_illegal_initial_char(self):
        # Create table with quote defaults
        metadata = MetaData()
        t1 = Table('$table', metadata,
            Column('$column', Integer),
            schema='$schema')

        # Note that the names are quoted b/c the initial
        # character is in ['$','0', '1' ... '9']
        result = 'CREATE TABLE "$schema"."$table" ("$column" INTEGER)'
        self.assert_compile(schema.CreateTable(t1), result)

        # Create the same table with quotes set to False now
        metadata = MetaData()
        t1 = Table('$table', metadata,
            Column('$column', Integer, quote=False),
            schema='$schema', quote=False, quote_schema=False)

        # Note that the names are now unquoted
        result = 'CREATE TABLE $schema.$table ($column INTEGER)'
        self.assert_compile(schema.CreateTable(t1), result)

    def test_reserved_words(self):
        # Create table with quote defaults
        metadata = MetaData()
        table = Table('foreign', metadata,
            Column('col1', Integer),
            Column('from', Integer),
            Column('order', Integer),
            schema='create')

        # Note that the names are quoted b/c they are reserved words
        x = select([table.c.col1, table.c['from'], table.c.order])
        self.assert_compile(x,
            'SELECT '
                '"create"."foreign".col1, '
                '"create"."foreign"."from", '
                '"create"."foreign"."order" '
            'FROM "create"."foreign"'
        )

        # Create the same table with quotes set to False now
        metadata = MetaData()
        table = Table('foreign', metadata,
            Column('col1', Integer),
            Column('from', Integer, quote=False),
            Column('order', Integer, quote=False),
            schema='create', quote=False, quote_schema=False)

        # Note that the names are now unquoted
        x = select([table.c.col1, table.c['from'], table.c.order])
        self.assert_compile(x,
            'SELECT '
                'create.foreign.col1, '
                'create.foreign.from, '
                'create.foreign.order '
            'FROM create.foreign'
        )

    def test_subquery(self):
        # Lower case names, should not quote
        metadata = MetaData()
        t1 = Table('t1', metadata,
            Column('col1', Integer),
            schema='foo')
        a = t1.select().alias('anon')
        b = select([1], a.c.col1 == 2, from_obj=a)
        self.assert_compile(b,
            'SELECT 1 '
            'FROM ('
                'SELECT '
                    'foo.t1.col1 AS col1 '
                'FROM '
                    'foo.t1'
            ') AS anon '
            'WHERE anon.col1 = :col1_1'
        )

        # Lower case names, quotes on, should quote
        metadata = MetaData()
        t1 = Table('t1', metadata,
            Column('col1', Integer, quote=True),
            schema='foo', quote=True, quote_schema=True)
        a = t1.select().alias('anon')
        b = select([1], a.c.col1 == 2, from_obj=a)
        self.assert_compile(b,
            'SELECT 1 '
            'FROM ('
                'SELECT '
                    '"foo"."t1"."col1" AS "col1" '
                'FROM '
                    '"foo"."t1"'
            ') AS anon '
            'WHERE anon."col1" = :col1_1'
        )

        # Not lower case names, should quote
        metadata = MetaData()
        t1 = Table('T1', metadata,
            Column('Col1', Integer),
            schema='Foo')
        a = t1.select().alias('Anon')
        b = select([1], a.c.Col1 == 2, from_obj=a)
        self.assert_compile(b,
            'SELECT 1 '
            'FROM ('
                'SELECT '
                    '"Foo"."T1"."Col1" AS "Col1" '
                'FROM '
                    '"Foo"."T1"'
            ') AS "Anon" '
            'WHERE '
                '"Anon"."Col1" = :Col1_1'
        )

        # Not lower case names, quotes off, should not quote
        metadata = MetaData()
        t1 = Table('T1', metadata,
            Column('Col1', Integer, quote=False),
            schema='Foo', quote=False, quote_schema=False)
        a = t1.select().alias('Anon')
        b = select([1], a.c.Col1 == 2, from_obj=a)
        self.assert_compile(b,
            'SELECT 1 '
            'FROM ('
                'SELECT '
                    'Foo.T1.Col1 AS Col1 '
                'FROM '
                    'Foo.T1'
            ') AS "Anon" '
            'WHERE '
                '"Anon".Col1 = :Col1_1'
        )

    def test_join(self):
        # Lower case names, should not quote
        metadata = MetaData()
        t1 = Table('t1', metadata,
           Column('col1', Integer))
        t2 = Table('t2', metadata,
           Column('col1', Integer),
           Column('t1col1', Integer, ForeignKey('t1.col1')))
        self.assert_compile(t2.join(t1).select(),
            'SELECT '
                't2.col1, t2.t1col1, t1.col1 '
            'FROM '
                't2 '
            'JOIN '
                't1 ON t1.col1 = t2.t1col1'
        )

        # Lower case names, quotes on, should quote
        metadata = MetaData()
        t1 = Table('t1', metadata,
           Column('col1', Integer, quote=True),
           quote=True)
        t2 = Table('t2', metadata,
           Column('col1', Integer, quote=True),
           Column('t1col1', Integer, ForeignKey('t1.col1'), quote=True),
           quote=True)
        self.assert_compile(t2.join(t1).select(),
            'SELECT '
                '"t2"."col1", "t2"."t1col1", "t1"."col1" '
            'FROM '
                '"t2" '
            'JOIN '
                '"t1" ON "t1"."col1" = "t2"."t1col1"'
        )

        # Not lower case names, should quote
        metadata = MetaData()
        t1 = Table('T1', metadata,
           Column('Col1', Integer))
        t2 = Table('T2', metadata,
           Column('Col1', Integer),
           Column('T1Col1', Integer, ForeignKey('T1.Col1')))
        self.assert_compile(t2.join(t1).select(),
            'SELECT '
                '"T2"."Col1", "T2"."T1Col1", "T1"."Col1" '
            'FROM '
                '"T2" '
            'JOIN '
                '"T1" ON "T1"."Col1" = "T2"."T1Col1"'
        )

        # Not lower case names, quotes off, should not quote
        metadata = MetaData()
        t1 = Table('T1', metadata,
           Column('Col1', Integer, quote=False),
           quote=False)
        t2 = Table('T2', metadata,
           Column('Col1', Integer, quote=False),
           Column('T1Col1', Integer, ForeignKey('T1.Col1'), quote=False),
           quote=False)
        self.assert_compile(t2.join(t1).select(),
            'SELECT '
                'T2.Col1, T2.T1Col1, T1.Col1 '
            'FROM '
                'T2 '
            'JOIN '
                'T1 ON T1.Col1 = T2.T1Col1'
        )

    def test_label_and_alias(self):
        # Lower case names, should not quote
        metadata = MetaData()
        table = Table('t1', metadata,
            Column('col1', Integer))
        x = select([table.c.col1.label('label1')]).alias('alias1')
        self.assert_compile(select([x.c.label1]),
            'SELECT '
                'alias1.label1 '
            'FROM ('
                'SELECT '
                    't1.col1 AS label1 '
                'FROM t1'
            ') AS alias1'
        )

        # Not lower case names, should quote
        metadata = MetaData()
        table = Table('T1', metadata,
            Column('Col1', Integer))
        x = select([table.c.Col1.label('Label1')]).alias('Alias1')
        self.assert_compile(select([x.c.Label1]),
            'SELECT '
                '"Alias1"."Label1" '
            'FROM ('
                'SELECT '
                    '"T1"."Col1" AS "Label1" '
                'FROM "T1"'
            ') AS "Alias1"'
        )

    def test_literal_column_already_with_quotes(self):
        # Lower case names
        metadata = MetaData()
        table = Table('t1', metadata,
            Column('col1', Integer))

        # Note that 'col1' is already quoted (literal_column)
        columns = [sql.literal_column("'col1'").label('label1')]
        x = select(columns, from_obj=[table]).alias('alias1')
        x = x.select()
        self.assert_compile(x,
            'SELECT '
                'alias1.label1 '
            'FROM ('
                'SELECT '
                    '\'col1\' AS label1 '
                'FROM t1'
            ') AS alias1'
        )

        # Not lower case names
        metadata = MetaData()
        table = Table('T1', metadata,
            Column('Col1', Integer))

        # Note that 'Col1' is already quoted (literal_column)
        columns = [sql.literal_column("'Col1'").label('Label1')]
        x = select(columns, from_obj=[table]).alias('Alias1')
        x = x.select()
        self.assert_compile(x,
            'SELECT '
                '"Alias1"."Label1" '
            'FROM ('
                'SELECT '
                    '\'Col1\' AS "Label1" '
                'FROM "T1"'
            ') AS "Alias1"'
        )

    def test_apply_labels(self):
        # Not lower case names, should quote
        metadata = MetaData()
        t1 = Table('T1', metadata,
            Column('Col1', Integer),
            schema='Foo')

        self.assert_compile(t1.select().apply_labels(),
            'SELECT '
                '"Foo"."T1"."Col1" AS "Foo_T1_Col1" '
            'FROM '
                '"Foo"."T1"'
        )

        # Not lower case names, quotes off
        metadata = MetaData()
        t1 = Table('T1', metadata,
            Column('Col1', Integer, quote=False),
            schema='Foo', quote=False, quote_schema=False)

        # TODO: is this what we really want here ?
        # what if table/schema *are* quoted?
        self.assert_compile(t1.select().apply_labels(),
            'SELECT '
                'Foo.T1.Col1 AS Foo_T1_Col1 '
            'FROM '
                'Foo.T1'
        )


class PreparerTest(fixtures.TestBase):
    """Test the db-agnostic quoting services of IdentifierPreparer."""

    def test_unformat(self):
        prep = compiler.IdentifierPreparer(None)
        unformat = prep.unformat_identifiers

        def a_eq(have, want):
            if have != want:
                print "Wanted %s" % want
                print "Received %s" % have
            self.assert_(have == want)

        a_eq(unformat('foo'), ['foo'])
        a_eq(unformat('"foo"'), ['foo'])
        a_eq(unformat("'foo'"), ["'foo'"])
        a_eq(unformat('foo.bar'), ['foo', 'bar'])
        a_eq(unformat('"foo"."bar"'), ['foo', 'bar'])
        a_eq(unformat('foo."bar"'), ['foo', 'bar'])
        a_eq(unformat('"foo".bar'), ['foo', 'bar'])
        a_eq(unformat('"foo"."b""a""r"."baz"'), ['foo', 'b"a"r', 'baz'])

    def test_unformat_custom(self):

        class Custom(compiler.IdentifierPreparer):

            def __init__(self, dialect):
                super(Custom, self).__init__(
                    dialect, initial_quote='`', final_quote='`')

            def _escape_identifier(self, value):
                return value.replace('`', '``')

            def _unescape_identifier(self, value):
                return value.replace('``', '`')

        prep = Custom(None)
        unformat = prep.unformat_identifiers

        def a_eq(have, want):
            if have != want:
                print "Wanted %s" % want
                print "Received %s" % have
            self.assert_(have == want)

        a_eq(unformat('foo'), ['foo'])
        a_eq(unformat('`foo`'), ['foo'])
        a_eq(unformat(`'foo'`), ["'foo'"])
        a_eq(unformat('foo.bar'), ['foo', 'bar'])
        a_eq(unformat('`foo`.`bar`'), ['foo', 'bar'])
        a_eq(unformat('foo.`bar`'), ['foo', 'bar'])
        a_eq(unformat('`foo`.bar'), ['foo', 'bar'])
        a_eq(unformat('`foo`.`b``a``r`.`baz`'), ['foo', 'b`a`r', 'baz'])