You've already forked mariadb-columnstore-engine
							
							
				mirror of
				https://github.com/mariadb-corporation/mariadb-columnstore-engine.git
				synced 2025-10-31 18:30:33 +03:00 
			
		
		
		
	
		
			
				
	
	
		
			208 lines
		
	
	
		
			6.2 KiB
		
	
	
	
		
			Plaintext
		
	
	
	
	
	
			
		
		
	
	
			208 lines
		
	
	
		
			6.2 KiB
		
	
	
	
		
			Plaintext
		
	
	
	
	
	
| --echo #
 | |
| --echo # MDEV-25080: Allow pushdown of queries involving UNIONs
 | |
| --echo # in outer select to foreign engines
 | |
| 
 | |
| --source ../include/have_columnstore.inc
 | |
| --source ../include/disable_11.8.inc
 | |
| 
 | |
| if (!$MASTER_MYPORT)
 | |
| {
 | |
|   # Running with --extern
 | |
|   let $MASTER_MYPORT=`SELECT @@port`;
 | |
| }
 | |
| 
 | |
| #
 | |
| # Enable cross engine join
 | |
| # Configure user and password in Columnstore.xml file
 | |
| #
 | |
| --exec $MCS_MCSSETCONFIG CrossEngineSupport User 'cejuser'
 | |
| --exec $MCS_MCSSETCONFIG CrossEngineSupport Password 'Vagrant1|0000001'
 | |
| --exec $MCS_MCSSETCONFIG CrossEngineSupport Port $MASTER_MYPORT
 | |
| 
 | |
| #
 | |
| # Create corresponding in the server
 | |
| #
 | |
| --disable_warnings
 | |
| CREATE USER IF NOT EXISTS'cejuser'@'localhost' IDENTIFIED BY 'Vagrant1|0000001';
 | |
| --enable_warnings
 | |
| GRANT ALL PRIVILEGES ON *.* TO 'cejuser'@'localhost';
 | |
| FLUSH PRIVILEGES;
 | |
| 
 | |
| --disable_warnings
 | |
| DROP DATABASE IF EXISTS mdev25080;
 | |
| --enable_warnings
 | |
| 
 | |
| CREATE DATABASE mdev25080;
 | |
| 
 | |
| USE mdev25080;
 | |
| 
 | |
| CREATE TABLE t1 (a varchar(30)) ENGINE=ColumnStore;
 | |
| CREATE TABLE t2 (a varchar(30)) ENGINE=ColumnStore;
 | |
| CREATE TABLE t3 (a varchar(30)) ENGINE=MyISAM;
 | |
| CREATE TABLE t4 (a varchar(30)) ENGINE=MyISAM;
 | |
| 
 | |
| INSERT INTO t1 VALUES ('abc'), ('bcd'), ('cde');
 | |
| INSERT INTO t2 VALUES ('bcd'), ('cde'), ('def'), ('efg');
 | |
| 
 | |
| INSERT INTO t3 VALUES ('t3_myisam1'), ('t3_myisam2'), ('t3_myisam3');
 | |
| INSERT INTO t4 VALUES ('t4_myisam1'), ('t4_myisam2'), ('t4_myisam3');
 | |
| 
 | |
| --echo # Pushdown of the whole UNION
 | |
| SELECT * FROM t1 UNION SELECT * FROM t2 ORDER BY 1;
 | |
| EXPLAIN SELECT * FROM t1 UNION SELECT * FROM t2 ORDER BY 1;
 | |
| 
 | |
| SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY 1;
 | |
| EXPLAIN SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY 1;
 | |
| 
 | |
| --echo # UNION with a foreign engine
 | |
| SELECT * FROM t1 UNION SELECT * FROM t3 ORDER BY 1;
 | |
| EXPLAIN SELECT * FROM t1 UNION SELECT * FROM t3 ORDER BY 1;
 | |
| 
 | |
| --echo # More than two SELECTs in a UNIT:
 | |
| SELECT * FROM t1 UNION
 | |
|   SELECT * FROM t2 UNION ALL
 | |
|   SELECT * FROM t1
 | |
| ORDER BY 1;
 | |
| 
 | |
| EXPLAIN SELECT * FROM t1 UNION
 | |
|   SELECT * FROM t2 UNION ALL
 | |
|   SELECT * FROM t1
 | |
| ORDER BY 1;
 | |
| 
 | |
| (SELECT * FROM t1 UNION
 | |
|   SELECT * FROM t2) UNION ALL
 | |
|   SELECT * FROM t1
 | |
| ORDER BY 1;
 | |
| 
 | |
| EXPLAIN (SELECT * FROM t1 UNION
 | |
|   SELECT * FROM t2) UNION ALL
 | |
|   SELECT * FROM t1
 | |
| ORDER BY 1;
 | |
| 
 | |
| SELECT * FROM t1 UNION
 | |
|   SELECT * FROM t2 UNION ALL
 | |
|   SELECT * FROM t3 UNION
 | |
|   SELECT * FROM t4
 | |
| ORDER BY 1;
 | |
| 
 | |
| EXPLAIN SELECT * FROM t1 UNION
 | |
|   SELECT * FROM t2 UNION ALL
 | |
|   SELECT * FROM t3 UNION
 | |
|   SELECT * FROM t4
 | |
| ORDER BY 1;
 | |
| 
 | |
| (SELECT * FROM t1 UNION
 | |
|   SELECT * FROM t2) UNION ALL
 | |
|   (SELECT * FROM t3 UNION
 | |
|   SELECT * FROM t4)
 | |
| ORDER BY 1;
 | |
| 
 | |
| EXPLAIN (SELECT * FROM t1 UNION
 | |
|   SELECT * FROM t2) UNION ALL
 | |
|   (SELECT * FROM t3 UNION
 | |
|   SELECT * FROM t4)
 | |
| ORDER BY 1;
 | |
| 
 | |
| SELECT count(*) FROM t1 UNION
 | |
|   SELECT count(*) FROM t2 UNION ALL
 | |
|   SELECT count(*)+20 FROM t2 UNION
 | |
|   SELECT count(*)+5 FROM t1
 | |
| ORDER BY 1;
 | |
| 
 | |
| EXPLAIN
 | |
|   SELECT count(*) FROM t1 UNION
 | |
|   SELECT count(*) FROM t2 UNION ALL
 | |
|   SELECT count(*)+20 FROM t2 UNION
 | |
|   SELECT count(*)+5 FROM t1
 | |
| ORDER BY 1;
 | |
| 
 | |
| --echo # UNION inside a derived table: the whole derived table must be pushed
 | |
| SELECT a FROM
 | |
|   (SELECT a FROM t1 UNION ALL SELECT a FROM t2) q ORDER BY a;
 | |
| 
 | |
| EXPLAIN
 | |
|   SELECT a FROM
 | |
|     (SELECT a FROM t1 UNION ALL SELECT a FROM t2) q ORDER BY a;
 | |
| 
 | |
| SELECT a FROM
 | |
|   (SELECT a FROM t1 UNION ALL SELECT a FROM t3) q ORDER BY a;
 | |
| 
 | |
| EXPLAIN
 | |
|   SELECT a FROM
 | |
|     (SELECT a FROM t1 UNION ALL SELECT a FROM t3) q ORDER BY a;
 | |
| 
 | |
| --echo # Prepared statements
 | |
| PREPARE stmt FROM "SELECT * FROM t1 UNION
 | |
|   SELECT * FROM t2 ORDER BY 1";
 | |
| 
 | |
| EXECUTE stmt;
 | |
| EXECUTE stmt;
 | |
| EXECUTE stmt;
 | |
| 
 | |
| PREPARE stmt FROM "EXPLAIN SELECT * FROM t1 UNION
 | |
|   SELECT * FROM t2 ORDER BY 1";
 | |
| 
 | |
| EXECUTE stmt;
 | |
| EXECUTE stmt;
 | |
| 
 | |
| PREPARE stmt FROM "(SELECT * FROM t1 UNION
 | |
|   SELECT * FROM t2) UNION ALL
 | |
|   (SELECT * FROM t1 UNION
 | |
|   SELECT * FROM t2) ORDER BY 1";
 | |
| 
 | |
| EXECUTE stmt;
 | |
| EXECUTE stmt;
 | |
| EXECUTE stmt;
 | |
| 
 | |
| PREPARE stmt FROM "EXPLAIN (SELECT * FROM t1 UNION
 | |
|   SELECT * FROM t2) UNION ALL
 | |
|   (SELECT * FROM t1 UNION
 | |
|   SELECT * FROM t2) ORDER BY 1";
 | |
| 
 | |
| EXECUTE stmt;
 | |
| EXECUTE stmt;
 | |
| 
 | |
| --echo # MCOL-5432 Disable UNION pushdown if an ORDER BY or a LIMIT
 | |
| --echo # clause is involved, until MCOL-5222 is fixed.
 | |
| SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY a;
 | |
| EXPLAIN SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY a;
 | |
| SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY a LIMIT 3;
 | |
| EXPLAIN SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY a LIMIT 3;
 | |
| SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY a DESC LIMIT 5;
 | |
| EXPLAIN SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY a DESC LIMIT 5;
 | |
| SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY a LIMIT 3 OFFSET 2;
 | |
| EXPLAIN SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY a LIMIT 3 OFFSET 2;
 | |
| 
 | |
| DELETE FROM t1; DELETE FROM t2; DELETE FROM t3; DELETE FROM t4;
 | |
| INSERT INTO t1 VALUES ('1_abc'), ('3_bcd'), ('4_cde');
 | |
| INSERT INTO t2 VALUES ('2_bcd'), ('5_cde'), ('6_def'), ('0_efg');
 | |
| INSERT INTO t3 VALUES ('10_t3_myisam1'), ('11_t3_myisam2'), ('12_t3_myisam3');
 | |
| INSERT INTO t4 VALUES ('20_t4_myisam1'), ('21_t4_myisam2'), ('22_t4_myisam3');
 | |
| 
 | |
| SELECT a FROM (SELECT a FROM t1 UNION SELECT a FROM t2) AS sub ORDER BY a ASC;
 | |
| EXPLAIN SELECT a FROM (SELECT a FROM t1 UNION SELECT a FROM t2) AS sub ORDER BY a ASC;
 | |
| 
 | |
| SELECT a FROM (SELECT a FROM t1 UNION ALL SELECT a FROM t2) AS sub ORDER BY a DESC;
 | |
| EXPLAIN SELECT a FROM (SELECT a FROM t1 UNION ALL SELECT a FROM t2) AS sub ORDER BY a DESC;
 | |
| 
 | |
| # multi-select chain
 | |
| SELECT a FROM (SELECT a FROM t1 UNION SELECT a FROM t2 UNION ALL SELECT a FROM t3) AS sub ORDER BY a;
 | |
| EXPLAIN SELECT a FROM (SELECT a FROM t1 UNION SELECT a FROM t2 UNION ALL SELECT a FROM t3) AS sub ORDER BY a;
 | |
| 
 | |
| # nested
 | |
| SELECT a FROM ((SELECT a FROM t1 UNION SELECT a FROM t2) UNION ALL SELECT a FROM t3) AS sub ORDER BY a;
 | |
| EXPLAIN SELECT a FROM ((SELECT a FROM t1 UNION SELECT a FROM t2) UNION ALL SELECT a FROM t3) AS sub ORDER BY a;
 | |
| 
 | |
| # aggregate
 | |
| SELECT cnt FROM (SELECT COUNT(*) AS cnt FROM t1 UNION SELECT COUNT(*) AS cnt FROM t2) AS sub ORDER BY cnt;
 | |
| EXPLAIN SELECT cnt FROM (SELECT COUNT(*) AS cnt FROM t1 UNION SELECT COUNT(*) AS cnt FROM t2) AS sub ORDER BY cnt;
 | |
| 
 | |
| # empty subquery result
 | |
| DELETE FROM t1; DELETE FROM t2;
 | |
| SELECT a FROM (SELECT a FROM t1 UNION SELECT a FROM t2) AS sub ORDER BY a;
 | |
| EXPLAIN SELECT a FROM (SELECT a FROM t1 UNION SELECT a FROM t2) AS sub ORDER BY a;
 | |
| 
 | |
| DROP USER 'cejuser'@'localhost';
 | |
| DROP TABLE t1, t2, t3, t4;
 | |
| DROP DATABASE mdev25080;
 |