Re: [Maria-developers] Sachin weekly report
Hi Sergei,
Weekly Report for 4th week of gsoc
1. Field property is_row_hash , field_visibility successfully saved and
retrived from frm , using extra2 space
2. Some tests added.
3. Solved the error when there is another primary key(it used to accept
duplicate in this case ).
4. Added hidden in parser.
5. Identified the memory leak 1 is because of malloc db_row_hash str.I did
not freed it. second memory leak i am searching for it.
Work for this week.
1 First solve the memory leak problem.
2 Work on FULL_HIDDEN_FIELDS.
3 in mysql_prepare_create_table I am using an iterator it would be better
if i can add custom field when it says an error. So will not have to use
iterator as suggested by you sir.
4 rename the hash field automatically in the case clash.
This week
On Thu, Jun 16, 2016 at 11:46 PM, Sergei Golubchik
Hi, Sachin!
On Jun 15, Sachin Setia wrote:
But the major problem is:- Consider this case
create table tbl(abc int primary key,xyz blob unique);
In this case , second key_info will have one user_defined_key_parts but
two
ext_key_parts second key_part refers to primary key. because of this ha_index_read_idx_map always return HA_ERR_KEY_NOT_FOUND I am trying to solve this problem.
I've seen you solved this, but I do not understand the problem (and so I cannot understand the fix either).
Problem was consider this create table tbl(abc int primary key , xyz blob unique); insert into tbl value(1,12); insert into tbl value(2,12); # no error , details in commit comment https://github.com/MariaDB/server/commit/baecc73380084c61b9323a30f3e25977176...
Please, try to add a test case for the problem you're fixing. In the same commit, preferrably.
Now you can still commit a test case for this problem and your fix,
then, I hope, I'll be able to understand better what the problem was.
Regards, Sergei Chief Architect MariaDB and security@mariadb.org
Hello everyone,
Weekly Report for 5th week of gsoc
1. select worked without showing db_row_hash
2. db_row_hash column is put in first place rather then last
3. show create table will not show db_row_hash_*
4. select will not show hidden level 3
5. user defined hidden field worked.
6 we can also create definition like create table t1(abc int blob
unique, db_row_hash_1 int unique); //this
will automatically create column db_row_hash_2 for storing hash
7. db_row_hash_1 are like invisible to alter command if we add column
db_row_hash_1 using alter. internal hidden column db_row_hash_1 will
automatically rename to db_row_hash_2.
8 we can also add unique constraint to blob in alter command and it
can also be deleted.
9 show create table will not show db_row_hash_* , and if it find hash
column it will show like unique(column names)
Regards
sachin
On Mon, Jun 20, 2016 at 11:50 AM, Sachin Setia
Hi Sergei,
Weekly Report for 4th week of gsoc
1. Field property is_row_hash , field_visibility successfully saved and retrived from frm , using extra2 space 2. Some tests added. 3. Solved the error when there is another primary key(it used to accept duplicate in this case ). 4. Added hidden in parser. 5. Identified the memory leak 1 is because of malloc db_row_hash str.I did not freed it. second memory leak i am searching for it. Work for this week. 1 First solve the memory leak problem. 2 Work on FULL_HIDDEN_FIELDS. 3 in mysql_prepare_create_table I am using an iterator it would be better if i can add custom field when it says an error. So will not have to use iterator as suggested by you sir. 4 rename the hash field automatically in the case clash. This week On Thu, Jun 16, 2016 at 11:46 PM, Sergei Golubchik
wrote: Hi, Sachin!
On Jun 15, Sachin Setia wrote:
But the major problem is:- Consider this case
create table tbl(abc int primary key,xyz blob unique);
In this case , second key_info will have one user_defined_key_parts but two ext_key_parts second key_part refers to primary key. because of this ha_index_read_idx_map always return HA_ERR_KEY_NOT_FOUND I am trying to solve this problem.
I've seen you solved this, but I do not understand the problem (and so I cannot understand the fix either).
Problem was consider this create table tbl(abc int primary key , xyz blob unique); insert into tbl value(1,12); insert into tbl value(2,12); # no error , details in commit comment https://github.com/MariaDB/server/commit/baecc73380084c61b9323a30f3e25977176...
Please, try to add a test case for the problem you're fixing. In the same commit, preferrably.
Now you can still commit a test case for this problem and your fix, then, I hope, I'll be able to understand better what the problem was.
Regards, Sergei Chief Architect MariaDB and security@mariadb.org
Hello everyone, Weekly Report for 6th week of gsoc 1.hidden fields fully supported , they also show in extra column 2.suppose if we declare key as unique(abc,df) then instead of key name to be abc it will be abc_df 3.prototype and prototype for how to store information about hash and type of hash in field and KEY finally decided to add bool flag (is_row_hash) in Field and added a new long flag in KEY named ex_flags it is stored and retried from extra2 region 4. studying optimizer code for where condition on unique key. 5. Now it will give error for these statements create table t1(abc blob unique,index(db_row_hash_1)); alter table t2 add column abc blob unique,add index(db_row_hash_1); 6.now we can delete unique blob columns.Db_row_hash will be automatically removed currently working on case like create table t1(a blob,b blob ,unique(a,b)); alter table t1 drop column a; this works after alter but records stored in table can be duplicate which voids the unique key rule. Regards sachin
Hi, Sachin! Here's a review of your commits from b69e141a32 to 674eb4c4277. Last time I've reviewed up to b69e141a32, so next time I'll review from 674eb4c4277 and up. Thanks for your work!
diff --git a/mysql-test/r/long_unique.result b/mysql-test/r/long_unique.result new file mode 100644 index 0000000..fc6ff12 --- /dev/null +++ b/mysql-test/r/long_unique.result @@ -0,0 +1,160 @@ +create table z_1(abc blob unique); +insert into z_1 values(112); +insert into z_1 values('5666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666'); +insert into z_1 values('sachin'); +insert into z_1 values('sachin'); +ERROR 23000: Can't write; duplicate key in table 'z_1' +select * from z_1; +abc +112 +5666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666 +sachin +select db_row_hash_1 from z_1; +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' +desc z_1; +Field Type Null Key Default Extra +abc blob YES NULL +select * from information_schema.columns where table_schema='mtr' and table_name='z_1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION COLUMN_DEFAULT IS_NULLABLE DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME COLUMN_TYPE COLUMN_KEY EXTRA PRIVILEGES COLUMN_COMMENT +create table tst_1(xyz blob unique , x2 blob unique); +insert into tst_1 values(1,22); +insert into tst_1 values(2,22); +ERROR 23000: Can't write; duplicate key in table 'tst_1' +select * from tst_1; +xyz x2 +1 22 +select db_row_hash_1 from tst_1; +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' +select db_row_hash_2 from tst_1; +ERROR 42S22: Unknown column 'db_row_hash_2' in 'field list' +select db_row_hash_1,db_row_hash_2 from tst_1; +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' +desc tst_1; +Field Type Null Key Default Extra +xyz blob YES NULL +x2 blob YES NULL +select * from information_schema.columns where table_schema='mtr' and table_name='tst_1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION COLUMN_DEFAULT IS_NULLABLE DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME COLUMN_TYPE COLUMN_KEY EXTRA PRIVILEGES COLUMN_COMMENT +create table t1 (empnum smallint, grp int); +create table t2 (empnum int, name char(5)); +insert into t1 values(1,1); +insert into t2 values(1,'bob'); +create view v1 as select * from t2 inner join t1 using (empnum); +select * from v1; +empnum name grp +1 bob 1
what is this test for? (with t1, t2, v1)
+create table c_1(abc blob unique, db_row_hash_1 int unique); +desc c_1; +Field Type Null Key Default Extra +abc blob YES NULL +db_row_hash_1 int(11) YES UNI NULL +insert into c_1 values(1,1); +insert into c_1 values(1,2); +ERROR 23000: Can't write; duplicate key in table 'c_1' +create table c_2(abc blob unique,xyz blob unique, db_row_hash_2 +int,db_row_hash_1 int unique); +desc c_2; +Field Type Null Key Default Extra +abc blob YES NULL +xyz blob YES NULL +db_row_hash_2 int(11) YES NULL +db_row_hash_1 int(11) YES UNI NULL +insert into c_2 values(1,1,1,1); +insert into c_2 values(1,23,4,5); +ERROR 23000: Can't write; duplicate key in table 'c_2' +create table u_1(abc int primary key , xyz blob unique); +insert into u_1 values(1,2); +insert into u_1 values(2,3); +update u_1 set xyz=2 where abc=1; +alter table z_1 drop db_row_hash_1; +ERROR 42000: Can't DROP 'db_row_hash_1'; check that column/key exists +alter table c_1 drop db_row_hash_2; +ERROR 42000: Can't DROP 'db_row_hash_2'; check that column/key exists +alter table c_1 drop db_row_hash_1; +alter table z_1 add column db_row_hash_1 int unique; +show create table z_1; +Table Create Table +z_1 CREATE TABLE `z_1` ( + `abc` blob, + `db_row_hash_1` int(11) DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `abc`(`abc`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +insert into z_1 values('sachin',1); +ERROR 23000: Can't write; duplicate key in table 'z_1' +alter table c_1 add column db_row_hash_2 int; +show create table c_1; +Table Create Table +c_1 CREATE TABLE `c_1` ( + `abc` blob, + `db_row_hash_2` int(11) DEFAULT NULL, + UNIQUE KEY `abc`(`abc`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +alter table z_1 change db_row_hash_2 temp int; +ERROR 42S22: Unknown column 'db_row_hash_2' in 'z_1' +alter table c_1 change db_row_hash_3 temp int; +ERROR 42S22: Unknown column 'db_row_hash_3' in 'c_1' +alter table c_1 change db_row_hash_4 temp int; +ERROR 42S22: Unknown column 'db_row_hash_4' in 'c_1' +alter table c_2 change db_row_hash_1 temp int; +create table c_3(abc blob unique, xyz blob); +alter table c_3 add index(db_row_hash_1); +ERROR 42000: Key column 'DB_ROW_HASH_1' doesn't exist in table +create table i_1(x1 int ); +alter table i_1 add column x2 blob unique; +insert into i_1 value(1,1); +insert into i_1 value(2,1); +ERROR 23000: Can't write; duplicate key in table 'i_1' +alter table i_1 drop index x2; +insert into i_1 value(2,1); +create table i_2(abc blob); +insert into i_2 values(1); +alter table i_2 add unique index(abc); +select * from i_2; +abc +1 +insert into i_2 values(22); +insert into i_2 values(22); +ERROR 23000: Can't write; duplicate key in table 'i_2' +alter table i_2 drop key abc; +insert into i_2 values(22); +drop table i_2; +create table i_2(abc blob); +insert into i_2 values(1); +alter table i_2 add constraint unique(abc); +select * from i_2; +abc +1 +insert into i_2 values(22); +insert into i_2 values(22); +ERROR 23000: Can't write; duplicate key in table 'i_2' +alter table i_2 drop key abc; +insert into i_2 values(22); +create table di_1(abc blob , xyz int , index(abc,xyz));
what is this test for?
+show create table di_1; +Table Create Table +di_1 CREATE TABLE `di_1` ( + `abc` blob, + `xyz` int(11) DEFAULT NULL, + INDEX `abc_xyz`(`abc`,`xyz`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +insert into di_1 values(1,1); +insert into di_1 values(1,1); +insert into di_1 values(2,1); +create table di_2 (abc blob); +insert into di_2 values(1); +insert into di_2 values(1); +alter table di_2 add index(abc); +show create table di_2; +Table Create Table +di_2 CREATE TABLE `di_2` ( + `abc` blob, + INDEX `abc`(`abc`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +insert into di_2 values(1); +alter table di_2 drop index abc; +show create table di_2; +Table Create Table +di_2 CREATE TABLE `di_2` ( + `abc` blob +) ENGINE=MyISAM DEFAULT CHARSET=latin1
please add tests for the following: 1. blob with a couple of really long lines. like into t1 values(repeat('x', 500*1024*1024)); into t1 values(repeat('y', 500*1024*1024)); into t1 values(repeat('x', 500*1024*1024)); just don't do select * after that :) 2. TEXT, where collation matters and equal strings aren't always bytewise identical: create t1 (a TEXT CHARSET latin1 COLLATE latin1_german2_ci); insert t1 values ('ae'); insert t1 values ('AE'); insert t1 values ('Ä'); last two inserts must be an error (I suspect. If not sure, you can always test it as, for example, SELECT 'ae' = 'AE' COLLATE latin1_german2_ci; 3. multi-column constraints, like create t1 (a blob, b int, unique (a,b)); create t2 (a blob, b blob, unique (a,b)); create t3 (a varchar(2048), b varchar(2048), unique(a,b)); and also test inserts and errors with this multi-column constraints, not only create table statement.
diff --git a/mysql-test/t/hidden_columns.test b/mysql-test/t/hidden_columns.test new file mode 100644 index 0000000..f0fed41 --- /dev/null +++ b/mysql-test/t/hidden_columns.test
where's the hidden_columns.result?
diff --git a/mysql-test/t/hidden_field.test b/mysql-test/t/hidden_field.test new file mode 100644 index 0000000..3806a92 --- /dev/null +++ b/mysql-test/t/hidden_field.test
where's the hidden_field.result? how is it different from hidden_columns.test, why not to put all tests there? I mean the difference between "hidden column" and "hidden field" is really subtle. Either rename one of the test files or, combine them, or, I think, the best way would be to move tests from hidden_columns.test to long_unique.test
@@ -0,0 +1,35 @@ +create table h_1(abc int primary key, xyz int hidden); +create table h_2(a1 int hidden);
This, probably, should not be allowed. I mean, what 'SELECT * FROM h_2' will do? Let's return an error ER_TABLE_MUST_HAVE_COLUMNS in this case.
+--error 1064
try to use error names, not error numbers (see them in include/mysqld_error.h)
+create table h_3(a1 blob,hidden(a1)); +--error 1981 +create table h_4(a1 int primary key hidden ,a2 int unique hidden , a3 blob,a4 +int not null hidden unique); +--error 1981 +create table h_5(abc int not null hidden); +# +create table t1(abc int hidden); +#should automatically add null +insert into t1 values(); +insert into t1 values(); +insert into t1 values(); +insert into t1 values(); +--error 1096 +select * from t1;
see, the error doesn't really fit here. 1096 is ER_NO_TABLES_USED, but the table is used here. Let's just disallow tables with no visible columns.
+select abc from t1; + +create table t2(abc int primary key); +insert into t2 values(); +select * from t2; +--error 1064 +create table sdsdsd(a int , b int, hidden(a,b)); + +create table hid_4(a int,abc int as (a mod 3) virtual hidden); +desc hid_4; +create table ht_5(abc int primary key hidden auto_increment, a int); +desc ht_5; +insert into ht_5 values(1); +insert into ht_5 values(2); +insert into ht_5 values(3); +select * from ht_5; +select abc,a from ht_5;
if you'd have hidden_field.result you'd notice that this test doesn't clean up after itself :)
diff --git a/mysql-test/t/long_unique.test b/mysql-test/t/long_unique.test new file mode 100644 index 0000000..fc8bcf5 --- /dev/null +++ b/mysql-test/t/long_unique.test @@ -0,0 +1,114 @@ +create table z_1(abc blob unique); +insert into z_1 values(112); +insert into z_1 values('5666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666');
better use repeat() function in these cases. makes test cases smaller and more readable.
+insert into z_1 values('sachin'); +--error 1022 +insert into z_1 values('sachin'); +select * from z_1; +--error 1054 +select db_row_hash_1 from z_1; +desc z_1; +select * from information_schema.columns where table_schema='mtr' and table_name='z_1';
did you read results of your tests? wasn't it suspicious that this select returns nothing? it's because the table is in the 'test' schema, not in 'mtr'. Please, fix.
+create table tst_1(xyz blob unique , x2 blob unique); +insert into tst_1 values(1,22); +--error 1022 +insert into tst_1 values(2,22); +select * from tst_1; +--error 1054 +select db_row_hash_1 from tst_1; +--error 1054 +select db_row_hash_2 from tst_1; +--error 1054 +select db_row_hash_1,db_row_hash_2 from tst_1; +desc tst_1; +select * from information_schema.columns where table_schema='mtr' and table_name='tst_1';
same
+create table t1 (empnum smallint, grp int); +create table t2 (empnum int, name char(5)); +insert into t1 values(1,1); +insert into t2 values(1,'bob'); +create view v1 as select * from t2 inner join t1 using (empnum); +select * from v1;
what was the point of this t1/t2/v1 test?
+#test on create table with column db_row_hash +create table c_1(abc blob unique, db_row_hash_1 int unique); +desc c_1; +insert into c_1 values(1,1); +--error 1022 +insert into c_1 values(1,2); +create table c_2(abc blob unique,xyz blob unique, db_row_hash_2 +int,db_row_hash_1 int unique); +desc c_2; +insert into c_2 values(1,1,1,1); +--error 1022 +insert into c_2 values(1,23,4,5); +#update table +create table u_1(abc int primary key , xyz blob unique); +insert into u_1 values(1,2); +insert into u_1 values(2,3); +update u_1 set xyz=2 where abc=1;
this updates the row to itw old values. test the update to new values. to non-duplicate and to duplicate values.
+#alter table drop column +--error 1091 +alter table z_1 drop db_row_hash_1; +--error 1091 +alter table c_1 drop db_row_hash_2; +alter table c_1 drop db_row_hash_1; +#add column +alter table z_1 add column db_row_hash_1 int unique; +show create table z_1; +#insert should not break +--error 1022 +insert into z_1 values('sachin',1);
good
+alter table c_1 add column db_row_hash_2 int;
test also adding and removing unique index for blobs. 1. adding when a column has no duplicates 2. adding when a column has duplicates 3. adding when a column has duplicates and IGNORE clause was used
+show create table c_1; +#modify db_row_hash +--error 1054 +alter table z_1 change db_row_hash_2 temp int; +--error 1054 +alter table c_1 change db_row_hash_3 temp int; +--error 1054 +alter table c_1 change db_row_hash_4 temp int; +alter table c_2 change db_row_hash_1 temp int; +# now try to index db_row_hash +create table c_3(abc blob unique, xyz blob); +--error 1072 +alter table c_3 add index(db_row_hash_1); +create table i_1(x1 int ); +alter table i_1 add column x2 blob unique; +insert into i_1 value(1,1); +--error 1022 +insert into i_1 value(2,1); +alter table i_1 drop index x2; +insert into i_1 value(2,1); +create table i_2(abc blob); +insert into i_2 values(1); +alter table i_2 add unique index(abc); +select * from i_2; +insert into i_2 values(22); +--error 1022 +insert into i_2 values(22); +alter table i_2 drop key abc; +insert into i_2 values(22); +drop table i_2; +create table i_2(abc blob); +insert into i_2 values(1); +alter table i_2 add constraint unique(abc); +select * from i_2; +insert into i_2 values(22); +--error 1022 +insert into i_2 values(22); +alter table i_2 drop key abc; +insert into i_2 values(22); +# now some indexes on blob these should allow +# duplicates these will be used in where clause +create table di_1(abc blob , xyz int , index(abc,xyz)); +show create table di_1; +insert into di_1 values(1,1); +insert into di_1 values(1,1); +insert into di_1 values(2,1); +create table di_2 (abc blob); +insert into di_2 values(1); +insert into di_2 values(1); +alter table di_2 add index(abc);
what kind of index is used here? should be a normal index, no hash, no hidden db_row_hash_1 column, just a normal b-tree index.
+show create table di_2; +insert into di_2 values(1); +alter table di_2 drop index abc; +show create table di_2;
you never clean up in these tests. see other - existing - test files, they always drop all created tables and views, so that when the test end all databases look exactly as before the test started.
diff --git a/include/my_base.h b/include/my_base.h index 8b546ed..d5c697b 100644 --- a/include/my_base.h +++ b/include/my_base.h @@ -250,6 +250,8 @@ enum ha_base_keytype {
#define HA_NOSAME 1 /* Set if not dupplicated records */ #define HA_PACK_KEY 2 /* Pack string key to previous key */ +#define HA_INDEX_HASH 4 /* */
you don't need HA_INDEX_HASH. See above, non-unique index on blobs should be just a normal b-tree index, no hash, subject to automatic key truncation, see sql_table.cc around the line with the comment /* not a critical problem */
+#define HA_UNIQUE_HASH 8
as you've found out already, there two bits are not free
#define HA_AUTO_KEY 16 #define HA_BINARY_PACK_KEY 32 /* Packing of all keys to prev key */ #define HA_FULLTEXT 128 /* For full-text search */ diff --git a/sql/field.h b/sql/field.h index 08905f2..2e6e0e4 100644 --- a/sql/field.h +++ b/sql/field.h @@ -628,6 +628,8 @@ class Field: public Value_source @c NOT @c NULL field, this member is @c NULL. */ uchar *null_ptr; + field_visible_type field_visibility=NORMAL; + bool is_hash=false;
please add a comment for is_hash or rename it to something that is self-explanatory. field_visibility, for example, is self-explanatory.
/* Note that you can use table->in_use as replacement for current_thd member only inside of val_*() and store() members (e.g. you can't use it in cons) @@ -3051,6 +3052,10 @@ class Field_blob :public Field_longstr { inline uint32 get_length(uint row_offset= 0) { return get_length(ptr+row_offset, this->packlength); } uint32 get_length(const uchar *ptr, uint packlength); + uint32 data_length(int row_offset=0) + { + return get_length(row_offset); + }
Huh? There was no Field_blob::data_length(), it was using the parent implementation Field::data_length(). That was returning pack_length(), that is Field_blob::pack_length(), which is simply packlength + portable_sizeof_char_ptr Now you've defined Field_blob::data_length() to return get_length(0). That is, you've changed the meaning of Field_blob::data_length(). Is that ok? Was old Field_blob::data_length() never used?
uint32 get_length(const uchar *ptr_arg) { return get_length(ptr_arg, this->packlength); } inline void get_ptr(uchar **str) @@ -3455,6 +3460,8 @@ class Create_field :public Sql_alloc max number of characters. */ ulonglong length; + field_visible_type field_visibility=NORMAL; + bool is_hash=false;
don't do that. gcc complains warning: non-static data member initializers only available with -std=c++11 or -std=gnu++11 and we don't use c++11 yet, because some of our compilers in buildbot don't support it.
/* The value of `length' as set by parser: is the number of characters for most of the types, or of bytes for BLOBs or numeric types. diff --git a/sql/handler.cc b/sql/handler.cc index 49e451e..e7d7815 100644 --- a/sql/handler.cc +++ b/sql/handler.cc @@ -5864,16 +5864,60 @@ int handler::ha_reset() DBUG_RETURN(reset()); }
- +/** @brief + Compare two records + It requires both records to be present in table->record[0] + and table->record[1] + @returns true if equal else false + */ +bool rec_hash_cmp(uchar *first_rec, uchar *sec_rec, Field *hash_field) +{ + Item_args * t_item=(Item_args *)hash_field->vcol_info->expr_item; + int arg_count = t_item->argument_count(); + Item ** arguments=t_item->arguments(); + int diff = sec_rec-first_rec; + Field * t_field; + for(int i=0;i
field;//need a debug assert + if(t_field->cmp_binary_offset(diff)) + return false; + } + return true; +}
1. please format the code like it's done elsewhere in the file. - in assignments: no space before '=', one space after - after a function/method must be one or two empty lines - in if/for/while: a space between the keyword and a parenthesys - in for() loop - a space after a semicolon - in function arguments - a space after a comma - not in the function above, but everywhere in your patch 2. it's better to avoid type conversion where it's not needed, for example, t_item->argument_count() returns uint, so your arg_count should be of that type too. 3. either write a completely generic function that compares two records given as pointers, or write a function that compares record[0] and record[1]. Ok, it looks you need to compare a record as a pointer with record[0]. Then remove first_rec, it only creates a false pretence that a function is more generic than it is. Instead, do int diff= sec_rec - hash_field->table->record[0]; (and, may be, rename sec_rec to "other_rec") 4. what do you mean "need a debug assert"? if you need it, add it :) if you want to add a debug assert, but don't know how - please, ask.
int handler::ha_write_row(uchar *buf) { - int error; + int error,result; Log_func *log_func= Write_rows_log_event::binlog_row_logging_function; + Field *field_iter; DBUG_ASSERT(table_share->tmp_table != NO_TMP_TABLE || m_lock_type == F_WRLCK); DBUG_ENTER("handler::ha_write_row"); DEBUG_SYNC_C("ha_write_row_start"); - + /* First need to whether inserted record is unique or not */ + /* One More Thing if i implement hidden field then detection can be easy */
this second comment is probably obsolete, you can remove it
+ for(uint i=0;i<table->s->keys;i++) + { + if(table->key_info[i].flags&HA_UNIQUE_HASH)
in fact, you don't need a special key flag. you can check, like if (table->key_info[i].key_part->field->is_hash) but a flag makes it kinda simpler, so if you like the flag, go ahead and use it (if you find an free bit for it). Perhaps, even, you can use the key flag and remove Field::is_hash? The field does not need any special treatment, does it? it only needs to be hidden.
+ { + field_iter=table->key_info[i].key_part->field;
why did you name it "field_iter"? it's not an iterator. may be "hash_field"?
+ int len =table->key_info[i].key_length; + uchar ptr[len];
we compile with -Wvla, so this will be a warning too. Just use ptr[9], for example. And add DBUG_ASSERT(len < sizeof(ptr));
+ if(field_iter->is_null()) + { + goto write_row;
no goto here, just break;
+ } + key_copy(ptr,buf,&table->key_info[i],len,false); + result= table->file->ha_index_read_idx_map(table->record[1],i,ptr, + HA_WHOLE_KEY,HA_READ_KEY_EXACT); + if(!result) + { + if(rec_hash_cmp(table->record[0],table->record[1],field_iter)) + DBUG_RETURN(HA_ERR_FOUND_DUPP_KEY); + } + } + } + write_row:
and no label here
MYSQL_INSERT_ROW_START(table_share->db.str, table_share->table_name.str); mark_trx_read_write(); increment_statistics(&SSV::ha_write_count); @@ -5907,6 +5952,36 @@ int handler::ha_update_row(const uchar *old_data, uchar *new_data) DBUG_ASSERT(new_data == table->record[0]); DBUG_ASSERT(old_data == table->record[1]);
+ /* First need to whether inserted record is unique or not */ + /* One More Thing if i implement hidden field then detection can be easy */ + for(uint i=0;i<table->s->keys;i++) + { + if(table->key_info[i].flags&HA_UNIQUE_HASH) + { + /* + We need to add the null bit + If the column can be NULL, then in the first byte we put 1 if the + field value is NULL, 0 otherwise. + */ + uchar *new_rec = (uchar *)alloc_root(&table->mem_root, + table->s->reclength*sizeof(uchar));
do you know how alloc_root works? read include/mysql/service_thd_alloc.h memory allocated with alloc_root() can not be freed individually, it is freed when the complete MEM_ROOT is reset or destroyed. so, three problems here: 1. you allocate memory on MEM_ROOT in a loop. so, if the table has, say three HA_UNIQUE_HASH keys, you'll allocate the buffer three times, while one should've been totally sufficient 2. you allocate for every row that is inserted 3. you allocate it on the *TABLE::mem_root*. Table's memroot is freed only when a table is closed! So, if you create a table with three unique(blob) keys, and insert four rows in one statement: INSERT ... VALUES (),(),(),(),(). And repeat this insert five times, you'll allocate 3*4*5=60 reclength bytes. They'll not be freed, so if you repeat this insert five more times, it'll be 60 reclength more bytes. And so on :) I think the good approach would be to have, like TABLE::check_unique_buf row buffer. See that TABLE has now: uchar *record[2]; /* Pointer to records */ uchar *write_row_record; /* Used as optimisation in THD::write_row */ uchar *insert_values; /* used by INSERT ... UPDATE */ that's where you add uchar *check_unique_buf; it's initialized to 0. and on the first use you do, like if (!table->check_unique_buf) table->check_unique_buf= alloc_root(&table->mem_root, ...) and then you can freely use it for checking your unique constraints. it'll be allocated only once per TABLE.
+ field_iter=table->key_info[i].key_part->field; + uchar ptr[9];
better #define UNIQ_HASH_KEY_LEN 9 and use it everywhere
+ if(field_iter->is_null()) + { + goto write_row; + } + key_copy(ptr,new_data,&table->key_info[i],9,false); + result= table->file->ha_index_read_idx_map(new_rec,i,ptr, + HA_WHOLE_KEY,HA_READ_KEY_EXACT); + if(!result) + { + if(rec_hash_cmp(table->record[0],new_rec,field_iter)) + return HA_ERR_FOUND_DUPP_KEY; + } + } + } + write_row:
this is the same code as in handler::ha_write_row, please combine them into one function (for simplicity you can use table->check_unique_buf also for INSERT)
MYSQL_UPDATE_ROW_START(table_share->db.str, table_share->table_name.str); mark_trx_read_write(); increment_statistics(&SSV::ha_update_count); diff --git a/sql/item.cc b/sql/item.cc index adf7031..2015752 100644 --- a/sql/item.cc +++ b/sql/item.cc @@ -5059,7 +5059,13 @@ bool Item_field::fix_fields(THD *thd, Item **reference) } else if (!from_field) goto error; - + if(from_field->field_visibility==FULL_HIDDEN) + { + my_error(ER_BAD_FIELD_ERROR, MYF(0), (* reference)->full_name(), + thd->where); + from_field=NULL; + goto error; + }
So, you're patching the "search for field by name" process, pretending that the field does not exist if it's FULL_HIDDEN. This is, of course, correct. But I suspect you're doing it too late. Consider this case: create table t1 (b blob, unique (b)); create table t2 (db_row_hash_1 int, a int); select * from t1, t2 where db_row_hash_1=5; in this case, mariadb needs to search for db_row_hash_1 field in t1, should not find it, continue searching in t2, find it there. in your code it will find it in t1, and later reject it with ER_BAD_FIELD_ERROR. there may be more complex cases, with subqueries and outer selects, views, etc. important part is - you need to reject FULL_HIDDEN field immediately when it's found, so that the search could continue in other tables, outer selects, etc. btw, don't forget to add tests for this behavior (one table or outer select has db_row_hash_1 visible field, another table has db_row_hash_1 FULL_HIDDEN field).
table_list= (cached_table ? cached_table : from_field != view_ref_found ? from_field->table->pos_in_table_list : 0); diff --git a/sql/item_func.cc b/sql/item_func.cc index 6edb276..889ac40 100644 --- a/sql/item_func.cc +++ b/sql/item_func.cc @@ -1916,6 +1916,37 @@ void Item_func_int_div::fix_length_and_dec() }
+longlong Item_func_hash::val_int() +{ + unsigned_flag= true; + ulong nr1= 1,nr2= 4; + CHARSET_INFO *cs; + for(uint i= 0;i
val_str(); + if(args[i]->null_value) + { + null_value= 1; + return 0; + } + cs= str->charset(); + uchar l[4]; + int4store(l,str->length()); + cs->coll->hash_sort(cs,l,sizeof(l), &nr1, &nr2);
looks good, but use my_charset_binary for the length.
+ cs->coll->hash_sort(cs, (uchar *)str->ptr(), str->length(), &nr1, &nr2); + } + return (longlong)nr1; +} + + +void Item_func_hash::fix_length_and_dec() +{ + maybe_null= 1; + decimals= 0; + max_length= 8; +} + + longlong Item_func_mod::int_op() { DBUG_ASSERT(fixed == 1); diff --git a/sql/lex.h b/sql/lex.h index 22ff4e6..d7a4e14 100644 --- a/sql/lex.h +++ b/sql/lex.h @@ -266,6 +266,7 @@ static SYMBOL symbols[] = { { "HAVING", SYM(HAVING)}, { "HELP", SYM(HELP_SYM)}, { "HIGH_PRIORITY", SYM(HIGH_PRIORITY)}, + {"HIDDEN", SYM(HIDDEN)},
spacing! align it as all other rows are
{ "HOST", SYM(HOST_SYM)}, { "HOSTS", SYM(HOSTS_SYM)}, { "HOUR", SYM(HOUR_SYM)}, diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index 709ac55..9ae3ac6 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -7139,3 +7139,5 @@ ER_KILL_QUERY_DENIED_ERROR ER_NO_EIS_FOR_FIELD eng "Engine-independent statistics are not collected for column '%s'" ukr "Незалежна від типу таблиці статистика не збирається для стовбця '%s'" +ER_HIDDEN_NOT_NULL_WOUT_DEFAULT + eng "Hidden column '%s' either allow null values or it must have default value"
when you'll merge with 10.2 make sure this your new error will end up at the very end, after ER_EXPRESSION_REFERS_TO_UNINIT_FIELD
diff --git a/sql/sql_class.h b/sql/sql_class.h index 8bfc243..bb206a8 100644 --- a/sql/sql_class.h +++ b/sql/sql_class.h @@ -297,7 +297,7 @@ class Key :public Sql_alloc, public DDL_options { LEX_STRING name; engine_option_value *option_list; bool generated; - + key_hash_type hash_type=NOT_HASH;
same as above about c++11
Key(enum Keytype type_par, const LEX_STRING &name_arg, ha_key_alg algorithm_arg, bool generated_arg, DDL_options_st ddl_options) :DDL_options(ddl_options), diff --git a/sql/sql_base.cc b/sql/sql_base.cc index e808fba..b2c8dfb 100644 --- a/sql/sql_base.cc +++ b/sql/sql_base.cc @@ -8343,6 +8343,8 @@ insert_fields(THD *thd, Name_resolution_context *context, const char *db_name,
for (; !field_iterator.end_of_fields(); field_iterator.next()) { + if(field_iterator.field()==NULL ||
eh... can it be NULL here, really?
+ field_iterator.field()->field_visibility==NORMAL){ Item *item;
if (!(item= field_iterator.create_item(thd))) diff --git a/sql/sql_insert.cc b/sql/sql_insert.cc index fcf8c14..2bfb288 100644 --- a/sql/sql_insert.cc +++ b/sql/sql_insert.cc @@ -723,7 +722,24 @@ bool mysql_insert(THD *thd,TABLE_LIST *table_list, if (open_and_lock_tables(thd, table_list, TRUE, 0)) DBUG_RETURN(TRUE); } - + + context= &thd->lex->select_lex.context; + if(table_list->table!=NULL)
can table_list->table be NULL here?
+ { + Field ** f=table_list->table->field; + List<Item> * i_list = (List<Item> *)values_list.first_node()->info; + for(uint i=0;i
table->s->fields;i++) + { + if((*f)->is_hash ||(*f)->field_visibility==USER_DEFINED_HIDDEN) + { + i_list->push_front(new (thd->mem_root) + Item_default_value(thd,context),thd->mem_root); + } + f++; + } + } + List_iterator_fast its(values_list); +
is that needed at all? one can always do INSERT t1 (a) VALUES (1) and all non-specified fields will get default values. without specifically adding Item_default_value to the list. So, it seems, that hidden fields will automatically get default values too.
lock_type= table_list->lock_type;
THD_STAGE_INFO(thd, stage_init); diff --git a/sql/sql_show.cc b/sql/sql_show.cc index 1cbad7e..60e586c 100644 --- a/sql/sql_show.cc +++ b/sql/sql_show.cc @@ -1932,6 +1931,26 @@ int show_create_table(THD *thd, TABLE_LIST *table_list, String *packet, } append_create_options(thd, packet, field->option_list, check_options, hton->field_options); + //TODO need a better logic to find wheter to put comma or not + int i=1; + bool is_comma_needed=false; + if (*(ptr+i)!=NULL) + { + is_comma_needed=true; + while((*(ptr+i))->field_visibility==MEDIUM_HIDDEN || + (*(ptr+i))->field_visibility==FULL_HIDDEN) + { + i++; + is_comma_needed=true; + if(!*(ptr+i)) + { + is_comma_needed =false; + break; + } + } + } + if(is_comma_needed) + packet->append(STRING_WITH_LEN(",\n"));
agree about "better logic". You can do it like this: bool is_comma_needed= false; for (ptr=table->field ; (field= *ptr); ptr++) { if (is_comma_needed) packet->append(STRING_WITH_LEN(",\n")); is_comma_needed= false; ... print field is_comma_needed= true; }
}
key_info= table->key_info; @@ -1946,6 +1965,22 @@ int show_create_table(THD *thd, TABLE_LIST *table_list, String *packet, for (uint i=0 ; i < share->keys ; i++,key_info++) { KEY_PART_INFO *key_part= key_info->key_part; + if(key_info->flags&HA_UNIQUE_HASH||key_info->flags&HA_INDEX_HASH)
code formatting. spaces!
+ { + char * column_names= key_part->field->vcol_info-> + expr_str.str+strlen("hash"); + int length=key_part->field->vcol_info->expr_str.length; + length-=strlen("hash"); + packet->append(STRING_WITH_LEN(",\n")); + if(key_info->flags&HA_INDEX_HASH) + packet->append(STRING_WITH_LEN(" INDEX `")); + else + packet->append(STRING_WITH_LEN(" UNIQUE KEY `")); + packet->append(key_info->name,strlen(key_info->name)); + packet->append(STRING_WITH_LEN("`")); + packet->append(column_names,length);
I don't like that ±strlen("hash"). Better do it like this: static LEX_CSTRING uniq_hash_func={ STRING_WITH_LEN("hash" }; and instead of strlen("hash") you use uniq_hash_func.length, and below instead of explicit "hash" string in the mysql_prepare_create_table you use uniq_hash_func.str.
+ continue; + } bool found_primary=0; packet->append(STRING_WITH_LEN(",\n "));
@@ -5416,6 +5454,22 @@ static int get_schema_column_record(THD *thd, TABLE_LIST *tables, else table->field[17]->store(STRING_WITH_LEN("VIRTUAL"), cs); } + /*hidden can coexist with auto_increment and virtual */ + if(field->field_visibility==USER_DEFINED_HIDDEN) + { + table->field[17]->store(STRING_WITH_LEN("HIDDEN"), cs); + if (field->unireg_check == Field::NEXT_NUMBER) + table->field[17]->store(STRING_WITH_LEN("auto_increment , HIDDEN"), cs); + if (print_on_update_clause(field, &type, true)) + table->field[17]->store(type.ptr(), type.length(), cs); + if (field->vcol_info) + { + if (field->stored_in_db) + table->field[17]->store(STRING_WITH_LEN("PERSISTENT, HIDDEN"), cs); + else + table->field[17]->store(STRING_WITH_LEN("VIRTUAL, HIDDEN"), cs); + } + }
eh, please no. don't duplicate the whole block. A variant that avoids it: StringBuffer<256> buf; if (autoinc) // this is pseudocode, see the correct condition is in the code above buf.set(STRING_WITH_LEN("auto_increment")) else if (virtual) buf.set(STRING_WITH_LEN("VIRTUAL"); ... if (hidden) { if (buf.length) buf.append(STRING_WITH_LEN(", ")); buf.append(STRING_WITH_LEN("HIDDEN")); } table->field[17]->store(buf.ptr(), buf.length(), cs);
table->field[19]->store(field->comment.str, field->comment.length, cs); if (schema_table_store_record(thd, table)) DBUG_RETURN(1); diff --git a/sql/sql_table.cc b/sql/sql_table.cc index dae3b7a..d9322ca 100644 --- a/sql/sql_table.cc +++ b/sql/sql_table.cc @@ -3013,7 +3013,7 @@ int prepare_create_field(Create_field *sql_field, break; } if (!(sql_field->flags & NOT_NULL_FLAG) || - (sql_field->vcol_info)) /* Make virtual columns allow NULL values */ + (sql_field->vcol_info))
why did you remove this comment?
sql_field->pack_flag|= FIELDFLAG_MAYBE_NULL; if (sql_field->flags & NO_DEFAULT_VALUE_FLAG) sql_field->pack_flag|= FIELDFLAG_NO_DEFAULT; @@ -3223,6 +3222,130 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, bool tmp_table= create_table_mode == C_ALTER_TABLE; DBUG_ENTER("mysql_prepare_create_table");
+ /* + scan the the whole alter list + and add one field if length of blob is zero + TODO change to work for all too-long unique keys like varchar,text + */ + + List_iterator<Key> key_iter(alter_info->key_list); + Key *key_iter_key; + Key_part_spec *temp_colms; + int num= 1; + bool is_long_unique=false; + int key_initial_elements=alter_info->key_list.elements; + while((key_iter_key=key_iter++)&&key_initial_elements) + { + key_initial_elements--; + List_iterator
key_part_iter(key_iter_key->columns); + while((temp_colms=key_part_iter++)) + { + while ((sql_field=it++) &&sql_field&& my_strcasecmp(system_charset_info, + temp_colms->field_name.str, + sql_field->field_name)){} + if(sql_field && (sql_field->sql_type==MYSQL_TYPE_BLOB || + sql_field->sql_type==MYSQL_TYPE_MEDIUM_BLOB|| + sql_field->sql_type==MYSQL_TYPE_LONG_BLOB) + &&temp_colms->length==0) + { + is_long_unique=true; + /* + One long key unique in enough + */ + it.rewind(); + break; + } + // if(sql_field->sql_type==MYSQL_TYPE_VARCHAR) + it.rewind(); + } + if(is_long_unique) + { + /* make a virtual field */ + key_part_iter.rewind(); + Create_field *cf = new (thd->mem_root) Create_field(); + cf->flags|=UNSIGNED_FLAG; + cf->length=cf->char_length=8; + cf->charset=NULL; + cf->decimals=0; + char temp_name[30]; + strcpy(temp_name,"DB_ROW_HASH_"); + char num_holder[10]; //10 is way more but i think it is ok + sprintf(num_holder,"%d",num); + strcat(temp_name,num_holder); + /* + Check for collusions + */ + while((dup_field=it++)) + { + if(!my_strcasecmp(system_charset_info,temp_name,dup_field->field_name)) + { + temp_name[12]='\0'; //now temp_name='DB_ROW_HASH_' + num++; + sprintf(num_holder,"%d",num); + strcat(temp_name,num_holder); + it.rewind(); + } + } + it.rewind(); + char * name = (char *)thd->alloc(30); + strcpy(name,temp_name); + cf->field_name=name; + cf->stored_in_db=true; + cf->sql_type=MYSQL_TYPE_LONGLONG; + /* hash column should be atmost hidden */ + cf->field_visibility=FULL_HIDDEN; + if(key_iter_key->type==Key::UNIQUE) + key_iter_key->hash_type=UNIQUE_HASH; + else + key_iter_key->hash_type=INDEX_HASH; + cf->is_hash=true; + /* add the virtual colmn info */ + Virtual_column_info *v= new (thd->mem_root) Virtual_column_info(); + char * hash_exp=(char *)thd->alloc(252); + char * key_name=(char *)thd->alloc(252); + strcpy(hash_exp,"hash(`"); + temp_colms=key_part_iter++; + strcat(hash_exp,temp_colms->field_name.str); + strcpy(key_name,temp_colms->field_name.str); + strcat(hash_exp,"`"); + while((temp_colms=key_part_iter++)){ + strcat(hash_exp,(const char * )","); + strcat(key_name,"_"); + strcat(hash_exp,"`"); + strcat(hash_exp,temp_colms->field_name.str); + strcat(key_name,temp_colms->field_name.str); + strcat(hash_exp,"`"); + } + strcat(hash_exp,(const char * )")"); + v->expr_str.str= hash_exp; + v->expr_str.length= strlen(hash_exp); + v->expr_item= NULL; + v->set_stored_in_db_flag(true); + cf->vcol_info=v; + alter_info->create_list.push_front(cf,thd->mem_root); + /* + Now create the key field kind + of harder then prevoius one i guess + */ + key_iter_key->type=Key::MULTIPLE; + key_iter_key->columns.delete_elements(); + LEX_STRING *ls =(LEX_STRING *)thd->alloc(sizeof(LEX_STRING)) ; + ls->str=(char *)sql_field->field_name; + ls->length =strlen(sql_field->field_name); + if(key_iter_key->name.length==0) + { + LEX_STRING *ls_name =(LEX_STRING *)thd->alloc(sizeof(LEX_STRING)) ; + ls_name->str=key_name; + ls_name->length=strlen(key_name); + key_iter_key->name= *ls_name; + } + key_iter_key->columns.push_back(new (thd->mem_root) Key_part_spec(name, + strlen(name), 0),thd->mem_root); + + } + is_long_unique=false; + } + it.rewind();
why are you doing it here, in a separate loop, insead of doing it where ER_TOO_LONG_KEY is issued?
select_field_pos= alter_info->create_list.elements - select_field_count; null_fields=blob_columns=0; create_info->varchar= 0; @@ -3241,7 +3364,7 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, /* Set field charset. */ save_cs= sql_field->charset= get_sql_field_charset(sql_field, create_info); if ((sql_field->flags & BINCMP_FLAG) && - !(sql_field->charset= find_bin_collation(sql_field->charset))) + !(sql_field->charset= find_bin_collation(sql_field->charset)))
typo. please revert
DBUG_RETURN(TRUE);
/* @@ -3274,7 +3397,17 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, DBUG_RETURN(TRUE); } } - + if(sql_field->field_visibility==USER_DEFINED_HIDDEN) + { + if(sql_field->flags&NOT_NULL_FLAG) + { + if(sql_field->flags&NO_DEFAULT_VALUE_FLAG)
do it in one if(), not in three, please
+ { + my_error(ER_HIDDEN_NOT_NULL_WOUT_DEFAULT, MYF(0), sql_field->field_name); + DBUG_RETURN(TRUE); + } + } + } if (sql_field->sql_type == MYSQL_TYPE_SET || sql_field->sql_type == MYSQL_TYPE_ENUM) { @@ -3831,8 +3968,8 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, sql_field->charset->mbminlen > 1 || // ucs2 doesn't work yet (ft_key_charset && sql_field->charset != ft_key_charset)) { - my_error(ER_BAD_FT_COLUMN, MYF(0), column->field_name.str); - DBUG_RETURN(-1); + my_error(ER_BAD_FT_COLUMN, MYF(0), column->field_name.str); + DBUG_RETURN(-1); }
indentation is two spaces, not one
ft_key_charset=sql_field->charset; /* @@ -3874,10 +4011,9 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, if (f_is_geom(sql_field->pack_flag) && sql_field->geom_type == Field::GEOM_POINT) column->length= MAX_LEN_GEOM_POINT_FIELD; - if (!column->length) + if (!column->length)
again, as a couple of times above - tabs confuse you and you mess up the indentation :(
{ - my_error(ER_BLOB_KEY_WITHOUT_LENGTH, MYF(0), column->field_name.str); - DBUG_RETURN(TRUE); + DBUG_ASSERT(0); } } #ifdef HAVE_SPATIAL @@ -7420,7 +7557,10 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, while ((drop=drop_it++)) { if (drop->type == Alter_drop::COLUMN && - !my_strcasecmp(system_charset_info,field->field_name, drop->name)) + !my_strcasecmp(system_charset_info,field->field_name, drop->name)
again
+ /* we cant not drop system generated column */ + && !(field->field_visibility==MEDIUM_HIDDEN + ||field->field_visibility==FULL_HIDDEN)) { /* Reset auto_increment value if it was dropped */ if (MTYP_TYPENR(field->unireg_check) == Field::NEXT_NUMBER && @@ -7444,7 +7584,10 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, while ((def=def_it++)) { if (def->change && - !my_strcasecmp(system_charset_info,field->field_name, def->change)) + !my_strcasecmp(system_charset_info,field->field_name, def->change)
and again
+ /* we cant change system generated column */ + && !(field->field_visibility==MEDIUM_HIDDEN + ||field->field_visibility==FULL_HIDDEN)) break; } if (def) @@ -7512,6 +7655,51 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, table->s->table_name.str); goto err; } + /* Need to see whether new added column clashes with already existed + DB_ROW_HASH_*(is must have is_hash==tru) + */ + for (f_ptr=table->vfield ;f_ptr&&(field= *f_ptr) ; f_ptr++) + { + if ((field->is_hash)&&!my_strcasecmp(system_charset_info,field->field_name,def->field_name)) + { + /* got a clash find the highest number in db_row_hash_* */ + Field *temp_field; + int max=0; + for (Field ** f_temp_ptr=table->vfield ; (temp_field= *f_temp_ptr); f_temp_ptr++) + { + if(temp_field->is_hash) + { + int temp = atoi(temp_field->field_name+12); + if(temp>max) + max=temp; + } + } + max++; + + Create_field * old_hash_field; + while((old_hash_field=field_it++)) + { + if(!my_strcasecmp(system_charset_info,old_hash_field->field_name, + field->field_name)) + { + field_it.remove(); + break; + } + } + /* Give field new name which does not clash with def->feild_name */ + new_hash_field = old_hash_field->clone(thd->mem_root); + char *name = (char *)thd->alloc(30); + strcpy(name,"DB_ROW_HASH_"); + char num_holder[10]; + sprintf(num_holder,"%d",max); + strcat(name,num_holder); + new_hash_field->field_name=name; + new_hash_field->field=field; + new_hash_field->change=old_hash_field->field_name; + new_create_list.push_front(new_hash_field,thd->mem_root); + field_it.rewind(); + } + }
okay... I wonder, if it would be easier not to look for collisions in mysql_prepare_alter_table, but simply rename all is_hash columns in mysql_prepare_create_table(). then you'll only need to do it in one place.
/* Check that the DATE/DATETIME not null field we are going to add is either has a default value or the '0000-00-00' is allowed by the @@ -7609,6 +7799,25 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, } if (drop) { + /* If we drop index of blob unique then we need to drop the db_row_hash col */ + if(key_info->flags&HA_UNIQUE_HASH||key_info->flags&HA_INDEX_HASH) + { + char * name = (char *)key_info->key_part->field->field_name; + /*iterate over field_it and remove db_row_hash col */ + field_it.rewind(); + Create_field * temp_field; + while ((temp_field=field_it++)) + { + if(!my_strcasecmp(system_charset_info,temp_field->field_name,name)) + { + field_it.remove(); + //add flag if it not exists + alter_info->flags|=Alter_info::ALTER_DROP_COLUMN; + break; + } + } + field_it.rewind();
this should be a little bit more complicated. an index can cover many columns, so the index should be dropped when its last column is removed. I suppose you've already done that, I need to pull and check.
+ } if (table->s->tmp_table == NO_TMP_TABLE) { (void) delete_statistics_for_index(thd, table, key_info, FALSE); @@ -7766,6 +7979,48 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, my_error(ER_WRONG_NAME_FOR_INDEX, MYF(0), key->name.str); goto err; } + List_iterator
key_part_iter(key->columns); + Key_part_spec * temp_colms; + Create_field * sql_field; + field_it.rewind(); + while((temp_colms=key_part_iter++)) + { + while ((sql_field=field_it++)) + { + if(!my_strcasecmp(system_charset_info, + temp_colms->field_name.str, + sql_field->field_name)) + { + if(sql_field->field_visibility==MEDIUM_HIDDEN||sql_field->field_visibility==FULL_HIDDEN) + { + /* If we added one column (which clash with db_row_has )then this key + is different then added by user to make it sure we check for */ + if(new_hash_field) + { + if(sql_field!=new_hash_field) + { + my_error(ER_KEY_COLUMN_DOES_NOT_EXITS, MYF(0), sql_field->field_name); + goto err; + } + } + else /*this is for add index to db_row_hash which must show error */ + { + my_error(ER_KEY_COLUMN_DOES_NOT_EXITS, MYF(0), sql_field->field_name); + goto err; + }
I don't quite understand these your conditions, but the logic should be like this: MEDIUM_HIDDEN can be indexed, FULL_HIDDEN can never be.
+ } + /* Check whether we adding index for blob or other long length column then add column flag*/ + if((sql_field->sql_type==MYSQL_TYPE_BLOB || + sql_field->sql_type==MYSQL_TYPE_MEDIUM_BLOB|| + sql_field->sql_type==MYSQL_TYPE_LONG_BLOB|| + sql_field->sql_type==MYSQL_TYPE_LONG_BLOB) + &&(temp_colms->length==0)) + alter_info->flags|=Alter_info::ALTER_ADD_COLUMN;
really? why don't you simply set this flag when you actually create new Create_field and push it into the list?
+ } + } + } + field_it.rewind(); + } }
diff --git a/sql/sql_update.cc b/sql/sql_update.cc index 4221025..4955881 100644 --- a/sql/sql_update.cc +++ b/sql/sql_update.cc @@ -92,24 +92,24 @@ bool compare_record(const TABLE *table) } return FALSE; } - - /* + + /* The storage engine has read all columns, so it's safe to compare all bits including those not in the write_set. This is cheaper than the field-by-field comparison done above. - */ + */ if (table->s->can_cmp_whole_record) return cmp_record(table,record[1]); /* Compare null bits */ if (memcmp(table->null_flags, - table->null_flags+table->s->rec_buff_length, - table->s->null_bytes_for_compare)) + table->null_flags+table->s->rec_buff_length, + table->s->null_bytes_for_compare))
in this file you've done *only* whitespace changes, some of them are ok, but many result in broken indentation, please fix them all!
return TRUE; // Diff in NULL value /* Compare updated fields */ for (Field **ptr= table->field ; *ptr ; ptr++) { if (bitmap_is_set(table->write_set, (*ptr)->field_index) && - (*ptr)->cmp_binary_offset(table->s->rec_buff_length)) + (*ptr)->cmp_binary_offset(table->s->rec_buff_length)) return TRUE; } return FALSE; diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index e614692..4872d20 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -1271,6 +1271,7 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); %token HEX_NUM %token HEX_STRING %token HIGH_PRIORITY +%token HIDDEN
HIDDEN_SYM, please
%token HOST_SYM %token HOSTS_SYM %token HOUR_MICROSECOND_SYM @@ -6047,6 +6048,11 @@ vcol_attribute: lex->alter_info.flags|= Alter_info::ALTER_ADD_INDEX; } | COMMENT_SYM TEXT_STRING_sys { Lex->last_field->comment= $2; } + | HIDDEN + { + LEX *lex =Lex;
no need to do that ^^^ you can simply write Lex->last_field->field_visibility=...
+ lex->last_field->field_visibility=USER_DEFINED_HIDDEN; + } ;
parse_vcol_expr: @@ -6469,6 +6475,11 @@ attribute: new (thd->mem_root) engine_option_value($1, &Lex->last_field->option_list, &Lex->option_list_last); } + | HIDDEN + { + LEX *lex =Lex; + lex->last_field->field_visibility=USER_DEFINED_HIDDEN; + }
no need to repeat this twice. Try to remove HIDDEN, COMMENT_SYM, UNIQUE, and UNIQUE KEY rules from attribute and add the vcol_attribute instead.
;
diff --git a/sql/table.h b/sql/table.h index eb4076e..982de6f 100644 --- a/sql/table.h +++ b/sql/table.h @@ -321,6 +321,24 @@ enum enum_vcol_update_mode VCOL_UPDATE_ALL };
+/* Field visibility enums */ + +enum field_visible_type{ + NORMAL=0,
better NOT_HIDDEN
+ USER_DEFINED_HIDDEN, + MEDIUM_HIDDEN, + FULL_HIDDEN +}; + +enum key_hash_type{ + /* normal column */ + NOT_HASH=0, + /* hash for defination index(A,...) in this case no duplicate will be checked */ + INDEX_HASH,
there's no point in having a hash index for blobs, if it doesn't check for duplicates
+ /* hash for defination unique(A,...) in this duplicate will be checked in ha_write_row and + update */ + UNIQUE_HASH +}; class Filesort_info { /// Buffer for sorting keys. diff --git a/sql/table.cc b/sql/table.cc index a90eb2e..31d8f1e 100644 --- a/sql/table.cc +++ b/sql/table.cc @@ -785,7 +785,8 @@ static bool create_key_infos(const uchar *strpos, const uchar *frm_image_end, keyinfo->ext_key_parts= keyinfo->user_defined_key_parts; keyinfo->ext_key_flags= keyinfo->flags; keyinfo->ext_key_part_map= 0; - if (share->use_ext_keys && i && !(keyinfo->flags & HA_NOSAME)) + if (share->use_ext_keys && i && !(keyinfo->flags & HA_NOSAME) + )
revert
{ for (j= 0; j < first_key_parts && keyinfo->ext_key_parts < MAX_REF_PARTS; @@ -985,7 +990,7 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, if (length < 256) goto err; } - if (extra2 + length > e2end) + if ( extra2 + length > e2end)
revert
goto err; switch (type) { case EXTRA2_TABLEDEF_VERSION: @@ -1040,7 +1048,6 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, if (extra2 != e2end) goto err; } -
nope, revert
if (frm_length < FRM_HEADER_SIZE + len || !(pos= uint4korr(frm_image + FRM_HEADER_SIZE + len))) goto err; @@ -1671,7 +1678,8 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, if (!reg_field) // Not supported field type goto err;
- + reg_field->field_visibility=(field_visible_type)*field_properties++;
please, add a feature status variable for it. search, for example, for
"feature_fulltext" or "feature_gis". Just as feature_gis, you can
increment your feature_hidden_column when a table with user-created hidden
columns is opened.
better use c++ casts here, like
static_cast
+ reg_field->is_hash=(bool)*field_properties++;
you don't need a cast at all, but if you want to keep it, use C++ cast
reg_field->field_index= i; reg_field->comment=comment; reg_field->vcol_info= vcol_info; @@ -1985,6 +1993,10 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, if ((keyinfo->flags & HA_NOSAME) || (ha_option & HA_ANY_INDEX_MAY_BE_UNIQUE)) set_if_bigger(share->max_unique_length,keyinfo->key_length); + if(keyinfo->flags&HA_UNIQUE_HASH||keyinfo->flags&HA_INDEX_HASH) + { + keyinfo->ext_key_parts=1;
why?
+ } } if (primary_key < MAX_KEY && (share->keys_in_use.is_set(primary_key))) diff --git a/sql/unireg.h b/sql/unireg.h index 10751b6..211749a 100644 --- a/sql/unireg.h +++ b/sql/unireg.h @@ -186,7 +186,8 @@ enum extra2_frm_value_type { EXTRA2_TABLEDEF_VERSION=0, EXTRA2_DEFAULT_PART_ENGINE=1, EXTRA2_GIS=2, - + EXTRA2_FIELD_FLAGS=3, + EXTRA2_KEY_HASH_FLAG=4,
make it 129 and 130
#define EXTRA2_ENGINE_IMPORTANT 128
EXTRA2_ENGINE_TABLEOPTS=128, diff --git a/sql/unireg.cc b/sql/unireg.cc index 66959f4..0d764a1 100644 --- a/sql/unireg.cc +++ b/sql/unireg.cc @@ -204,7 +224,8 @@ LEX_CUSTRING build_frm_image(THD *thd, const char *table, if (gis_extra2_len) extra2_size+= 1 + (gis_extra2_len > 255 ? 3 : 1) + gis_extra2_len;
- + extra2_size+=1 + ( 2*create_fields.elements > 255 ? 3 : 1) + + 2*create_fields.elements;// first one for type(extra2_field_flags) next 2 for length
for backward compatibility it would make sense to add this EXTRA2_FIELD_FLAGS data *only* if you have hidden fields.
key_buff_length= uint4korr(fileinfo+47);
frm.length= FRM_HEADER_SIZE; // fileinfo; diff --git a/storage/maria/maria_def.h b/storage/maria/maria_def.h index 7337b01..3d0860f 100644 --- a/storage/maria/maria_def.h +++ b/storage/maria/maria_def.h @@ -895,7 +895,7 @@ struct st_maria_handler
/* The UNIQUE check is done with a hashed long key */
-#define MARIA_UNIQUE_HASH_TYPE HA_KEYTYPE_ULONG_INT +#define MARIA_UNIQUE_hash_type HA_KEYTYPE_ULONG_INT
why?
#define maria_unique_store(A,B) mi_int4store((A),(B))
extern mysql_mutex_t THR_LOCK_maria;
Regards, Sergei Chief Architect MariaDB and security@mariadb.org
Hello everyone, Weekly Report for 7th week of gsoc 1Now we can alter blob columns query like create table t1(abc blob unique); alter table t1 change column abc a blob; Even we can some multiple changes in one alter create table t1(abc blob unique, xyz blob unique); alter table t1 change column abc a blob , change xyz x blob; Works. 2.Now we can delete blob columns if only one blob unique in key then db_row_hash_ will be removed other wise hash_str will be modified.If the query fails then there will be no side effect 3.chaning of delete operations create table t1(abc blob , xyz blob , pqr blob, unique(abc,xyz,pqr)); alter table t1 drop column abc, drop column xyz; 4. we will get right error message instead of duplicate hash 5. these was an glich in code when we try to add db_row_hash_ column to table with first key work mysql_prepare_alter_table select this instead of real hash now solved. 6. Added some test case.Will add more soon. @Sergei will reply to you soon. Regards sachin
Hello Sergei
Actually i have one doubt there is two options
1 add is_hash flag to field
2 add ha_unique_hash flag to field ,but i think all 16 bits of key flag is used
so to do this i need to add another ex_flag variable in key struct and
store it and retrieve it from frm
currently i have done both ,but as you pointed out in review that it
is better to have it in key only but
my question is that , whether is this approach is right ?
Regards
sachin
On Tue, Jul 12, 2016 at 2:43 PM, Sachin Setia
Hello everyone,
Weekly Report for 7th week of gsoc
1Now we can alter blob columns query like create table t1(abc blob unique); alter table t1 change column abc a blob; Even we can some multiple changes in one alter create table t1(abc blob unique, xyz blob unique); alter table t1 change column abc a blob , change xyz x blob; Works.
2.Now we can delete blob columns if only one blob unique in key then db_row_hash_ will be removed other wise hash_str will be modified.If the query fails then there will be no side effect
3.chaning of delete operations create table t1(abc blob , xyz blob , pqr blob, unique(abc,xyz,pqr)); alter table t1 drop column abc, drop column xyz; 4. we will get right error message instead of duplicate hash 5. these was an glich in code when we try to add db_row_hash_ column to table with first key work mysql_prepare_alter_table select this instead of real hash now solved. 6. Added some test case.Will add more soon. @Sergei will reply to you soon. Regards sachin
Hi, Sachin! On Jul 14, Sachin Setia wrote:
Hello Sergei Actually i have one doubt there is two options 1 add is_hash flag to field 2 add ha_unique_hash flag to field ,but i think all 16 bits of key flag is used so to do this i need to add another ex_flag variable in key struct and store it and retrieve it from frm currently i have done both ,but as you pointed out in review that it is better to have it in key only but my question is that, whether is this approach is right ?
From the storage point of view, it's much easier to put a special flag on the field. You can store it in EXTRA2 or you can store it in the Field::unireg_check enum.
And then you recognize your HA_UNIQUE_HASH keys by having is_hash property on the field of the first keypart. You can even set the HA_UNIQUE_HASH flag in the key, if HA_UNIQUE_HASH=65536, for example. That is, it won't be stored in the frm, and you set the flag in init_from_binary_frm_image - the flag can be used to simplify run-time checks, but it won't be stored on disk. Regards, Sergei Chief Architect MariaDB and security@mariadb.org
okay sir, i will just store the is_hash flag and on init_from_binary_frm_image
add flag to key. thanks
Regards
sachin
On Fri, Jul 15, 2016 at 3:58 PM, Sergei Golubchik
Hi, Sachin!
On Jul 14, Sachin Setia wrote:
Hello Sergei Actually i have one doubt there is two options 1 add is_hash flag to field 2 add ha_unique_hash flag to field ,but i think all 16 bits of key flag is used so to do this i need to add another ex_flag variable in key struct and store it and retrieve it from frm currently i have done both ,but as you pointed out in review that it is better to have it in key only but my question is that, whether is this approach is right ?
From the storage point of view, it's much easier to put a special flag on the field. You can store it in EXTRA2 or you can store it in the Field::unireg_check enum.
And then you recognize your HA_UNIQUE_HASH keys by having is_hash property on the field of the first keypart. You can even set the HA_UNIQUE_HASH flag in the key, if HA_UNIQUE_HASH=65536, for example. That is, it won't be stored in the frm, and you set the flag in init_from_binary_frm_image - the flag can be used to simplify run-time checks, but it won't be stored on disk.
Regards, Sergei Chief Architect MariaDB and security@mariadb.org
Weekly Report for 8 week of gsoc
1 Changed the key flags as suggested by you.
2 Now update will use only one buffer as suggested by you but there was one
problem some time offset can be
negative so i changed the field cmp_offset parameter from uint to long
3 Still working on coding conventions.
4 I have made prototype for optimizing where for keys like unique(a) , it
is on branch
https://github.com/SachinSetiya/server/tree/unique_index_where
Currently I am working on muliple keys like unique(a,b,c) i think this
should take 2-3 days and edits suggested by you.
Regards
sachin
On Fri, Jul 15, 2016 at 5:29 PM, Sachin Setia
okay sir, i will just store the is_hash flag and on init_from_binary_frm_image add flag to key. thanks Regards sachin
On Fri, Jul 15, 2016 at 3:58 PM, Sergei Golubchik
wrote: Hi, Sachin!
On Jul 14, Sachin Setia wrote:
Hello Sergei Actually i have one doubt there is two options 1 add is_hash flag to field 2 add ha_unique_hash flag to field ,but i think all 16 bits of key flag is used so to do this i need to add another ex_flag variable in key struct and store it and retrieve it from frm currently i have done both ,but as you pointed out in review that it is better to have it in key only but my question is that, whether is this approach is right ?
From the storage point of view, it's much easier to put a special flag on the field. You can store it in EXTRA2 or you can store it in the Field::unireg_check enum.
And then you recognize your HA_UNIQUE_HASH keys by having is_hash property on the field of the first keypart. You can even set the HA_UNIQUE_HASH flag in the key, if HA_UNIQUE_HASH=65536, for example. That is, it won't be stored in the frm, and you set the flag in init_from_binary_frm_image - the flag can be used to simplify run-time checks, but it won't be stored on disk.
Regards, Sergei Chief Architect MariaDB and security@mariadb.org
Hi, Sachin! On Jul 19, Sachin Setia wrote:
Weekly Report for 8 week of gsoc
1 Changed the key flags as suggested by you.
okay
2 Now update will use only one buffer as suggested by you but there was one problem some time offset can be negative so i changed the field cmp_offset parameter from uint to long
sure
3 Still working on coding conventions.
4 I have made prototype for optimizing where for keys like unique(a) , it is on branch https://github.com/SachinSetiya/server/tree/unique_index_where
Currently I am working on muliple keys like unique(a,b,c) i think this should take 2-3 days and edits suggested by you.
sounds good. did you merge with 10.2.1? tell me when you'd want me to do another review. Regards, Sergei Chief Architect MariaDB and security@mariadb.org
Just give me 3 days after you can review. yes I already merged with 10.2.1
days ago.
regards
Sachin
On Jul 19, 2016 17:28, "Sergei Golubchik"
Hi, Sachin!
On Jul 19, Sachin Setia wrote:
Weekly Report for 8 week of gsoc
1 Changed the key flags as suggested by you.
okay
2 Now update will use only one buffer as suggested by you but there was one problem some time offset can be negative so i changed the field cmp_offset parameter from uint to long
sure
3 Still working on coding conventions.
4 I have made prototype for optimizing where for keys like unique(a) , it is on branch https://github.com/SachinSetiya/server/tree/unique_index_where
Currently I am working on muliple keys like unique(a,b,c) i think this should take 2-3 days and edits suggested by you.
sounds good. did you merge with 10.2.1?
tell me when you'd want me to do another review.
Regards, Sergei Chief Architect MariaDB and security@mariadb.org
Hello Sergei,
I have one problem my where optimization works for query like
select * from t1 where abc=1;
but in query like
select * from t1 where abc=(select xyz from t2 where xyz=1);
does not work because in these query the charset is different from what
used in
t1 for inserting data and hence generation different hash for same data
how i solve this problem.
Regards
sachin
On Tue, Jul 19, 2016 at 5:52 PM, Sachin Setia
Just give me 3 days after you can review. yes I already merged with 10.2.1 days ago. regards Sachin
On Jul 19, 2016 17:28, "Sergei Golubchik"
wrote: Hi, Sachin!
On Jul 19, Sachin Setia wrote:
Weekly Report for 8 week of gsoc
1 Changed the key flags as suggested by you.
okay
2 Now update will use only one buffer as suggested by you but there was one problem some time offset can be negative so i changed the field cmp_offset parameter from uint to long
sure
3 Still working on coding conventions.
4 I have made prototype for optimizing where for keys like unique(a) , it is on branch https://github.com/SachinSetiya/server/tree/unique_index_where
Currently I am working on muliple keys like unique(a,b,c) i think this should take 2-3 days and edits suggested by you.
sounds good. did you merge with 10.2.1?
tell me when you'd want me to do another review.
Regards, Sergei Chief Architect MariaDB and security@mariadb.org
Hello Sergei,
I am getting one problem related to my_strcasecmp() function currently this
function does not allow
string comparison upto length l, is there any functon which can do
comparison upto length l, or should i
write mine.
Regards
sachin
On Fri, Jul 22, 2016 at 9:56 PM, Sachin Setia
Hello Sergei, I have one problem my where optimization works for query like select * from t1 where abc=1;
but in query like select * from t1 where abc=(select xyz from t2 where xyz=1); does not work because in these query the charset is different from what used in t1 for inserting data and hence generation different hash for same data how i solve this problem. Regards sachin
On Tue, Jul 19, 2016 at 5:52 PM, Sachin Setia
wrote: Just give me 3 days after you can review. yes I already merged with 10.2.1 days ago. regards Sachin
On Jul 19, 2016 17:28, "Sergei Golubchik"
wrote: Hi, Sachin!
On Jul 19, Sachin Setia wrote:
Weekly Report for 8 week of gsoc
1 Changed the key flags as suggested by you.
okay
2 Now update will use only one buffer as suggested by you but there was one problem some time offset can be negative so i changed the field cmp_offset parameter from uint to long
sure
3 Still working on coding conventions.
4 I have made prototype for optimizing where for keys like unique(a) , it is on branch https://github.com/SachinSetiya/server/tree/unique_index_where
Currently I am working on muliple keys like unique(a,b,c) i think this should take 2-3 days and edits suggested by you.
sounds good. did you merge with 10.2.1?
tell me when you'd want me to do another review.
Regards, Sergei Chief Architect MariaDB and security@mariadb.org
Actually i find that my_strnncoll wil work :)
Regards
sachin
On Mon, Jul 25, 2016 at 1:17 AM, Sachin Setia
Hello Sergei, I am getting one problem related to my_strcasecmp() function currently this function does not allow string comparison upto length l, is there any functon which can do comparison upto length l, or should i write mine. Regards sachin
On Fri, Jul 22, 2016 at 9:56 PM, Sachin Setia
wrote: Hello Sergei, I have one problem my where optimization works for query like select * from t1 where abc=1;
but in query like select * from t1 where abc=(select xyz from t2 where xyz=1); does not work because in these query the charset is different from what used in t1 for inserting data and hence generation different hash for same data how i solve this problem. Regards sachin
On Tue, Jul 19, 2016 at 5:52 PM, Sachin Setia
wrote: Just give me 3 days after you can review. yes I already merged with 10.2.1 days ago. regards Sachin
On Jul 19, 2016 17:28, "Sergei Golubchik"
wrote: Hi, Sachin!
On Jul 19, Sachin Setia wrote:
Weekly Report for 8 week of gsoc
1 Changed the key flags as suggested by you.
okay
2 Now update will use only one buffer as suggested by you but there was one problem some time offset can be negative so i changed the field cmp_offset parameter from uint to long
sure
3 Still working on coding conventions.
4 I have made prototype for optimizing where for keys like unique(a) , it is on branch https://github.com/SachinSetiya/server/tree/unique_index_where
Currently I am working on muliple keys like unique(a,b,c) i think this should take 2-3 days and edits suggested by you.
sounds good. did you merge with 10.2.1?
tell me when you'd want me to do another review.
Regards, Sergei Chief Architect MariaDB and security@mariadb.org
Hello Sergei!
Weekly Report for 9 week of gsoc
Unique Long
1. Changed mysql_prepare_create function as suggested by you , now addition
of hash column will not be added in function start.
2. Sorted out problem of full_hidden detection now it is detected as soon
as it is found.
Where Optimization
1. In case of unique(a) if hash collides then it fetches the next record
and compares it and so on.
2. Now unique(a,b,c ..) also works and also in case of hash collusion it
fetches the next record and compares it and so on.
Please review branch
https://github.com/SachinSetiya/server/tree/unique_index_where
The only problem i have is explain query fails , trying to solve it let you
know if something happens.
Regards
sachin
On Mon, Jul 25, 2016 at 1:34 AM, Sachin Setia
Actually i find that my_strnncoll wil work :) Regards sachin
On Mon, Jul 25, 2016 at 1:17 AM, Sachin Setia
wrote: Hello Sergei, I am getting one problem related to my_strcasecmp() function currently this function does not allow string comparison upto length l, is there any functon which can do comparison upto length l, or should i write mine. Regards sachin
On Fri, Jul 22, 2016 at 9:56 PM, Sachin Setia
wrote: Hello Sergei, I have one problem my where optimization works for query like select * from t1 where abc=1;
but in query like select * from t1 where abc=(select xyz from t2 where xyz=1); does not work because in these query the charset is different from what used in t1 for inserting data and hence generation different hash for same data how i solve this problem. Regards sachin
On Tue, Jul 19, 2016 at 5:52 PM, Sachin Setia
wrote:
Just give me 3 days after you can review. yes I already merged with 10.2.1 days ago. regards Sachin
On Jul 19, 2016 17:28, "Sergei Golubchik"
wrote: Hi, Sachin!
On Jul 19, Sachin Setia wrote:
Weekly Report for 8 week of gsoc
1 Changed the key flags as suggested by you.
okay
2 Now update will use only one buffer as suggested by you but there was one problem some time offset can be negative so i changed the field cmp_offset parameter from uint to long
sure
3 Still working on coding conventions.
4 I have made prototype for optimizing where for keys like unique(a) , it is on branch https://github.com/SachinSetiya/server/tree/unique_index_where
Currently I am working on muliple keys like unique(a,b,c) i think this should take 2-3 days and edits suggested by you.
sounds good. did you merge with 10.2.1?
tell me when you'd want me to do another review.
Regards, Sergei Chief Architect MariaDB and security@mariadb.org
Hi, Sachin! On Jul 27, Sachin Setia wrote:
Hello Sergei! Weekly Report for 9 week of gsoc
Unique Long
1. Changed mysql_prepare_create function as suggested by you , now addition of hash column will not be added in function start. 2. Sorted out problem of full_hidden detection now it is detected as soon as it is found.
I hope you've added a test for it, this issue is not trivial
Where Optimization 1. In case of unique(a) if hash collides then it fetches the next record and compares it and so on.
good! with a test case? :)
2. Now unique(a,b,c ..) also works and also in case of hash collision it fetches the next record and compares it and so on.
Please review branch https://github.com/SachinSetiya/server/tree/unique_index_where
Sure. Will do.
The only problem i have is explain query fails , trying to solve it let you know if something happens.
Regards, Sergei Chief Architect MariaDB and security@mariadb.org
Hello sergei Please review the code Work left 1 Where works on complex query including join , in , subquery but fails in this query do not know why CREATE table t1 (a blob unique not null , b blob unique not null ); select * from t1 where a=b; 2 Although alter works but thinking of changing the code so that it will become less complex. 3 delete , update using where is optimized in complex case involving joins subquery but normal case wont work because they use function like sql_quick _select which i do not optimized 4 need to write test cases for update. 5 tried to make prototype for update problem In this prototype what happenes is that when there is some dupp key tey then it caches the record in stack , and does this until some record insert is succeded then it checks succeded record's old data to key stack last element if it matches then we pop the stack and do update. update fails when there is some element left in stack prototype is on https://github.com/SachinSetiya/server/tree/up_proto_2 it works on table like create table t1 (a int unique , b int ); insert into t1 values(1,1),(2,2),(3,3),(4,4); update table t1 set a= a+1; currently this works only for sorted key but can be worked for unsorted key be sorting the records in stack with respect to key to extend this to multiple keys we can use 1 key stack for each key On 07/11/2016 11:41 PM, Sergei Golubchik wrote: > Hi, Sachin! > > Here's a review of your commits from > b69e141a32 to 674eb4c4277. > > Last time I've reviewed up to b69e141a32, > so next time I'll review from 674eb4c4277 and up. > > Thanks for your work! > >> diff --git a/mysql-test/r/long_unique.result b/mysql-test/r/long_unique.result >> new file mode 100644 >> index 0000000..fc6ff12 >> --- /dev/null >> +++ b/mysql-test/r/long_unique.result >> @@ -0,0 +1,160 @@ >> +create table z_1(abc blob unique); >> +insert into z_1 values(112); >> +insert into z_1 values('5666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666'); >> +insert into z_1 values('sachin'); >> +insert into z_1 values('sachin'); >> +ERROR 23000: Can't write; duplicate key in table 'z_1' >> +select * from z_1; >> +abc >> +112 >> +5666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666 >> +sachin >> +select db_row_hash_1 from z_1; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' >> +desc z_1; >> +Field Type Null Key Default Extra >> +abc blob YES NULL >> +select * from information_schema.columns where table_schema='mtr' and table_name='z_1'; >> +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION COLUMN_DEFAULT IS_NULLABLE DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME COLUMN_TYPE COLUMN_KEY EXTRA PRIVILEGES COLUMN_COMMENT >> +create table tst_1(xyz blob unique , x2 blob unique); >> +insert into tst_1 values(1,22); >> +insert into tst_1 values(2,22); >> +ERROR 23000: Can't write; duplicate key in table 'tst_1' >> +select * from tst_1; >> +xyz x2 >> +1 22 >> +select db_row_hash_1 from tst_1; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' >> +select db_row_hash_2 from tst_1; >> +ERROR 42S22: Unknown column 'db_row_hash_2' in 'field list' >> +select db_row_hash_1,db_row_hash_2 from tst_1; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' >> +desc tst_1; >> +Field Type Null Key Default Extra >> +xyz blob YES NULL >> +x2 blob YES NULL >> +select * from information_schema.columns where table_schema='mtr' and table_name='tst_1'; >> +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION COLUMN_DEFAULT IS_NULLABLE DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME COLUMN_TYPE COLUMN_KEY EXTRA PRIVILEGES COLUMN_COMMENT >> +create table t1 (empnum smallint, grp int); >> +create table t2 (empnum int, name char(5)); >> +insert into t1 values(1,1); >> +insert into t2 values(1,'bob'); >> +create view v1 as select * from t2 inner join t1 using (empnum); >> +select * from v1; >> +empnum name grp >> +1 bob 1 > what is this test for? (with t1, t2, v1) Removed this is one of the test in inoodb which was failing so i added this but now it is removed. > >> +create table c_1(abc blob unique, db_row_hash_1 int unique); >> +desc c_1; >> +Field Type Null Key Default Extra >> +abc blob YES NULL >> +db_row_hash_1 int(11) YES UNI NULL >> +insert into c_1 values(1,1); >> +insert into c_1 values(1,2); >> +ERROR 23000: Can't write; duplicate key in table 'c_1' >> +create table c_2(abc blob unique,xyz blob unique, db_row_hash_2 >> +int,db_row_hash_1 int unique); >> +desc c_2; >> +Field Type Null Key Default Extra >> +abc blob YES NULL >> +xyz blob YES NULL >> +db_row_hash_2 int(11) YES NULL >> +db_row_hash_1 int(11) YES UNI NULL >> +insert into c_2 values(1,1,1,1); >> +insert into c_2 values(1,23,4,5); >> +ERROR 23000: Can't write; duplicate key in table 'c_2' >> +create table u_1(abc int primary key , xyz blob unique); >> +insert into u_1 values(1,2); >> +insert into u_1 values(2,3); >> +update u_1 set xyz=2 where abc=1; >> +alter table z_1 drop db_row_hash_1; >> +ERROR 42000: Can't DROP 'db_row_hash_1'; check that column/key exists >> +alter table c_1 drop db_row_hash_2; >> +ERROR 42000: Can't DROP 'db_row_hash_2'; check that column/key exists >> +alter table c_1 drop db_row_hash_1; >> +alter table z_1 add column db_row_hash_1 int unique; >> +show create table z_1; >> +Table Create Table >> +z_1 CREATE TABLE `z_1` ( >> + `abc` blob, >> + `db_row_hash_1` int(11) DEFAULT NULL, >> + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), >> + UNIQUE KEY `abc`(`abc`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +insert into z_1 values('sachin',1); >> +ERROR 23000: Can't write; duplicate key in table 'z_1' >> +alter table c_1 add column db_row_hash_2 int; >> +show create table c_1; >> +Table Create Table >> +c_1 CREATE TABLE `c_1` ( >> + `abc` blob, >> + `db_row_hash_2` int(11) DEFAULT NULL, >> + UNIQUE KEY `abc`(`abc`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +alter table z_1 change db_row_hash_2 temp int; >> +ERROR 42S22: Unknown column 'db_row_hash_2' in 'z_1' >> +alter table c_1 change db_row_hash_3 temp int; >> +ERROR 42S22: Unknown column 'db_row_hash_3' in 'c_1' >> +alter table c_1 change db_row_hash_4 temp int; >> +ERROR 42S22: Unknown column 'db_row_hash_4' in 'c_1' >> +alter table c_2 change db_row_hash_1 temp int; >> +create table c_3(abc blob unique, xyz blob); >> +alter table c_3 add index(db_row_hash_1); >> +ERROR 42000: Key column 'DB_ROW_HASH_1' doesn't exist in table >> +create table i_1(x1 int ); >> +alter table i_1 add column x2 blob unique; >> +insert into i_1 value(1,1); >> +insert into i_1 value(2,1); >> +ERROR 23000: Can't write; duplicate key in table 'i_1' >> +alter table i_1 drop index x2; >> +insert into i_1 value(2,1); >> +create table i_2(abc blob); >> +insert into i_2 values(1); >> +alter table i_2 add unique index(abc); >> +select * from i_2; >> +abc >> +1 >> +insert into i_2 values(22); >> +insert into i_2 values(22); >> +ERROR 23000: Can't write; duplicate key in table 'i_2' >> +alter table i_2 drop key abc; >> +insert into i_2 values(22); >> +drop table i_2; >> +create table i_2(abc blob); >> +insert into i_2 values(1); >> +alter table i_2 add constraint unique(abc); >> +select * from i_2; >> +abc >> +1 >> +insert into i_2 values(22); >> +insert into i_2 values(22); >> +ERROR 23000: Can't write; duplicate key in table 'i_2' >> +alter table i_2 drop key abc; >> +insert into i_2 values(22); >> +create table di_1(abc blob , xyz int , index(abc,xyz)); > what is this test for? Early it will create a long unique index but now it will truncate > >> +show create table di_1; >> +Table Create Table >> +di_1 CREATE TABLE `di_1` ( >> + `abc` blob, >> + `xyz` int(11) DEFAULT NULL, >> + INDEX `abc_xyz`(`abc`,`xyz`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +insert into di_1 values(1,1); >> +insert into di_1 values(1,1); >> +insert into di_1 values(2,1); >> +create table di_2 (abc blob); >> +insert into di_2 values(1); >> +insert into di_2 values(1); >> +alter table di_2 add index(abc); >> +show create table di_2; >> +Table Create Table >> +di_2 CREATE TABLE `di_2` ( >> + `abc` blob, >> + INDEX `abc`(`abc`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +insert into di_2 values(1); >> +alter table di_2 drop index abc; >> +show create table di_2; >> +Table Create Table >> +di_2 CREATE TABLE `di_2` ( >> + `abc` blob >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 > please add tests for the following: > > 1. blob with a couple of really long lines. like > > into t1 values(repeat('x', 500*1024*1024)); > into t1 values(repeat('y', 500*1024*1024)); > into t1 values(repeat('x', 500*1024*1024)); > > just don't do select * after that :) > > 2. TEXT, where collation matters and equal strings aren't always > bytewise identical: > > create t1 (a TEXT CHARSET latin1 COLLATE latin1_german2_ci); > > insert t1 values ('ae'); > insert t1 values ('AE'); > insert t1 values ('Ä'); > > last two inserts must be an error (I suspect. If not sure, you can always > test it as, for example, SELECT 'ae' = 'AE' COLLATE latin1_german2_ci; > > 3. multi-column constraints, like > > create t1 (a blob, b int, unique (a,b)); > create t2 (a blob, b blob, unique (a,b)); > create t3 (a varchar(2048), b varchar(2048), unique(a,b)); > > and also test inserts and errors with this multi-column constraints, > not only create table statement. Done >> diff --git a/mysql-test/t/hidden_columns.test b/mysql-test/t/hidden_columns.test >> new file mode 100644 >> index 0000000..f0fed41 >> --- /dev/null >> +++ b/mysql-test/t/hidden_columns.test > where's the hidden_columns.result? sorry added >> diff --git a/mysql-test/t/hidden_field.test b/mysql-test/t/hidden_field.test >> new file mode 100644 >> index 0000000..3806a92 >> --- /dev/null >> +++ b/mysql-test/t/hidden_field.test > where's the hidden_field.result? > how is it different from hidden_columns.test, why not to put all tests > there? > > I mean the difference between "hidden column" and "hidden field" > is really subtle. Either rename one of the test files or, > combine them, or, I think, the best way would be to move tests from > hidden_columns.test to long_unique.test done and now there is only one file hidden_field > >> @@ -0,0 +1,35 @@ >> +create table h_1(abc int primary key, xyz int hidden); >> +create table h_2(a1 int hidden); > This, probably, should not be allowed. I mean, what 'SELECT * FROM h_2' > will do? > Let's return an error ER_TABLE_MUST_HAVE_COLUMNS in this case. Done > >> +--error 1064 > try to use error names, not error numbers (see them in include/mysqld_error.h) okay > >> +create table h_3(a1 blob,hidden(a1)); >> +--error 1981 >> +create table h_4(a1 int primary key hidden ,a2 int unique hidden , a3 blob,a4 >> +int not null hidden unique); >> +--error 1981 >> +create table h_5(abc int not null hidden); >> +# >> +create table t1(abc int hidden); >> +#should automatically add null >> +insert into t1 values(); >> +insert into t1 values(); >> +insert into t1 values(); >> +insert into t1 values(); >> +--error 1096 >> +select * from t1; > see, the error doesn't really fit here. 1096 is ER_NO_TABLES_USED, > but the table is used here. Let's just disallow tables with no > visible columns. > >> +select abc from t1; >> + >> +create table t2(abc int primary key); >> +insert into t2 values(); >> +select * from t2; >> +--error 1064 >> +create table sdsdsd(a int , b int, hidden(a,b)); >> + >> +create table hid_4(a int,abc int as (a mod 3) virtual hidden); >> +desc hid_4; >> +create table ht_5(abc int primary key hidden auto_increment, a int); >> +desc ht_5; >> +insert into ht_5 values(1); >> +insert into ht_5 values(2); >> +insert into ht_5 values(3); >> +select * from ht_5; >> +select abc,a from ht_5; > if you'd have hidden_field.result you'd notice that this test > doesn't clean up after itself :) > >> diff --git a/mysql-test/t/long_unique.test b/mysql-test/t/long_unique.test >> new file mode 100644 >> index 0000000..fc8bcf5 >> --- /dev/null >> +++ b/mysql-test/t/long_unique.test >> @@ -0,0 +1,114 @@ >> +create table z_1(abc blob unique); >> +insert into z_1 values(112); >> +insert into z_1 values('5666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666666'); > better use repeat() function in these cases. makes test cases smaller > and more readable. okay > >> +insert into z_1 values('sachin'); >> +--error 1022 >> +insert into z_1 values('sachin'); >> +select * from z_1; >> +--error 1054 >> +select db_row_hash_1 from z_1; >> +desc z_1; >> +select * from information_schema.columns where table_schema='mtr' and table_name='z_1'; > did you read results of your tests? wasn't it suspicious that > this select returns nothing? it's because the table is in the 'test' > schema, not in 'mtr'. Please, fix. changed > >> +create table tst_1(xyz blob unique , x2 blob unique); >> +insert into tst_1 values(1,22); >> +--error 1022 >> +insert into tst_1 values(2,22); >> +select * from tst_1; >> +--error 1054 >> +select db_row_hash_1 from tst_1; >> +--error 1054 >> +select db_row_hash_2 from tst_1; >> +--error 1054 >> +select db_row_hash_1,db_row_hash_2 from tst_1; >> +desc tst_1; >> +select * from information_schema.columns where table_schema='mtr' and table_name='tst_1'; > same > >> +create table t1 (empnum smallint, grp int); >> +create table t2 (empnum int, name char(5)); >> +insert into t1 values(1,1); >> +insert into t2 values(1,'bob'); >> +create view v1 as select * from t2 inner join t1 using (empnum); >> +select * from v1; > what was the point of this t1/t2/v1 test? > >> +#test on create table with column db_row_hash >> +create table c_1(abc blob unique, db_row_hash_1 int unique); >> +desc c_1; >> +insert into c_1 values(1,1); >> +--error 1022 >> +insert into c_1 values(1,2); >> +create table c_2(abc blob unique,xyz blob unique, db_row_hash_2 >> +int,db_row_hash_1 int unique); >> +desc c_2; >> +insert into c_2 values(1,1,1,1); >> +--error 1022 >> +insert into c_2 values(1,23,4,5); >> +#update table >> +create table u_1(abc int primary key , xyz blob unique); >> +insert into u_1 values(1,2); >> +insert into u_1 values(2,3); >> +update u_1 set xyz=2 where abc=1; > this updates the row to itw old values. test the update to new values. > to non-duplicate and to duplicate values. > >> +#alter table drop column >> +--error 1091 >> +alter table z_1 drop db_row_hash_1; >> +--error 1091 >> +alter table c_1 drop db_row_hash_2; >> +alter table c_1 drop db_row_hash_1; >> +#add column >> +alter table z_1 add column db_row_hash_1 int unique; >> +show create table z_1; >> +#insert should not break >> +--error 1022 >> +insert into z_1 values('sachin',1); > good > >> +alter table c_1 add column db_row_hash_2 int; > test also adding and removing unique index for blobs. > 1. adding when a column has no duplicates > 2. adding when a column has duplicates > 3. adding when a column has duplicates and IGNORE clause was used > >> +show create table c_1; >> +#modify db_row_hash >> +--error 1054 >> +alter table z_1 change db_row_hash_2 temp int; >> +--error 1054 >> +alter table c_1 change db_row_hash_3 temp int; >> +--error 1054 >> +alter table c_1 change db_row_hash_4 temp int; >> +alter table c_2 change db_row_hash_1 temp int; >> +# now try to index db_row_hash >> +create table c_3(abc blob unique, xyz blob); >> +--error 1072 >> +alter table c_3 add index(db_row_hash_1); >> +create table i_1(x1 int ); >> +alter table i_1 add column x2 blob unique; >> +insert into i_1 value(1,1); >> +--error 1022 >> +insert into i_1 value(2,1); >> +alter table i_1 drop index x2; >> +insert into i_1 value(2,1); >> +create table i_2(abc blob); >> +insert into i_2 values(1); >> +alter table i_2 add unique index(abc); >> +select * from i_2; >> +insert into i_2 values(22); >> +--error 1022 >> +insert into i_2 values(22); >> +alter table i_2 drop key abc; >> +insert into i_2 values(22); >> +drop table i_2; >> +create table i_2(abc blob); >> +insert into i_2 values(1); >> +alter table i_2 add constraint unique(abc); >> +select * from i_2; >> +insert into i_2 values(22); >> +--error 1022 >> +insert into i_2 values(22); >> +alter table i_2 drop key abc; >> +insert into i_2 values(22); >> +# now some indexes on blob these should allow >> +# duplicates these will be used in where clause >> +create table di_1(abc blob , xyz int , index(abc,xyz)); >> +show create table di_1; >> +insert into di_1 values(1,1); >> +insert into di_1 values(1,1); >> +insert into di_1 values(2,1); >> +create table di_2 (abc blob); >> +insert into di_2 values(1); >> +insert into di_2 values(1); >> +alter table di_2 add index(abc); > what kind of index is used here? should be a normal index, > no hash, no hidden db_row_hash_1 column, just a normal b-tree index. > >> +show create table di_2; >> +insert into di_2 values(1); >> +alter table di_2 drop index abc; >> +show create table di_2; > you never clean up in these tests. see other - existing - test files, > they always drop all created tables and views, so that when the test > end all databases look exactly as before the test started. > >> diff --git a/include/my_base.h b/include/my_base.h >> index 8b546ed..d5c697b 100644 >> --- a/include/my_base.h >> +++ b/include/my_base.h >> @@ -250,6 +250,8 @@ enum ha_base_keytype { >> >> #define HA_NOSAME 1 /* Set if not dupplicated records */ >> #define HA_PACK_KEY 2 /* Pack string key to previous key */ >> +#define HA_INDEX_HASH 4 /* */ > you don't need HA_INDEX_HASH. See above, non-unique index on blobs > should be just a normal b-tree index, no hash, subject to automatic > key truncation, see sql_table.cc around the line with the comment > /* not a critical problem */ removed >> +#define HA_UNIQUE_HASH 8 > as you've found out already, there two bits are not free > >> #define HA_AUTO_KEY 16 >> #define HA_BINARY_PACK_KEY 32 /* Packing of all keys to prev key */ >> #define HA_FULLTEXT 128 /* For full-text search */ >> diff --git a/sql/field.h b/sql/field.h >> index 08905f2..2e6e0e4 100644 >> --- a/sql/field.h >> +++ b/sql/field.h >> @@ -628,6 +628,8 @@ class Field: public Value_source >> @c NOT @c NULL field, this member is @c NULL. >> */ >> uchar *null_ptr; >> + field_visible_type field_visibility=NORMAL; >> + bool is_hash=false; > please add a comment for is_hash or rename it to something that is > self-explanatory. field_visibility, for example, is self-explanatory. okay >> /* >> Note that you can use table->in_use as replacement for current_thd member >> only inside of val_*() and store() members (e.g. you can't use it in cons) >> @@ -3051,6 +3052,10 @@ class Field_blob :public Field_longstr { >> inline uint32 get_length(uint row_offset= 0) >> { return get_length(ptr+row_offset, this->packlength); } >> uint32 get_length(const uchar *ptr, uint packlength); >> + uint32 data_length(int row_offset=0) >> + { >> + return get_length(row_offset); >> + } > Huh? > There was no Field_blob::data_length(), it was using the parent > implementation Field::data_length(). That was returning pack_length(), > that is Field_blob::pack_length(), which is simply packlength + portable_sizeof_char_ptr > Now you've defined Field_blob::data_length() to return get_length(0). > That is, you've changed the meaning of Field_blob::data_length(). > Is that ok? Was old Field_blob::data_length() never used? Reverted actually i used this in earlier code but now no longer use this function > >> uint32 get_length(const uchar *ptr_arg) >> { return get_length(ptr_arg, this->packlength); } >> inline void get_ptr(uchar **str) >> @@ -3455,6 +3460,8 @@ class Create_field :public Sql_alloc >> max number of characters. >> */ >> ulonglong length; >> + field_visible_type field_visibility=NORMAL; >> + bool is_hash=false; > don't do that. gcc complains > > warning: non-static data member initializers only available with -std=c++11 or -std=gnu++11 > > and we don't use c++11 yet, because some of our compilers in buildbot > don't support it. done >> /* >> The value of `length' as set by parser: is the number of characters >> for most of the types, or of bytes for BLOBs or numeric types. >> diff --git a/sql/handler.cc b/sql/handler.cc >> index 49e451e..e7d7815 100644 >> --- a/sql/handler.cc >> +++ b/sql/handler.cc >> @@ -5864,16 +5864,60 @@ int handler::ha_reset() >> DBUG_RETURN(reset()); >> } >> >> - >> +/** @brief >> + Compare two records >> + It requires both records to be present in table->record[0] >> + and table->record[1] >> + @returns true if equal else false >> + */ >> +bool rec_hash_cmp(uchar *first_rec, uchar *sec_rec, Field *hash_field) >> +{ >> + Item_args * t_item=(Item_args *)hash_field->vcol_info->expr_item; >> + int arg_count = t_item->argument_count(); >> + Item ** arguments=t_item->arguments(); >> + int diff = sec_rec-first_rec; >> + Field * t_field; >> + for(int i=0;i> + { >> + t_field = ((Item_field *)arguments[i])->field;//need a debug assert >> + if(t_field->cmp_binary_offset(diff)) >> + return false; >> + } >> + return true; >> +} > 1. please format the code like it's done elsewhere in the file. > - in assignments: no space before '=', one space after > - after a function/method must be one or two empty lines > - in if/for/while: a space between the keyword and a parenthesys > - in for() loop - a space after a semicolon > - in function arguments - a space after a comma > - not in the function above, but everywhere in your patch > > 2. it's better to avoid type conversion where it's not needed, for > example, t_item->argument_count() returns uint, so your arg_count should > be of that type too. > > 3. either write a completely generic function that compares two records > given as pointers, or write a function that compares record[0] and record[1]. > Ok, it looks you need to compare a record as a pointer with record[0]. > Then remove first_rec, it only creates a false pretence that a function > is more generic than it is. > Instead, do > > int diff= sec_rec - hash_field->table->record[0]; > > (and, may be, rename sec_rec to "other_rec") > > 4. what do you mean "need a debug assert"? if you need it, add it :) > if you want to add a debug assert, but don't know how - please, ask. > >> int handler::ha_write_row(uchar *buf) >> { >> - int error; >> + int error,result; >> Log_func *log_func= Write_rows_log_event::binlog_row_logging_function; >> + Field *field_iter; >> DBUG_ASSERT(table_share->tmp_table != NO_TMP_TABLE || >> m_lock_type == F_WRLCK); >> DBUG_ENTER("handler::ha_write_row"); >> DEBUG_SYNC_C("ha_write_row_start"); >> - >> + /* First need to whether inserted record is unique or not */ >> + /* One More Thing if i implement hidden field then detection can be easy */ > this second comment is probably obsolete, you can remove it > >> + for(uint i=0;i s->keys;i++) >> + { >> + if(table->key_info[i].flags&HA_UNIQUE_HASH) > in fact, you don't need a special key flag. you can check, like > > if (table->key_info[i].key_part->field->is_hash) > > but a flag makes it kinda simpler, so if you like the flag, go ahead and > use it (if you find an free bit for it). Perhaps, even, you can use the > key flag and remove Field::is_hash? The field does not need any special > treatment, does it? it only needs to be hidden. > >> + { >> + field_iter=table->key_info[i].key_part->field; > why did you name it "field_iter"? it's not an iterator. may be "hash_field"? > >> + int len =table->key_info[i].key_length; >> + uchar ptr[len]; > we compile with -Wvla, so this will be a warning too. Just use > ptr[9], for example. And add DBUG_ASSERT(len < sizeof(ptr)); > >> + if(field_iter->is_null()) >> + { >> + goto write_row; > no goto here, just break; > >> + } >> + key_copy(ptr,buf,&table->key_info[i],len,false); >> + result= table->file->ha_index_read_idx_map(table->record[1],i,ptr, >> + HA_WHOLE_KEY,HA_READ_KEY_EXACT); >> + if(!result) >> + { >> + if(rec_hash_cmp(table->record[0],table->record[1],field_iter)) >> + DBUG_RETURN(HA_ERR_FOUND_DUPP_KEY); >> + } >> + } >> + } >> + write_row: > and no label here > >> MYSQL_INSERT_ROW_START(table_share->db.str, table_share->table_name.str); >> mark_trx_read_write(); >> increment_statistics(&SSV::ha_write_count); >> @@ -5907,6 +5952,36 @@ int handler::ha_update_row(const uchar *old_data, uchar *new_data) >> DBUG_ASSERT(new_data == table->record[0]); >> DBUG_ASSERT(old_data == table->record[1]); >> >> + /* First need to whether inserted record is unique or not */ >> + /* One More Thing if i implement hidden field then detection can be easy */ >> + for(uint i=0;i s->keys;i++) >> + { >> + if(table->key_info[i].flags&HA_UNIQUE_HASH) >> + { >> + /* >> + We need to add the null bit >> + If the column can be NULL, then in the first byte we put 1 if the >> + field value is NULL, 0 otherwise. >> + */ >> + uchar *new_rec = (uchar *)alloc_root(&table->mem_root, >> + table->s->reclength*sizeof(uchar)); > do you know how alloc_root works? read include/mysql/service_thd_alloc.h > memory allocated with alloc_root() can not be freed individually, it is > freed when the complete MEM_ROOT is reset or destroyed. > so, three problems here: > 1. you allocate memory on MEM_ROOT in a loop. so, if the table has, say > three HA_UNIQUE_HASH keys, you'll allocate the buffer three times, while > one should've been totally sufficient > 2. you allocate for every row that is inserted > 3. you allocate it on the *TABLE::mem_root*. Table's memroot is freed > only when a table is closed! > > So, if you create a table with three unique(blob) keys, and insert > four rows in one statement: INSERT ... VALUES (),(),(),(),(). And > repeat this insert five times, you'll allocate 3*4*5=60 reclength bytes. > They'll not be freed, so if you repeat this insert five more times, it'll > be 60 reclength more bytes. And so on :) > > I think the good approach would be to have, like TABLE::check_unique_buf > row buffer. See that TABLE has now: > > uchar *record[2]; /* Pointer to records */ > uchar *write_row_record; /* Used as optimisation in > THD::write_row */ > uchar *insert_values; /* used by INSERT ... UPDATE */ > > that's where you add uchar *check_unique_buf; > it's initialized to 0. and on the first use you do, like > > if (!table->check_unique_buf) > table->check_unique_buf= alloc_root(&table->mem_root, ...) > > and then you can freely use it for checking your unique constraints. > it'll be allocated only once per TABLE. done > >> + field_iter=table->key_info[i].key_part->field; >> + uchar ptr[9]; > better #define UNIQ_HASH_KEY_LEN 9 and use it everywhere > >> + if(field_iter->is_null()) >> + { >> + goto write_row; >> + } >> + key_copy(ptr,new_data,&table->key_info[i],9,false); >> + result= table->file->ha_index_read_idx_map(new_rec,i,ptr, >> + HA_WHOLE_KEY,HA_READ_KEY_EXACT); >> + if(!result) >> + { >> + if(rec_hash_cmp(table->record[0],new_rec,field_iter)) >> + return HA_ERR_FOUND_DUPP_KEY; >> + } >> + } >> + } >> + write_row: > this is the same code as in handler::ha_write_row, please combine them > into one function (for simplicity you can use table->check_unique_buf also > for INSERT) done > >> MYSQL_UPDATE_ROW_START(table_share->db.str, table_share->table_name.str); >> mark_trx_read_write(); >> increment_statistics(&SSV::ha_update_count); >> diff --git a/sql/item.cc b/sql/item.cc >> index adf7031..2015752 100644 >> --- a/sql/item.cc >> +++ b/sql/item.cc >> @@ -5059,7 +5059,13 @@ bool Item_field::fix_fields(THD *thd, Item **reference) >> } >> else if (!from_field) >> goto error; >> - >> + if(from_field->field_visibility==FULL_HIDDEN) >> + { >> + my_error(ER_BAD_FIELD_ERROR, MYF(0), (* reference)->full_name(), >> + thd->where); >> + from_field=NULL; >> + goto error; >> + } > So, you're patching the "search for field by name" process, pretending > that the field does not exist if it's FULL_HIDDEN. This is, of course, > correct. But I suspect you're doing it too late. Consider this case: > > create table t1 (b blob, unique (b)); > create table t2 (db_row_hash_1 int, a int); > > select * from t1, t2 where db_row_hash_1=5; > > in this case, mariadb needs to search for db_row_hash_1 field in t1, > should not find it, continue searching in t2, find it there. > in your code it will find it in t1, and later reject it with > ER_BAD_FIELD_ERROR. > > there may be more complex cases, with subqueries and outer selects, > views, etc. important part is - you need to reject FULL_HIDDEN field > immediately when it's found, so that the search could continue in other > tables, outer selects, etc. > > btw, don't forget to add tests for this behavior (one table or outer > select has db_row_hash_1 visible field, another table has db_row_hash_1 > FULL_HIDDEN field). done >> table_list= (cached_table ? cached_table : >> from_field != view_ref_found ? >> from_field->table->pos_in_table_list : 0); >> diff --git a/sql/item_func.cc b/sql/item_func.cc >> index 6edb276..889ac40 100644 >> --- a/sql/item_func.cc >> +++ b/sql/item_func.cc >> @@ -1916,6 +1916,37 @@ void Item_func_int_div::fix_length_and_dec() >> } >> >> >> +longlong Item_func_hash::val_int() >> +{ >> + unsigned_flag= true; >> + ulong nr1= 1,nr2= 4; >> + CHARSET_INFO *cs; >> + for(uint i= 0;i > + { >> + String * str = args[i]->val_str(); >> + if(args[i]->null_value) >> + { >> + null_value= 1; >> + return 0; >> + } >> + cs= str->charset(); >> + uchar l[4]; >> + int4store(l,str->length()); >> + cs->coll->hash_sort(cs,l,sizeof(l), &nr1, &nr2); > looks good, but use my_charset_binary for the length. did not get it :( > >> + cs->coll->hash_sort(cs, (uchar *)str->ptr(), str->length(), &nr1, &nr2); >> + } >> + return (longlong)nr1; >> +} >> + >> + >> +void Item_func_hash::fix_length_and_dec() >> +{ >> + maybe_null= 1; >> + decimals= 0; >> + max_length= 8; >> +} >> + >> + >> longlong Item_func_mod::int_op() >> { >> DBUG_ASSERT(fixed == 1); >> diff --git a/sql/lex.h b/sql/lex.h >> index 22ff4e6..d7a4e14 100644 >> --- a/sql/lex.h >> +++ b/sql/lex.h >> @@ -266,6 +266,7 @@ static SYMBOL symbols[] = { >> { "HAVING", SYM(HAVING)}, >> { "HELP", SYM(HELP_SYM)}, >> { "HIGH_PRIORITY", SYM(HIGH_PRIORITY)}, >> + {"HIDDEN", SYM(HIDDEN)}, > spacing! align it as all other rows are > >> { "HOST", SYM(HOST_SYM)}, >> { "HOSTS", SYM(HOSTS_SYM)}, >> { "HOUR", SYM(HOUR_SYM)}, >> diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt >> index 709ac55..9ae3ac6 100644 >> --- a/sql/share/errmsg-utf8.txt >> +++ b/sql/share/errmsg-utf8.txt >> @@ -7139,3 +7139,5 @@ ER_KILL_QUERY_DENIED_ERROR >> ER_NO_EIS_FOR_FIELD >> eng "Engine-independent statistics are not collected for column '%s'" >> ukr "Незалежна від типу таблиці статистика не збирається для стовбця '%s'" >> +ER_HIDDEN_NOT_NULL_WOUT_DEFAULT >> + eng "Hidden column '%s' either allow null values or it must have default value" > when you'll merge with 10.2 make sure this your new error will > end up at the very end, after ER_EXPRESSION_REFERS_TO_UNINIT_FIELD > >> diff --git a/sql/sql_class.h b/sql/sql_class.h >> index 8bfc243..bb206a8 100644 >> --- a/sql/sql_class.h >> +++ b/sql/sql_class.h >> @@ -297,7 +297,7 @@ class Key :public Sql_alloc, public DDL_options { >> LEX_STRING name; >> engine_option_value *option_list; >> bool generated; >> - >> + key_hash_type hash_type=NOT_HASH; > same as above about c++11 > >> Key(enum Keytype type_par, const LEX_STRING &name_arg, >> ha_key_alg algorithm_arg, bool generated_arg, DDL_options_st ddl_options) >> :DDL_options(ddl_options), >> diff --git a/sql/sql_base.cc b/sql/sql_base.cc >> index e808fba..b2c8dfb 100644 >> --- a/sql/sql_base.cc >> +++ b/sql/sql_base.cc >> @@ -8343,6 +8343,8 @@ insert_fields(THD *thd, Name_resolution_context *context, const char *db_name, >> >> for (; !field_iterator.end_of_fields(); field_iterator.next()) >> { >> + if(field_iterator.field()==NULL || > eh... can it be NULL here, really? i do not there was a test in innodb which was failing because of this anyway changed the whole code > >> + field_iterator.field()->field_visibility==NORMAL){ >> Item *item; >> >> if (!(item= field_iterator.create_item(thd))) >> diff --git a/sql/sql_insert.cc b/sql/sql_insert.cc >> index fcf8c14..2bfb288 100644 >> --- a/sql/sql_insert.cc >> +++ b/sql/sql_insert.cc >> @@ -723,7 +722,24 @@ bool mysql_insert(THD *thd,TABLE_LIST *table_list, >> if (open_and_lock_tables(thd, table_list, TRUE, 0)) >> DBUG_RETURN(TRUE); >> } >> - >> + >> + context= &thd->lex->select_lex.context; >> + if(table_list->table!=NULL) > can table_list->table be NULL here? same a test in innodb was failing but now i do not use his logic > >> + { >> + Field ** f=table_list->table->field; >> + List - * i_list = (List
- *)values_list.first_node()->info; >> + for(uint i=0;i
table->s->fields;i++) >> + { >> + if((*f)->is_hash ||(*f)->field_visibility==USER_DEFINED_HIDDEN) >> + { >> + i_list->push_front(new (thd->mem_root) >> + Item_default_value(thd,context),thd->mem_root); >> + } >> + f++; >> + } >> + } >> + List_iterator_fast its(values_list); >> + > is that needed at all? one can always do INSERT t1 (a) VALUES (1) > and all non-specified fields will get default values. without > specifically adding Item_default_value to the list. So, it seems, that > hidden fields will automatically get default values too. > changed >> lock_type= table_list->lock_type; >> >> THD_STAGE_INFO(thd, stage_init); >> diff --git a/sql/sql_show.cc b/sql/sql_show.cc >> index 1cbad7e..60e586c 100644 >> --- a/sql/sql_show.cc >> +++ b/sql/sql_show.cc >> @@ -1932,6 +1931,26 @@ int show_create_table(THD *thd, TABLE_LIST *table_list, String *packet, >> } >> append_create_options(thd, packet, field->option_list, check_options, >> hton->field_options); >> + //TODO need a better logic to find wheter to put comma or not >> + int i=1; >> + bool is_comma_needed=false; >> + if (*(ptr+i)!=NULL) >> + { >> + is_comma_needed=true; >> + while((*(ptr+i))->field_visibility==MEDIUM_HIDDEN || >> + (*(ptr+i))->field_visibility==FULL_HIDDEN) >> + { >> + i++; >> + is_comma_needed=true; >> + if(!*(ptr+i)) >> + { >> + is_comma_needed =false; >> + break; >> + } >> + } >> + } >> + if(is_comma_needed) >> + packet->append(STRING_WITH_LEN(",\n")); > agree about "better logic". You can do it like this: > > bool is_comma_needed= false; > for (ptr=table->field ; (field= *ptr); ptr++) > { > if (is_comma_needed) > packet->append(STRING_WITH_LEN(",\n")); > is_comma_needed= false; > ... > print field > is_comma_needed= true; > } > but this wont work because i need to put comma only when there is remaning field but atleast one of then is non hidden so i have to use while >> } >> >> key_info= table->key_info; >> @@ -1946,6 +1965,22 @@ int show_create_table(THD *thd, TABLE_LIST *table_list, String *packet, >> for (uint i=0 ; i < share->keys ; i++,key_info++) >> { >> KEY_PART_INFO *key_part= key_info->key_part; >> + if(key_info->flags&HA_UNIQUE_HASH||key_info->flags&HA_INDEX_HASH) > code formatting. spaces! changed >> + { >> + char * column_names= key_part->field->vcol_info-> >> + expr_str.str+strlen("hash"); >> + int length=key_part->field->vcol_info->expr_str.length; >> + length-=strlen("hash"); >> + packet->append(STRING_WITH_LEN(",\n")); >> + if(key_info->flags&HA_INDEX_HASH) >> + packet->append(STRING_WITH_LEN(" INDEX `")); >> + else >> + packet->append(STRING_WITH_LEN(" UNIQUE KEY `")); >> + packet->append(key_info->name,strlen(key_info->name)); >> + packet->append(STRING_WITH_LEN("`")); >> + packet->append(column_names,length); > I don't like that ±strlen("hash"). Better do it like this: > > static LEX_CSTRING uniq_hash_func={ STRING_WITH_LEN("hash" }; > > and instead of strlen("hash") you use uniq_hash_func.length, > and below instead of explicit "hash" string in the mysql_prepare_create_table > you use uniq_hash_func.str. done but instead of static LEX_CSTRING uniq_hash_func={ STRING_WITH_LEN("hash" }; i have define macro in my_base.h >> + continue; >> + } >> bool found_primary=0; >> packet->append(STRING_WITH_LEN(",\n ")); >> >> @@ -5416,6 +5454,22 @@ static int get_schema_column_record(THD *thd, TABLE_LIST *tables, >> else >> table->field[17]->store(STRING_WITH_LEN("VIRTUAL"), cs); >> } >> + /*hidden can coexist with auto_increment and virtual */ >> + if(field->field_visibility==USER_DEFINED_HIDDEN) >> + { >> + table->field[17]->store(STRING_WITH_LEN("HIDDEN"), cs); >> + if (field->unireg_check == Field::NEXT_NUMBER) >> + table->field[17]->store(STRING_WITH_LEN("auto_increment , HIDDEN"), cs); >> + if (print_on_update_clause(field, &type, true)) >> + table->field[17]->store(type.ptr(), type.length(), cs); >> + if (field->vcol_info) >> + { >> + if (field->stored_in_db) >> + table->field[17]->store(STRING_WITH_LEN("PERSISTENT, HIDDEN"), cs); >> + else >> + table->field[17]->store(STRING_WITH_LEN("VIRTUAL, HIDDEN"), cs); >> + } >> + } > eh, please no. don't duplicate the whole block. A variant that avoids it: > > StringBuffer<256> buf; > > if (autoinc) // this is pseudocode, see the correct condition is in the code above > buf.set(STRING_WITH_LEN("auto_increment")) > else if (virtual) > buf.set(STRING_WITH_LEN("VIRTUAL"); > ... > > if (hidden) > { > if (buf.length) > buf.append(STRING_WITH_LEN(", ")); > buf.append(STRING_WITH_LEN("HIDDEN")); > } > table->field[17]->store(buf.ptr(), buf.length(), cs); changed >> table->field[19]->store(field->comment.str, field->comment.length, cs); >> if (schema_table_store_record(thd, table)) >> DBUG_RETURN(1); >> diff --git a/sql/sql_table.cc b/sql/sql_table.cc >> index dae3b7a..d9322ca 100644 >> --- a/sql/sql_table.cc >> +++ b/sql/sql_table.cc >> @@ -3013,7 +3013,7 @@ int prepare_create_field(Create_field *sql_field, >> break; >> } >> if (!(sql_field->flags & NOT_NULL_FLAG) || >> - (sql_field->vcol_info)) /* Make virtual columns allow NULL values */ >> + (sql_field->vcol_info)) > why did you remove this comment? > reverted >> sql_field->pack_flag|= FIELDFLAG_MAYBE_NULL; >> if (sql_field->flags & NO_DEFAULT_VALUE_FLAG) >> sql_field->pack_flag|= FIELDFLAG_NO_DEFAULT; >> @@ -3223,6 +3222,130 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, >> bool tmp_table= create_table_mode == C_ALTER_TABLE; >> DBUG_ENTER("mysql_prepare_create_table"); >> >> + /* >> + scan the the whole alter list >> + and add one field if length of blob is zero >> + TODO change to work for all too-long unique keys like varchar,text >> + */ >> + >> + List_iterator key_iter(alter_info->key_list); >> + Key *key_iter_key; >> + Key_part_spec *temp_colms; >> + int num= 1; >> + bool is_long_unique=false; >> + int key_initial_elements=alter_info->key_list.elements; >> + while((key_iter_key=key_iter++)&&key_initial_elements) >> + { >> + key_initial_elements--; >> + List_iterator key_part_iter(key_iter_key->columns); >> + while((temp_colms=key_part_iter++)) >> + { >> + while ((sql_field=it++) &&sql_field&& my_strcasecmp(system_charset_info, >> + temp_colms->field_name.str, >> + sql_field->field_name)){} >> + if(sql_field && (sql_field->sql_type==MYSQL_TYPE_BLOB || >> + sql_field->sql_type==MYSQL_TYPE_MEDIUM_BLOB|| >> + sql_field->sql_type==MYSQL_TYPE_LONG_BLOB) >> + &&temp_colms->length==0) >> + { >> + is_long_unique=true; >> + /* >> + One long key unique in enough >> + */ >> + it.rewind(); >> + break; >> + } >> + // if(sql_field->sql_type==MYSQL_TYPE_VARCHAR) >> + it.rewind(); >> + } >> + if(is_long_unique) >> + { >> + /* make a virtual field */ >> + key_part_iter.rewind(); >> + Create_field *cf = new (thd->mem_root) Create_field(); >> + cf->flags|=UNSIGNED_FLAG; >> + cf->length=cf->char_length=8; >> + cf->charset=NULL; >> + cf->decimals=0; >> + char temp_name[30]; >> + strcpy(temp_name,"DB_ROW_HASH_"); >> + char num_holder[10]; //10 is way more but i think it is ok >> + sprintf(num_holder,"%d",num); >> + strcat(temp_name,num_holder); >> + /* >> + Check for collusions >> + */ >> + while((dup_field=it++)) >> + { >> + if(!my_strcasecmp(system_charset_info,temp_name,dup_field->field_name)) >> + { >> + temp_name[12]='\0'; //now temp_name='DB_ROW_HASH_' >> + num++; >> + sprintf(num_holder,"%d",num); >> + strcat(temp_name,num_holder); >> + it.rewind(); >> + } >> + } >> + it.rewind(); >> + char * name = (char *)thd->alloc(30); >> + strcpy(name,temp_name); >> + cf->field_name=name; >> + cf->stored_in_db=true; >> + cf->sql_type=MYSQL_TYPE_LONGLONG; >> + /* hash column should be atmost hidden */ >> + cf->field_visibility=FULL_HIDDEN; >> + if(key_iter_key->type==Key::UNIQUE) >> + key_iter_key->hash_type=UNIQUE_HASH; >> + else >> + key_iter_key->hash_type=INDEX_HASH; >> + cf->is_hash=true; >> + /* add the virtual colmn info */ >> + Virtual_column_info *v= new (thd->mem_root) Virtual_column_info(); >> + char * hash_exp=(char *)thd->alloc(252); >> + char * key_name=(char *)thd->alloc(252); >> + strcpy(hash_exp,"hash(`"); >> + temp_colms=key_part_iter++; >> + strcat(hash_exp,temp_colms->field_name.str); >> + strcpy(key_name,temp_colms->field_name.str); >> + strcat(hash_exp,"`"); >> + while((temp_colms=key_part_iter++)){ >> + strcat(hash_exp,(const char * )","); >> + strcat(key_name,"_"); >> + strcat(hash_exp,"`"); >> + strcat(hash_exp,temp_colms->field_name.str); >> + strcat(key_name,temp_colms->field_name.str); >> + strcat(hash_exp,"`"); >> + } >> + strcat(hash_exp,(const char * )")"); >> + v->expr_str.str= hash_exp; >> + v->expr_str.length= strlen(hash_exp); >> + v->expr_item= NULL; >> + v->set_stored_in_db_flag(true); >> + cf->vcol_info=v; >> + alter_info->create_list.push_front(cf,thd->mem_root); >> + /* >> + Now create the key field kind >> + of harder then prevoius one i guess >> + */ >> + key_iter_key->type=Key::MULTIPLE; >> + key_iter_key->columns.delete_elements(); >> + LEX_STRING *ls =(LEX_STRING *)thd->alloc(sizeof(LEX_STRING)) ; >> + ls->str=(char *)sql_field->field_name; >> + ls->length =strlen(sql_field->field_name); >> + if(key_iter_key->name.length==0) >> + { >> + LEX_STRING *ls_name =(LEX_STRING *)thd->alloc(sizeof(LEX_STRING)) ; >> + ls_name->str=key_name; >> + ls_name->length=strlen(key_name); >> + key_iter_key->name= *ls_name; >> + } >> + key_iter_key->columns.push_back(new (thd->mem_root) Key_part_spec(name, >> + strlen(name), 0),thd->mem_root); >> + >> + } >> + is_long_unique=false; >> + } >> + it.rewind(); > why are you doing it here, in a separate loop, insead of doing it where > ER_TOO_LONG_KEY is issued? changed > >> select_field_pos= alter_info->create_list.elements - select_field_count; >> null_fields=blob_columns=0; >> create_info->varchar= 0; >> @@ -3241,7 +3364,7 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, >> /* Set field charset. */ >> save_cs= sql_field->charset= get_sql_field_charset(sql_field, create_info); >> if ((sql_field->flags & BINCMP_FLAG) && >> - !(sql_field->charset= find_bin_collation(sql_field->charset))) >> + !(sql_field->charset= find_bin_collation(sql_field->charset))) > typo. please revert > >> DBUG_RETURN(TRUE); >> >> /* >> @@ -3274,7 +3397,17 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, >> DBUG_RETURN(TRUE); >> } >> } >> - >> + if(sql_field->field_visibility==USER_DEFINED_HIDDEN) >> + { >> + if(sql_field->flags&NOT_NULL_FLAG) >> + { >> + if(sql_field->flags&NO_DEFAULT_VALUE_FLAG) > do it in one if(), not in three, please changed >> + { >> + my_error(ER_HIDDEN_NOT_NULL_WOUT_DEFAULT, MYF(0), sql_field->field_name); >> + DBUG_RETURN(TRUE); >> + } >> + } >> + } >> if (sql_field->sql_type == MYSQL_TYPE_SET || >> sql_field->sql_type == MYSQL_TYPE_ENUM) >> { >> @@ -3831,8 +3968,8 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, >> sql_field->charset->mbminlen > 1 || // ucs2 doesn't work yet >> (ft_key_charset && sql_field->charset != ft_key_charset)) >> { >> - my_error(ER_BAD_FT_COLUMN, MYF(0), column->field_name.str); >> - DBUG_RETURN(-1); >> + my_error(ER_BAD_FT_COLUMN, MYF(0), column->field_name.str); >> + DBUG_RETURN(-1); >> } > indentation is two spaces, not one i do not know why this is not working i tried in vi but does not worked i removed most of idention problem but this one is not solving :( >> ft_key_charset=sql_field->charset; >> /* >> @@ -3874,10 +4011,9 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, >> if (f_is_geom(sql_field->pack_flag) && sql_field->geom_type == >> Field::GEOM_POINT) >> column->length= MAX_LEN_GEOM_POINT_FIELD; >> - if (!column->length) >> + if (!column->length) > again, as a couple of times above - tabs confuse you > and you mess up the indentation :( > >> { >> - my_error(ER_BLOB_KEY_WITHOUT_LENGTH, MYF(0), column->field_name.str); >> - DBUG_RETURN(TRUE); >> + DBUG_ASSERT(0); >> } >> } >> #ifdef HAVE_SPATIAL >> @@ -7420,7 +7557,10 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, >> while ((drop=drop_it++)) >> { >> if (drop->type == Alter_drop::COLUMN && >> - !my_strcasecmp(system_charset_info,field->field_name, drop->name)) >> + !my_strcasecmp(system_charset_info,field->field_name, drop->name) > again > >> + /* we cant not drop system generated column */ >> + && !(field->field_visibility==MEDIUM_HIDDEN >> + ||field->field_visibility==FULL_HIDDEN)) >> { >> /* Reset auto_increment value if it was dropped */ >> if (MTYP_TYPENR(field->unireg_check) == Field::NEXT_NUMBER && >> @@ -7444,7 +7584,10 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, >> while ((def=def_it++)) >> { >> if (def->change && >> - !my_strcasecmp(system_charset_info,field->field_name, def->change)) >> + !my_strcasecmp(system_charset_info,field->field_name, def->change) > and again > >> + /* we cant change system generated column */ >> + && !(field->field_visibility==MEDIUM_HIDDEN >> + ||field->field_visibility==FULL_HIDDEN)) >> break; >> } >> if (def) >> @@ -7512,6 +7655,51 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, >> table->s->table_name.str); >> goto err; >> } >> + /* Need to see whether new added column clashes with already existed >> + DB_ROW_HASH_*(is must have is_hash==tru) >> + */ >> + for (f_ptr=table->vfield ;f_ptr&&(field= *f_ptr) ; f_ptr++) >> + { >> + if ((field->is_hash)&&!my_strcasecmp(system_charset_info,field->field_name,def->field_name)) >> + { >> + /* got a clash find the highest number in db_row_hash_* */ >> + Field *temp_field; >> + int max=0; >> + for (Field ** f_temp_ptr=table->vfield ; (temp_field= *f_temp_ptr); f_temp_ptr++) >> + { >> + if(temp_field->is_hash) >> + { >> + int temp = atoi(temp_field->field_name+12); >> + if(temp>max) >> + max=temp; >> + } >> + } >> + max++; >> + >> + Create_field * old_hash_field; >> + while((old_hash_field=field_it++)) >> + { >> + if(!my_strcasecmp(system_charset_info,old_hash_field->field_name, >> + field->field_name)) >> + { >> + field_it.remove(); >> + break; >> + } >> + } >> + /* Give field new name which does not clash with def->feild_name */ >> + new_hash_field = old_hash_field->clone(thd->mem_root); >> + char *name = (char *)thd->alloc(30); >> + strcpy(name,"DB_ROW_HASH_"); >> + char num_holder[10]; >> + sprintf(num_holder,"%d",max); >> + strcat(name,num_holder); >> + new_hash_field->field_name=name; >> + new_hash_field->field=field; >> + new_hash_field->change=old_hash_field->field_name; >> + new_create_list.push_front(new_hash_field,thd->mem_root); >> + field_it.rewind(); >> + } >> + } > okay... I wonder, if it would be easier not to look for collisions in > mysql_prepare_alter_table, but simply rename all is_hash columns > in mysql_prepare_create_table(). then you'll only need to do it > in one place. Actually i am thinking of changing the whole approch in mysql_prepare_alter table currently it works but i think better version would be in mysql_prepare_create table we have orignal table table->field and table->key_info i am thinking of making a copy of these two and making changes like deleting db_row_hash_1 from field and expanding keyinfo->key_part of those keys who are long unique but this way mysqll_prepare_create table work normally and all changes will be done in mysql prepare_create_table >> /* >> Check that the DATE/DATETIME not null field we are going to add is >> either has a default value or the '0000-00-00' is allowed by the >> @@ -7609,6 +7799,25 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, >> } >> if (drop) >> { >> + /* If we drop index of blob unique then we need to drop the db_row_hash col */ >> + if(key_info->flags&HA_UNIQUE_HASH||key_info->flags&HA_INDEX_HASH) >> + { >> + char * name = (char *)key_info->key_part->field->field_name; >> + /*iterate over field_it and remove db_row_hash col */ >> + field_it.rewind(); >> + Create_field * temp_field; >> + while ((temp_field=field_it++)) >> + { >> + if(!my_strcasecmp(system_charset_info,temp_field->field_name,name)) >> + { >> + field_it.remove(); >> + //add flag if it not exists >> + alter_info->flags|=Alter_info::ALTER_DROP_COLUMN; >> + break; >> + } >> + } >> + field_it.rewind(); > this should be a little bit more complicated. an index can cover many > columns, so the index should be dropped when its last column is removed. > I suppose you've already done that, I need to pull and check. works > >> + } >> if (table->s->tmp_table == NO_TMP_TABLE) >> { >> (void) delete_statistics_for_index(thd, table, key_info, FALSE); >> @@ -7766,6 +7979,48 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, >> my_error(ER_WRONG_NAME_FOR_INDEX, MYF(0), key->name.str); >> goto err; >> } >> + List_iterator key_part_iter(key->columns); >> + Key_part_spec * temp_colms; >> + Create_field * sql_field; >> + field_it.rewind(); >> + while((temp_colms=key_part_iter++)) >> + { >> + while ((sql_field=field_it++)) >> + { >> + if(!my_strcasecmp(system_charset_info, >> + temp_colms->field_name.str, >> + sql_field->field_name)) >> + { >> + if(sql_field->field_visibility==MEDIUM_HIDDEN||sql_field->field_visibility==FULL_HIDDEN) >> + { >> + /* If we added one column (which clash with db_row_has )then this key >> + is different then added by user to make it sure we check for */ >> + if(new_hash_field) >> + { >> + if(sql_field!=new_hash_field) >> + { >> + my_error(ER_KEY_COLUMN_DOES_NOT_EXITS, MYF(0), sql_field->field_name); >> + goto err; >> + } >> + } >> + else /*this is for add index to db_row_hash which must show error */ >> + { >> + my_error(ER_KEY_COLUMN_DOES_NOT_EXITS, MYF(0), sql_field->field_name); >> + goto err; >> + } > I don't quite understand these your conditions, but the logic should be > like this: MEDIUM_HIDDEN can be indexed, FULL_HIDDEN can never be. > >> + } >> + /* Check whether we adding index for blob or other long length column then add column flag*/ >> + if((sql_field->sql_type==MYSQL_TYPE_BLOB || >> + sql_field->sql_type==MYSQL_TYPE_MEDIUM_BLOB|| >> + sql_field->sql_type==MYSQL_TYPE_LONG_BLOB|| >> + sql_field->sql_type==MYSQL_TYPE_LONG_BLOB) >> + &&(temp_colms->length==0)) >> + alter_info->flags|=Alter_info::ALTER_ADD_COLUMN; > really? why don't you simply set this flag when you actually create new > Create_field and push it into the list? okay >> + } >> + } >> + } >> + field_it.rewind(); >> + >> } >> } >> >> diff --git a/sql/sql_update.cc b/sql/sql_update.cc >> index 4221025..4955881 100644 >> --- a/sql/sql_update.cc >> +++ b/sql/sql_update.cc >> @@ -92,24 +92,24 @@ bool compare_record(const TABLE *table) >> } >> return FALSE; >> } >> - >> - /* >> + >> + /* >> The storage engine has read all columns, so it's safe to compare all bits >> including those not in the write_set. This is cheaper than the field-by-field >> comparison done above. >> - */ >> + */ >> if (table->s->can_cmp_whole_record) >> return cmp_record(table,record[1]); >> /* Compare null bits */ >> if (memcmp(table->null_flags, >> - table->null_flags+table->s->rec_buff_length, >> - table->s->null_bytes_for_compare)) >> + table->null_flags+table->s->rec_buff_length, >> + table->s->null_bytes_for_compare)) > in this file you've done *only* whitespace changes, some of them are ok, > but many result in broken indentation, please fix them all! changed > >> return TRUE; // Diff in NULL value >> /* Compare updated fields */ >> for (Field **ptr= table->field ; *ptr ; ptr++) >> { >> if (bitmap_is_set(table->write_set, (*ptr)->field_index) && >> - (*ptr)->cmp_binary_offset(table->s->rec_buff_length)) >> + (*ptr)->cmp_binary_offset(table->s->rec_buff_length)) >> return TRUE; >> } >> return FALSE; >> diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy >> index e614692..4872d20 100644 >> --- a/sql/sql_yacc.yy >> +++ b/sql/sql_yacc.yy >> @@ -1271,6 +1271,7 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); >> %token HEX_NUM >> %token HEX_STRING >> %token HIGH_PRIORITY >> +%token HIDDEN > HIDDEN_SYM, please > >> %token HOST_SYM >> %token HOSTS_SYM >> %token HOUR_MICROSECOND_SYM >> @@ -6047,6 +6048,11 @@ vcol_attribute: >> lex->alter_info.flags|= Alter_info::ALTER_ADD_INDEX; >> } >> | COMMENT_SYM TEXT_STRING_sys { Lex->last_field->comment= $2; } >> + | HIDDEN >> + { >> + LEX *lex =Lex; > no need to do that ^^^ you can simply write Lex->last_field->field_visibility=... change but in sql_yacc.yy this type of code is use everywhere > >> + lex->last_field->field_visibility=USER_DEFINED_HIDDEN; >> + } >> ; >> >> parse_vcol_expr: >> @@ -6469,6 +6475,11 @@ attribute: >> new (thd->mem_root) >> engine_option_value($1, &Lex->last_field->option_list, &Lex->option_list_last); >> } >> + | HIDDEN >> + { >> + LEX *lex =Lex; >> + lex->last_field->field_visibility=USER_DEFINED_HIDDEN; >> + } > no need to repeat this twice. Try to remove HIDDEN, COMMENT_SYM, UNIQUE, > and UNIQUE KEY rules from attribute and add the vcol_attribute instead. > done >> ; >> >> >> diff --git a/sql/table.h b/sql/table.h >> index eb4076e..982de6f 100644 >> --- a/sql/table.h >> +++ b/sql/table.h >> @@ -321,6 +321,24 @@ enum enum_vcol_update_mode >> VCOL_UPDATE_ALL >> }; >> >> +/* Field visibility enums */ >> + >> +enum field_visible_type{ >> + NORMAL=0, > better NOT_HIDDEN changed >> + USER_DEFINED_HIDDEN, >> + MEDIUM_HIDDEN, >> + FULL_HIDDEN >> +}; >> + >> +enum key_hash_type{ >> + /* normal column */ >> + NOT_HASH=0, >> + /* hash for defination index(A,...) in this case no duplicate will be checked */ >> + INDEX_HASH, > there's no point in having a hash index for blobs, if it doesn't check > for duplicates okay reverted > >> + /* hash for defination unique(A,...) in this duplicate will be checked in ha_write_row and >> + update */ >> + UNIQUE_HASH >> +}; >> class Filesort_info >> { >> /// Buffer for sorting keys. >> diff --git a/sql/table.cc b/sql/table.cc >> index a90eb2e..31d8f1e 100644 >> --- a/sql/table.cc >> +++ b/sql/table.cc >> @@ -785,7 +785,8 @@ static bool create_key_infos(const uchar *strpos, const uchar *frm_image_end, >> keyinfo->ext_key_parts= keyinfo->user_defined_key_parts; >> keyinfo->ext_key_flags= keyinfo->flags; >> keyinfo->ext_key_part_map= 0; >> - if (share->use_ext_keys && i && !(keyinfo->flags & HA_NOSAME)) >> + if (share->use_ext_keys && i && !(keyinfo->flags & HA_NOSAME) >> + ) > revert > >> { >> for (j= 0; >> j < first_key_parts && keyinfo->ext_key_parts < MAX_REF_PARTS; >> @@ -985,7 +990,7 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, >> if (length < 256) >> goto err; >> } >> - if (extra2 + length > e2end) >> + if ( extra2 + length > e2end) > revert > >> goto err; >> switch (type) { >> case EXTRA2_TABLEDEF_VERSION: >> @@ -1040,7 +1048,6 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, >> if (extra2 != e2end) >> goto err; >> } >> - > nope, revert > >> if (frm_length < FRM_HEADER_SIZE + len || >> !(pos= uint4korr(frm_image + FRM_HEADER_SIZE + len))) >> goto err; >> @@ -1671,7 +1678,8 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, >> if (!reg_field) // Not supported field type >> goto err; >> >> - >> + reg_field->field_visibility=(field_visible_type)*field_properties++; > please, add a feature status variable for it. search, for example, for > "feature_fulltext" or "feature_gis". Just as feature_gis, you can > increment your feature_hidden_column when a table with user-created hidden > columns is opened. done > better use c++ casts here, like > > static_cast (*field_properties++) > > won't look as multiplication :) > >> + reg_field->is_hash=(bool)*field_properties++; > you don't need a cast at all, but if you want to keep it, use C++ cast > >> reg_field->field_index= i; >> reg_field->comment=comment; >> reg_field->vcol_info= vcol_info; >> @@ -1985,6 +1993,10 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, >> if ((keyinfo->flags & HA_NOSAME) || >> (ha_option & HA_ANY_INDEX_MAY_BE_UNIQUE)) >> set_if_bigger(share->max_unique_length,keyinfo->key_length); >> + if(keyinfo->flags&HA_UNIQUE_HASH||keyinfo->flags&HA_INDEX_HASH) >> + { >> + keyinfo->ext_key_parts=1; > why? this is because consider the query create table t1 (a int primary key, b blob unique); then in mysql will add field a as keypart in second key_info and increase ext_key_part and if i do not do this the query like this insert into t1(1,1); insert into t1(2,1); will succeed > >> + } >> } >> if (primary_key < MAX_KEY && >> (share->keys_in_use.is_set(primary_key))) >> diff --git a/sql/unireg.h b/sql/unireg.h >> index 10751b6..211749a 100644 >> --- a/sql/unireg.h >> +++ b/sql/unireg.h >> @@ -186,7 +186,8 @@ enum extra2_frm_value_type { >> EXTRA2_TABLEDEF_VERSION=0, >> EXTRA2_DEFAULT_PART_ENGINE=1, >> EXTRA2_GIS=2, >> - >> + EXTRA2_FIELD_FLAGS=3, >> + EXTRA2_KEY_HASH_FLAG=4, > make it 129 and 130 > >> #define EXTRA2_ENGINE_IMPORTANT 128 >> >> EXTRA2_ENGINE_TABLEOPTS=128, >> diff --git a/sql/unireg.cc b/sql/unireg.cc >> index 66959f4..0d764a1 100644 >> --- a/sql/unireg.cc >> +++ b/sql/unireg.cc >> @@ -204,7 +224,8 @@ LEX_CUSTRING build_frm_image(THD *thd, const char *table, >> if (gis_extra2_len) >> extra2_size+= 1 + (gis_extra2_len > 255 ? 3 : 1) + gis_extra2_len; >> >> - >> + extra2_size+=1 + ( 2*create_fields.elements > 255 ? 3 : 1) + >> + 2*create_fields.elements;// first one for type(extra2_field_flags) next 2 for length > for backward compatibility it would make sense to add this > EXTRA2_FIELD_FLAGS data *only* if you have hidden fields. okay > >> key_buff_length= uint4korr(fileinfo+47); >> >> frm.length= FRM_HEADER_SIZE; // fileinfo; >> diff --git a/storage/maria/maria_def.h b/storage/maria/maria_def.h >> index 7337b01..3d0860f 100644 >> --- a/storage/maria/maria_def.h >> +++ b/storage/maria/maria_def.h >> @@ -895,7 +895,7 @@ struct st_maria_handler >> >> /* The UNIQUE check is done with a hashed long key */ >> >> -#define MARIA_UNIQUE_HASH_TYPE HA_KEYTYPE_ULONG_INT >> +#define MARIA_UNIQUE_hash_type HA_KEYTYPE_ULONG_INT > why? > reverted sorry >> #define maria_unique_store(A,B) mi_int4store((A),(B)) >> >> extern mysql_mutex_t THR_LOCK_maria; > > Regards, > Sergei > Chief Architect MariaDB > and security@mariadb.org
Hello Sergei! Please review commit 71f9069 onward i have changed mysql_prepare_alter_table func. Regards sachin On Sat, Aug 13, 2016 at 4:31 PM, sachin setiyawrote: > Hello sergei > > Please review the code > > Work left > > > 1 Where works on complex query including join , in , subquery but fails > in this query do not know why > > CREATE table t1 (a blob unique not null , b blob unique not null ); > select * from t1 where a=b; > > 2 Although alter works but thinking of changing the code so that it will > become less complex. > > 3 delete , update using where is optimized in complex case involving joins > subquery but normal case wont work > because they use function like sql_quick _select which i do not optimized > > 4 need to write test cases for update. > > 5 tried to make prototype for update problem > In this prototype what happenes is that when there is some dupp key tey > then it caches the record in stack , > and does this until some record insert is succeded then it checks succeded > record's old data to key stack last element > if it matches then we pop the stack and do update. update fails when there > is some element left in stack > prototype is on https://github.com/SachinSetiya/server/tree/up_proto_2 > it works on table like > create table t1 (a int unique , b int ); > insert into t1 values(1,1),(2,2),(3,3),(4,4); > update table t1 set a= a+1; > currently this works only for sorted key but can be worked for unsorted > key be sorting the records in stack with respect to key > to extend this to multiple keys we can use 1 key stack for each key > > > On 07/11/2016 11:41 PM, Sergei Golubchik wrote: > >> Hi, Sachin! >> >> Here's a review of your commits from >> b69e141a32 to 674eb4c4277. >> >> Last time I've reviewed up to b69e141a32, >> so next time I'll review from 674eb4c4277 and up. >> >> Thanks for your work! >> >> diff --git a/mysql-test/r/long_unique.result >>> b/mysql-test/r/long_unique.result >>> new file mode 100644 >>> index 0000000..fc6ff12 >>> --- /dev/null >>> +++ b/mysql-test/r/long_unique.result >>> @@ -0,0 +1,160 @@ >>> +create table z_1(abc blob unique); >>> +insert into z_1 values(112); >>> +insert into z_1 values('5666666666666666666666 >>> 666666666666666666666666666666666666666666666666666666666666 >>> 666666666666666666666666666666666666666666666666666666666666 >>> 666666666666666666666666666666666666666666666666666666666666 >>> 666666666666666666666666666666666666666666666666666666666666 >>> 666666666666666666666666666666'); >>> +insert into z_1 values('sachin'); >>> +insert into z_1 values('sachin'); >>> +ERROR 23000: Can't write; duplicate key in table 'z_1' >>> +select * from z_1; >>> +abc >>> +112 >>> +56666666666666666666666666666666666666666666666666666666666 >>> 666666666666666666666666666666666666666666666666666666666666 >>> 666666666666666666666666666666666666666666666666666666666666 >>> 666666666666666666666666666666666666666666666666666666666666 >>> 66666666666666666666666666666666666666666666666666666 >>> +sachin >>> +select db_row_hash_1 from z_1; >>> +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' >>> +desc z_1; >>> +Field Type Null Key Default Extra >>> +abc blob YES NULL >>> +select * from information_schema.columns where table_schema='mtr' and >>> table_name='z_1'; >>> +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME >>> ORDINAL_POSITION COLUMN_DEFAULT IS_NULLABLE DATA_TYPE >>> CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION >>> NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME >>> COLLATION_NAME COLUMN_TYPE COLUMN_KEY EXTRA PRIVILEGES >>> COLUMN_COMMENT >>> +create table tst_1(xyz blob unique , x2 blob unique); >>> +insert into tst_1 values(1,22); >>> +insert into tst_1 values(2,22); >>> +ERROR 23000: Can't write; duplicate key in table 'tst_1' >>> +select * from tst_1; >>> +xyz x2 >>> +1 22 >>> +select db_row_hash_1 from tst_1; >>> +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' >>> +select db_row_hash_2 from tst_1; >>> +ERROR 42S22: Unknown column 'db_row_hash_2' in 'field list' >>> +select db_row_hash_1,db_row_hash_2 from tst_1; >>> +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' >>> +desc tst_1; >>> +Field Type Null Key Default Extra >>> +xyz blob YES NULL >>> +x2 blob YES NULL >>> +select * from information_schema.columns where table_schema='mtr' and >>> table_name='tst_1'; >>> +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME >>> ORDINAL_POSITION COLUMN_DEFAULT IS_NULLABLE DATA_TYPE >>> CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION >>> NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME >>> COLLATION_NAME COLUMN_TYPE COLUMN_KEY EXTRA PRIVILEGES >>> COLUMN_COMMENT >>> +create table t1 (empnum smallint, grp int); >>> +create table t2 (empnum int, name char(5)); >>> +insert into t1 values(1,1); >>> +insert into t2 values(1,'bob'); >>> +create view v1 as select * from t2 inner join t1 using (empnum); >>> +select * from v1; >>> +empnum name grp >>> +1 bob 1 >>> >> what is this test for? (with t1, t2, v1) >> > Removed this is one of the test in inoodb which was failing so i added this > but now it is removed. > > >> +create table c_1(abc blob unique, db_row_hash_1 int unique); >>> +desc c_1; >>> +Field Type Null Key Default Extra >>> +abc blob YES NULL >>> +db_row_hash_1 int(11) YES UNI NULL >>> +insert into c_1 values(1,1); >>> +insert into c_1 values(1,2); >>> +ERROR 23000: Can't write; duplicate key in table 'c_1' >>> +create table c_2(abc blob unique,xyz blob unique, db_row_hash_2 >>> +int,db_row_hash_1 int unique); >>> +desc c_2; >>> +Field Type Null Key Default Extra >>> +abc blob YES NULL >>> +xyz blob YES NULL >>> +db_row_hash_2 int(11) YES NULL >>> +db_row_hash_1 int(11) YES UNI NULL >>> +insert into c_2 values(1,1,1,1); >>> +insert into c_2 values(1,23,4,5); >>> +ERROR 23000: Can't write; duplicate key in table 'c_2' >>> +create table u_1(abc int primary key , xyz blob unique); >>> +insert into u_1 values(1,2); >>> +insert into u_1 values(2,3); >>> +update u_1 set xyz=2 where abc=1; >>> +alter table z_1 drop db_row_hash_1; >>> +ERROR 42000: Can't DROP 'db_row_hash_1'; check that column/key exists >>> +alter table c_1 drop db_row_hash_2; >>> +ERROR 42000: Can't DROP 'db_row_hash_2'; check that column/key exists >>> +alter table c_1 drop db_row_hash_1; >>> +alter table z_1 add column db_row_hash_1 int unique; >>> +show create table z_1; >>> +Table Create Table >>> +z_1 CREATE TABLE `z_1` ( >>> + `abc` blob, >>> + `db_row_hash_1` int(11) DEFAULT NULL, >>> + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), >>> + UNIQUE KEY `abc`(`abc`) >>> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >>> +insert into z_1 values('sachin',1); >>> +ERROR 23000: Can't write; duplicate key in table 'z_1' >>> +alter table c_1 add column db_row_hash_2 int; >>> +show create table c_1; >>> +Table Create Table >>> +c_1 CREATE TABLE `c_1` ( >>> + `abc` blob, >>> + `db_row_hash_2` int(11) DEFAULT NULL, >>> + UNIQUE KEY `abc`(`abc`) >>> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >>> +alter table z_1 change db_row_hash_2 temp int; >>> +ERROR 42S22: Unknown column 'db_row_hash_2' in 'z_1' >>> +alter table c_1 change db_row_hash_3 temp int; >>> +ERROR 42S22: Unknown column 'db_row_hash_3' in 'c_1' >>> +alter table c_1 change db_row_hash_4 temp int; >>> +ERROR 42S22: Unknown column 'db_row_hash_4' in 'c_1' >>> +alter table c_2 change db_row_hash_1 temp int; >>> +create table c_3(abc blob unique, xyz blob); >>> +alter table c_3 add index(db_row_hash_1); >>> +ERROR 42000: Key column 'DB_ROW_HASH_1' doesn't exist in table >>> +create table i_1(x1 int ); >>> +alter table i_1 add column x2 blob unique; >>> +insert into i_1 value(1,1); >>> +insert into i_1 value(2,1); >>> +ERROR 23000: Can't write; duplicate key in table 'i_1' >>> +alter table i_1 drop index x2; >>> +insert into i_1 value(2,1); >>> +create table i_2(abc blob); >>> +insert into i_2 values(1); >>> +alter table i_2 add unique index(abc); >>> +select * from i_2; >>> +abc >>> +1 >>> +insert into i_2 values(22); >>> +insert into i_2 values(22); >>> +ERROR 23000: Can't write; duplicate key in table 'i_2' >>> +alter table i_2 drop key abc; >>> +insert into i_2 values(22); >>> +drop table i_2; >>> +create table i_2(abc blob); >>> +insert into i_2 values(1); >>> +alter table i_2 add constraint unique(abc); >>> +select * from i_2; >>> +abc >>> +1 >>> +insert into i_2 values(22); >>> +insert into i_2 values(22); >>> +ERROR 23000: Can't write; duplicate key in table 'i_2' >>> +alter table i_2 drop key abc; >>> +insert into i_2 values(22); >>> +create table di_1(abc blob , xyz int , index(abc,xyz)); >>> >> what is this test for? >> > Early it will create a long unique index but now it > will truncate > > >> +show create table di_1; >>> +Table Create Table >>> +di_1 CREATE TABLE `di_1` ( >>> + `abc` blob, >>> + `xyz` int(11) DEFAULT NULL, >>> + INDEX `abc_xyz`(`abc`,`xyz`) >>> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >>> +insert into di_1 values(1,1); >>> +insert into di_1 values(1,1); >>> +insert into di_1 values(2,1); >>> +create table di_2 (abc blob); >>> +insert into di_2 values(1); >>> +insert into di_2 values(1); >>> +alter table di_2 add index(abc); >>> +show create table di_2; >>> +Table Create Table >>> +di_2 CREATE TABLE `di_2` ( >>> + `abc` blob, >>> + INDEX `abc`(`abc`) >>> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >>> +insert into di_2 values(1); >>> +alter table di_2 drop index abc; >>> +show create table di_2; >>> +Table Create Table >>> +di_2 CREATE TABLE `di_2` ( >>> + `abc` blob >>> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >>> >> please add tests for the following: >> >> 1. blob with a couple of really long lines. like >> >> into t1 values(repeat('x', 500*1024*1024)); >> into t1 values(repeat('y', 500*1024*1024)); >> into t1 values(repeat('x', 500*1024*1024)); >> >> just don't do select * after that :) >> >> 2. TEXT, where collation matters and equal strings aren't always >> bytewise identical: >> >> create t1 (a TEXT CHARSET latin1 COLLATE latin1_german2_ci); >> >> insert t1 values ('ae'); >> insert t1 values ('AE'); >> insert t1 values ('Ä'); >> >> last two inserts must be an error (I suspect. If not sure, you can always >> test it as, for example, SELECT 'ae' = 'AE' COLLATE latin1_german2_ci; >> >> 3. multi-column constraints, like >> >> create t1 (a blob, b int, unique (a,b)); >> create t2 (a blob, b blob, unique (a,b)); >> create t3 (a varchar(2048), b varchar(2048), unique(a,b)); >> >> and also test inserts and errors with this multi-column constraints, >> not only create table statement. >> > Done > >> diff --git a/mysql-test/t/hidden_columns.test >>> b/mysql-test/t/hidden_columns.test >>> new file mode 100644 >>> index 0000000..f0fed41 >>> --- /dev/null >>> +++ b/mysql-test/t/hidden_columns.test >>> >> where's the hidden_columns.result? >> > sorry added > >> diff --git a/mysql-test/t/hidden_field.test >>> b/mysql-test/t/hidden_field.test >>> new file mode 100644 >>> index 0000000..3806a92 >>> --- /dev/null >>> +++ b/mysql-test/t/hidden_field.test >>> >> where's the hidden_field.result? >> how is it different from hidden_columns.test, why not to put all tests >> there? >> >> I mean the difference between "hidden column" and "hidden field" >> is really subtle. Either rename one of the test files or, >> combine them, or, I think, the best way would be to move tests from >> hidden_columns.test to long_unique.test >> > done and now there is only one file hidden_field > >> >> @@ -0,0 +1,35 @@ >>> +create table h_1(abc int primary key, xyz int hidden); >>> +create table h_2(a1 int hidden); >>> >> This, probably, should not be allowed. I mean, what 'SELECT * FROM h_2' >> will do? >> Let's return an error ER_TABLE_MUST_HAVE_COLUMNS in this case. >> > Done > >> >> +--error 1064 >>> >> try to use error names, not error numbers (see them in >> include/mysqld_error.h) >> > okay > > >> +create table h_3(a1 blob,hidden(a1)); >>> +--error 1981 >>> +create table h_4(a1 int primary key hidden ,a2 int unique hidden , a3 >>> blob,a4 >>> +int not null hidden unique); >>> +--error 1981 >>> +create table h_5(abc int not null hidden); >>> +# >>> +create table t1(abc int hidden); >>> +#should automatically add null >>> +insert into t1 values(); >>> +insert into t1 values(); >>> +insert into t1 values(); >>> +insert into t1 values(); >>> +--error 1096 >>> +select * from t1; >>> >> see, the error doesn't really fit here. 1096 is ER_NO_TABLES_USED, >> but the table is used here. Let's just disallow tables with no >> visible columns. >> >> +select abc from t1; >>> + >>> +create table t2(abc int primary key); >>> +insert into t2 values(); >>> +select * from t2; >>> +--error 1064 >>> +create table sdsdsd(a int , b int, hidden(a,b)); >>> + >>> +create table hid_4(a int,abc int as (a mod 3) virtual hidden); >>> +desc hid_4; >>> +create table ht_5(abc int primary key hidden auto_increment, a int); >>> +desc ht_5; >>> +insert into ht_5 values(1); >>> +insert into ht_5 values(2); >>> +insert into ht_5 values(3); >>> +select * from ht_5; >>> +select abc,a from ht_5; >>> >> if you'd have hidden_field.result you'd notice that this test >> doesn't clean up after itself :) >> >> diff --git a/mysql-test/t/long_unique.test b/mysql-test/t/long_unique.tes >>> t >>> new file mode 100644 >>> index 0000000..fc8bcf5 >>> --- /dev/null >>> +++ b/mysql-test/t/long_unique.test >>> @@ -0,0 +1,114 @@ >>> +create table z_1(abc blob unique); >>> +insert into z_1 values(112); >>> +insert into z_1 values('5666666666666666666666 >>> 666666666666666666666666666666666666666666666666666666666666 >>> 666666666666666666666666666666666666666666666666666666666666 >>> 666666666666666666666666666666666666666666666666666666666666 >>> 666666666666666666666666666666666666666666666666666666666666 >>> 666666666666666666666666666666'); >>> >> better use repeat() function in these cases. makes test cases smaller >> and more readable. >> > okay > >> >> +insert into z_1 values('sachin'); >>> +--error 1022 >>> +insert into z_1 values('sachin'); >>> +select * from z_1; >>> +--error 1054 >>> +select db_row_hash_1 from z_1; >>> +desc z_1; >>> +select * from information_schema.columns where table_schema='mtr' and >>> table_name='z_1'; >>> >> did you read results of your tests? wasn't it suspicious that >> this select returns nothing? it's because the table is in the 'test' >> schema, not in 'mtr'. Please, fix. >> > changed > > >> +create table tst_1(xyz blob unique , x2 blob unique); >>> +insert into tst_1 values(1,22); >>> +--error 1022 >>> +insert into tst_1 values(2,22); >>> +select * from tst_1; >>> +--error 1054 >>> +select db_row_hash_1 from tst_1; >>> +--error 1054 >>> +select db_row_hash_2 from tst_1; >>> +--error 1054 >>> +select db_row_hash_1,db_row_hash_2 from tst_1; >>> +desc tst_1; >>> +select * from information_schema.columns where table_schema='mtr' and >>> table_name='tst_1'; >>> >> same >> >> +create table t1 (empnum smallint, grp int); >>> +create table t2 (empnum int, name char(5)); >>> +insert into t1 values(1,1); >>> +insert into t2 values(1,'bob'); >>> +create view v1 as select * from t2 inner join t1 using (empnum); >>> +select * from v1; >>> >> what was the point of this t1/t2/v1 test? >> >> +#test on create table with column db_row_hash >>> +create table c_1(abc blob unique, db_row_hash_1 int unique); >>> +desc c_1; >>> +insert into c_1 values(1,1); >>> +--error 1022 >>> +insert into c_1 values(1,2); >>> +create table c_2(abc blob unique,xyz blob unique, db_row_hash_2 >>> +int,db_row_hash_1 int unique); >>> +desc c_2; >>> +insert into c_2 values(1,1,1,1); >>> +--error 1022 >>> +insert into c_2 values(1,23,4,5); >>> +#update table >>> +create table u_1(abc int primary key , xyz blob unique); >>> +insert into u_1 values(1,2); >>> +insert into u_1 values(2,3); >>> +update u_1 set xyz=2 where abc=1; >>> >> this updates the row to itw old values. test the update to new values. >> to non-duplicate and to duplicate values. >> >> +#alter table drop column >>> +--error 1091 >>> +alter table z_1 drop db_row_hash_1; >>> +--error 1091 >>> +alter table c_1 drop db_row_hash_2; >>> +alter table c_1 drop db_row_hash_1; >>> +#add column >>> +alter table z_1 add column db_row_hash_1 int unique; >>> +show create table z_1; >>> +#insert should not break >>> +--error 1022 >>> +insert into z_1 values('sachin',1); >>> >> good >> >> +alter table c_1 add column db_row_hash_2 int; >>> >> test also adding and removing unique index for blobs. >> 1. adding when a column has no duplicates >> 2. adding when a column has duplicates >> 3. adding when a column has duplicates and IGNORE clause was used >> >> +show create table c_1; >>> +#modify db_row_hash >>> +--error 1054 >>> +alter table z_1 change db_row_hash_2 temp int; >>> +--error 1054 >>> +alter table c_1 change db_row_hash_3 temp int; >>> +--error 1054 >>> +alter table c_1 change db_row_hash_4 temp int; >>> +alter table c_2 change db_row_hash_1 temp int; >>> +# now try to index db_row_hash >>> +create table c_3(abc blob unique, xyz blob); >>> +--error 1072 >>> +alter table c_3 add index(db_row_hash_1); >>> +create table i_1(x1 int ); >>> +alter table i_1 add column x2 blob unique; >>> +insert into i_1 value(1,1); >>> +--error 1022 >>> +insert into i_1 value(2,1); >>> +alter table i_1 drop index x2; >>> +insert into i_1 value(2,1); >>> +create table i_2(abc blob); >>> +insert into i_2 values(1); >>> +alter table i_2 add unique index(abc); >>> +select * from i_2; >>> +insert into i_2 values(22); >>> +--error 1022 >>> +insert into i_2 values(22); >>> +alter table i_2 drop key abc; >>> +insert into i_2 values(22); >>> +drop table i_2; >>> +create table i_2(abc blob); >>> +insert into i_2 values(1); >>> +alter table i_2 add constraint unique(abc); >>> +select * from i_2; >>> +insert into i_2 values(22); >>> +--error 1022 >>> +insert into i_2 values(22); >>> +alter table i_2 drop key abc; >>> +insert into i_2 values(22); >>> +# now some indexes on blob these should allow >>> +# duplicates these will be used in where clause >>> +create table di_1(abc blob , xyz int , index(abc,xyz)); >>> +show create table di_1; >>> +insert into di_1 values(1,1); >>> +insert into di_1 values(1,1); >>> +insert into di_1 values(2,1); >>> +create table di_2 (abc blob); >>> +insert into di_2 values(1); >>> +insert into di_2 values(1); >>> +alter table di_2 add index(abc); >>> >> what kind of index is used here? should be a normal index, >> no hash, no hidden db_row_hash_1 column, just a normal b-tree index. >> >> +show create table di_2; >>> +insert into di_2 values(1); >>> +alter table di_2 drop index abc; >>> +show create table di_2; >>> >> you never clean up in these tests. see other - existing - test files, >> they always drop all created tables and views, so that when the test >> end all databases look exactly as before the test started. >> >> diff --git a/include/my_base.h b/include/my_base.h >>> index 8b546ed..d5c697b 100644 >>> --- a/include/my_base.h >>> +++ b/include/my_base.h >>> @@ -250,6 +250,8 @@ enum ha_base_keytype { >>> #define HA_NOSAME 1 /* Set if not dupplicated >>> records */ >>> #define HA_PACK_KEY 2 /* Pack string key to previous >>> key */ >>> +#define HA_INDEX_HASH 4 /* */ >>> >> you don't need HA_INDEX_HASH. See above, non-unique index on blobs >> should be just a normal b-tree index, no hash, subject to automatic >> key truncation, see sql_table.cc around the line with the comment >> /* not a critical problem */ >> > removed > >> +#define HA_UNIQUE_HASH 8 >>> >> as you've found out already, there two bits are not free >> >> #define HA_AUTO_KEY 16 >>> #define HA_BINARY_PACK_KEY 32 /* Packing of all keys to prev >>> key */ >>> #define HA_FULLTEXT 128 /* For full-text search */ >>> diff --git a/sql/field.h b/sql/field.h >>> index 08905f2..2e6e0e4 100644 >>> --- a/sql/field.h >>> +++ b/sql/field.h >>> @@ -628,6 +628,8 @@ class Field: public Value_source >>> @c NOT @c NULL field, this member is @c NULL. >>> */ >>> uchar *null_ptr; >>> + field_visible_type field_visibility=NORMAL; >>> + bool is_hash=false; >>> >> please add a comment for is_hash or rename it to something that is >> self-explanatory. field_visibility, for example, is self-explanatory. >> > okay > >> /* >>> Note that you can use table->in_use as replacement for current_thd >>> member >>> only inside of val_*() and store() members (e.g. you can't use it >>> in cons) >>> @@ -3051,6 +3052,10 @@ class Field_blob :public Field_longstr { >>> inline uint32 get_length(uint row_offset= 0) >>> { return get_length(ptr+row_offset, this->packlength); } >>> uint32 get_length(const uchar *ptr, uint packlength); >>> + uint32 data_length(int row_offset=0) >>> + { >>> + return get_length(row_offset); >>> + } >>> >> Huh? >> There was no Field_blob::data_length(), it was using the parent >> implementation Field::data_length(). That was returning pack_length(), >> that is Field_blob::pack_length(), which is simply packlength + >> portable_sizeof_char_ptr >> Now you've defined Field_blob::data_length() to return get_length(0). >> That is, you've changed the meaning of Field_blob::data_length(). >> Is that ok? Was old Field_blob::data_length() never used? >> > Reverted actually i used this in earlier code but now no longer use this > function > >> >> uint32 get_length(const uchar *ptr_arg) >>> { return get_length(ptr_arg, this->packlength); } >>> inline void get_ptr(uchar **str) >>> @@ -3455,6 +3460,8 @@ class Create_field :public Sql_alloc >>> max number of characters. >>> */ >>> ulonglong length; >>> + field_visible_type field_visibility=NORMAL; >>> + bool is_hash=false; >>> >> don't do that. gcc complains >> >> warning: non-static data member initializers only available with >> -std=c++11 or -std=gnu++11 >> >> and we don't use c++11 yet, because some of our compilers in buildbot >> don't support it. >> > done > > /* >>> The value of `length' as set by parser: is the number of characters >>> for most of the types, or of bytes for BLOBs or numeric types. >>> diff --git a/sql/handler.cc b/sql/handler.cc >>> index 49e451e..e7d7815 100644 >>> --- a/sql/handler.cc >>> +++ b/sql/handler.cc >>> @@ -5864,16 +5864,60 @@ int handler::ha_reset() >>> DBUG_RETURN(reset()); >>> } >>> - >>> +/** @brief >>> + Compare two records >>> + It requires both records to be present in table->record[0] >>> + and table->record[1] >>> + @returns true if equal else false >>> + */ >>> +bool rec_hash_cmp(uchar *first_rec, uchar *sec_rec, Field *hash_field) >>> +{ >>> + Item_args * t_item=(Item_args *)hash_field->vcol_info->expr_item; >>> + int arg_count = t_item->argument_count(); >>> + Item ** arguments=t_item->arguments(); >>> + int diff = sec_rec-first_rec; >>> + Field * t_field; >>> + for(int i=0;i >> + { >>> + t_field = ((Item_field *)arguments[i])->field;//need a debug assert >>> + if(t_field->cmp_binary_offset(diff)) >>> + return false; >>> + } >>> + return true; >>> +} >>> >> 1. please format the code like it's done elsewhere in the file. >> - in assignments: no space before '=', one space after >> - after a function/method must be one or two empty lines >> - in if/for/while: a space between the keyword and a parenthesys >> - in for() loop - a space after a semicolon >> - in function arguments - a space after a comma >> - not in the function above, but everywhere in your patch >> >> 2. it's better to avoid type conversion where it's not needed, for >> example, t_item->argument_count() returns uint, so your arg_count should >> be of that type too. >> >> 3. either write a completely generic function that compares two records >> given as pointers, or write a function that compares record[0] and >> record[1]. >> Ok, it looks you need to compare a record as a pointer with record[0]. >> Then remove first_rec, it only creates a false pretence that a function >> is more generic than it is. >> Instead, do >> >> int diff= sec_rec - hash_field->table->record[0]; >> >> (and, may be, rename sec_rec to "other_rec") >> >> 4. what do you mean "need a debug assert"? if you need it, add it :) >> if you want to add a debug assert, but don't know how - please, ask. >> >> int handler::ha_write_row(uchar *buf) >>> { >>> - int error; >>> + int error,result; >>> Log_func *log_func= Write_rows_log_event::binlog_r >>> ow_logging_function; >>> + Field *field_iter; >>> DBUG_ASSERT(table_share->tmp_table != NO_TMP_TABLE || >>> m_lock_type == F_WRLCK); >>> DBUG_ENTER("handler::ha_write_row"); >>> DEBUG_SYNC_C("ha_write_row_start"); >>> - >>> + /* First need to whether inserted record is unique or not */ >>> + /* One More Thing if i implement hidden field then detection can be >>> easy */ >>> >> this second comment is probably obsolete, you can remove it >> >> + for(uint i=0;i s->keys;i++) >>> + { >>> + if(table->key_info[i].flags&HA_UNIQUE_HASH) >>> >> in fact, you don't need a special key flag. you can check, like >> >> if (table->key_info[i].key_part->field->is_hash) >> >> but a flag makes it kinda simpler, so if you like the flag, go ahead and >> use it (if you find an free bit for it). Perhaps, even, you can use the >> key flag and remove Field::is_hash? The field does not need any special >> treatment, does it? it only needs to be hidden. >> >> + { >>> + field_iter=table->key_info[i].key_part->field; >>> >> why did you name it "field_iter"? it's not an iterator. may be >> "hash_field"? >> >> + int len =table->key_info[i].key_length; >>> + uchar ptr[len]; >>> >> we compile with -Wvla, so this will be a warning too. Just use >> ptr[9], for example. And add DBUG_ASSERT(len < sizeof(ptr)); >> >> + if(field_iter->is_null()) >>> + { >>> + goto write_row; >>> >> no goto here, just break; >> >> + } >>> + key_copy(ptr,buf,&table->key_info[i],len,false); >>> + result= table->file->ha_index_read_idx >>> _map(table->record[1],i,ptr, >>> + HA_WHOLE_KEY,HA_READ_KEY_EXACT); >>> + if(!result) >>> + { >>> + if(rec_hash_cmp(table->record[0],table->record[1],field_iter)) >>> + DBUG_RETURN(HA_ERR_FOUND_DUPP_KEY); >>> + } >>> + } >>> + } >>> + write_row: >>> >> and no label here >> >> MYSQL_INSERT_ROW_START(table_share->db.str, >>> table_share->table_name.str); >>> mark_trx_read_write(); >>> increment_statistics(&SSV::ha_write_count); >>> @@ -5907,6 +5952,36 @@ int handler::ha_update_row(const uchar *old_data, >>> uchar *new_data) >>> DBUG_ASSERT(new_data == table->record[0]); >>> DBUG_ASSERT(old_data == table->record[1]); >>> + /* First need to whether inserted record is unique or not */ >>> + /* One More Thing if i implement hidden field then detection can be >>> easy */ >>> + for(uint i=0;i s->keys;i++) >>> + { >>> + if(table->key_info[i].flags&HA_UNIQUE_HASH) >>> + { >>> + /* >>> + We need to add the null bit >>> + If the column can be NULL, then in the first byte we put 1 if >>> the >>> + field value is NULL, 0 otherwise. >>> + */ >>> + uchar *new_rec = (uchar *)alloc_root(&table->mem_root, >>> + table->s->reclength*sizeof(uc >>> har)); >>> >> do you know how alloc_root works? read include/mysql/service_thd_alloc.h >> memory allocated with alloc_root() can not be freed individually, it is >> freed when the complete MEM_ROOT is reset or destroyed. >> so, three problems here: >> 1. you allocate memory on MEM_ROOT in a loop. so, if the table has, say >> three HA_UNIQUE_HASH keys, you'll allocate the buffer three times, while >> one should've been totally sufficient >> 2. you allocate for every row that is inserted >> 3. you allocate it on the *TABLE::mem_root*. Table's memroot is freed >> only when a table is closed! >> >> So, if you create a table with three unique(blob) keys, and insert >> four rows in one statement: INSERT ... VALUES (),(),(),(),(). And >> repeat this insert five times, you'll allocate 3*4*5=60 reclength bytes. >> They'll not be freed, so if you repeat this insert five more times, it'll >> be 60 reclength more bytes. And so on :) >> >> I think the good approach would be to have, like TABLE::check_unique_buf >> row buffer. See that TABLE has now: >> >> uchar *record[2]; /* Pointer to records */ >> uchar *write_row_record; /* Used as optimisation in >> THD::write_row */ >> uchar *insert_values; /* used by INSERT ... UPDATE */ >> >> that's where you add uchar *check_unique_buf; >> it's initialized to 0. and on the first use you do, like >> >> if (!table->check_unique_buf) >> table->check_unique_buf= alloc_root(&table->mem_root, ...) >> >> and then you can freely use it for checking your unique constraints. >> it'll be allocated only once per TABLE. >> > done > >> >> + field_iter=table->key_info[i].key_part->field; >>> + uchar ptr[9]; >>> >> better #define UNIQ_HASH_KEY_LEN 9 and use it everywhere >> >> + if(field_iter->is_null()) >>> + { >>> + goto write_row; >>> + } >>> + key_copy(ptr,new_data,&table->key_info[i],9,false); >>> + result= table->file->ha_index_read_idx_map(new_rec,i,ptr, >>> + HA_WHOLE_KEY,HA_READ_KEY_EXACT); >>> + if(!result) >>> + { >>> + if(rec_hash_cmp(table->record[0],new_rec,field_iter)) >>> + return HA_ERR_FOUND_DUPP_KEY; >>> + } >>> + } >>> + } >>> + write_row: >>> >> this is the same code as in handler::ha_write_row, please combine them >> into one function (for simplicity you can use table->check_unique_buf also >> for INSERT) >> > done > > >> MYSQL_UPDATE_ROW_START(table_share->db.str, >>> table_share->table_name.str); >>> mark_trx_read_write(); >>> increment_statistics(&SSV::ha_update_count); >>> diff --git a/sql/item.cc b/sql/item.cc >>> index adf7031..2015752 100644 >>> --- a/sql/item.cc >>> +++ b/sql/item.cc >>> @@ -5059,7 +5059,13 @@ bool Item_field::fix_fields(THD *thd, Item >>> **reference) >>> } >>> else if (!from_field) >>> goto error; >>> - >>> + if(from_field->field_visibility==FULL_HIDDEN) >>> + { >>> + my_error(ER_BAD_FIELD_ERROR, MYF(0), (* reference)->full_name(), >>> + thd->where); >>> + from_field=NULL; >>> + goto error; >>> + } >>> >> So, you're patching the "search for field by name" process, pretending >> that the field does not exist if it's FULL_HIDDEN. This is, of course, >> correct. But I suspect you're doing it too late. Consider this case: >> >> create table t1 (b blob, unique (b)); >> create table t2 (db_row_hash_1 int, a int); >> >> select * from t1, t2 where db_row_hash_1=5; >> >> in this case, mariadb needs to search for db_row_hash_1 field in t1, >> should not find it, continue searching in t2, find it there. >> in your code it will find it in t1, and later reject it with >> ER_BAD_FIELD_ERROR. >> >> there may be more complex cases, with subqueries and outer selects, >> views, etc. important part is - you need to reject FULL_HIDDEN field >> immediately when it's found, so that the search could continue in other >> tables, outer selects, etc. >> >> btw, don't forget to add tests for this behavior (one table or outer >> select has db_row_hash_1 visible field, another table has db_row_hash_1 >> FULL_HIDDEN field). >> > done > > table_list= (cached_table ? cached_table : >>> from_field != view_ref_found ? >>> from_field->table->pos_in_table_list : 0); >>> diff --git a/sql/item_func.cc b/sql/item_func.cc >>> index 6edb276..889ac40 100644 >>> --- a/sql/item_func.cc >>> +++ b/sql/item_func.cc >>> @@ -1916,6 +1916,37 @@ void Item_func_int_div::fix_length_and_dec() >>> } >>> +longlong Item_func_hash::val_int() >>> +{ >>> + unsigned_flag= true; >>> + ulong nr1= 1,nr2= 4; >>> + CHARSET_INFO *cs; >>> + for(uint i= 0;i >> + { >>> + String * str = args[i]->val_str(); >>> + if(args[i]->null_value) >>> + { >>> + null_value= 1; >>> + return 0; >>> + } >>> + cs= str->charset(); >>> + uchar l[4]; >>> + int4store(l,str->length()); >>> + cs->coll->hash_sort(cs,l,sizeof(l), &nr1, &nr2); >>> >> looks good, but use my_charset_binary for the length. >> > did not get it :( > > >> + cs->coll->hash_sort(cs, (uchar *)str->ptr(), str->length(), &nr1, >>> &nr2); >>> + } >>> + return (longlong)nr1; >>> +} >>> + >>> + >>> +void Item_func_hash::fix_length_and_dec() >>> +{ >>> + maybe_null= 1; >>> + decimals= 0; >>> + max_length= 8; >>> +} >>> + >>> + >>> longlong Item_func_mod::int_op() >>> { >>> DBUG_ASSERT(fixed == 1); >>> diff --git a/sql/lex.h b/sql/lex.h >>> index 22ff4e6..d7a4e14 100644 >>> --- a/sql/lex.h >>> +++ b/sql/lex.h >>> @@ -266,6 +266,7 @@ static SYMBOL symbols[] = { >>> { "HAVING", SYM(HAVING)}, >>> { "HELP", SYM(HELP_SYM)}, >>> { "HIGH_PRIORITY", SYM(HIGH_PRIORITY)}, >>> + {"HIDDEN", SYM(HIDDEN)}, >>> >> spacing! align it as all other rows are >> >> { "HOST", SYM(HOST_SYM)}, >>> { "HOSTS", SYM(HOSTS_SYM)}, >>> { "HOUR", SYM(HOUR_SYM)}, >>> diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt >>> index 709ac55..9ae3ac6 100644 >>> --- a/sql/share/errmsg-utf8.txt >>> +++ b/sql/share/errmsg-utf8.txt >>> @@ -7139,3 +7139,5 @@ ER_KILL_QUERY_DENIED_ERROR >>> ER_NO_EIS_FOR_FIELD >>> eng "Engine-independent statistics are not collected for >>> column '%s'" >>> ukr "Незалежна від типу таблиці статистика не збирається для >>> стовбця '%s'" >>> +ER_HIDDEN_NOT_NULL_WOUT_DEFAULT >>> + eng "Hidden column '%s' either allow null values or it must >>> have default value" >>> >> when you'll merge with 10.2 make sure this your new error will >> end up at the very end, after ER_EXPRESSION_REFERS_TO_UNINIT_FIELD >> >> diff --git a/sql/sql_class.h b/sql/sql_class.h >>> index 8bfc243..bb206a8 100644 >>> --- a/sql/sql_class.h >>> +++ b/sql/sql_class.h >>> @@ -297,7 +297,7 @@ class Key :public Sql_alloc, public DDL_options { >>> LEX_STRING name; >>> engine_option_value *option_list; >>> bool generated; >>> - >>> + key_hash_type hash_type=NOT_HASH; >>> >> same as above about c++11 >> >> Key(enum Keytype type_par, const LEX_STRING &name_arg, >>> ha_key_alg algorithm_arg, bool generated_arg, DDL_options_st >>> ddl_options) >>> :DDL_options(ddl_options), >>> diff --git a/sql/sql_base.cc b/sql/sql_base.cc >>> index e808fba..b2c8dfb 100644 >>> --- a/sql/sql_base.cc >>> +++ b/sql/sql_base.cc >>> @@ -8343,6 +8343,8 @@ insert_fields(THD *thd, Name_resolution_context >>> *context, const char *db_name, >>> for (; !field_iterator.end_of_fields(); field_iterator.next()) >>> { >>> + if(field_iterator.field()==NULL || >>> >> eh... can it be NULL here, really? >> > i do not there was a test in innodb which was failing because of this > anyway changed the whole code > >> >> + field_iterator.field()->field_visibility==NORMAL){ >>> Item *item; >>> if (!(item= field_iterator.create_item(thd))) >>> diff --git a/sql/sql_insert.cc b/sql/sql_insert.cc >>> index fcf8c14..2bfb288 100644 >>> --- a/sql/sql_insert.cc >>> +++ b/sql/sql_insert.cc >>> @@ -723,7 +722,24 @@ bool mysql_insert(THD *thd,TABLE_LIST *table_list, >>> if (open_and_lock_tables(thd, table_list, TRUE, 0)) >>> DBUG_RETURN(TRUE); >>> } >>> - >>> + >>> + context= &thd->lex->select_lex.context; >>> + if(table_list->table!=NULL) >>> >> can table_list->table be NULL here? >> > same a test in innodb was failing but now i do not use his logic > >> >> + { >>> + Field ** f=table_list->table->field; >>> + List - * i_list = (List
- *)values_list.first_node()->info; >>> + for(uint i=0;i
table->s->fields;i++) >>> + { >>> + if((*f)->is_hash ||(*f)->field_visibility==USER_DEFINED_HIDDEN) >>> + { >>> + i_list->push_front(new (thd->mem_root) >>> + Item_default_value(thd,context),thd->mem_root); >>> + } >>> + f++; >>> + } >>> + } >>> + List_iterator_fast its(values_list); >>> + >>> >> is that needed at all? one can always do INSERT t1 (a) VALUES (1) >> and all non-specified fields will get default values. without >> specifically adding Item_default_value to the list. So, it seems, that >> hidden fields will automatically get default values too. >> >> changed > > lock_type= table_list->lock_type; >>> THD_STAGE_INFO(thd, stage_init); >>> diff --git a/sql/sql_show.cc b/sql/sql_show.cc >>> index 1cbad7e..60e586c 100644 >>> --- a/sql/sql_show.cc >>> +++ b/sql/sql_show.cc >>> @@ -1932,6 +1931,26 @@ int show_create_table(THD *thd, TABLE_LIST >>> *table_list, String *packet, >>> } >>> append_create_options(thd, packet, field->option_list, >>> check_options, >>> hton->field_options); >>> + //TODO need a better logic to find wheter to put comma or not >>> + int i=1; >>> + bool is_comma_needed=false; >>> + if (*(ptr+i)!=NULL) >>> + { >>> + is_comma_needed=true; >>> + while((*(ptr+i))->field_visibility==MEDIUM_HIDDEN || >>> + (*(ptr+i))->field_visibility==FULL_HIDDEN) >>> + { >>> + i++; >>> + is_comma_needed=true; >>> + if(!*(ptr+i)) >>> + { >>> + is_comma_needed =false; >>> + break; >>> + } >>> + } >>> + } >>> + if(is_comma_needed) >>> + packet->append(STRING_WITH_LEN(",\n")); >>> >> agree about "better logic". You can do it like this: >> >> bool is_comma_needed= false; >> for (ptr=table->field ; (field= *ptr); ptr++) >> { >> if (is_comma_needed) >> packet->append(STRING_WITH_LEN(",\n")); >> is_comma_needed= false; >> ... >> print field >> is_comma_needed= true; >> } >> >> but this wont work because i need to put comma only when > there is remaning field but atleast one of then is non hidden so i have to > use > while > >> } >>> key_info= table->key_info; >>> @@ -1946,6 +1965,22 @@ int show_create_table(THD *thd, TABLE_LIST >>> *table_list, String *packet, >>> for (uint i=0 ; i < share->keys ; i++,key_info++) >>> { >>> KEY_PART_INFO *key_part= key_info->key_part; >>> + if(key_info->flags&HA_UNIQUE_HASH||key_info->flags&HA_INDEX_HASH) >>> >> code formatting. spaces! >> > changed > >> + { >>> + char * column_names= key_part->field->vcol_info-> >>> + expr_str.str+strlen("hash"); >>> + int length=key_part->field->vcol_info->expr_str.length; >>> + length-=strlen("hash"); >>> + packet->append(STRING_WITH_LEN(",\n")); >>> + if(key_info->flags&HA_INDEX_HASH) >>> + packet->append(STRING_WITH_LEN(" INDEX `")); >>> + else >>> + packet->append(STRING_WITH_LEN(" UNIQUE KEY `")); >>> + packet->append(key_info->name,strlen(key_info->name)); >>> + packet->append(STRING_WITH_LEN("`")); >>> + packet->append(column_names,length); >>> >> I don't like that ±strlen("hash"). Better do it like this: >> >> static LEX_CSTRING uniq_hash_func={ STRING_WITH_LEN("hash" }; >> >> and instead of strlen("hash") you use uniq_hash_func.length, >> and below instead of explicit "hash" string in the >> mysql_prepare_create_table >> you use uniq_hash_func.str. >> > done > but instead of > > static LEX_CSTRING uniq_hash_func={ STRING_WITH_LEN("hash" }; > > i have define macro in my_base.h > > + continue; >>> + } >>> bool found_primary=0; >>> packet->append(STRING_WITH_LEN(",\n ")); >>> @@ -5416,6 +5454,22 @@ static int get_schema_column_record(THD *thd, >>> TABLE_LIST *tables, >>> else >>> table->field[17]->store(STRING_WITH_LEN("VIRTUAL"), cs); >>> } >>> + /*hidden can coexist with auto_increment and virtual */ >>> + if(field->field_visibility==USER_DEFINED_HIDDEN) >>> + { >>> + table->field[17]->store(STRING_WITH_LEN("HIDDEN"), cs); >>> + if (field->unireg_check == Field::NEXT_NUMBER) >>> + table->field[17]->store(STRING_WITH_LEN("auto_increment , >>> HIDDEN"), cs); >>> + if (print_on_update_clause(field, &type, true)) >>> + table->field[17]->store(type.ptr(), type.length(), cs); >>> + if (field->vcol_info) >>> + { >>> + if (field->stored_in_db) >>> + table->field[17]->store(STRING_WITH_LEN("PERSISTENT, >>> HIDDEN"), cs); >>> + else >>> + table->field[17]->store(STRING_WITH_LEN("VIRTUAL, HIDDEN"), >>> cs); >>> + } >>> + } >>> >> eh, please no. don't duplicate the whole block. A variant that avoids it: >> >> StringBuffer<256> buf; >> >> if (autoinc) // this is pseudocode, see the correct condition is in the >> code above >> buf.set(STRING_WITH_LEN("auto_increment")) >> else if (virtual) >> buf.set(STRING_WITH_LEN("VIRTUAL"); >> ... >> >> if (hidden) >> { >> if (buf.length) >> buf.append(STRING_WITH_LEN(", ")); >> buf.append(STRING_WITH_LEN("HIDDEN")); >> } >> table->field[17]->store(buf.ptr(), buf.length(), cs); >> > changed > >> table->field[19]->store(field->comment.str, field->comment.length, >>> cs); >>> if (schema_table_store_record(thd, table)) >>> DBUG_RETURN(1); >>> diff --git a/sql/sql_table.cc b/sql/sql_table.cc >>> index dae3b7a..d9322ca 100644 >>> --- a/sql/sql_table.cc >>> +++ b/sql/sql_table.cc >>> @@ -3013,7 +3013,7 @@ int prepare_create_field(Create_field *sql_field, >>> break; >>> } >>> if (!(sql_field->flags & NOT_NULL_FLAG) || >>> - (sql_field->vcol_info)) /* Make virtual columns allow NULL >>> values */ >>> + (sql_field->vcol_info)) >>> >> why did you remove this comment? >> >> reverted > > sql_field->pack_flag|= FIELDFLAG_MAYBE_NULL; >>> if (sql_field->flags & NO_DEFAULT_VALUE_FLAG) >>> sql_field->pack_flag|= FIELDFLAG_NO_DEFAULT; >>> @@ -3223,6 +3222,130 @@ mysql_prepare_create_table(THD *thd, >>> HA_CREATE_INFO *create_info, >>> bool tmp_table= create_table_mode == C_ALTER_TABLE; >>> DBUG_ENTER("mysql_prepare_create_table"); >>> + /* >>> + scan the the whole alter list >>> + and add one field if length of blob is zero >>> + TODO change to work for all too-long unique keys like varchar,text >>> + */ >>> + >>> + List_iterator key_iter(alter_info->key_list); >>> + Key *key_iter_key; >>> + Key_part_spec *temp_colms; >>> + int num= 1; >>> + bool is_long_unique=false; >>> + int key_initial_elements=alter_info->key_list.elements; >>> + while((key_iter_key=key_iter++)&&key_initial_elements) >>> + { >>> + key_initial_elements--; >>> + List_iterator key_part_iter(key_iter_key->columns); >>> + while((temp_colms=key_part_iter++)) >>> + { >>> + while ((sql_field=it++) &&sql_field&& >>> my_strcasecmp(system_charset_info, >>> + >>> temp_colms->field_name.str, >>> + >>> sql_field->field_name)){} >>> + if(sql_field && (sql_field->sql_type==MYSQL_TYPE_BLOB || >>> + sql_field->sql_type==MYSQL_TYPE_MEDIUM_BLOB|| >>> + sql_field->sql_type==MYSQL_TYPE_LONG_BLOB) >>> + &&temp_colms->length==0) >>> + { >>> + is_long_unique=true; >>> + /* >>> + One long key unique in enough >>> + */ >>> + it.rewind(); >>> + break; >>> + } >>> + // if(sql_field->sql_type==MYSQL_TYPE_VARCHAR) >>> + it.rewind(); >>> + } >>> + if(is_long_unique) >>> + { >>> + /* make a virtual field */ >>> + key_part_iter.rewind(); >>> + Create_field *cf = new (thd->mem_root) Create_field(); >>> + cf->flags|=UNSIGNED_FLAG; >>> + cf->length=cf->char_length=8; >>> + cf->charset=NULL; >>> + cf->decimals=0; >>> + char temp_name[30]; >>> + strcpy(temp_name,"DB_ROW_HASH_"); >>> + char num_holder[10]; //10 is way more but i think it is ok >>> + sprintf(num_holder,"%d",num); >>> + strcat(temp_name,num_holder); >>> + /* >>> + Check for collusions >>> + */ >>> + while((dup_field=it++)) >>> + { >>> + if(!my_strcasecmp(system_charset_info,temp_name,dup_field-> >>> field_name)) >>> + { >>> + temp_name[12]='\0'; //now temp_name='DB_ROW_HASH_' >>> + num++; >>> + sprintf(num_holder,"%d",num); >>> + strcat(temp_name,num_holder); >>> + it.rewind(); >>> + } >>> + } >>> + it.rewind(); >>> + char * name = (char *)thd->alloc(30); >>> + strcpy(name,temp_name); >>> + cf->field_name=name; >>> + cf->stored_in_db=true; >>> + cf->sql_type=MYSQL_TYPE_LONGLONG; >>> + /* hash column should be atmost hidden */ >>> + cf->field_visibility=FULL_HIDDEN; >>> + if(key_iter_key->type==Key::UNIQUE) >>> + key_iter_key->hash_type=UNIQUE_HASH; >>> + else >>> + key_iter_key->hash_type=INDEX_HASH; >>> + cf->is_hash=true; >>> + /* add the virtual colmn info */ >>> + Virtual_column_info *v= new (thd->mem_root) Virtual_column_info(); >>> + char * hash_exp=(char *)thd->alloc(252); >>> + char * key_name=(char *)thd->alloc(252); >>> + strcpy(hash_exp,"hash(`"); >>> + temp_colms=key_part_iter++; >>> + strcat(hash_exp,temp_colms->field_name.str); >>> + strcpy(key_name,temp_colms->field_name.str); >>> + strcat(hash_exp,"`"); >>> + while((temp_colms=key_part_iter++)){ >>> + strcat(hash_exp,(const char * )","); >>> + strcat(key_name,"_"); >>> + strcat(hash_exp,"`"); >>> + strcat(hash_exp,temp_colms->field_name.str); >>> + strcat(key_name,temp_colms->field_name.str); >>> + strcat(hash_exp,"`"); >>> + } >>> + strcat(hash_exp,(const char * )")"); >>> + v->expr_str.str= hash_exp; >>> + v->expr_str.length= strlen(hash_exp); >>> + v->expr_item= NULL; >>> + v->set_stored_in_db_flag(true); >>> + cf->vcol_info=v; >>> + alter_info->create_list.push_front(cf,thd->mem_root); >>> + /* >>> + Now create the key field kind >>> + of harder then prevoius one i guess >>> + */ >>> + key_iter_key->type=Key::MULTIPLE; >>> + key_iter_key->columns.delete_elements(); >>> + LEX_STRING *ls =(LEX_STRING *)thd->alloc(sizeof(LEX_STRING)) ; >>> + ls->str=(char *)sql_field->field_name; >>> + ls->length =strlen(sql_field->field_name); >>> + if(key_iter_key->name.length==0) >>> + { >>> + LEX_STRING *ls_name =(LEX_STRING *)thd->alloc(sizeof(LEX_STRING)) >>> ; >>> + ls_name->str=key_name; >>> + ls_name->length=strlen(key_name); >>> + key_iter_key->name= *ls_name; >>> + } >>> + key_iter_key->columns.push_back(new (thd->mem_root) >>> Key_part_spec(name, >>> + strlen(name), >>> 0),thd->mem_root); >>> + >>> + } >>> + is_long_unique=false; >>> + } >>> + it.rewind(); >>> >> why are you doing it here, in a separate loop, insead of doing it where >> ER_TOO_LONG_KEY is issued? >> > changed > >> >> select_field_pos= alter_info->create_list.elements - >>> select_field_count; >>> null_fields=blob_columns=0; >>> create_info->varchar= 0; >>> @@ -3241,7 +3364,7 @@ mysql_prepare_create_table(THD *thd, >>> HA_CREATE_INFO *create_info, >>> /* Set field charset. */ >>> save_cs= sql_field->charset= get_sql_field_charset(sql_field, >>> create_info); >>> if ((sql_field->flags & BINCMP_FLAG) && >>> - !(sql_field->charset= find_bin_collation(sql_field->charset))) >>> + !(sql_field->charset= find_bin_collation(sql_field->charset))) >>> >> typo. please revert >> >> DBUG_RETURN(TRUE); >>> /* >>> @@ -3274,7 +3397,17 @@ mysql_prepare_create_table(THD *thd, >>> HA_CREATE_INFO *create_info, >>> DBUG_RETURN(TRUE); >>> } >>> } >>> - >>> + if(sql_field->field_visibility==USER_DEFINED_HIDDEN) >>> + { >>> + if(sql_field->flags&NOT_NULL_FLAG) >>> + { >>> + if(sql_field->flags&NO_DEFAULT_VALUE_FLAG) >>> >> do it in one if(), not in three, please >> > changed > >> + { >>> + my_error(ER_HIDDEN_NOT_NULL_WOUT_DEFAULT, MYF(0), >>> sql_field->field_name); >>> + DBUG_RETURN(TRUE); >>> + } >>> + } >>> + } >>> if (sql_field->sql_type == MYSQL_TYPE_SET || >>> sql_field->sql_type == MYSQL_TYPE_ENUM) >>> { >>> @@ -3831,8 +3968,8 @@ mysql_prepare_create_table(THD *thd, >>> HA_CREATE_INFO *create_info, >>> sql_field->charset->mbminlen > 1 || // ucs2 doesn't work yet >>> (ft_key_charset && sql_field->charset != ft_key_charset)) >>> { >>> - my_error(ER_BAD_FT_COLUMN, MYF(0), column->field_name.str); >>> - DBUG_RETURN(-1); >>> + my_error(ER_BAD_FT_COLUMN, MYF(0), column->field_name.str); >>> + DBUG_RETURN(-1); >>> } >>> >> indentation is two spaces, not one >> > i do not know why this is not working i tried in vi but does not worked > i removed most of idention problem but this one is not solving :( > > ft_key_charset=sql_field->charset; >>> /* >>> @@ -3874,10 +4011,9 @@ mysql_prepare_create_table(THD *thd, >>> HA_CREATE_INFO *create_info, >>> if (f_is_geom(sql_field->pack_flag) && sql_field->geom_type >>> == >>> Field::GEOM_POINT) >>> column->length= MAX_LEN_GEOM_POINT_FIELD; >>> - if (!column->length) >>> + if (!column->length) >>> >> again, as a couple of times above - tabs confuse you >> and you mess up the indentation :( >> >> { >>> - my_error(ER_BLOB_KEY_WITHOUT_LENGTH, MYF(0), >>> column->field_name.str); >>> - DBUG_RETURN(TRUE); >>> + DBUG_ASSERT(0); >>> } >>> } >>> #ifdef HAVE_SPATIAL >>> @@ -7420,7 +7557,10 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, >>> while ((drop=drop_it++)) >>> { >>> if (drop->type == Alter_drop::COLUMN && >>> - !my_strcasecmp(system_charset_info,field->field_name, >>> drop->name)) >>> + !my_strcasecmp(system_charset_info,field->field_name, drop->name) >>> >> again >> >> + /* we cant not drop system generated column */ >>> + && !(field->field_visibility==MEDIUM_HIDDEN >>> + ||field->field_visibility==FULL_HIDDEN)) >>> { >>> /* Reset auto_increment value if it was dropped */ >>> if (MTYP_TYPENR(field->unireg_check) == Field::NEXT_NUMBER && >>> @@ -7444,7 +7584,10 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, >>> while ((def=def_it++)) >>> { >>> if (def->change && >>> - !my_strcasecmp(system_charset_info,field->field_name, >>> def->change)) >>> + !my_strcasecmp(system_charset_info,field->field_name, def->change) >>> >> and again >> >> + /* we cant change system generated column */ >>> + && !(field->field_visibility==MEDIUM_HIDDEN >>> + ||field->field_visibility==FULL_HIDDEN)) >>> break; >>> } >>> if (def) >>> @@ -7512,6 +7655,51 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, >>> table->s->table_name.str); >>> goto err; >>> } >>> + /* Need to see whether new added column clashes with already existed >>> + DB_ROW_HASH_*(is must have is_hash==tru) >>> + */ >>> + for (f_ptr=table->vfield ;f_ptr&&(field= *f_ptr) ; f_ptr++) >>> + { >>> + if ((field->is_hash)&&!my_strcasecmp(system_charset_info,field- >>> >field_name,def->field_name)) >>> + { >>> + /* got a clash find the highest number in db_row_hash_* */ >>> + Field *temp_field; >>> + int max=0; >>> + for (Field ** f_temp_ptr=table->vfield ; (temp_field= >>> *f_temp_ptr); f_temp_ptr++) >>> + { >>> + if(temp_field->is_hash) >>> + { >>> + int temp = atoi(temp_field->field_name+12); >>> + if(temp>max) >>> + max=temp; >>> + } >>> + } >>> + max++; >>> + >>> + Create_field * old_hash_field; >>> + while((old_hash_field=field_it++)) >>> + { >>> + if(!my_strcasecmp(system_charset_info,old_hash_field->field_ >>> name, >>> + field->field_name)) >>> + { >>> + field_it.remove(); >>> + break; >>> + } >>> + } >>> + /* Give field new name which does not clash with >>> def->feild_name */ >>> + new_hash_field = old_hash_field->clone(thd->mem_root); >>> + char *name = (char *)thd->alloc(30); >>> + strcpy(name,"DB_ROW_HASH_"); >>> + char num_holder[10]; >>> + sprintf(num_holder,"%d",max); >>> + strcat(name,num_holder); >>> + new_hash_field->field_name=name; >>> + new_hash_field->field=field; >>> + new_hash_field->change=old_hash_field->field_name; >>> + new_create_list.push_front(new_hash_field,thd->mem_root); >>> + field_it.rewind(); >>> + } >>> + } >>> >> okay... I wonder, if it would be easier not to look for collisions in >> mysql_prepare_alter_table, but simply rename all is_hash columns >> in mysql_prepare_create_table(). then you'll only need to do it >> in one place. >> > Actually i am thinking of changing the whole approch in > mysql_prepare_alter table > currently it works but i think better version would be > in mysql_prepare_create table we have orignal table table->field and > table->key_info > i am thinking of making a copy of these two and making changes like > deleting db_row_hash_1 from > field and expanding keyinfo->key_part of those keys who are long unique > but this way mysqll_prepare_create table work normally and all changes > will be done in mysql prepare_create_table > > /* >>> Check that the DATE/DATETIME not null field we are going to add >>> is >>> either has a default value or the '0000-00-00' is allowed by the >>> @@ -7609,6 +7799,25 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, >>> } >>> if (drop) >>> { >>> + /* If we drop index of blob unique then we need to drop the >>> db_row_hash col */ >>> + if(key_info->flags&HA_UNIQUE_HASH||key_info->flags&HA_INDEX_HASH) >>> + { >>> + char * name = (char *)key_info->key_part->field->field_name; >>> + /*iterate over field_it and remove db_row_hash col */ >>> + field_it.rewind(); >>> + Create_field * temp_field; >>> + while ((temp_field=field_it++)) >>> + { >>> + if(!my_strcasecmp(system_charset_info,temp_field->field_ >>> name,name)) >>> + { >>> + field_it.remove(); >>> + //add flag if it not exists >>> + alter_info->flags|=Alter_info::ALTER_DROP_COLUMN; >>> + break; >>> + } >>> + } >>> + field_it.rewind(); >>> >> this should be a little bit more complicated. an index can cover many >> columns, so the index should be dropped when its last column is removed. >> I suppose you've already done that, I need to pull and check. >> > works > > >> + } >>> if (table->s->tmp_table == NO_TMP_TABLE) >>> { >>> (void) delete_statistics_for_index(thd, table, key_info, >>> FALSE); >>> @@ -7766,6 +7979,48 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, >>> my_error(ER_WRONG_NAME_FOR_INDEX, MYF(0), key->name.str); >>> goto err; >>> } >>> + List_iterator key_part_iter(key->columns); >>> + Key_part_spec * temp_colms; >>> + Create_field * sql_field; >>> + field_it.rewind(); >>> + while((temp_colms=key_part_iter++)) >>> + { >>> + while ((sql_field=field_it++)) >>> + { >>> + if(!my_strcasecmp(system_charset_info, >>> + temp_colms->field_name.str, >>> + sql_field->field_name)) >>> + { >>> + if(sql_field->field_visibility==MEDIUM_HIDDEN||sql_field-> >>> field_visibility==FULL_HIDDEN) >>> + { >>> + /* If we added one column (which clash with db_row_has >>> )then this key >>> + is different then added by user to make it sure we check >>> for */ >>> + if(new_hash_field) >>> + { >>> + if(sql_field!=new_hash_field) >>> + { >>> + my_error(ER_KEY_COLUMN_DOES_NOT_EXITS, MYF(0), >>> sql_field->field_name); >>> + goto err; >>> + } >>> + } >>> + else /*this is for add index to db_row_hash which must >>> show error */ >>> + { >>> + my_error(ER_KEY_COLUMN_DOES_NOT_EXITS, MYF(0), >>> sql_field->field_name); >>> + goto err; >>> + } >>> >> I don't quite understand these your conditions, but the logic should be >> like this: MEDIUM_HIDDEN can be indexed, FULL_HIDDEN can never be. >> >> + } >>> + /* Check whether we adding index for blob or other long >>> length column then add column flag*/ >>> + if((sql_field->sql_type==MYSQL_TYPE_BLOB || >>> + sql_field->sql_type==MYSQL_TYPE_MEDIUM_BLOB|| >>> + sql_field->sql_type==MYSQL_TYPE_LONG_BLOB|| >>> + sql_field->sql_type==MYSQL_TYPE_LONG_BLOB) >>> + &&(temp_colms->length==0)) >>> + alter_info->flags|=Alter_info::ALTER_ADD_COLUMN; >>> >> really? why don't you simply set this flag when you actually create new >> Create_field and push it into the list? >> > okay > > + } >>> + } >>> + } >>> + field_it.rewind(); >>> + >>> } >>> } >>> diff --git a/sql/sql_update.cc b/sql/sql_update.cc >>> index 4221025..4955881 100644 >>> --- a/sql/sql_update.cc >>> +++ b/sql/sql_update.cc >>> @@ -92,24 +92,24 @@ bool compare_record(const TABLE *table) >>> } >>> return FALSE; >>> } >>> - >>> - /* >>> + >>> + /* >>> The storage engine has read all columns, so it's safe to compare >>> all bits >>> including those not in the write_set. This is cheaper than the >>> field-by-field >>> comparison done above. >>> - */ >>> + */ >>> if (table->s->can_cmp_whole_record) >>> return cmp_record(table,record[1]); >>> /* Compare null bits */ >>> if (memcmp(table->null_flags, >>> - table->null_flags+table->s->rec_buff_length, >>> - table->s->null_bytes_for_compare)) >>> + table->null_flags+table->s->rec_buff_length, >>> + table->s->null_bytes_for_compare)) >>> >> in this file you've done *only* whitespace changes, some of them are ok, >> but many result in broken indentation, please fix them all! >> > changed > > >> return TRUE; // Diff in NULL value >>> /* Compare updated fields */ >>> for (Field **ptr= table->field ; *ptr ; ptr++) >>> { >>> if (bitmap_is_set(table->write_set, (*ptr)->field_index) && >>> - (*ptr)->cmp_binary_offset(table->s->rec_buff_length)) >>> + (*ptr)->cmp_binary_offset(table->s->rec_buff_length)) >>> return TRUE; >>> } >>> return FALSE; >>> diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy >>> index e614692..4872d20 100644 >>> --- a/sql/sql_yacc.yy >>> +++ b/sql/sql_yacc.yy >>> @@ -1271,6 +1271,7 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong >>> *yystacksize); >>> %token HEX_NUM >>> %token HEX_STRING >>> %token HIGH_PRIORITY >>> +%token HIDDEN >>> >> HIDDEN_SYM, please >> >> %token HOST_SYM >>> %token HOSTS_SYM >>> %token HOUR_MICROSECOND_SYM >>> @@ -6047,6 +6048,11 @@ vcol_attribute: >>> lex->alter_info.flags|= Alter_info::ALTER_ADD_INDEX; >>> } >>> | COMMENT_SYM TEXT_STRING_sys { Lex->last_field->comment= $2; } >>> + | HIDDEN >>> + { >>> + LEX *lex =Lex; >>> >> no need to do that ^^^ you can simply write Lex->last_field->field_visibil >> ity=... >> > change but in sql_yacc.yy this type of code is use everywhere > >> >> + lex->last_field->field_visibility=USER_DEFINED_HIDDEN; >>> + } >>> ; >>> parse_vcol_expr: >>> @@ -6469,6 +6475,11 @@ attribute: >>> new (thd->mem_root) >>> engine_option_value($1, &Lex->last_field->option_list, >>> &Lex->option_list_last); >>> } >>> + | HIDDEN >>> + { >>> + LEX *lex =Lex; >>> + lex->last_field->field_visibility=USER_DEFINED_HIDDEN; >>> + } >>> >> no need to repeat this twice. Try to remove HIDDEN, COMMENT_SYM, UNIQUE, >> and UNIQUE KEY rules from attribute and add the vcol_attribute instead. >> >> done > >> ; >>> diff --git a/sql/table.h b/sql/table.h >>> index eb4076e..982de6f 100644 >>> --- a/sql/table.h >>> +++ b/sql/table.h >>> @@ -321,6 +321,24 @@ enum enum_vcol_update_mode >>> VCOL_UPDATE_ALL >>> }; >>> +/* Field visibility enums */ >>> + >>> +enum field_visible_type{ >>> + NORMAL=0, >>> >> better NOT_HIDDEN >> > changed > >> + USER_DEFINED_HIDDEN, >>> + MEDIUM_HIDDEN, >>> + FULL_HIDDEN >>> +}; >>> + >>> +enum key_hash_type{ >>> + /* normal column */ >>> + NOT_HASH=0, >>> + /* hash for defination index(A,...) in this case no duplicate >>> will be checked */ >>> + INDEX_HASH, >>> >> there's no point in having a hash index for blobs, if it doesn't check >> for duplicates >> > okay reverted > > >> + /* hash for defination unique(A,...) in this duplicate will be >>> checked in ha_write_row and >>> + update */ >>> + UNIQUE_HASH >>> +}; >>> class Filesort_info >>> { >>> /// Buffer for sorting keys. >>> diff --git a/sql/table.cc b/sql/table.cc >>> index a90eb2e..31d8f1e 100644 >>> --- a/sql/table.cc >>> +++ b/sql/table.cc >>> @@ -785,7 +785,8 @@ static bool create_key_infos(const uchar *strpos, >>> const uchar *frm_image_end, >>> keyinfo->ext_key_parts= keyinfo->user_defined_key_parts; >>> keyinfo->ext_key_flags= keyinfo->flags; >>> keyinfo->ext_key_part_map= 0; >>> - if (share->use_ext_keys && i && !(keyinfo->flags & HA_NOSAME)) >>> + if (share->use_ext_keys && i && !(keyinfo->flags & HA_NOSAME) >>> + ) >>> >> revert >> >> { >>> for (j= 0; >>> j < first_key_parts && keyinfo->ext_key_parts < >>> MAX_REF_PARTS; >>> @@ -985,7 +990,7 @@ int TABLE_SHARE::init_from_binary_frm_image(THD >>> *thd, bool write, >>> if (length < 256) >>> goto err; >>> } >>> - if (extra2 + length > e2end) >>> + if ( extra2 + length > e2end) >>> >> revert >> >> goto err; >>> switch (type) { >>> case EXTRA2_TABLEDEF_VERSION: >>> @@ -1040,7 +1048,6 @@ int TABLE_SHARE::init_from_binary_frm_image(THD >>> *thd, bool write, >>> if (extra2 != e2end) >>> goto err; >>> } >>> - >>> >> nope, revert >> >> if (frm_length < FRM_HEADER_SIZE + len || >>> !(pos= uint4korr(frm_image + FRM_HEADER_SIZE + len))) >>> goto err; >>> @@ -1671,7 +1678,8 @@ int TABLE_SHARE::init_from_binary_frm_image(THD >>> *thd, bool write, >>> if (!reg_field) // Not supported field >>> type >>> goto err; >>> - >>> + reg_field->field_visibility=(field_visible_type)*field_prope >>> rties++; >>> >> please, add a feature status variable for it. search, for example, for >> "feature_fulltext" or "feature_gis". Just as feature_gis, you can >> increment your feature_hidden_column when a table with user-created hidden >> columns is opened. >> > done > >> better use c++ casts here, like >> >> static_cast (*field_properties++) >> >> won't look as multiplication :) >> >> + reg_field->is_hash=(bool)*field_properties++; >>> >> you don't need a cast at all, but if you want to keep it, use C++ cast >> >> reg_field->field_index= i; >>> reg_field->comment=comment; >>> reg_field->vcol_info= vcol_info; >>> @@ -1985,6 +1993,10 @@ int TABLE_SHARE::init_from_binary_frm_image(THD >>> *thd, bool write, >>> if ((keyinfo->flags & HA_NOSAME) || >>> (ha_option & HA_ANY_INDEX_MAY_BE_UNIQUE)) >>> set_if_bigger(share->max_unique_length,keyinfo->key_length); >>> + if(keyinfo->flags&HA_UNIQUE_HASH||keyinfo->flags&HA_INDEX_HASH) >>> + { >>> + keyinfo->ext_key_parts=1; >>> >> why? >> > this is because consider the query > create table t1 (a int primary key, b blob unique); > then in mysql will add field a as keypart in second key_info > and increase ext_key_part and if i do not do this the query like this > insert into t1(1,1); > insert into t1(2,1); > will succeed > > >> + } >>> } >>> if (primary_key < MAX_KEY && >>> (share->keys_in_use.is_set(primary_key))) >>> diff --git a/sql/unireg.h b/sql/unireg.h >>> index 10751b6..211749a 100644 >>> --- a/sql/unireg.h >>> +++ b/sql/unireg.h >>> @@ -186,7 +186,8 @@ enum extra2_frm_value_type { >>> EXTRA2_TABLEDEF_VERSION=0, >>> EXTRA2_DEFAULT_PART_ENGINE=1, >>> EXTRA2_GIS=2, >>> - >>> + EXTRA2_FIELD_FLAGS=3, >>> + EXTRA2_KEY_HASH_FLAG=4, >>> >> make it 129 and 130 >> >> #define EXTRA2_ENGINE_IMPORTANT 128 >>> EXTRA2_ENGINE_TABLEOPTS=128, >>> diff --git a/sql/unireg.cc b/sql/unireg.cc >>> index 66959f4..0d764a1 100644 >>> --- a/sql/unireg.cc >>> +++ b/sql/unireg.cc >>> @@ -204,7 +224,8 @@ LEX_CUSTRING build_frm_image(THD *thd, const char >>> *table, >>> if (gis_extra2_len) >>> extra2_size+= 1 + (gis_extra2_len > 255 ? 3 : 1) + gis_extra2_len; >>> - >>> + extra2_size+=1 + ( 2*create_fields.elements > 255 ? 3 : 1) + >>> + 2*create_fields.elements;// first one for >>> type(extra2_field_flags) next 2 for length >>> >> for backward compatibility it would make sense to add this >> EXTRA2_FIELD_FLAGS data *only* if you have hidden fields. >> > okay > >> >> key_buff_length= uint4korr(fileinfo+47); >>> frm.length= FRM_HEADER_SIZE; // fileinfo; >>> diff --git a/storage/maria/maria_def.h b/storage/maria/maria_def.h >>> index 7337b01..3d0860f 100644 >>> --- a/storage/maria/maria_def.h >>> +++ b/storage/maria/maria_def.h >>> @@ -895,7 +895,7 @@ struct st_maria_handler >>> /* The UNIQUE check is done with a hashed long key */ >>> -#define MARIA_UNIQUE_HASH_TYPE HA_KEYTYPE_ULONG_INT >>> +#define MARIA_UNIQUE_hash_type HA_KEYTYPE_ULONG_INT >>> >> why? >> >> reverted sorry > > #define maria_unique_store(A,B) mi_int4store((A),(B)) >>> extern mysql_mutex_t THR_LOCK_maria; >>> >> >> Regards, >> Sergei >> Chief Architect MariaDB >> and security@mariadb.org >> > >
Hi, Sachin! On Aug 13, Sachin Setia wrote:
Hello Sergei! Please review commit 71f9069 onward i have changed mysql_prepare_alter_table func.
Okay, here it is. Up to the 03e29c6 (this is one after 71f9069). Short summary - this all looks pretty good. There're issues, but as a whole - great work!
diff --git a/include/my_base.h b/include/my_base.h index 1317639..d03ca0f 100644 --- a/include/my_base.h +++ b/include/my_base.h @@ -241,6 +241,19 @@ enum ha_base_keytype { HA_KEYTYPE_BIT=19 };
+/* Add some constant related to unique long hash column like length hash string etc*/ + +#define HA_HASH_KEY_LENGTH_WITHOUT_NULL 8 +#define HA_HASH_FIELD_LENGTH 8 +#define HA_HASH_KEY_LENGTH_WITH_NULL 9 +#define HA_HASH_STR_HEAD "hash(`" //used in mysql_prepare_create_table +#define HA_HASH_STR_HEAD_LEN strlen(HA_HASH_STR_HEAD_LEN) +#define HA_HASH_STR "hash" +#define HA_HASH_STR_LEN strlen(HA_HASH_STR) +#define HA_HASH_STR_INDEX "HASH_INDEX" +#define HA_HASH_STR_INDEX_LEN strlen(HA_HASH_STR_INDEX) +#define HA_DB_ROW_HASH_STR "DB_ROW_HASH_"
no need to put all these constants into the very global my_base.h. better to define them in sql_show.cc or sql_table.cc (depending on where they're used)
+ #define HA_MAX_KEYTYPE 31 /* Must be log2-1 */
/* diff --git a/mysql-test/r/features.result b/mysql-test/r/features.result index 52650d1..e050efb 100644 --- a/mysql-test/r/features.result +++ b/mysql-test/r/features.result @@ -7,6 +7,7 @@ Feature_delay_key_write 0 Feature_dynamic_columns 0 Feature_fulltext 0 Feature_gis 0 +Feature_hidden_column 0
Great! Please, add also a test where it's not 0. I mean, in your hidden_field.test you can add FLUSH STATUS; at the beginning of the file and SHOW STATUS LIKE 'Feature_hidden_column'; somewhere later. This will show that Feature_hidden_column is incremented accordingly.
Feature_locale 0 Feature_subquery 0 Feature_timezone 0 diff --git a/mysql-test/r/hidden_field.result b/mysql-test/r/hidden_field.result new file mode 100644 index 0000000..09a2c21 --- /dev/null +++ b/mysql-test/r/hidden_field.result @@ -0,0 +1,367 @@ +create table h_1(abc int primary key, xyz int hidden); +desc h_1; +Field Type Null Key Default Extra +abc int(11) NO PRI NULL +xyz int(11) YES NULL HIDDEN +show create table h_1; +Table Create Table +h_1 CREATE TABLE `h_1` ( + `abc` int(11) NOT NULL, + `xyz` int(11) HIDDEN DEFAULT NULL, + PRIMARY KEY (`abc`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +drop table h_1; +create table h_2(a1 int hidden); +ERROR 42000: A table must have at least 1 column +create table h_3(a1 blob,hidden(a1)); +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'hidden(a1))' at line 1 +create table h_4(a1 int primary key hidden ,a2 int unique hidden , a3 blob,a4 +int not null hidden unique); +ERROR HY000: Hidden column 'a1' either allow null values or it must have default value +create table h_5(abc int not null hidden); +ERROR HY000: Hidden column 'abc' either allow null values or it must have default value +create table t1(a int hidden, b int); +insert into t1 values(1); +insert into t1(a) values(1); +insert into t1(b) values(1);
better insert 1,2,3 not 1,1,1 so that in SELECT you could unambigously see what INSERT has added what row
+insert into t1(a,b) values(5,5); +select * from t1; +b +1 +NULL +1 +5 +select a,b from t1; +a b +NULL 1 +1 NULL +NULL 1 +5 5 +delete from t1; +insert into t1 values(1),(2),(3),(4); +select * from t1; +b +1 +2 +3 +4 +select a from t1; +a +NULL +NULL +NULL +NULL +drop table t1; +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +desc t1; +Field Type Null Key Default Extra +a int(11) YES NULL +b int(11) YES NULL HIDDEN +c int(11) NO PRI NULL auto_increment , HIDDEN
why a space before the comma?
+d blob YES NULL +e int(11) YES UNI NULL +f int(11) YES NULL +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +select * from t1; +a d e f +1 d blob 1 1 +1 d blob 11 1 +1 d blob 2 1 +1 d blob 3 1 +1 d blob 41 1 +drop table t1; +create table sdsdsd(a int , b int, hidden(a,b)); +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'hidden(a,b))' at line 1 +create table t1(a int,abc int as (a mod 3) virtual hidden); +desc t1; +Field Type Null Key Default Extra +a int(11) YES NULL +abc int(11) YES NULL VIRTUAL , HIDDEN +insert into t1 values(1,default); +ERROR 21S01: Column count doesn't match value count at row 1 +insert into t1 values(1),(22),(233); +select * from t1; +a +1 +22 +233 +select a,abc from t1; +a abc +1 1 +22 1 +233 2 +drop table t1; +create table t1(abc int primary key hidden auto_increment, a int); +desc t1; +Field Type Null Key Default Extra +abc int(11) NO PRI NULL auto_increment , HIDDEN +a int(11) YES NULL +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `abc` int(11) NOT NULL HIDDEN AUTO_INCREMENT, + `a` int(11) DEFAULT NULL, + PRIMARY KEY (`abc`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +insert into t1 values(1); +insert into t1 values(2); +insert into t1 values(3); +select * from t1; +a +1 +2 +3 +select abc,a from t1; +abc a +1 1 +2 2 +3 3 +delete from t1; +insert into t1 values(1),(2),(3),(4),(6); +select abc,a from t1; +abc a +4 1 +5 2 +6 3 +7 4 +8 6 +drop table t1; +create table t1(abc int); +alter table t1 change abc ss int hidden; +ERROR 42000: A table must have at least 1 column +alter table t1 add column xyz int; +alter table t1 modify column abc int ; +desc t1; +Field Type Null Key Default Extra +abc int(11) YES NULL +xyz int(11) YES NULL +insert into t1 values(22); +ERROR 21S01: Column count doesn't match value count at row 1 +alter table t1 modify column abc int hidden;
please, add also tests for making hidden fields visible again. I think that alter table t1 modify column abc int; will do the job
+desc t1; +Field Type Null Key Default Extra +abc int(11) YES NULL HIDDEN +xyz int(11) YES NULL +insert into t1 values(12); +drop table t1; +some test on copy table structure with table data; +table with hidden fields and unique keys; +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +desc t1; +Field Type Null Key Default Extra +a int(11) YES NULL +b int(11) YES NULL HIDDEN +c int(11) NO PRI NULL auto_increment , HIDDEN +d blob YES NULL +e int(11) YES UNI NULL +f int(11) YES NULL +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +select * from t1; +a d e f +1 d blob 1 1 +1 d blob 11 1 +1 d blob 2 1 +1 d blob 3 1 +1 d blob 41 1 +select a,b,c,d,e,f from t1; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +this wont copy hidden fields and keys; +create table t2 as select * from t1; +desc t2; +Field Type Null Key Default Extra +a int(11) YES NULL +d blob YES NULL +e int(11) YES NULL +f int(11) YES NULL +select * from t2; +a d e f +1 d blob 1 1 +1 d blob 11 1 +1 d blob 2 1 +1 d blob 3 1 +1 d blob 41 1 +select a,b,c,d,e,f from t2; +ERROR 42S22: Unknown column 'b' in 'field list' +drop table t2; +now this will copy hidden fields +create table t2 as select a,b,c,d,e,f from t1; +desc t2; +Field Type Null Key Default Extra +a int(11) YES NULL +b int(11) YES NULL HIDDEN +c int(11) NO 0 HIDDEN +d blob YES NULL +e int(11) YES NULL +f int(11) YES NULL +select * from t2; +a d e f +1 d blob 1 1 +1 d blob 11 1 +1 d blob 2 1 +1 d blob 3 1 +1 d blob 41 1 +select a,b,c,d,e,f from t2; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +drop table t2,t1; +some test related to copy of data from one table to another; +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +select a,b,c,d,e,f from t1; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +create table t2(a int , b int hidden , c int hidden , d blob , e int unique, f int); +insert into t2 select * from t1; +select a,b,c,d,e,f from t2; +a b c d e f +1 NULL NULL d blob 1 1 +1 NULL NULL d blob 11 1 +1 NULL NULL d blob 2 1 +1 NULL NULL d blob 3 1 +1 NULL NULL d blob 41 1 +truncate t2; +insert into t2 (a,b,c,d,e,f) select a,b,c,d,e,f from t1; +select a,b,c,d,e,f from t2; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +truncate t2; +drop table t1,t2; +some test related to creating view on table with hidden column; +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +create view v as select * from t1; +desc v; +Field Type Null Key Default Extra +a int(11) YES NULL +d blob YES NULL +e int(11) YES NULL +f int(11) YES NULL +select * from v; +a d e f +1 d blob 1 1 +1 d blob 11 1 +1 d blob 2 1 +1 d blob 3 1 +1 d blob 41 1 +v does not have hidden column; +select a,b,c,d,e,f from v; +ERROR 42S22: Unknown column 'b' in 'field list' +insert into v values(1,21,32,4); +select * from v; +a d e f +1 d blob 1 1 +1 d blob 11 1 +1 d blob 2 1 +1 d blob 3 1 +1 d blob 41 1 +1 21 32 4 +insert into v(a,b,c,d,e,f) values(1,12,3,4,5,6); +ERROR 42S22: Unknown column 'b' in 'field list' +drop view v; +create view v as select a,b,c,d,e,f from t1; +desc v; +Field Type Null Key Default Extra +a int(11) YES NULL +b int(11) YES NULL HIDDEN +c int(11) NO 0 HIDDEN +d blob YES NULL +e int(11) YES NULL +f int(11) YES NULL +select * from v; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +1 NULL 6 21 32 4 +v does have hidden column; +select a,b,c,d,e,f from v; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +1 NULL 6 21 32 4 +insert into v values(1,26,33,4,45,66); +select a,b,c,d,e,f from v; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +1 NULL 6 21 32 4 +1 26 33 4 45 66 +insert into v(a,b,c,d,e,f) values(1,32,31,41,5,6); +select a,b,c,d,e,f from v; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +1 NULL 6 21 32 4 +1 26 33 4 45 66 +1 32 31 41 5 6 +drop view v; +drop table t1; +now hidden column in where and some join query i think no use of this test but anyway; +create table t1 (a int unique , b int hidden unique, c int unique hidden); +insert into t1(a,b,c) values(1,1,1); +insert into t1(a,b,c) values(2,2,2); +insert into t1(a,b,c) values(3,3,3); +insert into t1(a,b,c) values(4,4,4); +insert into t1(a,b,c) values(21,21,26); +insert into t1(a,b,c) values(31,31,35); +insert into t1(a,b,c) values(41,41,45); +insert into t1(a,b,c) values(22,22,24); +insert into t1(a,b,c) values(32,32,33); +insert into t1(a,b,c) values(42,42,43); +explain select * from t1 where b=3; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const b b 5 const 1 +select * from t1 where b=3; +a +3 +explain select * from t1 where c=3; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const c c 5 const 1 +select * from t1 where c=3; +a +3 +create table t2 as select a,b,c from t1; +desc t2; +Field Type Null Key Default Extra +a int(11) YES NULL +b int(11) YES NULL HIDDEN +c int(11) YES NULL HIDDEN +explain select * from t1,t2 where t1.b = t2.c and t1.c = t2.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t2 ALL NULL NULL NULL NULL 10 +1 SIMPLE t1 ALL b,c NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +select * from t1,t2 where t1.b = t2.c and t1.c = t2.b; +a a +1 1 +2 2 +3 3 +4 4 +drop table t1,t2; diff --git a/mysql-test/r/long_unique_where.result b/mysql-test/r/long_unique_where.result new file mode 100644 index 0000000..e9bd416 --- /dev/null +++ b/mysql-test/r/long_unique_where.result @@ -0,0 +1,340 @@ +create table t1(abc blob unique); +insert into t1 values(1),(2),(3),(4),(5),(11),(12),(31),(14),(15),(NULL) +,(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL), +(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL), +(NULL),(NULL),(NULL),(NULL),(NULL); +insert into t1 value(1); +ERROR 23000: Duplicate entry '1' for key 'abc' +explain select * from t1 where abc=31; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc=31; +abc +31 +# in case of null we do not use any optimization +explain select * from t1 where abc is NULL; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 36 Using where +select * from t1 where abc is NULL limit 1; +abc +NULL +#range query
please clarify it here, for example, like #range query (index not used, because it's a hash)
+explain select * from t1 where abc >1 limit 1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 36 Using where +select * from t1 where abc >1 limit 1; +abc +2 +explain select * from t1 where abc >1 and abc <4; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 36 Using where +select * from t1 where abc >1 and abc <4; +abc +2 +3 +explain select * from t1 where abc =15 or abc <4 ; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 36 Using where +select * from t1 where abc =15 or abc <4 ; +abc +1 +2 +3 +15 +drop table t1; +create table t1(abc blob unique, xyz int ); +insert into t1 values(1,1),(2,1),(3,3),(4,1),(5,6),(NULL,3),(NULL,1), +(NULL,NULL),(11,11),(12,11),(31,31), +(14,1),(15,61),(NULL,32),(NULL,12),(NULL,NULL); +insert into t1 value(1,NULL); +ERROR 23000: Duplicate entry '1' for key 'abc' +explain select * from t1 where abc=15; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc= 15; +abc xyz +15 61 +explain select * from t1 where abc=15 and xyz =61; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc= 15 and 61;
type in the where clause
+abc xyz +15 61 +# now xyz has different value
what do you mean by that?
+explain select * from t1 where abc=1000; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where abc= 1000; +abc xyz +explain select * from t1 where abc=14 and xyz =56; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where abc=14 and xyz =56; +abc xyz +#range query +explain select * from t1 where abc >5 limit 1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 16 Using where +select * from t1 where abc >5 limit 1; +abc xyz +11 11 +explain select * from t1 where abc=5 and xyz <56; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc=5 and xyz <56; +abc xyz +5 6 +explain select * from t1 where abc>=5 and xyz <56; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 16 Using where +select * from t1 where abc>=5 and xyz <56; +abc xyz +5 6 +11 11 +12 11 +31 31 +14 1 +explain select * from t1 where abc>5 and xyz =56; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 16 Using where +select * from t1 where abc>5 and xyz =56; +abc xyz +drop table t1; +create table t1(abc blob unique, xyz blob unique ); +insert into t1 values(1,1),(2,11),(3,31),(4,12),(5,63),(NULL,2),(NULL,NULL), +(91,19),(92,119),(93,391),(94,192),(95,693); +insert into t1 value(1,NULL); +ERROR 23000: Duplicate entry '1' for key 'abc' +explain select * from t1 where abc=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc=1; +abc xyz +1 1 +explain select * from t1 where xyz=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const xyz xyz 9 const 1 +select * from t1 where xyz=1; +abc xyz +1 1 +explain select * from t1 where abc=5 and xyz=63; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc=5 and xyz=63; +abc xyz +5 63 +explain select * from t1 where xyz=63 and abc=5; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where xyz=63 and abc=5; +abc xyz +5 63 +explain select * from t1 where xyz=63 or abc=5; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where xyz=63 or abc=5; +abc xyz +5 63 +# now the first one does not exist +explain select * from t1 where abc=51 and xyz=63; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where abc=51 and xyz=63; +abc xyz +# now the second one does not exist +explain select * from t1 where abc=5 and xyz=613; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where abc=5 and xyz=613; +abc xyz +explain select * from t1 where abc is NULL; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where abc is NULL; +abc xyz +NULL 2 +NULL NULL +explain select * from t1 where abc is NULL and xyz=2; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const xyz xyz 9 const 1 +select * from t1 where abc is NULL and xyz=2; +abc xyz +NULL 2 +#range conditions +explain select * from t1 where abc>11 limit 5; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where abc>11 limit 5; +abc xyz +91 19 +92 119 +93 391 +94 192 +95 693 +explain select * from t1 where xyz<11; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where xyz<11; +abc xyz +1 1 +NULL 2 +explain select * from t1 where abc>=51 and xyz<=63; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where abc>=51 and xyz<=63; +abc xyz +91 19 +explain select * from t1 where abc>5 and xyz<613; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where abc>5 and xyz<613; +abc xyz +91 19 +92 119 +93 391 +94 192 +explain select * from t1 where abc=5 and xyz>1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc=5 and xyz>1; +abc xyz +5 63 +explain select * from t1 where abc<55 and xyz=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const xyz xyz 9 const 1 +select * from t1 where abc<55 and xyz=1; +abc xyz +1 1 +explain select * from t1 where abc<=55 or xyz>=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where abc<=55 and xyz>=1; +abc xyz +1 1 +2 11 +3 31 +4 12 +5 63 +drop table t1; +#now the unique (a,b,c..........) +#let us do more hard test by using unique(a,b,c,d) key first +create table t1 (a blob , b blob , c blob , d blob ,unique(a,b,c,d), +unique(a,b,c) ,unique (b,c,d));
hmm, better do not use redundant keys. it works now, but tenchnically we can implement the optimization where the server will internally remove "unique(a,b,c,d)" - will store it in the frm, but won't tell the engine about it - because unique(a,b,c) guarantees that (a,b,c,d) is *always* unique. so, if we add this optimization someday your test case will no longer test what it was supposed to.
+show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` blob DEFAULT NULL, + `c` blob DEFAULT NULL, + `d` blob DEFAULT NULL, + UNIQUE KEY `a_b_c_d`(`a`,`b`,`c`,`d`), + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), + UNIQUE KEY `b_c_d`(`b`,`c`,`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +insert into t1 values(1,1,1,1),(2,1,2,1),(1,3,3,1),(4,1,4,1),(1,5,1,5), +(6,1,6,1),(1,7,1,7),(8,1,1,8),(1,9,9,1),(2,2,2,2),(4,4,4,4),(5,5,5,5),(6,6,6,6), +(126,216,603,640),(603,460,660,706),(806,609,609,605),(62,62,22,33),(64,65,66,76), +(16,26,63,64),(63,46,66,76),(86,69,69,65),(622,622,622,633),(644,655,666,776); +select * from t1 limit 3; +a b c d +1 1 1 1 +2 1 2 1 +1 3 3 1 +#simple where +#key (a,b,c) +explain select * from t1 where a=1 and b=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const a_b_c a_b_c 9 const 1 +select * from t1 where a=1 and b=1 and c=1; +a b c d +1 1 1 1 +explain select * from t1 where a=1 and b=4444 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where a=1 and b=4444 and c=1; +a b c d +#incomplete key +explain select * from t1 where a=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where a=1 and c=1; +a b c d +1 1 1 1 +1 5 1 5 +1 7 1 7 +explain select * from t1 where a=1 and b=4444 ; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where a=1 and b=4444 ; +a b c d +explain select * from t1 where b=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where b=1 and c=1; +a b c d +1 1 1 1 +8 1 1 8 +#key (b,c,d) +explain select * from t1 where d=1 and b=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const b_c_d b_c_d 9 const 1 +select * from t1 where d=1 and b=1 and c=1; +a b c d +1 1 1 1 +explain select * from t1 where d=1 and b=4444 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where d=1 and b=4444 and c=1; +a b c d +#incomplete key +explain select * from t1 where d=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where d=1 and c=1; +a b c d +1 1 1 1 +explain select * from t1 where d=1 and b=4444 ; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where d=1 and b=4444 ; +a b c d +explain select * from t1 where b=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where b=1 and c=1; +a b c d +1 1 1 1 +8 1 1 8 +#key (a,b,c,d) +explain select * from t1 where a=1 and d=1 and b=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const a_b_c_d a_b_c_d 9 const 1 +select * from t1 where a=1 and d=1 and b=1 and c=1; +a b c d +1 1 1 1 +explain select * from t1 where a=1 and d=1 and b=4444 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where a=1 and d=1 and b=4444 and c=1; +a b c d +#incomplete key +explain select * from t1 where a=1 and d=1 and c=1 ; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where a=1 and d=1 and c=1 ; +a b c d +1 1 1 1 +explain select * from t1 where d=1 and b=4444 and a=1 ; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where d=1 and b=4444 and a=1 ; +a b c d +explain select * from t1 where a=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where a=1 and c=1; +a b c d +1 1 1 1 +1 5 1 5 +1 7 1 7 +drop table t1; diff --git a/mysql-test/r/long_uniques.result b/mysql-test/r/long_uniques.result new file mode 100644 index 0000000..e410fc1 --- /dev/null +++ b/mysql-test/r/long_uniques.result @@ -0,0 +1,1163 @@ +#Structure of tests +#First we will check all option for +#table containing single unique column +#table containing keys like unique(a,b,c,d) etc +#then table containing 2 blob unique etc +#table with single long blob column; +create table t1(a blob unique); +insert into t1 values(1),(2),(3),(56),('sachin'),('maria'),(123456789034567891),(null),(null),(123456789034567890); +#table structure; +desc t1; +Field Type Null Key Default Extra +a blob YES UNI NULL +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + UNIQUE KEY `a`(`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1;
for these statements, use "query_vertical" prefix, like query_vertical show keys from t1; it works better when the result has only few (best: one) row
+Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a 1 a A 0 NULL NULL YES HASH_INDEX
here, notice that your index is shown as "non-unique"
+select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION COLUMN_DEFAULT IS_NULLABLE DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME COLUMN_TYPE COLUMN_KEY EXTRA PRIVILEGES COLUMN_COMMENT +def test t1 a 1 NULL YES blob 65535 65535 NULL NULL NULL NULL NULL blob UNI select,insert,update,references +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME NON_UNIQUE INDEX_SCHEMA INDEX_NAME SEQ_IN_INDEX COLUMN_NAME COLLATION CARDINALITY SUB_PART PACKED NULLABLE INDEX_TYPE COMMENT INDEX_COMMENT +def test t1 1 test a 1 a A 0 NULL NULL YES HASH_INDEX +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; +CONSTRAINT_CATALOG CONSTRAINT_SCHEMA CONSTRAINT_NAME TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION POSITION_IN_UNIQUE_CONSTRAINT REFERENCED_TABLE_SCHEMA REFERENCED_TABLE_NAME REFERENCED_COLUMN_NAME +def test a def test t1 a 1 NULL NULL NULL NULL +# table select we should not be able to see db_row_hash_column;
"not able to see db_row_hash_1 column"
+select * from t1; +a +1 +2 +3 +56 +sachin +maria +123456789034567891 +NULL +NULL +123456789034567890 +select db_row_hash_1 from t1; +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' +#duplicate entry test; +insert into t1 values(2); +ERROR 23000: Duplicate entry '2' for key 'a' +insert into t1 values('sachin'); +ERROR 23000: Duplicate entry 'sachi' for key 'a' +insert into t1 values(123456789034567891); +ERROR 23000: Duplicate entry '12345' for key 'a' +select * from t1; +a +1 +2 +3 +56 +sachin +maria +123456789034567891 +NULL +NULL +123456789034567890 +insert into t1 values(11),(22),(33); +insert into t1 values(12),(22); +ERROR 23000: Duplicate entry '22' for key 'a' +select * from t1; +a +1 +2 +3 +56 +sachin +maria +123456789034567891 +NULL +NULL +123456789034567890 +11 +22 +33 +12 +insert into t1 values(repeat('s',4000*10)),(repeat('s',4001*10)); +insert into t1 values(repeat('m',4000*10)),(repeat('m',4000*10)); +ERROR 23000: Duplicate entry 'mmmmm' for key 'a' +insert into t1 values(repeat('m',4001)),(repeat('m',4002)); +truncate table t1; +insert into t1 values(1),(2),(3),(4),(5),(8),(7); +#now some alter commands; +alter table t1 add column b int; +desc t1; +Field Type Null Key Default Extra +a blob YES UNI NULL +b int(11) YES NULL +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` int(11) DEFAULT NULL, + UNIQUE KEY `a`(`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +insert into t1 values(1,2); +ERROR 23000: Duplicate entry '1' for key 'a' +insert into t1 values(2,2); +ERROR 23000: Duplicate entry '2' for key 'a' +select db_row_hash_1 from t1; +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' +#now try to change db_row_hash_1 column; +alter table t1 drop column db_row_hash_1; +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists +alter table t1 add column d int , add column e int , drop column db_row_hash_1; +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists +alter table t1 modify column db_row_hash_1 int ; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 add column a int , add column b int, modify column db_row_hash_1 int ; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 change column db_row_hash_1 dsds int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 add column asd int, change column db_row_hash_1 dsds int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 drop column b , add column c int; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `c` int(11) DEFAULT NULL, + UNIQUE KEY `a`(`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +#now add some column with name db_row_hash; +alter table t1 add column db_row_hash_1 int unique; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `c` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `a`(`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +insert into t1 values(45,1,55),(46,1,55); +ERROR 23000: Duplicate entry '55' for key 'db_row_hash_1' +alter table t1 add column db_row_hash_2 int, add column db_row_hash_3 int; +desc t1; +Field Type Null Key Default Extra +a blob YES UNI NULL +c int(11) YES NULL +db_row_hash_1 int(11) YES UNI NULL +db_row_hash_2 int(11) YES NULL +db_row_hash_3 int(11) YES NULL +#this should also drop the unique index ; +alter table t1 drop column a; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_3` int(11) DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +#add column with unique index on blob ; +alter table t1 add column a blob unique; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_3` int(11) DEFAULT NULL, + `a` blob DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `a`(`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +# try to change the blob unique column name; +#this will change index to b tree; +alter table t1 modify column a int ; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_3` int(11) DEFAULT NULL, + `a` int(11) DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `a` (`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 a 1 a A NULL NULL NULL YES BTREE +alter table t1 add column clm blob unique; +#try changing the name ; +alter table t1 change column clm clm_changed blob; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_3` int(11) DEFAULT NULL, + `a` int(11) DEFAULT NULL, + `clm_changed` blob DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `a` (`a`), + UNIQUE KEY `clm`(`clm_changed`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 a 1 a A NULL NULL NULL YES BTREE +t1 1 clm 1 clm_changed A 0 NULL NULL YES HASH_INDEX +#now drop the unique key; +alter table t1 drop key clm; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_3` int(11) DEFAULT NULL, + `a` int(11) DEFAULT NULL, + `clm_changed` blob DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `a` (`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 a 1 a A NULL NULL NULL YES BTREE
you can use myisamchk to see *actually created* indexes in MYI file. examples are in myisam.test, but in short, it's something like let datadir=`select @@datadir`; replace_result $datadir DATADIR; exec $MYISAMCHK -d $datadir/test/t1 the first command needs to be done only once, in the beginning of the file, usually. The other pair you do whenever you want to examine the table, like, where you do "desc t1" or "show keys".
+drop table t1; +create table t1 (a TEXT CHARSET latin1 COLLATE latin1_german2_ci unique); +desc t1; +Field Type Null Key Default Extra +a text YES UNI NULL +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a 1 a A 0 NULL NULL YES HASH_INDEX +insert into t1 values ('ae'); +insert into t1 values ('AE'); +ERROR 23000: Duplicate entry 'AE' for key 'a' +insert into t1 values ('Ä');
good!
+drop table t1; +#table with multiple long blob column and varchar text column ; +create table t1(a blob unique, b int , c blob unique , d text unique , e varchar(3000) unique); +insert into t1 values(1,2,3,4,5),(2,11,22,33,44),(3111,222,333,444,555),(5611,2222,3333,4444,5555), +('sachin','ff','fdf','gfgfgfg','hghgr'),('maria','db','frter','dasd','utyuty'), +(123456789034567891,3534534534534,53453453453456,64565464564564,45435345345345), +(123456789034567890,435345345345,657567567567,78967657567567,657567567567567676); +Warnings: +Warning 1366 Incorrect integer value: 'ff' for column 'b' at row 5 +Warning 1366 Incorrect integer value: 'db' for column 'b' at row 6 +Warning 1264 Out of range value for column 'b' at row 7 +Warning 1264 Out of range value for column 'b' at row 8
did you really need to insert invalid values in this test?
+#table structure; +desc t1; +Field Type Null Key Default Extra +a blob YES UNI NULL +b int(11) YES NULL +c blob YES UNI NULL +d text YES UNI NULL +e varchar(3000) YES UNI NULL +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` int(11) DEFAULT NULL, + `c` blob DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + UNIQUE KEY `a`(`a`), + UNIQUE KEY `c`(`c`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `e`(`e`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 c 1 c A 0 NULL NULL YES HASH_INDEX +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 e 1 e A 0 NULL NULL YES HASH_INDEX +select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION COLUMN_DEFAULT IS_NULLABLE DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME COLUMN_TYPE COLUMN_KEY EXTRA PRIVILEGES COLUMN_COMMENT +def test t1 a 1 NULL YES blob 65535 65535 NULL NULL NULL NULL NULL blob UNI select,insert,update,references +def test t1 b 2 NULL YES int NULL NULL 10 0 NULL NULL NULL int(11) select,insert,update,references +def test t1 c 3 NULL YES blob 65535 65535 NULL NULL NULL NULL NULL blob UNI select,insert,update,references +def test t1 d 4 NULL YES text 65535 65535 NULL NULL NULL latin1 latin1_swedish_ci text UNI select,insert,update,references +def test t1 e 5 NULL YES varchar 3000 3000 NULL NULL NULL latin1 latin1_swedish_ci varchar(3000) UNI select,insert,update,references +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME NON_UNIQUE INDEX_SCHEMA INDEX_NAME SEQ_IN_INDEX COLUMN_NAME COLLATION CARDINALITY SUB_PART PACKED NULLABLE INDEX_TYPE COMMENT INDEX_COMMENT +def test t1 1 test a 1 a A 0 NULL NULL YES HASH_INDEX +def test t1 1 test c 1 c A 0 NULL NULL YES HASH_INDEX +def test t1 1 test d 1 d A 0 NULL NULL YES HASH_INDEX +def test t1 1 test e 1 e A 0 NULL NULL YES HASH_INDEX +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; +CONSTRAINT_CATALOG CONSTRAINT_SCHEMA CONSTRAINT_NAME TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION POSITION_IN_UNIQUE_CONSTRAINT REFERENCED_TABLE_SCHEMA REFERENCED_TABLE_NAME REFERENCED_COLUMN_NAME +def test a def test t1 a 1 NULL NULL NULL NULL +def test c def test t1 c 1 NULL NULL NULL NULL +def test d def test t1 d 1 NULL NULL NULL NULL +def test e def test t1 e 1 NULL NULL NULL NULL +#table select we should not be able to see db_row_hash_column; +select * from t1; +a b c d e +1 2 3 4 5 +2 11 22 33 44 +3111 222 333 444 555 +5611 2222 3333 4444 5555 +sachin 0 fdf gfgfgfg hghgr +maria 0 frter dasd utyuty +123456789034567891 2147483647 53453453453456 64565464564564 45435345345345 +123456789034567890 2147483647 657567567567 78967657567567 657567567567567676 +select db_row_hash_1 from t1; +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' +select db_row_hash_2 from t1; +ERROR 42S22: Unknown column 'db_row_hash_2' in 'field list' +select db_row_hash_3 from t1; +ERROR 42S22: Unknown column 'db_row_hash_3' in 'field list' +#duplicate entry test; +insert into t1 values(21,2,3,42,51); +ERROR 23000: Duplicate entry '3' for key 'c' +insert into t1 values('sachin',null,null,null,null); +ERROR 23000: Duplicate entry 'sachi' for key 'a' +insert into t1 values(1234567890345671890,4353453453451,6575675675617,789676575675617,657567567567567676); +ERROR 23000: Duplicate entry '65756' for key 'e' +select * from t1; +a b c d e +1 2 3 4 5 +2 11 22 33 44 +3111 222 333 444 555 +5611 2222 3333 4444 5555 +sachin 0 fdf gfgfgfg hghgr +maria 0 frter dasd utyuty +123456789034567891 2147483647 53453453453456 64565464564564 45435345345345 +123456789034567890 2147483647 657567567567 78967657567567 657567567567567676 +insert into t1 values(repeat('s',4000*10),100,repeat('s',4000*10),repeat('s',4000*10), +repeat('s',400)),(repeat('s',4001*10),1000,repeat('s',4001*10),repeat('s',4001*10), +repeat('s',401)); +insert into t1 values(repeat('m',4000*11),10,repeat('s',4000*11),repeat('s',4000*11),repeat('s',400)); +ERROR 23000: Duplicate entry 'sssss' for key 'e'
400 characters (that you insert into 'e') - that looks a bit too short for varchar(3000). Why wouldn't you insert, say, 2990 characters? 400 is something that even b-tree can handle, I suspect.
+truncate table t1; +insert into t1 values(1,2,3,4,5),(2,11,22,33,44),(3111,222,333,444,555),(5611,2222,3333,4444,5555); +#now some alter commands; +alter table t1 add column f int; +desc t1; +Field Type Null Key Default Extra +a blob YES UNI NULL +b int(11) YES NULL +c blob YES UNI NULL +d text YES UNI NULL +e varchar(3000) YES UNI NULL +f int(11) YES NULL +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` int(11) DEFAULT NULL, + `c` blob DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + UNIQUE KEY `a`(`a`), + UNIQUE KEY `c`(`c`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `e`(`e`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +#unique key should not break; +insert into t1 values(1,2,3,4,5,6); +ERROR 23000: Duplicate entry '1' for key 'a' +select db_row_hash_1 , db_row_hash_2, db_row_hash_3 from t1; +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' +#now try to change db_row_hash_1 column; +alter table t1 drop column db_row_hash_1, drop column db_row_hash_2, drop column db_row_hash_3; +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists +alter table t1 add column dg int , add column ef int , drop column db_row_hash_1; +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists +alter table t1 modify column db_row_hash_1 int , modify column db_row_hash_2 int, modify column db_row_hash_3 int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 add column ar int , add column rb int, modify column db_row_hash_1 int , modify column db_row_hash_3 int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 change column db_row_hash_1 dsds int , change column db_row_hash_2 dfdf int , change column db_row_hash_3 gdfg int ; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 add column asd int, drop column a, change column db_row_hash_1 dsds int, change db_row_hash_3 fdfdfd int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 drop column b , add column g int; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `c` blob DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + UNIQUE KEY `a`(`a`), + UNIQUE KEY `c`(`c`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `e`(`e`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +#now add some column with name db_row_hash; +alter table t1 add column db_row_hash_1 int unique; +alter table t1 add column db_row_hash_2 int unique; +alter table t1 add column db_row_hash_3 int unique; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `c` blob DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_3` int(11) DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), + UNIQUE KEY `db_row_hash_3` (`db_row_hash_3`), + UNIQUE KEY `a`(`a`), + UNIQUE KEY `c`(`c`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `e`(`e`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +alter table t1 add column db_row_hash_7 int, add column db_row_hash_5 int , add column db_row_hash_4 int ; +alter table t1 drop column db_row_hash_7,drop column db_row_hash_3, drop column db_row_hash_4; +desc t1; +Field Type Null Key Default Extra +a blob YES UNI NULL +c blob YES UNI NULL +d text YES UNI NULL +e varchar(3000) YES UNI NULL +f int(11) YES NULL +g int(11) YES NULL +db_row_hash_1 int(11) YES UNI NULL +db_row_hash_2 int(11) YES UNI NULL +db_row_hash_5 int(11) YES NULL +#this show now break anything; +insert into t1 values(1,2,3,4,5,6,23,5,6); +ERROR 23000: Duplicate entry '1' for key 'a' +#this should also drop the unique index; +alter table t1 drop column a, drop column c; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_5` int(11) DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `e`(`e`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 e 1 e A 0 NULL NULL YES HASH_INDEX +#add column with unique index on blob; +alter table t1 add column a blob unique; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_5` int(11) DEFAULT NULL, + `a` blob DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `e`(`e`), + UNIQUE KEY `a`(`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 e 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 a 1 a A 0 NULL NULL YES HASH_INDEX +#try to change the blob unique column name; +#this will change index to b tree; +alter table t1 modify column a int , modify column e int; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `d` text DEFAULT NULL, + `e` int(11) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_5` int(11) DEFAULT NULL, + `a` int(11) DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), + UNIQUE KEY `e` (`e`), + UNIQUE KEY `a` (`a`), + UNIQUE KEY `d`(`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE +t1 0 e 1 e A NULL NULL NULL YES BTREE +t1 0 a 1 a A NULL NULL NULL YES BTREE +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX +alter table t1 add column clm1 blob unique,add column clm2 blob unique; +#try changing the name; +alter table t1 change column clm1 clm_changed1 blob, change column clm2 clm_changed2 blob; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `d` text DEFAULT NULL, + `e` int(11) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_5` int(11) DEFAULT NULL, + `a` int(11) DEFAULT NULL, + `clm_changed1` blob DEFAULT NULL, + `clm_changed2` blob DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), + UNIQUE KEY `e` (`e`), + UNIQUE KEY `a` (`a`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `clm1`(`clm_changed1`), + UNIQUE KEY `clm2`(`clm_changed2`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE +t1 0 e 1 e A NULL NULL NULL YES BTREE +t1 0 a 1 a A NULL NULL NULL YES BTREE +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 clm1 1 clm_changed1 A 0 NULL NULL YES HASH_INDEX +t1 1 clm2 1 clm_changed2 A 0 NULL NULL YES HASH_INDEX +#now drop the unique key; +alter table t1 drop key clm1, drop key clm2; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `d` text DEFAULT NULL, + `e` int(11) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_5` int(11) DEFAULT NULL, + `a` int(11) DEFAULT NULL, + `clm_changed1` blob DEFAULT NULL, + `clm_changed2` blob DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), + UNIQUE KEY `e` (`e`), + UNIQUE KEY `a` (`a`), + UNIQUE KEY `d`(`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE +t1 0 e 1 e A NULL NULL NULL YES BTREE +t1 0 a 1 a A NULL NULL NULL YES BTREE +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX
test also alter table ... add unique key (blob_column) in three different variants: 1. there were no duplicates in blob_column, key added successfully, 2. there were duplicates, alter table failed. 3. there were duplicates, ALTER IGNORE TABLE... succeeds
+drop table t1; +#now the table with key on multiple columns; the ultimate test; +create table t1(a blob, b int , c varchar(2000) , d text , e varchar(3000) , f longblob , g int , h text , +unique(a,b,c), unique(c,d,e),unique(e,f,g,h),unique(a,b,c,d,e,f),unique(d,e,f,g,h),unique(a,b,c,d,e,f,g,h)); +insert into t1 values(1,1,1,1,1,1,1,1),(2,2,2,2,2,2,2,2),(3,3,3,3,3,3,3,3),(4,4,4,4,4,4,4,4),(5,5,5,5,5,5,5,5), +('maria',6,'maria','maria','maria','maria',6,'maria'),('mariadb',7,'mariadb','mariadb','mariadb','mariadb',8,'mariadb'); +#table structure; +desc t1; +Field Type Null Key Default Extra +a blob YES MUL NULL +b int(11) YES NULL +c varchar(2000) YES MUL NULL +d text YES MUL NULL +e varchar(3000) YES MUL NULL +f longblob YES NULL +g int(11) YES NULL +h text YES NULL +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` int(11) DEFAULT NULL, + `c` varchar(2000) DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a_b_c 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 2 d A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX +select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION COLUMN_DEFAULT IS_NULLABLE DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME COLUMN_TYPE COLUMN_KEY EXTRA PRIVILEGES COLUMN_COMMENT +def test t1 a 1 NULL YES blob 65535 65535 NULL NULL NULL NULL NULL blob MUL select,insert,update,references +def test t1 b 2 NULL YES int NULL NULL 10 0 NULL NULL NULL int(11) select,insert,update,references +def test t1 c 3 NULL YES varchar 2000 2000 NULL NULL NULL latin1 latin1_swedish_ci varchar(2000) MUL select,insert,update,references +def test t1 d 4 NULL YES text 65535 65535 NULL NULL NULL latin1 latin1_swedish_ci text MUL select,insert,update,references +def test t1 e 5 NULL YES varchar 3000 3000 NULL NULL NULL latin1 latin1_swedish_ci varchar(3000) MUL select,insert,update,references +def test t1 f 6 NULL YES longblob 4294967295 4294967295 NULL NULL NULL NULL NULL longblob select,insert,update,references +def test t1 g 7 NULL YES int NULL NULL 10 0 NULL NULL NULL int(11) select,insert,update,references +def test t1 h 8 NULL YES text 65535 65535 NULL NULL NULL latin1 latin1_swedish_ci text select,insert,update,references +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME NON_UNIQUE INDEX_SCHEMA INDEX_NAME SEQ_IN_INDEX COLUMN_NAME COLLATION CARDINALITY SUB_PART PACKED NULLABLE INDEX_TYPE COMMENT INDEX_COMMENT +def test t1 1 test a_b_c 1 a A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c 2 b A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c 3 c A 0 NULL NULL YES HASH_INDEX +def test t1 1 test c_d_e 1 c A 0 NULL NULL YES HASH_INDEX +def test t1 1 test c_d_e 2 d A 0 NULL NULL YES HASH_INDEX +def test t1 1 test c_d_e 3 e A 0 NULL NULL YES HASH_INDEX +def test t1 1 test e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +def test t1 1 test e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +def test t1 1 test e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX +def test t1 1 test e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX +def test t1 1 test d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +def test t1 1 test d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +def test t1 1 test d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +def test t1 1 test d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +def test t1 1 test d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; +CONSTRAINT_CATALOG CONSTRAINT_SCHEMA CONSTRAINT_NAME TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION POSITION_IN_UNIQUE_CONSTRAINT REFERENCED_TABLE_SCHEMA REFERENCED_TABLE_NAME REFERENCED_COLUMN_NAME +def test a_b_c def test t1 a 1 NULL NULL NULL NULL +def test a_b_c def test t1 b 2 NULL NULL NULL NULL +def test a_b_c def test t1 c 3 NULL NULL NULL NULL +def test c_d_e def test t1 c 1 NULL NULL NULL NULL +def test c_d_e def test t1 d 2 NULL NULL NULL NULL +def test c_d_e def test t1 e 3 NULL NULL NULL NULL +def test e_f_g_h def test t1 e 1 NULL NULL NULL NULL +def test e_f_g_h def test t1 f 2 NULL NULL NULL NULL +def test e_f_g_h def test t1 g 3 NULL NULL NULL NULL +def test e_f_g_h def test t1 h 4 NULL NULL NULL NULL +def test a_b_c_d_e_f def test t1 a 1 NULL NULL NULL NULL +def test a_b_c_d_e_f def test t1 b 2 NULL NULL NULL NULL +def test a_b_c_d_e_f def test t1 c 3 NULL NULL NULL NULL +def test a_b_c_d_e_f def test t1 d 4 NULL NULL NULL NULL +def test a_b_c_d_e_f def test t1 e 5 NULL NULL NULL NULL +def test a_b_c_d_e_f def test t1 f 6 NULL NULL NULL NULL +def test d_e_f_g_h def test t1 d 1 NULL NULL NULL NULL +def test d_e_f_g_h def test t1 e 2 NULL NULL NULL NULL +def test d_e_f_g_h def test t1 f 3 NULL NULL NULL NULL +def test d_e_f_g_h def test t1 g 4 NULL NULL NULL NULL +def test d_e_f_g_h def test t1 h 5 NULL NULL NULL NULL +def test a_b_c_d_e_f_g_h def test t1 a 1 NULL NULL NULL NULL +def test a_b_c_d_e_f_g_h def test t1 b 2 NULL NULL NULL NULL +def test a_b_c_d_e_f_g_h def test t1 c 3 NULL NULL NULL NULL +def test a_b_c_d_e_f_g_h def test t1 d 4 NULL NULL NULL NULL +def test a_b_c_d_e_f_g_h def test t1 e 5 NULL NULL NULL NULL +def test a_b_c_d_e_f_g_h def test t1 f 6 NULL NULL NULL NULL +def test a_b_c_d_e_f_g_h def test t1 g 7 NULL NULL NULL NULL +def test a_b_c_d_e_f_g_h def test t1 h 8 NULL NULL NULL NULL +# table select we should not be able to see db_row_hash_column; +select * from t1; +a b c d e f g h +1 1 1 1 1 1 1 1 +2 2 2 2 2 2 2 2 +3 3 3 3 3 3 3 3 +4 4 4 4 4 4 4 4 +5 5 5 5 5 5 5 5 +maria 6 maria maria maria maria 6 maria +mariadb 7 mariadb mariadb mariadb mariadb 8 mariadb +select db_row_hash_1 from t1; +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' +select db_row_hash_2 from t1; +ERROR 42S22: Unknown column 'db_row_hash_2' in 'field list' +select db_row_hash_3 from t1; +ERROR 42S22: Unknown column 'db_row_hash_3' in 'field list' +#duplicate entry test; +#duplicate keys entry; +insert into t1 values(1,1,1,0,0,0,0,0); +ERROR 23000: Duplicate entry '1-1-1' for key 'a_b_c' +insert into t1 values(0,0,1,1,1,0,0,0); +ERROR 23000: Duplicate entry '1-1-1' for key 'c_d_e' +insert into t1 values(0,0,0,0,1,1,1,1); +ERROR 23000: Duplicate entry '1-1-1-1' for key 'e_f_g_h' +insert into t1 values(1,1,1,1,1,0,0,0); +ERROR 23000: Duplicate entry '1-1-1' for key 'a_b_c' +insert into t1 values(0,0,0,0,1,1,1,1); +ERROR 23000: Duplicate entry '1-1-1-1' for key 'e_f_g_h' +insert into t1 values(1,1,1,1,1,1,1,1); +ERROR 23000: Duplicate entry '1-1-1' for key 'a_b_c' +select db_row_hash_1,db_row_hash_2,db_row_hash_3,db_row_hash_4,db_row_hash_5 from t1; +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' +alter table t1 drop column db_row_hash_1, drop column db_row_hash_2, drop column db_row_hash_3; +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists +alter table t1 add column dg int , add column ef int , drop column db_row_hash_1; +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists +alter table t1 modify column db_row_hash_1 int , modify column db_row_hash_2 int, modify column db_row_hash_3 int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 add column ar int , add column rb int, modify column db_row_hash_1 int , modify column db_row_hash_3 int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 change column db_row_hash_1 dsds int , change column db_row_hash_2 dfdf int , change column db_row_hash_3 gdfg int ; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 add column asd int, drop column a, change column db_row_hash_1 dsds int, change db_row_hash_3 fdfdfd int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` int(11) DEFAULT NULL, + `c` varchar(2000) DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +# add column named db_row_hash_*; +alter table t1 add column db_row_hash_7 int , add column db_row_hash_5 int, +add column db_row_hash_1 int, add column db_row_hash_2 int; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` int(11) DEFAULT NULL, + `c` varchar(2000) DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + `db_row_hash_7` int(11) DEFAULT NULL, + `db_row_hash_5` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a_b_c 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 2 d A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX +alter table t1 drop column db_row_hash_7 , drop column db_row_hash_5 , +drop column db_row_hash_1, drop column db_row_hash_2 ; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` int(11) DEFAULT NULL, + `c` varchar(2000) DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a_b_c 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 2 d A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX +#try to change column names; +alter table t1 change column a aa blob , change column b bb blob , change column d dd blob; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `aa` blob DEFAULT NULL, + `bb` blob DEFAULT NULL, + `c` varchar(2000) DEFAULT NULL, + `dd` blob DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + UNIQUE KEY `a_b_c`(`aa`,`bb`,`c`), + UNIQUE KEY `c_d_e`(`c`,`dd`,`e`), + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f`(`aa`,`bb`,`c`,`dd`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`dd`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`aa`,`bb`,`c`,`dd`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a_b_c 1 aa A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 2 bb A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 2 dd A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 1 aa A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 2 bb A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 4 dd A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 1 dd A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 1 aa A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 2 bb A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 4 dd A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX +alter table t1 change column aa a blob , change column bb b blob , change column dd d blob; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` blob DEFAULT NULL, + `c` varchar(2000) DEFAULT NULL, + `d` blob DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a_b_c 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 2 d A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX +#now we will change the data type to int and varchar limit so that we no longer require hash_index; +#on key a_b_c; +alter table t1 modify column a int , modify column b int , modify column c int; +Warnings: +Warning 1292 Truncated incorrect INTEGER value: 'maria' +Warning 1292 Truncated incorrect INTEGER value: 'maria' +Warning 1292 Truncated incorrect INTEGER value: 'mariadb' +Warning 1292 Truncated incorrect INTEGER value: 'mariadb' +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` int(11) DEFAULT NULL, + `b` int(11) DEFAULT NULL, + `c` int(11) DEFAULT NULL, + `d` blob DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + UNIQUE KEY `a_b_c` (`a`,`b`,`c`), + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 a_b_c 1 a A NULL NULL NULL YES BTREE +t1 0 a_b_c 2 b A NULL NULL NULL YES BTREE +t1 0 a_b_c 3 c A NULL NULL NULL YES BTREE +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 2 d A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX +#change it back; +alter table t1 modify column a blob , modify column b blob , modify column c blob; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` blob DEFAULT NULL, + `c` blob DEFAULT NULL, + `d` blob DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a_b_c 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 2 d A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX +#try to delete blob column in unique; +truncate table t1; +alter table t1 drop column a, drop column b, drop column c; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `d` blob DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + UNIQUE KEY `c_d_e`(`d`,`e`), + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f`(`d`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 c_d_e 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +#now try to delete keys; +alter table t1 drop key c_d_e, drop key e_f_g_h; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `d` blob DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + UNIQUE KEY `a_b_c_d_e_f`(`d`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a_b_c_d_e_f 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +drop table t1; diff --git a/mysql-test/t/hidden_field.test b/mysql-test/t/hidden_field.test new file mode 100644 index 0000000..8f3b452 --- /dev/null +++ b/mysql-test/t/hidden_field.test @@ -0,0 +1,152 @@ +create table h_1(abc int primary key, xyz int hidden); +desc h_1; +show create table h_1; +drop table h_1; +--error ER_TABLE_MUST_HAVE_COLUMNS +create table h_2(a1 int hidden); +--error ER_PARSE_ERROR +create table h_3(a1 blob,hidden(a1)); +--error ER_HIDDEN_NOT_NULL_WOUT_DEFAULT +create table h_4(a1 int primary key hidden ,a2 int unique hidden , a3 blob,a4 +int not null hidden unique); +--error ER_HIDDEN_NOT_NULL_WOUT_DEFAULT +create table h_5(abc int not null hidden); +create table t1(a int hidden, b int); +#should automatically add null +insert into t1 values(1); +insert into t1(a) values(1); +insert into t1(b) values(1); +insert into t1(a,b) values(5,5); +select * from t1; +select a,b from t1; +delete from t1; +insert into t1 values(1),(2),(3),(4); +select * from t1; +select a from t1; +drop table t1; +#echo more complex case of hidden +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +desc t1; +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +select * from t1; +drop table t1; +--error ER_PARSE_ERROR +create table sdsdsd(a int , b int, hidden(a,b)); +create table t1(a int,abc int as (a mod 3) virtual hidden); +desc t1; +--error ER_WRONG_VALUE_COUNT_ON_ROW +insert into t1 values(1,default); +insert into t1 values(1),(22),(233); +select * from t1; +select a,abc from t1; +drop table t1; +create table t1(abc int primary key hidden auto_increment, a int); +desc t1; +show create table t1; +insert into t1 values(1); +insert into t1 values(2); +insert into t1 values(3); +select * from t1; +select abc,a from t1; +delete from t1; +insert into t1 values(1),(2),(3),(4),(6); +select abc,a from t1; +drop table t1; +create table t1(abc int); +--error ER_TABLE_MUST_HAVE_COLUMNS +alter table t1 change abc ss int hidden; +alter table t1 add column xyz int; +alter table t1 modify column abc int ; +desc t1; +--error ER_WRONG_VALUE_COUNT_ON_ROW +insert into t1 values(22); +alter table t1 modify column abc int hidden; +desc t1; +insert into t1 values(12); +drop table t1; + +--echo some test on copy table structure with table data;
in echo's start the message from #-sign to make it better visible in a result
+ +--echo table with hidden fields and unique keys; + +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +desc t1; +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +select * from t1; +select a,b,c,d,e,f from t1; +--echo this wont copy hidden fields and keys; +create table t2 as select * from t1; +desc t2; +select * from t2; +--error ER_BAD_FIELD_ERROR +select a,b,c,d,e,f from t2; +drop table t2; +--echo now this will copy hidden fields +create table t2 as select a,b,c,d,e,f from t1; +desc t2; +select * from t2; +select a,b,c,d,e,f from t2; +drop table t2,t1; + +--echo some test related to copy of data from one table to another; +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +select a,b,c,d,e,f from t1; +create table t2(a int , b int hidden , c int hidden , d blob , e int unique, f int); +insert into t2 select * from t1; +select a,b,c,d,e,f from t2; +truncate t2; +insert into t2 (a,b,c,d,e,f) select a,b,c,d,e,f from t1; +select a,b,c,d,e,f from t2; +truncate t2; +drop table t1,t2; + +--echo some test related to creating view on table with hidden column; +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +create view v as select * from t1; +desc v; +select * from v; +--echo v does not have hidden column; +--error ER_BAD_FIELD_ERROR +select a,b,c,d,e,f from v; +insert into v values(1,21,32,4); +select * from v; +--error ER_BAD_FIELD_ERROR +insert into v(a,b,c,d,e,f) values(1,12,3,4,5,6); +drop view v; + +create view v as select a,b,c,d,e,f from t1; +desc v; +select * from v; +--echo v does have hidden column; +select a,b,c,d,e,f from v; +insert into v values(1,26,33,4,45,66); +select a,b,c,d,e,f from v; +insert into v(a,b,c,d,e,f) values(1,32,31,41,5,6); +select a,b,c,d,e,f from v; +drop view v; +drop table t1; + +--echo now hidden column in where and some join query i think no use of this test but anyway; +create table t1 (a int unique , b int hidden unique, c int unique hidden); +insert into t1(a,b,c) values(1,1,1); +insert into t1(a,b,c) values(2,2,2); +insert into t1(a,b,c) values(3,3,3); +insert into t1(a,b,c) values(4,4,4); +insert into t1(a,b,c) values(21,21,26); +insert into t1(a,b,c) values(31,31,35); +insert into t1(a,b,c) values(41,41,45); +insert into t1(a,b,c) values(22,22,24); +insert into t1(a,b,c) values(32,32,33); +insert into t1(a,b,c) values(42,42,43); +explain select * from t1 where b=3; +select * from t1 where b=3; +explain select * from t1 where c=3; +select * from t1 where c=3; + +create table t2 as select a,b,c from t1; +desc t2; +explain select * from t1,t2 where t1.b = t2.c and t1.c = t2.b; +select * from t1,t2 where t1.b = t2.c and t1.c = t2.b; +drop table t1,t2; diff --git a/mysql-test/t/long_uniques.test b/mysql-test/t/long_uniques.test new file mode 100644 index 0000000..8777aaa --- /dev/null +++ b/mysql-test/t/long_uniques.test @@ -0,0 +1,294 @@
please add also a test case for innodb. In a separate file, long_uniques_innodb.test in particular, test this case: connection con1; start transaction; insert ('bbbb') connection con2; start transaction; insert ('bbbb') see? insert the conflicting value in two simultaneously running transactions. try that in different transaction isolation levels. normally the second transaction should *not* see the first 'bbbb' because the first transaction is not committed yet. But InnoDB next-key locks should guarantee that the second transaction will wait for the first.
+--echo #Structure of tests +--echo #First we will check all option for +--echo #table containing single unique column +--echo #table containing keys like unique(a,b,c,d) etc +--echo #then table containing 2 blob unique etc + +--echo #table with single long blob column; +create table t1(a blob unique); +insert into t1 values(1),(2),(3),(56),('sachin'),('maria'),(123456789034567891),(null),(null),(123456789034567890); + +--echo #table structure; +desc t1; +show create table t1; +show keys from t1; +select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; +--echo # table select we should not be able to see db_row_hash_column; +select * from t1; +--error ER_BAD_FIELD_ERROR +select db_row_hash_1 from t1; +--echo #duplicate entry test; +--error ER_DUP_ENTRY +insert into t1 values(2); +--error ER_DUP_ENTRY +insert into t1 values('sachin'); +--error ER_DUP_ENTRY +insert into t1 values(123456789034567891); +select * from t1; +insert into t1 values(11),(22),(33); +--error ER_DUP_ENTRY +insert into t1 values(12),(22); +select * from t1; +insert into t1 values(repeat('s',4000*10)),(repeat('s',4001*10)); +--error ER_DUP_ENTRY +insert into t1 values(repeat('m',4000*10)),(repeat('m',4000*10)); +insert into t1 values(repeat('m',4001)),(repeat('m',4002)); +truncate table t1; +insert into t1 values(1),(2),(3),(4),(5),(8),(7); + +--echo #now some alter commands; +alter table t1 add column b int; +desc t1; +show create table t1; +--error ER_DUP_ENTRY +insert into t1 values(1,2); +--error ER_DUP_ENTRY +insert into t1 values(2,2); +--error ER_BAD_FIELD_ERROR +select db_row_hash_1 from t1; +--echo #now try to change db_row_hash_1 column; +--error ER_CANT_DROP_FIELD_OR_KEY +alter table t1 drop column db_row_hash_1; +--error ER_CANT_DROP_FIELD_OR_KEY +alter table t1 add column d int , add column e int , drop column db_row_hash_1; +--error ER_BAD_FIELD_ERROR +alter table t1 modify column db_row_hash_1 int ; +--error ER_BAD_FIELD_ERROR +alter table t1 add column a int , add column b int, modify column db_row_hash_1 int ; +--error ER_BAD_FIELD_ERROR +alter table t1 change column db_row_hash_1 dsds int; +--error ER_BAD_FIELD_ERROR +alter table t1 add column asd int, change column db_row_hash_1 dsds int; +alter table t1 drop column b , add column c int; +show create table t1; + +--echo #now add some column with name db_row_hash; +alter table t1 add column db_row_hash_1 int unique; +show create table t1; +--error ER_DUP_ENTRY +insert into t1 values(45,1,55),(46,1,55); +alter table t1 add column db_row_hash_2 int, add column db_row_hash_3 int; +desc t1; +--echo #this should also drop the unique index ; +alter table t1 drop column a; +show create table t1; +show keys from t1; +--echo #add column with unique index on blob ; +alter table t1 add column a blob unique; +show create table t1; +--echo # try to change the blob unique column name; +--echo #this will change index to b tree; +alter table t1 modify column a int ; +show create table t1; +show keys from t1; +alter table t1 add column clm blob unique; +--echo #try changing the name ; +alter table t1 change column clm clm_changed blob; +show create table t1; +show keys from t1; +--echo #now drop the unique key; +alter table t1 drop key clm; +show create table t1; +show keys from t1; +drop table t1; + +create table t1 (a TEXT CHARSET latin1 COLLATE latin1_german2_ci unique); +desc t1; +show keys from t1; + insert into t1 values ('ae'); +--error ER_DUP_ENTRY + insert into t1 values ('AE'); + insert into t1 values ('Ä'); +drop table t1; + +--echo #table with multiple long blob column and varchar text column ; +create table t1(a blob unique, b int , c blob unique , d text unique , e varchar(3000) unique); +insert into t1 values(1,2,3,4,5),(2,11,22,33,44),(3111,222,333,444,555),(5611,2222,3333,4444,5555), +('sachin','ff','fdf','gfgfgfg','hghgr'),('maria','db','frter','dasd','utyuty'), +(123456789034567891,3534534534534,53453453453456,64565464564564,45435345345345), +(123456789034567890,435345345345,657567567567,78967657567567,657567567567567676); + +--echo #table structure; +desc t1; +show create table t1; +show keys from t1; +select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; +--echo #table select we should not be able to see db_row_hash_column; +select * from t1; +--error ER_BAD_FIELD_ERROR +select db_row_hash_1 from t1; +--error ER_BAD_FIELD_ERROR +select db_row_hash_2 from t1; +--error ER_BAD_FIELD_ERROR +select db_row_hash_3 from t1; +--echo #duplicate entry test; +--error ER_DUP_ENTRY +insert into t1 values(21,2,3,42,51); +--error ER_DUP_ENTRY +insert into t1 values('sachin',null,null,null,null); +--error ER_DUP_ENTRY +insert into t1 values(1234567890345671890,4353453453451,6575675675617,789676575675617,657567567567567676); +select * from t1; +insert into t1 values(repeat('s',4000*10),100,repeat('s',4000*10),repeat('s',4000*10), +repeat('s',400)),(repeat('s',4001*10),1000,repeat('s',4001*10),repeat('s',4001*10), +repeat('s',401)); +--error ER_DUP_ENTRY +insert into t1 values(repeat('m',4000*11),10,repeat('s',4000*11),repeat('s',4000*11),repeat('s',400)); +truncate table t1; +insert into t1 values(1,2,3,4,5),(2,11,22,33,44),(3111,222,333,444,555),(5611,2222,3333,4444,5555); + +--echo #now some alter commands; +alter table t1 add column f int; +desc t1; +show create table t1; +--echo #unique key should not break; +--error ER_DUP_ENTRY +insert into t1 values(1,2,3,4,5,6); +--error ER_BAD_FIELD_ERROR +select db_row_hash_1 , db_row_hash_2, db_row_hash_3 from t1; +--echo #now try to change db_row_hash_1 column; +--error ER_CANT_DROP_FIELD_OR_KEY +alter table t1 drop column db_row_hash_1, drop column db_row_hash_2, drop column db_row_hash_3; +--error ER_CANT_DROP_FIELD_OR_KEY +alter table t1 add column dg int , add column ef int , drop column db_row_hash_1; +--error ER_BAD_FIELD_ERROR +alter table t1 modify column db_row_hash_1 int , modify column db_row_hash_2 int, modify column db_row_hash_3 int; +--error ER_BAD_FIELD_ERROR +alter table t1 add column ar int , add column rb int, modify column db_row_hash_1 int , modify column db_row_hash_3 int; +--error ER_BAD_FIELD_ERROR +alter table t1 change column db_row_hash_1 dsds int , change column db_row_hash_2 dfdf int , change column db_row_hash_3 gdfg int ; +--error ER_BAD_FIELD_ERROR +alter table t1 add column asd int, drop column a, change column db_row_hash_1 dsds int, change db_row_hash_3 fdfdfd int; +alter table t1 drop column b , add column g int; +show create table t1; + +--echo #now add some column with name db_row_hash; +alter table t1 add column db_row_hash_1 int unique; +alter table t1 add column db_row_hash_2 int unique; +alter table t1 add column db_row_hash_3 int unique; +show create table t1; + +alter table t1 add column db_row_hash_7 int, add column db_row_hash_5 int , add column db_row_hash_4 int ; +alter table t1 drop column db_row_hash_7,drop column db_row_hash_3, drop column db_row_hash_4; +desc t1; +--echo #this show now break anything; +--error ER_DUP_ENTRY +insert into t1 values(1,2,3,4,5,6,23,5,6); +--echo #this should also drop the unique index; +alter table t1 drop column a, drop column c; +show create table t1; +show keys from t1; +--echo #add column with unique index on blob; +alter table t1 add column a blob unique; +show create table t1; +show keys from t1; +--echo #try to change the blob unique column name; +--echo #this will change index to b tree; +alter table t1 modify column a int , modify column e int; +show create table t1; +show keys from t1; +alter table t1 add column clm1 blob unique,add column clm2 blob unique; +--echo #try changing the name; +alter table t1 change column clm1 clm_changed1 blob, change column clm2 clm_changed2 blob; +show create table t1; +show keys from t1; +--echo #now drop the unique key; +alter table t1 drop key clm1, drop key clm2; +show create table t1; +show keys from t1; +drop table t1; + +--echo #now the table with key on multiple columns; the ultimate test; +create table t1(a blob, b int , c varchar(2000) , d text , e varchar(3000) , f longblob , g int , h text , + unique(a,b,c), unique(c,d,e),unique(e,f,g,h),unique(a,b,c,d,e,f),unique(d,e,f,g,h),unique(a,b,c,d,e,f,g,h)); + +insert into t1 values(1,1,1,1,1,1,1,1),(2,2,2,2,2,2,2,2),(3,3,3,3,3,3,3,3),(4,4,4,4,4,4,4,4),(5,5,5,5,5,5,5,5), +('maria',6,'maria','maria','maria','maria',6,'maria'),('mariadb',7,'mariadb','mariadb','mariadb','mariadb',8,'mariadb'); + +--echo #table structure; +desc t1; +show create table t1; +show keys from t1; +select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; +--echo # table select we should not be able to see db_row_hash_column; +select * from t1; +--error ER_BAD_FIELD_ERROR +select db_row_hash_1 from t1; +--error ER_BAD_FIELD_ERROR +select db_row_hash_2 from t1; +--error ER_BAD_FIELD_ERROR +select db_row_hash_3 from t1; +--echo #duplicate entry test; +--echo #duplicate keys entry; +--error ER_DUP_ENTRY +insert into t1 values(1,1,1,0,0,0,0,0); +--error ER_DUP_ENTRY +insert into t1 values(0,0,1,1,1,0,0,0); +--error ER_DUP_ENTRY +insert into t1 values(0,0,0,0,1,1,1,1); +--error ER_DUP_ENTRY +insert into t1 values(1,1,1,1,1,0,0,0); +--error ER_DUP_ENTRY +insert into t1 values(0,0,0,0,1,1,1,1); +--error ER_DUP_ENTRY +insert into t1 values(1,1,1,1,1,1,1,1); +--error ER_BAD_FIELD_ERROR +select db_row_hash_1,db_row_hash_2,db_row_hash_3,db_row_hash_4,db_row_hash_5 from t1; +--error ER_CANT_DROP_FIELD_OR_KEY +alter table t1 drop column db_row_hash_1, drop column db_row_hash_2, drop column db_row_hash_3; +--error ER_CANT_DROP_FIELD_OR_KEY +alter table t1 add column dg int , add column ef int , drop column db_row_hash_1; +--error ER_BAD_FIELD_ERROR +alter table t1 modify column db_row_hash_1 int , modify column db_row_hash_2 int, modify column db_row_hash_3 int; +--error ER_BAD_FIELD_ERROR +alter table t1 add column ar int , add column rb int, modify column db_row_hash_1 int , modify column db_row_hash_3 int; +--error ER_BAD_FIELD_ERROR +alter table t1 change column db_row_hash_1 dsds int , change column db_row_hash_2 dfdf int , change column db_row_hash_3 gdfg int ; +--error ER_BAD_FIELD_ERROR +alter table t1 add column asd int, drop column a, change column db_row_hash_1 dsds int, change db_row_hash_3 fdfdfd int; + +show create table t1; +--echo # add column named db_row_hash_*; +alter table t1 add column db_row_hash_7 int , add column db_row_hash_5 int, + add column db_row_hash_1 int, add column db_row_hash_2 int; +show create table t1; +show keys from t1; +alter table t1 drop column db_row_hash_7 , drop column db_row_hash_5 , + drop column db_row_hash_1, drop column db_row_hash_2 ; +show create table t1; +show keys from t1; + +--echo #try to change column names; +alter table t1 change column a aa blob , change column b bb blob , change column d dd blob; +show create table t1; +show keys from t1; +alter table t1 change column aa a blob , change column bb b blob , change column dd d blob; +show create table t1; +show keys from t1; + +--echo #now we will change the data type to int and varchar limit so that we no longer require hash_index; +--echo #on key a_b_c; +alter table t1 modify column a int , modify column b int , modify column c int; +show create table t1; +show keys from t1; +--echo #change it back; +alter table t1 modify column a blob , modify column b blob , modify column c blob; +show create table t1; +show keys from t1; + +--echo #try to delete blob column in unique; +truncate table t1; +alter table t1 drop column a, drop column b, drop column c; +show create table t1; +show keys from t1; +--echo #now try to delete keys; +alter table t1 drop key c_d_e, drop key e_f_g_h; +show create table t1; +show keys from t1; +drop table t1; diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index 8dfa519..9d5b4f5 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -7214,3 +7214,5 @@ ER_CALCULATING_DEFAULT_VALUE eng "Got an error when calculating default value for %`s" ER_EXPRESSION_REFERS_TO_UNINIT_FIELD 01000 eng "Expression for field %`-.64s is refering to uninitialized field %`s" +ER_HIDDEN_NOT_NULL_WOUT_DEFAULT + eng "Hidden column '%s' either allow null values or it must have default value"
"... should either allow null values ..." or "... should either be nullable ..."
diff --git a/sql/table.h b/sql/table.h index 651fab7..9d2b279 100644 --- a/sql/table.h +++ b/sql/table.h @@ -330,7 +330,28 @@ enum enum_vcol_update_mode VCOL_UPDATE_ALL };
+/* Field visibility enums */
+enum field_visible_type{ + NOT_HIDDEN=0, + USER_DEFINED_HIDDEN, + MEDIUM_HIDDEN, + FULL_HIDDEN
this could use some comments. Or better names. NOT_HIDDEN is very clear. USER_DEFINED_HIDDEN is kind of ok too. But MEDIUM_HIDDEN is not - what does that mean? Please, either add a comment, like // pseudo-columns (like ROWID). Can be queried explicitly in SELECT, otherwise hidden from anything or rename MEDIUM_HIDDEN to something self-explanatory (may be, PSEUDO_COLUMN_HIDDEN?). FULL_HIDDEN is ok, although FULLY_HIDDEN or COMPLETELY_HIDDEN is a bit easier to read, I'd think.
+}; + +int rem_field_from_hash_col_str(LEX_STRING *hash_lex, const char *field_name);
confus way to abbr words. plz rena to smth lik remove_field_from_hash_index or, may be remove_field_from_hash_index_def remove_field_from_hash_index_sql by the way, this function isn't used anywhere. Forgot to remove it?
+ +int change_field_from_hash_col_str(LEX_STRING *hash_lex, + const char *old_name, char *new_name);
1. notice many <Tab> characters on the previous line that indent that line way too much. 2. this function doesn't seem to be used either
+ +int find_field_name_in_hash(char * hash_str, const char *field_name, + int hash_str_length);
again, many <Tab>s on the previous line. Prefer spaces, please.
+ +int find_field_index_in_hash(LEX_STRING * hash_lex, const char * field_name);
name's pretty bad, compared to find_field_name_in_hash. better rename the previous function to find_field_pos_in_hash_str or something like that.
+ +int fields_in_hash_str(LEX_STRING *hash_lex); + +Field * field_ptr_in_hash_str(LEX_STRING * hash_str, TABLE *table, int index); /** Category of table found in the table share. */ @@ -1031,6 +1052,19 @@ struct TABLE Field **field; /* Pointer to fields */
uchar *record[2]; /* Pointer to records */ + uchar *check_unique_buf; /* Pointer to record with same hash */
better comment: /* record buf to resolve hash collisions for long UNIQUE constraints */
+ handler *update_handler; /* Handler used in case of update */
I don't think you need to store it in the TABLE. You can either pass it as an argument to ha_update_row() or invoke check_duplicate_long_entries() before ha_update_row() not from it.
+ /* + In the case of write row for long unique we are unable of find + Whick key is voilated because we in case of duplicate we never reach + handler write_row function so print_error will always print that + key 0 is voilated we store which key is voilated in this variable + by default this should be initialized to -1 + */ + int dupp_key; + /* If dupp != -1 then this string + store message which should be printed */ + char *err_message;
I wonder whether you need it. You can issue an error (with my_error()) directly from check_duplicate_long_entries(), no need to store the error till later. If you issue an error early, you'll simply skip handler::print_keydup_error() later.
uchar *write_row_record; /* Used as optimisation in THD::write_row */ uchar *insert_values; /* used by INSERT ... UPDATE */ diff --git a/sql/field.h b/sql/field.h index 05e0615..35a7006 100644 --- a/sql/field.h +++ b/sql/field.h @@ -998,9 +1001,9 @@ class Field: public Value_source virtual int cmp(const uchar *,const uchar *)=0; virtual int cmp_binary(const uchar *a,const uchar *b, uint32 max_length=~0L) { return memcmp(a,b,pack_length()); } - virtual int cmp_offset(uint row_offset) + virtual int cmp_offset(long row_offset)
1. why is that? because old offset was unsigned? 2. better use my_ptrdiff_t type here
{ return cmp(ptr,ptr+row_offset); } - virtual int cmp_binary_offset(uint row_offset) + virtual int cmp_binary_offset(long row_offset) { return cmp_binary(ptr, ptr+row_offset); }; virtual int key_cmp(const uchar *a,const uchar *b) { return cmp(a, b); } diff --git a/sql/sql_select.h b/sql/sql_select.h index 92ba74f..dd55d94 100644 --- a/sql/sql_select.h +++ b/sql/sql_select.h @@ -1818,6 +1825,27 @@ class store_key_field: public store_key When the implementation of this function will be replaced for a proper full version this statement probably should be removed. */ + if (is_hash) + { + Field *f= copy_field.from_field; + String str;
Normally in these cases you should use StringBuffer
+ f->val_str(&str); + if (f->is_null()) + { + *(copy_field.to_ptr-1)= 1; //set it null
why do you write to copy_field.to_ptr directly? store_key methods don't do that anywhere else
+ null_key= true;
where you reset null_key and copy_field.ptr[-1] back to 0?
+ dbug_tmp_restore_column_map(table->write_set, old_map); + return STORE_KEY_OK; + } + CHARSET_INFO* cs= str.charset(); + uchar l[4]; + int4store(l,str.length()); + cs->coll->hash_sort(cs, l, sizeof(l), &nr1, &nr2);
cs= &my_charset_bin; for hash_sort() above, cs= str.charset(); for hash_sort() below.
+ cs->coll->hash_sort(cs, (uchar *)str.ptr(), str.length(), &nr1, &nr2); + int8store(copy_field.to_ptr, nr1); + dbug_tmp_restore_column_map(table->write_set, old_map); + return STORE_KEY_OK;
I suppose you don't need to calculate hashes if null_key is already true for this row (if it's a multi-column key and one of the previous columns was NULL) btw, could you add a test case for that? a test case where f->is_null() is true? like, add assert(0); under that if() and try to create a test case that will cause it to crash.
+ } bzero(copy_field.to_ptr,copy_field.to_length);
copy_field.do_copy(©_field); @@ -1860,6 +1889,26 @@ class store_key_item :public store_key table->write_set); int res= FALSE;
+ if (is_hash) + { + String *str= item->val_str(); + if (item->null_value) + { + *(to_field->ptr - 1)= 1; + null_key= true; + dbug_tmp_restore_column_map(table->write_set, old_map); + return STORE_KEY_OK; + } + CHARSET_INFO *cs= str->charset(); + uchar l[4]; + int4store(l,str->length()); + cs->coll->hash_sort(cs,l,sizeof(l), &nr1, &nr2); + cs->coll->hash_sort(cs, (uchar *)str->ptr(), str->length(), &nr1, &nr2); + int8store(to_field->ptr, nr1); + //no idea what it does
remove this comment, please :) and if you're curious what it does, you can always comment dbug_tmp_use_all_columns() and dbug_tmp_restore_column_map() in this function out and run the test suite in debug build, you'll see how it will crash :) or you can ask, that works too...
+ dbug_tmp_restore_column_map(table->write_set, old_map); + return STORE_KEY_OK; + } /* It looks like the next statement is needed only for a simplified hash function over key values used now in BNLH join. @@ -2271,4 +2320,11 @@ class Pushdown_query: public Sql_alloc bool test_if_order_compatible(SQL_I_List<ORDER> &a, SQL_I_List<ORDER> &b); int test_if_group_changed(List
&list); int create_sort_index(THD *thd, JOIN *join, JOIN_TAB *tab, Filesort *fsort); +/* + It compares the record with same hash to key if + record is equal then return 0 else fetches next + record with same hash and so on if some error + then returns error +*/
better put this comment where a function is defined, in sql_select.cc
+int compare_hash_and_fetch_next(JOIN_TAB *join); #endif /* SQL_SELECT_INCLUDED */ diff --git a/sql/mysqld.cc b/sql/mysqld.cc index fa8f143..eb1769b 100644 --- a/sql/mysqld.cc +++ b/sql/mysqld.cc @@ -8394,6 +8394,7 @@ SHOW_VAR status_vars[]= { {"Feature_dynamic_columns", (char*) offsetof(STATUS_VAR, feature_dynamic_columns), SHOW_LONG_STATUS}, {"Feature_fulltext", (char*) offsetof(STATUS_VAR, feature_fulltext), SHOW_LONG_STATUS}, {"Feature_gis", (char*) offsetof(STATUS_VAR, feature_gis), SHOW_LONG_STATUS}, + {"Feature_hidden_column", (char*) offsetof(STATUS_VAR, feature_hidden_column), SHOW_LONG_STATUS},
I feel that Feature_hidden_columns (plural) would look better here. I know we aren't consistent, there's Feature_dynamic_columns (plural) but Feature_subquery, Feature_timezone (singular), so there is no rule here, unfortunately.
{"Feature_locale", (char*) offsetof(STATUS_VAR, feature_locale), SHOW_LONG_STATUS}, {"Feature_subquery", (char*) offsetof(STATUS_VAR, feature_subquery), SHOW_LONG_STATUS}, {"Feature_timezone", (char*) offsetof(STATUS_VAR, feature_timezone), SHOW_LONG_STATUS}, diff --git a/sql/field.cc b/sql/field.cc index c684e6a..8c17b76 100644 --- a/sql/field.cc +++ b/sql/field.cc @@ -7671,7 +7672,6 @@ uint32 Field_varstring::data_length() { return length_bytes == 1 ? (uint32) *ptr : uint2korr(ptr); } -
restore the empty line, please
/* Functions to create a packed row. Here the number of length bytes are depending on the given max_length diff --git a/sql/item_subselect.cc b/sql/item_subselect.cc index 8bb12ce..45e6cce 100644 --- a/sql/item_subselect.cc +++ b/sql/item_subselect.cc @@ -3899,6 +3899,25 @@ bool subselect_uniquesubquery_engine::copy_ref_key(bool skip_constants) */ DBUG_RETURN(true); } + if ((*copy)->is_hash) + { + if (!(*copy)->null_key && *(copy+1)) + { + (*(copy+1))->nr1= (*copy)->nr1; + (*(copy+1))->nr2= (*copy)->nr2;
I don't get it, why *(copy+1) ?
+ } + else + break; + } + } + //reset nr1 and nr2 + for (store_key **copy=tab->ref.key_copy ; *copy ; copy++) + { + if ((*copy)->is_hash) + { + (*copy)->nr1= 1; + (*copy)->nr2= 4; + } } DBUG_RETURN(false); } diff --git a/sql/item_func.cc b/sql/item_func.cc index 7f8c89c..3c71e8c 100644 --- a/sql/item_func.cc +++ b/sql/item_func.cc @@ -1839,6 +1839,40 @@ void Item_func_int_div::fix_length_and_dec() }
+longlong Item_func_hash::val_int() +{ + unsigned_flag= true; + ulong nr1= 1,nr2= 4; + CHARSET_INFO *cs; + for(uint i= 0;i
val_str(); + if(args[i]->null_value) + { + null_value= 1; + return 0; + } + cs= str->charset(); + uchar l[4]; + int4store(l, str->length()); + cs->coll->hash_sort(cs, l, sizeof(l), &nr1, &nr2); + cs->coll->hash_sort(cs, (uchar *)str->ptr(), str->length(), &nr1, &nr2);
that's the third time I see these sequence of lines (and there's one more below). Why not to put it in a reusable function? like calc_hash_for_unique(&nr1, &nr2, str) { uchar l[4]; int4store(l, str->length()); cs= &my_charset_bin; cs->coll->hash_sort(cs, l, sizeof(l), &nr1, &nr2); cs= str->charset(); cs->coll->hash_sort(cs, (uchar *)str->ptr(), str->length(), &nr1, &nr2); }
+ } + null_value= 0; + //for testing purpose + //nr1=12;
remove that, please ^^^
+ return (longlong)nr1; +} + + +void Item_func_hash::fix_length_and_dec() +{ + maybe_null= 1; + decimals= 0; + max_length= 8; +} + + longlong Item_func_mod::int_op() { DBUG_ASSERT(fixed == 1); diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index 9d7e735..61022e6 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -6191,6 +6192,11 @@ vcol_attribute: lex->alter_info.flags|= Alter_info::ALTER_ADD_INDEX; } | COMMENT_SYM TEXT_STRING_sys { Lex->last_field->comment= $2; } + | HIDDEN_SYM + { + LEX *lex =Lex; + lex->last_field->field_visibility=USER_DEFINED_HIDDEN; + }
Please, make HIDDEN keyword non-reserved. For that it should be added to the keyword_sp rule. And add a test case for it, like --echo # HIDDEN is not reserved create table t1 (hidden int); drop table t1;
;
parse_vcol_expr: @@ -9482,6 +9476,12 @@ function_call_keyword: if ($$ == NULL) MYSQL_YYABORT; } + |HASH_SYM '(' expr_list ')'
You've added it to function_call_keyword rule, but it should have been added to the function_call_conflict rule. See comments before these both rules.
+ { + $$= new (thd->mem_root)Item_func_hash(thd,*$3); + if($$==NULL) + MYSQL_YYABORT; + } | INSERT '(' expr ',' expr ',' expr ',' expr ')' { $$= new (thd->mem_root) Item_func_insert(thd, $3, $5, $7, $9); diff --git a/sql/sql_insert.cc b/sql/sql_insert.cc index 8028779..41f5a55 100644 --- a/sql/sql_insert.cc +++ b/sql/sql_insert.cc @@ -198,6 +198,17 @@ static int check_insert_fields(THD *thd, TABLE_LIST *table_list, TABLE *table= table_list->table; DBUG_ENTER("check_insert_fields");
+ List_iterator<Item> i_iter(values);
1. you don't use i_iter here 2. I'd move the loop into a separate function or a method of TABLE: uint num_of_hiddens_fields() { for (...) } see below
+ int num_of_hiddens_fields= 0; + if (!fields.elements) + { + Field ** f= table->field, *field; + for (; f && (field= *f); f++) + { + if (field->field_visibility != NOT_HIDDEN) + num_of_hiddens_fields++; + } + } if (!table_list->single_table_updatable()) { my_error(ER_NON_INSERTABLE_TABLE, MYF(0), table_list->alias, "INSERT"); @@ -212,7 +223,7 @@ static int check_insert_fields(THD *thd, TABLE_LIST *table_list, table_list->view_db.str, table_list->view_name.str); DBUG_RETURN(-1); } - if (values.elements != table->s->fields) + if (values.elements+num_of_hiddens_fields != table->s->fields)
then this if() becomes: if (values.elements + num_of_hiddens_fields() != table->s->fields) in fact, you can have a function that counts *visible* fields, then this if() becomes simply if (values.elements != table->not_hidden_fields())
{ my_error(ER_WRONG_VALUE_COUNT_ON_ROW, MYF(0), 1L); DBUG_RETURN(-1); @@ -1485,7 +1497,28 @@ bool mysql_prepare_insert(THD *thd, TABLE_LIST *table_list, update_values, false, &map); select_lex->no_wrap_view_item= FALSE; } - + /* + Reason for this condition + suppose this + create table t1 (a int , b int , c int hidden , d int); + create view v as select a,b,c,d from t1; + now query like this fails + insert into v values(1,1,1) + because in insert_view_fields we copy all the fields + whether they are hidden or not we can not do the change + there because there we have only fields name so we need + to manually setup fields as insert_view_fields is called + by only mysql_prepare_insert_check_table function and + mysql_prepare_insert_check_table is called by only by this + function so it is safe to do here + + NOT YET IMPLEMENTED + if (insert_into_view && !is_field_specified_for_view + && fields.elements) + { + Item *ii= fields.pop(); + } + **/
1. I didn't understand the comment, couldn't parse it. Could you, please add some punctuation to it? :) 2. I believe you have a test case for it, and it works. Does it mean that the whole commented block is obsolete and should be removed? If yes, don't forget to remove is_field_specified_for_view declaration.
/* Restore the current context. */ ctx_state.restore_state(context, table_list); } diff --git a/sql/sql_update.cc b/sql/sql_update.cc index d59b8b7..dfe83e7 100644 --- a/sql/sql_update.cc +++ b/sql/sql_update.cc @@ -729,7 +729,17 @@ int mysql_update(THD *thd, */ can_compare_record= records_are_comparable(table); explain->tracker.on_scan_init(); - + for (uint i= 0; i < table->s->keys; i++) + { + if (table->key_info[i].flags & HA_UNIQUE_HASH) + { + if (!table->update_handler)
Can table->update_handler be possibly not NULL here?
+ table->update_handler= table->file->clone(table->s->normalized_path.str, + &table->mem_root);
Note that you create this new handler on the table's memroot! This is wrong, as I've explained in an earlier review, memroot can only be freed as a whole, so by repeating UPDATE statements, you will allocate more and more memory in the table's memroot for update_handler's. You need to allocate it in the thd's memroot, because update_handler's has a life time of only one statement.
+ table->update_handler->ha_external_lock(current_thd, F_RDLCK); + break; + } + } while (!(error=info.read_record(&info)) && !thd->killed) { explain->tracker.on_record_read(); @@ -1912,6 +1929,19 @@ multi_update::initialize_tables(JOIN *join)
if (ignore) table->file->extra(HA_EXTRA_IGNORE_DUP_KEY); + + for (uint i= 0; i < table->s->keys; i++) + { + if (table->key_info[i].flags & HA_UNIQUE_HASH) + { + if (!table->update_handler) + table->update_handler= table->file->clone(table->s->normalized_path.str, + &table->mem_root); + table->update_handler->ha_external_lock(current_thd, F_RDLCK); + break; + } + }
same code as in mysql_update(), right? better move it to a small function. For example, handler *create_update_handler(THD *thd, TABLE *table) { handler *update_handler= 0; for (uint i= 0; i < table->s->keys; i++) { if (table->key_info[i].flags & HA_UNIQUE_HASH) { update_handler= table->file->clone(table->s->normalized_path.str, &table->mem_root); update_handler->ha_external_lock(thd, F_RDLCK); return update_handler; } } return NULL; }
+ if (table == main_table) // First table in join { if (safe_update_on_fly(thd, join->join_tab, table_ref, all_tables)) @@ -2039,6 +2069,13 @@ multi_update::~multi_update() for (table= update_tables ; table; table= table->next_local) { table->table->no_keyread= table->table->no_cache= 0; + if (table->table->update_handler) + { + table->table->update_handler->ha_external_lock(current_thd, F_UNLCK); + table->table->update_handler->ha_close(); + delete table->table->update_handler; + table->table->update_handler= NULL; + }
same here: void delete_update_handler(THD *thd, handler *h) { if (h) { h->ha_external_lock(thd, F_UNLCK); h->ha_close(); delete h; } } by the way, try to avoid current_thd, if possible. it is farily expensive on some platforms.
if (ignore) table->table->file->extra(HA_EXTRA_NO_IGNORE_DUP_KEY); } diff --git a/sql/unireg.cc b/sql/unireg.cc index 19d03d2..d502b68 100644 --- a/sql/unireg.cc +++ b/sql/unireg.cc @@ -89,6 +89,26 @@ static uchar *extra2_write(uchar *pos, enum extra2_frm_value_type type, return extra2_write(pos, type, reinterpret_cast
(str)); } +static uchar *extra2_write_field_visibility_hash_info(uchar *pos,
please, rename to extra2_write_additional_field_properties or something like that.
+ int number_of_fields,List_iterator
* it) +{ + *pos++=EXTRA2_FIELD_FLAGS; + /* + always 2 first for field visibility + second for is this column represent long unique hash + */ + size_t len = 2*number_of_fields; + pos= extra2_write_len(pos,len); + Create_field *cf; + while((cf=(*it)++)) + { + *pos++=cf->field_visibility; + *pos++=cf->is_long_column_hash;
you can do one byte per field, field_visibility is only two bits, is_long_column_hash is one bit.
+ } + return pos; +} + + /** Create a frm (table definition) file
@@ -121,6 +141,22 @@ LEX_CUSTRING build_frm_image(THD *thd, const char *table, uchar *frm_ptr, *pos; LEX_CUSTRING frm= {0,0}; DBUG_ENTER("build_frm_image"); + List_iterator
it(create_fields); + Create_field *field; + bool is_hidden_fields_present= false;
please, rename to "have_additional_field_properties"
+ /* + Loop througt the iterator to find whether we have any field whose + visibility_type != NOT_HIDDEN + */
Please remove the comment above. Remember, a comment needs to say *why* you are doing something, it should not say *what* you are doing. In this case your comment merely says what the loop below is doing, the comment is in English, the loop in C++, but otherwise they say exactly the same thing. If you rename the variable (as I suggested above) this loop will be completely clear without any comments anyway.
+ while ((field=it++)) + { + if (field->field_visibility != NOT_HIDDEN) + { + is_hidden_fields_present= true; + break; + } + } + it.rewind();
/* If fixed row records, we need one bit to check for deleted rows */ if (!(create_info->table_options & HA_OPTION_PACK_RECORD)) @@ -265,7 +303,9 @@ LEX_CUSTRING build_frm_image(THD *thd, const char *table, pos+= gis_field_options_image(pos, create_fields); } #endif /*HAVE_SPATIAL*/ - + if (is_hidden_fields_present) + pos=extra2_write_field_visibility_hash_info(pos,create_fields.elements,&it); + it.rewind();
you can rewind from inside extra2_write_field_visibility_hash_info. seems logical - it moves the iterator, it should restore it
int4store(pos, filepos); // end of the extra2 segment pos+= 4;
diff --git a/sql/sql_base.cc b/sql/sql_base.cc index 3481bf1..ce63a88 100644 --- a/sql/sql_base.cc +++ b/sql/sql_base.cc @@ -5287,6 +5287,8 @@ find_field_in_table(THD *thd, TABLE *table, const char *name, uint length,
if (field_ptr && *field_ptr) { + if ((*field_ptr)->field_visibility == FULL_HIDDEN) + DBUG_RETURN((Field*) 0);
good. please add a test case for that, with a subquery and an outer reference, as I wrote earlier.
*cached_field_index_ptr= field_ptr - table->field; field= *field_ptr; } @@ -7351,6 +7353,10 @@ insert_fields(THD *thd, Name_resolution_context *context, const char *db_name,
for (; !field_iterator.end_of_fields(); field_iterator.next()) { + /* Field can be null here details in test case*/
"details in test case" is not very helpful. in what case can field be 0 here?
+ if ((field= field_iterator.field()) && + field->field_visibility != NOT_HIDDEN) + continue; Item *item;
if (!(item= field_iterator.create_item(thd))) @@ -7986,6 +7992,42 @@ fill_record(THD *thd, TABLE *table, Field **ptr, List<Item> &values, only one row. */ table->auto_increment_field_not_null= FALSE; + Field **f; + List_iterator<Item> i_iter(values); + uint field_count= 0; + for (f= ptr; f && (field= *f); f++) + field_count++; + /* + This if is required in query like + suppose table + create table t1 (a int , b int hidden , c int , d int hidden ); + and query is + create table t2 as select a,b,c,d from t1; + in this case field count will be equal to values.elements + */ + if (field_count != values.elements) + { + Name_resolution_context *context= & thd->lex->select_lex.context; + for (f= ptr; f && (field= *f); f++) + { + if (field->field_visibility!=NOT_HIDDEN) + { + if (f == ptr) + { + values.push_front(new (thd->mem_root) + Item_default_value(thd,context),thd->mem_root); + i_iter.rewind(); + i_iter++; + } + else + i_iter.after(new (thd->mem_root) Item_default_value(thd,context)); + } + else + i_iter++; + } + f= ptr; + i_iter.rewind(); + }
I don't understand what this is doing and why. Could you explain, please?
while ((field = *ptr++) && ! thd->is_error()) { /* Ensure that all fields are from the same table */ diff --git a/sql/handler.cc b/sql/handler.cc index 3fbd1b3..99e043b 100644 --- a/sql/handler.cc +++ b/sql/handler.cc @@ -5875,6 +5883,132 @@ int handler::ha_reset() DBUG_RETURN(reset()); }
+/** @brief + check whether inserted/updated records breaks the + unique constraint on long columns. + In the case of update we just need to check the specic key + reason for that is consider case + create table t1(a blob , b blob , x blob , y blob ,unique(a,b) + ,unique(c,d)) + and update statement like this + update t1 set a=23+a; in this case if we try to scan for + whole keys in table then index scan on c_d will return 0 + because data is same so in the case of update we take + key as a parameter in normal insert key should be -1
Sorry, I didn't understand this comment. Could you rephrase it? btw, there are no columns 'c' and 'd' in your table example. also, please, explain all function parameters here (use @param).
+ @returns 0 if no duplicate else returns error + */ +int check_duplicate_long_entries(TABLE *table, handler *h, uchar *new_rec, + int key) +{ + Field *hash_field; + int result; + table->dupp_key= -1; + for (uint i= 0; i < table->s->keys; i++) + { + if (key != -1) + i= key; + if (table->key_info[i].flags & HA_UNIQUE_HASH) + {
you invoke check_duplicate_long_entries() only in two places. one is in check_duplicate_long_entries_update(), inside the loop that checks for (table->key_info[i].flags & HA_UNIQUE_HASH). So I really don't see why you need to repeat this loop and the check here. The second invocation is in ha_write_row(), where key==-1 and you need a loop, indeed. So, the logical thing to do would be to have a function (let's call if F()) which is the content of this if() and always takes a valid key number as an argument. Then check_duplicate_long_entries() would do: for (uint i= 0; i < table->s->keys; i++) { if (table->key_info[i].flags & HA_UNIQUE_HASH) F(table, h, new_rec, i); } and check_duplicate_long_entries_update() would invoke F() directly. also, note that if a function is only used in one file - like this your check_duplicate_long_entries(), it should be declared static.
+ hash_field= table->key_info[i].key_part->field; + DBUG_ASSERT(table->key_info[i].key_length == HA_HASH_KEY_LENGTH_WITH_NULL); + uchar ptr[HA_HASH_KEY_LENGTH_WITH_NULL]; + + if (hash_field->is_null()) + continue; + + key_copy(ptr, new_rec, &table->key_info[i], + table->key_info[i].key_length, false); + + if (!table->check_unique_buf) + table->check_unique_buf= (uchar *)alloc_root(&table->mem_root, + table->s->reclength*sizeof(uchar)); + + result= h->ha_index_read_idx_map(table->check_unique_buf, + i, ptr, HA_WHOLE_KEY, HA_READ_KEY_EXACT); + if (!result) + { + Item_func_or_sum * temp= static_cast
(hash_field-> + vcol_info->expr_item); + Item_args * t_item= static_cast (temp); + uint arg_count= t_item->argument_count(); + Item ** arguments= t_item->arguments(); + int diff= table->check_unique_buf-new_rec; + Field * t_field; + + for (uint j=0; j < arg_count; j++) + {
Add DBUG_ASSERT(arguments[j]->type() == FIELD_ITEM);
+ t_field= static_cast
(arguments[j])->field; + if(t_field->cmp_binary_offset(diff)) + continue; + } + table->dupp_key= i; + if (!table->err_message) + { + table->err_message= (char *) alloc_root(&table->mem_root, + MAX_KEY_LENGTH); + } + StringBuffer str; + str.length(0); + for(uint i= 0; i < arg_count; i++) + { + t_field= ((Item_field *)arguments[i])->field; + if (str.length()) + str.append('-'); + field_unpack(&str, t_field, new_rec, 5,//since blob can be to long + false);
truncation is a great idea. Two comments: 1. make this 5 a defined constant. Like #define MAX_BLOB_LEN_FOR_ERRMSG 5 2. perhaps 5 is too short? dunno. 3. indicate the truncation. Like if (t_field->pack_length() > MAX_BLOB_LEN_FOR_ERRMSG) str.append(STRING_WITH_LEN("..."));
+ } + memcpy(table->err_message,str.ptr(),str.length()); + return HA_ERR_FOUND_DUPP_KEY; + } + } + if (key != -1) + break; + } + return 0; +} + +/** @brief + check whether updated records breaks the + unique constraint on long columns. + @returns 0 if no duplicate else returns error + */ +int check_duplicate_long_entries_update(TABLE *table, handler *h, uchar *new_rec) +{ + Field **f, *field; + LEX_STRING *ls; + int error; + /* + Here we are comparing whether new record and old record are same + with respect to fields in hash_str + */ + long reclength= table->record[1]-table->record[0]; + for (uint i= 0; i < table->s->keys; i++) + { + if (table->key_info[i].flags & HA_UNIQUE_HASH) + { + ls= &table->key_info[i].key_part->field->vcol_info->expr_str; + for (f= table->field; f && (field= *f); f++) + { + if (find_field_name_in_hash(ls->str, (char *)field->field_name, ls->length) != -1)
ok, I'm confused. Why are you doing that? For INSERT you take the HASH Item and iterate its argument array. That's fine, I get it. For UPDATE you get the vcol expression as a *string* (!!!) and extract column names from there by looking at commas (???). What was that?
+ { + /* Compare fields if they are different then check for duplicates*/ + if(field->cmp_binary_offset(reclength)) + { + if((error= check_duplicate_long_entries(table, table->update_handler, + new_rec, i))) + return error; + /* + break beacuse check_duplicate_long_entries will + take care of remaning fields + */ + break; + } + } + } + } + } + return 0; +}
int handler::ha_write_row(uchar *buf) { @@ -5921,6 +6057,8 @@ int handler::ha_update_row(const uchar *old_data, uchar *new_data)
note that mysql_update can use ha_bulk_update_row() instead of ha_update_row() for some storage engine. I don't think bulk update can work with your code at all, so you need to make sure will_batch is always false if long unique indexes are used (this is easy). See sql_update.cc And there's bulk insert too, start_bulk_insert(), that you probably need to disable as well.
mark_trx_read_write(); increment_statistics(&SSV::ha_update_count);
+ if ((error= check_duplicate_long_entries_update(table, table->file, new_data))) + return error; TABLE_IO_WAIT(tracker, m_psi, PSI_TABLE_UPDATE_ROW, active_index, 0, { error= update_row(old_data, new_data);})
diff --git a/sql/sql_show.cc b/sql/sql_show.cc index 30c65e6..a55cccd 100644 --- a/sql/sql_show.cc +++ b/sql/sql_show.cc @@ -1972,6 +1976,25 @@ int show_create_table(THD *thd, TABLE_LIST *table_list, String *packet, } append_create_options(thd, packet, field->option_list, check_options, hton->field_options); + //TODO need a better logic to find wheter to put comma or not + int i=1; + bool is_comma_needed=false; + if (*(ptr+i)!=NULL) + { + is_comma_needed=true; + while((*(ptr+i))->field_visibility==MEDIUM_HIDDEN || + (*(ptr+i))->field_visibility==FULL_HIDDEN) + { + i++; + if(!*(ptr+i)) + { + is_comma_needed =false; + break; + } + } + } + if(is_comma_needed) + packet->append(STRING_WITH_LEN(",\n"));
What was wrong with the old logic? Print the comma before every visible column, excluding the first one. You only need to replace the "first one" condition, like - if (ptr != table->field) + if (not_the_first_field) packet->append(STRING_WITH_LEN(",\n")); + not_the_first_field= true;
}
key_info= table->key_info; @@ -1986,6 +2009,19 @@ int show_create_table(THD *thd, TABLE_LIST *table_list, String *packet, for (uint i=0 ; i < share->keys ; i++,key_info++) { KEY_PART_INFO *key_part= key_info->key_part; + if (key_info->flags & HA_UNIQUE_HASH) + { + char * column_names= key_part->field->vcol_info-> + expr_str.str + HA_HASH_STR_LEN; + int length= key_part->field->vcol_info->expr_str.length; + length-= HA_HASH_STR_LEN; + packet->append(STRING_WITH_LEN(",\n")); + packet->append(STRING_WITH_LEN(" UNIQUE KEY `")); + packet->append(key_info->name, strlen(key_info->name)); + packet->append(STRING_WITH_LEN("`")); + packet->append(column_names, length);
No, I'm afraid you cannot do that. You need to generate the column list by iterating arguments and printing them. Add this test case to your long_uniques.test: create table t1 (a int, b int, c blob, d blob, unique(a,b), unique(c,d)); set sql_quote_show_create=0; show create table t1; set sql_quote_show_create=default; show create table t1; set sql_mode=ansi_quotes; show create table t1; set sql_mode=default; (you don't need create table as above, of course, you can use any existing table in the test file).
+ continue; + } bool found_primary=0; packet->append(STRING_WITH_LEN(",\n "));
@@ -5411,6 +5447,10 @@ static int get_schema_column_record(THD *thd, TABLE_LIST *tables,
for (; (field= *ptr) ; ptr++) { + if(field->field_visibility == FULL_HIDDEN || + field->field_visibility == MEDIUM_HIDDEN) + continue; + /* For now we will only show UNI or MUL for TODO */
what do you mean by this comment?
uchar *pos; char tmp[MAX_FIELD_WIDTH]; String type(tmp,sizeof(tmp), system_charset_info); @@ -5465,20 +5505,48 @@ static int get_schema_column_record(THD *thd, TABLE_LIST *tables, pos=(uchar*) ((field->flags & PRI_KEY_FLAG) ? "PRI" : (field->flags & UNIQUE_KEY_FLAG) ? "UNI" : (field->flags & MULTIPLE_KEY_FLAG) ? "MUL":""); + KEY *key= show_table->key_info; + for (int i=0; i
s->keys; i++, key++) + { + if (key->flags & HA_UNIQUE_HASH) + { + LEX_STRING * ls= &key->key_part->field->vcol_info->expr_str; + int position= find_field_index_in_hash(ls, field->field_name); + int fields= fields_in_hash_str(ls); + //this is for single hash(`abc`) + if (position == 0 && fields == 1) + { + pos= (uchar *) "UNI"; + } + //this is for hash(`abc`,`xyzs`) + if (position == 0 && fields > 1) + { + pos=(uchar *) "MUL"; + } + } + }
really? why wouldn't you set UNIQUE_KEY_FLAG or MULTIPLE_KEY_FLAG instead so that the old code would just work for your new keys?
table->field[16]->store((const char*) pos, strlen((const char*) pos), cs); - + StringBuffer<256> buf; if (field->unireg_check == Field::NEXT_NUMBER) - table->field[17]->store(STRING_WITH_LEN("auto_increment"), cs); + buf.set(STRING_WITH_LEN("auto_increment"),cs); if (print_on_update_clause(field, &type, true)) - table->field[17]->store(type.ptr(), type.length(), cs); + buf.set(type.ptr(), type.length(),cs); if (field->vcol_info) { if (field->vcol_info->stored_in_db) - table->field[17]->store(STRING_WITH_LEN("PERSISTENT"), cs); + buf.set(STRING_WITH_LEN("PERSISTENT"), cs); else - table->field[17]->store(STRING_WITH_LEN("VIRTUAL"), cs); + buf.set(STRING_WITH_LEN("VIRTUAL"), cs); + } + /*hidden can coexist with auto_increment and virtual */ + if(field->field_visibility==USER_DEFINED_HIDDEN) + { + if (buf.length()) + buf.append(STRING_WITH_LEN(" , "));
no space before the comma
+ buf.append(STRING_WITH_LEN("HIDDEN"),cs); } + table->field[17]->store(buf.ptr(), buf.length(), cs); table->field[19]->store(field->comment.str, field->comment.length, cs); if (schema_table_store_record(thd, table)) DBUG_RETURN(1); @@ -6030,6 +6098,89 @@ int fill_schema_proc(THD *thd, TABLE_LIST *tables, COND *cond) DBUG_RETURN(res); }
+static int print_get_schema_stat_keypart(THD *thd, TABLE_LIST *tables, + TABLE *table,TABLE *show_table, + LEX_STRING *db_name, + LEX_STRING *table_name, + KEY * key_info,KEY_PART_INFO + *key_part,Field * field ,int i,int j)
1. lots of tabs above that mess up the indentation. 2. Function comment, please. 3. i and j are *really* lousy argument names, please rename.
+{ + CHARSET_INFO *cs= system_charset_info; + const char *str; + restore_record(table, s->default_values); + table->field[0]->store(STRING_WITH_LEN("def"), cs); + table->field[1]->store(db_name->str, db_name->length, cs); + table->field[2]->store(table_name->str, table_name->length, cs); + table->field[3]->store((longlong) ((key_info->flags & + HA_NOSAME) ? 0 : 1), TRUE); + table->field[4]->store(db_name->str, db_name->length, cs); + table->field[5]->store(key_info->name, strlen(key_info->name), cs); + table->field[6]->store((longlong) (j+1), TRUE); + str=field ? field->field_name :"?unknown field?"; + table->field[7]->store(str, strlen(str), cs); + if (show_table->file) + { + if (show_table->file->index_flags(i, j, 0) & HA_READ_ORDER) + { + table->field[8]->store(((key_part->key_part_flag & + HA_REVERSE_SORT) ? + "D" : "A"), 1, cs); + table->field[8]->set_notnull(); + } + KEY *key=show_table->key_info+i; + if (key->rec_per_key[j]) + { + ha_rows records= (ha_rows) ((double) show_table->stat_records() / + key->actual_rec_per_key(j)); + table->field[9]->store((longlong) records, TRUE); + table->field[9]->set_notnull(); + } + /* + In the case of long unique hash as we try + to calc key->rec_per_key[j] it will give zero + so cardinality will be set to null we do not want + this so + */
why not? if you don't know the cardinality - set it to NULL. but, in fact, it shouldn't be zero, why is it?
+ if (key_info->flags & HA_UNIQUE_HASH) + { + table->field[9]->store(0, TRUE); + table->field[9]->set_notnull(); + } + if (key_info->flags & HA_UNIQUE_HASH) + table->field[13]->store(HA_HASH_STR_INDEX,HA_HASH_STR_INDEX_LEN , cs);
I don't think you need to define that string, just put it here like table->field[13]->store(STRING_WITH_LEN("HASH_INDEX") , cs);
+ else + { + str= show_table->file->index_type(i); + table->field[13]->store(str, strlen(str), cs); + } + } + if (!(key_info->flags & HA_FULLTEXT) && + (key_part->field && + key_part->length != + show_table->s->field[key_part->fieldnr-1]->key_length())) + { + table->field[10]->store((longlong) key_part->length / + key_part->field->charset()->mbmaxlen, TRUE); + table->field[10]->set_notnull(); + } + uint flags= key_part->field ? key_part->field->flags : 0; + const char *pos=(char*) ((flags & NOT_NULL_FLAG) ? "" : "YES"); + table->field[12]->store(pos, strlen(pos), cs); + if (!show_table->s->keys_in_use.is_set(i)) + table->field[14]->store(STRING_WITH_LEN("disabled"), cs); + else + table->field[14]->store("", 0, cs); + table->field[14]->set_notnull(); + DBUG_ASSERT(MY_TEST(key_info->flags & HA_USES_COMMENT) == + (key_info->comment.length > 0)); + if (key_info->flags & HA_USES_COMMENT) + table->field[15]->store(key_info->comment.str, + key_info->comment.length, cs); + if (schema_table_store_record(thd, table)) + return 1; + return 0; +} +
static int get_schema_stat_record(THD *thd, TABLE_LIST *tables, TABLE *table, bool res, @@ -6066,67 +6217,34 @@ static int get_schema_stat_record(THD *thd, TABLE_LIST *tables, HA_STATUS_TIME); set_statistics_for_table(thd, show_table); } for (uint i=0 ; i < show_table->s->keys ; i++, key_info++) { KEY_PART_INFO *key_part= key_info->key_part; - const char *str; for (uint j=0 ; j < key_info->user_defined_key_parts; j++, key_part++) { - restore_record(table, s->default_values); - table->field[0]->store(STRING_WITH_LEN("def"), cs); - table->field[1]->store(db_name->str, db_name->length, cs); - table->field[2]->store(table_name->str, table_name->length, cs); - table->field[3]->store((longlong) ((key_info->flags & - HA_NOSAME) ? 0 : 1), TRUE); - table->field[4]->store(db_name->str, db_name->length, cs); - table->field[5]->store(key_info->name, strlen(key_info->name), cs); - table->field[6]->store((longlong) (j+1), TRUE); - str=(key_part->field ? key_part->field->field_name : - "?unknown field?"); - table->field[7]->store(str, strlen(str), cs); - if (show_table->file) + + if (key_info->flags & HA_UNIQUE_HASH && key_info->key_part->field) { - if (show_table->file->index_flags(i, j, 0) & HA_READ_ORDER) + LEX_STRING *ls = &key_info->key_part->field->vcol_info->expr_str; + int total_fields= fields_in_hash_str(ls); + int counter= 0; + Field *fld; + while (counter < total_fields) { - table->field[8]->store(((key_part->key_part_flag & - HA_REVERSE_SORT) ? - "D" : "A"), 1, cs); - table->field[8]->set_notnull(); - } - KEY *key=show_table->key_info+i; - if (key->rec_per_key[j]) - { - ha_rows records= (ha_rows) ((double) show_table->stat_records() / - key->actual_rec_per_key(j)); - table->field[9]->store((longlong) records, TRUE); - table->field[9]->set_notnull(); + fld= field_ptr_in_hash_str(ls, show_table, counter);
parsing strings, again? don't do that, please.
+ if(print_get_schema_stat_keypart(thd, tables, table, + show_table, db_name, + table_name, key_info, + key_part, fld, i, counter)) + DBUG_RETURN(1); + counter++; } - str= show_table->file->index_type(i); - table->field[13]->store(str, strlen(str), cs); - } - if (!(key_info->flags & HA_FULLTEXT) && - (key_part->field && - key_part->length != - show_table->s->field[key_part->fieldnr-1]->key_length())) - { - table->field[10]->store((longlong) key_part->length / - key_part->field->charset()->mbmaxlen, TRUE); - table->field[10]->set_notnull(); + + continue; } - uint flags= key_part->field ? key_part->field->flags : 0; - const char *pos=(char*) ((flags & NOT_NULL_FLAG) ? "" : "YES"); - table->field[12]->store(pos, strlen(pos), cs); - if (!show_table->s->keys_in_use.is_set(i)) - table->field[14]->store(STRING_WITH_LEN("disabled"), cs); - else - table->field[14]->store("", 0, cs); - table->field[14]->set_notnull(); - DBUG_ASSERT(MY_TEST(key_info->flags & HA_USES_COMMENT) == - (key_info->comment.length > 0)); - if (key_info->flags & HA_USES_COMMENT) - table->field[15]->store(key_info->comment.str, - key_info->comment.length, cs); - if (schema_table_store_record(thd, table)) + + if(print_get_schema_stat_keypart(thd, tables,table,show_table,db_name, + table_name,key_info,key_part,key_part->field,i,j)) DBUG_RETURN(1); } } @@ -6134,7 +6252,6 @@ static int get_schema_stat_record(THD *thd, TABLE_LIST *tables, DBUG_RETURN(res); }
-
add the empty line back, please
static int get_schema_views_record(THD *thd, TABLE_LIST *tables, TABLE *table, bool res, LEX_STRING *db_name, diff --git a/sql/table.cc b/sql/table.cc index 640ab82..5d5be01 100644 --- a/sql/table.cc +++ b/sql/table.cc @@ -685,7 +685,7 @@ static bool create_key_infos(const uchar *strpos, const uchar *frm_image_end, uint keys, KEY *keyinfo, uint new_frm_ver, uint &ext_key_parts, TABLE_SHARE *share, uint len, - KEY *first_keyinfo, char* &keynames) + KEY *first_keyinfo, char* &keynames,const uchar *key_ex_flags)
this new argument seems to be unused
{ uint i, j, n_length; KEY_PART_INFO *key_part= NULL; @@ -738,7 +738,6 @@ static bool create_key_infos(const uchar *strpos, const uchar *frm_image_end, keyinfo->algorithm= HA_KEY_ALG_UNDEF; strpos+=4; } -
don't delete empty lines, please, restore them all
if (i == 0) { ext_key_parts+= (share->use_ext_keys ? first_keyinfo->user_defined_key_parts*(keys-1) : 0); @@ -801,7 +799,8 @@ static bool create_key_infos(const uchar *strpos, const uchar *frm_image_end, keyinfo->ext_key_parts= keyinfo->user_defined_key_parts; keyinfo->ext_key_flags= keyinfo->flags; keyinfo->ext_key_part_map= 0; - if (share->use_ext_keys && i && !(keyinfo->flags & HA_NOSAME)) + if (share->use_ext_keys && i && !(keyinfo->flags & HA_NOSAME) + )
revert
{ for (j= 0; j < first_key_parts && keyinfo->ext_key_parts < MAX_REF_PARTS; @@ -989,6 +988,7 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, const uchar *frm_image_end = frm_image + frm_length; uchar *record, *null_flags, *null_pos, *mysql57_vcol_null_pos; const uchar *disk_buff, *strpos; + const uchar * field_properties=NULL,*key_ex_flags=NULL;
this key_ex_flags is not used for anything
ulong pos, record_offset; ulong rec_buff_length; handler *handler_file= 0; @@ -1056,7 +1056,7 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, if (length < 256) goto err; } - if (extra2 + length > e2end) + if ( extra2 + length > e2end)
revert
goto err; switch (type) { case EXTRA2_TABLEDEF_VERSION: @@ -1101,6 +1101,9 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, } #endif /*HAVE_SPATIAL*/ break; + case EXTRA2_FIELD_FLAGS: + field_properties = extra2;
imagine in some later MariaDB version we'll need more flags. there may be more than two bytes per column. so here you can check the length and fail with an error (no assert!) if it's not num_of_fields*2.
+ break; default: /* abort frm parsing if it's an unknown but important extra2 value */ if (type >= EXTRA2_ENGINE_IMPORTANT) @@ -1795,6 +1797,16 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, reg_field->field_index= i; reg_field->comment=comment; reg_field->vcol_info= vcol_info; + if(field_properties!=NULL) + { + reg_field->field_visibility=static_cast
(*field_properties++); + reg_field->is_long_column_hash=static_cast<bool>(*field_properties++);
why did you need a cast here? was there compiler warning?
+ } + /* + We will add status variable only when we find a user defined hidden column
"increment". or, better, remove this comment completely, it's obvious anyway
+ */ + if (reg_field->field_visibility == USER_DEFINED_HIDDEN) + status_var_increment(thd->status_var.feature_hidden_column); if (field_type == MYSQL_TYPE_BIT && !f_bit_as_char(pack_flag)) { null_bits_are_used= 1; @@ -2004,13 +2016,27 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write,
field= key_part->field= share->field[key_part->fieldnr-1]; key_part->type= field->key_type(); + /* + Add HA_UNIQUE_HASH flag if keyinfo has only one field + and field has is_long_column_hash flag on + */ + if (keyinfo->user_defined_key_parts == 1 && + field->is_long_column_hash) + { + keyinfo->flags|= HA_UNIQUE_HASH; + keyinfo->ext_key_flags|= HA_UNIQUE_HASH;
why do you set it in ext_key_flags?
+ } if (field->null_ptr) { key_part->null_offset=(uint) ((uchar*) field->null_ptr - share->default_values); key_part->null_bit= field->null_bit; key_part->store_length+=HA_KEY_NULL_LENGTH; - keyinfo->flags|=HA_NULL_PART_KEY; + if (keyinfo->flags & HA_UNIQUE_HASH && + !(keyinfo->flags & HA_NULL_PART_KEY)) + {} + else + keyinfo->flags|=HA_NULL_PART_KEY;
1. why not simply if (!(keyinfo->flags & HA_UNIQUE_HASH)) keyinfo->flags|=HA_NULL_PART_KEY; 2. this needs a comment
keyinfo->key_length+= HA_KEY_NULL_LENGTH; } if (field->type() == MYSQL_TYPE_BLOB || @@ -2124,6 +2149,11 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, if ((keyinfo->flags & HA_NOSAME) || (ha_option & HA_ANY_INDEX_MAY_BE_UNIQUE)) set_if_bigger(share->max_unique_length,keyinfo->key_length); + if (keyinfo->flags & HA_UNIQUE_HASH) + { + keyinfo->ext_key_parts= 1; + keyinfo->ext_key_part_map= 0; + }
why?
} if (primary_key < MAX_KEY && (share->keys_in_use.is_set(primary_key))) @@ -7808,3 +7842,193 @@ double KEY::actual_rec_per_key(uint i) return (is_statistics_from_stat_tables ? read_stats->get_avg_frequency(i) : (double) rec_per_key[i]); } + +/* + find out that whether field name exists in hash_str + return index of hash_str if found other wise returns + -1 +*/ +int find_field_name_in_hash(char * hash_str, const char * field_name, + int hash_str_length)
ok, all these manipulations with the expression *string* should be removed. Column names might contain commas, column names might contain backticks - you don't handle that. And you should not, really, don't use vcol_info->expr_str, use vcol_info->expr_item instead.
+{ + + int j= 0, i= 0; + for (i= 0; i < hash_str_length; i++) + { + while (*(hash_str+i) == *(field_name+j)) + { + i++; + j++; + if(*(field_name+j)=='\0' &&*(hash_str+i)=='`') + goto done; + } + j=0; + } + return -1; + done: + return i; +} + +/* + find out the field positoin in hash_str() + position starts from 0 + else return -1; +*/ +int find_field_index_in_hash(LEX_STRING *hash_lex, const char * field_name) +{ + char *hash_str= hash_lex->str; + int hash_str_length= hash_lex->length; + int field_name_position= find_field_name_in_hash(hash_str, field_name, hash_str_length); + if (field_name_position == -1) + return -1; + int index= 0; + for (int i= 0; i < field_name_position; i++) + { + if (hash_str[i] == ',') + index++; + } + return index; +} + +/* + find total number of field in hash_str +*/ +int fields_in_hash_str(LEX_STRING * hash_lex) +{ + int hash_str_length= hash_lex->length; + char *hash_str= hash_lex->str; + int num_of_fields= 1; + for (int i= 0; i
str; + int i= strlen("hash"), j; + Field **f, *field; + while (i < hash_str->length) + { + if (str[i] == ',') + temp_index++; + if (temp_index >= index) + break; + i++; + } + i+= 2; // now i point to first character of field name + for (j= 0; str[i+j] != '`'; j++) + field_name[j]= str[i+j]; + field_name[j]= '\0'; + for (f= table->field; f && (field= *f); f++) + { + if (!my_strcasecmp(system_charset_info, field->field_name, field_name)) + break; + } + return field; +} + +/* + Remove field name from db_row_hash_* column vcol info str + For example + + hash(`abc`,`xyz`) + remove "abc" will return + 0 and hash_str will be set hash(`xyz`) and length will be set + + hash(`xyz`) + remove "xyz" will return + 0 and hash_str will be set NULL and length will be 0 + hash(`xyz`) + remove "xyzff" will return + 1 no change to hash_str and length + TODO a better and less complex logic +*/ +int rem_field_from_hash_col_str(LEX_STRING * hash_lex, const char * field_name) +{ + /* first of all find field_name in hash_str*/ + char * temp= hash_lex->str; + const char * t_field= field_name; + int i= find_field_name_in_hash(temp, field_name, hash_lex->length); + if ( i != -1) + { + /* + We found the field location + First of all we need to find the + , position and there can be three + situations + 1. two , not a problem remove any one + 2. one , remove this + 3 no , return + */ + // see if there is , before field name + int j= strlen(field_name); + if (*(temp + i -j-2) == ',') + { + hash_lex->length= hash_lex->length- j-2-1;//-2 for two '`' and -1 for ',' + memmove(temp+i-j-2, temp+i+1, hash_lex->length); + return 0; + } + if (*(temp+i+1) == ',') + { + hash_lex->length= hash_lex->length-j-2-1;//-2 for two '`' and -1 for ',' + memmove(temp+i-j-1, temp+i+2, hash_lex->length); + return 0; + } + if (*(temp+i+1) == ')') + { + hash_lex->length= 0; + hash_lex->str= NULL; + return 0; + } + } + return 1; +} +/* returns 1 if old_name not found in hash_lex 0 other wise*/ +int change_field_from_hash_col_str(LEX_STRING * hash_lex, const char * old_name, + char * new_name) +{ + /* first of all find field_name in hash_lex*/ + char * temp= hash_lex->str; + const char * t_field= old_name; + int i= find_field_name_in_hash(temp, old_name, hash_lex->length); + if (i != -1) + { + int len= hash_lex->length-strlen(old_name) + strlen(new_name); + int num= 0; + char temp_arr[len]; + int s_c_position= i - strlen(old_name);//here it represent the posotion of + //'`' before old f_name + for (int index= 0; index < len; index++) + { + if (index >= s_c_position && index < s_c_position+strlen(new_name)) + { + temp_arr[index]= new_name[index-s_c_position]; + continue; + } + if (index >= s_c_position+strlen(new_name)) + { + temp_arr[index]= temp[i+num]; + num++; + continue; + } + temp_arr[index]= temp[index]; + } + strcpy(hash_lex->str, temp_arr); + hash_lex->length= len; + return 0; + } + return 1; +} diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 5cc7798..921cf18 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc
this is impressive :) but to send you something sooner, I'm going to skip your optimizer changes now, I'll send the review of the original project (long UNIQUE constraint) first, then I'll finish the review of the optimizer part.
diff --git a/sql/sql_table.cc b/sql/sql_table.cc index e745fe8..ed8aa8f 100644 --- a/sql/sql_table.cc +++ b/sql/sql_table.cc @@ -3186,6 +3186,177 @@ static void check_duplicate_key(THD *thd, } }
+/* + Add hidden level 3 hash field to table in case of long + unique column + Returns 0 on success + else 1 +*/ + +int add_hash_field(THD * thd, Alter_info *alter_info, Key *current_key, + KEY *current_key_info, KEY *key_info, CHARSET_INFO *cs)
should be declared static
+{ + int num= 1; + List_iterator<Key> key_iter(alter_info->key_list); + List_iterator
key_part_iter(current_key->columns); + List_iterator it(alter_info->create_list); + Create_field *dup_field, * sql_field; + Key_part_spec *temp_colms; + + Create_field *cf= new (thd->mem_root) Create_field(); + cf->flags|= UNSIGNED_FLAG; + cf->length= cf->char_length= HA_HASH_FIELD_LENGTH; + cf->charset= NULL; + cf->decimals= 0; + char *temp_name= (char *)thd->alloc(30); + strcpy(temp_name, HA_DB_ROW_HASH_STR); + char num_holder[10]; //10 is way more but i think it is ok + sprintf(num_holder, "%d",num); + strcat(temp_name, num_holder);
1. my_snprintf, not sprintf. for just one number - strtol 2. "%u" not "%d" 3. with sprintf, you don't need strcat: my_snprintf(temp_name, sizeof(temp_name), "DB_ROW_HASH_%u", num);
+ /* + Check for collusions + */ + while ((dup_field= it++)) + { + if (!my_strcasecmp(system_charset_info, temp_name, dup_field->field_name)) + { + temp_name[12]= '\0'; //now temp_name='DB_ROW_HASH_' + num++; + sprintf(num_holder, "%d",num); + strcat(temp_name, num_holder); + it.rewind(); + } + } + it.rewind(); + cf->field_name= temp_name; + cf->sql_type= MYSQL_TYPE_LONGLONG; + /* hash column should be atmost hidden */
should be "fully hidden"
+ cf->field_visibility= FULL_HIDDEN; + cf->is_long_column_hash= true; + /* add the virtual colmn info */ + Virtual_column_info *v= new (thd->mem_root) Virtual_column_info(); + char * hash_exp= (char *)thd->alloc(1024); + char * key_name= (char *)thd->alloc(252); + strcpy(hash_exp, HA_HASH_STR_HEAD); + temp_colms= key_part_iter++; + strcat(hash_exp, temp_colms->field_name.str); + strcpy(key_name, temp_colms->field_name.str); + strcat(hash_exp, "`"); + while ((temp_colms= key_part_iter++)) + { + while ((sql_field= it++) && + my_strcasecmp(system_charset_info, + temp_colms->field_name.str, sql_field->field_name)) + {} + it.rewind(); + /* + There should be only one key for db_row_hash_* column + we need to give user a error when the accidently query + like + + create table t1(abc blob unique, unique(db_row_hash_1)); + alter table t2 add column abc blob unique,add unique key(db_row_hash_1); + + for this we will iterate through the key_list and + find if and key_part has the same name as of temp_name + */ + if (!sql_field || sql_field->is_long_column_hash) + { + my_error(ER_KEY_COLUMN_DOES_NOT_EXITS, MYF(0), temp_name); + return 1; + }
hmm, are you sure this check is needed? you've just added a column, there can be no existing key that refers to it, can it? Or, may be, you added a column before the code that checks whether a key is valid? In that case, that code will still fail with ER_KEY_COLUMN_DOES_NOT_EXITS, because your column is fully hidden. Either way, your check looks redundant.
+ /* + This test for wrong query like + create table t1(a blob ,unique(a,a)); + */ + if (find_field_name_in_hash(hash_exp, + temp_colms->field_name.str, strlen(hash_exp))!=-1) + { + my_error(ER_DUP_FIELDNAME, MYF(0), temp_colms->field_name.str); + return 1; + } + /* If any field can be null add flag */ + if (!sql_field->flags & NOT_NULL_FLAG) + current_key_info->flags|= HA_NULL_PART_KEY; + strcat(hash_exp, (const char * )","); + strcat(key_name, "_"); + strcat(hash_exp, "`"); + strcat(hash_exp, temp_colms->field_name.str); + strcat(key_name, temp_colms->field_name.str); + strcat(hash_exp, "`");
1. hash_exp is generated incorrectly, you forgot that a column name itself can contain backticks. There are quoting functions in sql_show.cc and as my_snprintf("%`s") 2. do you really need to create a true virtual column here, with the hash expression and store it in the frm? you can store the key as a normal key (with actual blobs, not uint for the hash value), and generate the vcol in init_from_binary_frm_image().
+ } + strcat(hash_exp, (const char * )")"); + v->expr_str.str= hash_exp; + v->expr_str.length= strlen(hash_exp); + v->expr_item= NULL; + v->set_stored_in_db_flag(true); + cf->vcol_info= v; + cf->charset= cs; + cf->create_length_to_internal_length(); + cf->length= cf->char_length= cf->pack_length; + prepare_create_field(cf, NULL, 0); + if (!current_key_info->flags & HA_NULL_PART_KEY) + { + cf->pack_flag^= FIELDFLAG_MAYBE_NULL; + cf->flags^= NOT_NULL_FLAG; + } + alter_info->create_list.push_front(cf,thd->mem_root); + /* Update row offset because field is added in first position */ + int offset=0; + it.rewind(); + while ((dup_field= it++)) + { + dup_field->offset= offset; + if (dup_field->stored_in_db()) + offset+= dup_field->pack_length; + } + it.rewind(); + while ((dup_field= it++)) + { + if (!dup_field->stored_in_db()) + { + dup_field->offset= offset; + offset+= dup_field->pack_length; + } + } + if(current_key->name.length==0) + { + current_key_info->name= key_name; + current_key_info->name_length= strlen(key_name); + key_name= make_unique_key_name(thd, key_name, + key_info, current_key_info); + } + else + current_key_info->name= current_key->name.str; + if (check_if_keyname_exists(current_key_info->name, key_info, + current_key_info)) + { + my_error(ER_DUP_KEYNAME, MYF(0), key_name); + return 1; + } + current_key->type= Key::MULTIPLE; + current_key_info->key_length= cf->pack_length; //length of mysql long column + current_key_info->user_defined_key_parts= 1; + current_key_info->flags= 0; + current_key_info->key_part->fieldnr= 0; + current_key_info->key_part->offset= 0; + current_key_info->key_part->key_type= cf->pack_flag; + current_key_info->key_part->length= cf->pack_length; + /* As key is added in front so update update keyinfo field ref and offset*/ + KEY * t_key = key_info; + KEY_PART_INFO *t_key_part; + while (t_key != current_key_info) + { + t_key_part= t_key->key_part; + for (int i= 0; i < t_key->user_defined_key_parts; i++,t_key_part++) + { + t_key_part->fieldnr+= 1; + t_key_part->offset+= cf->pack_length; + } + t_key++; + } + return 0; +}
/* Preparation for table creation @@ -3283,7 +3454,13 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, /* Fix for prepare statement */ thd->change_item_tree(&sql_field->default_value->expr_item, item); } - + if (sql_field->field_visibility == USER_DEFINED_HIDDEN && + sql_field->flags & NOT_NULL_FLAG && + sql_field->flags & NO_DEFAULT_VALUE_FLAG) + { + my_error(ER_HIDDEN_NOT_NULL_WOUT_DEFAULT, MYF(0), sql_field->field_name);
say "WITHOUT", this "WOUT" looks weird
+ DBUG_RETURN(TRUE); + } if (sql_field->sql_type == MYSQL_TYPE_SET || sql_field->sql_type == MYSQL_TYPE_ENUM) { @@ -3884,10 +4070,24 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, if (f_is_geom(sql_field->pack_flag) && sql_field->geom_type == Field::GEOM_POINT) column->length= MAX_LEN_GEOM_POINT_FIELD; - if (!column->length) - { - my_error(ER_BLOB_KEY_WITHOUT_LENGTH, MYF(0), column->field_name.str); - DBUG_RETURN(TRUE); + if (!column->length) + { + if (key->type == Key::PRIMARY) + { //todo change error message
agree, ER_TOO_LONG_KEY would be better here
+ my_error(ER_BLOB_KEY_WITHOUT_LENGTH, MYF(0), column->field_name.str); + DBUG_RETURN(TRUE); + } + if (!add_hash_field(thd, alter_info, key, key_info, + *key_info_buffer, create_info->default_table_charset)) + { + key_part_info= key_info->key_part; + key_part_info++; + null_fields++; + key_length= HA_HASH_KEY_LENGTH_WITHOUT_NULL; + break; + } + else + DBUG_RETURN(TRUE); } } #ifdef HAVE_SPATIAL @@ -3974,9 +4174,9 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, } else { - my_error(ER_TOO_LONG_KEY, MYF(0), key_part_length); - DBUG_RETURN(TRUE); - } + my_error(ER_TOO_LONG_KEY, MYF(0), key_part_length); + DBUG_RETURN(TRUE);
why don't you call add_hash_field() here? if this place is now impossible, add a DBUG_ASSERT(0) there or remove the if() completely and replace it with an assert. I mean: if (condition) { something; } else { something else; } becomes DBUG_ASSERT(condition); something;
+ } } } // Catch invalid use of partial keys @@ -4021,8 +4221,23 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, } else { - my_error(ER_TOO_LONG_KEY, MYF(0), key_part_length); - DBUG_RETURN(TRUE); + if(key->type != Key::UNIQUE) + { + my_error(ER_TOO_LONG_KEY, MYF(0), key_part_length); + DBUG_RETURN(TRUE); + } + //todo we does not respect length given by user in calculating hash
oh. that's a bug. good that you have a comment about it, there're more urgent issues that this one, but it should be fixed eventually
+ if(!add_hash_field(thd, alter_info, key, key_info, + *key_info_buffer, create_info->default_table_charset)) + { + key_part_info= key_info->key_part; + key_part_info++; + null_fields++; + key_length= HA_HASH_KEY_LENGTH_WITHOUT_NULL; + break; + } + else + DBUG_RETURN(TRUE); } } key_part_info->length= (uint16) key_part_length; @@ -7502,6 +7717,8 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, */ for (f_ptr=table->field ; (field= *f_ptr) ; f_ptr++) { + if (field->field_visibility == FULL_HIDDEN) + continue;
ok, so you recreate DB_ROW_HASH_xxx columns every time
Alter_drop *drop; if (field->type() == MYSQL_TYPE_VARCHAR) create_info->varchar= TRUE; @@ -7818,7 +8057,7 @@ mysql_prepare_alter_table(THD *thd, TABLE *table,
if (key_info->flags & HA_SPATIAL) key_type= Key::SPATIAL; - else if (key_info->flags & HA_NOSAME) + else if (key_info->flags & HA_NOSAME || key_info->flags & HA_UNIQUE_HASH) { if (! my_strcasecmp(system_charset_info, key_name, primary_key_name)) key_type= Key::PRIMARY;
huh? I thought your HA_UNIQUE_HASH indexes cannot be Key::PRIMARY Regards, Sergei Chief Architect MariaDB and security@mariadb.org
Hi Sachim, Sergei! One quick thing I wanted to point out. I did not specifically look at how things get called, but, when defining constants, I don't agree with:
+#define HA_HASH_STR_LEN strlen(HA_HASH_STR)
Or:
+#define HA_HASH_STR_INDEX_LEN strlen(HA_HASH_STR_INDEX)
This hides an underlying strlen. Better make it a real constant value. Perhaps the compiler is smart enough to optimize it away, but why risk it? Another one is why not define them as const char * and const int? This also helps during debugging, as you can do: (gdb) $ print HA_HAST_STR_INDEX_LEN I know that a lot of the code makes use of defines with #define, but why not enforce a bit of type safety while we're at it? Just my 2 cents, feel free to disagree. :) Vicentiu
Hi, Vicențiu! On Aug 26, Vicențiu Ciorbaru wrote:
Hi Sachim, Sergei!
One quick thing I wanted to point out. I did not specifically look at how things get called, but, when defining constants, I don't agree with:
+#define HA_HASH_STR_LEN strlen(HA_HASH_STR)
Or:
+#define HA_HASH_STR_INDEX_LEN strlen(HA_HASH_STR_INDEX)
This hides an underlying strlen. Better make it a real constant value. Perhaps the compiler is smart enough to optimize it away, but why risk it?
Right, we usually use sizeof() for this. With the pattern const LEX_CSTRING ha_hash_str= { STRING_WITH_LEN("HASH") }; although I'm pretty sure that any modern compiler will replace strlen("string") with a constant.
Another one is why not define them as const char * and const int? This also helps during debugging, as you can do:
(gdb) $ print HA_HAST_STR_INDEX_LEN
if you compile with -ggdb3, gdb will show macro values too :)
I know that a lot of the code makes use of defines with #define, but why not enforce a bit of type safety while we're at it?
I don't disagree. As far as this patch is concerned, I hope that in the final version there will be no define for "HASH" or "HASH_INDEX" at all. As a general rule, I agree that typed constants and sizeof() is preferrable. Regards, Sergei Chief Architect MariaDB and security@mariadb.org
Hi Vicențiu
Thanks Vicențiu for your comment. Although I agree with you but defining
#define HA_HASH_STR_LEN 4
or
const int HA_HASH_STR_LEN = 4;
make it independent of length of "hash". Although we rarely gone
change "hash", so I think it
is a good idea. What do you think , Sergei?
Regards
sachin
On Fri, Aug 26, 2016 at 7:26 PM, Vicențiu Ciorbaru
Hi Sachin, Sergei!
One quick thing I wanted to point out. I did not specifically look at how things get called, but, when defining constants, I don't agree with:
+#define HA_HASH_STR_LEN strlen(HA_HASH_STR)
Or:
+#define HA_HASH_STR_INDEX_LEN strlen(HA_HASH_STR_INDEX)
This hides an underlying strlen. Better make it a real constant value. Perhaps the compiler is smart enough to optimize it away, but why risk it?
Another one is why not define them as const char * and const int? This also helps during debugging, as you can do:
(gdb) $ print HA_HAST_STR_INDEX_LEN
I know that a lot of the code makes use of defines with #define, but why not enforce a bit of type safety while we're at it?
Just my 2 cents, feel free to disagree. :) Vicentiu
Hi Sachim,
Sergei's suggestion with STRING_WITH_LEN macro or sizeof("string") should
fix the problem you're raising.
Regards,
Vicentiu
On Fri, 26 Aug 2016 at 18:11 Sachin Setia
Hi Vicențiu
Thanks Vicențiu for your comment. Although I agree with you but defining #define HA_HASH_STR_LEN 4 or const int HA_HASH_STR_LEN = 4;
make it independent of length of "hash". Although we rarely gone change "hash", so I think it is a good idea. What do you think , Sergei? Regards sachin
On Fri, Aug 26, 2016 at 7:26 PM, Vicențiu Ciorbaru
wrote: Hi Sachin, Sergei!
One quick thing I wanted to point out. I did not specifically look at how things get called, but, when defining constants, I don't agree with:
+#define HA_HASH_STR_LEN strlen(HA_HASH_STR)
Or:
+#define HA_HASH_STR_INDEX_LEN strlen(HA_HASH_STR_INDEX)
This hides an underlying strlen. Better make it a real constant value. Perhaps the compiler is smart enough to optimize it away, but why risk it?
Another one is why not define them as const char * and const int? This also helps during debugging, as you can do:
(gdb) $ print HA_HAST_STR_INDEX_LEN
I know that a lot of the code makes use of defines with #define, but why not enforce a bit of type safety while we're at it?
Just my 2 cents, feel free to disagree. :) Vicentiu
Hi Sergei! Actually I changed code as I was suggesting you in previous email. Duplicate scanning , update etc all works fine using this new approach. Currently I am working on optimizer part using this new approach although the normal where works but now I am working on cases involving join and delete and update optimization. I also applied most of the changes suggested by you. but some are left. Regards sachin
Hi Sergei! On 08/24/2016 11:05 PM, Sergei Golubchik wrote: > Hi, Sachin! > > On Aug 13, Sachin Setia wrote: >> Hello Sergei! >> Please review commit 71f9069 onward i have changed >> mysql_prepare_alter_table func. > Okay, here it is. Up to the 03e29c6 (this is one after 71f9069). > > Short summary - this all looks pretty good. There're issues, but as a > whole - great work! > >> diff --git a/include/my_base.h b/include/my_base.h >> index 1317639..d03ca0f 100644 >> --- a/include/my_base.h >> +++ b/include/my_base.h >> @@ -241,6 +241,19 @@ enum ha_base_keytype { >> HA_KEYTYPE_BIT=19 >> }; >> >> +/* Add some constant related to unique long hash column like length hash string etc*/ >> + >> +#define HA_HASH_KEY_LENGTH_WITHOUT_NULL 8 >> +#define HA_HASH_FIELD_LENGTH 8 >> +#define HA_HASH_KEY_LENGTH_WITH_NULL 9 >> +#define HA_HASH_STR_HEAD "hash(`" //used in mysql_prepare_create_table >> +#define HA_HASH_STR_HEAD_LEN strlen(HA_HASH_STR_HEAD_LEN) >> +#define HA_HASH_STR "hash" >> +#define HA_HASH_STR_LEN strlen(HA_HASH_STR) >> +#define HA_HASH_STR_INDEX "HASH_INDEX" >> +#define HA_HASH_STR_INDEX_LEN strlen(HA_HASH_STR_INDEX) >> +#define HA_DB_ROW_HASH_STR "DB_ROW_HASH_" > no need to put all these constants into the very global my_base.h. > better to define them in sql_show.cc or sql_table.cc (depending on where > they're used) Actually first three are needed in files like opt_range.cc. I moved this to table.h >> + >> #define HA_MAX_KEYTYPE 31 /* Must be log2-1 */ >> >> /* >> diff --git a/mysql-test/r/features.result b/mysql-test/r/features.result >> index 52650d1..e050efb 100644 >> --- a/mysql-test/r/features.result >> +++ b/mysql-test/r/features.result >> @@ -7,6 +7,7 @@ Feature_delay_key_write 0 >> Feature_dynamic_columns 0 >> Feature_fulltext 0 >> Feature_gis 0 >> +Feature_hidden_column 0 > Great! > Please, add also a test where it's not 0. I mean, in your hidden_field.test > you can add > > FLUSH STATUS; > > at the beginning of the file and SHOW STATUS LIKE 'Feature_hidden_column'; > somewhere later. This will show that Feature_hidden_column is incremented > accordingly. > Done. >> Feature_locale 0 >> Feature_subquery 0 >> Feature_timezone 0 >> diff --git a/mysql-test/r/hidden_field.result b/mysql-test/r/hidden_field.result >> new file mode 100644 >> index 0000000..09a2c21 >> --- /dev/null >> +++ b/mysql-test/r/hidden_field.result >> @@ -0,0 +1,367 @@ >> +create table h_1(abc int primary key, xyz int hidden); >> +desc h_1; >> +Field Type Null Key Default Extra >> +abc int(11) NO PRI NULL >> +xyz int(11) YES NULL HIDDEN >> +show create table h_1; >> +Table Create Table >> +h_1 CREATE TABLE `h_1` ( >> + `abc` int(11) NOT NULL, >> + `xyz` int(11) HIDDEN DEFAULT NULL, >> + PRIMARY KEY (`abc`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +drop table h_1; >> +create table h_2(a1 int hidden); >> +ERROR 42000: A table must have at least 1 column >> +create table h_3(a1 blob,hidden(a1)); >> +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'hidden(a1))' at line 1 >> +create table h_4(a1 int primary key hidden ,a2 int unique hidden , a3 blob,a4 >> +int not null hidden unique); >> +ERROR HY000: Hidden column 'a1' either allow null values or it must have default value >> +create table h_5(abc int not null hidden); >> +ERROR HY000: Hidden column 'abc' either allow null values or it must have default value >> +create table t1(a int hidden, b int); >> +insert into t1 values(1); >> +insert into t1(a) values(1); >> +insert into t1(b) values(1); > better insert 1,2,3 not 1,1,1 > so that in SELECT you could unambigously see what INSERT has added what row > Changed. >> +insert into t1(a,b) values(5,5); >> +select * from t1; >> +b >> +1 >> +NULL >> +1 >> +5 >> +select a,b from t1; >> +a b >> +NULL 1 >> +1 NULL >> +NULL 1 >> +5 5 >> +delete from t1; >> +insert into t1 values(1),(2),(3),(4); >> +select * from t1; >> +b >> +1 >> +2 >> +3 >> +4 >> +select a from t1; >> +a >> +NULL >> +NULL >> +NULL >> +NULL >> +drop table t1; >> +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); >> +desc t1; >> +Field Type Null Key Default Extra >> +a int(11) YES NULL >> +b int(11) YES NULL HIDDEN >> +c int(11) NO PRI NULL auto_increment , HIDDEN > why a space before the comma? Okay Reverted. >> +d blob YES NULL >> +e int(11) YES UNI NULL >> +f int(11) YES NULL >> +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); >> +select * from t1; >> +a d e f >> +1 d blob 1 1 >> +1 d blob 11 1 >> +1 d blob 2 1 >> +1 d blob 3 1 >> +1 d blob 41 1 >> +drop table t1; >> +create table sdsdsd(a int , b int, hidden(a,b)); >> +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'hidden(a,b))' at line 1 >> +create table t1(a int,abc int as (a mod 3) virtual hidden); >> +desc t1; >> +Field Type Null Key Default Extra >> +a int(11) YES NULL >> +abc int(11) YES NULL VIRTUAL , HIDDEN >> +insert into t1 values(1,default); >> +ERROR 21S01: Column count doesn't match value count at row 1 >> +insert into t1 values(1),(22),(233); >> +select * from t1; >> +a >> +1 >> +22 >> +233 >> +select a,abc from t1; >> +a abc >> +1 1 >> +22 1 >> +233 2 >> +drop table t1; >> +create table t1(abc int primary key hidden auto_increment, a int); >> +desc t1; >> +Field Type Null Key Default Extra >> +abc int(11) NO PRI NULL auto_increment , HIDDEN >> +a int(11) YES NULL >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `abc` int(11) NOT NULL HIDDEN AUTO_INCREMENT, >> + `a` int(11) DEFAULT NULL, >> + PRIMARY KEY (`abc`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +insert into t1 values(1); >> +insert into t1 values(2); >> +insert into t1 values(3); >> +select * from t1; >> +a >> +1 >> +2 >> +3 >> +select abc,a from t1; >> +abc a >> +1 1 >> +2 2 >> +3 3 >> +delete from t1; >> +insert into t1 values(1),(2),(3),(4),(6); >> +select abc,a from t1; >> +abc a >> +4 1 >> +5 2 >> +6 3 >> +7 4 >> +8 6 >> +drop table t1; >> +create table t1(abc int); >> +alter table t1 change abc ss int hidden; >> +ERROR 42000: A table must have at least 1 column >> +alter table t1 add column xyz int; >> +alter table t1 modify column abc int ; >> +desc t1; >> +Field Type Null Key Default Extra >> +abc int(11) YES NULL >> +xyz int(11) YES NULL >> +insert into t1 values(22); >> +ERROR 21S01: Column count doesn't match value count at row 1 >> +alter table t1 modify column abc int hidden; > please, add also tests for making hidden fields visible again. > I think that > > alter table t1 modify column abc int; > > will do the job Okay, Added. >> +desc t1; >> +Field Type Null Key Default Extra >> +abc int(11) YES NULL HIDDEN >> +xyz int(11) YES NULL >> +insert into t1 values(12); >> +drop table t1; >> +some test on copy table structure with table data; >> +table with hidden fields and unique keys; >> +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); >> +desc t1; >> +Field Type Null Key Default Extra >> +a int(11) YES NULL >> +b int(11) YES NULL HIDDEN >> +c int(11) NO PRI NULL auto_increment , HIDDEN >> +d blob YES NULL >> +e int(11) YES UNI NULL >> +f int(11) YES NULL >> +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); >> +select * from t1; >> +a d e f >> +1 d blob 1 1 >> +1 d blob 11 1 >> +1 d blob 2 1 >> +1 d blob 3 1 >> +1 d blob 41 1 >> +select a,b,c,d,e,f from t1; >> +a b c d e f >> +1 NULL 1 d blob 1 1 >> +1 NULL 2 d blob 11 1 >> +1 NULL 3 d blob 2 1 >> +1 NULL 4 d blob 3 1 >> +1 NULL 5 d blob 41 1 >> +this wont copy hidden fields and keys; >> +create table t2 as select * from t1; >> +desc t2; >> +Field Type Null Key Default Extra >> +a int(11) YES NULL >> +d blob YES NULL >> +e int(11) YES NULL >> +f int(11) YES NULL >> +select * from t2; >> +a d e f >> +1 d blob 1 1 >> +1 d blob 11 1 >> +1 d blob 2 1 >> +1 d blob 3 1 >> +1 d blob 41 1 >> +select a,b,c,d,e,f from t2; >> +ERROR 42S22: Unknown column 'b' in 'field list' >> +drop table t2; >> +now this will copy hidden fields >> +create table t2 as select a,b,c,d,e,f from t1; >> +desc t2; >> +Field Type Null Key Default Extra >> +a int(11) YES NULL >> +b int(11) YES NULL HIDDEN >> +c int(11) NO 0 HIDDEN >> +d blob YES NULL >> +e int(11) YES NULL >> +f int(11) YES NULL >> +select * from t2; >> +a d e f >> +1 d blob 1 1 >> +1 d blob 11 1 >> +1 d blob 2 1 >> +1 d blob 3 1 >> +1 d blob 41 1 >> +select a,b,c,d,e,f from t2; >> +a b c d e f >> +1 NULL 1 d blob 1 1 >> +1 NULL 2 d blob 11 1 >> +1 NULL 3 d blob 2 1 >> +1 NULL 4 d blob 3 1 >> +1 NULL 5 d blob 41 1 >> +drop table t2,t1; >> +some test related to copy of data from one table to another; >> +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); >> +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); >> +select a,b,c,d,e,f from t1; >> +a b c d e f >> +1 NULL 1 d blob 1 1 >> +1 NULL 2 d blob 11 1 >> +1 NULL 3 d blob 2 1 >> +1 NULL 4 d blob 3 1 >> +1 NULL 5 d blob 41 1 >> +create table t2(a int , b int hidden , c int hidden , d blob , e int unique, f int); >> +insert into t2 select * from t1; >> +select a,b,c,d,e,f from t2; >> +a b c d e f >> +1 NULL NULL d blob 1 1 >> +1 NULL NULL d blob 11 1 >> +1 NULL NULL d blob 2 1 >> +1 NULL NULL d blob 3 1 >> +1 NULL NULL d blob 41 1 >> +truncate t2; >> +insert into t2 (a,b,c,d,e,f) select a,b,c,d,e,f from t1; >> +select a,b,c,d,e,f from t2; >> +a b c d e f >> +1 NULL 1 d blob 1 1 >> +1 NULL 2 d blob 11 1 >> +1 NULL 3 d blob 2 1 >> +1 NULL 4 d blob 3 1 >> +1 NULL 5 d blob 41 1 >> +truncate t2; >> +drop table t1,t2; >> +some test related to creating view on table with hidden column; >> +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); >> +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); >> +create view v as select * from t1; >> +desc v; >> +Field Type Null Key Default Extra >> +a int(11) YES NULL >> +d blob YES NULL >> +e int(11) YES NULL >> +f int(11) YES NULL >> +select * from v; >> +a d e f >> +1 d blob 1 1 >> +1 d blob 11 1 >> +1 d blob 2 1 >> +1 d blob 3 1 >> +1 d blob 41 1 >> +v does not have hidden column; >> +select a,b,c,d,e,f from v; >> +ERROR 42S22: Unknown column 'b' in 'field list' >> +insert into v values(1,21,32,4); >> +select * from v; >> +a d e f >> +1 d blob 1 1 >> +1 d blob 11 1 >> +1 d blob 2 1 >> +1 d blob 3 1 >> +1 d blob 41 1 >> +1 21 32 4 >> +insert into v(a,b,c,d,e,f) values(1,12,3,4,5,6); >> +ERROR 42S22: Unknown column 'b' in 'field list' >> +drop view v; >> +create view v as select a,b,c,d,e,f from t1; >> +desc v; >> +Field Type Null Key Default Extra >> +a int(11) YES NULL >> +b int(11) YES NULL HIDDEN >> +c int(11) NO 0 HIDDEN >> +d blob YES NULL >> +e int(11) YES NULL >> +f int(11) YES NULL >> +select * from v; >> +a b c d e f >> +1 NULL 1 d blob 1 1 >> +1 NULL 2 d blob 11 1 >> +1 NULL 3 d blob 2 1 >> +1 NULL 4 d blob 3 1 >> +1 NULL 5 d blob 41 1 >> +1 NULL 6 21 32 4 >> +v does have hidden column; >> +select a,b,c,d,e,f from v; >> +a b c d e f >> +1 NULL 1 d blob 1 1 >> +1 NULL 2 d blob 11 1 >> +1 NULL 3 d blob 2 1 >> +1 NULL 4 d blob 3 1 >> +1 NULL 5 d blob 41 1 >> +1 NULL 6 21 32 4 >> +insert into v values(1,26,33,4,45,66); >> +select a,b,c,d,e,f from v; >> +a b c d e f >> +1 NULL 1 d blob 1 1 >> +1 NULL 2 d blob 11 1 >> +1 NULL 3 d blob 2 1 >> +1 NULL 4 d blob 3 1 >> +1 NULL 5 d blob 41 1 >> +1 NULL 6 21 32 4 >> +1 26 33 4 45 66 >> +insert into v(a,b,c,d,e,f) values(1,32,31,41,5,6); >> +select a,b,c,d,e,f from v; >> +a b c d e f >> +1 NULL 1 d blob 1 1 >> +1 NULL 2 d blob 11 1 >> +1 NULL 3 d blob 2 1 >> +1 NULL 4 d blob 3 1 >> +1 NULL 5 d blob 41 1 >> +1 NULL 6 21 32 4 >> +1 26 33 4 45 66 >> +1 32 31 41 5 6 >> +drop view v; >> +drop table t1; >> +now hidden column in where and some join query i think no use of this test but anyway; >> +create table t1 (a int unique , b int hidden unique, c int unique hidden); >> +insert into t1(a,b,c) values(1,1,1); >> +insert into t1(a,b,c) values(2,2,2); >> +insert into t1(a,b,c) values(3,3,3); >> +insert into t1(a,b,c) values(4,4,4); >> +insert into t1(a,b,c) values(21,21,26); >> +insert into t1(a,b,c) values(31,31,35); >> +insert into t1(a,b,c) values(41,41,45); >> +insert into t1(a,b,c) values(22,22,24); >> +insert into t1(a,b,c) values(32,32,33); >> +insert into t1(a,b,c) values(42,42,43); >> +explain select * from t1 where b=3; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 const b b 5 const 1 >> +select * from t1 where b=3; >> +a >> +3 >> +explain select * from t1 where c=3; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 const c c 5 const 1 >> +select * from t1 where c=3; >> +a >> +3 >> +create table t2 as select a,b,c from t1; >> +desc t2; >> +Field Type Null Key Default Extra >> +a int(11) YES NULL >> +b int(11) YES NULL HIDDEN >> +c int(11) YES NULL HIDDEN >> +explain select * from t1,t2 where t1.b = t2.c and t1.c = t2.b; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t2 ALL NULL NULL NULL NULL 10 >> +1 SIMPLE t1 ALL b,c NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) >> +select * from t1,t2 where t1.b = t2.c and t1.c = t2.b; >> +a a >> +1 1 >> +2 2 >> +3 3 >> +4 4 >> +drop table t1,t2; >> diff --git a/mysql-test/r/long_unique_where.result b/mysql-test/r/long_unique_where.result >> new file mode 100644 >> index 0000000..e9bd416 >> --- /dev/null >> +++ b/mysql-test/r/long_unique_where.result >> @@ -0,0 +1,340 @@ >> +create table t1(abc blob unique); >> +insert into t1 values(1),(2),(3),(4),(5),(11),(12),(31),(14),(15),(NULL) >> +,(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL), >> +(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL), >> +(NULL),(NULL),(NULL),(NULL),(NULL); >> +insert into t1 value(1); >> +ERROR 23000: Duplicate entry '1' for key 'abc' >> +explain select * from t1 where abc=31; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 const abc abc 9 const 1 >> +select * from t1 where abc=31; >> +abc >> +31 >> +# in case of null we do not use any optimization >> +explain select * from t1 where abc is NULL; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 36 Using where >> +select * from t1 where abc is NULL limit 1; >> +abc >> +NULL >> +#range query > please clarify it here, for example, like > > #range query (index not used, because it's a hash) > Copied , :). >> +explain select * from t1 where abc >1 limit 1; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 36 Using where >> +select * from t1 where abc >1 limit 1; >> +abc >> +2 >> +explain select * from t1 where abc >1 and abc <4; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 36 Using where >> +select * from t1 where abc >1 and abc <4; >> +abc >> +2 >> +3 >> +explain select * from t1 where abc =15 or abc <4 ; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 36 Using where >> +select * from t1 where abc =15 or abc <4 ; >> +abc >> +1 >> +2 >> +3 >> +15 >> +drop table t1; >> +create table t1(abc blob unique, xyz int ); >> +insert into t1 values(1,1),(2,1),(3,3),(4,1),(5,6),(NULL,3),(NULL,1), >> +(NULL,NULL),(11,11),(12,11),(31,31), >> +(14,1),(15,61),(NULL,32),(NULL,12),(NULL,NULL); >> +insert into t1 value(1,NULL); >> +ERROR 23000: Duplicate entry '1' for key 'abc' >> +explain select * from t1 where abc=15; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 const abc abc 9 const 1 >> +select * from t1 where abc= 15; >> +abc xyz >> +15 61 >> +explain select * from t1 where abc=15 and xyz =61; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 const abc abc 9 const 1 >> +select * from t1 where abc= 15 and 61; > type in the where clause Changed. >> +abc xyz >> +15 61 >> +# now xyz has different value > what do you mean by that? echo # now xyz has a value which is not present in table; Added. >> +explain select * from t1 where abc=1000; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables >> +select * from t1 where abc= 1000; >> +abc xyz >> +explain select * from t1 where abc=14 and xyz =56; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables >> +select * from t1 where abc=14 and xyz =56; >> +abc xyz >> +#range query >> +explain select * from t1 where abc >5 limit 1; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 16 Using where >> +select * from t1 where abc >5 limit 1; >> +abc xyz >> +11 11 >> +explain select * from t1 where abc=5 and xyz <56; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 const abc abc 9 const 1 >> +select * from t1 where abc=5 and xyz <56; >> +abc xyz >> +5 6 >> +explain select * from t1 where abc>=5 and xyz <56; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 16 Using where >> +select * from t1 where abc>=5 and xyz <56; >> +abc xyz >> +5 6 >> +11 11 >> +12 11 >> +31 31 >> +14 1 >> +explain select * from t1 where abc>5 and xyz =56; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 16 Using where >> +select * from t1 where abc>5 and xyz =56; >> +abc xyz >> +drop table t1; >> +create table t1(abc blob unique, xyz blob unique ); >> +insert into t1 values(1,1),(2,11),(3,31),(4,12),(5,63),(NULL,2),(NULL,NULL), >> +(91,19),(92,119),(93,391),(94,192),(95,693); >> +insert into t1 value(1,NULL); >> +ERROR 23000: Duplicate entry '1' for key 'abc' >> +explain select * from t1 where abc=1; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 const abc abc 9 const 1 >> +select * from t1 where abc=1; >> +abc xyz >> +1 1 >> +explain select * from t1 where xyz=1; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 const xyz xyz 9 const 1 >> +select * from t1 where xyz=1; >> +abc xyz >> +1 1 >> +explain select * from t1 where abc=5 and xyz=63; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 const abc abc 9 const 1 >> +select * from t1 where abc=5 and xyz=63; >> +abc xyz >> +5 63 >> +explain select * from t1 where xyz=63 and abc=5; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 const abc abc 9 const 1 >> +select * from t1 where xyz=63 and abc=5; >> +abc xyz >> +5 63 >> +explain select * from t1 where xyz=63 or abc=5; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where >> +select * from t1 where xyz=63 or abc=5; >> +abc xyz >> +5 63 >> +# now the first one does not exist >> +explain select * from t1 where abc=51 and xyz=63; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables >> +select * from t1 where abc=51 and xyz=63; >> +abc xyz >> +# now the second one does not exist >> +explain select * from t1 where abc=5 and xyz=613; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables >> +select * from t1 where abc=5 and xyz=613; >> +abc xyz >> +explain select * from t1 where abc is NULL; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where >> +select * from t1 where abc is NULL; >> +abc xyz >> +NULL 2 >> +NULL NULL >> +explain select * from t1 where abc is NULL and xyz=2; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 const xyz xyz 9 const 1 >> +select * from t1 where abc is NULL and xyz=2; >> +abc xyz >> +NULL 2 >> +#range conditions >> +explain select * from t1 where abc>11 limit 5; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where >> +select * from t1 where abc>11 limit 5; >> +abc xyz >> +91 19 >> +92 119 >> +93 391 >> +94 192 >> +95 693 >> +explain select * from t1 where xyz<11; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where >> +select * from t1 where xyz<11; >> +abc xyz >> +1 1 >> +NULL 2 >> +explain select * from t1 where abc>=51 and xyz<=63; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where >> +select * from t1 where abc>=51 and xyz<=63; >> +abc xyz >> +91 19 >> +explain select * from t1 where abc>5 and xyz<613; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where >> +select * from t1 where abc>5 and xyz<613; >> +abc xyz >> +91 19 >> +92 119 >> +93 391 >> +94 192 >> +explain select * from t1 where abc=5 and xyz>1; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 const abc abc 9 const 1 >> +select * from t1 where abc=5 and xyz>1; >> +abc xyz >> +5 63 >> +explain select * from t1 where abc<55 and xyz=1; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 const xyz xyz 9 const 1 >> +select * from t1 where abc<55 and xyz=1; >> +abc xyz >> +1 1 >> +explain select * from t1 where abc<=55 or xyz>=1; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where >> +select * from t1 where abc<=55 and xyz>=1; >> +abc xyz >> +1 1 >> +2 11 >> +3 31 >> +4 12 >> +5 63 >> +drop table t1; >> +#now the unique (a,b,c..........) >> +#let us do more hard test by using unique(a,b,c,d) key first >> +create table t1 (a blob , b blob , c blob , d blob ,unique(a,b,c,d), >> +unique(a,b,c) ,unique (b,c,d)); > hmm, better do not use redundant keys. it works now, but tenchnically > we can implement the optimization where the server will internally > remove "unique(a,b,c,d)" - will store it in the frm, but won't tell > the engine about it - because unique(a,b,c) guarantees that (a,b,c,d) > is *always* unique. > > so, if we add this optimization someday your test case will no longer test > what it was supposed to. Okay , Changed. >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `a` blob DEFAULT NULL, >> + `b` blob DEFAULT NULL, >> + `c` blob DEFAULT NULL, >> + `d` blob DEFAULT NULL, >> + UNIQUE KEY `a_b_c_d`(`a`,`b`,`c`,`d`), >> + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), >> + UNIQUE KEY `b_c_d`(`b`,`c`,`d`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +insert into t1 values(1,1,1,1),(2,1,2,1),(1,3,3,1),(4,1,4,1),(1,5,1,5), >> +(6,1,6,1),(1,7,1,7),(8,1,1,8),(1,9,9,1),(2,2,2,2),(4,4,4,4),(5,5,5,5),(6,6,6,6), >> +(126,216,603,640),(603,460,660,706),(806,609,609,605),(62,62,22,33),(64,65,66,76), >> +(16,26,63,64),(63,46,66,76),(86,69,69,65),(622,622,622,633),(644,655,666,776); >> +select * from t1 limit 3; >> +a b c d >> +1 1 1 1 >> +2 1 2 1 >> +1 3 3 1 >> +#simple where >> +#key (a,b,c) >> +explain select * from t1 where a=1 and b=1 and c=1; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 const a_b_c a_b_c 9 const 1 >> +select * from t1 where a=1 and b=1 and c=1; >> +a b c d >> +1 1 1 1 >> +explain select * from t1 where a=1 and b=4444 and c=1; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables >> +select * from t1 where a=1 and b=4444 and c=1; >> +a b c d >> +#incomplete key >> +explain select * from t1 where a=1 and c=1; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where >> +select * from t1 where a=1 and c=1; >> +a b c d >> +1 1 1 1 >> +1 5 1 5 >> +1 7 1 7 >> +explain select * from t1 where a=1 and b=4444 ; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where >> +select * from t1 where a=1 and b=4444 ; >> +a b c d >> +explain select * from t1 where b=1 and c=1; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where >> +select * from t1 where b=1 and c=1; >> +a b c d >> +1 1 1 1 >> +8 1 1 8 >> +#key (b,c,d) >> +explain select * from t1 where d=1 and b=1 and c=1; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 const b_c_d b_c_d 9 const 1 >> +select * from t1 where d=1 and b=1 and c=1; >> +a b c d >> +1 1 1 1 >> +explain select * from t1 where d=1 and b=4444 and c=1; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables >> +select * from t1 where d=1 and b=4444 and c=1; >> +a b c d >> +#incomplete key >> +explain select * from t1 where d=1 and c=1; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where >> +select * from t1 where d=1 and c=1; >> +a b c d >> +1 1 1 1 >> +explain select * from t1 where d=1 and b=4444 ; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where >> +select * from t1 where d=1 and b=4444 ; >> +a b c d >> +explain select * from t1 where b=1 and c=1; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where >> +select * from t1 where b=1 and c=1; >> +a b c d >> +1 1 1 1 >> +8 1 1 8 >> +#key (a,b,c,d) >> +explain select * from t1 where a=1 and d=1 and b=1 and c=1; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 const a_b_c_d a_b_c_d 9 const 1 >> +select * from t1 where a=1 and d=1 and b=1 and c=1; >> +a b c d >> +1 1 1 1 >> +explain select * from t1 where a=1 and d=1 and b=4444 and c=1; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables >> +select * from t1 where a=1 and d=1 and b=4444 and c=1; >> +a b c d >> +#incomplete key >> +explain select * from t1 where a=1 and d=1 and c=1 ; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where >> +select * from t1 where a=1 and d=1 and c=1 ; >> +a b c d >> +1 1 1 1 >> +explain select * from t1 where d=1 and b=4444 and a=1 ; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where >> +select * from t1 where d=1 and b=4444 and a=1 ; >> +a b c d >> +explain select * from t1 where a=1 and c=1; >> +id select_type table type possible_keys key key_len ref rows Extra >> +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where >> +select * from t1 where a=1 and c=1; >> +a b c d >> +1 1 1 1 >> +1 5 1 5 >> +1 7 1 7 >> +drop table t1; >> diff --git a/mysql-test/r/long_uniques.result b/mysql-test/r/long_uniques.result >> new file mode 100644 >> index 0000000..e410fc1 >> --- /dev/null >> +++ b/mysql-test/r/long_uniques.result >> @@ -0,0 +1,1163 @@ >> +#Structure of tests >> +#First we will check all option for >> +#table containing single unique column >> +#table containing keys like unique(a,b,c,d) etc >> +#then table containing 2 blob unique etc >> +#table with single long blob column; >> +create table t1(a blob unique); >> +insert into t1 values(1),(2),(3),(56),('sachin'),('maria'),(123456789034567891),(null),(null),(123456789034567890); >> +#table structure; >> +desc t1; >> +Field Type Null Key Default Extra >> +a blob YES UNI NULL >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `a` blob DEFAULT NULL, >> + UNIQUE KEY `a`(`a`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; > for these statements, use "query_vertical" prefix, like > > query_vertical show keys from t1; > > it works better when the result has only few (best: one) row Added. >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 1 a 1 a A 0 NULL NULL YES HASH_INDEX > here, notice that your index is shown as "non-unique" Corrected. >> +select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; >> +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION COLUMN_DEFAULT IS_NULLABLE DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME COLUMN_TYPE COLUMN_KEY EXTRA PRIVILEGES COLUMN_COMMENT >> +def test t1 a 1 NULL YES blob 65535 65535 NULL NULL NULL NULL NULL blob UNI select,insert,update,references >> +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; >> +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME NON_UNIQUE INDEX_SCHEMA INDEX_NAME SEQ_IN_INDEX COLUMN_NAME COLLATION CARDINALITY SUB_PART PACKED NULLABLE INDEX_TYPE COMMENT INDEX_COMMENT >> +def test t1 1 test a 1 a A 0 NULL NULL YES HASH_INDEX >> +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; >> +CONSTRAINT_CATALOG CONSTRAINT_SCHEMA CONSTRAINT_NAME TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION POSITION_IN_UNIQUE_CONSTRAINT REFERENCED_TABLE_SCHEMA REFERENCED_TABLE_NAME REFERENCED_COLUMN_NAME >> +def test a def test t1 a 1 NULL NULL NULL NULL >> +# table select we should not be able to see db_row_hash_column; > "not able to see db_row_hash_1 column" > Changed, Sorry. >> +select * from t1; >> +a >> +1 >> +2 >> +3 >> +56 >> +sachin >> +maria >> +123456789034567891 >> +NULL >> +NULL >> +123456789034567890 >> +select db_row_hash_1 from t1; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' >> +#duplicate entry test; >> +insert into t1 values(2); >> +ERROR 23000: Duplicate entry '2' for key 'a' >> +insert into t1 values('sachin'); >> +ERROR 23000: Duplicate entry 'sachi' for key 'a' >> +insert into t1 values(123456789034567891); >> +ERROR 23000: Duplicate entry '12345' for key 'a' >> +select * from t1; >> +a >> +1 >> +2 >> +3 >> +56 >> +sachin >> +maria >> +123456789034567891 >> +NULL >> +NULL >> +123456789034567890 >> +insert into t1 values(11),(22),(33); >> +insert into t1 values(12),(22); >> +ERROR 23000: Duplicate entry '22' for key 'a' >> +select * from t1; >> +a >> +1 >> +2 >> +3 >> +56 >> +sachin >> +maria >> +123456789034567891 >> +NULL >> +NULL >> +123456789034567890 >> +11 >> +22 >> +33 >> +12 >> +insert into t1 values(repeat('s',4000*10)),(repeat('s',4001*10)); >> +insert into t1 values(repeat('m',4000*10)),(repeat('m',4000*10)); >> +ERROR 23000: Duplicate entry 'mmmmm' for key 'a' >> +insert into t1 values(repeat('m',4001)),(repeat('m',4002)); >> +truncate table t1; >> +insert into t1 values(1),(2),(3),(4),(5),(8),(7); >> +#now some alter commands; >> +alter table t1 add column b int; >> +desc t1; >> +Field Type Null Key Default Extra >> +a blob YES UNI NULL >> +b int(11) YES NULL >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `a` blob DEFAULT NULL, >> + `b` int(11) DEFAULT NULL, >> + UNIQUE KEY `a`(`a`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +insert into t1 values(1,2); >> +ERROR 23000: Duplicate entry '1' for key 'a' >> +insert into t1 values(2,2); >> +ERROR 23000: Duplicate entry '2' for key 'a' >> +select db_row_hash_1 from t1; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' >> +#now try to change db_row_hash_1 column; >> +alter table t1 drop column db_row_hash_1; >> +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists >> +alter table t1 add column d int , add column e int , drop column db_row_hash_1; >> +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists >> +alter table t1 modify column db_row_hash_1 int ; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' >> +alter table t1 add column a int , add column b int, modify column db_row_hash_1 int ; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' >> +alter table t1 change column db_row_hash_1 dsds int; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' >> +alter table t1 add column asd int, change column db_row_hash_1 dsds int; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' >> +alter table t1 drop column b , add column c int; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `a` blob DEFAULT NULL, >> + `c` int(11) DEFAULT NULL, >> + UNIQUE KEY `a`(`a`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +#now add some column with name db_row_hash; >> +alter table t1 add column db_row_hash_1 int unique; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `a` blob DEFAULT NULL, >> + `c` int(11) DEFAULT NULL, >> + `db_row_hash_1` int(11) DEFAULT NULL, >> + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), >> + UNIQUE KEY `a`(`a`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +insert into t1 values(45,1,55),(46,1,55); >> +ERROR 23000: Duplicate entry '55' for key 'db_row_hash_1' >> +alter table t1 add column db_row_hash_2 int, add column db_row_hash_3 int; >> +desc t1; >> +Field Type Null Key Default Extra >> +a blob YES UNI NULL >> +c int(11) YES NULL >> +db_row_hash_1 int(11) YES UNI NULL >> +db_row_hash_2 int(11) YES NULL >> +db_row_hash_3 int(11) YES NULL >> +#this should also drop the unique index ; >> +alter table t1 drop column a; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `c` int(11) DEFAULT NULL, >> + `db_row_hash_1` int(11) DEFAULT NULL, >> + `db_row_hash_2` int(11) DEFAULT NULL, >> + `db_row_hash_3` int(11) DEFAULT NULL, >> + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE >> +#add column with unique index on blob ; >> +alter table t1 add column a blob unique; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `c` int(11) DEFAULT NULL, >> + `db_row_hash_1` int(11) DEFAULT NULL, >> + `db_row_hash_2` int(11) DEFAULT NULL, >> + `db_row_hash_3` int(11) DEFAULT NULL, >> + `a` blob DEFAULT NULL, >> + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), >> + UNIQUE KEY `a`(`a`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +# try to change the blob unique column name; >> +#this will change index to b tree; >> +alter table t1 modify column a int ; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `c` int(11) DEFAULT NULL, >> + `db_row_hash_1` int(11) DEFAULT NULL, >> + `db_row_hash_2` int(11) DEFAULT NULL, >> + `db_row_hash_3` int(11) DEFAULT NULL, >> + `a` int(11) DEFAULT NULL, >> + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), >> + UNIQUE KEY `a` (`a`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE >> +t1 0 a 1 a A NULL NULL NULL YES BTREE >> +alter table t1 add column clm blob unique; >> +#try changing the name ; >> +alter table t1 change column clm clm_changed blob; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `c` int(11) DEFAULT NULL, >> + `db_row_hash_1` int(11) DEFAULT NULL, >> + `db_row_hash_2` int(11) DEFAULT NULL, >> + `db_row_hash_3` int(11) DEFAULT NULL, >> + `a` int(11) DEFAULT NULL, >> + `clm_changed` blob DEFAULT NULL, >> + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), >> + UNIQUE KEY `a` (`a`), >> + UNIQUE KEY `clm`(`clm_changed`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE >> +t1 0 a 1 a A NULL NULL NULL YES BTREE >> +t1 1 clm 1 clm_changed A 0 NULL NULL YES HASH_INDEX >> +#now drop the unique key; >> +alter table t1 drop key clm; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `c` int(11) DEFAULT NULL, >> + `db_row_hash_1` int(11) DEFAULT NULL, >> + `db_row_hash_2` int(11) DEFAULT NULL, >> + `db_row_hash_3` int(11) DEFAULT NULL, >> + `a` int(11) DEFAULT NULL, >> + `clm_changed` blob DEFAULT NULL, >> + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), >> + UNIQUE KEY `a` (`a`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE >> +t1 0 a 1 a A NULL NULL NULL YES BTREE > you can use myisamchk to see *actually created* indexes in MYI file. > examples are in myisam.test, but in short, it's something like > > let datadir=`select @@datadir`; > replace_result $datadir DATADIR; > exec $MYISAMCHK -d $datadir/test/t1 > > the first command needs to be done only once, in the beginning of the file, > usually. The other pair you do whenever you want to examine the table, > like, where you do "desc t1" or "show keys". Done. >> +drop table t1; >> +create table t1 (a TEXT CHARSET latin1 COLLATE latin1_german2_ci unique); >> +desc t1; >> +Field Type Null Key Default Extra >> +a text YES UNI NULL >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 1 a 1 a A 0 NULL NULL YES HASH_INDEX >> +insert into t1 values ('ae'); >> +insert into t1 values ('AE'); >> +ERROR 23000: Duplicate entry 'AE' for key 'a' >> +insert into t1 values ('Ä'); > good! > >> +drop table t1; >> +#table with multiple long blob column and varchar text column ; >> +create table t1(a blob unique, b int , c blob unique , d text unique , e varchar(3000) unique); >> +insert into t1 values(1,2,3,4,5),(2,11,22,33,44),(3111,222,333,444,555),(5611,2222,3333,4444,5555), >> +('sachin','ff','fdf','gfgfgfg','hghgr'),('maria','db','frter','dasd','utyuty'), >> +(123456789034567891,3534534534534,53453453453456,64565464564564,45435345345345), >> +(123456789034567890,435345345345,657567567567,78967657567567,657567567567567676); >> +Warnings: >> +Warning 1366 Incorrect integer value: 'ff' for column 'b' at row 5 >> +Warning 1366 Incorrect integer value: 'db' for column 'b' at row 6 >> +Warning 1264 Out of range value for column 'b' at row 7 >> +Warning 1264 Out of range value for column 'b' at row 8 > did you really need to insert invalid values in this test? No, I did not see Warning. >> +#table structure; >> +desc t1; >> +Field Type Null Key Default Extra >> +a blob YES UNI NULL >> +b int(11) YES NULL >> +c blob YES UNI NULL >> +d text YES UNI NULL >> +e varchar(3000) YES UNI NULL >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `a` blob DEFAULT NULL, >> + `b` int(11) DEFAULT NULL, >> + `c` blob DEFAULT NULL, >> + `d` text DEFAULT NULL, >> + `e` varchar(3000) DEFAULT NULL, >> + UNIQUE KEY `a`(`a`), >> + UNIQUE KEY `c`(`c`), >> + UNIQUE KEY `d`(`d`), >> + UNIQUE KEY `e`(`e`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 1 a 1 a A 0 NULL NULL YES HASH_INDEX >> +t1 1 c 1 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 e 1 e A 0 NULL NULL YES HASH_INDEX >> +select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; >> +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION COLUMN_DEFAULT IS_NULLABLE DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME COLUMN_TYPE COLUMN_KEY EXTRA PRIVILEGES COLUMN_COMMENT >> +def test t1 a 1 NULL YES blob 65535 65535 NULL NULL NULL NULL NULL blob UNI select,insert,update,references >> +def test t1 b 2 NULL YES int NULL NULL 10 0 NULL NULL NULL int(11) select,insert,update,references >> +def test t1 c 3 NULL YES blob 65535 65535 NULL NULL NULL NULL NULL blob UNI select,insert,update,references >> +def test t1 d 4 NULL YES text 65535 65535 NULL NULL NULL latin1 latin1_swedish_ci text UNI select,insert,update,references >> +def test t1 e 5 NULL YES varchar 3000 3000 NULL NULL NULL latin1 latin1_swedish_ci varchar(3000) UNI select,insert,update,references >> +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; >> +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME NON_UNIQUE INDEX_SCHEMA INDEX_NAME SEQ_IN_INDEX COLUMN_NAME COLLATION CARDINALITY SUB_PART PACKED NULLABLE INDEX_TYPE COMMENT INDEX_COMMENT >> +def test t1 1 test a 1 a A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test c 1 c A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test d 1 d A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test e 1 e A 0 NULL NULL YES HASH_INDEX >> +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; >> +CONSTRAINT_CATALOG CONSTRAINT_SCHEMA CONSTRAINT_NAME TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION POSITION_IN_UNIQUE_CONSTRAINT REFERENCED_TABLE_SCHEMA REFERENCED_TABLE_NAME REFERENCED_COLUMN_NAME >> +def test a def test t1 a 1 NULL NULL NULL NULL >> +def test c def test t1 c 1 NULL NULL NULL NULL >> +def test d def test t1 d 1 NULL NULL NULL NULL >> +def test e def test t1 e 1 NULL NULL NULL NULL >> +#table select we should not be able to see db_row_hash_column; >> +select * from t1; >> +a b c d e >> +1 2 3 4 5 >> +2 11 22 33 44 >> +3111 222 333 444 555 >> +5611 2222 3333 4444 5555 >> +sachin 0 fdf gfgfgfg hghgr >> +maria 0 frter dasd utyuty >> +123456789034567891 2147483647 53453453453456 64565464564564 45435345345345 >> +123456789034567890 2147483647 657567567567 78967657567567 657567567567567676 >> +select db_row_hash_1 from t1; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' >> +select db_row_hash_2 from t1; >> +ERROR 42S22: Unknown column 'db_row_hash_2' in 'field list' >> +select db_row_hash_3 from t1; >> +ERROR 42S22: Unknown column 'db_row_hash_3' in 'field list' >> +#duplicate entry test; >> +insert into t1 values(21,2,3,42,51); >> +ERROR 23000: Duplicate entry '3' for key 'c' >> +insert into t1 values('sachin',null,null,null,null); >> +ERROR 23000: Duplicate entry 'sachi' for key 'a' >> +insert into t1 values(1234567890345671890,4353453453451,6575675675617,789676575675617,657567567567567676); >> +ERROR 23000: Duplicate entry '65756' for key 'e' >> +select * from t1; >> +a b c d e >> +1 2 3 4 5 >> +2 11 22 33 44 >> +3111 222 333 444 555 >> +5611 2222 3333 4444 5555 >> +sachin 0 fdf gfgfgfg hghgr >> +maria 0 frter dasd utyuty >> +123456789034567891 2147483647 53453453453456 64565464564564 45435345345345 >> +123456789034567890 2147483647 657567567567 78967657567567 657567567567567676 >> +insert into t1 values(repeat('s',4000*10),100,repeat('s',4000*10),repeat('s',4000*10), >> +repeat('s',400)),(repeat('s',4001*10),1000,repeat('s',4001*10),repeat('s',4001*10), >> +repeat('s',401)); >> +insert into t1 values(repeat('m',4000*11),10,repeat('s',4000*11),repeat('s',4000*11),repeat('s',400)); >> +ERROR 23000: Duplicate entry 'sssss' for key 'e' > 400 characters (that you insert into 'e') - that looks a bit too short for > varchar(3000). Why wouldn't you insert, say, 2990 characters? > 400 is something that even b-tree can handle, I suspect. Changed. >> +truncate table t1; >> +insert into t1 values(1,2,3,4,5),(2,11,22,33,44),(3111,222,333,444,555),(5611,2222,3333,4444,5555); >> +#now some alter commands; >> +alter table t1 add column f int; >> +desc t1; >> +Field Type Null Key Default Extra >> +a blob YES UNI NULL >> +b int(11) YES NULL >> +c blob YES UNI NULL >> +d text YES UNI NULL >> +e varchar(3000) YES UNI NULL >> +f int(11) YES NULL >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `a` blob DEFAULT NULL, >> + `b` int(11) DEFAULT NULL, >> + `c` blob DEFAULT NULL, >> + `d` text DEFAULT NULL, >> + `e` varchar(3000) DEFAULT NULL, >> + `f` int(11) DEFAULT NULL, >> + UNIQUE KEY `a`(`a`), >> + UNIQUE KEY `c`(`c`), >> + UNIQUE KEY `d`(`d`), >> + UNIQUE KEY `e`(`e`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +#unique key should not break; >> +insert into t1 values(1,2,3,4,5,6); >> +ERROR 23000: Duplicate entry '1' for key 'a' >> +select db_row_hash_1 , db_row_hash_2, db_row_hash_3 from t1; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' >> +#now try to change db_row_hash_1 column; >> +alter table t1 drop column db_row_hash_1, drop column db_row_hash_2, drop column db_row_hash_3; >> +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists >> +alter table t1 add column dg int , add column ef int , drop column db_row_hash_1; >> +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists >> +alter table t1 modify column db_row_hash_1 int , modify column db_row_hash_2 int, modify column db_row_hash_3 int; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' >> +alter table t1 add column ar int , add column rb int, modify column db_row_hash_1 int , modify column db_row_hash_3 int; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' >> +alter table t1 change column db_row_hash_1 dsds int , change column db_row_hash_2 dfdf int , change column db_row_hash_3 gdfg int ; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' >> +alter table t1 add column asd int, drop column a, change column db_row_hash_1 dsds int, change db_row_hash_3 fdfdfd int; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' >> +alter table t1 drop column b , add column g int; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `a` blob DEFAULT NULL, >> + `c` blob DEFAULT NULL, >> + `d` text DEFAULT NULL, >> + `e` varchar(3000) DEFAULT NULL, >> + `f` int(11) DEFAULT NULL, >> + `g` int(11) DEFAULT NULL, >> + UNIQUE KEY `a`(`a`), >> + UNIQUE KEY `c`(`c`), >> + UNIQUE KEY `d`(`d`), >> + UNIQUE KEY `e`(`e`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +#now add some column with name db_row_hash; >> +alter table t1 add column db_row_hash_1 int unique; >> +alter table t1 add column db_row_hash_2 int unique; >> +alter table t1 add column db_row_hash_3 int unique; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `a` blob DEFAULT NULL, >> + `c` blob DEFAULT NULL, >> + `d` text DEFAULT NULL, >> + `e` varchar(3000) DEFAULT NULL, >> + `f` int(11) DEFAULT NULL, >> + `g` int(11) DEFAULT NULL, >> + `db_row_hash_1` int(11) DEFAULT NULL, >> + `db_row_hash_2` int(11) DEFAULT NULL, >> + `db_row_hash_3` int(11) DEFAULT NULL, >> + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), >> + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), >> + UNIQUE KEY `db_row_hash_3` (`db_row_hash_3`), >> + UNIQUE KEY `a`(`a`), >> + UNIQUE KEY `c`(`c`), >> + UNIQUE KEY `d`(`d`), >> + UNIQUE KEY `e`(`e`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +alter table t1 add column db_row_hash_7 int, add column db_row_hash_5 int , add column db_row_hash_4 int ; >> +alter table t1 drop column db_row_hash_7,drop column db_row_hash_3, drop column db_row_hash_4; >> +desc t1; >> +Field Type Null Key Default Extra >> +a blob YES UNI NULL >> +c blob YES UNI NULL >> +d text YES UNI NULL >> +e varchar(3000) YES UNI NULL >> +f int(11) YES NULL >> +g int(11) YES NULL >> +db_row_hash_1 int(11) YES UNI NULL >> +db_row_hash_2 int(11) YES UNI NULL >> +db_row_hash_5 int(11) YES NULL >> +#this show now break anything; >> +insert into t1 values(1,2,3,4,5,6,23,5,6); >> +ERROR 23000: Duplicate entry '1' for key 'a' >> +#this should also drop the unique index; >> +alter table t1 drop column a, drop column c; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `d` text DEFAULT NULL, >> + `e` varchar(3000) DEFAULT NULL, >> + `f` int(11) DEFAULT NULL, >> + `g` int(11) DEFAULT NULL, >> + `db_row_hash_1` int(11) DEFAULT NULL, >> + `db_row_hash_2` int(11) DEFAULT NULL, >> + `db_row_hash_5` int(11) DEFAULT NULL, >> + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), >> + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), >> + UNIQUE KEY `d`(`d`), >> + UNIQUE KEY `e`(`e`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE >> +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE >> +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 e 1 e A 0 NULL NULL YES HASH_INDEX >> +#add column with unique index on blob; >> +alter table t1 add column a blob unique; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `d` text DEFAULT NULL, >> + `e` varchar(3000) DEFAULT NULL, >> + `f` int(11) DEFAULT NULL, >> + `g` int(11) DEFAULT NULL, >> + `db_row_hash_1` int(11) DEFAULT NULL, >> + `db_row_hash_2` int(11) DEFAULT NULL, >> + `db_row_hash_5` int(11) DEFAULT NULL, >> + `a` blob DEFAULT NULL, >> + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), >> + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), >> + UNIQUE KEY `d`(`d`), >> + UNIQUE KEY `e`(`e`), >> + UNIQUE KEY `a`(`a`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE >> +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE >> +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 e 1 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 a 1 a A 0 NULL NULL YES HASH_INDEX >> +#try to change the blob unique column name; >> +#this will change index to b tree; >> +alter table t1 modify column a int , modify column e int; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `d` text DEFAULT NULL, >> + `e` int(11) DEFAULT NULL, >> + `f` int(11) DEFAULT NULL, >> + `g` int(11) DEFAULT NULL, >> + `db_row_hash_1` int(11) DEFAULT NULL, >> + `db_row_hash_2` int(11) DEFAULT NULL, >> + `db_row_hash_5` int(11) DEFAULT NULL, >> + `a` int(11) DEFAULT NULL, >> + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), >> + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), >> + UNIQUE KEY `e` (`e`), >> + UNIQUE KEY `a` (`a`), >> + UNIQUE KEY `d`(`d`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE >> +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE >> +t1 0 e 1 e A NULL NULL NULL YES BTREE >> +t1 0 a 1 a A NULL NULL NULL YES BTREE >> +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX >> +alter table t1 add column clm1 blob unique,add column clm2 blob unique; >> +#try changing the name; >> +alter table t1 change column clm1 clm_changed1 blob, change column clm2 clm_changed2 blob; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `d` text DEFAULT NULL, >> + `e` int(11) DEFAULT NULL, >> + `f` int(11) DEFAULT NULL, >> + `g` int(11) DEFAULT NULL, >> + `db_row_hash_1` int(11) DEFAULT NULL, >> + `db_row_hash_2` int(11) DEFAULT NULL, >> + `db_row_hash_5` int(11) DEFAULT NULL, >> + `a` int(11) DEFAULT NULL, >> + `clm_changed1` blob DEFAULT NULL, >> + `clm_changed2` blob DEFAULT NULL, >> + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), >> + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), >> + UNIQUE KEY `e` (`e`), >> + UNIQUE KEY `a` (`a`), >> + UNIQUE KEY `d`(`d`), >> + UNIQUE KEY `clm1`(`clm_changed1`), >> + UNIQUE KEY `clm2`(`clm_changed2`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE >> +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE >> +t1 0 e 1 e A NULL NULL NULL YES BTREE >> +t1 0 a 1 a A NULL NULL NULL YES BTREE >> +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 clm1 1 clm_changed1 A 0 NULL NULL YES HASH_INDEX >> +t1 1 clm2 1 clm_changed2 A 0 NULL NULL YES HASH_INDEX >> +#now drop the unique key; >> +alter table t1 drop key clm1, drop key clm2; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `d` text DEFAULT NULL, >> + `e` int(11) DEFAULT NULL, >> + `f` int(11) DEFAULT NULL, >> + `g` int(11) DEFAULT NULL, >> + `db_row_hash_1` int(11) DEFAULT NULL, >> + `db_row_hash_2` int(11) DEFAULT NULL, >> + `db_row_hash_5` int(11) DEFAULT NULL, >> + `a` int(11) DEFAULT NULL, >> + `clm_changed1` blob DEFAULT NULL, >> + `clm_changed2` blob DEFAULT NULL, >> + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), >> + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), >> + UNIQUE KEY `e` (`e`), >> + UNIQUE KEY `a` (`a`), >> + UNIQUE KEY `d`(`d`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE >> +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE >> +t1 0 e 1 e A NULL NULL NULL YES BTREE >> +t1 0 a 1 a A NULL NULL NULL YES BTREE >> +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX > test also > > alter table ... add unique key (blob_column) > > in three different variants: > 1. there were no duplicates in blob_column, key added successfully, > 2. there were duplicates, alter table failed. > 3. there were duplicates, ALTER IGNORE TABLE... succeeds > Already added in later commit. >> +drop table t1; >> +#now the table with key on multiple columns; the ultimate test; >> +create table t1(a blob, b int , c varchar(2000) , d text , e varchar(3000) , f longblob , g int , h text , >> +unique(a,b,c), unique(c,d,e),unique(e,f,g,h),unique(a,b,c,d,e,f),unique(d,e,f,g,h),unique(a,b,c,d,e,f,g,h)); >> +insert into t1 values(1,1,1,1,1,1,1,1),(2,2,2,2,2,2,2,2),(3,3,3,3,3,3,3,3),(4,4,4,4,4,4,4,4),(5,5,5,5,5,5,5,5), >> +('maria',6,'maria','maria','maria','maria',6,'maria'),('mariadb',7,'mariadb','mariadb','mariadb','mariadb',8,'mariadb'); >> +#table structure; >> +desc t1; >> +Field Type Null Key Default Extra >> +a blob YES MUL NULL >> +b int(11) YES NULL >> +c varchar(2000) YES MUL NULL >> +d text YES MUL NULL >> +e varchar(3000) YES MUL NULL >> +f longblob YES NULL >> +g int(11) YES NULL >> +h text YES NULL >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `a` blob DEFAULT NULL, >> + `b` int(11) DEFAULT NULL, >> + `c` varchar(2000) DEFAULT NULL, >> + `d` text DEFAULT NULL, >> + `e` varchar(3000) DEFAULT NULL, >> + `f` longblob DEFAULT NULL, >> + `g` int(11) DEFAULT NULL, >> + `h` text DEFAULT NULL, >> + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), >> + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), >> + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), >> + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), >> + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), >> + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 1 a_b_c 1 a A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c 2 b A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 2 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX >> +select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; >> +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION COLUMN_DEFAULT IS_NULLABLE DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME COLUMN_TYPE COLUMN_KEY EXTRA PRIVILEGES COLUMN_COMMENT >> +def test t1 a 1 NULL YES blob 65535 65535 NULL NULL NULL NULL NULL blob MUL select,insert,update,references >> +def test t1 b 2 NULL YES int NULL NULL 10 0 NULL NULL NULL int(11) select,insert,update,references >> +def test t1 c 3 NULL YES varchar 2000 2000 NULL NULL NULL latin1 latin1_swedish_ci varchar(2000) MUL select,insert,update,references >> +def test t1 d 4 NULL YES text 65535 65535 NULL NULL NULL latin1 latin1_swedish_ci text MUL select,insert,update,references >> +def test t1 e 5 NULL YES varchar 3000 3000 NULL NULL NULL latin1 latin1_swedish_ci varchar(3000) MUL select,insert,update,references >> +def test t1 f 6 NULL YES longblob 4294967295 4294967295 NULL NULL NULL NULL NULL longblob select,insert,update,references >> +def test t1 g 7 NULL YES int NULL NULL 10 0 NULL NULL NULL int(11) select,insert,update,references >> +def test t1 h 8 NULL YES text 65535 65535 NULL NULL NULL latin1 latin1_swedish_ci text select,insert,update,references >> +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; >> +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME NON_UNIQUE INDEX_SCHEMA INDEX_NAME SEQ_IN_INDEX COLUMN_NAME COLLATION CARDINALITY SUB_PART PACKED NULLABLE INDEX_TYPE COMMENT INDEX_COMMENT >> +def test t1 1 test a_b_c 1 a A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test a_b_c 2 b A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test a_b_c 3 c A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test c_d_e 1 c A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test c_d_e 2 d A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test c_d_e 3 e A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX >> +def test t1 1 test a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX >> +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; >> +CONSTRAINT_CATALOG CONSTRAINT_SCHEMA CONSTRAINT_NAME TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION POSITION_IN_UNIQUE_CONSTRAINT REFERENCED_TABLE_SCHEMA REFERENCED_TABLE_NAME REFERENCED_COLUMN_NAME >> +def test a_b_c def test t1 a 1 NULL NULL NULL NULL >> +def test a_b_c def test t1 b 2 NULL NULL NULL NULL >> +def test a_b_c def test t1 c 3 NULL NULL NULL NULL >> +def test c_d_e def test t1 c 1 NULL NULL NULL NULL >> +def test c_d_e def test t1 d 2 NULL NULL NULL NULL >> +def test c_d_e def test t1 e 3 NULL NULL NULL NULL >> +def test e_f_g_h def test t1 e 1 NULL NULL NULL NULL >> +def test e_f_g_h def test t1 f 2 NULL NULL NULL NULL >> +def test e_f_g_h def test t1 g 3 NULL NULL NULL NULL >> +def test e_f_g_h def test t1 h 4 NULL NULL NULL NULL >> +def test a_b_c_d_e_f def test t1 a 1 NULL NULL NULL NULL >> +def test a_b_c_d_e_f def test t1 b 2 NULL NULL NULL NULL >> +def test a_b_c_d_e_f def test t1 c 3 NULL NULL NULL NULL >> +def test a_b_c_d_e_f def test t1 d 4 NULL NULL NULL NULL >> +def test a_b_c_d_e_f def test t1 e 5 NULL NULL NULL NULL >> +def test a_b_c_d_e_f def test t1 f 6 NULL NULL NULL NULL >> +def test d_e_f_g_h def test t1 d 1 NULL NULL NULL NULL >> +def test d_e_f_g_h def test t1 e 2 NULL NULL NULL NULL >> +def test d_e_f_g_h def test t1 f 3 NULL NULL NULL NULL >> +def test d_e_f_g_h def test t1 g 4 NULL NULL NULL NULL >> +def test d_e_f_g_h def test t1 h 5 NULL NULL NULL NULL >> +def test a_b_c_d_e_f_g_h def test t1 a 1 NULL NULL NULL NULL >> +def test a_b_c_d_e_f_g_h def test t1 b 2 NULL NULL NULL NULL >> +def test a_b_c_d_e_f_g_h def test t1 c 3 NULL NULL NULL NULL >> +def test a_b_c_d_e_f_g_h def test t1 d 4 NULL NULL NULL NULL >> +def test a_b_c_d_e_f_g_h def test t1 e 5 NULL NULL NULL NULL >> +def test a_b_c_d_e_f_g_h def test t1 f 6 NULL NULL NULL NULL >> +def test a_b_c_d_e_f_g_h def test t1 g 7 NULL NULL NULL NULL >> +def test a_b_c_d_e_f_g_h def test t1 h 8 NULL NULL NULL NULL >> +# table select we should not be able to see db_row_hash_column; >> +select * from t1; >> +a b c d e f g h >> +1 1 1 1 1 1 1 1 >> +2 2 2 2 2 2 2 2 >> +3 3 3 3 3 3 3 3 >> +4 4 4 4 4 4 4 4 >> +5 5 5 5 5 5 5 5 >> +maria 6 maria maria maria maria 6 maria >> +mariadb 7 mariadb mariadb mariadb mariadb 8 mariadb >> +select db_row_hash_1 from t1; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' >> +select db_row_hash_2 from t1; >> +ERROR 42S22: Unknown column 'db_row_hash_2' in 'field list' >> +select db_row_hash_3 from t1; >> +ERROR 42S22: Unknown column 'db_row_hash_3' in 'field list' >> +#duplicate entry test; >> +#duplicate keys entry; >> +insert into t1 values(1,1,1,0,0,0,0,0); >> +ERROR 23000: Duplicate entry '1-1-1' for key 'a_b_c' >> +insert into t1 values(0,0,1,1,1,0,0,0); >> +ERROR 23000: Duplicate entry '1-1-1' for key 'c_d_e' >> +insert into t1 values(0,0,0,0,1,1,1,1); >> +ERROR 23000: Duplicate entry '1-1-1-1' for key 'e_f_g_h' >> +insert into t1 values(1,1,1,1,1,0,0,0); >> +ERROR 23000: Duplicate entry '1-1-1' for key 'a_b_c' >> +insert into t1 values(0,0,0,0,1,1,1,1); >> +ERROR 23000: Duplicate entry '1-1-1-1' for key 'e_f_g_h' >> +insert into t1 values(1,1,1,1,1,1,1,1); >> +ERROR 23000: Duplicate entry '1-1-1' for key 'a_b_c' >> +select db_row_hash_1,db_row_hash_2,db_row_hash_3,db_row_hash_4,db_row_hash_5 from t1; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' >> +alter table t1 drop column db_row_hash_1, drop column db_row_hash_2, drop column db_row_hash_3; >> +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists >> +alter table t1 add column dg int , add column ef int , drop column db_row_hash_1; >> +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists >> +alter table t1 modify column db_row_hash_1 int , modify column db_row_hash_2 int, modify column db_row_hash_3 int; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' >> +alter table t1 add column ar int , add column rb int, modify column db_row_hash_1 int , modify column db_row_hash_3 int; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' >> +alter table t1 change column db_row_hash_1 dsds int , change column db_row_hash_2 dfdf int , change column db_row_hash_3 gdfg int ; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' >> +alter table t1 add column asd int, drop column a, change column db_row_hash_1 dsds int, change db_row_hash_3 fdfdfd int; >> +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `a` blob DEFAULT NULL, >> + `b` int(11) DEFAULT NULL, >> + `c` varchar(2000) DEFAULT NULL, >> + `d` text DEFAULT NULL, >> + `e` varchar(3000) DEFAULT NULL, >> + `f` longblob DEFAULT NULL, >> + `g` int(11) DEFAULT NULL, >> + `h` text DEFAULT NULL, >> + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), >> + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), >> + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), >> + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), >> + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), >> + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +# add column named db_row_hash_*; >> +alter table t1 add column db_row_hash_7 int , add column db_row_hash_5 int, >> +add column db_row_hash_1 int, add column db_row_hash_2 int; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `a` blob DEFAULT NULL, >> + `b` int(11) DEFAULT NULL, >> + `c` varchar(2000) DEFAULT NULL, >> + `d` text DEFAULT NULL, >> + `e` varchar(3000) DEFAULT NULL, >> + `f` longblob DEFAULT NULL, >> + `g` int(11) DEFAULT NULL, >> + `h` text DEFAULT NULL, >> + `db_row_hash_7` int(11) DEFAULT NULL, >> + `db_row_hash_5` int(11) DEFAULT NULL, >> + `db_row_hash_1` int(11) DEFAULT NULL, >> + `db_row_hash_2` int(11) DEFAULT NULL, >> + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), >> + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), >> + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), >> + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), >> + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), >> + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 1 a_b_c 1 a A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c 2 b A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 2 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX >> +alter table t1 drop column db_row_hash_7 , drop column db_row_hash_5 , >> +drop column db_row_hash_1, drop column db_row_hash_2 ; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `a` blob DEFAULT NULL, >> + `b` int(11) DEFAULT NULL, >> + `c` varchar(2000) DEFAULT NULL, >> + `d` text DEFAULT NULL, >> + `e` varchar(3000) DEFAULT NULL, >> + `f` longblob DEFAULT NULL, >> + `g` int(11) DEFAULT NULL, >> + `h` text DEFAULT NULL, >> + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), >> + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), >> + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), >> + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), >> + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), >> + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 1 a_b_c 1 a A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c 2 b A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 2 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX >> +#try to change column names; >> +alter table t1 change column a aa blob , change column b bb blob , change column d dd blob; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `aa` blob DEFAULT NULL, >> + `bb` blob DEFAULT NULL, >> + `c` varchar(2000) DEFAULT NULL, >> + `dd` blob DEFAULT NULL, >> + `e` varchar(3000) DEFAULT NULL, >> + `f` longblob DEFAULT NULL, >> + `g` int(11) DEFAULT NULL, >> + `h` text DEFAULT NULL, >> + UNIQUE KEY `a_b_c`(`aa`,`bb`,`c`), >> + UNIQUE KEY `c_d_e`(`c`,`dd`,`e`), >> + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), >> + UNIQUE KEY `a_b_c_d_e_f`(`aa`,`bb`,`c`,`dd`,`e`,`f`), >> + UNIQUE KEY `d_e_f_g_h`(`dd`,`e`,`f`,`g`,`h`), >> + UNIQUE KEY `a_b_c_d_e_f_g_h`(`aa`,`bb`,`c`,`dd`,`e`,`f`,`g`,`h`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 1 a_b_c 1 aa A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c 2 bb A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 2 dd A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 1 aa A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 2 bb A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 4 dd A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 1 dd A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 1 aa A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 2 bb A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 4 dd A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX >> +alter table t1 change column aa a blob , change column bb b blob , change column dd d blob; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `a` blob DEFAULT NULL, >> + `b` blob DEFAULT NULL, >> + `c` varchar(2000) DEFAULT NULL, >> + `d` blob DEFAULT NULL, >> + `e` varchar(3000) DEFAULT NULL, >> + `f` longblob DEFAULT NULL, >> + `g` int(11) DEFAULT NULL, >> + `h` text DEFAULT NULL, >> + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), >> + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), >> + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), >> + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), >> + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), >> + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 1 a_b_c 1 a A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c 2 b A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 2 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX >> +#now we will change the data type to int and varchar limit so that we no longer require hash_index; >> +#on key a_b_c; >> +alter table t1 modify column a int , modify column b int , modify column c int; >> +Warnings: >> +Warning 1292 Truncated incorrect INTEGER value: 'maria' >> +Warning 1292 Truncated incorrect INTEGER value: 'maria' >> +Warning 1292 Truncated incorrect INTEGER value: 'mariadb' >> +Warning 1292 Truncated incorrect INTEGER value: 'mariadb' >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `a` int(11) DEFAULT NULL, >> + `b` int(11) DEFAULT NULL, >> + `c` int(11) DEFAULT NULL, >> + `d` blob DEFAULT NULL, >> + `e` varchar(3000) DEFAULT NULL, >> + `f` longblob DEFAULT NULL, >> + `g` int(11) DEFAULT NULL, >> + `h` text DEFAULT NULL, >> + UNIQUE KEY `a_b_c` (`a`,`b`,`c`), >> + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), >> + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), >> + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), >> + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), >> + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 0 a_b_c 1 a A NULL NULL NULL YES BTREE >> +t1 0 a_b_c 2 b A NULL NULL NULL YES BTREE >> +t1 0 a_b_c 3 c A NULL NULL NULL YES BTREE >> +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 2 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX >> +#change it back; >> +alter table t1 modify column a blob , modify column b blob , modify column c blob; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `a` blob DEFAULT NULL, >> + `b` blob DEFAULT NULL, >> + `c` blob DEFAULT NULL, >> + `d` blob DEFAULT NULL, >> + `e` varchar(3000) DEFAULT NULL, >> + `f` longblob DEFAULT NULL, >> + `g` int(11) DEFAULT NULL, >> + `h` text DEFAULT NULL, >> + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), >> + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), >> + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), >> + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), >> + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), >> + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 1 a_b_c 1 a A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c 2 b A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 2 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX >> +#try to delete blob column in unique; >> +truncate table t1; >> +alter table t1 drop column a, drop column b, drop column c; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `d` blob DEFAULT NULL, >> + `e` varchar(3000) DEFAULT NULL, >> + `f` longblob DEFAULT NULL, >> + `g` int(11) DEFAULT NULL, >> + `h` text DEFAULT NULL, >> + UNIQUE KEY `c_d_e`(`d`,`e`), >> + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), >> + UNIQUE KEY `a_b_c_d_e_f`(`d`,`e`,`f`), >> + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), >> + UNIQUE KEY `a_b_c_d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 1 c_d_e 1 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 c_d_e 2 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 1 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 2 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 3 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX >> +#now try to delete keys; >> +alter table t1 drop key c_d_e, drop key e_f_g_h; >> +show create table t1; >> +Table Create Table >> +t1 CREATE TABLE `t1` ( >> + `d` blob DEFAULT NULL, >> + `e` varchar(3000) DEFAULT NULL, >> + `f` longblob DEFAULT NULL, >> + `g` int(11) DEFAULT NULL, >> + `h` text DEFAULT NULL, >> + UNIQUE KEY `a_b_c_d_e_f`(`d`,`e`,`f`), >> + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), >> + UNIQUE KEY `a_b_c_d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`) >> +) ENGINE=MyISAM DEFAULT CHARSET=latin1 >> +show keys from t1; >> +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment >> +t1 1 a_b_c_d_e_f 1 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 2 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f 3 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX >> +t1 1 a_b_c_d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX >> +drop table t1; >> diff --git a/mysql-test/t/hidden_field.test b/mysql-test/t/hidden_field.test >> new file mode 100644 >> index 0000000..8f3b452 >> --- /dev/null >> +++ b/mysql-test/t/hidden_field.test >> @@ -0,0 +1,152 @@ >> +create table h_1(abc int primary key, xyz int hidden); >> +desc h_1; >> +show create table h_1; >> +drop table h_1; >> +--error ER_TABLE_MUST_HAVE_COLUMNS >> +create table h_2(a1 int hidden); >> +--error ER_PARSE_ERROR >> +create table h_3(a1 blob,hidden(a1)); >> +--error ER_HIDDEN_NOT_NULL_WOUT_DEFAULT >> +create table h_4(a1 int primary key hidden ,a2 int unique hidden , a3 blob,a4 >> +int not null hidden unique); >> +--error ER_HIDDEN_NOT_NULL_WOUT_DEFAULT >> +create table h_5(abc int not null hidden); >> +create table t1(a int hidden, b int); >> +#should automatically add null >> +insert into t1 values(1); >> +insert into t1(a) values(1); >> +insert into t1(b) values(1); >> +insert into t1(a,b) values(5,5); >> +select * from t1; >> +select a,b from t1; >> +delete from t1; >> +insert into t1 values(1),(2),(3),(4); >> +select * from t1; >> +select a from t1; >> +drop table t1; >> +#echo more complex case of hidden >> +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); >> +desc t1; >> +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); >> +select * from t1; >> +drop table t1; >> +--error ER_PARSE_ERROR >> +create table sdsdsd(a int , b int, hidden(a,b)); >> +create table t1(a int,abc int as (a mod 3) virtual hidden); >> +desc t1; >> +--error ER_WRONG_VALUE_COUNT_ON_ROW >> +insert into t1 values(1,default); >> +insert into t1 values(1),(22),(233); >> +select * from t1; >> +select a,abc from t1; >> +drop table t1; >> +create table t1(abc int primary key hidden auto_increment, a int); >> +desc t1; >> +show create table t1; >> +insert into t1 values(1); >> +insert into t1 values(2); >> +insert into t1 values(3); >> +select * from t1; >> +select abc,a from t1; >> +delete from t1; >> +insert into t1 values(1),(2),(3),(4),(6); >> +select abc,a from t1; >> +drop table t1; >> +create table t1(abc int); >> +--error ER_TABLE_MUST_HAVE_COLUMNS >> +alter table t1 change abc ss int hidden; >> +alter table t1 add column xyz int; >> +alter table t1 modify column abc int ; >> +desc t1; >> +--error ER_WRONG_VALUE_COUNT_ON_ROW >> +insert into t1 values(22); >> +alter table t1 modify column abc int hidden; >> +desc t1; >> +insert into t1 values(12); >> +drop table t1; >> + >> +--echo some test on copy table structure with table data; > in echo's start the message from #-sign to make it better visible in a result Changed. >> + >> +--echo table with hidden fields and unique keys; >> + >> +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); >> +desc t1; >> +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); >> +select * from t1; >> +select a,b,c,d,e,f from t1; >> +--echo this wont copy hidden fields and keys; >> +create table t2 as select * from t1; >> +desc t2; >> +select * from t2; >> +--error ER_BAD_FIELD_ERROR >> +select a,b,c,d,e,f from t2; >> +drop table t2; >> +--echo now this will copy hidden fields >> +create table t2 as select a,b,c,d,e,f from t1; >> +desc t2; >> +select * from t2; >> +select a,b,c,d,e,f from t2; >> +drop table t2,t1; >> + >> +--echo some test related to copy of data from one table to another; >> +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); >> +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); >> +select a,b,c,d,e,f from t1; >> +create table t2(a int , b int hidden , c int hidden , d blob , e int unique, f int); >> +insert into t2 select * from t1; >> +select a,b,c,d,e,f from t2; >> +truncate t2; >> +insert into t2 (a,b,c,d,e,f) select a,b,c,d,e,f from t1; >> +select a,b,c,d,e,f from t2; >> +truncate t2; >> +drop table t1,t2; >> + >> +--echo some test related to creating view on table with hidden column; >> +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); >> +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); >> +create view v as select * from t1; >> +desc v; >> +select * from v; >> +--echo v does not have hidden column; >> +--error ER_BAD_FIELD_ERROR >> +select a,b,c,d,e,f from v; >> +insert into v values(1,21,32,4); >> +select * from v; >> +--error ER_BAD_FIELD_ERROR >> +insert into v(a,b,c,d,e,f) values(1,12,3,4,5,6); >> +drop view v; >> + >> +create view v as select a,b,c,d,e,f from t1; >> +desc v; >> +select * from v; >> +--echo v does have hidden column; >> +select a,b,c,d,e,f from v; >> +insert into v values(1,26,33,4,45,66); >> +select a,b,c,d,e,f from v; >> +insert into v(a,b,c,d,e,f) values(1,32,31,41,5,6); >> +select a,b,c,d,e,f from v; >> +drop view v; >> +drop table t1; >> + >> +--echo now hidden column in where and some join query i think no use of this test but anyway; >> +create table t1 (a int unique , b int hidden unique, c int unique hidden); >> +insert into t1(a,b,c) values(1,1,1); >> +insert into t1(a,b,c) values(2,2,2); >> +insert into t1(a,b,c) values(3,3,3); >> +insert into t1(a,b,c) values(4,4,4); >> +insert into t1(a,b,c) values(21,21,26); >> +insert into t1(a,b,c) values(31,31,35); >> +insert into t1(a,b,c) values(41,41,45); >> +insert into t1(a,b,c) values(22,22,24); >> +insert into t1(a,b,c) values(32,32,33); >> +insert into t1(a,b,c) values(42,42,43); >> +explain select * from t1 where b=3; >> +select * from t1 where b=3; >> +explain select * from t1 where c=3; >> +select * from t1 where c=3; >> + >> +create table t2 as select a,b,c from t1; >> +desc t2; >> +explain select * from t1,t2 where t1.b = t2.c and t1.c = t2.b; >> +select * from t1,t2 where t1.b = t2.c and t1.c = t2.b; >> +drop table t1,t2; >> diff --git a/mysql-test/t/long_uniques.test b/mysql-test/t/long_uniques.test >> new file mode 100644 >> index 0000000..8777aaa >> --- /dev/null >> +++ b/mysql-test/t/long_uniques.test >> @@ -0,0 +1,294 @@ > please add also a test case for innodb. In a separate file, long_uniques_innodb.test > in particular, test this case: > > connection con1; > start transaction; > insert ('bbbb') > connection con2; > start transaction; > insert ('bbbb') > > see? insert the conflicting value in two simultaneously running transactions. > try that in different transaction isolation levels. > normally the second transaction should *not* see the first 'bbbb' because > the first transaction is not committed yet. But InnoDB next-key locks > should guarantee that the second transaction will wait for the first. TODO >> +--echo #Structure of tests >> +--echo #First we will check all option for >> +--echo #table containing single unique column >> +--echo #table containing keys like unique(a,b,c,d) etc >> +--echo #then table containing 2 blob unique etc >> + >> +--echo #table with single long blob column; >> +create table t1(a blob unique); >> +insert into t1 values(1),(2),(3),(56),('sachin'),('maria'),(123456789034567891),(null),(null),(123456789034567890); >> + >> +--echo #table structure; >> +desc t1; >> +show create table t1; >> +show keys from t1; >> +select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; >> +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; >> +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; >> +--echo # table select we should not be able to see db_row_hash_column; >> +select * from t1; >> +--error ER_BAD_FIELD_ERROR >> +select db_row_hash_1 from t1; >> +--echo #duplicate entry test; >> +--error ER_DUP_ENTRY >> +insert into t1 values(2); >> +--error ER_DUP_ENTRY >> +insert into t1 values('sachin'); >> +--error ER_DUP_ENTRY >> +insert into t1 values(123456789034567891); >> +select * from t1; >> +insert into t1 values(11),(22),(33); >> +--error ER_DUP_ENTRY >> +insert into t1 values(12),(22); >> +select * from t1; >> +insert into t1 values(repeat('s',4000*10)),(repeat('s',4001*10)); >> +--error ER_DUP_ENTRY >> +insert into t1 values(repeat('m',4000*10)),(repeat('m',4000*10)); >> +insert into t1 values(repeat('m',4001)),(repeat('m',4002)); >> +truncate table t1; >> +insert into t1 values(1),(2),(3),(4),(5),(8),(7); >> + >> +--echo #now some alter commands; >> +alter table t1 add column b int; >> +desc t1; >> +show create table t1; >> +--error ER_DUP_ENTRY >> +insert into t1 values(1,2); >> +--error ER_DUP_ENTRY >> +insert into t1 values(2,2); >> +--error ER_BAD_FIELD_ERROR >> +select db_row_hash_1 from t1; >> +--echo #now try to change db_row_hash_1 column; >> +--error ER_CANT_DROP_FIELD_OR_KEY >> +alter table t1 drop column db_row_hash_1; >> +--error ER_CANT_DROP_FIELD_OR_KEY >> +alter table t1 add column d int , add column e int , drop column db_row_hash_1; >> +--error ER_BAD_FIELD_ERROR >> +alter table t1 modify column db_row_hash_1 int ; >> +--error ER_BAD_FIELD_ERROR >> +alter table t1 add column a int , add column b int, modify column db_row_hash_1 int ; >> +--error ER_BAD_FIELD_ERROR >> +alter table t1 change column db_row_hash_1 dsds int; >> +--error ER_BAD_FIELD_ERROR >> +alter table t1 add column asd int, change column db_row_hash_1 dsds int; >> +alter table t1 drop column b , add column c int; >> +show create table t1; >> + >> +--echo #now add some column with name db_row_hash; >> +alter table t1 add column db_row_hash_1 int unique; >> +show create table t1; >> +--error ER_DUP_ENTRY >> +insert into t1 values(45,1,55),(46,1,55); >> +alter table t1 add column db_row_hash_2 int, add column db_row_hash_3 int; >> +desc t1; >> +--echo #this should also drop the unique index ; >> +alter table t1 drop column a; >> +show create table t1; >> +show keys from t1; >> +--echo #add column with unique index on blob ; >> +alter table t1 add column a blob unique; >> +show create table t1; >> +--echo # try to change the blob unique column name; >> +--echo #this will change index to b tree; >> +alter table t1 modify column a int ; >> +show create table t1; >> +show keys from t1; >> +alter table t1 add column clm blob unique; >> +--echo #try changing the name ; >> +alter table t1 change column clm clm_changed blob; >> +show create table t1; >> +show keys from t1; >> +--echo #now drop the unique key; >> +alter table t1 drop key clm; >> +show create table t1; >> +show keys from t1; >> +drop table t1; >> + >> +create table t1 (a TEXT CHARSET latin1 COLLATE latin1_german2_ci unique); >> +desc t1; >> +show keys from t1; >> + insert into t1 values ('ae'); >> +--error ER_DUP_ENTRY >> + insert into t1 values ('AE'); >> + insert into t1 values ('Ä'); >> +drop table t1; >> + >> +--echo #table with multiple long blob column and varchar text column ; >> +create table t1(a blob unique, b int , c blob unique , d text unique , e varchar(3000) unique); >> +insert into t1 values(1,2,3,4,5),(2,11,22,33,44),(3111,222,333,444,555),(5611,2222,3333,4444,5555), >> +('sachin','ff','fdf','gfgfgfg','hghgr'),('maria','db','frter','dasd','utyuty'), >> +(123456789034567891,3534534534534,53453453453456,64565464564564,45435345345345), >> +(123456789034567890,435345345345,657567567567,78967657567567,657567567567567676); >> + >> +--echo #table structure; >> +desc t1; >> +show create table t1; >> +show keys from t1; >> +select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; >> +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; >> +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; >> +--echo #table select we should not be able to see db_row_hash_column; >> +select * from t1; >> +--error ER_BAD_FIELD_ERROR >> +select db_row_hash_1 from t1; >> +--error ER_BAD_FIELD_ERROR >> +select db_row_hash_2 from t1; >> +--error ER_BAD_FIELD_ERROR >> +select db_row_hash_3 from t1; >> +--echo #duplicate entry test; >> +--error ER_DUP_ENTRY >> +insert into t1 values(21,2,3,42,51); >> +--error ER_DUP_ENTRY >> +insert into t1 values('sachin',null,null,null,null); >> +--error ER_DUP_ENTRY >> +insert into t1 values(1234567890345671890,4353453453451,6575675675617,789676575675617,657567567567567676); >> +select * from t1; >> +insert into t1 values(repeat('s',4000*10),100,repeat('s',4000*10),repeat('s',4000*10), >> +repeat('s',400)),(repeat('s',4001*10),1000,repeat('s',4001*10),repeat('s',4001*10), >> +repeat('s',401)); >> +--error ER_DUP_ENTRY >> +insert into t1 values(repeat('m',4000*11),10,repeat('s',4000*11),repeat('s',4000*11),repeat('s',400)); >> +truncate table t1; >> +insert into t1 values(1,2,3,4,5),(2,11,22,33,44),(3111,222,333,444,555),(5611,2222,3333,4444,5555); >> + >> +--echo #now some alter commands; >> +alter table t1 add column f int; >> +desc t1; >> +show create table t1; >> +--echo #unique key should not break; >> +--error ER_DUP_ENTRY >> +insert into t1 values(1,2,3,4,5,6); >> +--error ER_BAD_FIELD_ERROR >> +select db_row_hash_1 , db_row_hash_2, db_row_hash_3 from t1; >> +--echo #now try to change db_row_hash_1 column; >> +--error ER_CANT_DROP_FIELD_OR_KEY >> +alter table t1 drop column db_row_hash_1, drop column db_row_hash_2, drop column db_row_hash_3; >> +--error ER_CANT_DROP_FIELD_OR_KEY >> +alter table t1 add column dg int , add column ef int , drop column db_row_hash_1; >> +--error ER_BAD_FIELD_ERROR >> +alter table t1 modify column db_row_hash_1 int , modify column db_row_hash_2 int, modify column db_row_hash_3 int; >> +--error ER_BAD_FIELD_ERROR >> +alter table t1 add column ar int , add column rb int, modify column db_row_hash_1 int , modify column db_row_hash_3 int; >> +--error ER_BAD_FIELD_ERROR >> +alter table t1 change column db_row_hash_1 dsds int , change column db_row_hash_2 dfdf int , change column db_row_hash_3 gdfg int ; >> +--error ER_BAD_FIELD_ERROR >> +alter table t1 add column asd int, drop column a, change column db_row_hash_1 dsds int, change db_row_hash_3 fdfdfd int; >> +alter table t1 drop column b , add column g int; >> +show create table t1; >> + >> +--echo #now add some column with name db_row_hash; >> +alter table t1 add column db_row_hash_1 int unique; >> +alter table t1 add column db_row_hash_2 int unique; >> +alter table t1 add column db_row_hash_3 int unique; >> +show create table t1; >> + >> +alter table t1 add column db_row_hash_7 int, add column db_row_hash_5 int , add column db_row_hash_4 int ; >> +alter table t1 drop column db_row_hash_7,drop column db_row_hash_3, drop column db_row_hash_4; >> +desc t1; >> +--echo #this show now break anything; >> +--error ER_DUP_ENTRY >> +insert into t1 values(1,2,3,4,5,6,23,5,6); >> +--echo #this should also drop the unique index; >> +alter table t1 drop column a, drop column c; >> +show create table t1; >> +show keys from t1; >> +--echo #add column with unique index on blob; >> +alter table t1 add column a blob unique; >> +show create table t1; >> +show keys from t1; >> +--echo #try to change the blob unique column name; >> +--echo #this will change index to b tree; >> +alter table t1 modify column a int , modify column e int; >> +show create table t1; >> +show keys from t1; >> +alter table t1 add column clm1 blob unique,add column clm2 blob unique; >> +--echo #try changing the name; >> +alter table t1 change column clm1 clm_changed1 blob, change column clm2 clm_changed2 blob; >> +show create table t1; >> +show keys from t1; >> +--echo #now drop the unique key; >> +alter table t1 drop key clm1, drop key clm2; >> +show create table t1; >> +show keys from t1; >> +drop table t1; >> + >> +--echo #now the table with key on multiple columns; the ultimate test; >> +create table t1(a blob, b int , c varchar(2000) , d text , e varchar(3000) , f longblob , g int , h text , >> + unique(a,b,c), unique(c,d,e),unique(e,f,g,h),unique(a,b,c,d,e,f),unique(d,e,f,g,h),unique(a,b,c,d,e,f,g,h)); >> + >> +insert into t1 values(1,1,1,1,1,1,1,1),(2,2,2,2,2,2,2,2),(3,3,3,3,3,3,3,3),(4,4,4,4,4,4,4,4),(5,5,5,5,5,5,5,5), >> +('maria',6,'maria','maria','maria','maria',6,'maria'),('mariadb',7,'mariadb','mariadb','mariadb','mariadb',8,'mariadb'); >> + >> +--echo #table structure; >> +desc t1; >> +show create table t1; >> +show keys from t1; >> +select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; >> +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; >> +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; >> +--echo # table select we should not be able to see db_row_hash_column; >> +select * from t1; >> +--error ER_BAD_FIELD_ERROR >> +select db_row_hash_1 from t1; >> +--error ER_BAD_FIELD_ERROR >> +select db_row_hash_2 from t1; >> +--error ER_BAD_FIELD_ERROR >> +select db_row_hash_3 from t1; >> +--echo #duplicate entry test; >> +--echo #duplicate keys entry; >> +--error ER_DUP_ENTRY >> +insert into t1 values(1,1,1,0,0,0,0,0); >> +--error ER_DUP_ENTRY >> +insert into t1 values(0,0,1,1,1,0,0,0); >> +--error ER_DUP_ENTRY >> +insert into t1 values(0,0,0,0,1,1,1,1); >> +--error ER_DUP_ENTRY >> +insert into t1 values(1,1,1,1,1,0,0,0); >> +--error ER_DUP_ENTRY >> +insert into t1 values(0,0,0,0,1,1,1,1); >> +--error ER_DUP_ENTRY >> +insert into t1 values(1,1,1,1,1,1,1,1); >> +--error ER_BAD_FIELD_ERROR >> +select db_row_hash_1,db_row_hash_2,db_row_hash_3,db_row_hash_4,db_row_hash_5 from t1; >> +--error ER_CANT_DROP_FIELD_OR_KEY >> +alter table t1 drop column db_row_hash_1, drop column db_row_hash_2, drop column db_row_hash_3; >> +--error ER_CANT_DROP_FIELD_OR_KEY >> +alter table t1 add column dg int , add column ef int , drop column db_row_hash_1; >> +--error ER_BAD_FIELD_ERROR >> +alter table t1 modify column db_row_hash_1 int , modify column db_row_hash_2 int, modify column db_row_hash_3 int; >> +--error ER_BAD_FIELD_ERROR >> +alter table t1 add column ar int , add column rb int, modify column db_row_hash_1 int , modify column db_row_hash_3 int; >> +--error ER_BAD_FIELD_ERROR >> +alter table t1 change column db_row_hash_1 dsds int , change column db_row_hash_2 dfdf int , change column db_row_hash_3 gdfg int ; >> +--error ER_BAD_FIELD_ERROR >> +alter table t1 add column asd int, drop column a, change column db_row_hash_1 dsds int, change db_row_hash_3 fdfdfd int; >> + >> +show create table t1; >> +--echo # add column named db_row_hash_*; >> +alter table t1 add column db_row_hash_7 int , add column db_row_hash_5 int, >> + add column db_row_hash_1 int, add column db_row_hash_2 int; >> +show create table t1; >> +show keys from t1; >> +alter table t1 drop column db_row_hash_7 , drop column db_row_hash_5 , >> + drop column db_row_hash_1, drop column db_row_hash_2 ; >> +show create table t1; >> +show keys from t1; >> + >> +--echo #try to change column names; >> +alter table t1 change column a aa blob , change column b bb blob , change column d dd blob; >> +show create table t1; >> +show keys from t1; >> +alter table t1 change column aa a blob , change column bb b blob , change column dd d blob; >> +show create table t1; >> +show keys from t1; >> + >> +--echo #now we will change the data type to int and varchar limit so that we no longer require hash_index; >> +--echo #on key a_b_c; >> +alter table t1 modify column a int , modify column b int , modify column c int; >> +show create table t1; >> +show keys from t1; >> +--echo #change it back; >> +alter table t1 modify column a blob , modify column b blob , modify column c blob; >> +show create table t1; >> +show keys from t1; >> + >> +--echo #try to delete blob column in unique; >> +truncate table t1; >> +alter table t1 drop column a, drop column b, drop column c; >> +show create table t1; >> +show keys from t1; >> +--echo #now try to delete keys; >> +alter table t1 drop key c_d_e, drop key e_f_g_h; >> +show create table t1; >> +show keys from t1; >> +drop table t1; >> diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt >> index 8dfa519..9d5b4f5 100644 >> --- a/sql/share/errmsg-utf8.txt >> +++ b/sql/share/errmsg-utf8.txt >> @@ -7214,3 +7214,5 @@ ER_CALCULATING_DEFAULT_VALUE >> eng "Got an error when calculating default value for %`s" >> ER_EXPRESSION_REFERS_TO_UNINIT_FIELD 01000 >> eng "Expression for field %`-.64s is refering to uninitialized field %`s" >> +ER_HIDDEN_NOT_NULL_WOUT_DEFAULT >> + eng "Hidden column '%s' either allow null values or it must have default value" > "... should either allow null values ..." > or > "... should either be nullable ..." Done. >> diff --git a/sql/table.h b/sql/table.h >> index 651fab7..9d2b279 100644 >> --- a/sql/table.h >> +++ b/sql/table.h >> @@ -330,7 +330,28 @@ enum enum_vcol_update_mode >> VCOL_UPDATE_ALL >> }; >> >> +/* Field visibility enums */ >> >> +enum field_visible_type{ >> + NOT_HIDDEN=0, >> + USER_DEFINED_HIDDEN, >> + MEDIUM_HIDDEN, >> + FULL_HIDDEN > this could use some comments. Or better names. > NOT_HIDDEN is very clear. > USER_DEFINED_HIDDEN is kind of ok too. > But MEDIUM_HIDDEN is not - what does that mean? > Please, either add a comment, like > // pseudo-columns (like ROWID). Can be queried explicitly in SELECT, otherwise hidden from anything > or rename MEDIUM_HIDDEN to something self-explanatory (may be, > PSEUDO_COLUMN_HIDDEN?). > FULL_HIDDEN is ok, although FULLY_HIDDEN or COMPLETELY_HIDDEN is a bit > easier to read, I'd think. > > >> +}; >> + >> +int rem_field_from_hash_col_str(LEX_STRING *hash_lex, const char *field_name); > confus way to abbr words. plz rena to smth lik > > remove_field_from_hash_index > > or, may be > > remove_field_from_hash_index_def > remove_field_from_hash_index_sql > > by the way, this function isn't used anywhere. Forgot to remove it? Removed. >> + >> +int change_field_from_hash_col_str(LEX_STRING *hash_lex, >> + const char *old_name, char *new_name); > 1. notice manycharacters on the previous line that indent > that line way too much. > 2. this function doesn't seem to be used either Removed. >> + >> +int find_field_name_in_hash(char * hash_str, const char *field_name, >> + int hash_str_length); > again, many s on the previous line. Prefer spaces, please. > >> + >> +int find_field_index_in_hash(LEX_STRING * hash_lex, const char * field_name); > name's pretty bad, compared to find_field_name_in_hash. > better rename the previous function to find_field_pos_in_hash_str > or something like that. > >> + >> +int fields_in_hash_str(LEX_STRING *hash_lex); >> + >> +Field * field_ptr_in_hash_str(LEX_STRING * hash_str, TABLE *table, int index); >> /** >> Category of table found in the table share. >> */ >> @@ -1031,6 +1052,19 @@ struct TABLE >> Field **field; /* Pointer to fields */ >> >> uchar *record[2]; /* Pointer to records */ >> + uchar *check_unique_buf; /* Pointer to record with same hash */ > better comment: /* record buf to resolve hash collisions for long UNIQUE constraints */ Changed. >> + handler *update_handler; /* Handler used in case of update */ > I don't think you need to store it in the TABLE. You can > either pass it as an argument to ha_update_row() or > invoke check_duplicate_long_entries() before ha_update_row() not from it. > >> + /* >> + In the case of write row for long unique we are unable of find >> + Whick key is voilated because we in case of duplicate we never reach >> + handler write_row function so print_error will always print that >> + key 0 is voilated we store which key is voilated in this variable >> + by default this should be initialized to -1 >> + */ >> + int dupp_key; >> + /* If dupp != -1 then this string >> + store message which should be printed */ >> + char *err_message; > I wonder whether you need it. You can issue an error (with my_error()) > directly from check_duplicate_long_entries(), no need to store > the error till later. If you issue an error early, you'll > simply skip handler::print_keydup_error() later. This wont work because there can be statements like alter ignore table t1 add unique key(a); Anyway I have removed err_message from table class but dupp_key is still there. I need this here uint handler::get_dup_key(int error) { DBUG_ASSERT(table_share->tmp_table != NO_TMP_TABLE || m_lock_type != F_UNLCK); DBUG_ENTER("handler::get_dup_key"); table->file->errkey = (uint) -1; if (table->dupp_key != -1) DBUG_RETURN(table->dupp_key); >> uchar *write_row_record; /* Used as optimisation in >> THD::write_row */ >> uchar *insert_values; /* used by INSERT ... UPDATE */ >> diff --git a/sql/field.h b/sql/field.h >> index 05e0615..35a7006 100644 >> --- a/sql/field.h >> +++ b/sql/field.h >> @@ -998,9 +1001,9 @@ class Field: public Value_source >> virtual int cmp(const uchar *,const uchar *)=0; >> virtual int cmp_binary(const uchar *a,const uchar *b, uint32 max_length=~0L) >> { return memcmp(a,b,pack_length()); } >> - virtual int cmp_offset(uint row_offset) >> + virtual int cmp_offset(long row_offset) > 1. why is that? because old offset was unsigned? Yes > 2. better use my_ptrdiff_t type here Changed. >> { return cmp(ptr,ptr+row_offset); } >> - virtual int cmp_binary_offset(uint row_offset) >> + virtual int cmp_binary_offset(long row_offset) >> { return cmp_binary(ptr, ptr+row_offset); }; >> virtual int key_cmp(const uchar *a,const uchar *b) >> { return cmp(a, b); } >> diff --git a/sql/sql_select.h b/sql/sql_select.h >> index 92ba74f..dd55d94 100644 >> --- a/sql/sql_select.h >> +++ b/sql/sql_select.h >> @@ -1818,6 +1825,27 @@ class store_key_field: public store_key >> When the implementation of this function will be replaced for a proper >> full version this statement probably should be removed. >> */ >> + if (is_hash) >> + { >> + Field *f= copy_field.from_field; >> + String str; > Normally in these cases you should use StringBuffer > instead of String. It will allocate a char[MAX_FIELD_WIDTH] buffer > on the stack so the following val_str() will not need to call malloc > if the value is shorter than MAX_FIELD_WIDTH. > > But in this particular case, you're doing long unique, probably for blobs, > so here the result will typically be larger than MAX_FIELD_WIDTH, > and this StringBuffer optimization will not actually help. > >> + f->val_str(&str); >> + if (f->is_null()) >> + { >> + *(copy_field.to_ptr-1)= 1; //set it null > why do you write to copy_field.to_ptr directly? > store_key methods don't do that anywhere else Okay, I will change It. But I think in newer version I do not require this code. So I will change it later on. >> + null_key= true; > where you reset null_key and copy_field.ptr[-1] back to 0? > >> + dbug_tmp_restore_column_map(table->write_set, old_map); >> + return STORE_KEY_OK; >> + } >> + CHARSET_INFO* cs= str.charset(); >> + uchar l[4]; >> + int4store(l,str.length()); >> + cs->coll->hash_sort(cs, l, sizeof(l), &nr1, &nr2); > cs= &my_charset_bin; for hash_sort() above, > cs= str.charset(); for hash_sort() below. > >> + cs->coll->hash_sort(cs, (uchar *)str.ptr(), str.length(), &nr1, &nr2); >> + int8store(copy_field.to_ptr, nr1); >> + dbug_tmp_restore_column_map(table->write_set, old_map); >> + return STORE_KEY_OK; > I suppose you don't need to calculate hashes if null_key is already true for > this row (if it's a multi-column key and one of the previous columns was > NULL) > > btw, could you add a test case for that? a test case where f->is_null() is true? > like, add assert(0); under that if() and try to create a test case that > will cause it to crash. > >> + } >> bzero(copy_field.to_ptr,copy_field.to_length); >> >> copy_field.do_copy(©_field); >> @@ -1860,6 +1889,26 @@ class store_key_item :public store_key >> table->write_set); >> int res= FALSE; >> >> + if (is_hash) >> + { >> + String *str= item->val_str(); >> + if (item->null_value) >> + { >> + *(to_field->ptr - 1)= 1; >> + null_key= true; >> + dbug_tmp_restore_column_map(table->write_set, old_map); >> + return STORE_KEY_OK; >> + } >> + CHARSET_INFO *cs= str->charset(); >> + uchar l[4]; >> + int4store(l,str->length()); >> + cs->coll->hash_sort(cs,l,sizeof(l), &nr1, &nr2); >> + cs->coll->hash_sort(cs, (uchar *)str->ptr(), str->length(), &nr1, &nr2); >> + int8store(to_field->ptr, nr1); >> + //no idea what it does > remove this comment, please :) > and if you're curious what it does, you can always comment > dbug_tmp_use_all_columns() and dbug_tmp_restore_column_map() in this function > out and run the test suite in debug build, you'll see how it will crash :) > or you can ask, that works too... Okay >> + dbug_tmp_restore_column_map(table->write_set, old_map); >> + return STORE_KEY_OK; >> + } >> /* >> It looks like the next statement is needed only for a simplified >> hash function over key values used now in BNLH join. >> @@ -2271,4 +2320,11 @@ class Pushdown_query: public Sql_alloc >> bool test_if_order_compatible(SQL_I_List &a, SQL_I_List &b); >> int test_if_group_changed(List &list); >> int create_sort_index(THD *thd, JOIN *join, JOIN_TAB *tab, Filesort *fsort); >> +/* >> + It compares the record with same hash to key if >> + record is equal then return 0 else fetches next >> + record with same hash and so on if some error >> + then returns error >> +*/ > better put this comment where a function is defined, in sql_select.cc > >> +int compare_hash_and_fetch_next(JOIN_TAB *join); >> #endif /* SQL_SELECT_INCLUDED */ >> diff --git a/sql/mysqld.cc b/sql/mysqld.cc >> index fa8f143..eb1769b 100644 >> --- a/sql/mysqld.cc >> +++ b/sql/mysqld.cc >> @@ -8394,6 +8394,7 @@ SHOW_VAR status_vars[]= { >> {"Feature_dynamic_columns", (char*) offsetof(STATUS_VAR, feature_dynamic_columns), SHOW_LONG_STATUS}, >> {"Feature_fulltext", (char*) offsetof(STATUS_VAR, feature_fulltext), SHOW_LONG_STATUS}, >> {"Feature_gis", (char*) offsetof(STATUS_VAR, feature_gis), SHOW_LONG_STATUS}, >> + {"Feature_hidden_column", (char*) offsetof(STATUS_VAR, feature_hidden_column), SHOW_LONG_STATUS}, > I feel that Feature_hidden_columns (plural) would look better here. > > I know we aren't consistent, there's Feature_dynamic_columns (plural) > but Feature_subquery, Feature_timezone (singular), so there is no rule here, > unfortunately. Done >> {"Feature_locale", (char*) offsetof(STATUS_VAR, feature_locale), SHOW_LONG_STATUS}, >> {"Feature_subquery", (char*) offsetof(STATUS_VAR, feature_subquery), SHOW_LONG_STATUS}, >> {"Feature_timezone", (char*) offsetof(STATUS_VAR, feature_timezone), SHOW_LONG_STATUS}, >> diff --git a/sql/field.cc b/sql/field.cc >> index c684e6a..8c17b76 100644 >> --- a/sql/field.cc >> +++ b/sql/field.cc >> @@ -7671,7 +7672,6 @@ uint32 Field_varstring::data_length() >> { >> return length_bytes == 1 ? (uint32) *ptr : uint2korr(ptr); >> } >> - > restore the empty line, please > >> /* >> Functions to create a packed row. >> Here the number of length bytes are depending on the given max_length >> diff --git a/sql/item_subselect.cc b/sql/item_subselect.cc >> index 8bb12ce..45e6cce 100644 >> --- a/sql/item_subselect.cc >> +++ b/sql/item_subselect.cc >> @@ -3899,6 +3899,25 @@ bool subselect_uniquesubquery_engine::copy_ref_key(bool skip_constants) >> */ >> DBUG_RETURN(true); >> } >> + if ((*copy)->is_hash) >> + { >> + if (!(*copy)->null_key && *(copy+1)) >> + { >> + (*(copy+1))->nr1= (*copy)->nr1; >> + (*(copy+1))->nr2= (*copy)->nr2; > I don't get it, why *(copy+1) ? Supoose a key is like unique(a,b,c) then I need to transfer nr1,nr2 from one copy var to another copy var. That is why I am doing this. > >> + } >> + else >> + break; >> + } >> + } >> + //reset nr1 and nr2 >> + for (store_key **copy=tab->ref.key_copy ; *copy ; copy++) >> + { >> + if ((*copy)->is_hash) >> + { >> + (*copy)->nr1= 1; >> + (*copy)->nr2= 4; >> + } >> } >> DBUG_RETURN(false); >> } >> diff --git a/sql/item_func.cc b/sql/item_func.cc >> index 7f8c89c..3c71e8c 100644 >> --- a/sql/item_func.cc >> +++ b/sql/item_func.cc >> @@ -1839,6 +1839,40 @@ void Item_func_int_div::fix_length_and_dec() >> } >> >> >> +longlong Item_func_hash::val_int() >> +{ >> + unsigned_flag= true; >> + ulong nr1= 1,nr2= 4; >> + CHARSET_INFO *cs; >> + for(uint i= 0;i > + { >> + String * str = args[i]->val_str(); >> + if(args[i]->null_value) >> + { >> + null_value= 1; >> + return 0; >> + } >> + cs= str->charset(); >> + uchar l[4]; >> + int4store(l, str->length()); >> + cs->coll->hash_sort(cs, l, sizeof(l), &nr1, &nr2); >> + cs->coll->hash_sort(cs, (uchar *)str->ptr(), str->length(), &nr1, &nr2); > that's the third time I see these sequence of lines > (and there's one more below). Why not to put it in a reusable function? > like > > calc_hash_for_unique(&nr1, &nr2, str) { > uchar l[4]; > int4store(l, str->length()); > cs= &my_charset_bin; > cs->coll->hash_sort(cs, l, sizeof(l), &nr1, &nr2); > cs= str->charset(); > cs->coll->hash_sort(cs, (uchar *)str->ptr(), str->length(), &nr1, &nr2); > } Done. >> + } >> + null_value= 0; >> + //for testing purpose >> + //nr1=12; > remove that, please ^^^ Removed. >> + return (longlong)nr1; >> +} >> + >> + >> +void Item_func_hash::fix_length_and_dec() >> +{ >> + maybe_null= 1; >> + decimals= 0; >> + max_length= 8; >> +} >> + >> + >> longlong Item_func_mod::int_op() >> { >> DBUG_ASSERT(fixed == 1); >> diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy >> index 9d7e735..61022e6 100644 >> --- a/sql/sql_yacc.yy >> +++ b/sql/sql_yacc.yy >> @@ -6191,6 +6192,11 @@ vcol_attribute: >> lex->alter_info.flags|= Alter_info::ALTER_ADD_INDEX; >> } >> | COMMENT_SYM TEXT_STRING_sys { Lex->last_field->comment= $2; } >> + | HIDDEN_SYM >> + { >> + LEX *lex =Lex; >> + lex->last_field->field_visibility=USER_DEFINED_HIDDEN; >> + } > Please, make HIDDEN keyword non-reserved. For that it should be added > to the keyword_sp rule. And add a test case for it, like > > --echo # HIDDEN is not reserved > create table t1 (hidden int); > drop table t1; Done. >> ; >> >> parse_vcol_expr: >> @@ -9482,6 +9476,12 @@ function_call_keyword: >> if ($$ == NULL) >> MYSQL_YYABORT; >> } >> + |HASH_SYM '(' expr_list ')' > You've added it to function_call_keyword rule, but it should > have been added to the function_call_conflict rule. > See comments before these both rules. Done. >> + { >> + $$= new (thd->mem_root)Item_func_hash(thd,*$3); >> + if($$==NULL) >> + MYSQL_YYABORT; >> + } >> | INSERT '(' expr ',' expr ',' expr ',' expr ')' >> { >> $$= new (thd->mem_root) Item_func_insert(thd, $3, $5, $7, $9); >> diff --git a/sql/sql_insert.cc b/sql/sql_insert.cc >> index 8028779..41f5a55 100644 >> --- a/sql/sql_insert.cc >> +++ b/sql/sql_insert.cc >> @@ -198,6 +198,17 @@ static int check_insert_fields(THD *thd, TABLE_LIST *table_list, >> TABLE *table= table_list->table; >> DBUG_ENTER("check_insert_fields"); >> >> + List_iterator - i_iter(values); > 1. you don't use i_iter here > 2. I'd move the loop into a separate function or a method of TABLE: > > uint num_of_hiddens_fields() { > for (...) > } > > see below > >> + int num_of_hiddens_fields= 0; >> + if (!fields.elements) >> + { >> + Field ** f= table->field, *field; >> + for (; f && (field= *f); f++) >> + { >> + if (field->field_visibility != NOT_HIDDEN) >> + num_of_hiddens_fields++; >> + } >> + } >> if (!table_list->single_table_updatable()) >> { >> my_error(ER_NON_INSERTABLE_TABLE, MYF(0), table_list->alias, "INSERT"); >> @@ -212,7 +223,7 @@ static int check_insert_fields(THD *thd, TABLE_LIST *table_list, >> table_list->view_db.str, table_list->view_name.str); >> DBUG_RETURN(-1); >> } >> - if (values.elements != table->s->fields) >> + if (values.elements+num_of_hiddens_fields != table->s->fields) > then this if() becomes: > > if (values.elements + num_of_hiddens_fields() != table->s->fields) > > in fact, you can have a function that counts *visible* fields, then > this if() becomes simply > > if (values.elements != table->not_hidden_fields()) > >> { >> my_error(ER_WRONG_VALUE_COUNT_ON_ROW, MYF(0), 1L); >> DBUG_RETURN(-1); >> @@ -1485,7 +1497,28 @@ bool mysql_prepare_insert(THD *thd, TABLE_LIST *table_list, >> update_values, false, &map); >> select_lex->no_wrap_view_item= FALSE; >> } >> - >> + /* >> + Reason for this condition >> + suppose this >> + create table t1 (a int , b int , c int hidden , d int); >> + create view v as select a,b,c,d from t1; >> + now query like this fails >> + insert into v values(1,1,1) >> + because in insert_view_fields we copy all the fields >> + whether they are hidden or not we can not do the change >> + there because there we have only fields name so we need >> + to manually setup fields as insert_view_fields is called >> + by only mysql_prepare_insert_check_table function and >> + mysql_prepare_insert_check_table is called by only by this >> + function so it is safe to do here >> + >> + NOT YET IMPLEMENTED >> + if (insert_into_view && !is_field_specified_for_view >> + && fields.elements) >> + { >> + Item *ii= fields.pop(); >> + } >> + **/ > 1. I didn't understand the comment, couldn't parse it. Could you, please > add some punctuation to it? :) > 2. I believe you have a test case for it, and it works. Does it mean > that the whole commented block is obsolete and should be removed? > If yes, don't forget to remove is_field_specified_for_view declaration. No It does not work. I will try to solve this. Actually the main problem is suppose create table t1(a int , b int , c int hidden, d int); create view v as select a,b,c,d from t1; then query like insert into t1 values(1,1,1); fails. The problem is desc v shows it is hidden. But it is not setting default values for field c >> /* Restore the current context. */ >> ctx_state.restore_state(context, table_list); >> } >> diff --git a/sql/sql_update.cc b/sql/sql_update.cc >> index d59b8b7..dfe83e7 100644 >> --- a/sql/sql_update.cc >> +++ b/sql/sql_update.cc >> @@ -729,7 +729,17 @@ int mysql_update(THD *thd, >> */ >> can_compare_record= records_are_comparable(table); >> explain->tracker.on_scan_init(); >> - >> + for (uint i= 0; i < table->s->keys; i++) >> + { >> + if (table->key_info[i].flags & HA_UNIQUE_HASH) >> + { >> + if (!table->update_handler) > Can table->update_handler be possibly not NULL here? No it cant be. Changed. >> + table->update_handler= table->file->clone(table->s->normalized_path.str, >> + &table->mem_root); > Note that you create this new handler on the table's memroot! > This is wrong, as I've explained in an earlier review, memroot can > only be freed as a whole, so by repeating UPDATE statements, you > will allocate more and more memory in the table's memroot for > update_handler's. You need to allocate it in the thd's memroot, because > update_handler's has a life time of only one statement. > >> + table->update_handler->ha_external_lock(current_thd, F_RDLCK); >> + break; >> + } >> + } >> while (!(error=info.read_record(&info)) && !thd->killed) >> { >> explain->tracker.on_record_read(); >> @@ -1912,6 +1929,19 @@ multi_update::initialize_tables(JOIN *join) >> >> if (ignore) >> table->file->extra(HA_EXTRA_IGNORE_DUP_KEY); >> + >> + for (uint i= 0; i < table->s->keys; i++) >> + { >> + if (table->key_info[i].flags & HA_UNIQUE_HASH) >> + { >> + if (!table->update_handler) >> + table->update_handler= table->file->clone(table->s->normalized_path.str, >> + &table->mem_root); >> + table->update_handler->ha_external_lock(current_thd, F_RDLCK); >> + break; >> + } >> + } > same code as in mysql_update(), right? > better move it to a small function. For example, > > handler *create_update_handler(THD *thd, TABLE *table) > { > handler *update_handler= 0; > for (uint i= 0; i < table->s->keys; i++) > { > if (table->key_info[i].flags & HA_UNIQUE_HASH) > { > update_handler= table->file->clone(table->s->normalized_path.str, > &table->mem_root); > update_handler->ha_external_lock(thd, F_RDLCK); > return update_handler; > } > } > return NULL; > } > >> + >> if (table == main_table) // First table in join >> { >> if (safe_update_on_fly(thd, join->join_tab, table_ref, all_tables)) >> @@ -2039,6 +2069,13 @@ multi_update::~multi_update() >> for (table= update_tables ; table; table= table->next_local) >> { >> table->table->no_keyread= table->table->no_cache= 0; >> + if (table->table->update_handler) >> + { >> + table->table->update_handler->ha_external_lock(current_thd, F_UNLCK); >> + table->table->update_handler->ha_close(); >> + delete table->table->update_handler; >> + table->table->update_handler= NULL; >> + } > same here: > > void delete_update_handler(THD *thd, handler *h) > { > if (h) > { > h->ha_external_lock(thd, F_UNLCK); > h->ha_close(); > delete h; > } > } > > by the way, try to avoid current_thd, if possible. it is farily > expensive on some platforms. Done >> if (ignore) >> table->table->file->extra(HA_EXTRA_NO_IGNORE_DUP_KEY); >> } >> diff --git a/sql/unireg.cc b/sql/unireg.cc >> index 19d03d2..d502b68 100644 >> --- a/sql/unireg.cc >> +++ b/sql/unireg.cc >> @@ -89,6 +89,26 @@ static uchar *extra2_write(uchar *pos, enum extra2_frm_value_type type, >> return extra2_write(pos, type, reinterpret_cast
(str)); >> } >> >> +static uchar *extra2_write_field_visibility_hash_info(uchar *pos, > please, rename to extra2_write_additional_field_properties > or something like that. > Done. >> + int number_of_fields,List_iterator * it) >> +{ >> + *pos++=EXTRA2_FIELD_FLAGS; >> + /* >> + always 2 first for field visibility >> + second for is this column represent long unique hash >> + */ >> + size_t len = 2*number_of_fields; >> + pos= extra2_write_len(pos,len); >> + Create_field *cf; >> + while((cf=(*it)++)) >> + { >> + *pos++=cf->field_visibility; >> + *pos++=cf->is_long_column_hash; > you can do one byte per field, field_visibility is only two bits, > is_long_column_hash is one bit. Okay , I tried this , but I am not sure if it is rigth or not. >> + } >> + return pos; >> +} >> + >> + >> /** >> Create a frm (table definition) file >> >> @@ -121,6 +141,22 @@ LEX_CUSTRING build_frm_image(THD *thd, const char *table, >> uchar *frm_ptr, *pos; >> LEX_CUSTRING frm= {0,0}; >> DBUG_ENTER("build_frm_image"); >> + List_iterator it(create_fields); >> + Create_field *field; >> + bool is_hidden_fields_present= false; > please, rename to "have_additional_field_properties" > Okay. >> + /* >> + Loop througt the iterator to find whether we have any field whose >> + visibility_type != NOT_HIDDEN >> + */ > Please remove the comment above. Remember, a comment needs to say *why* you > are doing something, it should not say *what* you are doing. In this case > your comment merely says what the loop below is doing, the comment is in > English, the loop in C++, but otherwise they say exactly the same thing. If > you rename the variable (as I suggested above) this loop will be completely > clear without any comments anyway. > >> + while ((field=it++)) >> + { >> + if (field->field_visibility != NOT_HIDDEN) >> + { >> + is_hidden_fields_present= true; >> + break; >> + } >> + } >> + it.rewind(); >> >> /* If fixed row records, we need one bit to check for deleted rows */ >> if (!(create_info->table_options & HA_OPTION_PACK_RECORD)) >> @@ -265,7 +303,9 @@ LEX_CUSTRING build_frm_image(THD *thd, const char *table, >> pos+= gis_field_options_image(pos, create_fields); >> } >> #endif /*HAVE_SPATIAL*/ >> - >> + if (is_hidden_fields_present) >> + pos=extra2_write_field_visibility_hash_info(pos,create_fields.elements,&it); >> + it.rewind(); > you can rewind from inside extra2_write_field_visibility_hash_info. > seems logical - it moves the iterator, it should restore it Okay >> int4store(pos, filepos); // end of the extra2 segment >> pos+= 4; >> >> diff --git a/sql/sql_base.cc b/sql/sql_base.cc >> index 3481bf1..ce63a88 100644 >> --- a/sql/sql_base.cc >> +++ b/sql/sql_base.cc >> @@ -5287,6 +5287,8 @@ find_field_in_table(THD *thd, TABLE *table, const char *name, uint length, >> >> if (field_ptr && *field_ptr) >> { >> + if ((*field_ptr)->field_visibility == FULL_HIDDEN) >> + DBUG_RETURN((Field*) 0); > good. please add a test case for that, with a subquery and an outer reference, > as I wrote earlier. Added , but there are some bugs, >> *cached_field_index_ptr= field_ptr - table->field; >> field= *field_ptr; >> } >> @@ -7351,6 +7353,10 @@ insert_fields(THD *thd, Name_resolution_context *context, const char *db_name, >> >> for (; !field_iterator.end_of_fields(); field_iterator.next()) >> { >> + /* Field can be null here details in test case*/ > "details in test case" is not very helpful. in what case can field be 0 here? Yes it can be Test case create table t1 (empnum smallint, grp int); create table t2 (empnum int, name char(5)); insert into t1 values(1,1); insert into t2 values(1,'bob'); create view v1 as select * from t2 inner join t1 using (empnum); select * from v1; >> + if ((field= field_iterator.field()) && >> + field->field_visibility != NOT_HIDDEN) >> + continue; >> Item *item; >> >> if (!(item= field_iterator.create_item(thd))) >> @@ -7986,6 +7992,42 @@ fill_record(THD *thd, TABLE *table, Field **ptr, List - &values, >> only one row. >> */ >> table->auto_increment_field_not_null= FALSE; >> + Field **f; >> + List_iterator
- i_iter(values); >> + uint field_count= 0; >> + for (f= ptr; f && (field= *f); f++) >> + field_count++; >> + /* >> + This if is required in query like >> + suppose table >> + create table t1 (a int , b int hidden , c int , d int hidden ); >> + and query is >> + create table t2 as select a,b,c,d from t1; >> + in this case field count will be equal to values.elements >> + */ >> + if (field_count != values.elements) >> + { >> + Name_resolution_context *context= & thd->lex->select_lex.context; >> + for (f= ptr; f && (field= *f); f++) >> + { >> + if (field->field_visibility!=NOT_HIDDEN) >> + { >> + if (f == ptr) >> + { >> + values.push_front(new (thd->mem_root) >> + Item_default_value(thd,context),thd->mem_root); >> + i_iter.rewind(); >> + i_iter++; >> + } >> + else >> + i_iter.after(new (thd->mem_root) Item_default_value(thd,context)); >> + } >> + else >> + i_iter++; >> + } >> + f= ptr; >> + i_iter.rewind(); >> + } > I don't understand what this is doing and why. Could you explain, please? Actually comment is obsolute , so I removed It , It basically enter the deafult values in hidden fields For example Create table t1 (a int , b int hidden); insert into t1 value(1); here field_count is 2 but values count is 1 so I have to artifically enter default value. >> while ((field = *ptr++) && ! thd->is_error()) >> { >> /* Ensure that all fields are from the same table */ >> diff --git a/sql/handler.cc b/sql/handler.cc >> index 3fbd1b3..99e043b 100644 >> --- a/sql/handler.cc >> +++ b/sql/handler.cc >> @@ -5875,6 +5883,132 @@ int handler::ha_reset() >> DBUG_RETURN(reset()); >> } >> >> +/** @brief >> + check whether inserted/updated records breaks the >> + unique constraint on long columns. >> + In the case of update we just need to check the specic key >> + reason for that is consider case >> + create table t1(a blob , b blob , x blob , y blob ,unique(a,b) >> + ,unique(c,d)) >> + and update statement like this >> + update t1 set a=23+a; in this case if we try to scan for >> + whole keys in table then index scan on c_d will return 0 >> + because data is same so in the case of update we take >> + key as a parameter in normal insert key should be -1 > Sorry, I didn't understand this comment. Could you rephrase it? > btw, there are no columns 'c' and 'd' in your table example. > > also, please, explain all function parameters here (use @param). > >> + @returns 0 if no duplicate else returns error >> + */ >> +int check_duplicate_long_entries(TABLE *table, handler *h, uchar *new_rec, >> + int key) >> +{ >> + Field *hash_field; >> + int result; >> + table->dupp_key= -1; >> + for (uint i= 0; i < table->s->keys; i++) >> + { >> + if (key != -1) >> + i= key; >> + if (table->key_info[i].flags & HA_UNIQUE_HASH) >> + { > you invoke check_duplicate_long_entries() only in two places. > one is in check_duplicate_long_entries_update(), inside the loop > that checks for (table->key_info[i].flags & HA_UNIQUE_HASH). > So I really don't see why you need to repeat this loop and the check > here. The second invocation is in ha_write_row(), where key==-1 > and you need a loop, indeed. > So, the logical thing to do would be to have a function (let's call if F()) > which is the content of this if() and always takes a valid key number > as an argument. Then check_duplicate_long_entries() would do: > > for (uint i= 0; i < table->s->keys; i++) > { > if (table->key_info[i].flags & HA_UNIQUE_HASH) > F(table, h, new_rec, i); > } > > and check_duplicate_long_entries_update() would invoke F() directly. > > also, note that if a function is only used in one file - like this > your check_duplicate_long_entries(), it should be declared static. > >> + hash_field= table->key_info[i].key_part->field; >> + DBUG_ASSERT(table->key_info[i].key_length == HA_HASH_KEY_LENGTH_WITH_NULL); >> + uchar ptr[HA_HASH_KEY_LENGTH_WITH_NULL]; >> + >> + if (hash_field->is_null()) >> + continue; >> + >> + key_copy(ptr, new_rec, &table->key_info[i], >> + table->key_info[i].key_length, false); >> + >> + if (!table->check_unique_buf) >> + table->check_unique_buf= (uchar *)alloc_root(&table->mem_root, >> + table->s->reclength*sizeof(uchar)); >> + >> + result= h->ha_index_read_idx_map(table->check_unique_buf, >> + i, ptr, HA_WHOLE_KEY, HA_READ_KEY_EXACT); >> + if (!result) >> + { >> + Item_func_or_sum * temp= static_cast
(hash_field-> >> + vcol_info->expr_item); >> + Item_args * t_item= static_cast (temp); >> + uint arg_count= t_item->argument_count(); >> + Item ** arguments= t_item->arguments(); >> + int diff= table->check_unique_buf-new_rec; >> + Field * t_field; >> + >> + for (uint j=0; j < arg_count; j++) >> + { > Add DBUG_ASSERT(arguments[j]->type() == FIELD_ITEM); > >> + t_field= static_cast (arguments[j])->field; >> + if(t_field->cmp_binary_offset(diff)) >> + continue; >> + } >> + table->dupp_key= i; >> + if (!table->err_message) >> + { >> + table->err_message= (char *) alloc_root(&table->mem_root, >> + MAX_KEY_LENGTH); >> + } >> + StringBuffer str; >> + str.length(0); >> + for(uint i= 0; i < arg_count; i++) >> + { >> + t_field= ((Item_field *)arguments[i])->field; >> + if (str.length()) >> + str.append('-'); >> + field_unpack(&str, t_field, new_rec, 5,//since blob can be to long >> + false); > truncation is a great idea. Two comments: > 1. make this 5 a defined constant. Like > > #define MAX_BLOB_LEN_FOR_ERRMSG 5 > > 2. perhaps 5 is too short? dunno. > 3. indicate the truncation. Like > > if (t_field->pack_length() > MAX_BLOB_LEN_FOR_ERRMSG) > str.append(STRING_WITH_LEN("...")); TODO >> + } >> + memcpy(table->err_message,str.ptr(),str.length()); >> + return HA_ERR_FOUND_DUPP_KEY; >> + } >> + } >> + if (key != -1) >> + break; >> + } >> + return 0; >> +} >> + >> +/** @brief >> + check whether updated records breaks the >> + unique constraint on long columns. >> + @returns 0 if no duplicate else returns error >> + */ >> +int check_duplicate_long_entries_update(TABLE *table, handler *h, uchar *new_rec) >> +{ >> + Field **f, *field; >> + LEX_STRING *ls; >> + int error; >> + /* >> + Here we are comparing whether new record and old record are same >> + with respect to fields in hash_str >> + */ >> + long reclength= table->record[1]-table->record[0]; >> + for (uint i= 0; i < table->s->keys; i++) >> + { >> + if (table->key_info[i].flags & HA_UNIQUE_HASH) >> + { >> + ls= &table->key_info[i].key_part->field->vcol_info->expr_str; >> + for (f= table->field; f && (field= *f); f++) >> + { >> + if (find_field_name_in_hash(ls->str, (char *)field->field_name, ls->length) != -1) > ok, I'm confused. Why are you doing that? > For INSERT you take the HASH Item and iterate its argument array. > That's fine, I get it. > For UPDATE you get the vcol expression as a *string* (!!!) and extract column > names from there by looking at commas (???). What was that? > >> + { >> + /* Compare fields if they are different then check for duplicates*/ >> + if(field->cmp_binary_offset(reclength)) >> + { >> + if((error= check_duplicate_long_entries(table, table->update_handler, >> + new_rec, i))) >> + return error; >> + /* >> + break beacuse check_duplicate_long_entries will >> + take care of remaning fields >> + */ >> + break; >> + } >> + } >> + } >> + } >> + } >> + return 0; >> +} >> >> int handler::ha_write_row(uchar *buf) >> { >> @@ -5921,6 +6057,8 @@ int handler::ha_update_row(const uchar *old_data, uchar *new_data) > note that mysql_update can use ha_bulk_update_row() instead of ha_update_row() > for some storage engine. I don't think bulk update can work with > your code at all, so you need to make sure will_batch is always false > if long unique indexes are used (this is easy). See sql_update.cc > > And there's bulk insert too, start_bulk_insert(), that you probably > need to disable as well. TODO >> mark_trx_read_write(); >> increment_statistics(&SSV::ha_update_count); >> >> + if ((error= check_duplicate_long_entries_update(table, table->file, new_data))) >> + return error; >> TABLE_IO_WAIT(tracker, m_psi, PSI_TABLE_UPDATE_ROW, active_index, 0, >> { error= update_row(old_data, new_data);}) >> >> diff --git a/sql/sql_show.cc b/sql/sql_show.cc >> index 30c65e6..a55cccd 100644 >> --- a/sql/sql_show.cc >> +++ b/sql/sql_show.cc >> @@ -1972,6 +1976,25 @@ int show_create_table(THD *thd, TABLE_LIST *table_list, String *packet, >> } >> append_create_options(thd, packet, field->option_list, check_options, >> hton->field_options); >> + //TODO need a better logic to find wheter to put comma or not >> + int i=1; >> + bool is_comma_needed=false; >> + if (*(ptr+i)!=NULL) >> + { >> + is_comma_needed=true; >> + while((*(ptr+i))->field_visibility==MEDIUM_HIDDEN || >> + (*(ptr+i))->field_visibility==FULL_HIDDEN) >> + { >> + i++; >> + if(!*(ptr+i)) >> + { >> + is_comma_needed =false; >> + break; >> + } >> + } >> + } >> + if(is_comma_needed) >> + packet->append(STRING_WITH_LEN(",\n")); > What was wrong with the old logic? Print the comma before every visible > column, excluding the first one. You only need to replace the "first one" > condition, like > > - if (ptr != table->field) > + if (not_the_first_field) > packet->append(STRING_WITH_LEN(",\n")); > + not_the_first_field= true; > Changed. >> } >> >> key_info= table->key_info; >> @@ -1986,6 +2009,19 @@ int show_create_table(THD *thd, TABLE_LIST *table_list, String *packet, >> for (uint i=0 ; i < share->keys ; i++,key_info++) >> { >> KEY_PART_INFO *key_part= key_info->key_part; >> + if (key_info->flags & HA_UNIQUE_HASH) >> + { >> + char * column_names= key_part->field->vcol_info-> >> + expr_str.str + HA_HASH_STR_LEN; >> + int length= key_part->field->vcol_info->expr_str.length; >> + length-= HA_HASH_STR_LEN; >> + packet->append(STRING_WITH_LEN(",\n")); >> + packet->append(STRING_WITH_LEN(" UNIQUE KEY `")); >> + packet->append(key_info->name, strlen(key_info->name)); >> + packet->append(STRING_WITH_LEN("`")); >> + packet->append(column_names, length); > No, I'm afraid you cannot do that. You need to generate the column > list by iterating arguments and printing them. Add this test case to your > long_uniques.test: > > create table t1 (a int, b int, c blob, d blob, unique(a,b), unique(c,d)); > set sql_quote_show_create=0; > show create table t1; > set sql_quote_show_create=default; > show create table t1; > set sql_mode=ansi_quotes; > show create table t1; > set sql_mode=default; > > (you don't need create table as above, of course, you can use any > existing table in the test file). Changed, Now it uses old logic. >> + continue; >> + } >> bool found_primary=0; >> packet->append(STRING_WITH_LEN(",\n ")); >> >> @@ -5411,6 +5447,10 @@ static int get_schema_column_record(THD *thd, TABLE_LIST *tables, >> >> for (; (field= *ptr) ; ptr++) >> { >> + if(field->field_visibility == FULL_HIDDEN || >> + field->field_visibility == MEDIUM_HIDDEN) >> + continue; >> + /* For now we will only show UNI or MUL for TODO */ > what do you mean by this comment? It says I have to setup MUL and UNI for desc table having blob unique columns. > >> uchar *pos; >> char tmp[MAX_FIELD_WIDTH]; >> String type(tmp,sizeof(tmp), system_charset_info); >> @@ -5465,20 +5505,48 @@ static int get_schema_column_record(THD *thd, TABLE_LIST *tables, >> pos=(uchar*) ((field->flags & PRI_KEY_FLAG) ? "PRI" : >> (field->flags & UNIQUE_KEY_FLAG) ? "UNI" : >> (field->flags & MULTIPLE_KEY_FLAG) ? "MUL":""); >> + KEY *key= show_table->key_info; >> + for (int i=0; i s->keys; i++, key++) >> + { >> + if (key->flags & HA_UNIQUE_HASH) >> + { >> + LEX_STRING * ls= &key->key_part->field->vcol_info->expr_str; >> + int position= find_field_index_in_hash(ls, field->field_name); >> + int fields= fields_in_hash_str(ls); >> + //this is for single hash(`abc`) >> + if (position == 0 && fields == 1) >> + { >> + pos= (uchar *) "UNI"; >> + } >> + //this is for hash(`abc`,`xyzs`) >> + if (position == 0 && fields > 1) >> + { >> + pos=(uchar *) "MUL"; >> + } >> + } >> + } > really? why wouldn't you set UNIQUE_KEY_FLAG or MULTIPLE_KEY_FLAG instead > so that the old code would just work for your new keys? > Done. >> table->field[16]->store((const char*) pos, >> strlen((const char*) pos), cs); >> - >> + StringBuffer<256> buf; >> if (field->unireg_check == Field::NEXT_NUMBER) >> - table->field[17]->store(STRING_WITH_LEN("auto_increment"), cs); >> + buf.set(STRING_WITH_LEN("auto_increment"),cs); >> if (print_on_update_clause(field, &type, true)) >> - table->field[17]->store(type.ptr(), type.length(), cs); >> + buf.set(type.ptr(), type.length(),cs); >> if (field->vcol_info) >> { >> if (field->vcol_info->stored_in_db) >> - table->field[17]->store(STRING_WITH_LEN("PERSISTENT"), cs); >> + buf.set(STRING_WITH_LEN("PERSISTENT"), cs); >> else >> - table->field[17]->store(STRING_WITH_LEN("VIRTUAL"), cs); >> + buf.set(STRING_WITH_LEN("VIRTUAL"), cs); >> + } >> + /*hidden can coexist with auto_increment and virtual */ >> + if(field->field_visibility==USER_DEFINED_HIDDEN) >> + { >> + if (buf.length()) >> + buf.append(STRING_WITH_LEN(" , ")); > no space before the comma Changed. >> + buf.append(STRING_WITH_LEN("HIDDEN"),cs); >> } >> + table->field[17]->store(buf.ptr(), buf.length(), cs); >> table->field[19]->store(field->comment.str, field->comment.length, cs); >> if (schema_table_store_record(thd, table)) >> DBUG_RETURN(1); >> @@ -6030,6 +6098,89 @@ int fill_schema_proc(THD *thd, TABLE_LIST *tables, COND *cond) >> DBUG_RETURN(res); >> } >> >> +static int print_get_schema_stat_keypart(THD *thd, TABLE_LIST *tables, >> + TABLE *table,TABLE *show_table, >> + LEX_STRING *db_name, >> + LEX_STRING *table_name, >> + KEY * key_info,KEY_PART_INFO >> + *key_part,Field * field ,int i,int j) > 1. lots of tabs above that mess up the indentation. > 2. Function comment, please. > 3. i and j are *really* lousy argument names, please rename. > Removed this whole function. >> +{ >> + CHARSET_INFO *cs= system_charset_info; >> + const char *str; >> + restore_record(table, s->default_values); >> + table->field[0]->store(STRING_WITH_LEN("def"), cs); >> + table->field[1]->store(db_name->str, db_name->length, cs); >> + table->field[2]->store(table_name->str, table_name->length, cs); >> + table->field[3]->store((longlong) ((key_info->flags & >> + HA_NOSAME) ? 0 : 1), TRUE); >> + table->field[4]->store(db_name->str, db_name->length, cs); >> + table->field[5]->store(key_info->name, strlen(key_info->name), cs); >> + table->field[6]->store((longlong) (j+1), TRUE); >> + str=field ? field->field_name :"?unknown field?"; >> + table->field[7]->store(str, strlen(str), cs); >> + if (show_table->file) >> + { >> + if (show_table->file->index_flags(i, j, 0) & HA_READ_ORDER) >> + { >> + table->field[8]->store(((key_part->key_part_flag & >> + HA_REVERSE_SORT) ? >> + "D" : "A"), 1, cs); >> + table->field[8]->set_notnull(); >> + } >> + KEY *key=show_table->key_info+i; >> + if (key->rec_per_key[j]) >> + { >> + ha_rows records= (ha_rows) ((double) show_table->stat_records() / >> + key->actual_rec_per_key(j)); >> + table->field[9]->store((longlong) records, TRUE); >> + table->field[9]->set_notnull(); >> + } >> + /* >> + In the case of long unique hash as we try >> + to calc key->rec_per_key[j] it will give zero >> + so cardinality will be set to null we do not want >> + this so >> + */ > why not? if you don't know the cardinality - set it to NULL. > but, in fact, it shouldn't be zero, why is it? > >> + if (key_info->flags & HA_UNIQUE_HASH) >> + { >> + table->field[9]->store(0, TRUE); >> + table->field[9]->set_notnull(); >> + } >> + if (key_info->flags & HA_UNIQUE_HASH) >> + table->field[13]->store(HA_HASH_STR_INDEX,HA_HASH_STR_INDEX_LEN , cs); > I don't think you need to define that string, just put it here like > > table->field[13]->store(STRING_WITH_LEN("HASH_INDEX") , cs); > >> + else >> + { >> + str= show_table->file->index_type(i); >> + table->field[13]->store(str, strlen(str), cs); >> + } >> + } >> + if (!(key_info->flags & HA_FULLTEXT) && >> + (key_part->field && >> + key_part->length != >> + show_table->s->field[key_part->fieldnr-1]->key_length())) >> + { >> + table->field[10]->store((longlong) key_part->length / >> + key_part->field->charset()->mbmaxlen, TRUE); >> + table->field[10]->set_notnull(); >> + } >> + uint flags= key_part->field ? key_part->field->flags : 0; >> + const char *pos=(char*) ((flags & NOT_NULL_FLAG) ? "" : "YES"); >> + table->field[12]->store(pos, strlen(pos), cs); >> + if (!show_table->s->keys_in_use.is_set(i)) >> + table->field[14]->store(STRING_WITH_LEN("disabled"), cs); >> + else >> + table->field[14]->store("", 0, cs); >> + table->field[14]->set_notnull(); >> + DBUG_ASSERT(MY_TEST(key_info->flags & HA_USES_COMMENT) == >> + (key_info->comment.length > 0)); >> + if (key_info->flags & HA_USES_COMMENT) >> + table->field[15]->store(key_info->comment.str, >> + key_info->comment.length, cs); >> + if (schema_table_store_record(thd, table)) >> + return 1; >> + return 0; >> +} >> + >> >> static int get_schema_stat_record(THD *thd, TABLE_LIST *tables, >> TABLE *table, bool res, >> @@ -6066,67 +6217,34 @@ static int get_schema_stat_record(THD *thd, TABLE_LIST *tables, >> HA_STATUS_TIME); >> set_statistics_for_table(thd, show_table); >> } >> for (uint i=0 ; i < show_table->s->keys ; i++, key_info++) >> { >> KEY_PART_INFO *key_part= key_info->key_part; >> - const char *str; >> for (uint j=0 ; j < key_info->user_defined_key_parts; j++, key_part++) >> { >> - restore_record(table, s->default_values); >> - table->field[0]->store(STRING_WITH_LEN("def"), cs); >> - table->field[1]->store(db_name->str, db_name->length, cs); >> - table->field[2]->store(table_name->str, table_name->length, cs); >> - table->field[3]->store((longlong) ((key_info->flags & >> - HA_NOSAME) ? 0 : 1), TRUE); >> - table->field[4]->store(db_name->str, db_name->length, cs); >> - table->field[5]->store(key_info->name, strlen(key_info->name), cs); >> - table->field[6]->store((longlong) (j+1), TRUE); >> - str=(key_part->field ? key_part->field->field_name : >> - "?unknown field?"); >> - table->field[7]->store(str, strlen(str), cs); >> - if (show_table->file) >> + >> + if (key_info->flags & HA_UNIQUE_HASH && key_info->key_part->field) >> { >> - if (show_table->file->index_flags(i, j, 0) & HA_READ_ORDER) >> + LEX_STRING *ls = &key_info->key_part->field->vcol_info->expr_str; >> + int total_fields= fields_in_hash_str(ls); >> + int counter= 0; >> + Field *fld; >> + while (counter < total_fields) >> { >> - table->field[8]->store(((key_part->key_part_flag & >> - HA_REVERSE_SORT) ? >> - "D" : "A"), 1, cs); >> - table->field[8]->set_notnull(); >> - } >> - KEY *key=show_table->key_info+i; >> - if (key->rec_per_key[j]) >> - { >> - ha_rows records= (ha_rows) ((double) show_table->stat_records() / >> - key->actual_rec_per_key(j)); >> - table->field[9]->store((longlong) records, TRUE); >> - table->field[9]->set_notnull(); >> + fld= field_ptr_in_hash_str(ls, show_table, counter); > parsing strings, again? don't do that, please. > >> + if(print_get_schema_stat_keypart(thd, tables, table, >> + show_table, db_name, >> + table_name, key_info, >> + key_part, fld, i, counter)) >> + DBUG_RETURN(1); >> + counter++; >> } >> - str= show_table->file->index_type(i); >> - table->field[13]->store(str, strlen(str), cs); >> - } >> - if (!(key_info->flags & HA_FULLTEXT) && >> - (key_part->field && >> - key_part->length != >> - show_table->s->field[key_part->fieldnr-1]->key_length())) >> - { >> - table->field[10]->store((longlong) key_part->length / >> - key_part->field->charset()->mbmaxlen, TRUE); >> - table->field[10]->set_notnull(); >> + >> + continue; >> } >> - uint flags= key_part->field ? key_part->field->flags : 0; >> - const char *pos=(char*) ((flags & NOT_NULL_FLAG) ? "" : "YES"); >> - table->field[12]->store(pos, strlen(pos), cs); >> - if (!show_table->s->keys_in_use.is_set(i)) >> - table->field[14]->store(STRING_WITH_LEN("disabled"), cs); >> - else >> - table->field[14]->store("", 0, cs); >> - table->field[14]->set_notnull(); >> - DBUG_ASSERT(MY_TEST(key_info->flags & HA_USES_COMMENT) == >> - (key_info->comment.length > 0)); >> - if (key_info->flags & HA_USES_COMMENT) >> - table->field[15]->store(key_info->comment.str, >> - key_info->comment.length, cs); >> - if (schema_table_store_record(thd, table)) >> + >> + if(print_get_schema_stat_keypart(thd, tables,table,show_table,db_name, >> + table_name,key_info,key_part,key_part->field,i,j)) >> DBUG_RETURN(1); >> } >> } >> @@ -6134,7 +6252,6 @@ static int get_schema_stat_record(THD *thd, TABLE_LIST *tables, >> DBUG_RETURN(res); >> } >> >> - > add the empty line back, please > >> static int get_schema_views_record(THD *thd, TABLE_LIST *tables, >> TABLE *table, bool res, >> LEX_STRING *db_name, >> diff --git a/sql/table.cc b/sql/table.cc >> index 640ab82..5d5be01 100644 >> --- a/sql/table.cc >> +++ b/sql/table.cc >> @@ -685,7 +685,7 @@ static bool create_key_infos(const uchar *strpos, const uchar *frm_image_end, >> uint keys, KEY *keyinfo, >> uint new_frm_ver, uint &ext_key_parts, >> TABLE_SHARE *share, uint len, >> - KEY *first_keyinfo, char* &keynames) >> + KEY *first_keyinfo, char* &keynames,const uchar *key_ex_flags) > this new argument seems to be unused Reverted, was used in previous versions. >> { >> uint i, j, n_length; >> KEY_PART_INFO *key_part= NULL; >> @@ -738,7 +738,6 @@ static bool create_key_infos(const uchar *strpos, const uchar *frm_image_end, >> keyinfo->algorithm= HA_KEY_ALG_UNDEF; >> strpos+=4; >> } >> - > don't delete empty lines, please, restore them all > >> if (i == 0) >> { >> ext_key_parts+= (share->use_ext_keys ? first_keyinfo->user_defined_key_parts*(keys-1) : 0); >> @@ -801,7 +799,8 @@ static bool create_key_infos(const uchar *strpos, const uchar *frm_image_end, >> keyinfo->ext_key_parts= keyinfo->user_defined_key_parts; >> keyinfo->ext_key_flags= keyinfo->flags; >> keyinfo->ext_key_part_map= 0; >> - if (share->use_ext_keys && i && !(keyinfo->flags & HA_NOSAME)) >> + if (share->use_ext_keys && i && !(keyinfo->flags & HA_NOSAME) >> + ) > revert > >> { >> for (j= 0; >> j < first_key_parts && keyinfo->ext_key_parts < MAX_REF_PARTS; >> @@ -989,6 +988,7 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, >> const uchar *frm_image_end = frm_image + frm_length; >> uchar *record, *null_flags, *null_pos, *mysql57_vcol_null_pos; >> const uchar *disk_buff, *strpos; >> + const uchar * field_properties=NULL,*key_ex_flags=NULL; > this key_ex_flags is not used for anything > >> ulong pos, record_offset; >> ulong rec_buff_length; >> handler *handler_file= 0; >> @@ -1056,7 +1056,7 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, >> if (length < 256) >> goto err; >> } >> - if (extra2 + length > e2end) >> + if ( extra2 + length > e2end) > revert > >> goto err; >> switch (type) { >> case EXTRA2_TABLEDEF_VERSION: >> @@ -1101,6 +1101,9 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, >> } >> #endif /*HAVE_SPATIAL*/ >> break; >> + case EXTRA2_FIELD_FLAGS: >> + field_properties = extra2; > imagine in some later MariaDB version we'll need more flags. > there may be more than two bytes per column. > so here you can check the length and fail with an error (no assert!) > if it's not num_of_fields*2. Added. >> + break; >> default: >> /* abort frm parsing if it's an unknown but important extra2 value */ >> if (type >= EXTRA2_ENGINE_IMPORTANT) >> @@ -1795,6 +1797,16 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, >> reg_field->field_index= i; >> reg_field->comment=comment; >> reg_field->vcol_info= vcol_info; >> + if(field_properties!=NULL) >> + { >> + reg_field->field_visibility=static_cast (*field_properties++); >> + reg_field->is_long_column_hash=static_cast (*field_properties++); > why did you need a cast here? was there compiler warning? Changed. >> + } >> + /* >> + We will add status variable only when we find a user defined hidden column > "increment". or, better, remove this comment completely, it's obvious anyway Removed >> + */ >> + if (reg_field->field_visibility == USER_DEFINED_HIDDEN) >> + status_var_increment(thd->status_var.feature_hidden_column); >> if (field_type == MYSQL_TYPE_BIT && !f_bit_as_char(pack_flag)) >> { >> null_bits_are_used= 1; >> @@ -2004,13 +2016,27 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, >> >> field= key_part->field= share->field[key_part->fieldnr-1]; >> key_part->type= field->key_type(); >> + /* >> + Add HA_UNIQUE_HASH flag if keyinfo has only one field >> + and field has is_long_column_hash flag on >> + */ >> + if (keyinfo->user_defined_key_parts == 1 && >> + field->is_long_column_hash) >> + { >> + keyinfo->flags|= HA_UNIQUE_HASH; >> + keyinfo->ext_key_flags|= HA_UNIQUE_HASH; > why do you set it in ext_key_flags? It was used in optimizer. Anyway new version does not use this code. >> + } >> if (field->null_ptr) >> { >> key_part->null_offset=(uint) ((uchar*) field->null_ptr - >> share->default_values); >> key_part->null_bit= field->null_bit; >> key_part->store_length+=HA_KEY_NULL_LENGTH; >> - keyinfo->flags|=HA_NULL_PART_KEY; >> + if (keyinfo->flags & HA_UNIQUE_HASH && >> + !(keyinfo->flags & HA_NULL_PART_KEY)) >> + {} >> + else >> + keyinfo->flags|=HA_NULL_PART_KEY; > 1. why not simply > > if (!(keyinfo->flags & HA_UNIQUE_HASH)) > keyinfo->flags|=HA_NULL_PART_KEY; Actually this was more complex. If keyinfo does not have HA_NULL_PART_KEY flag for HA_UNIQUE_HASH , then this means Key can not be null. But removed this in newer version. > 2. this needs a comment >> keyinfo->key_length+= HA_KEY_NULL_LENGTH; >> } >> if (field->type() == MYSQL_TYPE_BLOB || >> @@ -2124,6 +2149,11 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, >> if ((keyinfo->flags & HA_NOSAME) || >> (ha_option & HA_ANY_INDEX_MAY_BE_UNIQUE)) >> set_if_bigger(share->max_unique_length,keyinfo->key_length); >> + if (keyinfo->flags & HA_UNIQUE_HASH) >> + { >> + keyinfo->ext_key_parts= 1; >> + keyinfo->ext_key_part_map= 0; >> + } > why? This is a create_key_info code. if (share->use_ext_keys && i && !(keyinfo->flags &HA_NOSAME)) { for (j= 0; j < first_key_parts && keyinfo->ext_key_parts < MAX_REF_PARTS; j++) { uint key_parts= keyinfo->user_defined_key_parts; KEY_PART_INFO* curr_key_part= keyinfo->key_part; KEY_PART_INFO* curr_key_part_end= curr_key_part+key_parts; for ( ; curr_key_part < curr_key_part_end; curr_key_part++) { if (curr_key_part->fieldnr == first_key_part[j].fieldnr) break; } if (curr_key_part == curr_key_part_end) { *key_part++= first_key_part[j]; *rec_per_key++= 0; keyinfo->ext_key_parts++; keyinfo->ext_key_part_map|= 1 << j; } } if (j == first_key_parts) keyinfo->ext_key_flags= keyinfo->flags | HA_EXT_NOSAME; hash key_info does not have HA_NOSAME flag so, its keyinfo->ext_key_parts is added. But we do not want this. Anyway removed this in new version. Now HA_UNIQUE_HASH key also have HA_NOSAME flag. >> } >> if (primary_key < MAX_KEY && >> (share->keys_in_use.is_set(primary_key))) >> @@ -7808,3 +7842,193 @@ double KEY::actual_rec_per_key(uint i) >> return (is_statistics_from_stat_tables ? >> read_stats->get_avg_frequency(i) : (double) rec_per_key[i]); >> } >> + >> +/* >> + find out that whether field name exists in hash_str >> + return index of hash_str if found other wise returns >> + -1 >> +*/ >> +int find_field_name_in_hash(char * hash_str, const char * field_name, >> + int hash_str_length) > ok, all these manipulations with the expression *string* > should be removed. Column names might contain commas, > column names might contain backticks - you don't handle that. > And you should not, really, don't use vcol_info->expr_str, use > vcol_info->expr_item instead. > Removed. Now I use expr_item. >> +{ >> + >> + int j= 0, i= 0; >> + for (i= 0; i < hash_str_length; i++) >> + { >> + while (*(hash_str+i) == *(field_name+j)) >> + { >> + i++; >> + j++; >> + if(*(field_name+j)=='\0' &&*(hash_str+i)=='`') >> + goto done; >> + } >> + j=0; >> + } >> + return -1; >> + done: >> + return i; >> +} >> + >> +/* >> + find out the field positoin in hash_str() >> + position starts from 0 >> + else return -1; >> +*/ >> +int find_field_index_in_hash(LEX_STRING *hash_lex, const char * field_name) >> +{ >> + char *hash_str= hash_lex->str; >> + int hash_str_length= hash_lex->length; >> + int field_name_position= find_field_name_in_hash(hash_str, field_name, hash_str_length); >> + if (field_name_position == -1) >> + return -1; >> + int index= 0; >> + for (int i= 0; i < field_name_position; i++) >> + { >> + if (hash_str[i] == ',') >> + index++; >> + } >> + return index; >> +} >> + >> +/* >> + find total number of field in hash_str >> +*/ >> +int fields_in_hash_str(LEX_STRING * hash_lex) >> +{ >> + int hash_str_length= hash_lex->length; >> + char *hash_str= hash_lex->str; >> + int num_of_fields= 1; >> + for (int i= 0; i > + { >> + if (hash_str[i] == ',' && hash_str[i-1] == '`' >> + && hash_str[i+1] == '`' ) >> + num_of_fields++; >> + } >> + return num_of_fields; >> +} >> + >> +/* >> + return fields ptr given by hash_str index >> + for example >> + hash(`abc`,`xyz`) >> + index 1 will return pointer to xyz field >> +*/ >> +Field * field_ptr_in_hash_str(LEX_STRING * hash_str, TABLE *table, int index) >> +{ >> + char field_name[100]; // 100 is enough i think >> + int temp_index= 0; >> + char *str= hash_str->str; >> + int i= strlen("hash"), j; >> + Field **f, *field; >> + while (i < hash_str->length) >> + { >> + if (str[i] == ',') >> + temp_index++; >> + if (temp_index >= index) >> + break; >> + i++; >> + } >> + i+= 2; // now i point to first character of field name >> + for (j= 0; str[i+j] != '`'; j++) >> + field_name[j]= str[i+j]; >> + field_name[j]= '\0'; >> + for (f= table->field; f && (field= *f); f++) >> + { >> + if (!my_strcasecmp(system_charset_info, field->field_name, field_name)) >> + break; >> + } >> + return field; >> +} >> + >> +/* >> + Remove field name from db_row_hash_* column vcol info str >> + For example >> + >> + hash(`abc`,`xyz`) >> + remove "abc" will return >> + 0 and hash_str will be set hash(`xyz`) and length will be set >> + >> + hash(`xyz`) >> + remove "xyz" will return >> + 0 and hash_str will be set NULL and length will be 0 >> + hash(`xyz`) >> + remove "xyzff" will return >> + 1 no change to hash_str and length >> + TODO a better and less complex logic >> +*/ >> +int rem_field_from_hash_col_str(LEX_STRING * hash_lex, const char * field_name) >> +{ >> + /* first of all find field_name in hash_str*/ >> + char * temp= hash_lex->str; >> + const char * t_field= field_name; >> + int i= find_field_name_in_hash(temp, field_name, hash_lex->length); >> + if ( i != -1) >> + { >> + /* >> + We found the field location >> + First of all we need to find the >> + , position and there can be three >> + situations >> + 1. two , not a problem remove any one >> + 2. one , remove this >> + 3 no , return >> + */ >> + // see if there is , before field name >> + int j= strlen(field_name); >> + if (*(temp + i -j-2) == ',') >> + { >> + hash_lex->length= hash_lex->length- j-2-1;//-2 for two '`' and -1 for ',' >> + memmove(temp+i-j-2, temp+i+1, hash_lex->length); >> + return 0; >> + } >> + if (*(temp+i+1) == ',') >> + { >> + hash_lex->length= hash_lex->length-j-2-1;//-2 for two '`' and -1 for ',' >> + memmove(temp+i-j-1, temp+i+2, hash_lex->length); >> + return 0; >> + } >> + if (*(temp+i+1) == ')') >> + { >> + hash_lex->length= 0; >> + hash_lex->str= NULL; >> + return 0; >> + } >> + } >> + return 1; >> +} >> +/* returns 1 if old_name not found in hash_lex 0 other wise*/ >> +int change_field_from_hash_col_str(LEX_STRING * hash_lex, const char * old_name, >> + char * new_name) >> +{ >> + /* first of all find field_name in hash_lex*/ >> + char * temp= hash_lex->str; >> + const char * t_field= old_name; >> + int i= find_field_name_in_hash(temp, old_name, hash_lex->length); >> + if (i != -1) >> + { >> + int len= hash_lex->length-strlen(old_name) + strlen(new_name); >> + int num= 0; >> + char temp_arr[len]; >> + int s_c_position= i - strlen(old_name);//here it represent the posotion of >> + //'`' before old f_name >> + for (int index= 0; index < len; index++) >> + { >> + if (index >= s_c_position && index < s_c_position+strlen(new_name)) >> + { >> + temp_arr[index]= new_name[index-s_c_position]; >> + continue; >> + } >> + if (index >= s_c_position+strlen(new_name)) >> + { >> + temp_arr[index]= temp[i+num]; >> + num++; >> + continue; >> + } >> + temp_arr[index]= temp[index]; >> + } >> + strcpy(hash_lex->str, temp_arr); >> + hash_lex->length= len; >> + return 0; >> + } >> + return 1; >> +} >> diff --git a/sql/sql_select.cc b/sql/sql_select.cc >> index 5cc7798..921cf18 100644 >> --- a/sql/sql_select.cc >> +++ b/sql/sql_select.cc > this is impressive :) > but to send you something sooner, I'm going to skip your optimizer > changes now, I'll send the review of the original project (long UNIQUE > constraint) first, then I'll finish the review of the optimizer part. > >> diff --git a/sql/sql_table.cc b/sql/sql_table.cc >> index e745fe8..ed8aa8f 100644 >> --- a/sql/sql_table.cc >> +++ b/sql/sql_table.cc >> @@ -3186,6 +3186,177 @@ static void check_duplicate_key(THD *thd, >> } >> } >> >> +/* >> + Add hidden level 3 hash field to table in case of long >> + unique column >> + Returns 0 on success >> + else 1 >> +*/ >> + >> +int add_hash_field(THD * thd, Alter_info *alter_info, Key *current_key, >> + KEY *current_key_info, KEY *key_info, CHARSET_INFO *cs) > should be declared static > Done. >> +{ >> + int num= 1; >> + List_iterator key_iter(alter_info->key_list); >> + List_iterator key_part_iter(current_key->columns); >> + List_iterator it(alter_info->create_list); >> + Create_field *dup_field, * sql_field; >> + Key_part_spec *temp_colms; >> + >> + Create_field *cf= new (thd->mem_root) Create_field(); >> + cf->flags|= UNSIGNED_FLAG; >> + cf->length= cf->char_length= HA_HASH_FIELD_LENGTH; >> + cf->charset= NULL; >> + cf->decimals= 0; >> + char *temp_name= (char *)thd->alloc(30); >> + strcpy(temp_name, HA_DB_ROW_HASH_STR); >> + char num_holder[10]; //10 is way more but i think it is ok >> + sprintf(num_holder, "%d",num); >> + strcat(temp_name, num_holder); > 1. my_snprintf, not sprintf. for just one number - strtol > 2. "%u" not "%d" > 3. with sprintf, you don't need strcat: > > my_snprintf(temp_name, sizeof(temp_name), "DB_ROW_HASH_%u", num); Okay , Changed. >> + /* >> + Check for collusions >> + */ >> + while ((dup_field= it++)) >> + { >> + if (!my_strcasecmp(system_charset_info, temp_name, dup_field->field_name)) >> + { >> + temp_name[12]= '\0'; //now temp_name='DB_ROW_HASH_' >> + num++; >> + sprintf(num_holder, "%d",num); >> + strcat(temp_name, num_holder); >> + it.rewind(); >> + } >> + } >> + it.rewind(); >> + cf->field_name= temp_name; >> + cf->sql_type= MYSQL_TYPE_LONGLONG; >> + /* hash column should be atmost hidden */ > should be "fully hidden" Changed >> + cf->field_visibility= FULL_HIDDEN; >> + cf->is_long_column_hash= true; >> + /* add the virtual colmn info */ >> + Virtual_column_info *v= new (thd->mem_root) Virtual_column_info(); >> + char * hash_exp= (char *)thd->alloc(1024); >> + char * key_name= (char *)thd->alloc(252); >> + strcpy(hash_exp, HA_HASH_STR_HEAD); >> + temp_colms= key_part_iter++; >> + strcat(hash_exp, temp_colms->field_name.str); >> + strcpy(key_name, temp_colms->field_name.str); >> + strcat(hash_exp, "`"); >> + while ((temp_colms= key_part_iter++)) >> + { >> + while ((sql_field= it++) && >> + my_strcasecmp(system_charset_info, >> + temp_colms->field_name.str, sql_field->field_name)) >> + {} >> + it.rewind(); >> + /* >> + There should be only one key for db_row_hash_* column >> + we need to give user a error when the accidently query >> + like >> + >> + create table t1(abc blob unique, unique(db_row_hash_1)); >> + alter table t2 add column abc blob unique,add unique key(db_row_hash_1); >> + >> + for this we will iterate through the key_list and >> + find if and key_part has the same name as of temp_name >> + */ >> + if (!sql_field || sql_field->is_long_column_hash) >> + { >> + my_error(ER_KEY_COLUMN_DOES_NOT_EXITS, MYF(0), temp_name); >> + return 1; >> + } > hmm, are you sure this check is needed? > you've just added a column, there can be no existing key that > refers to it, can it? > > Or, may be, you added a column before the code that checks whether a key is > valid? In that case, that code will still fail with > ER_KEY_COLUMN_DOES_NOT_EXITS, because your column is fully hidden. > > Either way, your check looks redundant. Removed this whole part. >> + /* >> + This test for wrong query like >> + create table t1(a blob ,unique(a,a)); >> + */ >> + if (find_field_name_in_hash(hash_exp, >> + temp_colms->field_name.str, strlen(hash_exp))!=-1) >> + { >> + my_error(ER_DUP_FIELDNAME, MYF(0), temp_colms->field_name.str); >> + return 1; >> + } >> + /* If any field can be null add flag */ >> + if (!sql_field->flags & NOT_NULL_FLAG) >> + current_key_info->flags|= HA_NULL_PART_KEY; >> + strcat(hash_exp, (const char * )","); >> + strcat(key_name, "_"); >> + strcat(hash_exp, "`"); >> + strcat(hash_exp, temp_colms->field_name.str); >> + strcat(key_name, temp_colms->field_name.str); >> + strcat(hash_exp, "`"); > 1. hash_exp is generated incorrectly, you forgot that a column > name itself can contain backticks. There are quoting functions > in sql_show.cc and as my_snprintf("%`s") Changed. > 2. do you really need to create a true virtual column here, with the > hash expression and store it in the frm? you can store the key as a > normal key (with actual blobs, not uint for the hash value), > and generate the vcol in init_from_binary_frm_image(). This is a big change. Took me 3-4 days , But anyway done. >> + } >> + strcat(hash_exp, (const char * )")"); >> + v->expr_str.str= hash_exp; >> + v->expr_str.length= strlen(hash_exp); >> + v->expr_item= NULL; >> + v->set_stored_in_db_flag(true); >> + cf->vcol_info= v; >> + cf->charset= cs; >> + cf->create_length_to_internal_length(); >> + cf->length= cf->char_length= cf->pack_length; >> + prepare_create_field(cf, NULL, 0); >> + if (!current_key_info->flags & HA_NULL_PART_KEY) >> + { >> + cf->pack_flag^= FIELDFLAG_MAYBE_NULL; >> + cf->flags^= NOT_NULL_FLAG; >> + } >> + alter_info->create_list.push_front(cf,thd->mem_root); >> + /* Update row offset because field is added in first position */ >> + int offset=0; >> + it.rewind(); >> + while ((dup_field= it++)) >> + { >> + dup_field->offset= offset; >> + if (dup_field->stored_in_db()) >> + offset+= dup_field->pack_length; >> + } >> + it.rewind(); >> + while ((dup_field= it++)) >> + { >> + if (!dup_field->stored_in_db()) >> + { >> + dup_field->offset= offset; >> + offset+= dup_field->pack_length; >> + } >> + } >> + if(current_key->name.length==0) >> + { >> + current_key_info->name= key_name; >> + current_key_info->name_length= strlen(key_name); >> + key_name= make_unique_key_name(thd, key_name, >> + key_info, current_key_info); >> + } >> + else >> + current_key_info->name= current_key->name.str; >> + if (check_if_keyname_exists(current_key_info->name, key_info, >> + current_key_info)) >> + { >> + my_error(ER_DUP_KEYNAME, MYF(0), key_name); >> + return 1; >> + } >> + current_key->type= Key::MULTIPLE; >> + current_key_info->key_length= cf->pack_length; //length of mysql long column >> + current_key_info->user_defined_key_parts= 1; >> + current_key_info->flags= 0; >> + current_key_info->key_part->fieldnr= 0; >> + current_key_info->key_part->offset= 0; >> + current_key_info->key_part->key_type= cf->pack_flag; >> + current_key_info->key_part->length= cf->pack_length; >> + /* As key is added in front so update update keyinfo field ref and offset*/ >> + KEY * t_key = key_info; >> + KEY_PART_INFO *t_key_part; >> + while (t_key != current_key_info) >> + { >> + t_key_part= t_key->key_part; >> + for (int i= 0; i < t_key->user_defined_key_parts; i++,t_key_part++) >> + { >> + t_key_part->fieldnr+= 1; >> + t_key_part->offset+= cf->pack_length; >> + } >> + t_key++; >> + } >> + return 0; >> +} >> >> /* >> Preparation for table creation >> @@ -3283,7 +3454,13 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, >> /* Fix for prepare statement */ >> thd->change_item_tree(&sql_field->default_value->expr_item, item); >> } >> - >> + if (sql_field->field_visibility == USER_DEFINED_HIDDEN && >> + sql_field->flags & NOT_NULL_FLAG && >> + sql_field->flags & NO_DEFAULT_VALUE_FLAG) >> + { >> + my_error(ER_HIDDEN_NOT_NULL_WOUT_DEFAULT, MYF(0), sql_field->field_name); > say "WITHOUT", this "WOUT" looks weird Changed, I thought short form will work. >> + DBUG_RETURN(TRUE); >> + } >> if (sql_field->sql_type == MYSQL_TYPE_SET || >> sql_field->sql_type == MYSQL_TYPE_ENUM) >> { >> @@ -3884,10 +4070,24 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, >> if (f_is_geom(sql_field->pack_flag) && sql_field->geom_type == >> Field::GEOM_POINT) >> column->length= MAX_LEN_GEOM_POINT_FIELD; >> - if (!column->length) >> - { >> - my_error(ER_BLOB_KEY_WITHOUT_LENGTH, MYF(0), column->field_name.str); >> - DBUG_RETURN(TRUE); >> + if (!column->length) >> + { >> + if (key->type == Key::PRIMARY) >> + { //todo change error message > agree, ER_TOO_LONG_KEY would be better here Changed >> + my_error(ER_BLOB_KEY_WITHOUT_LENGTH, MYF(0), column->field_name.str); >> + DBUG_RETURN(TRUE); >> + } >> + if (!add_hash_field(thd, alter_info, key, key_info, >> + *key_info_buffer, create_info->default_table_charset)) >> + { >> + key_part_info= key_info->key_part; >> + key_part_info++; >> + null_fields++; >> + key_length= HA_HASH_KEY_LENGTH_WITHOUT_NULL; >> + break; >> + } >> + else >> + DBUG_RETURN(TRUE); >> } >> } >> #ifdef HAVE_SPATIAL >> @@ -3974,9 +4174,9 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, >> } >> else >> { >> - my_error(ER_TOO_LONG_KEY, MYF(0), key_part_length); >> - DBUG_RETURN(TRUE); >> - } >> + my_error(ER_TOO_LONG_KEY, MYF(0), key_part_length); >> + DBUG_RETURN(TRUE); > why don't you call add_hash_field() here? > if this place is now impossible, add a DBUG_ASSERT(0) there or remove the > if() completely and replace it with an assert. I mean: > > if (condition) > { > something; > } > else > { > something else; > } > > becomes > > DBUG_ASSERT(condition); > something; > >> + } >> } >> } >> // Catch invalid use of partial keys >> @@ -4021,8 +4221,23 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, >> } >> else >> { >> - my_error(ER_TOO_LONG_KEY, MYF(0), key_part_length); >> - DBUG_RETURN(TRUE); >> + if(key->type != Key::UNIQUE) >> + { >> + my_error(ER_TOO_LONG_KEY, MYF(0), key_part_length); >> + DBUG_RETURN(TRUE); >> + } >> + //todo we does not respect length given by user in calculating hash > oh. that's a bug. good that you have a comment about it, > there're more urgent issues that this one, but it should be fixed eventually //TODO >> + if(!add_hash_field(thd, alter_info, key, key_info, >> + *key_info_buffer, create_info->default_table_charset)) >> + { >> + key_part_info= key_info->key_part; >> + key_part_info++; >> + null_fields++; >> + key_length= HA_HASH_KEY_LENGTH_WITHOUT_NULL; >> + break; >> + } >> + else >> + DBUG_RETURN(TRUE); >> } >> } >> key_part_info->length= (uint16) key_part_length; >> @@ -7502,6 +7717,8 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, >> */ >> for (f_ptr=table->field ; (field= *f_ptr) ; f_ptr++) >> { >> + if (field->field_visibility == FULL_HIDDEN) >> + continue; > ok, so you recreate DB_ROW_HASH_xxx columns every time Yes, BTW I changed this If condition to this one if (field->is_long_unique_hash) continue; >> Alter_drop *drop; >> if (field->type() == MYSQL_TYPE_VARCHAR) >> create_info->varchar= TRUE; >> @@ -7818,7 +8057,7 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, >> >> if (key_info->flags & HA_SPATIAL) >> key_type= Key::SPATIAL; >> - else if (key_info->flags & HA_NOSAME) >> + else if (key_info->flags & HA_NOSAME || key_info->flags & HA_UNIQUE_HASH) >> { >> if (! my_strcasecmp(system_charset_info, key_name, primary_key_name)) >> key_type= Key::PRIMARY; > huh? I thought your HA_UNIQUE_HASH indexes cannot be Key::PRIMARY Sorry , I did not see this. > Regards, > Sergei > Chief Architect MariaDB > andsecurity@mariadb.org
Hi Sergei!
This code is about adding new long unique key, This is a section of
code from mysql_prepare_create_table, The main problem is can we make
this code more shorter ? And the reason for this code is that we need
to add
Alter_info::ALTER_ADD_CHECK_CONSTRAINT , only if there is unique key
on long columns
Query statements can be like this
alter table t1 add unique key a; // here a is blob
or
alter table t1 add b blob unique;
alter table t1 add c varchar(1000) unique;
This is code
{
Key *key;
while ((key=key_it++)) // Add new keys
{
if (key->type == Key::FOREIGN_KEY &&
((Foreign_key *)key)->validate(new_create_list))
goto err;
from here
==> if (key->type == Key::UNIQUE)
{
List_iterator_fast
Hi Sergei!
On 08/24/2016 11:05 PM, Sergei Golubchik wrote:
Hi, Sachin!
On Aug 13, Sachin Setia wrote:
Hello Sergei! Please review commit 71f9069 onward i have changed mysql_prepare_alter_table func.
Okay, here it is. Up to the 03e29c6 (this is one after 71f9069).
Short summary - this all looks pretty good. There're issues, but as a whole - great work!
diff --git a/include/my_base.h b/include/my_base.h index 1317639..d03ca0f 100644 --- a/include/my_base.h +++ b/include/my_base.h @@ -241,6 +241,19 @@ enum ha_base_keytype { HA_KEYTYPE_BIT=19 };
+/* Add some constant related to unique long hash column like length hash string etc*/ + +#define HA_HASH_KEY_LENGTH_WITHOUT_NULL 8 +#define HA_HASH_FIELD_LENGTH 8 +#define HA_HASH_KEY_LENGTH_WITH_NULL 9 +#define HA_HASH_STR_HEAD "hash(`" //used in mysql_prepare_create_table +#define HA_HASH_STR_HEAD_LEN strlen(HA_HASH_STR_HEAD_LEN) +#define HA_HASH_STR "hash" +#define HA_HASH_STR_LEN strlen(HA_HASH_STR) +#define HA_HASH_STR_INDEX "HASH_INDEX" +#define HA_HASH_STR_INDEX_LEN strlen(HA_HASH_STR_INDEX) +#define HA_DB_ROW_HASH_STR "DB_ROW_HASH_"
no need to put all these constants into the very global my_base.h. better to define them in sql_show.cc or sql_table.cc (depending on where they're used)
Actually first three are needed in files like opt_range.cc. I moved this to table.h
+ #define HA_MAX_KEYTYPE 31 /* Must be log2-1 */
/* diff --git a/mysql-test/r/features.result b/mysql-test/r/features.result index 52650d1..e050efb 100644 --- a/mysql-test/r/features.result +++ b/mysql-test/r/features.result @@ -7,6 +7,7 @@ Feature_delay_key_write 0 Feature_dynamic_columns 0 Feature_fulltext 0 Feature_gis 0 +Feature_hidden_column 0
Great! Please, add also a test where it's not 0. I mean, in your hidden_field.test you can add
FLUSH STATUS;
at the beginning of the file and SHOW STATUS LIKE 'Feature_hidden_column'; somewhere later. This will show that Feature_hidden_column is incremented accordingly.
Done.
Feature_locale 0 Feature_subquery 0 Feature_timezone 0 diff --git a/mysql-test/r/hidden_field.result b/mysql-test/r/hidden_field.result new file mode 100644 index 0000000..09a2c21 --- /dev/null +++ b/mysql-test/r/hidden_field.result @@ -0,0 +1,367 @@ +create table h_1(abc int primary key, xyz int hidden); +desc h_1; +Field Type Null Key Default Extra +abc int(11) NO PRI NULL +xyz int(11) YES NULL HIDDEN +show create table h_1; +Table Create Table +h_1 CREATE TABLE `h_1` ( + `abc` int(11) NOT NULL, + `xyz` int(11) HIDDEN DEFAULT NULL, + PRIMARY KEY (`abc`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +drop table h_1; +create table h_2(a1 int hidden); +ERROR 42000: A table must have at least 1 column +create table h_3(a1 blob,hidden(a1)); +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'hidden(a1))' at line 1 +create table h_4(a1 int primary key hidden ,a2 int unique hidden , a3 blob,a4 +int not null hidden unique); +ERROR HY000: Hidden column 'a1' either allow null values or it must have default value +create table h_5(abc int not null hidden); +ERROR HY000: Hidden column 'abc' either allow null values or it must have default value +create table t1(a int hidden, b int); +insert into t1 values(1); +insert into t1(a) values(1); +insert into t1(b) values(1);
better insert 1,2,3 not 1,1,1 so that in SELECT you could unambigously see what INSERT has added what row
Changed.
+insert into t1(a,b) values(5,5); +select * from t1; +b +1 +NULL +1 +5 +select a,b from t1; +a b +NULL 1 +1 NULL +NULL 1 +5 5 +delete from t1; +insert into t1 values(1),(2),(3),(4); +select * from t1; +b +1 +2 +3 +4 +select a from t1; +a +NULL +NULL +NULL +NULL +drop table t1; +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +desc t1; +Field Type Null Key Default Extra +a int(11) YES NULL +b int(11) YES NULL HIDDEN +c int(11) NO PRI NULL auto_increment , HIDDEN
why a space before the comma?
Okay Reverted.
+d blob YES NULL +e int(11) YES UNI NULL +f int(11) YES NULL +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +select * from t1; +a d e f +1 d blob 1 1 +1 d blob 11 1 +1 d blob 2 1 +1 d blob 3 1 +1 d blob 41 1 +drop table t1; +create table sdsdsd(a int , b int, hidden(a,b)); +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'hidden(a,b))' at line 1 +create table t1(a int,abc int as (a mod 3) virtual hidden); +desc t1; +Field Type Null Key Default Extra +a int(11) YES NULL +abc int(11) YES NULL VIRTUAL , HIDDEN +insert into t1 values(1,default); +ERROR 21S01: Column count doesn't match value count at row 1 +insert into t1 values(1),(22),(233); +select * from t1; +a +1 +22 +233 +select a,abc from t1; +a abc +1 1 +22 1 +233 2 +drop table t1; +create table t1(abc int primary key hidden auto_increment, a int); +desc t1; +Field Type Null Key Default Extra +abc int(11) NO PRI NULL auto_increment , HIDDEN +a int(11) YES NULL +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `abc` int(11) NOT NULL HIDDEN AUTO_INCREMENT, + `a` int(11) DEFAULT NULL, + PRIMARY KEY (`abc`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +insert into t1 values(1); +insert into t1 values(2); +insert into t1 values(3); +select * from t1; +a +1 +2 +3 +select abc,a from t1; +abc a +1 1 +2 2 +3 3 +delete from t1; +insert into t1 values(1),(2),(3),(4),(6); +select abc,a from t1; +abc a +4 1 +5 2 +6 3 +7 4 +8 6 +drop table t1; +create table t1(abc int); +alter table t1 change abc ss int hidden; +ERROR 42000: A table must have at least 1 column +alter table t1 add column xyz int; +alter table t1 modify column abc int ; +desc t1; +Field Type Null Key Default Extra +abc int(11) YES NULL +xyz int(11) YES NULL +insert into t1 values(22); +ERROR 21S01: Column count doesn't match value count at row 1 +alter table t1 modify column abc int hidden;
please, add also tests for making hidden fields visible again. I think that
alter table t1 modify column abc int;
will do the job
Okay, Added.
+desc t1; +Field Type Null Key Default Extra +abc int(11) YES NULL HIDDEN +xyz int(11) YES NULL +insert into t1 values(12); +drop table t1; +some test on copy table structure with table data; +table with hidden fields and unique keys; +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +desc t1; +Field Type Null Key Default Extra +a int(11) YES NULL +b int(11) YES NULL HIDDEN +c int(11) NO PRI NULL auto_increment , HIDDEN +d blob YES NULL +e int(11) YES UNI NULL +f int(11) YES NULL +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +select * from t1; +a d e f +1 d blob 1 1 +1 d blob 11 1 +1 d blob 2 1 +1 d blob 3 1 +1 d blob 41 1 +select a,b,c,d,e,f from t1; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +this wont copy hidden fields and keys; +create table t2 as select * from t1; +desc t2; +Field Type Null Key Default Extra +a int(11) YES NULL +d blob YES NULL +e int(11) YES NULL +f int(11) YES NULL +select * from t2; +a d e f +1 d blob 1 1 +1 d blob 11 1 +1 d blob 2 1 +1 d blob 3 1 +1 d blob 41 1 +select a,b,c,d,e,f from t2; +ERROR 42S22: Unknown column 'b' in 'field list' +drop table t2; +now this will copy hidden fields +create table t2 as select a,b,c,d,e,f from t1; +desc t2; +Field Type Null Key Default Extra +a int(11) YES NULL +b int(11) YES NULL HIDDEN +c int(11) NO 0 HIDDEN +d blob YES NULL +e int(11) YES NULL +f int(11) YES NULL +select * from t2; +a d e f +1 d blob 1 1 +1 d blob 11 1 +1 d blob 2 1 +1 d blob 3 1 +1 d blob 41 1 +select a,b,c,d,e,f from t2; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +drop table t2,t1; +some test related to copy of data from one table to another; +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +select a,b,c,d,e,f from t1; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +create table t2(a int , b int hidden , c int hidden , d blob , e int unique, f int); +insert into t2 select * from t1; +select a,b,c,d,e,f from t2; +a b c d e f +1 NULL NULL d blob 1 1 +1 NULL NULL d blob 11 1 +1 NULL NULL d blob 2 1 +1 NULL NULL d blob 3 1 +1 NULL NULL d blob 41 1 +truncate t2; +insert into t2 (a,b,c,d,e,f) select a,b,c,d,e,f from t1; +select a,b,c,d,e,f from t2; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +truncate t2; +drop table t1,t2; +some test related to creating view on table with hidden column; +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +create view v as select * from t1; +desc v; +Field Type Null Key Default Extra +a int(11) YES NULL +d blob YES NULL +e int(11) YES NULL +f int(11) YES NULL +select * from v; +a d e f +1 d blob 1 1 +1 d blob 11 1 +1 d blob 2 1 +1 d blob 3 1 +1 d blob 41 1 +v does not have hidden column; +select a,b,c,d,e,f from v; +ERROR 42S22: Unknown column 'b' in 'field list' +insert into v values(1,21,32,4); +select * from v; +a d e f +1 d blob 1 1 +1 d blob 11 1 +1 d blob 2 1 +1 d blob 3 1 +1 d blob 41 1 +1 21 32 4 +insert into v(a,b,c,d,e,f) values(1,12,3,4,5,6); +ERROR 42S22: Unknown column 'b' in 'field list' +drop view v; +create view v as select a,b,c,d,e,f from t1; +desc v; +Field Type Null Key Default Extra +a int(11) YES NULL +b int(11) YES NULL HIDDEN +c int(11) NO 0 HIDDEN +d blob YES NULL +e int(11) YES NULL +f int(11) YES NULL +select * from v; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +1 NULL 6 21 32 4 +v does have hidden column; +select a,b,c,d,e,f from v; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +1 NULL 6 21 32 4 +insert into v values(1,26,33,4,45,66); +select a,b,c,d,e,f from v; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +1 NULL 6 21 32 4 +1 26 33 4 45 66 +insert into v(a,b,c,d,e,f) values(1,32,31,41,5,6); +select a,b,c,d,e,f from v; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +1 NULL 6 21 32 4 +1 26 33 4 45 66 +1 32 31 41 5 6 +drop view v; +drop table t1; +now hidden column in where and some join query i think no use of this test but anyway; +create table t1 (a int unique , b int hidden unique, c int unique hidden); +insert into t1(a,b,c) values(1,1,1); +insert into t1(a,b,c) values(2,2,2); +insert into t1(a,b,c) values(3,3,3); +insert into t1(a,b,c) values(4,4,4); +insert into t1(a,b,c) values(21,21,26); +insert into t1(a,b,c) values(31,31,35); +insert into t1(a,b,c) values(41,41,45); +insert into t1(a,b,c) values(22,22,24); +insert into t1(a,b,c) values(32,32,33); +insert into t1(a,b,c) values(42,42,43); +explain select * from t1 where b=3; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const b b 5 const 1 +select * from t1 where b=3; +a +3 +explain select * from t1 where c=3; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const c c 5 const 1 +select * from t1 where c=3; +a +3 +create table t2 as select a,b,c from t1; +desc t2; +Field Type Null Key Default Extra +a int(11) YES NULL +b int(11) YES NULL HIDDEN +c int(11) YES NULL HIDDEN +explain select * from t1,t2 where t1.b = t2.c and t1.c = t2.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t2 ALL NULL NULL NULL NULL 10 +1 SIMPLE t1 ALL b,c NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +select * from t1,t2 where t1.b = t2.c and t1.c = t2.b; +a a +1 1 +2 2 +3 3 +4 4 +drop table t1,t2; diff --git a/mysql-test/r/long_unique_where.result b/mysql-test/r/long_unique_where.result new file mode 100644 index 0000000..e9bd416 --- /dev/null +++ b/mysql-test/r/long_unique_where.result @@ -0,0 +1,340 @@ +create table t1(abc blob unique); +insert into t1 values(1),(2),(3),(4),(5),(11),(12),(31),(14),(15),(NULL) +,(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL), +(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL), +(NULL),(NULL),(NULL),(NULL),(NULL); +insert into t1 value(1); +ERROR 23000: Duplicate entry '1' for key 'abc' +explain select * from t1 where abc=31; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc=31; +abc +31 +# in case of null we do not use any optimization +explain select * from t1 where abc is NULL; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 36 Using where +select * from t1 where abc is NULL limit 1; +abc +NULL +#range query
please clarify it here, for example, like
#range query (index not used, because it's a hash)
Copied , :).
+explain select * from t1 where abc >1 limit 1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 36 Using where +select * from t1 where abc >1 limit 1; +abc +2 +explain select * from t1 where abc >1 and abc <4; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 36 Using where +select * from t1 where abc >1 and abc <4; +abc +2 +3 +explain select * from t1 where abc =15 or abc <4 ; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 36 Using where +select * from t1 where abc =15 or abc <4 ; +abc +1 +2 +3 +15 +drop table t1; +create table t1(abc blob unique, xyz int ); +insert into t1 values(1,1),(2,1),(3,3),(4,1),(5,6),(NULL,3),(NULL,1), +(NULL,NULL),(11,11),(12,11),(31,31), +(14,1),(15,61),(NULL,32),(NULL,12),(NULL,NULL); +insert into t1 value(1,NULL); +ERROR 23000: Duplicate entry '1' for key 'abc' +explain select * from t1 where abc=15; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc= 15; +abc xyz +15 61 +explain select * from t1 where abc=15 and xyz =61; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc= 15 and 61;
type in the where clause
Changed.
+abc xyz +15 61 +# now xyz has different value
what do you mean by that?
echo # now xyz has a value which is not present in table; Added.
+explain select * from t1 where abc=1000; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where abc= 1000; +abc xyz +explain select * from t1 where abc=14 and xyz =56; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where abc=14 and xyz =56; +abc xyz +#range query +explain select * from t1 where abc >5 limit 1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 16 Using where +select * from t1 where abc >5 limit 1; +abc xyz +11 11 +explain select * from t1 where abc=5 and xyz <56; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc=5 and xyz <56; +abc xyz +5 6 +explain select * from t1 where abc>=5 and xyz <56; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 16 Using where +select * from t1 where abc>=5 and xyz <56; +abc xyz +5 6 +11 11 +12 11 +31 31 +14 1 +explain select * from t1 where abc>5 and xyz =56; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 16 Using where +select * from t1 where abc>5 and xyz =56; +abc xyz +drop table t1; +create table t1(abc blob unique, xyz blob unique ); +insert into t1 values(1,1),(2,11),(3,31),(4,12),(5,63),(NULL,2),(NULL,NULL), +(91,19),(92,119),(93,391),(94,192),(95,693); +insert into t1 value(1,NULL); +ERROR 23000: Duplicate entry '1' for key 'abc' +explain select * from t1 where abc=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc=1; +abc xyz +1 1 +explain select * from t1 where xyz=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const xyz xyz 9 const 1 +select * from t1 where xyz=1; +abc xyz +1 1 +explain select * from t1 where abc=5 and xyz=63; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc=5 and xyz=63; +abc xyz +5 63 +explain select * from t1 where xyz=63 and abc=5; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where xyz=63 and abc=5; +abc xyz +5 63 +explain select * from t1 where xyz=63 or abc=5; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where xyz=63 or abc=5; +abc xyz +5 63 +# now the first one does not exist +explain select * from t1 where abc=51 and xyz=63; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where abc=51 and xyz=63; +abc xyz +# now the second one does not exist +explain select * from t1 where abc=5 and xyz=613; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where abc=5 and xyz=613; +abc xyz +explain select * from t1 where abc is NULL; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where abc is NULL; +abc xyz +NULL 2 +NULL NULL +explain select * from t1 where abc is NULL and xyz=2; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const xyz xyz 9 const 1 +select * from t1 where abc is NULL and xyz=2; +abc xyz +NULL 2 +#range conditions +explain select * from t1 where abc>11 limit 5; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where abc>11 limit 5; +abc xyz +91 19 +92 119 +93 391 +94 192 +95 693 +explain select * from t1 where xyz<11; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where xyz<11; +abc xyz +1 1 +NULL 2 +explain select * from t1 where abc>=51 and xyz<=63; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where abc>=51 and xyz<=63; +abc xyz +91 19 +explain select * from t1 where abc>5 and xyz<613; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where abc>5 and xyz<613; +abc xyz +91 19 +92 119 +93 391 +94 192 +explain select * from t1 where abc=5 and xyz>1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc=5 and xyz>1; +abc xyz +5 63 +explain select * from t1 where abc<55 and xyz=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const xyz xyz 9 const 1 +select * from t1 where abc<55 and xyz=1; +abc xyz +1 1 +explain select * from t1 where abc<=55 or xyz>=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where abc<=55 and xyz>=1; +abc xyz +1 1 +2 11 +3 31 +4 12 +5 63 +drop table t1; +#now the unique (a,b,c..........) +#let us do more hard test by using unique(a,b,c,d) key first +create table t1 (a blob , b blob , c blob , d blob ,unique(a,b,c,d), +unique(a,b,c) ,unique (b,c,d));
hmm, better do not use redundant keys. it works now, but tenchnically we can implement the optimization where the server will internally remove "unique(a,b,c,d)" - will store it in the frm, but won't tell the engine about it - because unique(a,b,c) guarantees that (a,b,c,d) is *always* unique.
so, if we add this optimization someday your test case will no longer test what it was supposed to.
Okay , Changed.
+show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` blob DEFAULT NULL, + `c` blob DEFAULT NULL, + `d` blob DEFAULT NULL, + UNIQUE KEY `a_b_c_d`(`a`,`b`,`c`,`d`), + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), + UNIQUE KEY `b_c_d`(`b`,`c`,`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +insert into t1 values(1,1,1,1),(2,1,2,1),(1,3,3,1),(4,1,4,1),(1,5,1,5), +(6,1,6,1),(1,7,1,7),(8,1,1,8),(1,9,9,1),(2,2,2,2),(4,4,4,4),(5,5,5,5),(6,6,6,6), +(126,216,603,640),(603,460,660,706),(806,609,609,605),(62,62,22,33),(64,65,66,76), +(16,26,63,64),(63,46,66,76),(86,69,69,65),(622,622,622,633),(644,655,666,776); +select * from t1 limit 3; +a b c d +1 1 1 1 +2 1 2 1 +1 3 3 1 +#simple where +#key (a,b,c) +explain select * from t1 where a=1 and b=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const a_b_c a_b_c 9 const 1 +select * from t1 where a=1 and b=1 and c=1; +a b c d +1 1 1 1 +explain select * from t1 where a=1 and b=4444 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where a=1 and b=4444 and c=1; +a b c d +#incomplete key +explain select * from t1 where a=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where a=1 and c=1; +a b c d +1 1 1 1 +1 5 1 5 +1 7 1 7 +explain select * from t1 where a=1 and b=4444 ; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where a=1 and b=4444 ; +a b c d +explain select * from t1 where b=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where b=1 and c=1; +a b c d +1 1 1 1 +8 1 1 8 +#key (b,c,d) +explain select * from t1 where d=1 and b=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const b_c_d b_c_d 9 const 1 +select * from t1 where d=1 and b=1 and c=1; +a b c d +1 1 1 1 +explain select * from t1 where d=1 and b=4444 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where d=1 and b=4444 and c=1; +a b c d +#incomplete key +explain select * from t1 where d=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where d=1 and c=1; +a b c d +1 1 1 1 +explain select * from t1 where d=1 and b=4444 ; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where d=1 and b=4444 ; +a b c d +explain select * from t1 where b=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where b=1 and c=1; +a b c d +1 1 1 1 +8 1 1 8 +#key (a,b,c,d) +explain select * from t1 where a=1 and d=1 and b=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const a_b_c_d a_b_c_d 9 const 1 +select * from t1 where a=1 and d=1 and b=1 and c=1; +a b c d +1 1 1 1 +explain select * from t1 where a=1 and d=1 and b=4444 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where a=1 and d=1 and b=4444 and c=1; +a b c d +#incomplete key +explain select * from t1 where a=1 and d=1 and c=1 ; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where a=1 and d=1 and c=1 ; +a b c d +1 1 1 1 +explain select * from t1 where d=1 and b=4444 and a=1 ; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where d=1 and b=4444 and a=1 ; +a b c d +explain select * from t1 where a=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where a=1 and c=1; +a b c d +1 1 1 1 +1 5 1 5 +1 7 1 7 +drop table t1; diff --git a/mysql-test/r/long_uniques.result b/mysql-test/r/long_uniques.result new file mode 100644 index 0000000..e410fc1 --- /dev/null +++ b/mysql-test/r/long_uniques.result @@ -0,0 +1,1163 @@ +#Structure of tests +#First we will check all option for +#table containing single unique column +#table containing keys like unique(a,b,c,d) etc +#then table containing 2 blob unique etc +#table with single long blob column; +create table t1(a blob unique); +insert into t1 values(1),(2),(3),(56),('sachin'),('maria'),(123456789034567891),(null),(null),(123456789034567890); +#table structure; +desc t1; +Field Type Null Key Default Extra +a blob YES UNI NULL +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + UNIQUE KEY `a`(`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1;
for these statements, use "query_vertical" prefix, like
query_vertical show keys from t1;
it works better when the result has only few (best: one) row
Added.
+Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a 1 a A 0 NULL NULL YES HASH_INDEX
here, notice that your index is shown as "non-unique"
Corrected.
+select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION COLUMN_DEFAULT IS_NULLABLE DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME COLUMN_TYPE COLUMN_KEY EXTRA PRIVILEGES COLUMN_COMMENT +def test t1 a 1 NULL YES blob 65535 65535 NULL NULL NULL NULL NULL blob UNI select,insert,update,references +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME NON_UNIQUE INDEX_SCHEMA INDEX_NAME SEQ_IN_INDEX COLUMN_NAME COLLATION CARDINALITY SUB_PART PACKED NULLABLE INDEX_TYPE COMMENT INDEX_COMMENT +def test t1 1 test a 1 a A 0 NULL NULL YES HASH_INDEX +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; +CONSTRAINT_CATALOG CONSTRAINT_SCHEMA CONSTRAINT_NAME TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION POSITION_IN_UNIQUE_CONSTRAINT REFERENCED_TABLE_SCHEMA REFERENCED_TABLE_NAME REFERENCED_COLUMN_NAME +def test a def test t1 a 1 NULL NULL NULL NULL +# table select we should not be able to see db_row_hash_column;
"not able to see db_row_hash_1 column"
Changed, Sorry.
+select * from t1; +a +1 +2 +3 +56 +sachin +maria +123456789034567891 +NULL +NULL +123456789034567890 +select db_row_hash_1 from t1; +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' +#duplicate entry test; +insert into t1 values(2); +ERROR 23000: Duplicate entry '2' for key 'a' +insert into t1 values('sachin'); +ERROR 23000: Duplicate entry 'sachi' for key 'a' +insert into t1 values(123456789034567891); +ERROR 23000: Duplicate entry '12345' for key 'a' +select * from t1; +a +1 +2 +3 +56 +sachin +maria +123456789034567891 +NULL +NULL +123456789034567890 +insert into t1 values(11),(22),(33); +insert into t1 values(12),(22); +ERROR 23000: Duplicate entry '22' for key 'a' +select * from t1; +a +1 +2 +3 +56 +sachin +maria +123456789034567891 +NULL +NULL +123456789034567890 +11 +22 +33 +12 +insert into t1 values(repeat('s',4000*10)),(repeat('s',4001*10)); +insert into t1 values(repeat('m',4000*10)),(repeat('m',4000*10)); +ERROR 23000: Duplicate entry 'mmmmm' for key 'a' +insert into t1 values(repeat('m',4001)),(repeat('m',4002)); +truncate table t1; +insert into t1 values(1),(2),(3),(4),(5),(8),(7); +#now some alter commands; +alter table t1 add column b int; +desc t1; +Field Type Null Key Default Extra +a blob YES UNI NULL +b int(11) YES NULL +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` int(11) DEFAULT NULL, + UNIQUE KEY `a`(`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +insert into t1 values(1,2); +ERROR 23000: Duplicate entry '1' for key 'a' +insert into t1 values(2,2); +ERROR 23000: Duplicate entry '2' for key 'a' +select db_row_hash_1 from t1; +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' +#now try to change db_row_hash_1 column; +alter table t1 drop column db_row_hash_1; +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists +alter table t1 add column d int , add column e int , drop column db_row_hash_1; +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists +alter table t1 modify column db_row_hash_1 int ; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 add column a int , add column b int, modify column db_row_hash_1 int ; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 change column db_row_hash_1 dsds int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 add column asd int, change column db_row_hash_1 dsds int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 drop column b , add column c int; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `c` int(11) DEFAULT NULL, + UNIQUE KEY `a`(`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +#now add some column with name db_row_hash; +alter table t1 add column db_row_hash_1 int unique; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `c` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `a`(`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +insert into t1 values(45,1,55),(46,1,55); +ERROR 23000: Duplicate entry '55' for key 'db_row_hash_1' +alter table t1 add column db_row_hash_2 int, add column db_row_hash_3 int; +desc t1; +Field Type Null Key Default Extra +a blob YES UNI NULL +c int(11) YES NULL +db_row_hash_1 int(11) YES UNI NULL +db_row_hash_2 int(11) YES NULL +db_row_hash_3 int(11) YES NULL +#this should also drop the unique index ; +alter table t1 drop column a; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_3` int(11) DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +#add column with unique index on blob ; +alter table t1 add column a blob unique; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_3` int(11) DEFAULT NULL, + `a` blob DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `a`(`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +# try to change the blob unique column name; +#this will change index to b tree; +alter table t1 modify column a int ; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_3` int(11) DEFAULT NULL, + `a` int(11) DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `a` (`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 a 1 a A NULL NULL NULL YES BTREE +alter table t1 add column clm blob unique; +#try changing the name ; +alter table t1 change column clm clm_changed blob; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_3` int(11) DEFAULT NULL, + `a` int(11) DEFAULT NULL, + `clm_changed` blob DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `a` (`a`), + UNIQUE KEY `clm`(`clm_changed`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 a 1 a A NULL NULL NULL YES BTREE +t1 1 clm 1 clm_changed A 0 NULL NULL YES HASH_INDEX +#now drop the unique key; +alter table t1 drop key clm; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_3` int(11) DEFAULT NULL, + `a` int(11) DEFAULT NULL, + `clm_changed` blob DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `a` (`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 a 1 a A NULL NULL NULL YES BTREE
you can use myisamchk to see *actually created* indexes in MYI file. examples are in myisam.test, but in short, it's something like
let datadir=`select @@datadir`; replace_result $datadir DATADIR; exec $MYISAMCHK -d $datadir/test/t1
the first command needs to be done only once, in the beginning of the file, usually. The other pair you do whenever you want to examine the table, like, where you do "desc t1" or "show keys".
Done.
+drop table t1; +create table t1 (a TEXT CHARSET latin1 COLLATE latin1_german2_ci unique); +desc t1; +Field Type Null Key Default Extra +a text YES UNI NULL +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a 1 a A 0 NULL NULL YES HASH_INDEX +insert into t1 values ('ae'); +insert into t1 values ('AE'); +ERROR 23000: Duplicate entry 'AE' for key 'a' +insert into t1 values ('Ä');
good!
+drop table t1; +#table with multiple long blob column and varchar text column ; +create table t1(a blob unique, b int , c blob unique , d text unique , e varchar(3000) unique); +insert into t1 values(1,2,3,4,5),(2,11,22,33,44),(3111,222,333,444,555),(5611,2222,3333,4444,5555), +('sachin','ff','fdf','gfgfgfg','hghgr'),('maria','db','frter','dasd','utyuty'), +(123456789034567891,3534534534534,53453453453456,64565464564564,45435345345345), +(123456789034567890,435345345345,657567567567,78967657567567,657567567567567676); +Warnings: +Warning 1366 Incorrect integer value: 'ff' for column 'b' at row 5 +Warning 1366 Incorrect integer value: 'db' for column 'b' at row 6 +Warning 1264 Out of range value for column 'b' at row 7 +Warning 1264 Out of range value for column 'b' at row 8
did you really need to insert invalid values in this test?
No, I did not see Warning.
+#table structure; +desc t1; +Field Type Null Key Default Extra +a blob YES UNI NULL +b int(11) YES NULL +c blob YES UNI NULL +d text YES UNI NULL +e varchar(3000) YES UNI NULL +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` int(11) DEFAULT NULL, + `c` blob DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + UNIQUE KEY `a`(`a`), + UNIQUE KEY `c`(`c`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `e`(`e`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 c 1 c A 0 NULL NULL YES HASH_INDEX +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 e 1 e A 0 NULL NULL YES HASH_INDEX +select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION COLUMN_DEFAULT IS_NULLABLE DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME COLUMN_TYPE COLUMN_KEY EXTRA PRIVILEGES COLUMN_COMMENT +def test t1 a 1 NULL YES blob 65535 65535 NULL NULL NULL NULL NULL blob UNI select,insert,update,references +def test t1 b 2 NULL YES int NULL NULL 10 0 NULL NULL NULL int(11) select,insert,update,references +def test t1 c 3 NULL YES blob 65535 65535 NULL NULL NULL NULL NULL blob UNI select,insert,update,references +def test t1 d 4 NULL YES text 65535 65535 NULL NULL NULL latin1 latin1_swedish_ci text UNI select,insert,update,references +def test t1 e 5 NULL YES varchar 3000 3000 NULL NULL NULL latin1 latin1_swedish_ci varchar(3000) UNI select,insert,update,references +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME NON_UNIQUE INDEX_SCHEMA INDEX_NAME SEQ_IN_INDEX COLUMN_NAME COLLATION CARDINALITY SUB_PART PACKED NULLABLE INDEX_TYPE COMMENT INDEX_COMMENT +def test t1 1 test a 1 a A 0 NULL NULL YES HASH_INDEX +def test t1 1 test c 1 c A 0 NULL NULL YES HASH_INDEX +def test t1 1 test d 1 d A 0 NULL NULL YES HASH_INDEX +def test t1 1 test e 1 e A 0 NULL NULL YES HASH_INDEX +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; +CONSTRAINT_CATALOG CONSTRAINT_SCHEMA CONSTRAINT_NAME TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION POSITION_IN_UNIQUE_CONSTRAINT REFERENCED_TABLE_SCHEMA REFERENCED_TABLE_NAME REFERENCED_COLUMN_NAME +def test a def test t1 a 1 NULL NULL NULL NULL +def test c def test t1 c 1 NULL NULL NULL NULL +def test d def test t1 d 1 NULL NULL NULL NULL +def test e def test t1 e 1 NULL NULL NULL NULL +#table select we should not be able to see db_row_hash_column; +select * from t1; +a b c d e +1 2 3 4 5 +2 11 22 33 44 +3111 222 333 444 555 +5611 2222 3333 4444 5555 +sachin 0 fdf gfgfgfg hghgr +maria 0 frter dasd utyuty +123456789034567891 2147483647 53453453453456 64565464564564 45435345345345 +123456789034567890 2147483647 657567567567 78967657567567 657567567567567676 +select db_row_hash_1 from t1; +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' +select db_row_hash_2 from t1; +ERROR 42S22: Unknown column 'db_row_hash_2' in 'field list' +select db_row_hash_3 from t1; +ERROR 42S22: Unknown column 'db_row_hash_3' in 'field list' +#duplicate entry test; +insert into t1 values(21,2,3,42,51); +ERROR 23000: Duplicate entry '3' for key 'c' +insert into t1 values('sachin',null,null,null,null); +ERROR 23000: Duplicate entry 'sachi' for key 'a' +insert into t1 values(1234567890345671890,4353453453451,6575675675617,789676575675617,657567567567567676); +ERROR 23000: Duplicate entry '65756' for key 'e' +select * from t1; +a b c d e +1 2 3 4 5 +2 11 22 33 44 +3111 222 333 444 555 +5611 2222 3333 4444 5555 +sachin 0 fdf gfgfgfg hghgr +maria 0 frter dasd utyuty +123456789034567891 2147483647 53453453453456 64565464564564 45435345345345 +123456789034567890 2147483647 657567567567 78967657567567 657567567567567676 +insert into t1 values(repeat('s',4000*10),100,repeat('s',4000*10),repeat('s',4000*10), +repeat('s',400)),(repeat('s',4001*10),1000,repeat('s',4001*10),repeat('s',4001*10), +repeat('s',401)); +insert into t1 values(repeat('m',4000*11),10,repeat('s',4000*11),repeat('s',4000*11),repeat('s',400)); +ERROR 23000: Duplicate entry 'sssss' for key 'e'
400 characters (that you insert into 'e') - that looks a bit too short for varchar(3000). Why wouldn't you insert, say, 2990 characters? 400 is something that even b-tree can handle, I suspect.
Changed.
+truncate table t1; +insert into t1 values(1,2,3,4,5),(2,11,22,33,44),(3111,222,333,444,555),(5611,2222,3333,4444,5555); +#now some alter commands; +alter table t1 add column f int; +desc t1; +Field Type Null Key Default Extra +a blob YES UNI NULL +b int(11) YES NULL +c blob YES UNI NULL +d text YES UNI NULL +e varchar(3000) YES UNI NULL +f int(11) YES NULL +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` int(11) DEFAULT NULL, + `c` blob DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + UNIQUE KEY `a`(`a`), + UNIQUE KEY `c`(`c`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `e`(`e`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +#unique key should not break; +insert into t1 values(1,2,3,4,5,6); +ERROR 23000: Duplicate entry '1' for key 'a' +select db_row_hash_1 , db_row_hash_2, db_row_hash_3 from t1; +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' +#now try to change db_row_hash_1 column; +alter table t1 drop column db_row_hash_1, drop column db_row_hash_2, drop column db_row_hash_3; +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists +alter table t1 add column dg int , add column ef int , drop column db_row_hash_1; +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists +alter table t1 modify column db_row_hash_1 int , modify column db_row_hash_2 int, modify column db_row_hash_3 int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 add column ar int , add column rb int, modify column db_row_hash_1 int , modify column db_row_hash_3 int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 change column db_row_hash_1 dsds int , change column db_row_hash_2 dfdf int , change column db_row_hash_3 gdfg int ; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 add column asd int, drop column a, change column db_row_hash_1 dsds int, change db_row_hash_3 fdfdfd int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 drop column b , add column g int; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `c` blob DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + UNIQUE KEY `a`(`a`), + UNIQUE KEY `c`(`c`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `e`(`e`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +#now add some column with name db_row_hash; +alter table t1 add column db_row_hash_1 int unique; +alter table t1 add column db_row_hash_2 int unique; +alter table t1 add column db_row_hash_3 int unique; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `c` blob DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_3` int(11) DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), + UNIQUE KEY `db_row_hash_3` (`db_row_hash_3`), + UNIQUE KEY `a`(`a`), + UNIQUE KEY `c`(`c`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `e`(`e`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +alter table t1 add column db_row_hash_7 int, add column db_row_hash_5 int , add column db_row_hash_4 int ; +alter table t1 drop column db_row_hash_7,drop column db_row_hash_3, drop column db_row_hash_4; +desc t1; +Field Type Null Key Default Extra +a blob YES UNI NULL +c blob YES UNI NULL +d text YES UNI NULL +e varchar(3000) YES UNI NULL +f int(11) YES NULL +g int(11) YES NULL +db_row_hash_1 int(11) YES UNI NULL +db_row_hash_2 int(11) YES UNI NULL +db_row_hash_5 int(11) YES NULL +#this show now break anything; +insert into t1 values(1,2,3,4,5,6,23,5,6); +ERROR 23000: Duplicate entry '1' for key 'a' +#this should also drop the unique index; +alter table t1 drop column a, drop column c; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_5` int(11) DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `e`(`e`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 e 1 e A 0 NULL NULL YES HASH_INDEX +#add column with unique index on blob; +alter table t1 add column a blob unique; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_5` int(11) DEFAULT NULL, + `a` blob DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `e`(`e`), + UNIQUE KEY `a`(`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 e 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 a 1 a A 0 NULL NULL YES HASH_INDEX +#try to change the blob unique column name; +#this will change index to b tree; +alter table t1 modify column a int , modify column e int; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `d` text DEFAULT NULL, + `e` int(11) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_5` int(11) DEFAULT NULL, + `a` int(11) DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), + UNIQUE KEY `e` (`e`), + UNIQUE KEY `a` (`a`), + UNIQUE KEY `d`(`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE +t1 0 e 1 e A NULL NULL NULL YES BTREE +t1 0 a 1 a A NULL NULL NULL YES BTREE +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX +alter table t1 add column clm1 blob unique,add column clm2 blob unique; +#try changing the name; +alter table t1 change column clm1 clm_changed1 blob, change column clm2 clm_changed2 blob; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `d` text DEFAULT NULL, + `e` int(11) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_5` int(11) DEFAULT NULL, + `a` int(11) DEFAULT NULL, + `clm_changed1` blob DEFAULT NULL, + `clm_changed2` blob DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), + UNIQUE KEY `e` (`e`), + UNIQUE KEY `a` (`a`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `clm1`(`clm_changed1`), + UNIQUE KEY `clm2`(`clm_changed2`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE +t1 0 e 1 e A NULL NULL NULL YES BTREE +t1 0 a 1 a A NULL NULL NULL YES BTREE +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 clm1 1 clm_changed1 A 0 NULL NULL YES HASH_INDEX +t1 1 clm2 1 clm_changed2 A 0 NULL NULL YES HASH_INDEX +#now drop the unique key; +alter table t1 drop key clm1, drop key clm2; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `d` text DEFAULT NULL, + `e` int(11) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_5` int(11) DEFAULT NULL, + `a` int(11) DEFAULT NULL, + `clm_changed1` blob DEFAULT NULL, + `clm_changed2` blob DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), + UNIQUE KEY `e` (`e`), + UNIQUE KEY `a` (`a`), + UNIQUE KEY `d`(`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE +t1 0 e 1 e A NULL NULL NULL YES BTREE +t1 0 a 1 a A NULL NULL NULL YES BTREE +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX
test also
alter table ... add unique key (blob_column)
in three different variants: 1. there were no duplicates in blob_column, key added successfully, 2. there were duplicates, alter table failed. 3. there were duplicates, ALTER IGNORE TABLE... succeeds
Already added in later commit.
+drop table t1; +#now the table with key on multiple columns; the ultimate test; +create table t1(a blob, b int , c varchar(2000) , d text , e varchar(3000) , f longblob , g int , h text , +unique(a,b,c), unique(c,d,e),unique(e,f,g,h),unique(a,b,c,d,e,f),unique(d,e,f,g,h),unique(a,b,c,d,e,f,g,h)); +insert into t1 values(1,1,1,1,1,1,1,1),(2,2,2,2,2,2,2,2),(3,3,3,3,3,3,3,3),(4,4,4,4,4,4,4,4),(5,5,5,5,5,5,5,5), +('maria',6,'maria','maria','maria','maria',6,'maria'),('mariadb',7,'mariadb','mariadb','mariadb','mariadb',8,'mariadb'); +#table structure; +desc t1; +Field Type Null Key Default Extra +a blob YES MUL NULL +b int(11) YES NULL +c varchar(2000) YES MUL NULL +d text YES MUL NULL +e varchar(3000) YES MUL NULL +f longblob YES NULL +g int(11) YES NULL +h text YES NULL +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` int(11) DEFAULT NULL, + `c` varchar(2000) DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a_b_c 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 2 d A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX +select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION COLUMN_DEFAULT IS_NULLABLE DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME COLUMN_TYPE COLUMN_KEY EXTRA PRIVILEGES COLUMN_COMMENT +def test t1 a 1 NULL YES blob 65535 65535 NULL NULL NULL NULL NULL blob MUL select,insert,update,references +def test t1 b 2 NULL YES int NULL NULL 10 0 NULL NULL NULL int(11) select,insert,update,references +def test t1 c 3 NULL YES varchar 2000 2000 NULL NULL NULL latin1 latin1_swedish_ci varchar(2000) MUL select,insert,update,references +def test t1 d 4 NULL YES text 65535 65535 NULL NULL NULL latin1 latin1_swedish_ci text MUL select,insert,update,references +def test t1 e 5 NULL YES varchar 3000 3000 NULL NULL NULL latin1 latin1_swedish_ci varchar(3000) MUL select,insert,update,references +def test t1 f 6 NULL YES longblob 4294967295 4294967295 NULL NULL NULL NULL NULL longblob select,insert,update,references +def test t1 g 7 NULL YES int NULL NULL 10 0 NULL NULL NULL int(11) select,insert,update,references +def test t1 h 8 NULL YES text 65535 65535 NULL NULL NULL latin1 latin1_swedish_ci text select,insert,update,references +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME NON_UNIQUE INDEX_SCHEMA INDEX_NAME SEQ_IN_INDEX COLUMN_NAME COLLATION CARDINALITY SUB_PART PACKED NULLABLE INDEX_TYPE COMMENT INDEX_COMMENT +def test t1 1 test a_b_c 1 a A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c 2 b A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c 3 c A 0 NULL NULL YES HASH_INDEX +def test t1 1 test c_d_e 1 c A 0 NULL NULL YES HASH_INDEX +def test t1 1 test c_d_e 2 d A 0 NULL NULL YES HASH_INDEX +def test t1 1 test c_d_e 3 e A 0 NULL NULL YES HASH_INDEX +def test t1 1 test e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +def test t1 1 test e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +def test t1 1 test e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX +def test t1 1 test e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX +def test t1 1 test d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +def test t1 1 test d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +def test t1 1 test d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +def test t1 1 test d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +def test t1 1 test d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; +CONSTRAINT_CATALOG CONSTRAINT_SCHEMA CONSTRAINT_NAME TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION POSITION_IN_UNIQUE_CONSTRAINT REFERENCED_TABLE_SCHEMA REFERENCED_TABLE_NAME REFERENCED_COLUMN_NAME +def test a_b_c def test t1 a 1 NULL NULL NULL NULL +def test a_b_c def test t1 b 2 NULL NULL NULL NULL +def test a_b_c def test t1 c 3 NULL NULL NULL NULL +def test c_d_e def test t1 c 1 NULL NULL NULL NULL +def test c_d_e def test t1 d 2 NULL NULL NULL NULL +def test c_d_e def test t1 e 3 NULL NULL NULL NULL +def test e_f_g_h def test t1 e 1 NULL NULL NULL NULL +def test e_f_g_h def test t1 f 2 NULL NULL NULL NULL +def test e_f_g_h def test t1 g 3 NULL NULL NULL NULL +def test e_f_g_h def test t1 h 4 NULL NULL NULL NULL +def test a_b_c_d_e_f def test t1 a 1 NULL NULL NULL NULL +def test a_b_c_d_e_f def test t1 b 2 NULL NULL NULL NULL +def test a_b_c_d_e_f def test t1 c 3 NULL NULL NULL NULL +def test a_b_c_d_e_f def test t1 d 4 NULL NULL NULL NULL +def test a_b_c_d_e_f def test t1 e 5 NULL NULL NULL NULL +def test a_b_c_d_e_f def test t1 f 6 NULL NULL NULL NULL +def test d_e_f_g_h def test t1 d 1 NULL NULL NULL NULL +def test d_e_f_g_h def test t1 e 2 NULL NULL NULL NULL +def test d_e_f_g_h def test t1 f 3 NULL NULL NULL NULL +def test d_e_f_g_h def test t1 g 4 NULL NULL NULL NULL +def test d_e_f_g_h def test t1 h 5 NULL NULL NULL NULL +def test a_b_c_d_e_f_g_h def test t1 a 1 NULL NULL NULL NULL +def test a_b_c_d_e_f_g_h def test t1 b 2 NULL NULL NULL NULL +def test a_b_c_d_e_f_g_h def test t1 c 3 NULL NULL NULL NULL +def test a_b_c_d_e_f_g_h def test t1 d 4 NULL NULL NULL NULL +def test a_b_c_d_e_f_g_h def test t1 e 5 NULL NULL NULL NULL +def test a_b_c_d_e_f_g_h def test t1 f 6 NULL NULL NULL NULL +def test a_b_c_d_e_f_g_h def test t1 g 7 NULL NULL NULL NULL +def test a_b_c_d_e_f_g_h def test t1 h 8 NULL NULL NULL NULL +# table select we should not be able to see db_row_hash_column; +select * from t1; +a b c d e f g h +1 1 1 1 1 1 1 1 +2 2 2 2 2 2 2 2 +3 3 3 3 3 3 3 3 +4 4 4 4 4 4 4 4 +5 5 5 5 5 5 5 5 +maria 6 maria maria maria maria 6 maria +mariadb 7 mariadb mariadb mariadb mariadb 8 mariadb +select db_row_hash_1 from t1; +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' +select db_row_hash_2 from t1; +ERROR 42S22: Unknown column 'db_row_hash_2' in 'field list' +select db_row_hash_3 from t1; +ERROR 42S22: Unknown column 'db_row_hash_3' in 'field list' +#duplicate entry test; +#duplicate keys entry; +insert into t1 values(1,1,1,0,0,0,0,0); +ERROR 23000: Duplicate entry '1-1-1' for key 'a_b_c' +insert into t1 values(0,0,1,1,1,0,0,0); +ERROR 23000: Duplicate entry '1-1-1' for key 'c_d_e' +insert into t1 values(0,0,0,0,1,1,1,1); +ERROR 23000: Duplicate entry '1-1-1-1' for key 'e_f_g_h' +insert into t1 values(1,1,1,1,1,0,0,0); +ERROR 23000: Duplicate entry '1-1-1' for key 'a_b_c' +insert into t1 values(0,0,0,0,1,1,1,1); +ERROR 23000: Duplicate entry '1-1-1-1' for key 'e_f_g_h' +insert into t1 values(1,1,1,1,1,1,1,1); +ERROR 23000: Duplicate entry '1-1-1' for key 'a_b_c' +select db_row_hash_1,db_row_hash_2,db_row_hash_3,db_row_hash_4,db_row_hash_5 from t1; +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' +alter table t1 drop column db_row_hash_1, drop column db_row_hash_2, drop column db_row_hash_3; +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists +alter table t1 add column dg int , add column ef int , drop column db_row_hash_1; +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists +alter table t1 modify column db_row_hash_1 int , modify column db_row_hash_2 int, modify column db_row_hash_3 int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 add column ar int , add column rb int, modify column db_row_hash_1 int , modify column db_row_hash_3 int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 change column db_row_hash_1 dsds int , change column db_row_hash_2 dfdf int , change column db_row_hash_3 gdfg int ; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 add column asd int, drop column a, change column db_row_hash_1 dsds int, change db_row_hash_3 fdfdfd int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` int(11) DEFAULT NULL, + `c` varchar(2000) DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +# add column named db_row_hash_*; +alter table t1 add column db_row_hash_7 int , add column db_row_hash_5 int, +add column db_row_hash_1 int, add column db_row_hash_2 int; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` int(11) DEFAULT NULL, + `c` varchar(2000) DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + `db_row_hash_7` int(11) DEFAULT NULL, + `db_row_hash_5` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a_b_c 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 2 d A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX +alter table t1 drop column db_row_hash_7 , drop column db_row_hash_5 , +drop column db_row_hash_1, drop column db_row_hash_2 ; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` int(11) DEFAULT NULL, + `c` varchar(2000) DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a_b_c 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 2 d A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX +#try to change column names; +alter table t1 change column a aa blob , change column b bb blob , change column d dd blob; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `aa` blob DEFAULT NULL, + `bb` blob DEFAULT NULL, + `c` varchar(2000) DEFAULT NULL, + `dd` blob DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + UNIQUE KEY `a_b_c`(`aa`,`bb`,`c`), + UNIQUE KEY `c_d_e`(`c`,`dd`,`e`), + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f`(`aa`,`bb`,`c`,`dd`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`dd`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`aa`,`bb`,`c`,`dd`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a_b_c 1 aa A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 2 bb A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 2 dd A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 1 aa A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 2 bb A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 4 dd A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 1 dd A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 1 aa A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 2 bb A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 4 dd A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX +alter table t1 change column aa a blob , change column bb b blob , change column dd d blob; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` blob DEFAULT NULL, + `c` varchar(2000) DEFAULT NULL, + `d` blob DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a_b_c 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 2 d A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX +#now we will change the data type to int and varchar limit so that we no longer require hash_index; +#on key a_b_c; +alter table t1 modify column a int , modify column b int , modify column c int; +Warnings: +Warning 1292 Truncated incorrect INTEGER value: 'maria' +Warning 1292 Truncated incorrect INTEGER value: 'maria' +Warning 1292 Truncated incorrect INTEGER value: 'mariadb' +Warning 1292 Truncated incorrect INTEGER value: 'mariadb' +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` int(11) DEFAULT NULL, + `b` int(11) DEFAULT NULL, + `c` int(11) DEFAULT NULL, + `d` blob DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + UNIQUE KEY `a_b_c` (`a`,`b`,`c`), + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 a_b_c 1 a A NULL NULL NULL YES BTREE +t1 0 a_b_c 2 b A NULL NULL NULL YES BTREE +t1 0 a_b_c 3 c A NULL NULL NULL YES BTREE +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 2 d A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX +#change it back; +alter table t1 modify column a blob , modify column b blob , modify column c blob; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` blob DEFAULT NULL, + `c` blob DEFAULT NULL, + `d` blob DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a_b_c 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 2 d A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX +#try to delete blob column in unique; +truncate table t1; +alter table t1 drop column a, drop column b, drop column c; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `d` blob DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + UNIQUE KEY `c_d_e`(`d`,`e`), + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f`(`d`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 c_d_e 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +#now try to delete keys; +alter table t1 drop key c_d_e, drop key e_f_g_h; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `d` blob DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + UNIQUE KEY `a_b_c_d_e_f`(`d`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a_b_c_d_e_f 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +drop table t1; diff --git a/mysql-test/t/hidden_field.test b/mysql-test/t/hidden_field.test new file mode 100644 index 0000000..8f3b452 --- /dev/null +++ b/mysql-test/t/hidden_field.test @@ -0,0 +1,152 @@ +create table h_1(abc int primary key, xyz int hidden); +desc h_1; +show create table h_1; +drop table h_1; +--error ER_TABLE_MUST_HAVE_COLUMNS +create table h_2(a1 int hidden); +--error ER_PARSE_ERROR +create table h_3(a1 blob,hidden(a1)); +--error ER_HIDDEN_NOT_NULL_WOUT_DEFAULT +create table h_4(a1 int primary key hidden ,a2 int unique hidden , a3 blob,a4 +int not null hidden unique); +--error ER_HIDDEN_NOT_NULL_WOUT_DEFAULT +create table h_5(abc int not null hidden); +create table t1(a int hidden, b int); +#should automatically add null +insert into t1 values(1); +insert into t1(a) values(1); +insert into t1(b) values(1); +insert into t1(a,b) values(5,5); +select * from t1; +select a,b from t1; +delete from t1; +insert into t1 values(1),(2),(3),(4); +select * from t1; +select a from t1; +drop table t1; +#echo more complex case of hidden +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +desc t1; +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +select * from t1; +drop table t1; +--error ER_PARSE_ERROR +create table sdsdsd(a int , b int, hidden(a,b)); +create table t1(a int,abc int as (a mod 3) virtual hidden); +desc t1; +--error ER_WRONG_VALUE_COUNT_ON_ROW +insert into t1 values(1,default); +insert into t1 values(1),(22),(233); +select * from t1; +select a,abc from t1; +drop table t1; +create table t1(abc int primary key hidden auto_increment, a int); +desc t1; +show create table t1; +insert into t1 values(1); +insert into t1 values(2); +insert into t1 values(3); +select * from t1; +select abc,a from t1; +delete from t1; +insert into t1 values(1),(2),(3),(4),(6); +select abc,a from t1; +drop table t1; +create table t1(abc int); +--error ER_TABLE_MUST_HAVE_COLUMNS +alter table t1 change abc ss int hidden; +alter table t1 add column xyz int; +alter table t1 modify column abc int ; +desc t1; +--error ER_WRONG_VALUE_COUNT_ON_ROW +insert into t1 values(22); +alter table t1 modify column abc int hidden; +desc t1; +insert into t1 values(12); +drop table t1; + +--echo some test on copy table structure with table data;
in echo's start the message from #-sign to make it better visible in a result
Changed.
+ +--echo table with hidden fields and unique keys; + +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +desc t1; +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +select * from t1; +select a,b,c,d,e,f from t1; +--echo this wont copy hidden fields and keys; +create table t2 as select * from t1; +desc t2; +select * from t2; +--error ER_BAD_FIELD_ERROR +select a,b,c,d,e,f from t2; +drop table t2; +--echo now this will copy hidden fields +create table t2 as select a,b,c,d,e,f from t1; +desc t2; +select * from t2; +select a,b,c,d,e,f from t2; +drop table t2,t1; + +--echo some test related to copy of data from one table to another; +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +select a,b,c,d,e,f from t1; +create table t2(a int , b int hidden , c int hidden , d blob , e int unique, f int); +insert into t2 select * from t1; +select a,b,c,d,e,f from t2; +truncate t2; +insert into t2 (a,b,c,d,e,f) select a,b,c,d,e,f from t1; +select a,b,c,d,e,f from t2; +truncate t2; +drop table t1,t2; + +--echo some test related to creating view on table with hidden column; +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +create view v as select * from t1; +desc v; +select * from v; +--echo v does not have hidden column; +--error ER_BAD_FIELD_ERROR +select a,b,c,d,e,f from v; +insert into v values(1,21,32,4); +select * from v; +--error ER_BAD_FIELD_ERROR +insert into v(a,b,c,d,e,f) values(1,12,3,4,5,6); +drop view v; + +create view v as select a,b,c,d,e,f from t1; +desc v; +select * from v; +--echo v does have hidden column; +select a,b,c,d,e,f from v; +insert into v values(1,26,33,4,45,66); +select a,b,c,d,e,f from v; +insert into v(a,b,c,d,e,f) values(1,32,31,41,5,6); +select a,b,c,d,e,f from v; +drop view v; +drop table t1; + +--echo now hidden column in where and some join query i think no use of this test but anyway; +create table t1 (a int unique , b int hidden unique, c int unique hidden); +insert into t1(a,b,c) values(1,1,1); +insert into t1(a,b,c) values(2,2,2); +insert into t1(a,b,c) values(3,3,3); +insert into t1(a,b,c) values(4,4,4); +insert into t1(a,b,c) values(21,21,26); +insert into t1(a,b,c) values(31,31,35); +insert into t1(a,b,c) values(41,41,45); +insert into t1(a,b,c) values(22,22,24); +insert into t1(a,b,c) values(32,32,33); +insert into t1(a,b,c) values(42,42,43); +explain select * from t1 where b=3; +select * from t1 where b=3; +explain select * from t1 where c=3; +select * from t1 where c=3; + +create table t2 as select a,b,c from t1; +desc t2; +explain select * from t1,t2 where t1.b = t2.c and t1.c = t2.b; +select * from t1,t2 where t1.b = t2.c and t1.c = t2.b; +drop table t1,t2; diff --git a/mysql-test/t/long_uniques.test b/mysql-test/t/long_uniques.test new file mode 100644 index 0000000..8777aaa --- /dev/null +++ b/mysql-test/t/long_uniques.test @@ -0,0 +1,294 @@
please add also a test case for innodb. In a separate file, long_uniques_innodb.test in particular, test this case:
connection con1; start transaction; insert ('bbbb') connection con2; start transaction; insert ('bbbb')
see? insert the conflicting value in two simultaneously running transactions. try that in different transaction isolation levels. normally the second transaction should *not* see the first 'bbbb' because the first transaction is not committed yet. But InnoDB next-key locks should guarantee that the second transaction will wait for the first.
TODO
+--echo #Structure of tests +--echo #First we will check all option for +--echo #table containing single unique column +--echo #table containing keys like unique(a,b,c,d) etc +--echo #then table containing 2 blob unique etc + +--echo #table with single long blob column; +create table t1(a blob unique); +insert into t1 values(1),(2),(3),(56),('sachin'),('maria'),(123456789034567891),(null),(null),(123456789034567890); + +--echo #table structure; +desc t1; +show create table t1; +show keys from t1; +select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; +--echo # table select we should not be able to see db_row_hash_column; +select * from t1; +--error ER_BAD_FIELD_ERROR +select db_row_hash_1 from t1; +--echo #duplicate entry test; +--error ER_DUP_ENTRY +insert into t1 values(2); +--error ER_DUP_ENTRY +insert into t1 values('sachin'); +--error ER_DUP_ENTRY +insert into t1 values(123456789034567891); +select * from t1; +insert into t1 values(11),(22),(33); +--error ER_DUP_ENTRY +insert into t1 values(12),(22); +select * from t1; +insert into t1 values(repeat('s',4000*10)),(repeat('s',4001*10)); +--error ER_DUP_ENTRY +insert into t1 values(repeat('m',4000*10)),(repeat('m',4000*10)); +insert into t1 values(repeat('m',4001)),(repeat('m',4002)); +truncate table t1; +insert into t1 values(1),(2),(3),(4),(5),(8),(7); + +--echo #now some alter commands; +alter table t1 add column b int; +desc t1; +show create table t1; +--error ER_DUP_ENTRY +insert into t1 values(1,2); +--error ER_DUP_ENTRY +insert into t1 values(2,2); +--error ER_BAD_FIELD_ERROR +select db_row_hash_1 from t1; +--echo #now try to change db_row_hash_1 column; +--error ER_CANT_DROP_FIELD_OR_KEY +alter table t1 drop column db_row_hash_1; +--error ER_CANT_DROP_FIELD_OR_KEY +alter table t1 add column d int , add column e int , drop column db_row_hash_1; +--error ER_BAD_FIELD_ERROR +alter table t1 modify column db_row_hash_1 int ; +--error ER_BAD_FIELD_ERROR +alter table t1 add column a int , add column b int, modify column db_row_hash_1 int ; +--error ER_BAD_FIELD_ERROR +alter table t1 change column db_row_hash_1 dsds int; +--error ER_BAD_FIELD_ERROR +alter table t1 add column asd int, change column db_row_hash_1 dsds int; +alter table t1 drop column b , add column c int; +show create table t1; + +--echo #now add some column with name db_row_hash; +alter table t1 add column db_row_hash_1 int unique; +show create table t1; +--error ER_DUP_ENTRY +insert into t1 values(45,1,55),(46,1,55); +alter table t1 add column db_row_hash_2 int, add column db_row_hash_3 int; +desc t1; +--echo #this should also drop the unique index ; +alter table t1 drop column a; +show create table t1; +show keys from t1; +--echo #add column with unique index on blob ; +alter table t1 add column a blob unique; +show create table t1; +--echo # try to change the blob unique column name; +--echo #this will change index to b tree; +alter table t1 modify column a int ; +show create table t1; +show keys from t1; +alter table t1 add column clm blob unique; +--echo #try changing the name ; +alter table t1 change column clm clm_changed blob; +show create table t1; +show keys from t1; +--echo #now drop the unique key; +alter table t1 drop key clm; +show create table t1; +show keys from t1; +drop table t1; + +create table t1 (a TEXT CHARSET latin1 COLLATE latin1_german2_ci unique); +desc t1; +show keys from t1; + insert into t1 values ('ae'); +--error ER_DUP_ENTRY + insert into t1 values ('AE'); + insert into t1 values ('Ä'); +drop table t1; + +--echo #table with multiple long blob column and varchar text column ; +create table t1(a blob unique, b int , c blob unique , d text unique , e varchar(3000) unique); +insert into t1 values(1,2,3,4,5),(2,11,22,33,44),(3111,222,333,444,555),(5611,2222,3333,4444,5555), +('sachin','ff','fdf','gfgfgfg','hghgr'),('maria','db','frter','dasd','utyuty'), +(123456789034567891,3534534534534,53453453453456,64565464564564,45435345345345), +(123456789034567890,435345345345,657567567567,78967657567567,657567567567567676); + +--echo #table structure; +desc t1; +show create table t1; +show keys from t1; +select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; +--echo #table select we should not be able to see db_row_hash_column; +select * from t1; +--error ER_BAD_FIELD_ERROR +select db_row_hash_1 from t1; +--error ER_BAD_FIELD_ERROR +select db_row_hash_2 from t1; +--error ER_BAD_FIELD_ERROR +select db_row_hash_3 from t1; +--echo #duplicate entry test; +--error ER_DUP_ENTRY +insert into t1 values(21,2,3,42,51); +--error ER_DUP_ENTRY +insert into t1 values('sachin',null,null,null,null); +--error ER_DUP_ENTRY +insert into t1 values(1234567890345671890,4353453453451,6575675675617,789676575675617,657567567567567676); +select * from t1; +insert into t1 values(repeat('s',4000*10),100,repeat('s',4000*10),repeat('s',4000*10), +repeat('s',400)),(repeat('s',4001*10),1000,repeat('s',4001*10),repeat('s',4001*10), +repeat('s',401)); +--error ER_DUP_ENTRY +insert into t1 values(repeat('m',4000*11),10,repeat('s',4000*11),repeat('s',4000*11),repeat('s',400)); +truncate table t1; +insert into t1 values(1,2,3,4,5),(2,11,22,33,44),(3111,222,333,444,555),(5611,2222,3333,4444,5555); + +--echo #now some alter commands; +alter table t1 add column f int; +desc t1; +show create table t1; +--echo #unique key should not break; +--error ER_DUP_ENTRY +insert into t1 values(1,2,3,4,5,6); +--error ER_BAD_FIELD_ERROR +select db_row_hash_1 , db_row_hash_2, db_row_hash_3 from t1; +--echo #now try to change db_row_hash_1 column; +--error ER_CANT_DROP_FIELD_OR_KEY +alter table t1 drop column db_row_hash_1, drop column db_row_hash_2, drop column db_row_hash_3; +--error ER_CANT_DROP_FIELD_OR_KEY +alter table t1 add column dg int , add column ef int , drop column db_row_hash_1; +--error ER_BAD_FIELD_ERROR +alter table t1 modify column db_row_hash_1 int , modify column db_row_hash_2 int, modify column db_row_hash_3 int; +--error ER_BAD_FIELD_ERROR +alter table t1 add column ar int , add column rb int, modify column db_row_hash_1 int , modify column db_row_hash_3 int; +--error ER_BAD_FIELD_ERROR +alter table t1 change column db_row_hash_1 dsds int , change column db_row_hash_2 dfdf int , change column db_row_hash_3 gdfg int ; +--error ER_BAD_FIELD_ERROR +alter table t1 add column asd int, drop column a, change column db_row_hash_1 dsds int, change db_row_hash_3 fdfdfd int; +alter table t1 drop column b , add column g int; +show create table t1; + +--echo #now add some column with name db_row_hash; +alter table t1 add column db_row_hash_1 int unique; +alter table t1 add column db_row_hash_2 int unique; +alter table t1 add column db_row_hash_3 int unique; +show create table t1; + +alter table t1 add column db_row_hash_7 int, add column db_row_hash_5 int , add column db_row_hash_4 int ; +alter table t1 drop column db_row_hash_7,drop column db_row_hash_3, drop column db_row_hash_4; +desc t1; +--echo #this show now break anything; +--error ER_DUP_ENTRY +insert into t1 values(1,2,3,4,5,6,23,5,6); +--echo #this should also drop the unique index; +alter table t1 drop column a, drop column c; +show create table t1; +show keys from t1; +--echo #add column with unique index on blob; +alter table t1 add column a blob unique; +show create table t1; +show keys from t1; +--echo #try to change the blob unique column name; +--echo #this will change index to b tree; +alter table t1 modify column a int , modify column e int; +show create table t1; +show keys from t1; +alter table t1 add column clm1 blob unique,add column clm2 blob unique; +--echo #try changing the name; +alter table t1 change column clm1 clm_changed1 blob, change column clm2 clm_changed2 blob; +show create table t1; +show keys from t1; +--echo #now drop the unique key; +alter table t1 drop key clm1, drop key clm2; +show create table t1; +show keys from t1; +drop table t1; + +--echo #now the table with key on multiple columns; the ultimate test; +create table t1(a blob, b int , c varchar(2000) , d text , e varchar(3000) , f longblob , g int , h text , + unique(a,b,c), unique(c,d,e),unique(e,f,g,h),unique(a,b,c,d,e,f),unique(d,e,f,g,h),unique(a,b,c,d,e,f,g,h)); + +insert into t1 values(1,1,1,1,1,1,1,1),(2,2,2,2,2,2,2,2),(3,3,3,3,3,3,3,3),(4,4,4,4,4,4,4,4),(5,5,5,5,5,5,5,5), +('maria',6,'maria','maria','maria','maria',6,'maria'),('mariadb',7,'mariadb','mariadb','mariadb','mariadb',8,'mariadb'); + +--echo #table structure; +desc t1; +show create table t1; +show keys from t1; +select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; +--echo # table select we should not be able to see db_row_hash_column; +select * from t1; +--error ER_BAD_FIELD_ERROR +select db_row_hash_1 from t1; +--error ER_BAD_FIELD_ERROR +select db_row_hash_2 from t1; +--error ER_BAD_FIELD_ERROR +select db_row_hash_3 from t1; +--echo #duplicate entry test; +--echo #duplicate keys entry; +--error ER_DUP_ENTRY +insert into t1 values(1,1,1,0,0,0,0,0); +--error ER_DUP_ENTRY +insert into t1 values(0,0,1,1,1,0,0,0); +--error ER_DUP_ENTRY +insert into t1 values(0,0,0,0,1,1,1,1); +--error ER_DUP_ENTRY +insert into t1 values(1,1,1,1,1,0,0,0); +--error ER_DUP_ENTRY +insert into t1 values(0,0,0,0,1,1,1,1); +--error ER_DUP_ENTRY +insert into t1 values(1,1,1,1,1,1,1,1); +--error ER_BAD_FIELD_ERROR +select db_row_hash_1,db_row_hash_2,db_row_hash_3,db_row_hash_4,db_row_hash_5 from t1; +--error ER_CANT_DROP_FIELD_OR_KEY +alter table t1 drop column db_row_hash_1, drop column db_row_hash_2, drop column db_row_hash_3; +--error ER_CANT_DROP_FIELD_OR_KEY +alter table t1 add column dg int , add column ef int , drop column db_row_hash_1; +--error ER_BAD_FIELD_ERROR +alter table t1 modify column db_row_hash_1 int , modify column db_row_hash_2 int, modify column db_row_hash_3 int; +--error ER_BAD_FIELD_ERROR +alter table t1 add column ar int , add column rb int, modify column db_row_hash_1 int , modify column db_row_hash_3 int; +--error ER_BAD_FIELD_ERROR +alter table t1 change column db_row_hash_1 dsds int , change column db_row_hash_2 dfdf int , change column db_row_hash_3 gdfg int ; +--error ER_BAD_FIELD_ERROR +alter table t1 add column asd int, drop column a, change column db_row_hash_1 dsds int, change db_row_hash_3 fdfdfd int; + +show create table t1; +--echo # add column named db_row_hash_*; +alter table t1 add column db_row_hash_7 int , add column db_row_hash_5 int, + add column db_row_hash_1 int, add column db_row_hash_2 int; +show create table t1; +show keys from t1; +alter table t1 drop column db_row_hash_7 , drop column db_row_hash_5 , + drop column db_row_hash_1, drop column db_row_hash_2 ; +show create table t1; +show keys from t1; + +--echo #try to change column names; +alter table t1 change column a aa blob , change column b bb blob , change column d dd blob; +show create table t1; +show keys from t1; +alter table t1 change column aa a blob , change column bb b blob , change column dd d blob; +show create table t1; +show keys from t1; + +--echo #now we will change the data type to int and varchar limit so that we no longer require hash_index; +--echo #on key a_b_c; +alter table t1 modify column a int , modify column b int , modify column c int; +show create table t1; +show keys from t1; +--echo #change it back; +alter table t1 modify column a blob , modify column b blob , modify column c blob; +show create table t1; +show keys from t1; + +--echo #try to delete blob column in unique; +truncate table t1; +alter table t1 drop column a, drop column b, drop column c; +show create table t1; +show keys from t1; +--echo #now try to delete keys; +alter table t1 drop key c_d_e, drop key e_f_g_h; +show create table t1; +show keys from t1; +drop table t1; diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index 8dfa519..9d5b4f5 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -7214,3 +7214,5 @@ ER_CALCULATING_DEFAULT_VALUE eng "Got an error when calculating default value for %`s" ER_EXPRESSION_REFERS_TO_UNINIT_FIELD 01000 eng "Expression for field %`-.64s is refering to uninitialized field %`s" +ER_HIDDEN_NOT_NULL_WOUT_DEFAULT + eng "Hidden column '%s' either allow null values or it must have default value"
"... should either allow null values ..." or "... should either be nullable ..."
Done.
diff --git a/sql/table.h b/sql/table.h index 651fab7..9d2b279 100644 --- a/sql/table.h +++ b/sql/table.h @@ -330,7 +330,28 @@ enum enum_vcol_update_mode VCOL_UPDATE_ALL };
+/* Field visibility enums */
+enum field_visible_type{ + NOT_HIDDEN=0, + USER_DEFINED_HIDDEN, + MEDIUM_HIDDEN, + FULL_HIDDEN
this could use some comments. Or better names. NOT_HIDDEN is very clear. USER_DEFINED_HIDDEN is kind of ok too. But MEDIUM_HIDDEN is not - what does that mean? Please, either add a comment, like // pseudo-columns (like ROWID). Can be queried explicitly in SELECT, otherwise hidden from anything or rename MEDIUM_HIDDEN to something self-explanatory (may be, PSEUDO_COLUMN_HIDDEN?). FULL_HIDDEN is ok, although FULLY_HIDDEN or COMPLETELY_HIDDEN is a bit easier to read, I'd think.
+}; + +int rem_field_from_hash_col_str(LEX_STRING *hash_lex, const char *field_name);
confus way to abbr words. plz rena to smth lik
remove_field_from_hash_index
or, may be
remove_field_from_hash_index_def remove_field_from_hash_index_sql
by the way, this function isn't used anywhere. Forgot to remove it?
Removed.
+ +int change_field_from_hash_col_str(LEX_STRING *hash_lex, + const char *old_name, char *new_name);
1. notice many <Tab> characters on the previous line that indent that line way too much. 2. this function doesn't seem to be used either
Removed.
+ +int find_field_name_in_hash(char * hash_str, const char *field_name, + int hash_str_length);
again, many <Tab>s on the previous line. Prefer spaces, please.
+ +int find_field_index_in_hash(LEX_STRING * hash_lex, const char * field_name);
name's pretty bad, compared to find_field_name_in_hash. better rename the previous function to find_field_pos_in_hash_str or something like that.
+ +int fields_in_hash_str(LEX_STRING *hash_lex); + +Field * field_ptr_in_hash_str(LEX_STRING * hash_str, TABLE *table, int index); /** Category of table found in the table share. */ @@ -1031,6 +1052,19 @@ struct TABLE Field **field; /* Pointer to fields */
uchar *record[2]; /* Pointer to records */ + uchar *check_unique_buf; /* Pointer to record with same hash */
better comment: /* record buf to resolve hash collisions for long UNIQUE constraints */
Changed.
+ handler *update_handler; /* Handler used in case of update */
I don't think you need to store it in the TABLE. You can either pass it as an argument to ha_update_row() or invoke check_duplicate_long_entries() before ha_update_row() not from it.
+ /* + In the case of write row for long unique we are unable of find + Whick key is voilated because we in case of duplicate we never reach + handler write_row function so print_error will always print that + key 0 is voilated we store which key is voilated in this variable + by default this should be initialized to -1 + */ + int dupp_key; + /* If dupp != -1 then this string + store message which should be printed */ + char *err_message;
I wonder whether you need it. You can issue an error (with my_error()) directly from check_duplicate_long_entries(), no need to store the error till later. If you issue an error early, you'll simply skip handler::print_keydup_error() later.
This wont work because there can be statements like alter ignore table t1 add unique key(a); Anyway I have removed err_message from table class but dupp_key is still there. I need this here uint handler::get_dup_key(int error) { DBUG_ASSERT(table_share->tmp_table != NO_TMP_TABLE || m_lock_type != F_UNLCK); DBUG_ENTER("handler::get_dup_key"); table->file->errkey = (uint) -1; if (table->dupp_key != -1) DBUG_RETURN(table->dupp_key);
uchar *write_row_record; /* Used as optimisation in THD::write_row */ uchar *insert_values; /* used by INSERT ... UPDATE */ diff --git a/sql/field.h b/sql/field.h index 05e0615..35a7006 100644 --- a/sql/field.h +++ b/sql/field.h @@ -998,9 +1001,9 @@ class Field: public Value_source virtual int cmp(const uchar *,const uchar *)=0; virtual int cmp_binary(const uchar *a,const uchar *b, uint32 max_length=~0L) { return memcmp(a,b,pack_length()); } - virtual int cmp_offset(uint row_offset) + virtual int cmp_offset(long row_offset)
1. why is that? because old offset was unsigned?
Yes
2. better use my_ptrdiff_t type here
Changed.
{ return cmp(ptr,ptr+row_offset); } - virtual int cmp_binary_offset(uint row_offset) + virtual int cmp_binary_offset(long row_offset) { return cmp_binary(ptr, ptr+row_offset); }; virtual int key_cmp(const uchar *a,const uchar *b) { return cmp(a, b); } diff --git a/sql/sql_select.h b/sql/sql_select.h index 92ba74f..dd55d94 100644 --- a/sql/sql_select.h +++ b/sql/sql_select.h @@ -1818,6 +1825,27 @@ class store_key_field: public store_key When the implementation of this function will be replaced for a proper full version this statement probably should be removed. */ + if (is_hash) + { + Field *f= copy_field.from_field; + String str;
Normally in these cases you should use StringBuffer
instead of String. It will allocate a char[MAX_FIELD_WIDTH] buffer on the stack so the following val_str() will not need to call malloc if the value is shorter than MAX_FIELD_WIDTH. But in this particular case, you're doing long unique, probably for blobs, so here the result will typically be larger than MAX_FIELD_WIDTH, and this StringBuffer optimization will not actually help.
+ f->val_str(&str); + if (f->is_null()) + { + *(copy_field.to_ptr-1)= 1; //set it null
why do you write to copy_field.to_ptr directly? store_key methods don't do that anywhere else
Okay, I will change It. But I think in newer version I do not require this code. So I will change it later on.
+ null_key= true;
where you reset null_key and copy_field.ptr[-1] back to 0?
+ dbug_tmp_restore_column_map(table->write_set, old_map); + return STORE_KEY_OK; + } + CHARSET_INFO* cs= str.charset(); + uchar l[4]; + int4store(l,str.length()); + cs->coll->hash_sort(cs, l, sizeof(l), &nr1, &nr2);
cs= &my_charset_bin; for hash_sort() above, cs= str.charset(); for hash_sort() below.
+ cs->coll->hash_sort(cs, (uchar *)str.ptr(), str.length(), &nr1, &nr2); + int8store(copy_field.to_ptr, nr1); + dbug_tmp_restore_column_map(table->write_set, old_map); + return STORE_KEY_OK;
I suppose you don't need to calculate hashes if null_key is already true for this row (if it's a multi-column key and one of the previous columns was NULL)
btw, could you add a test case for that? a test case where f->is_null() is true? like, add assert(0); under that if() and try to create a test case that will cause it to crash.
+ } bzero(copy_field.to_ptr,copy_field.to_length);
copy_field.do_copy(©_field); @@ -1860,6 +1889,26 @@ class store_key_item :public store_key table->write_set); int res= FALSE;
+ if (is_hash) + { + String *str= item->val_str(); + if (item->null_value) + { + *(to_field->ptr - 1)= 1; + null_key= true; + dbug_tmp_restore_column_map(table->write_set, old_map); + return STORE_KEY_OK; + } + CHARSET_INFO *cs= str->charset(); + uchar l[4]; + int4store(l,str->length()); + cs->coll->hash_sort(cs,l,sizeof(l), &nr1, &nr2); + cs->coll->hash_sort(cs, (uchar *)str->ptr(), str->length(), &nr1, &nr2); + int8store(to_field->ptr, nr1); + //no idea what it does
remove this comment, please :) and if you're curious what it does, you can always comment dbug_tmp_use_all_columns() and dbug_tmp_restore_column_map() in this function out and run the test suite in debug build, you'll see how it will crash :) or you can ask, that works too...
Okay
+ dbug_tmp_restore_column_map(table->write_set, old_map); + return STORE_KEY_OK; + } /* It looks like the next statement is needed only for a simplified hash function over key values used now in BNLH join. @@ -2271,4 +2320,11 @@ class Pushdown_query: public Sql_alloc bool test_if_order_compatible(SQL_I_List<ORDER> &a, SQL_I_List<ORDER> &b); int test_if_group_changed(List
&list); int create_sort_index(THD *thd, JOIN *join, JOIN_TAB *tab, Filesort *fsort); +/* + It compares the record with same hash to key if + record is equal then return 0 else fetches next + record with same hash and so on if some error + then returns error +*/ better put this comment where a function is defined, in sql_select.cc
+int compare_hash_and_fetch_next(JOIN_TAB *join); #endif /* SQL_SELECT_INCLUDED */ diff --git a/sql/mysqld.cc b/sql/mysqld.cc index fa8f143..eb1769b 100644 --- a/sql/mysqld.cc +++ b/sql/mysqld.cc @@ -8394,6 +8394,7 @@ SHOW_VAR status_vars[]= { {"Feature_dynamic_columns", (char*) offsetof(STATUS_VAR, feature_dynamic_columns), SHOW_LONG_STATUS}, {"Feature_fulltext", (char*) offsetof(STATUS_VAR, feature_fulltext), SHOW_LONG_STATUS}, {"Feature_gis", (char*) offsetof(STATUS_VAR, feature_gis), SHOW_LONG_STATUS}, + {"Feature_hidden_column", (char*) offsetof(STATUS_VAR, feature_hidden_column), SHOW_LONG_STATUS},
I feel that Feature_hidden_columns (plural) would look better here.
I know we aren't consistent, there's Feature_dynamic_columns (plural) but Feature_subquery, Feature_timezone (singular), so there is no rule here, unfortunately.
Done
{"Feature_locale", (char*) offsetof(STATUS_VAR, feature_locale), SHOW_LONG_STATUS}, {"Feature_subquery", (char*) offsetof(STATUS_VAR, feature_subquery), SHOW_LONG_STATUS}, {"Feature_timezone", (char*) offsetof(STATUS_VAR, feature_timezone), SHOW_LONG_STATUS}, diff --git a/sql/field.cc b/sql/field.cc index c684e6a..8c17b76 100644 --- a/sql/field.cc +++ b/sql/field.cc @@ -7671,7 +7672,6 @@ uint32 Field_varstring::data_length() { return length_bytes == 1 ? (uint32) *ptr : uint2korr(ptr); } -
restore the empty line, please
/* Functions to create a packed row. Here the number of length bytes are depending on the given max_length diff --git a/sql/item_subselect.cc b/sql/item_subselect.cc index 8bb12ce..45e6cce 100644 --- a/sql/item_subselect.cc +++ b/sql/item_subselect.cc @@ -3899,6 +3899,25 @@ bool subselect_uniquesubquery_engine::copy_ref_key(bool skip_constants) */ DBUG_RETURN(true); } + if ((*copy)->is_hash) + { + if (!(*copy)->null_key && *(copy+1)) + { + (*(copy+1))->nr1= (*copy)->nr1; + (*(copy+1))->nr2= (*copy)->nr2;
I don't get it, why *(copy+1) ?
Supoose a key is like unique(a,b,c) then I need to transfer nr1,nr2 from one copy var to another copy var. That is why I am doing this.
+ } + else + break; + } + } + //reset nr1 and nr2 + for (store_key **copy=tab->ref.key_copy ; *copy ; copy++) + { + if ((*copy)->is_hash) + { + (*copy)->nr1= 1; + (*copy)->nr2= 4; + } } DBUG_RETURN(false); } diff --git a/sql/item_func.cc b/sql/item_func.cc index 7f8c89c..3c71e8c 100644 --- a/sql/item_func.cc +++ b/sql/item_func.cc @@ -1839,6 +1839,40 @@ void Item_func_int_div::fix_length_and_dec() }
+longlong Item_func_hash::val_int() +{ + unsigned_flag= true; + ulong nr1= 1,nr2= 4; + CHARSET_INFO *cs; + for(uint i= 0;i
val_str(); + if(args[i]->null_value) + { + null_value= 1; + return 0; + } + cs= str->charset(); + uchar l[4]; + int4store(l, str->length()); + cs->coll->hash_sort(cs, l, sizeof(l), &nr1, &nr2); + cs->coll->hash_sort(cs, (uchar *)str->ptr(), str->length(), &nr1, &nr2); that's the third time I see these sequence of lines (and there's one more below). Why not to put it in a reusable function? like
calc_hash_for_unique(&nr1, &nr2, str) { uchar l[4]; int4store(l, str->length()); cs= &my_charset_bin; cs->coll->hash_sort(cs, l, sizeof(l), &nr1, &nr2); cs= str->charset(); cs->coll->hash_sort(cs, (uchar *)str->ptr(), str->length(), &nr1, &nr2); }
Done.
+ } + null_value= 0; + //for testing purpose + //nr1=12;
remove that, please ^^^
Removed.
+ return (longlong)nr1; +} + + +void Item_func_hash::fix_length_and_dec() +{ + maybe_null= 1; + decimals= 0; + max_length= 8; +} + + longlong Item_func_mod::int_op() { DBUG_ASSERT(fixed == 1); diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index 9d7e735..61022e6 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -6191,6 +6192,11 @@ vcol_attribute: lex->alter_info.flags|= Alter_info::ALTER_ADD_INDEX; } | COMMENT_SYM TEXT_STRING_sys { Lex->last_field->comment= $2; } + | HIDDEN_SYM + { + LEX *lex =Lex; + lex->last_field->field_visibility=USER_DEFINED_HIDDEN; + }
Please, make HIDDEN keyword non-reserved. For that it should be added to the keyword_sp rule. And add a test case for it, like
--echo # HIDDEN is not reserved create table t1 (hidden int); drop table t1;
Done.
;
parse_vcol_expr: @@ -9482,6 +9476,12 @@ function_call_keyword: if ($$ == NULL) MYSQL_YYABORT; } + |HASH_SYM '(' expr_list ')'
You've added it to function_call_keyword rule, but it should have been added to the function_call_conflict rule. See comments before these both rules.
Done.
+ { + $$= new (thd->mem_root)Item_func_hash(thd,*$3); + if($$==NULL) + MYSQL_YYABORT; + } | INSERT '(' expr ',' expr ',' expr ',' expr ')' { $$= new (thd->mem_root) Item_func_insert(thd, $3, $5, $7, $9); diff --git a/sql/sql_insert.cc b/sql/sql_insert.cc index 8028779..41f5a55 100644 --- a/sql/sql_insert.cc +++ b/sql/sql_insert.cc @@ -198,6 +198,17 @@ static int check_insert_fields(THD *thd, TABLE_LIST *table_list, TABLE *table= table_list->table; DBUG_ENTER("check_insert_fields");
+ List_iterator<Item> i_iter(values);
1. you don't use i_iter here 2. I'd move the loop into a separate function or a method of TABLE:
uint num_of_hiddens_fields() { for (...) }
see below
+ int num_of_hiddens_fields= 0; + if (!fields.elements) + { + Field ** f= table->field, *field; + for (; f && (field= *f); f++) + { + if (field->field_visibility != NOT_HIDDEN) + num_of_hiddens_fields++; + } + } if (!table_list->single_table_updatable()) { my_error(ER_NON_INSERTABLE_TABLE, MYF(0), table_list->alias, "INSERT"); @@ -212,7 +223,7 @@ static int check_insert_fields(THD *thd, TABLE_LIST *table_list, table_list->view_db.str, table_list->view_name.str); DBUG_RETURN(-1); } - if (values.elements != table->s->fields) + if (values.elements+num_of_hiddens_fields != table->s->fields)
then this if() becomes:
if (values.elements + num_of_hiddens_fields() != table->s->fields)
in fact, you can have a function that counts *visible* fields, then this if() becomes simply
if (values.elements != table->not_hidden_fields())
{ my_error(ER_WRONG_VALUE_COUNT_ON_ROW, MYF(0), 1L); DBUG_RETURN(-1); @@ -1485,7 +1497,28 @@ bool mysql_prepare_insert(THD *thd, TABLE_LIST *table_list, update_values, false, &map); select_lex->no_wrap_view_item= FALSE; } - + /* + Reason for this condition + suppose this + create table t1 (a int , b int , c int hidden , d int); + create view v as select a,b,c,d from t1; + now query like this fails + insert into v values(1,1,1) + because in insert_view_fields we copy all the fields + whether they are hidden or not we can not do the change + there because there we have only fields name so we need + to manually setup fields as insert_view_fields is called + by only mysql_prepare_insert_check_table function and + mysql_prepare_insert_check_table is called by only by this + function so it is safe to do here + + NOT YET IMPLEMENTED + if (insert_into_view && !is_field_specified_for_view + && fields.elements) + { + Item *ii= fields.pop(); + } + **/
1. I didn't understand the comment, couldn't parse it. Could you, please add some punctuation to it? :) 2. I believe you have a test case for it, and it works. Does it mean that the whole commented block is obsolete and should be removed? If yes, don't forget to remove is_field_specified_for_view declaration.
No It does not work. I will try to solve this. Actually the main problem is suppose create table t1(a int , b int , c int hidden, d int); create view v as select a,b,c,d from t1; then query like insert into t1 values(1,1,1); fails. The problem is desc v shows it is hidden. But it is not setting default values for field c
/* Restore the current context. */ ctx_state.restore_state(context, table_list); } diff --git a/sql/sql_update.cc b/sql/sql_update.cc index d59b8b7..dfe83e7 100644 --- a/sql/sql_update.cc +++ b/sql/sql_update.cc @@ -729,7 +729,17 @@ int mysql_update(THD *thd, */ can_compare_record= records_are_comparable(table); explain->tracker.on_scan_init(); - + for (uint i= 0; i < table->s->keys; i++) + { + if (table->key_info[i].flags & HA_UNIQUE_HASH) + { + if (!table->update_handler)
Can table->update_handler be possibly not NULL here?
No it cant be. Changed.
+ table->update_handler= table->file->clone(table->s->normalized_path.str, + &table->mem_root);
Note that you create this new handler on the table's memroot! This is wrong, as I've explained in an earlier review, memroot can only be freed as a whole, so by repeating UPDATE statements, you will allocate more and more memory in the table's memroot for update_handler's. You need to allocate it in the thd's memroot, because update_handler's has a life time of only one statement.
+ table->update_handler->ha_external_lock(current_thd, F_RDLCK); + break; + } + } while (!(error=info.read_record(&info)) && !thd->killed) { explain->tracker.on_record_read(); @@ -1912,6 +1929,19 @@ multi_update::initialize_tables(JOIN *join)
if (ignore) table->file->extra(HA_EXTRA_IGNORE_DUP_KEY); + + for (uint i= 0; i < table->s->keys; i++) + { + if (table->key_info[i].flags & HA_UNIQUE_HASH) + { + if (!table->update_handler) + table->update_handler= table->file->clone(table->s->normalized_path.str, + &table->mem_root); + table->update_handler->ha_external_lock(current_thd, F_RDLCK); + break; + } + }
same code as in mysql_update(), right? better move it to a small function. For example,
handler *create_update_handler(THD *thd, TABLE *table) { handler *update_handler= 0; for (uint i= 0; i < table->s->keys; i++) { if (table->key_info[i].flags & HA_UNIQUE_HASH) { update_handler= table->file->clone(table->s->normalized_path.str, &table->mem_root); update_handler->ha_external_lock(thd, F_RDLCK); return update_handler; } } return NULL; }
+ if (table == main_table) // First table in join { if (safe_update_on_fly(thd, join->join_tab, table_ref, all_tables)) @@ -2039,6 +2069,13 @@ multi_update::~multi_update() for (table= update_tables ; table; table= table->next_local) { table->table->no_keyread= table->table->no_cache= 0; + if (table->table->update_handler) + { + table->table->update_handler->ha_external_lock(current_thd, F_UNLCK); + table->table->update_handler->ha_close(); + delete table->table->update_handler; + table->table->update_handler= NULL; + }
same here:
void delete_update_handler(THD *thd, handler *h) { if (h) { h->ha_external_lock(thd, F_UNLCK); h->ha_close(); delete h; } }
by the way, try to avoid current_thd, if possible. it is farily expensive on some platforms.
Done
if (ignore) table->table->file->extra(HA_EXTRA_NO_IGNORE_DUP_KEY); } diff --git a/sql/unireg.cc b/sql/unireg.cc index 19d03d2..d502b68 100644 --- a/sql/unireg.cc +++ b/sql/unireg.cc @@ -89,6 +89,26 @@ static uchar *extra2_write(uchar *pos, enum extra2_frm_value_type type, return extra2_write(pos, type, reinterpret_cast
(str)); } +static uchar *extra2_write_field_visibility_hash_info(uchar *pos,
please, rename to extra2_write_additional_field_properties or something like that.
Done.
+ int number_of_fields,List_iterator
* it) +{ + *pos++=EXTRA2_FIELD_FLAGS; + /* + always 2 first for field visibility + second for is this column represent long unique hash + */ + size_t len = 2*number_of_fields; + pos= extra2_write_len(pos,len); + Create_field *cf; + while((cf=(*it)++)) + { + *pos++=cf->field_visibility; + *pos++=cf->is_long_column_hash; you can do one byte per field, field_visibility is only two bits, is_long_column_hash is one bit.
Okay , I tried this , but I am not sure if it is rigth or not.
+ } + return pos; +} + + /** Create a frm (table definition) file
@@ -121,6 +141,22 @@ LEX_CUSTRING build_frm_image(THD *thd, const char *table, uchar *frm_ptr, *pos; LEX_CUSTRING frm= {0,0}; DBUG_ENTER("build_frm_image"); + List_iterator
it(create_fields); + Create_field *field; + bool is_hidden_fields_present= false; please, rename to "have_additional_field_properties"
Okay.
+ /* + Loop througt the iterator to find whether we have any field whose + visibility_type != NOT_HIDDEN + */
Please remove the comment above. Remember, a comment needs to say *why* you are doing something, it should not say *what* you are doing. In this case your comment merely says what the loop below is doing, the comment is in English, the loop in C++, but otherwise they say exactly the same thing. If you rename the variable (as I suggested above) this loop will be completely clear without any comments anyway.
+ while ((field=it++)) + { + if (field->field_visibility != NOT_HIDDEN) + { + is_hidden_fields_present= true; + break; + } + } + it.rewind();
/* If fixed row records, we need one bit to check for deleted rows */ if (!(create_info->table_options & HA_OPTION_PACK_RECORD)) @@ -265,7 +303,9 @@ LEX_CUSTRING build_frm_image(THD *thd, const char *table, pos+= gis_field_options_image(pos, create_fields); } #endif /*HAVE_SPATIAL*/ - + if (is_hidden_fields_present) + pos=extra2_write_field_visibility_hash_info(pos,create_fields.elements,&it); + it.rewind();
you can rewind from inside extra2_write_field_visibility_hash_info. seems logical - it moves the iterator, it should restore it
Okay
int4store(pos, filepos); // end of the extra2 segment pos+= 4;
diff --git a/sql/sql_base.cc b/sql/sql_base.cc index 3481bf1..ce63a88 100644 --- a/sql/sql_base.cc +++ b/sql/sql_base.cc @@ -5287,6 +5287,8 @@ find_field_in_table(THD *thd, TABLE *table, const char *name, uint length,
if (field_ptr && *field_ptr) { + if ((*field_ptr)->field_visibility == FULL_HIDDEN) + DBUG_RETURN((Field*) 0);
good. please add a test case for that, with a subquery and an outer reference, as I wrote earlier.
Added , but there are some bugs,
*cached_field_index_ptr= field_ptr - table->field; field= *field_ptr; } @@ -7351,6 +7353,10 @@ insert_fields(THD *thd, Name_resolution_context *context, const char *db_name,
for (; !field_iterator.end_of_fields(); field_iterator.next()) { + /* Field can be null here details in test case*/
"details in test case" is not very helpful. in what case can field be 0 here?
Yes it can be Test case create table t1 (empnum smallint, grp int); create table t2 (empnum int, name char(5)); insert into t1 values(1,1); insert into t2 values(1,'bob'); create view v1 as select * from t2 inner join t1 using (empnum); select * from v1;
+ if ((field= field_iterator.field()) && + field->field_visibility != NOT_HIDDEN) + continue; Item *item;
if (!(item= field_iterator.create_item(thd))) @@ -7986,6 +7992,42 @@ fill_record(THD *thd, TABLE *table, Field **ptr, List<Item> &values, only one row. */ table->auto_increment_field_not_null= FALSE; + Field **f; + List_iterator<Item> i_iter(values); + uint field_count= 0; + for (f= ptr; f && (field= *f); f++) + field_count++; + /* + This if is required in query like + suppose table + create table t1 (a int , b int hidden , c int , d int hidden ); + and query is + create table t2 as select a,b,c,d from t1; + in this case field count will be equal to values.elements + */ + if (field_count != values.elements) + { + Name_resolution_context *context= & thd->lex->select_lex.context; + for (f= ptr; f && (field= *f); f++) + { + if (field->field_visibility!=NOT_HIDDEN) + { + if (f == ptr) + { + values.push_front(new (thd->mem_root) + Item_default_value(thd,context),thd->mem_root); + i_iter.rewind(); + i_iter++; + } + else + i_iter.after(new (thd->mem_root) Item_default_value(thd,context)); + } + else + i_iter++; + } + f= ptr; + i_iter.rewind(); + }
I don't understand what this is doing and why. Could you explain, please?
Actually comment is obsolute , so I removed It , It basically enter the deafult values in hidden fields For example Create table t1 (a int , b int hidden); insert into t1 value(1); here field_count is 2 but values count is 1 so I have to artifically enter default value.
while ((field = *ptr++) && ! thd->is_error()) { /* Ensure that all fields are from the same table */ diff --git a/sql/handler.cc b/sql/handler.cc index 3fbd1b3..99e043b 100644 --- a/sql/handler.cc +++ b/sql/handler.cc @@ -5875,6 +5883,132 @@ int handler::ha_reset() DBUG_RETURN(reset()); }
+/** @brief + check whether inserted/updated records breaks the + unique constraint on long columns. + In the case of update we just need to check the specic key + reason for that is consider case + create table t1(a blob , b blob , x blob , y blob ,unique(a,b) + ,unique(c,d)) + and update statement like this + update t1 set a=23+a; in this case if we try to scan for + whole keys in table then index scan on c_d will return 0 + because data is same so in the case of update we take + key as a parameter in normal insert key should be -1
Sorry, I didn't understand this comment. Could you rephrase it? btw, there are no columns 'c' and 'd' in your table example.
also, please, explain all function parameters here (use @param).
+ @returns 0 if no duplicate else returns error + */ +int check_duplicate_long_entries(TABLE *table, handler *h, uchar *new_rec, + int key) +{ + Field *hash_field; + int result; + table->dupp_key= -1; + for (uint i= 0; i < table->s->keys; i++) + { + if (key != -1) + i= key; + if (table->key_info[i].flags & HA_UNIQUE_HASH) + {
you invoke check_duplicate_long_entries() only in two places. one is in check_duplicate_long_entries_update(), inside the loop that checks for (table->key_info[i].flags & HA_UNIQUE_HASH). So I really don't see why you need to repeat this loop and the check here. The second invocation is in ha_write_row(), where key==-1 and you need a loop, indeed. So, the logical thing to do would be to have a function (let's call if F()) which is the content of this if() and always takes a valid key number as an argument. Then check_duplicate_long_entries() would do:
for (uint i= 0; i < table->s->keys; i++) { if (table->key_info[i].flags & HA_UNIQUE_HASH) F(table, h, new_rec, i); }
and check_duplicate_long_entries_update() would invoke F() directly.
also, note that if a function is only used in one file - like this your check_duplicate_long_entries(), it should be declared static.
+ hash_field= table->key_info[i].key_part->field; + DBUG_ASSERT(table->key_info[i].key_length == HA_HASH_KEY_LENGTH_WITH_NULL); + uchar ptr[HA_HASH_KEY_LENGTH_WITH_NULL]; + + if (hash_field->is_null()) + continue; + + key_copy(ptr, new_rec, &table->key_info[i], + table->key_info[i].key_length, false); + + if (!table->check_unique_buf) + table->check_unique_buf= (uchar *)alloc_root(&table->mem_root, + table->s->reclength*sizeof(uchar)); + + result= h->ha_index_read_idx_map(table->check_unique_buf, + i, ptr, HA_WHOLE_KEY, HA_READ_KEY_EXACT); + if (!result) + { + Item_func_or_sum * temp= static_cast
(hash_field-> + vcol_info->expr_item); + Item_args * t_item= static_cast (temp); + uint arg_count= t_item->argument_count(); + Item ** arguments= t_item->arguments(); + int diff= table->check_unique_buf-new_rec; + Field * t_field; + + for (uint j=0; j < arg_count; j++) + { Add DBUG_ASSERT(arguments[j]->type() == FIELD_ITEM);
+ t_field= static_cast
(arguments[j])->field; + if(t_field->cmp_binary_offset(diff)) + continue; + } + table->dupp_key= i; + if (!table->err_message) + { + table->err_message= (char *) alloc_root(&table->mem_root, + MAX_KEY_LENGTH); + } + StringBuffer str; + str.length(0); + for(uint i= 0; i < arg_count; i++) + { + t_field= ((Item_field *)arguments[i])->field; + if (str.length()) + str.append('-'); + field_unpack(&str, t_field, new_rec, 5,//since blob can be to long + false); truncation is a great idea. Two comments: 1. make this 5 a defined constant. Like
#define MAX_BLOB_LEN_FOR_ERRMSG 5
2. perhaps 5 is too short? dunno. 3. indicate the truncation. Like
if (t_field->pack_length() > MAX_BLOB_LEN_FOR_ERRMSG) str.append(STRING_WITH_LEN("..."));
TODO
+ } + memcpy(table->err_message,str.ptr(),str.length()); + return HA_ERR_FOUND_DUPP_KEY; + } + } + if (key != -1) + break; + } + return 0; +} + +/** @brief + check whether updated records breaks the + unique constraint on long columns. + @returns 0 if no duplicate else returns error + */ +int check_duplicate_long_entries_update(TABLE *table, handler *h, uchar *new_rec) +{ + Field **f, *field; + LEX_STRING *ls; + int error; + /* + Here we are comparing whether new record and old record are same + with respect to fields in hash_str + */ + long reclength= table->record[1]-table->record[0]; + for (uint i= 0; i < table->s->keys; i++) + { + if (table->key_info[i].flags & HA_UNIQUE_HASH) + { + ls= &table->key_info[i].key_part->field->vcol_info->expr_str; + for (f= table->field; f && (field= *f); f++) + { + if (find_field_name_in_hash(ls->str, (char *)field->field_name, ls->length) != -1)
ok, I'm confused. Why are you doing that? For INSERT you take the HASH Item and iterate its argument array. That's fine, I get it. For UPDATE you get the vcol expression as a *string* (!!!) and extract column names from there by looking at commas (???). What was that?
+ { + /* Compare fields if they are different then check for duplicates*/ + if(field->cmp_binary_offset(reclength)) + { + if((error= check_duplicate_long_entries(table, table->update_handler, + new_rec, i))) + return error; + /* + break beacuse check_duplicate_long_entries will + take care of remaning fields + */ + break; + } + } + } + } + } + return 0; +}
int handler::ha_write_row(uchar *buf) { @@ -5921,6 +6057,8 @@ int handler::ha_update_row(const uchar *old_data, uchar *new_data)
note that mysql_update can use ha_bulk_update_row() instead of ha_update_row() for some storage engine. I don't think bulk update can work with your code at all, so you need to make sure will_batch is always false if long unique indexes are used (this is easy). See sql_update.cc
And there's bulk insert too, start_bulk_insert(), that you probably need to disable as well.
TODO
mark_trx_read_write(); increment_statistics(&SSV::ha_update_count);
+ if ((error= check_duplicate_long_entries_update(table, table->file, new_data))) + return error; TABLE_IO_WAIT(tracker, m_psi, PSI_TABLE_UPDATE_ROW, active_index, 0, { error= update_row(old_data, new_data);})
diff --git a/sql/sql_show.cc b/sql/sql_show.cc index 30c65e6..a55cccd 100644 --- a/sql/sql_show.cc +++ b/sql/sql_show.cc @@ -1972,6 +1976,25 @@ int show_create_table(THD *thd, TABLE_LIST *table_list, String *packet, } append_create_options(thd, packet, field->option_list, check_options, hton->field_options); + //TODO need a better logic to find wheter to put comma or not + int i=1; + bool is_comma_needed=false; + if (*(ptr+i)!=NULL) + { + is_comma_needed=true; + while((*(ptr+i))->field_visibility==MEDIUM_HIDDEN || + (*(ptr+i))->field_visibility==FULL_HIDDEN) + { + i++; + if(!*(ptr+i)) + { + is_comma_needed =false; + break; + } + } + } + if(is_comma_needed) + packet->append(STRING_WITH_LEN(",\n"));
What was wrong with the old logic? Print the comma before every visible column, excluding the first one. You only need to replace the "first one" condition, like
- if (ptr != table->field) + if (not_the_first_field) packet->append(STRING_WITH_LEN(",\n")); + not_the_first_field= true;
Changed.
}
key_info= table->key_info; @@ -1986,6 +2009,19 @@ int show_create_table(THD *thd, TABLE_LIST *table_list, String *packet, for (uint i=0 ; i < share->keys ; i++,key_info++) { KEY_PART_INFO *key_part= key_info->key_part; + if (key_info->flags & HA_UNIQUE_HASH) + { + char * column_names= key_part->field->vcol_info-> + expr_str.str + HA_HASH_STR_LEN; + int length= key_part->field->vcol_info->expr_str.length; + length-= HA_HASH_STR_LEN; + packet->append(STRING_WITH_LEN(",\n")); + packet->append(STRING_WITH_LEN(" UNIQUE KEY `")); + packet->append(key_info->name, strlen(key_info->name)); + packet->append(STRING_WITH_LEN("`")); + packet->append(column_names, length);
No, I'm afraid you cannot do that. You need to generate the column list by iterating arguments and printing them. Add this test case to your long_uniques.test:
create table t1 (a int, b int, c blob, d blob, unique(a,b), unique(c,d)); set sql_quote_show_create=0; show create table t1; set sql_quote_show_create=default; show create table t1; set sql_mode=ansi_quotes; show create table t1; set sql_mode=default;
(you don't need create table as above, of course, you can use any existing table in the test file).
Changed, Now it uses old logic.
+ continue; + } bool found_primary=0; packet->append(STRING_WITH_LEN(",\n "));
@@ -5411,6 +5447,10 @@ static int get_schema_column_record(THD *thd, TABLE_LIST *tables,
for (; (field= *ptr) ; ptr++) { + if(field->field_visibility == FULL_HIDDEN || + field->field_visibility == MEDIUM_HIDDEN) + continue; + /* For now we will only show UNI or MUL for TODO */
what do you mean by this comment?
It says I have to setup MUL and UNI for desc table having blob unique columns.
uchar *pos; char tmp[MAX_FIELD_WIDTH]; String type(tmp,sizeof(tmp), system_charset_info); @@ -5465,20 +5505,48 @@ static int get_schema_column_record(THD *thd, TABLE_LIST *tables, pos=(uchar*) ((field->flags & PRI_KEY_FLAG) ? "PRI" : (field->flags & UNIQUE_KEY_FLAG) ? "UNI" : (field->flags & MULTIPLE_KEY_FLAG) ? "MUL":""); + KEY *key= show_table->key_info; + for (int i=0; i
s->keys; i++, key++) + { + if (key->flags & HA_UNIQUE_HASH) + { + LEX_STRING * ls= &key->key_part->field->vcol_info->expr_str; + int position= find_field_index_in_hash(ls, field->field_name); + int fields= fields_in_hash_str(ls); + //this is for single hash(`abc`) + if (position == 0 && fields == 1) + { + pos= (uchar *) "UNI"; + } + //this is for hash(`abc`,`xyzs`) + if (position == 0 && fields > 1) + { + pos=(uchar *) "MUL"; + } + } + } really? why wouldn't you set UNIQUE_KEY_FLAG or MULTIPLE_KEY_FLAG instead so that the old code would just work for your new keys?
Done.
table->field[16]->store((const char*) pos, strlen((const char*) pos), cs); - + StringBuffer<256> buf; if (field->unireg_check == Field::NEXT_NUMBER) - table->field[17]->store(STRING_WITH_LEN("auto_increment"), cs); + buf.set(STRING_WITH_LEN("auto_increment"),cs); if (print_on_update_clause(field, &type, true)) - table->field[17]->store(type.ptr(), type.length(), cs); + buf.set(type.ptr(), type.length(),cs); if (field->vcol_info) { if (field->vcol_info->stored_in_db) - table->field[17]->store(STRING_WITH_LEN("PERSISTENT"), cs); + buf.set(STRING_WITH_LEN("PERSISTENT"), cs); else - table->field[17]->store(STRING_WITH_LEN("VIRTUAL"), cs); + buf.set(STRING_WITH_LEN("VIRTUAL"), cs); + } + /*hidden can coexist with auto_increment and virtual */ + if(field->field_visibility==USER_DEFINED_HIDDEN) + { + if (buf.length()) + buf.append(STRING_WITH_LEN(" , "));
no space before the comma
Changed.
+ buf.append(STRING_WITH_LEN("HIDDEN"),cs); } + table->field[17]->store(buf.ptr(), buf.length(), cs); table->field[19]->store(field->comment.str, field->comment.length, cs); if (schema_table_store_record(thd, table)) DBUG_RETURN(1); @@ -6030,6 +6098,89 @@ int fill_schema_proc(THD *thd, TABLE_LIST *tables, COND *cond) DBUG_RETURN(res); }
+static int print_get_schema_stat_keypart(THD *thd, TABLE_LIST *tables, + TABLE *table,TABLE *show_table, + LEX_STRING *db_name, + LEX_STRING *table_name, + KEY * key_info,KEY_PART_INFO + *key_part,Field * field ,int i,int j)
1. lots of tabs above that mess up the indentation. 2. Function comment, please. 3. i and j are *really* lousy argument names, please rename.
Removed this whole function.
+{ + CHARSET_INFO *cs= system_charset_info; + const char *str; + restore_record(table, s->default_values); + table->field[0]->store(STRING_WITH_LEN("def"), cs); + table->field[1]->store(db_name->str, db_name->length, cs); + table->field[2]->store(table_name->str, table_name->length, cs); + table->field[3]->store((longlong) ((key_info->flags & + HA_NOSAME) ? 0 : 1), TRUE); + table->field[4]->store(db_name->str, db_name->length, cs); + table->field[5]->store(key_info->name, strlen(key_info->name), cs); + table->field[6]->store((longlong) (j+1), TRUE); + str=field ? field->field_name :"?unknown field?"; + table->field[7]->store(str, strlen(str), cs); + if (show_table->file) + { + if (show_table->file->index_flags(i, j, 0) & HA_READ_ORDER) + { + table->field[8]->store(((key_part->key_part_flag & + HA_REVERSE_SORT) ? + "D" : "A"), 1, cs); + table->field[8]->set_notnull(); + } + KEY *key=show_table->key_info+i; + if (key->rec_per_key[j]) + { + ha_rows records= (ha_rows) ((double) show_table->stat_records() / + key->actual_rec_per_key(j)); + table->field[9]->store((longlong) records, TRUE); + table->field[9]->set_notnull(); + } + /* + In the case of long unique hash as we try + to calc key->rec_per_key[j] it will give zero + so cardinality will be set to null we do not want + this so + */
why not? if you don't know the cardinality - set it to NULL. but, in fact, it shouldn't be zero, why is it?
+ if (key_info->flags & HA_UNIQUE_HASH) + { + table->field[9]->store(0, TRUE); + table->field[9]->set_notnull(); + } + if (key_info->flags & HA_UNIQUE_HASH) + table->field[13]->store(HA_HASH_STR_INDEX,HA_HASH_STR_INDEX_LEN , cs);
I don't think you need to define that string, just put it here like
table->field[13]->store(STRING_WITH_LEN("HASH_INDEX") , cs);
+ else + { + str= show_table->file->index_type(i); + table->field[13]->store(str, strlen(str), cs); + } + } + if (!(key_info->flags & HA_FULLTEXT) && + (key_part->field && + key_part->length != + show_table->s->field[key_part->fieldnr-1]->key_length())) + { + table->field[10]->store((longlong) key_part->length / + key_part->field->charset()->mbmaxlen, TRUE); + table->field[10]->set_notnull(); + } + uint flags= key_part->field ? key_part->field->flags : 0; + const char *pos=(char*) ((flags & NOT_NULL_FLAG) ? "" : "YES"); + table->field[12]->store(pos, strlen(pos), cs); + if (!show_table->s->keys_in_use.is_set(i)) + table->field[14]->store(STRING_WITH_LEN("disabled"), cs); + else + table->field[14]->store("", 0, cs); + table->field[14]->set_notnull(); + DBUG_ASSERT(MY_TEST(key_info->flags & HA_USES_COMMENT) == + (key_info->comment.length > 0)); + if (key_info->flags & HA_USES_COMMENT) + table->field[15]->store(key_info->comment.str, + key_info->comment.length, cs); + if (schema_table_store_record(thd, table)) + return 1; + return 0; +} +
static int get_schema_stat_record(THD *thd, TABLE_LIST *tables, TABLE *table, bool res, @@ -6066,67 +6217,34 @@ static int get_schema_stat_record(THD *thd, TABLE_LIST *tables, HA_STATUS_TIME); set_statistics_for_table(thd, show_table); } for (uint i=0 ; i < show_table->s->keys ; i++, key_info++) { KEY_PART_INFO *key_part= key_info->key_part; - const char *str; for (uint j=0 ; j < key_info->user_defined_key_parts; j++, key_part++) { - restore_record(table, s->default_values); - table->field[0]->store(STRING_WITH_LEN("def"), cs); - table->field[1]->store(db_name->str, db_name->length, cs); - table->field[2]->store(table_name->str, table_name->length, cs); - table->field[3]->store((longlong) ((key_info->flags & - HA_NOSAME) ? 0 : 1), TRUE); - table->field[4]->store(db_name->str, db_name->length, cs); - table->field[5]->store(key_info->name, strlen(key_info->name), cs); - table->field[6]->store((longlong) (j+1), TRUE); - str=(key_part->field ? key_part->field->field_name : - "?unknown field?"); - table->field[7]->store(str, strlen(str), cs); - if (show_table->file) + + if (key_info->flags & HA_UNIQUE_HASH && key_info->key_part->field) { - if (show_table->file->index_flags(i, j, 0) & HA_READ_ORDER) + LEX_STRING *ls = &key_info->key_part->field->vcol_info->expr_str; + int total_fields= fields_in_hash_str(ls); + int counter= 0; + Field *fld; + while (counter < total_fields) { - table->field[8]->store(((key_part->key_part_flag & - HA_REVERSE_SORT) ? - "D" : "A"), 1, cs); - table->field[8]->set_notnull(); - } - KEY *key=show_table->key_info+i; - if (key->rec_per_key[j]) - { - ha_rows records= (ha_rows) ((double) show_table->stat_records() / - key->actual_rec_per_key(j)); - table->field[9]->store((longlong) records, TRUE); - table->field[9]->set_notnull(); + fld= field_ptr_in_hash_str(ls, show_table, counter);
parsing strings, again? don't do that, please.
+ if(print_get_schema_stat_keypart(thd, tables, table, + show_table, db_name, + table_name, key_info, + key_part, fld, i, counter)) + DBUG_RETURN(1); + counter++; } - str= show_table->file->index_type(i); - table->field[13]->store(str, strlen(str), cs); - } - if (!(key_info->flags & HA_FULLTEXT) && - (key_part->field && - key_part->length != - show_table->s->field[key_part->fieldnr-1]->key_length())) - { - table->field[10]->store((longlong) key_part->length / - key_part->field->charset()->mbmaxlen, TRUE); - table->field[10]->set_notnull(); + + continue; } - uint flags= key_part->field ? key_part->field->flags : 0; - const char *pos=(char*) ((flags & NOT_NULL_FLAG) ? "" : "YES"); - table->field[12]->store(pos, strlen(pos), cs); - if (!show_table->s->keys_in_use.is_set(i)) - table->field[14]->store(STRING_WITH_LEN("disabled"), cs); - else - table->field[14]->store("", 0, cs); - table->field[14]->set_notnull(); - DBUG_ASSERT(MY_TEST(key_info->flags & HA_USES_COMMENT) == - (key_info->comment.length > 0)); - if (key_info->flags & HA_USES_COMMENT) - table->field[15]->store(key_info->comment.str, - key_info->comment.length, cs); - if (schema_table_store_record(thd, table)) + + if(print_get_schema_stat_keypart(thd, tables,table,show_table,db_name, + table_name,key_info,key_part,key_part->field,i,j)) DBUG_RETURN(1); } } @@ -6134,7 +6252,6 @@ static int get_schema_stat_record(THD *thd, TABLE_LIST *tables, DBUG_RETURN(res); }
-
add the empty line back, please
static int get_schema_views_record(THD *thd, TABLE_LIST *tables, TABLE *table, bool res, LEX_STRING *db_name, diff --git a/sql/table.cc b/sql/table.cc index 640ab82..5d5be01 100644 --- a/sql/table.cc +++ b/sql/table.cc @@ -685,7 +685,7 @@ static bool create_key_infos(const uchar *strpos, const uchar *frm_image_end, uint keys, KEY *keyinfo, uint new_frm_ver, uint &ext_key_parts, TABLE_SHARE *share, uint len, - KEY *first_keyinfo, char* &keynames) + KEY *first_keyinfo, char* &keynames,const uchar *key_ex_flags)
this new argument seems to be unused
Reverted, was used in previous versions.
{ uint i, j, n_length; KEY_PART_INFO *key_part= NULL; @@ -738,7 +738,6 @@ static bool create_key_infos(const uchar *strpos, const uchar *frm_image_end, keyinfo->algorithm= HA_KEY_ALG_UNDEF; strpos+=4; } -
don't delete empty lines, please, restore them all
if (i == 0) { ext_key_parts+= (share->use_ext_keys ? first_keyinfo->user_defined_key_parts*(keys-1) : 0); @@ -801,7 +799,8 @@ static bool create_key_infos(const uchar *strpos, const uchar *frm_image_end, keyinfo->ext_key_parts= keyinfo->user_defined_key_parts; keyinfo->ext_key_flags= keyinfo->flags; keyinfo->ext_key_part_map= 0; - if (share->use_ext_keys && i && !(keyinfo->flags & HA_NOSAME)) + if (share->use_ext_keys && i && !(keyinfo->flags & HA_NOSAME) + )
revert
{ for (j= 0; j < first_key_parts && keyinfo->ext_key_parts < MAX_REF_PARTS; @@ -989,6 +988,7 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, const uchar *frm_image_end = frm_image + frm_length; uchar *record, *null_flags, *null_pos, *mysql57_vcol_null_pos; const uchar *disk_buff, *strpos; + const uchar * field_properties=NULL,*key_ex_flags=NULL;
this key_ex_flags is not used for anything
ulong pos, record_offset; ulong rec_buff_length; handler *handler_file= 0; @@ -1056,7 +1056,7 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, if (length < 256) goto err; } - if (extra2 + length > e2end) + if ( extra2 + length > e2end)
revert
goto err; switch (type) { case EXTRA2_TABLEDEF_VERSION: @@ -1101,6 +1101,9 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, } #endif /*HAVE_SPATIAL*/ break; + case EXTRA2_FIELD_FLAGS: + field_properties = extra2;
imagine in some later MariaDB version we'll need more flags. there may be more than two bytes per column. so here you can check the length and fail with an error (no assert!) if it's not num_of_fields*2.
Added.
+ break; default: /* abort frm parsing if it's an unknown but important extra2 value */ if (type >= EXTRA2_ENGINE_IMPORTANT) @@ -1795,6 +1797,16 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, reg_field->field_index= i; reg_field->comment=comment; reg_field->vcol_info= vcol_info; + if(field_properties!=NULL) + { + reg_field->field_visibility=static_cast
(*field_properties++); + reg_field->is_long_column_hash=static_cast<bool>(*field_properties++); why did you need a cast here? was there compiler warning?
Changed.
+ } + /* + We will add status variable only when we find a user defined hidden column
"increment". or, better, remove this comment completely, it's obvious anyway
Removed
+ */ + if (reg_field->field_visibility == USER_DEFINED_HIDDEN) + status_var_increment(thd->status_var.feature_hidden_column); if (field_type == MYSQL_TYPE_BIT && !f_bit_as_char(pack_flag)) { null_bits_are_used= 1; @@ -2004,13 +2016,27 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write,
field= key_part->field= share->field[key_part->fieldnr-1]; key_part->type= field->key_type(); + /* + Add HA_UNIQUE_HASH flag if keyinfo has only one field + and field has is_long_column_hash flag on + */ + if (keyinfo->user_defined_key_parts == 1 && + field->is_long_column_hash) + { + keyinfo->flags|= HA_UNIQUE_HASH; + keyinfo->ext_key_flags|= HA_UNIQUE_HASH;
why do you set it in ext_key_flags?
It was used in optimizer. Anyway new version does not use this code.
+ } if (field->null_ptr) { key_part->null_offset=(uint) ((uchar*) field->null_ptr - share->default_values); key_part->null_bit= field->null_bit; key_part->store_length+=HA_KEY_NULL_LENGTH; - keyinfo->flags|=HA_NULL_PART_KEY; + if (keyinfo->flags & HA_UNIQUE_HASH && + !(keyinfo->flags & HA_NULL_PART_KEY)) + {} + else + keyinfo->flags|=HA_NULL_PART_KEY;
1. why not simply
if (!(keyinfo->flags & HA_UNIQUE_HASH)) keyinfo->flags|=HA_NULL_PART_KEY;
Actually this was more complex. If keyinfo does not have HA_NULL_PART_KEY flag for HA_UNIQUE_HASH , then this means Key can not be null. But removed this in newer version.
2. this needs a comment
keyinfo->key_length+= HA_KEY_NULL_LENGTH; } if (field->type() == MYSQL_TYPE_BLOB || @@ -2124,6 +2149,11 @@ int TABLE_SHARE::init_from_binary_frm_image(THD *thd, bool write, if ((keyinfo->flags & HA_NOSAME) || (ha_option & HA_ANY_INDEX_MAY_BE_UNIQUE)) set_if_bigger(share->max_unique_length,keyinfo->key_length); + if (keyinfo->flags & HA_UNIQUE_HASH) + { + keyinfo->ext_key_parts= 1; + keyinfo->ext_key_part_map= 0; + }
why?
This is a create_key_info code. if (share->use_ext_keys && i && !(keyinfo->flags &HA_NOSAME)) { for (j= 0; j < first_key_parts && keyinfo->ext_key_parts < MAX_REF_PARTS; j++) { uint key_parts= keyinfo->user_defined_key_parts; KEY_PART_INFO* curr_key_part= keyinfo->key_part; KEY_PART_INFO* curr_key_part_end= curr_key_part+key_parts; for ( ; curr_key_part < curr_key_part_end; curr_key_part++) { if (curr_key_part->fieldnr == first_key_part[j].fieldnr) break; } if (curr_key_part == curr_key_part_end) { *key_part++= first_key_part[j]; *rec_per_key++= 0; keyinfo->ext_key_parts++; keyinfo->ext_key_part_map|= 1 << j; } } if (j == first_key_parts) keyinfo->ext_key_flags= keyinfo->flags | HA_EXT_NOSAME; hash key_info does not have HA_NOSAME flag so, its keyinfo->ext_key_parts is added. But we do not want this. Anyway removed this in new version. Now HA_UNIQUE_HASH key also have HA_NOSAME flag.
} if (primary_key < MAX_KEY && (share->keys_in_use.is_set(primary_key))) @@ -7808,3 +7842,193 @@ double KEY::actual_rec_per_key(uint i) return (is_statistics_from_stat_tables ? read_stats->get_avg_frequency(i) : (double) rec_per_key[i]); } + +/* + find out that whether field name exists in hash_str + return index of hash_str if found other wise returns + -1 +*/ +int find_field_name_in_hash(char * hash_str, const char * field_name, + int hash_str_length)
ok, all these manipulations with the expression *string* should be removed. Column names might contain commas, column names might contain backticks - you don't handle that. And you should not, really, don't use vcol_info->expr_str, use vcol_info->expr_item instead.
Removed. Now I use expr_item.
+{ + + int j= 0, i= 0; + for (i= 0; i < hash_str_length; i++) + { + while (*(hash_str+i) == *(field_name+j)) + { + i++; + j++; + if(*(field_name+j)=='\0' &&*(hash_str+i)=='`') + goto done; + } + j=0; + } + return -1; + done: + return i; +} + +/* + find out the field positoin in hash_str() + position starts from 0 + else return -1; +*/ +int find_field_index_in_hash(LEX_STRING *hash_lex, const char * field_name) +{ + char *hash_str= hash_lex->str; + int hash_str_length= hash_lex->length; + int field_name_position= find_field_name_in_hash(hash_str, field_name, hash_str_length); + if (field_name_position == -1) + return -1; + int index= 0; + for (int i= 0; i < field_name_position; i++) + { + if (hash_str[i] == ',') + index++; + } + return index; +} + +/* + find total number of field in hash_str +*/ +int fields_in_hash_str(LEX_STRING * hash_lex) +{ + int hash_str_length= hash_lex->length; + char *hash_str= hash_lex->str; + int num_of_fields= 1; + for (int i= 0; i
str; + int i= strlen("hash"), j; + Field **f, *field; + while (i < hash_str->length) + { + if (str[i] == ',') + temp_index++; + if (temp_index >= index) + break; + i++; + } + i+= 2; // now i point to first character of field name + for (j= 0; str[i+j] != '`'; j++) + field_name[j]= str[i+j]; + field_name[j]= '\0'; + for (f= table->field; f && (field= *f); f++) + { + if (!my_strcasecmp(system_charset_info, field->field_name, field_name)) + break; + } + return field; +} + +/* + Remove field name from db_row_hash_* column vcol info str + For example + + hash(`abc`,`xyz`) + remove "abc" will return + 0 and hash_str will be set hash(`xyz`) and length will be set + + hash(`xyz`) + remove "xyz" will return + 0 and hash_str will be set NULL and length will be 0 + hash(`xyz`) + remove "xyzff" will return + 1 no change to hash_str and length + TODO a better and less complex logic +*/ +int rem_field_from_hash_col_str(LEX_STRING * hash_lex, const char * field_name) +{ + /* first of all find field_name in hash_str*/ + char * temp= hash_lex->str; + const char * t_field= field_name; + int i= find_field_name_in_hash(temp, field_name, hash_lex->length); + if ( i != -1) + { + /* + We found the field location + First of all we need to find the + , position and there can be three + situations + 1. two , not a problem remove any one + 2. one , remove this + 3 no , return + */ + // see if there is , before field name + int j= strlen(field_name); + if (*(temp + i -j-2) == ',') + { + hash_lex->length= hash_lex->length- j-2-1;//-2 for two '`' and -1 for ',' + memmove(temp+i-j-2, temp+i+1, hash_lex->length); + return 0; + } + if (*(temp+i+1) == ',') + { + hash_lex->length= hash_lex->length-j-2-1;//-2 for two '`' and -1 for ',' + memmove(temp+i-j-1, temp+i+2, hash_lex->length); + return 0; + } + if (*(temp+i+1) == ')') + { + hash_lex->length= 0; + hash_lex->str= NULL; + return 0; + } + } + return 1; +} +/* returns 1 if old_name not found in hash_lex 0 other wise*/ +int change_field_from_hash_col_str(LEX_STRING * hash_lex, const char * old_name, + char * new_name) +{ + /* first of all find field_name in hash_lex*/ + char * temp= hash_lex->str; + const char * t_field= old_name; + int i= find_field_name_in_hash(temp, old_name, hash_lex->length); + if (i != -1) + { + int len= hash_lex->length-strlen(old_name) + strlen(new_name); + int num= 0; + char temp_arr[len]; + int s_c_position= i - strlen(old_name);//here it represent the posotion of + //'`' before old f_name + for (int index= 0; index < len; index++) + { + if (index >= s_c_position && index < s_c_position+strlen(new_name)) + { + temp_arr[index]= new_name[index-s_c_position]; + continue; + } + if (index >= s_c_position+strlen(new_name)) + { + temp_arr[index]= temp[i+num]; + num++; + continue; + } + temp_arr[index]= temp[index]; + } + strcpy(hash_lex->str, temp_arr); + hash_lex->length= len; + return 0; + } + return 1; +} diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 5cc7798..921cf18 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc this is impressive :) but to send you something sooner, I'm going to skip your optimizer changes now, I'll send the review of the original project (long UNIQUE constraint) first, then I'll finish the review of the optimizer part.
diff --git a/sql/sql_table.cc b/sql/sql_table.cc index e745fe8..ed8aa8f 100644 --- a/sql/sql_table.cc +++ b/sql/sql_table.cc @@ -3186,6 +3186,177 @@ static void check_duplicate_key(THD *thd, } }
+/* + Add hidden level 3 hash field to table in case of long + unique column + Returns 0 on success + else 1 +*/ + +int add_hash_field(THD * thd, Alter_info *alter_info, Key *current_key, + KEY *current_key_info, KEY *key_info, CHARSET_INFO *cs)
should be declared static
Done.
+{ + int num= 1; + List_iterator<Key> key_iter(alter_info->key_list); + List_iterator
key_part_iter(current_key->columns); + List_iterator it(alter_info->create_list); + Create_field *dup_field, * sql_field; + Key_part_spec *temp_colms; + + Create_field *cf= new (thd->mem_root) Create_field(); + cf->flags|= UNSIGNED_FLAG; + cf->length= cf->char_length= HA_HASH_FIELD_LENGTH; + cf->charset= NULL; + cf->decimals= 0; + char *temp_name= (char *)thd->alloc(30); + strcpy(temp_name, HA_DB_ROW_HASH_STR); + char num_holder[10]; //10 is way more but i think it is ok + sprintf(num_holder, "%d",num); + strcat(temp_name, num_holder); 1. my_snprintf, not sprintf. for just one number - strtol 2. "%u" not "%d" 3. with sprintf, you don't need strcat:
my_snprintf(temp_name, sizeof(temp_name), "DB_ROW_HASH_%u", num);
Okay , Changed.
+ /* + Check for collusions + */ + while ((dup_field= it++)) + { + if (!my_strcasecmp(system_charset_info, temp_name, dup_field->field_name)) + { + temp_name[12]= '\0'; //now temp_name='DB_ROW_HASH_' + num++; + sprintf(num_holder, "%d",num); + strcat(temp_name, num_holder); + it.rewind(); + } + } + it.rewind(); + cf->field_name= temp_name; + cf->sql_type= MYSQL_TYPE_LONGLONG; + /* hash column should be atmost hidden */
should be "fully hidden"
Changed
+ cf->field_visibility= FULL_HIDDEN; + cf->is_long_column_hash= true; + /* add the virtual colmn info */ + Virtual_column_info *v= new (thd->mem_root) Virtual_column_info(); + char * hash_exp= (char *)thd->alloc(1024); + char * key_name= (char *)thd->alloc(252); + strcpy(hash_exp, HA_HASH_STR_HEAD); + temp_colms= key_part_iter++; + strcat(hash_exp, temp_colms->field_name.str); + strcpy(key_name, temp_colms->field_name.str); + strcat(hash_exp, "`"); + while ((temp_colms= key_part_iter++)) + { + while ((sql_field= it++) && + my_strcasecmp(system_charset_info, + temp_colms->field_name.str, sql_field->field_name)) + {} + it.rewind(); + /* + There should be only one key for db_row_hash_* column + we need to give user a error when the accidently query + like + + create table t1(abc blob unique, unique(db_row_hash_1)); + alter table t2 add column abc blob unique,add unique key(db_row_hash_1); + + for this we will iterate through the key_list and + find if and key_part has the same name as of temp_name + */ + if (!sql_field || sql_field->is_long_column_hash) + { + my_error(ER_KEY_COLUMN_DOES_NOT_EXITS, MYF(0), temp_name); + return 1; + }
hmm, are you sure this check is needed? you've just added a column, there can be no existing key that refers to it, can it?
Or, may be, you added a column before the code that checks whether a key is valid? In that case, that code will still fail with ER_KEY_COLUMN_DOES_NOT_EXITS, because your column is fully hidden.
Either way, your check looks redundant.
Removed this whole part.
+ /* + This test for wrong query like + create table t1(a blob ,unique(a,a)); + */ + if (find_field_name_in_hash(hash_exp, + temp_colms->field_name.str, strlen(hash_exp))!=-1) + { + my_error(ER_DUP_FIELDNAME, MYF(0), temp_colms->field_name.str); + return 1; + } + /* If any field can be null add flag */ + if (!sql_field->flags & NOT_NULL_FLAG) + current_key_info->flags|= HA_NULL_PART_KEY; + strcat(hash_exp, (const char * )","); + strcat(key_name, "_"); + strcat(hash_exp, "`"); + strcat(hash_exp, temp_colms->field_name.str); + strcat(key_name, temp_colms->field_name.str); + strcat(hash_exp, "`");
1. hash_exp is generated incorrectly, you forgot that a column name itself can contain backticks. There are quoting functions in sql_show.cc and as my_snprintf("%`s")
Changed.
2. do you really need to create a true virtual column here, with the hash expression and store it in the frm? you can store the key as a normal key (with actual blobs, not uint for the hash value), and generate the vcol in init_from_binary_frm_image().
This is a big change. Took me 3-4 days , But anyway done.
+ } + strcat(hash_exp, (const char * )")"); + v->expr_str.str= hash_exp; + v->expr_str.length= strlen(hash_exp); + v->expr_item= NULL; + v->set_stored_in_db_flag(true); + cf->vcol_info= v; + cf->charset= cs; + cf->create_length_to_internal_length(); + cf->length= cf->char_length= cf->pack_length; + prepare_create_field(cf, NULL, 0); + if (!current_key_info->flags & HA_NULL_PART_KEY) + { + cf->pack_flag^= FIELDFLAG_MAYBE_NULL; + cf->flags^= NOT_NULL_FLAG; + } + alter_info->create_list.push_front(cf,thd->mem_root); + /* Update row offset because field is added in first position */ + int offset=0; + it.rewind(); + while ((dup_field= it++)) + { + dup_field->offset= offset; + if (dup_field->stored_in_db()) + offset+= dup_field->pack_length; + } + it.rewind(); + while ((dup_field= it++)) + { + if (!dup_field->stored_in_db()) + { + dup_field->offset= offset; + offset+= dup_field->pack_length; + } + } + if(current_key->name.length==0) + { + current_key_info->name= key_name; + current_key_info->name_length= strlen(key_name); + key_name= make_unique_key_name(thd, key_name, + key_info, current_key_info); + } + else + current_key_info->name= current_key->name.str; + if (check_if_keyname_exists(current_key_info->name, key_info, + current_key_info)) + { + my_error(ER_DUP_KEYNAME, MYF(0), key_name); + return 1; + } + current_key->type= Key::MULTIPLE; + current_key_info->key_length= cf->pack_length; //length of mysql long column + current_key_info->user_defined_key_parts= 1; + current_key_info->flags= 0; + current_key_info->key_part->fieldnr= 0; + current_key_info->key_part->offset= 0; + current_key_info->key_part->key_type= cf->pack_flag; + current_key_info->key_part->length= cf->pack_length; + /* As key is added in front so update update keyinfo field ref and offset*/ + KEY * t_key = key_info; + KEY_PART_INFO *t_key_part; + while (t_key != current_key_info) + { + t_key_part= t_key->key_part; + for (int i= 0; i < t_key->user_defined_key_parts; i++,t_key_part++) + { + t_key_part->fieldnr+= 1; + t_key_part->offset+= cf->pack_length; + } + t_key++; + } + return 0; +}
/* Preparation for table creation @@ -3283,7 +3454,13 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, /* Fix for prepare statement */ thd->change_item_tree(&sql_field->default_value->expr_item, item); } - + if (sql_field->field_visibility == USER_DEFINED_HIDDEN && + sql_field->flags & NOT_NULL_FLAG && + sql_field->flags & NO_DEFAULT_VALUE_FLAG) + { + my_error(ER_HIDDEN_NOT_NULL_WOUT_DEFAULT, MYF(0), sql_field->field_name);
say "WITHOUT", this "WOUT" looks weird
Changed, I thought short form will work.
+ DBUG_RETURN(TRUE); + } if (sql_field->sql_type == MYSQL_TYPE_SET || sql_field->sql_type == MYSQL_TYPE_ENUM) { @@ -3884,10 +4070,24 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, if (f_is_geom(sql_field->pack_flag) && sql_field->geom_type == Field::GEOM_POINT) column->length= MAX_LEN_GEOM_POINT_FIELD; - if (!column->length) - { - my_error(ER_BLOB_KEY_WITHOUT_LENGTH, MYF(0), column->field_name.str); - DBUG_RETURN(TRUE); + if (!column->length) + { + if (key->type == Key::PRIMARY) + { //todo change error message
agree, ER_TOO_LONG_KEY would be better here
Changed
+ my_error(ER_BLOB_KEY_WITHOUT_LENGTH, MYF(0), column->field_name.str); + DBUG_RETURN(TRUE); + } + if (!add_hash_field(thd, alter_info, key, key_info, + *key_info_buffer, create_info->default_table_charset)) + { + key_part_info= key_info->key_part; + key_part_info++; + null_fields++; + key_length= HA_HASH_KEY_LENGTH_WITHOUT_NULL; + break; + } + else + DBUG_RETURN(TRUE); } } #ifdef HAVE_SPATIAL @@ -3974,9 +4174,9 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, } else { - my_error(ER_TOO_LONG_KEY, MYF(0), key_part_length); - DBUG_RETURN(TRUE); - } + my_error(ER_TOO_LONG_KEY, MYF(0), key_part_length); + DBUG_RETURN(TRUE);
why don't you call add_hash_field() here? if this place is now impossible, add a DBUG_ASSERT(0) there or remove the if() completely and replace it with an assert. I mean:
if (condition) { something; } else { something else; }
becomes
DBUG_ASSERT(condition); something;
+ } } } // Catch invalid use of partial keys @@ -4021,8 +4221,23 @@ mysql_prepare_create_table(THD *thd, HA_CREATE_INFO *create_info, } else { - my_error(ER_TOO_LONG_KEY, MYF(0), key_part_length); - DBUG_RETURN(TRUE); + if(key->type != Key::UNIQUE) + { + my_error(ER_TOO_LONG_KEY, MYF(0), key_part_length); + DBUG_RETURN(TRUE); + } + //todo we does not respect length given by user in calculating hash
oh. that's a bug. good that you have a comment about it, there're more urgent issues that this one, but it should be fixed eventually
//TODO
+ if(!add_hash_field(thd, alter_info, key, key_info, + *key_info_buffer, create_info->default_table_charset)) + { + key_part_info= key_info->key_part; + key_part_info++; + null_fields++; + key_length= HA_HASH_KEY_LENGTH_WITHOUT_NULL; + break; + } + else + DBUG_RETURN(TRUE); } } key_part_info->length= (uint16) key_part_length; @@ -7502,6 +7717,8 @@ mysql_prepare_alter_table(THD *thd, TABLE *table, */ for (f_ptr=table->field ; (field= *f_ptr) ; f_ptr++) { + if (field->field_visibility == FULL_HIDDEN) + continue;
ok, so you recreate DB_ROW_HASH_xxx columns every time
Yes, BTW I changed this If condition to this one if (field->is_long_unique_hash) continue;
Alter_drop *drop; if (field->type() == MYSQL_TYPE_VARCHAR) create_info->varchar= TRUE; @@ -7818,7 +8057,7 @@ mysql_prepare_alter_table(THD *thd, TABLE *table,
if (key_info->flags & HA_SPATIAL) key_type= Key::SPATIAL; - else if (key_info->flags & HA_NOSAME) + else if (key_info->flags & HA_NOSAME || key_info->flags & HA_UNIQUE_HASH) { if (! my_strcasecmp(system_charset_info, key_name, primary_key_name)) key_type= Key::PRIMARY;
huh? I thought your HA_UNIQUE_HASH indexes cannot be Key::PRIMARY
Sorry , I did not see this.
Regards, Sergei Chief Architect MariaDB and security@mariadb.org
Hi Sergei!
Actually I implemented optimization on where with update and delete ,
with minimal changes on optimizer. Also now we can
use optimization in joins, select including subquery etc. I haven't
written much test case, but I will write it soon.
Please review it.
Regards
sachin
On Wed, Sep 7, 2016 at 11:06 PM, Sachin Setia
Hi Sergei!
This code is about adding new long unique key, This is a section of code from mysql_prepare_create_table, The main problem is can we make this code more shorter ? And the reason for this code is that we need to add Alter_info::ALTER_ADD_CHECK_CONSTRAINT , only if there is unique key on long columns
Query statements can be like this
alter table t1 add unique key a; // here a is blob
or
alter table t1 add b blob unique; alter table t1 add c varchar(1000) unique;
This is code
{ Key *key; while ((key=key_it++)) // Add new keys { if (key->type == Key::FOREIGN_KEY && ((Foreign_key *)key)->validate(new_create_list)) goto err;
from here ==> if (key->type == Key::UNIQUE) { List_iterator_fast
li(key->columns); Key_part_spec *column; uint total_length= 0; Field **f, *field; Create_field *cf; bool is_hash_key= false; while ((column= li++)) { if (column->length > table->file->max_key_part_length()) { is_hash_key= true; break; } else if (!column->length) { for (f= table->field; f && (field= *f); f++) { if (!my_strcasecmp(system_charset_info, field->field_name, column->field_name.str)) { if (field->max_display_length() > table->file->max_key_part_length()) { is_hash_key= true; goto exit; } total_length+= field->max_display_length(); } } /* Suppose query is like alter table t1 add column a blob unique; alter table t2 add column a blob,add column c blob, add unique key(a,b); In this case we have to add ALTER_ADD_CHECK_CONSTRAINT_FLAG We cant simply add ALTER_ADD_CHECK_CONSTRAINT flag because it is expensive. And there is no other way of doing this type of check. */ field_it.rewind(); while((cf= field_it++)) { if (!my_strcasecmp(system_charset_info, cf->field_name, column->field_name.str)) { if (cf->sql_type == MYSQL_TYPE_TINY_BLOB || cf->sql_type == MYSQL_TYPE_MEDIUM_BLOB || cf->sql_type == MYSQL_TYPE_LONG_BLOB || cf->sql_type == MYSQL_TYPE_BLOB) { is_hash_key= true; break; } if ((cf->sql_type == MYSQL_TYPE_VARCHAR || cf->sql_type == MYSQL_TYPE_VAR_STRING) && cf->length > table->file->max_key_part_length()) { is_hash_key= true; break; } total_length+= cf->length; } } } } exit: if (is_hash_key || total_length > table->file->max_key_length()) { alter_info->flags |= Alter_info::ALTER_ADD_CHECK_CONSTRAINT; alter_info->flags |= Alter_info::ALTER_ADD_COLUMN; } } new_key_list.push_back(key, thd->mem_root); if (key->name.str && !my_strcasecmp(system_charset_info, key->name.str, primary_key_name)) { my_error(ER_WRONG_NAME_FOR_INDEX, MYF(0), key->name.str); goto err; } } } On Wed, Aug 31, 2016 at 8:49 PM, sachin setiya
wrote: Hi Sergei!
On 08/24/2016 11:05 PM, Sergei Golubchik wrote:
Hi, Sachin!
On Aug 13, Sachin Setia wrote:
Hello Sergei! Please review commit 71f9069 onward i have changed mysql_prepare_alter_table func.
Okay, here it is. Up to the 03e29c6 (this is one after 71f9069).
Short summary - this all looks pretty good. There're issues, but as a whole - great work!
diff --git a/include/my_base.h b/include/my_base.h index 1317639..d03ca0f 100644 --- a/include/my_base.h +++ b/include/my_base.h @@ -241,6 +241,19 @@ enum ha_base_keytype { HA_KEYTYPE_BIT=19 };
+/* Add some constant related to unique long hash column like length hash string etc*/ + +#define HA_HASH_KEY_LENGTH_WITHOUT_NULL 8 +#define HA_HASH_FIELD_LENGTH 8 +#define HA_HASH_KEY_LENGTH_WITH_NULL 9 +#define HA_HASH_STR_HEAD "hash(`" //used in mysql_prepare_create_table +#define HA_HASH_STR_HEAD_LEN strlen(HA_HASH_STR_HEAD_LEN) +#define HA_HASH_STR "hash" +#define HA_HASH_STR_LEN strlen(HA_HASH_STR) +#define HA_HASH_STR_INDEX "HASH_INDEX" +#define HA_HASH_STR_INDEX_LEN strlen(HA_HASH_STR_INDEX) +#define HA_DB_ROW_HASH_STR "DB_ROW_HASH_"
no need to put all these constants into the very global my_base.h. better to define them in sql_show.cc or sql_table.cc (depending on where they're used)
Actually first three are needed in files like opt_range.cc. I moved this to table.h
+ #define HA_MAX_KEYTYPE 31 /* Must be log2-1 */
/* diff --git a/mysql-test/r/features.result b/mysql-test/r/features.result index 52650d1..e050efb 100644 --- a/mysql-test/r/features.result +++ b/mysql-test/r/features.result @@ -7,6 +7,7 @@ Feature_delay_key_write 0 Feature_dynamic_columns 0 Feature_fulltext 0 Feature_gis 0 +Feature_hidden_column 0
Great! Please, add also a test where it's not 0. I mean, in your hidden_field.test you can add
FLUSH STATUS;
at the beginning of the file and SHOW STATUS LIKE 'Feature_hidden_column'; somewhere later. This will show that Feature_hidden_column is incremented accordingly.
Done.
Feature_locale 0 Feature_subquery 0 Feature_timezone 0 diff --git a/mysql-test/r/hidden_field.result b/mysql-test/r/hidden_field.result new file mode 100644 index 0000000..09a2c21 --- /dev/null +++ b/mysql-test/r/hidden_field.result @@ -0,0 +1,367 @@ +create table h_1(abc int primary key, xyz int hidden); +desc h_1; +Field Type Null Key Default Extra +abc int(11) NO PRI NULL +xyz int(11) YES NULL HIDDEN +show create table h_1; +Table Create Table +h_1 CREATE TABLE `h_1` ( + `abc` int(11) NOT NULL, + `xyz` int(11) HIDDEN DEFAULT NULL, + PRIMARY KEY (`abc`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +drop table h_1; +create table h_2(a1 int hidden); +ERROR 42000: A table must have at least 1 column +create table h_3(a1 blob,hidden(a1)); +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'hidden(a1))' at line 1 +create table h_4(a1 int primary key hidden ,a2 int unique hidden , a3 blob,a4 +int not null hidden unique); +ERROR HY000: Hidden column 'a1' either allow null values or it must have default value +create table h_5(abc int not null hidden); +ERROR HY000: Hidden column 'abc' either allow null values or it must have default value +create table t1(a int hidden, b int); +insert into t1 values(1); +insert into t1(a) values(1); +insert into t1(b) values(1);
better insert 1,2,3 not 1,1,1 so that in SELECT you could unambigously see what INSERT has added what row
Changed.
+insert into t1(a,b) values(5,5); +select * from t1; +b +1 +NULL +1 +5 +select a,b from t1; +a b +NULL 1 +1 NULL +NULL 1 +5 5 +delete from t1; +insert into t1 values(1),(2),(3),(4); +select * from t1; +b +1 +2 +3 +4 +select a from t1; +a +NULL +NULL +NULL +NULL +drop table t1; +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +desc t1; +Field Type Null Key Default Extra +a int(11) YES NULL +b int(11) YES NULL HIDDEN +c int(11) NO PRI NULL auto_increment , HIDDEN
why a space before the comma?
Okay Reverted.
+d blob YES NULL +e int(11) YES UNI NULL +f int(11) YES NULL +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +select * from t1; +a d e f +1 d blob 1 1 +1 d blob 11 1 +1 d blob 2 1 +1 d blob 3 1 +1 d blob 41 1 +drop table t1; +create table sdsdsd(a int , b int, hidden(a,b)); +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'hidden(a,b))' at line 1 +create table t1(a int,abc int as (a mod 3) virtual hidden); +desc t1; +Field Type Null Key Default Extra +a int(11) YES NULL +abc int(11) YES NULL VIRTUAL , HIDDEN +insert into t1 values(1,default); +ERROR 21S01: Column count doesn't match value count at row 1 +insert into t1 values(1),(22),(233); +select * from t1; +a +1 +22 +233 +select a,abc from t1; +a abc +1 1 +22 1 +233 2 +drop table t1; +create table t1(abc int primary key hidden auto_increment, a int); +desc t1; +Field Type Null Key Default Extra +abc int(11) NO PRI NULL auto_increment , HIDDEN +a int(11) YES NULL +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `abc` int(11) NOT NULL HIDDEN AUTO_INCREMENT, + `a` int(11) DEFAULT NULL, + PRIMARY KEY (`abc`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +insert into t1 values(1); +insert into t1 values(2); +insert into t1 values(3); +select * from t1; +a +1 +2 +3 +select abc,a from t1; +abc a +1 1 +2 2 +3 3 +delete from t1; +insert into t1 values(1),(2),(3),(4),(6); +select abc,a from t1; +abc a +4 1 +5 2 +6 3 +7 4 +8 6 +drop table t1; +create table t1(abc int); +alter table t1 change abc ss int hidden; +ERROR 42000: A table must have at least 1 column +alter table t1 add column xyz int; +alter table t1 modify column abc int ; +desc t1; +Field Type Null Key Default Extra +abc int(11) YES NULL +xyz int(11) YES NULL +insert into t1 values(22); +ERROR 21S01: Column count doesn't match value count at row 1 +alter table t1 modify column abc int hidden;
please, add also tests for making hidden fields visible again. I think that
alter table t1 modify column abc int;
will do the job
Okay, Added.
+desc t1; +Field Type Null Key Default Extra +abc int(11) YES NULL HIDDEN +xyz int(11) YES NULL +insert into t1 values(12); +drop table t1; +some test on copy table structure with table data; +table with hidden fields and unique keys; +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +desc t1; +Field Type Null Key Default Extra +a int(11) YES NULL +b int(11) YES NULL HIDDEN +c int(11) NO PRI NULL auto_increment , HIDDEN +d blob YES NULL +e int(11) YES UNI NULL +f int(11) YES NULL +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +select * from t1; +a d e f +1 d blob 1 1 +1 d blob 11 1 +1 d blob 2 1 +1 d blob 3 1 +1 d blob 41 1 +select a,b,c,d,e,f from t1; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +this wont copy hidden fields and keys; +create table t2 as select * from t1; +desc t2; +Field Type Null Key Default Extra +a int(11) YES NULL +d blob YES NULL +e int(11) YES NULL +f int(11) YES NULL +select * from t2; +a d e f +1 d blob 1 1 +1 d blob 11 1 +1 d blob 2 1 +1 d blob 3 1 +1 d blob 41 1 +select a,b,c,d,e,f from t2; +ERROR 42S22: Unknown column 'b' in 'field list' +drop table t2; +now this will copy hidden fields +create table t2 as select a,b,c,d,e,f from t1; +desc t2; +Field Type Null Key Default Extra +a int(11) YES NULL +b int(11) YES NULL HIDDEN +c int(11) NO 0 HIDDEN +d blob YES NULL +e int(11) YES NULL +f int(11) YES NULL +select * from t2; +a d e f +1 d blob 1 1 +1 d blob 11 1 +1 d blob 2 1 +1 d blob 3 1 +1 d blob 41 1 +select a,b,c,d,e,f from t2; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +drop table t2,t1; +some test related to copy of data from one table to another; +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +select a,b,c,d,e,f from t1; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +create table t2(a int , b int hidden , c int hidden , d blob , e int unique, f int); +insert into t2 select * from t1; +select a,b,c,d,e,f from t2; +a b c d e f +1 NULL NULL d blob 1 1 +1 NULL NULL d blob 11 1 +1 NULL NULL d blob 2 1 +1 NULL NULL d blob 3 1 +1 NULL NULL d blob 41 1 +truncate t2; +insert into t2 (a,b,c,d,e,f) select a,b,c,d,e,f from t1; +select a,b,c,d,e,f from t2; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +truncate t2; +drop table t1,t2; +some test related to creating view on table with hidden column; +create table t1(a int , b int hidden , c int hidden auto_increment unique, d blob , e int unique, f int); +insert into t1 values(1,'d blob',1,1),(1,'d blob',11,1),(1,'d blob',2,1),(1,'d blob',3,1),(1,'d blob',41,1); +create view v as select * from t1; +desc v; +Field Type Null Key Default Extra +a int(11) YES NULL +d blob YES NULL +e int(11) YES NULL +f int(11) YES NULL +select * from v; +a d e f +1 d blob 1 1 +1 d blob 11 1 +1 d blob 2 1 +1 d blob 3 1 +1 d blob 41 1 +v does not have hidden column; +select a,b,c,d,e,f from v; +ERROR 42S22: Unknown column 'b' in 'field list' +insert into v values(1,21,32,4); +select * from v; +a d e f +1 d blob 1 1 +1 d blob 11 1 +1 d blob 2 1 +1 d blob 3 1 +1 d blob 41 1 +1 21 32 4 +insert into v(a,b,c,d,e,f) values(1,12,3,4,5,6); +ERROR 42S22: Unknown column 'b' in 'field list' +drop view v; +create view v as select a,b,c,d,e,f from t1; +desc v; +Field Type Null Key Default Extra +a int(11) YES NULL +b int(11) YES NULL HIDDEN +c int(11) NO 0 HIDDEN +d blob YES NULL +e int(11) YES NULL +f int(11) YES NULL +select * from v; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +1 NULL 6 21 32 4 +v does have hidden column; +select a,b,c,d,e,f from v; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +1 NULL 6 21 32 4 +insert into v values(1,26,33,4,45,66); +select a,b,c,d,e,f from v; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +1 NULL 6 21 32 4 +1 26 33 4 45 66 +insert into v(a,b,c,d,e,f) values(1,32,31,41,5,6); +select a,b,c,d,e,f from v; +a b c d e f +1 NULL 1 d blob 1 1 +1 NULL 2 d blob 11 1 +1 NULL 3 d blob 2 1 +1 NULL 4 d blob 3 1 +1 NULL 5 d blob 41 1 +1 NULL 6 21 32 4 +1 26 33 4 45 66 +1 32 31 41 5 6 +drop view v; +drop table t1; +now hidden column in where and some join query i think no use of this test but anyway; +create table t1 (a int unique , b int hidden unique, c int unique hidden); +insert into t1(a,b,c) values(1,1,1); +insert into t1(a,b,c) values(2,2,2); +insert into t1(a,b,c) values(3,3,3); +insert into t1(a,b,c) values(4,4,4); +insert into t1(a,b,c) values(21,21,26); +insert into t1(a,b,c) values(31,31,35); +insert into t1(a,b,c) values(41,41,45); +insert into t1(a,b,c) values(22,22,24); +insert into t1(a,b,c) values(32,32,33); +insert into t1(a,b,c) values(42,42,43); +explain select * from t1 where b=3; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const b b 5 const 1 +select * from t1 where b=3; +a +3 +explain select * from t1 where c=3; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const c c 5 const 1 +select * from t1 where c=3; +a +3 +create table t2 as select a,b,c from t1; +desc t2; +Field Type Null Key Default Extra +a int(11) YES NULL +b int(11) YES NULL HIDDEN +c int(11) YES NULL HIDDEN +explain select * from t1,t2 where t1.b = t2.c and t1.c = t2.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t2 ALL NULL NULL NULL NULL 10 +1 SIMPLE t1 ALL b,c NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +select * from t1,t2 where t1.b = t2.c and t1.c = t2.b; +a a +1 1 +2 2 +3 3 +4 4 +drop table t1,t2; diff --git a/mysql-test/r/long_unique_where.result b/mysql-test/r/long_unique_where.result new file mode 100644 index 0000000..e9bd416 --- /dev/null +++ b/mysql-test/r/long_unique_where.result @@ -0,0 +1,340 @@ +create table t1(abc blob unique); +insert into t1 values(1),(2),(3),(4),(5),(11),(12),(31),(14),(15),(NULL) +,(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL), +(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL), +(NULL),(NULL),(NULL),(NULL),(NULL); +insert into t1 value(1); +ERROR 23000: Duplicate entry '1' for key 'abc' +explain select * from t1 where abc=31; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc=31; +abc +31 +# in case of null we do not use any optimization +explain select * from t1 where abc is NULL; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 36 Using where +select * from t1 where abc is NULL limit 1; +abc +NULL +#range query
please clarify it here, for example, like
#range query (index not used, because it's a hash)
Copied , :).
+explain select * from t1 where abc >1 limit 1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 36 Using where +select * from t1 where abc >1 limit 1; +abc +2 +explain select * from t1 where abc >1 and abc <4; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 36 Using where +select * from t1 where abc >1 and abc <4; +abc +2 +3 +explain select * from t1 where abc =15 or abc <4 ; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 36 Using where +select * from t1 where abc =15 or abc <4 ; +abc +1 +2 +3 +15 +drop table t1; +create table t1(abc blob unique, xyz int ); +insert into t1 values(1,1),(2,1),(3,3),(4,1),(5,6),(NULL,3),(NULL,1), +(NULL,NULL),(11,11),(12,11),(31,31), +(14,1),(15,61),(NULL,32),(NULL,12),(NULL,NULL); +insert into t1 value(1,NULL); +ERROR 23000: Duplicate entry '1' for key 'abc' +explain select * from t1 where abc=15; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc= 15; +abc xyz +15 61 +explain select * from t1 where abc=15 and xyz =61; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc= 15 and 61;
type in the where clause
Changed.
+abc xyz +15 61 +# now xyz has different value
what do you mean by that?
echo # now xyz has a value which is not present in table; Added.
+explain select * from t1 where abc=1000; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where abc= 1000; +abc xyz +explain select * from t1 where abc=14 and xyz =56; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where abc=14 and xyz =56; +abc xyz +#range query +explain select * from t1 where abc >5 limit 1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 16 Using where +select * from t1 where abc >5 limit 1; +abc xyz +11 11 +explain select * from t1 where abc=5 and xyz <56; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc=5 and xyz <56; +abc xyz +5 6 +explain select * from t1 where abc>=5 and xyz <56; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 16 Using where +select * from t1 where abc>=5 and xyz <56; +abc xyz +5 6 +11 11 +12 11 +31 31 +14 1 +explain select * from t1 where abc>5 and xyz =56; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 16 Using where +select * from t1 where abc>5 and xyz =56; +abc xyz +drop table t1; +create table t1(abc blob unique, xyz blob unique ); +insert into t1 values(1,1),(2,11),(3,31),(4,12),(5,63),(NULL,2),(NULL,NULL), +(91,19),(92,119),(93,391),(94,192),(95,693); +insert into t1 value(1,NULL); +ERROR 23000: Duplicate entry '1' for key 'abc' +explain select * from t1 where abc=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc=1; +abc xyz +1 1 +explain select * from t1 where xyz=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const xyz xyz 9 const 1 +select * from t1 where xyz=1; +abc xyz +1 1 +explain select * from t1 where abc=5 and xyz=63; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc=5 and xyz=63; +abc xyz +5 63 +explain select * from t1 where xyz=63 and abc=5; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where xyz=63 and abc=5; +abc xyz +5 63 +explain select * from t1 where xyz=63 or abc=5; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where xyz=63 or abc=5; +abc xyz +5 63 +# now the first one does not exist +explain select * from t1 where abc=51 and xyz=63; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where abc=51 and xyz=63; +abc xyz +# now the second one does not exist +explain select * from t1 where abc=5 and xyz=613; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where abc=5 and xyz=613; +abc xyz +explain select * from t1 where abc is NULL; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where abc is NULL; +abc xyz +NULL 2 +NULL NULL +explain select * from t1 where abc is NULL and xyz=2; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const xyz xyz 9 const 1 +select * from t1 where abc is NULL and xyz=2; +abc xyz +NULL 2 +#range conditions +explain select * from t1 where abc>11 limit 5; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where abc>11 limit 5; +abc xyz +91 19 +92 119 +93 391 +94 192 +95 693 +explain select * from t1 where xyz<11; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where xyz<11; +abc xyz +1 1 +NULL 2 +explain select * from t1 where abc>=51 and xyz<=63; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where abc>=51 and xyz<=63; +abc xyz +91 19 +explain select * from t1 where abc>5 and xyz<613; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where abc>5 and xyz<613; +abc xyz +91 19 +92 119 +93 391 +94 192 +explain select * from t1 where abc=5 and xyz>1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const abc abc 9 const 1 +select * from t1 where abc=5 and xyz>1; +abc xyz +5 63 +explain select * from t1 where abc<55 and xyz=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const xyz xyz 9 const 1 +select * from t1 where abc<55 and xyz=1; +abc xyz +1 1 +explain select * from t1 where abc<=55 or xyz>=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 12 Using where +select * from t1 where abc<=55 and xyz>=1; +abc xyz +1 1 +2 11 +3 31 +4 12 +5 63 +drop table t1; +#now the unique (a,b,c..........) +#let us do more hard test by using unique(a,b,c,d) key first +create table t1 (a blob , b blob , c blob , d blob ,unique(a,b,c,d), +unique(a,b,c) ,unique (b,c,d));
hmm, better do not use redundant keys. it works now, but tenchnically we can implement the optimization where the server will internally remove "unique(a,b,c,d)" - will store it in the frm, but won't tell the engine about it - because unique(a,b,c) guarantees that (a,b,c,d) is *always* unique.
so, if we add this optimization someday your test case will no longer test what it was supposed to.
Okay , Changed.
+show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` blob DEFAULT NULL, + `c` blob DEFAULT NULL, + `d` blob DEFAULT NULL, + UNIQUE KEY `a_b_c_d`(`a`,`b`,`c`,`d`), + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), + UNIQUE KEY `b_c_d`(`b`,`c`,`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +insert into t1 values(1,1,1,1),(2,1,2,1),(1,3,3,1),(4,1,4,1),(1,5,1,5), +(6,1,6,1),(1,7,1,7),(8,1,1,8),(1,9,9,1),(2,2,2,2),(4,4,4,4),(5,5,5,5),(6,6,6,6), +(126,216,603,640),(603,460,660,706),(806,609,609,605),(62,62,22,33),(64,65,66,76), +(16,26,63,64),(63,46,66,76),(86,69,69,65),(622,622,622,633),(644,655,666,776); +select * from t1 limit 3; +a b c d +1 1 1 1 +2 1 2 1 +1 3 3 1 +#simple where +#key (a,b,c) +explain select * from t1 where a=1 and b=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const a_b_c a_b_c 9 const 1 +select * from t1 where a=1 and b=1 and c=1; +a b c d +1 1 1 1 +explain select * from t1 where a=1 and b=4444 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where a=1 and b=4444 and c=1; +a b c d +#incomplete key +explain select * from t1 where a=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where a=1 and c=1; +a b c d +1 1 1 1 +1 5 1 5 +1 7 1 7 +explain select * from t1 where a=1 and b=4444 ; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where a=1 and b=4444 ; +a b c d +explain select * from t1 where b=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where b=1 and c=1; +a b c d +1 1 1 1 +8 1 1 8 +#key (b,c,d) +explain select * from t1 where d=1 and b=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const b_c_d b_c_d 9 const 1 +select * from t1 where d=1 and b=1 and c=1; +a b c d +1 1 1 1 +explain select * from t1 where d=1 and b=4444 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where d=1 and b=4444 and c=1; +a b c d +#incomplete key +explain select * from t1 where d=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where d=1 and c=1; +a b c d +1 1 1 1 +explain select * from t1 where d=1 and b=4444 ; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where d=1 and b=4444 ; +a b c d +explain select * from t1 where b=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where b=1 and c=1; +a b c d +1 1 1 1 +8 1 1 8 +#key (a,b,c,d) +explain select * from t1 where a=1 and d=1 and b=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const a_b_c_d a_b_c_d 9 const 1 +select * from t1 where a=1 and d=1 and b=1 and c=1; +a b c d +1 1 1 1 +explain select * from t1 where a=1 and d=1 and b=4444 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select * from t1 where a=1 and d=1 and b=4444 and c=1; +a b c d +#incomplete key +explain select * from t1 where a=1 and d=1 and c=1 ; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where a=1 and d=1 and c=1 ; +a b c d +1 1 1 1 +explain select * from t1 where d=1 and b=4444 and a=1 ; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where d=1 and b=4444 and a=1 ; +a b c d +explain select * from t1 where a=1 and c=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 23 Using where +select * from t1 where a=1 and c=1; +a b c d +1 1 1 1 +1 5 1 5 +1 7 1 7 +drop table t1; diff --git a/mysql-test/r/long_uniques.result b/mysql-test/r/long_uniques.result new file mode 100644 index 0000000..e410fc1 --- /dev/null +++ b/mysql-test/r/long_uniques.result @@ -0,0 +1,1163 @@ +#Structure of tests +#First we will check all option for +#table containing single unique column +#table containing keys like unique(a,b,c,d) etc +#then table containing 2 blob unique etc +#table with single long blob column; +create table t1(a blob unique); +insert into t1 values(1),(2),(3),(56),('sachin'),('maria'),(123456789034567891),(null),(null),(123456789034567890); +#table structure; +desc t1; +Field Type Null Key Default Extra +a blob YES UNI NULL +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + UNIQUE KEY `a`(`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1;
for these statements, use "query_vertical" prefix, like
query_vertical show keys from t1;
it works better when the result has only few (best: one) row
Added.
+Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a 1 a A 0 NULL NULL YES HASH_INDEX
here, notice that your index is shown as "non-unique"
Corrected.
+select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION COLUMN_DEFAULT IS_NULLABLE DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME COLUMN_TYPE COLUMN_KEY EXTRA PRIVILEGES COLUMN_COMMENT +def test t1 a 1 NULL YES blob 65535 65535 NULL NULL NULL NULL NULL blob UNI select,insert,update,references +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME NON_UNIQUE INDEX_SCHEMA INDEX_NAME SEQ_IN_INDEX COLUMN_NAME COLLATION CARDINALITY SUB_PART PACKED NULLABLE INDEX_TYPE COMMENT INDEX_COMMENT +def test t1 1 test a 1 a A 0 NULL NULL YES HASH_INDEX +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; +CONSTRAINT_CATALOG CONSTRAINT_SCHEMA CONSTRAINT_NAME TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION POSITION_IN_UNIQUE_CONSTRAINT REFERENCED_TABLE_SCHEMA REFERENCED_TABLE_NAME REFERENCED_COLUMN_NAME +def test a def test t1 a 1 NULL NULL NULL NULL +# table select we should not be able to see db_row_hash_column;
"not able to see db_row_hash_1 column"
Changed, Sorry.
+select * from t1; +a +1 +2 +3 +56 +sachin +maria +123456789034567891 +NULL +NULL +123456789034567890 +select db_row_hash_1 from t1; +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' +#duplicate entry test; +insert into t1 values(2); +ERROR 23000: Duplicate entry '2' for key 'a' +insert into t1 values('sachin'); +ERROR 23000: Duplicate entry 'sachi' for key 'a' +insert into t1 values(123456789034567891); +ERROR 23000: Duplicate entry '12345' for key 'a' +select * from t1; +a +1 +2 +3 +56 +sachin +maria +123456789034567891 +NULL +NULL +123456789034567890 +insert into t1 values(11),(22),(33); +insert into t1 values(12),(22); +ERROR 23000: Duplicate entry '22' for key 'a' +select * from t1; +a +1 +2 +3 +56 +sachin +maria +123456789034567891 +NULL +NULL +123456789034567890 +11 +22 +33 +12 +insert into t1 values(repeat('s',4000*10)),(repeat('s',4001*10)); +insert into t1 values(repeat('m',4000*10)),(repeat('m',4000*10)); +ERROR 23000: Duplicate entry 'mmmmm' for key 'a' +insert into t1 values(repeat('m',4001)),(repeat('m',4002)); +truncate table t1; +insert into t1 values(1),(2),(3),(4),(5),(8),(7); +#now some alter commands; +alter table t1 add column b int; +desc t1; +Field Type Null Key Default Extra +a blob YES UNI NULL +b int(11) YES NULL +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` int(11) DEFAULT NULL, + UNIQUE KEY `a`(`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +insert into t1 values(1,2); +ERROR 23000: Duplicate entry '1' for key 'a' +insert into t1 values(2,2); +ERROR 23000: Duplicate entry '2' for key 'a' +select db_row_hash_1 from t1; +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' +#now try to change db_row_hash_1 column; +alter table t1 drop column db_row_hash_1; +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists +alter table t1 add column d int , add column e int , drop column db_row_hash_1; +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists +alter table t1 modify column db_row_hash_1 int ; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 add column a int , add column b int, modify column db_row_hash_1 int ; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 change column db_row_hash_1 dsds int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 add column asd int, change column db_row_hash_1 dsds int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 drop column b , add column c int; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `c` int(11) DEFAULT NULL, + UNIQUE KEY `a`(`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +#now add some column with name db_row_hash; +alter table t1 add column db_row_hash_1 int unique; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `c` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `a`(`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +insert into t1 values(45,1,55),(46,1,55); +ERROR 23000: Duplicate entry '55' for key 'db_row_hash_1' +alter table t1 add column db_row_hash_2 int, add column db_row_hash_3 int; +desc t1; +Field Type Null Key Default Extra +a blob YES UNI NULL +c int(11) YES NULL +db_row_hash_1 int(11) YES UNI NULL +db_row_hash_2 int(11) YES NULL +db_row_hash_3 int(11) YES NULL +#this should also drop the unique index ; +alter table t1 drop column a; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_3` int(11) DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +#add column with unique index on blob ; +alter table t1 add column a blob unique; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_3` int(11) DEFAULT NULL, + `a` blob DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `a`(`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +# try to change the blob unique column name; +#this will change index to b tree; +alter table t1 modify column a int ; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_3` int(11) DEFAULT NULL, + `a` int(11) DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `a` (`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 a 1 a A NULL NULL NULL YES BTREE +alter table t1 add column clm blob unique; +#try changing the name ; +alter table t1 change column clm clm_changed blob; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_3` int(11) DEFAULT NULL, + `a` int(11) DEFAULT NULL, + `clm_changed` blob DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `a` (`a`), + UNIQUE KEY `clm`(`clm_changed`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 a 1 a A NULL NULL NULL YES BTREE +t1 1 clm 1 clm_changed A 0 NULL NULL YES HASH_INDEX +#now drop the unique key; +alter table t1 drop key clm; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_3` int(11) DEFAULT NULL, + `a` int(11) DEFAULT NULL, + `clm_changed` blob DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `a` (`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 a 1 a A NULL NULL NULL YES BTREE
you can use myisamchk to see *actually created* indexes in MYI file. examples are in myisam.test, but in short, it's something like
let datadir=`select @@datadir`; replace_result $datadir DATADIR; exec $MYISAMCHK -d $datadir/test/t1
the first command needs to be done only once, in the beginning of the file, usually. The other pair you do whenever you want to examine the table, like, where you do "desc t1" or "show keys".
Done.
+drop table t1; +create table t1 (a TEXT CHARSET latin1 COLLATE latin1_german2_ci unique); +desc t1; +Field Type Null Key Default Extra +a text YES UNI NULL +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a 1 a A 0 NULL NULL YES HASH_INDEX +insert into t1 values ('ae'); +insert into t1 values ('AE'); +ERROR 23000: Duplicate entry 'AE' for key 'a' +insert into t1 values ('Ä');
good!
+drop table t1; +#table with multiple long blob column and varchar text column ; +create table t1(a blob unique, b int , c blob unique , d text unique , e varchar(3000) unique); +insert into t1 values(1,2,3,4,5),(2,11,22,33,44),(3111,222,333,444,555),(5611,2222,3333,4444,5555), +('sachin','ff','fdf','gfgfgfg','hghgr'),('maria','db','frter','dasd','utyuty'), +(123456789034567891,3534534534534,53453453453456,64565464564564,45435345345345), +(123456789034567890,435345345345,657567567567,78967657567567,657567567567567676); +Warnings: +Warning 1366 Incorrect integer value: 'ff' for column 'b' at row 5 +Warning 1366 Incorrect integer value: 'db' for column 'b' at row 6 +Warning 1264 Out of range value for column 'b' at row 7 +Warning 1264 Out of range value for column 'b' at row 8
did you really need to insert invalid values in this test?
No, I did not see Warning.
+#table structure; +desc t1; +Field Type Null Key Default Extra +a blob YES UNI NULL +b int(11) YES NULL +c blob YES UNI NULL +d text YES UNI NULL +e varchar(3000) YES UNI NULL +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` int(11) DEFAULT NULL, + `c` blob DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + UNIQUE KEY `a`(`a`), + UNIQUE KEY `c`(`c`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `e`(`e`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 c 1 c A 0 NULL NULL YES HASH_INDEX +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 e 1 e A 0 NULL NULL YES HASH_INDEX +select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION COLUMN_DEFAULT IS_NULLABLE DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME COLUMN_TYPE COLUMN_KEY EXTRA PRIVILEGES COLUMN_COMMENT +def test t1 a 1 NULL YES blob 65535 65535 NULL NULL NULL NULL NULL blob UNI select,insert,update,references +def test t1 b 2 NULL YES int NULL NULL 10 0 NULL NULL NULL int(11) select,insert,update,references +def test t1 c 3 NULL YES blob 65535 65535 NULL NULL NULL NULL NULL blob UNI select,insert,update,references +def test t1 d 4 NULL YES text 65535 65535 NULL NULL NULL latin1 latin1_swedish_ci text UNI select,insert,update,references +def test t1 e 5 NULL YES varchar 3000 3000 NULL NULL NULL latin1 latin1_swedish_ci varchar(3000) UNI select,insert,update,references +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME NON_UNIQUE INDEX_SCHEMA INDEX_NAME SEQ_IN_INDEX COLUMN_NAME COLLATION CARDINALITY SUB_PART PACKED NULLABLE INDEX_TYPE COMMENT INDEX_COMMENT +def test t1 1 test a 1 a A 0 NULL NULL YES HASH_INDEX +def test t1 1 test c 1 c A 0 NULL NULL YES HASH_INDEX +def test t1 1 test d 1 d A 0 NULL NULL YES HASH_INDEX +def test t1 1 test e 1 e A 0 NULL NULL YES HASH_INDEX +select * from information_schema.key_column_usage where table_schema= 'test' and table_name= 't1'; +CONSTRAINT_CATALOG CONSTRAINT_SCHEMA CONSTRAINT_NAME TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION POSITION_IN_UNIQUE_CONSTRAINT REFERENCED_TABLE_SCHEMA REFERENCED_TABLE_NAME REFERENCED_COLUMN_NAME +def test a def test t1 a 1 NULL NULL NULL NULL +def test c def test t1 c 1 NULL NULL NULL NULL +def test d def test t1 d 1 NULL NULL NULL NULL +def test e def test t1 e 1 NULL NULL NULL NULL +#table select we should not be able to see db_row_hash_column; +select * from t1; +a b c d e +1 2 3 4 5 +2 11 22 33 44 +3111 222 333 444 555 +5611 2222 3333 4444 5555 +sachin 0 fdf gfgfgfg hghgr +maria 0 frter dasd utyuty +123456789034567891 2147483647 53453453453456 64565464564564 45435345345345 +123456789034567890 2147483647 657567567567 78967657567567 657567567567567676 +select db_row_hash_1 from t1; +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' +select db_row_hash_2 from t1; +ERROR 42S22: Unknown column 'db_row_hash_2' in 'field list' +select db_row_hash_3 from t1; +ERROR 42S22: Unknown column 'db_row_hash_3' in 'field list' +#duplicate entry test; +insert into t1 values(21,2,3,42,51); +ERROR 23000: Duplicate entry '3' for key 'c' +insert into t1 values('sachin',null,null,null,null); +ERROR 23000: Duplicate entry 'sachi' for key 'a' +insert into t1 values(1234567890345671890,4353453453451,6575675675617,789676575675617,657567567567567676); +ERROR 23000: Duplicate entry '65756' for key 'e' +select * from t1; +a b c d e +1 2 3 4 5 +2 11 22 33 44 +3111 222 333 444 555 +5611 2222 3333 4444 5555 +sachin 0 fdf gfgfgfg hghgr +maria 0 frter dasd utyuty +123456789034567891 2147483647 53453453453456 64565464564564 45435345345345 +123456789034567890 2147483647 657567567567 78967657567567 657567567567567676 +insert into t1 values(repeat('s',4000*10),100,repeat('s',4000*10),repeat('s',4000*10), +repeat('s',400)),(repeat('s',4001*10),1000,repeat('s',4001*10),repeat('s',4001*10), +repeat('s',401)); +insert into t1 values(repeat('m',4000*11),10,repeat('s',4000*11),repeat('s',4000*11),repeat('s',400)); +ERROR 23000: Duplicate entry 'sssss' for key 'e'
400 characters (that you insert into 'e') - that looks a bit too short for varchar(3000). Why wouldn't you insert, say, 2990 characters? 400 is something that even b-tree can handle, I suspect.
Changed.
+truncate table t1; +insert into t1 values(1,2,3,4,5),(2,11,22,33,44),(3111,222,333,444,555),(5611,2222,3333,4444,5555); +#now some alter commands; +alter table t1 add column f int; +desc t1; +Field Type Null Key Default Extra +a blob YES UNI NULL +b int(11) YES NULL +c blob YES UNI NULL +d text YES UNI NULL +e varchar(3000) YES UNI NULL +f int(11) YES NULL +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` int(11) DEFAULT NULL, + `c` blob DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + UNIQUE KEY `a`(`a`), + UNIQUE KEY `c`(`c`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `e`(`e`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +#unique key should not break; +insert into t1 values(1,2,3,4,5,6); +ERROR 23000: Duplicate entry '1' for key 'a' +select db_row_hash_1 , db_row_hash_2, db_row_hash_3 from t1; +ERROR 42S22: Unknown column 'db_row_hash_1' in 'field list' +#now try to change db_row_hash_1 column; +alter table t1 drop column db_row_hash_1, drop column db_row_hash_2, drop column db_row_hash_3; +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists +alter table t1 add column dg int , add column ef int , drop column db_row_hash_1; +ERROR 42000: Can't DROP COLUMN `db_row_hash_1`; check that it exists +alter table t1 modify column db_row_hash_1 int , modify column db_row_hash_2 int, modify column db_row_hash_3 int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 add column ar int , add column rb int, modify column db_row_hash_1 int , modify column db_row_hash_3 int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 change column db_row_hash_1 dsds int , change column db_row_hash_2 dfdf int , change column db_row_hash_3 gdfg int ; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 add column asd int, drop column a, change column db_row_hash_1 dsds int, change db_row_hash_3 fdfdfd int; +ERROR 42S22: Unknown column 'db_row_hash_1' in 't1' +alter table t1 drop column b , add column g int; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `c` blob DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + UNIQUE KEY `a`(`a`), + UNIQUE KEY `c`(`c`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `e`(`e`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +#now add some column with name db_row_hash; +alter table t1 add column db_row_hash_1 int unique; +alter table t1 add column db_row_hash_2 int unique; +alter table t1 add column db_row_hash_3 int unique; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `c` blob DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_3` int(11) DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), + UNIQUE KEY `db_row_hash_3` (`db_row_hash_3`), + UNIQUE KEY `a`(`a`), + UNIQUE KEY `c`(`c`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `e`(`e`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +alter table t1 add column db_row_hash_7 int, add column db_row_hash_5 int , add column db_row_hash_4 int ; +alter table t1 drop column db_row_hash_7,drop column db_row_hash_3, drop column db_row_hash_4; +desc t1; +Field Type Null Key Default Extra +a blob YES UNI NULL +c blob YES UNI NULL +d text YES UNI NULL +e varchar(3000) YES UNI NULL +f int(11) YES NULL +g int(11) YES NULL +db_row_hash_1 int(11) YES UNI NULL +db_row_hash_2 int(11) YES UNI NULL +db_row_hash_5 int(11) YES NULL +#this show now break anything; +insert into t1 values(1,2,3,4,5,6,23,5,6); +ERROR 23000: Duplicate entry '1' for key 'a' +#this should also drop the unique index; +alter table t1 drop column a, drop column c; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_5` int(11) DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `e`(`e`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 e 1 e A 0 NULL NULL YES HASH_INDEX +#add column with unique index on blob; +alter table t1 add column a blob unique; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_5` int(11) DEFAULT NULL, + `a` blob DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `e`(`e`), + UNIQUE KEY `a`(`a`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 e 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 a 1 a A 0 NULL NULL YES HASH_INDEX +#try to change the blob unique column name; +#this will change index to b tree; +alter table t1 modify column a int , modify column e int; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `d` text DEFAULT NULL, + `e` int(11) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_5` int(11) DEFAULT NULL, + `a` int(11) DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), + UNIQUE KEY `e` (`e`), + UNIQUE KEY `a` (`a`), + UNIQUE KEY `d`(`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE +t1 0 e 1 e A NULL NULL NULL YES BTREE +t1 0 a 1 a A NULL NULL NULL YES BTREE +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX +alter table t1 add column clm1 blob unique,add column clm2 blob unique; +#try changing the name; +alter table t1 change column clm1 clm_changed1 blob, change column clm2 clm_changed2 blob; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `d` text DEFAULT NULL, + `e` int(11) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_5` int(11) DEFAULT NULL, + `a` int(11) DEFAULT NULL, + `clm_changed1` blob DEFAULT NULL, + `clm_changed2` blob DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), + UNIQUE KEY `e` (`e`), + UNIQUE KEY `a` (`a`), + UNIQUE KEY `d`(`d`), + UNIQUE KEY `clm1`(`clm_changed1`), + UNIQUE KEY `clm2`(`clm_changed2`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE +t1 0 e 1 e A NULL NULL NULL YES BTREE +t1 0 a 1 a A NULL NULL NULL YES BTREE +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 clm1 1 clm_changed1 A 0 NULL NULL YES HASH_INDEX +t1 1 clm2 1 clm_changed2 A 0 NULL NULL YES HASH_INDEX +#now drop the unique key; +alter table t1 drop key clm1, drop key clm2; +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `d` text DEFAULT NULL, + `e` int(11) DEFAULT NULL, + `f` int(11) DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `db_row_hash_1` int(11) DEFAULT NULL, + `db_row_hash_2` int(11) DEFAULT NULL, + `db_row_hash_5` int(11) DEFAULT NULL, + `a` int(11) DEFAULT NULL, + `clm_changed1` blob DEFAULT NULL, + `clm_changed2` blob DEFAULT NULL, + UNIQUE KEY `db_row_hash_1` (`db_row_hash_1`), + UNIQUE KEY `db_row_hash_2` (`db_row_hash_2`), + UNIQUE KEY `e` (`e`), + UNIQUE KEY `a` (`a`), + UNIQUE KEY `d`(`d`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 0 db_row_hash_1 1 db_row_hash_1 A NULL NULL NULL YES BTREE +t1 0 db_row_hash_2 1 db_row_hash_2 A NULL NULL NULL YES BTREE +t1 0 e 1 e A NULL NULL NULL YES BTREE +t1 0 a 1 a A NULL NULL NULL YES BTREE +t1 1 d 1 d A 0 NULL NULL YES HASH_INDEX
test also
alter table ... add unique key (blob_column)
in three different variants: 1. there were no duplicates in blob_column, key added successfully, 2. there were duplicates, alter table failed. 3. there were duplicates, ALTER IGNORE TABLE... succeeds
Already added in later commit.
+drop table t1; +#now the table with key on multiple columns; the ultimate test; +create table t1(a blob, b int , c varchar(2000) , d text , e varchar(3000) , f longblob , g int , h text , +unique(a,b,c), unique(c,d,e),unique(e,f,g,h),unique(a,b,c,d,e,f),unique(d,e,f,g,h),unique(a,b,c,d,e,f,g,h)); +insert into t1 values(1,1,1,1,1,1,1,1),(2,2,2,2,2,2,2,2),(3,3,3,3,3,3,3,3),(4,4,4,4,4,4,4,4),(5,5,5,5,5,5,5,5), +('maria',6,'maria','maria','maria','maria',6,'maria'),('mariadb',7,'mariadb','mariadb','mariadb','mariadb',8,'mariadb'); +#table structure; +desc t1; +Field Type Null Key Default Extra +a blob YES MUL NULL +b int(11) YES NULL +c varchar(2000) YES MUL NULL +d text YES MUL NULL +e varchar(3000) YES MUL NULL +f longblob YES NULL +g int(11) YES NULL +h text YES NULL +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `a` blob DEFAULT NULL, + `b` int(11) DEFAULT NULL, + `c` varchar(2000) DEFAULT NULL, + `d` text DEFAULT NULL, + `e` varchar(3000) DEFAULT NULL, + `f` longblob DEFAULT NULL, + `g` int(11) DEFAULT NULL, + `h` text DEFAULT NULL, + UNIQUE KEY `a_b_c`(`a`,`b`,`c`), + UNIQUE KEY `c_d_e`(`c`,`d`,`e`), + UNIQUE KEY `e_f_g_h`(`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f`(`a`,`b`,`c`,`d`,`e`,`f`), + UNIQUE KEY `d_e_f_g_h`(`d`,`e`,`f`,`g`,`h`), + UNIQUE KEY `a_b_c_d_e_f_g_h`(`a`,`b`,`c`,`d`,`e`,`f`,`g`,`h`) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +show keys from t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment Index_comment +t1 1 a_b_c 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 1 c A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 2 d A 0 NULL NULL YES HASH_INDEX +t1 1 c_d_e 3 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 3 g A 0 NULL NULL YES HASH_INDEX +t1 1 e_f_g_h 4 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 1 d A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 2 e A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 3 f A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 4 g A 0 NULL NULL YES HASH_INDEX +t1 1 d_e_f_g_h 5 h A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 1 a A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 2 b A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 3 c A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 4 d A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 5 e A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 6 f A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 7 g A 0 NULL NULL YES HASH_INDEX +t1 1 a_b_c_d_e_f_g_h 8 h A 0 NULL NULL YES HASH_INDEX +select * from information_schema.columns where table_schema = 'test' and table_name = 't1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME COLUMN_NAME ORDINAL_POSITION COLUMN_DEFAULT IS_NULLABLE DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME COLUMN_TYPE COLUMN_KEY EXTRA PRIVILEGES COLUMN_COMMENT +def test t1 a 1 NULL YES blob 65535 65535 NULL NULL NULL NULL NULL blob MUL select,insert,update,references +def test t1 b 2 NULL YES int NULL NULL 10 0 NULL NULL NULL int(11) select,insert,update,references +def test t1 c 3 NULL YES varchar 2000 2000 NULL NULL NULL latin1 latin1_swedish_ci varchar(2000) MUL select,insert,update,references +def test t1 d 4 NULL YES text 65535 65535 NULL NULL NULL latin1 latin1_swedish_ci text MUL select,insert,update,references +def test t1 e 5 NULL YES varchar 3000 3000 NULL NULL NULL latin1 latin1_swedish_ci varchar(3000) MUL select,insert,update,references +def test t1 f 6 NULL YES longblob 4294967295 4294967295 NULL NULL NULL NULL NULL longblob select,insert,update,references +def test t1 g 7 NULL YES int NULL NULL 10 0 NULL NULL NULL int(11) select,insert,update,references +def test t1 h 8 NULL YES text 65535 65535 NULL NULL NULL latin1 latin1_swedish_ci text select,insert,update,references +select * from information_schema.statistics where table_schema = 'test' and table_name = 't1'; +TABLE_CATALOG TABLE_SCHEMA TABLE_NAME NON_UNIQUE INDEX_SCHEMA INDEX_NAME SEQ_IN_INDEX COLUMN_NAME COLLATION CARDINALITY SUB_PART PACKED NULLABLE INDEX_TYPE COMMENT INDEX_COMMENT +def test t1 1 test a_b_c 1 a A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c 2 b A 0 NULL NULL YES HASH_INDEX +def test t1 1 test a_b_c 3 c A 0 NULL NULL YES HASH_INDEX +def test t1 1 test c_d_e 1 c A 0 NULL NULL YES HASH_INDEX +def test t1 1 test c_d_e 2 d A 0 NULL NULL YES HASH_INDEX +def test t1 1 test c_d_e 3 e A 0 NULL NULL YES HASH_INDEX +def test t1 1 test e_f_g_h 1 e A 0 NULL NULL YES HASH_INDEX +def test t1 1 test e_f_g_h 2 f A 0 NULL NULL YES HASH_INDEX +def test t1 1 test e_f_g_h 3 g A 0 NULL NULL YE