File: NullableUniqueConstraintTest.java

package info (click to toggle)
derby 10.14.2.0-3
  • links: PTS, VCS
  • area: main
  • in suites: forky, sid, trixie
  • size: 79,056 kB
  • sloc: java: 691,961; sql: 42,686; xml: 20,512; sh: 3,373; sed: 96; makefile: 60
file content (596 lines) | stat: -rw-r--r-- 23,494 bytes parent folder | download | duplicates (4)
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
/**
 *  Derby - Class org.apache.derbyTesting.functionTests.tests.lang.NullableUniqueConstraintTest
 *
 * Licensed to the Apache Software Foundation (ASF) under one
 * or more contributor license agreements.  See the NOTICE file
 * distributed with this work for additional information
 * regarding copyright ownership.  The ASF licenses this file
 * to you under the Apache License, Version 2.0 (the
 * "License"); you may not use this file except in compliance
 * with the License.  You may obtain a copy of the License at
 *
 *   http://www.apache.org/licenses/LICENSE-2.0
 *
 * Unless required by applicable law or agreed to in writing,
 * software distributed under the License is distributed on an
 * "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
 * KIND, either express or implied.  See the License for the
 * specific language governing permissions and limitations
 * under the License.
 */

package org.apache.derbyTesting.functionTests.tests.lang;

import java.sql.Connection;
import java.sql.PreparedStatement;
import java.sql.ResultSet;
import java.sql.SQLException;
import java.sql.Savepoint;
import java.sql.Statement;
import java.sql.Types;
import java.util.Enumeration;
import junit.framework.Test;
import junit.framework.TestFailure;
import junit.framework.TestResult;
import org.apache.derbyTesting.junit.BaseJDBCTestCase;
import org.apache.derbyTesting.junit.BaseTestSuite;
import org.apache.derbyTesting.junit.TestConfiguration;

/**
 * Test unique constraint
 */
public class NullableUniqueConstraintTest extends BaseJDBCTestCase {
    
    /**
     * Basic constructor.
     */
    public NullableUniqueConstraintTest(String name) {
        super(name);
    }
    
    /**
     * Returns the implemented tests.
     *
     * @return An instance of <code>Test</code> with the implemented tests to
     *         run.
     */
    public static Test suite() {
        BaseTestSuite suite =
            new BaseTestSuite("NullableUniqueConstraintTest");

        suite.addTest(TestConfiguration.defaultSuite(
                            NullableUniqueConstraintTest.class));
        return suite;
    }
    
    /**
     * Create table for test cases to use.
     */
    protected void setUp() throws Exception {
        Connection con = getConnection();
        Statement stmt = con.createStatement();
        stmt.executeUpdate("create table constraintest (val1 varchar (20), " +
                "val2 varchar (20), val3 varchar (20), val4 varchar (20))");
    }
    
    protected void tearDown() throws Exception {
        Connection con = getConnection();
        con.commit ();
        Statement stmt = con.createStatement();
        stmt.executeUpdate("drop table constraintest");
        stmt.close ();
        con.commit ();
        super.tearDown();
    }
    /**
     * Basic test of Unique Constraint using single part key.
     * @throws SQLException
     */
    public void testSingleKeyPartUniqueConstraint() throws SQLException {
        Connection con = getConnection();
        Statement stmt = con.createStatement();
        //create unique constraint without not null
        stmt.executeUpdate("alter table constraintest add constraint " +
                "u_con unique (val1)");
        PreparedStatement ps  = con.prepareStatement("insert into " +
                "constraintest (val1, val2) values (?, ?)");
        ps.setString(1, "test");
        ps.setString(2, "should pass");
        ps.execute();
        try {
            ps.setString(1, "test");
            ps.setString(2, "should fail");
            ps.execute();
            fail("duplicate key inserted expected '23505'");
        }
        catch (SQLException e) {
            assertSQLState("inserting duplicate", "23505", e);
        }
        ps.setNull(1, Types.VARCHAR);
        ps.setString(2, "should pass");
        ps.execute();
        ps.setNull(1, Types.VARCHAR);
        ps.setString(2, "should pass");
        ps.execute();
        //check if there are two record with val1=null
        ResultSet rs = stmt.executeQuery("select count (*) from " +
                "constraintest where val1 is null");
        rs.next();
        assertEquals("expected 2 rows", 2, rs.getInt(1));
        //try creating constraint with existing value
        stmt.execute("alter table constraintest drop constraint u_con");
        stmt.execute("delete from constraintest where val1 is null");
        con.commit ();
        ps.setString(1, "test");
        ps.setString(2, "removeit");
        ps.execute();
        //constraint dropped successfully
        //create constraint - must fail
        try {
            stmt.executeUpdate("alter table constraintest add constraint " +
                "u_con unique (val1)");
            fail ("create unique constraint with duplicate key in " +
                    "table should fail");
        }
        catch (SQLException e) {
            assertSQLState("creating unique constraint when duplicate" +
                    " keys are present  duplicate", "23505", e);
        }
        //remove duplicate record
        stmt.execute ("delete from constraintest where val2 = 'removeit'");
        //should be fine now
        stmt.executeUpdate("alter table constraintest add constraint " +
                "u_con unique (val1)");
        con.commit();
        stmt.close ();
        ps.close();
    }

    /**
     * Compress table should recreate the indexes correctly rather
     * than ignoring the unique nullable property of the index
     * @throws SQLException
     */
    public void testDerby4677CompressTable() throws SQLException {
        Connection con = getConnection();
        Statement stmt = con.createStatement();
        stmt.executeUpdate("CREATE TABLE TABLE1(NAME1 INT UNIQUE, "+
        		"name2 int unique not null, name3 int primary key)");
        stmt.execute("call syscs_util.syscs_compress_table('APP','TABLE1',1)");
        stmt.executeUpdate("INSERT INTO TABLE1 VALUES(1,11,111)");
        //following should run into problem because of constraint on name1
        assertStatementError("23505", stmt,
        		"INSERT INTO TABLE1 VALUES(1,22,222)");
        //following should run into problem because of constraint on name2
        assertStatementError("23505", stmt,
        		"INSERT INTO TABLE1 VALUES(3,11,333)");
        //following should run into problem because of constraint on name3
        assertStatementError("23505", stmt,
        		"INSERT INTO TABLE1 VALUES(4,44,111)");
        stmt.executeUpdate("DROP TABLE TABLE1");    
    }
    
    /**
     * Basic test of Unique Constraint using multipart part key.
     * @throws SQLException
     */
    public void testMultipartKeyUniqueConstraint() throws SQLException {
        Connection con = getConnection();
        Statement stmt = con.createStatement();
        //create unique constraint without not null
        stmt.executeUpdate("alter table constraintest add constraint " +
                "u_con unique (val1, val2, val3)");
        PreparedStatement ps  = con.prepareStatement("insert into " +
                "constraintest (val1, val2, val3, val4) values (?, ?, ?, ?)");
        ps.setString(1, "part1");
        ps.setString(2, "part2");
        ps.setString(3, "part3");
        ps.setString(4, "should pass");
        ps.execute();
        try {
            ps.setString(1, "part1");
            ps.setString(2, "part2");
            ps.setString(3, "part3");
            ps.setString(4, "should fail");
            ps.execute();
            fail("duplicate key inserted expected '23505'");
        }
        catch (SQLException e) {
            assertSQLState("inserting duplicate", "23505", e);
        }
        ps.setNull(1, Types.VARCHAR);
        ps.setString(2, "part2");
        ps.setString(3, "part3");
        ps.setString(4, "should pass");
        ps.execute();
        ps.setNull(1, Types.VARCHAR);
        ps.setString(2, "part2");
        ps.setString(3, "part3");
        ps.setString(4, "should pass");
        ps.execute();
        ps.setString(1, "part1");
        ps.setNull(2, Types.VARCHAR);
        ps.setString(3, "part3");
        ps.setString(4, "should pass");
        ps.execute();
        //check if there are two record with val1=null
        ResultSet rs = stmt.executeQuery("select count (*) from " +
                "constraintest where val1 is null");
        rs.next();
        assertEquals("expected 2 rows", 2, rs.getInt(1));
        //try creating constraint with existing value
        stmt.execute("alter table constraintest drop constraint u_con");
        con.commit ();
        ps.setString(1, "part1");
        ps.setString(2, "part2");
        ps.setString(3, "part3");
        ps.setString(4, "removeit");
        ps.execute();
        //constraint dropped successfully
        //create constraint - must fail
        try {
            stmt.executeUpdate("alter table constraintest add constraint " +
                "u_con unique (val1, val2, val3)");
            fail ("create unique constraint with duplicate key in " +
                    "table should fail");
        }
        catch (SQLException e) {
            assertSQLState("creating unique constraint when duplicate" +
                    " keys are present  duplicate", "23505", e);
        }
        //remove duplicate record
        stmt.execute ("delete from constraintest where val4 = 'removeit'");
        //should be fine now
        stmt.executeUpdate("alter table constraintest add constraint " +
                "u_con unique (val1, val2, val3)");
        con.commit();
        stmt.close ();
        ps.close();
    }
    
    /**
     * Inserts a duplicate key of a deleted key within same transaction.
     * @throws java.sql.SQLException
     */
    public void testWithDeletedKey() throws SQLException {
        Connection con = getConnection();
        Statement stmt = con.createStatement();
        //create unique constraint without not null
        stmt.executeUpdate("alter table constraintest add constraint " +
                "u_con unique (val1, val2, val3)");
        PreparedStatement ps  = con.prepareStatement("insert into " +
                "constraintest (val1, val2, val3, val4) values (?, ?, ?, ?)");
        ps.setString(1, "part1");
        ps.setString(2, "part2");
        ps.setString(3, "part3");
        ps.setString(4, "should pass");
        ps.execute();
        //delete a record within transaction and try inserting same record
        con.setAutoCommit(false);
        stmt.executeUpdate("delete from constraintest where " +
                "val1 = 'part1' and val2 = 'part2' and val3 = 'part3'");
        //insert same record
        ps.setString(1, "part1");
        ps.setString(2, "part2");
        ps.setString(3, "part3");
        ps.setString(4, "should pass");
        ps.execute();
        stmt.close();
        ps.close();
        con.commit();
    }
    
    public void testDistinctQuery() throws SQLException {
        Connection con = getConnection();
        Statement stmt = con.createStatement();
        stmt.executeUpdate("alter table constraintest add constraint " +
                "u_con unique (val1)");
        PreparedStatement ps  = con.prepareStatement("insert into " +
                "constraintest (val1) values (?)");
        //insert 5 null keys
        for (int i = 0; i < 5; i++) {
            ps.setNull(1, Types.VARCHAR);
            ps.executeUpdate();
        }
        
        //insert 5 null keys
        for (int i = 0; i < 5; i++) {
            ps.setString(1, String.valueOf(i));
            ps.executeUpdate();
        }
        ResultSet rs = stmt.executeQuery("select count (*) from constraintest");
        rs.next();
        assertEquals(10, rs.getInt(1));
        rs.close ();

        rs = stmt.executeQuery("select count (distinct (val1)) from " +
                "constraintest");
        rs.next();
        assertEquals(5, rs.getInt(1));
        rs.close ();
    }
    /**
     * Test null ordering of the key in order by query.
     * @throws java.sql.SQLException
     */
    public void testNullOrdering() throws SQLException {
        Connection con = getConnection();
        Statement stmt = con.createStatement();
        stmt.executeUpdate("alter table constraintest add constraint " +
                "u_con unique (val1)");
        PreparedStatement ps  = con.prepareStatement("insert into " +
                "constraintest (val1) values (?)");
        //insert 5 null keys
        for (int i = 0; i < 5; i++) {
            ps.setNull(1, Types.VARCHAR);
            ps.executeUpdate();
        }
        
        //insert 5 non null keys
        for (int i = 0; i < 5; i++) {
            ps.setString(1, String.valueOf(i));
            ps.executeUpdate();
        }
        
        ResultSet rs = stmt.executeQuery("select val1 from constraintest " +
                            "order by val1 nulls last");
        //first 5 should be non null
        for (int i = 0; i < 5; i++) {
            rs.next();
            assertEquals (String.valueOf(i), rs.getString(1));
        }
        
        //next 5 should be null
        for (int i = 0; i < 5; i++) {
            rs.next();
            assertEquals (null, rs.getString(1));
        }
        rs.close ();
        rs = stmt.executeQuery("select val1 from constraintest " +
                            "order by val1 nulls first");
        //first 5 should be null
        for (int i = 0; i < 5; i++) {
            rs.next();
            assertEquals (null, rs.getString(1));
        }
        
        //next 5 should be null
        for (int i = 0; i < 5; i++) {
            rs.next();
            assertEquals (String.valueOf(i), rs.getString(1));
        }
        rs.close ();
    }
    
    /**
     * Tries to forces internal routibe to travel across
     * pages to check for duplicates. It first inserts large 
     * number of records assuming they occupy multiple pages 
     * in index and then tries to insert duplicates of each 
     * of them. Rrecords at the page boundry will require 
     * duplucate checking routine to check more than one page 
     * to look for locate. If that routine is not working properly 
     * duplucate will be inserted in tree.
     * @throws java.sql.SQLException
     */
    public void testComparisonAcrossPages() throws SQLException {
        Connection con = getConnection();
        Statement stmt = con.createStatement();
        //create unique constraint without not null
        stmt.executeUpdate("alter table constraintest add constraint " +
                "u_con unique (val1)");
        PreparedStatement ps  = con.prepareStatement("insert into " +
                "constraintest (val1, val2) values (?, ?)");
        for (int i = 0; i < 500; i++) {
            ps.setString(1, "" + i);
            ps.setString (2, "" + i);
            ps.execute();
        }
        
        for (int i = 0; i < 500; i++) {
            ps.setString(1, "" + i);
            ps.setString (2, "" + i);
            try {
                ps.execute();
                fail("duplicate key inserted expected '23505'");
            }
            catch (SQLException e) {
                assertSQLState("inserting duplicate", "23505", e);  
            }
        }
        //mark all records except for first, as deleted and try 
        //inserting duplicate. This will force comparison 
        //logic to scan all the records to find another rcord for 
        //comparison.
        con.setAutoCommit(false);
        assertEquals (499, stmt.executeUpdate (
                "delete from constraintest where val1 != '0'"));
        Savepoint deleted = con.setSavepoint("deleted");
        ps.setString(1, "0");
        ps.setString (2, "test");
        try {
            ps.execute();
            fail ("managed to insert a duplicate");
        }
        catch (SQLException e) {
            assertSQLState("inserting duplicate", "23505",  e);
        }
        //rollback to check point and try to insert a record 
        //at the middle
        con.rollback(deleted);
        ps.setString(1, "250");
        ps.setString(2, "test");
        ps.execute ();
        //rollback to check point and try 
        //inserting at end
        con.rollback(deleted);
        ps.setString(1, "499");
        ps.setString (2, "test");
        ps.execute ();

        ResultSet rs = stmt.executeQuery("select count (*) from constraintest");
        rs.next ();
        assertEquals(2, rs.getInt(1));
        
        con.rollback ();
        ps.close();
        stmt.close();
        ps.close();
    }
    
    /**
     * Checks is insert for updates uses deffered inserts or not. 
     * It inserts two part keys in the form of
     * part1 part2
     * 1        1
     * 1        2
     * 1        3
     * 2        1
     * 2        2
     * 2        3
     * 3        1
     * 3        2
     * 3        3
     * 
     * and then tries to update all the records so that the values 
     * part1 and part2 are interchanged. Internally updates are 
     * treated as delete and insert and unless inserts are deffered 
     * till all deletes are over, there will be unique constraint 
     * violation.
     * @throws java.sql.SQLException
     */
    public void testDefferedInsert() throws SQLException {
        Connection con = getConnection();
        Statement stmt = con.createStatement();
        //create unique constraint without not null
        stmt.executeUpdate("alter table constraintest add constraint " +
                "u_con unique (val1, val2)");
        PreparedStatement ps  = con.prepareStatement("insert into " +
                "constraintest (val1, val2) values (?, ?)");
        for (int i = 0; i < 5; i++) {
            for (int j = 0; j < 5; j++) {
                ps.setString(1, String.valueOf(i));
                ps.setString(2, String.valueOf(j));
                ps.executeUpdate();
            }
        }
        //interchange the values of val1 and val2
        //this will fail unless its handled by deffered inserts
        assertEquals("updating 25 records", 25, 
                stmt.executeUpdate("update constraintest set " +
                "val1 = val2, val2 = val1"));
    }

    /**
     * Test that repeatedly performing multi-row inserts and deletes spanning
     * multiple pages works correctly with nullable unique constraint. This
     * used to cause <tt>ERROR XSDA1: An attempt was made to access an out of
     * range slot on a page</tt> (DERBY-4027).
     */
    public void testMixedInsertDelete() throws SQLException {
        createStatement().execute(
                "alter table constraintest add constraint uc unique (val1)");
        PreparedStatement insert = prepareStatement(
                "insert into constraintest(val1) values ?");
        PreparedStatement delete = prepareStatement(
                "delete from constraintest");
        // The error happened most frequently in the second iteration, but
        // it didn't always, so we repeat it ten times to increase the
        // likelihood of triggering the bug.
        // DERBY-4097: Increase the number of iterations to increase the
        // likelihood of exposing another timing-dependent problem with a
        // WaitError caused by a conflict between the post-commit thread
        // and the user thread.
        for (int i = 0; i < 100; i++) {
            for (int j = 0; j < 1000; j++) {
                insert.setInt(1, j);
                insert.addBatch();
            }
            insert.executeBatch();
            assertEquals(1000, delete.executeUpdate());
        }
    }

    /**
     * Test that a deleted duplicate value on the right side of the slot
     * into which a new value is inserted does not hide a non-deleted
     * duplicate two slots to the right. DERBY-4028
     */
    public void testDeletedDuplicateHidesDuplicateOnRightSide()
            throws SQLException {
        Statement s = createStatement();
        s.execute("alter table constraintest add constraint c unique(val1)");
        s.execute("insert into constraintest(val1) values '1','2','3'");
        // Make sure there's a deleted index entry for val1 = 2
        s.execute("delete from constraintest where val1 = '2'");
        // Make sure there's an index entry for val1 = 2 after the deleted one
        // (the third row will be located after the deleted one because it
        // was inserted later and its record id is greater)
        s.execute("update constraintest set val1 = '2' where val1 = '3'");
        // Insert an index entry in front of the deleted one. It should fail,
        // but before DERBY-4028 it was successfully inserted.
        assertStatementError("23505", s,
                "update constraintest set val1 = '2' where val1 = '1'");
    }

    /**
     * Test that a deleted duplicate value on the left side of the slot
     * into which a new value is inserted does not hide a non-deleted
     * duplicate two slots to the left. DERBY-4028
     */
    public void testDeletedDuplicateHidesDuplicateOnLeftSide()
            throws SQLException {
        Statement s = createStatement();
        s.execute("alter table constraintest add constraint c unique(val1)");
        s.execute("insert into constraintest(val1) values '1','2','3'");
        // Make sure there's a deleted index entry for val1 = 2
        s.execute("delete from constraintest where val1 = '2'");
        // Make sure there's an index entry for val1 = 2 in front of the
        // deleted one (the first row will be located in front of the deleted
        // one because it was inserted before and its record id is smaller)
        s.execute("update constraintest set val1 = '2' where val1 = '1'");
        // Insert an index entry after the deleted one. It should fail,
        // but before DERBY-4028 it was successfully inserted.
        assertStatementError("23505", s,
                "update constraintest set val1 = '2' where val1 = '3'");
    }

    /**
     * Test that we can insert and delete the same value multiple times in a
     * nullable unique index. This used to cause a livelock before DERBY-4081
     * because the duplicate check on insert sometimes didn't release all
     * latches.
     */
    public void testInsertDeleteContinuouslySameValue() throws SQLException {
        // Must disable auto-commit for reliable reproduction, otherwise the
        // post-commit worker thread will remove deleted index rows.
        setAutoCommit(false);

        Statement s = createStatement();
        s.execute("create table d4081(x int unique)");

        // The loop below did not get past the 372nd iteration before
        // DERBY-4081 was fixed. Try 500 iterations now.
        PreparedStatement ins = prepareStatement("insert into d4081 values 0");
        PreparedStatement del = prepareStatement("delete from d4081");
        for (int i = 0; i < 500; i++) {
            ins.execute();
            del.execute();
        }

        // Verify that the table is empty after the last delete operation.
        assertTableRowCount("D4081", 0);
    }

    public static void main(String [] args) {
        TestResult tr = new TestResult();
        Test t = suite();
        t.run(tr);
        System.out.println(tr.errorCount());
        Enumeration e = tr.failures();
        while (e.hasMoreElements()) {
            ((TestFailure)e.nextElement ()).thrownException().printStackTrace();
        }
        System.out.println(tr.failureCount());
    }
}