Skip to content
Projects
Groups
Snippets
Help
Loading...
Help
Support
Keyboard shortcuts
?
Submit feedback
Contribute to GitLab
Sign in / Register
Toggle navigation
M
mariadb
Project overview
Project overview
Details
Activity
Releases
Repository
Repository
Files
Commits
Branches
Tags
Contributors
Graph
Compare
Issues
0
Issues
0
List
Boards
Labels
Milestones
Merge Requests
0
Merge Requests
0
Analytics
Analytics
Repository
Value Stream
Wiki
Wiki
Snippets
Snippets
Members
Members
Collapse sidebar
Close sidebar
Activity
Graph
Create a new issue
Commits
Issue Boards
Open sidebar
Kirill Smelkov
mariadb
Commits
76c48d43
Commit
76c48d43
authored
Sep 14, 2006
by
unknown
Browse files
Options
Browse Files
Download
Plain Diff
Merge epotemkin@bk-internal.mysql.com:/home/bk/mysql-4.1-opt
into moonbone.local:/work/21677-bug-4.1-opt-mysql
parents
54caf667
cca7be1c
Changes
5
Hide whitespace changes
Inline
Side-by-side
Showing
5 changed files
with
66 additions
and
137 deletions
+66
-137
mysql-test/r/func_time.result
mysql-test/r/func_time.result
+11
-12
mysql-test/r/type_date.result
mysql-test/r/type_date.result
+8
-2
mysql-test/t/func_time.test
mysql-test/t/func_time.test
+11
-11
mysql-test/t/type_date.test
mysql-test/t/type_date.test
+9
-2
sql/item_cmpfunc.cc
sql/item_cmpfunc.cc
+27
-110
No files found.
mysql-test/r/func_time.result
View file @
76c48d43
...
...
@@ -646,37 +646,36 @@ drop table t1;
create table t1(f1 date, f2 time, f3 datetime);
insert into t1 values ("2006-01-01", "12:01:01", "2006-01-01 12:01:01");
insert into t1 values ("2006-01-02", "12:01:02", "2006-01-02 12:01:02");
select f1 from t1 where f1 between
"2006-1-1" and 20060101
;
select f1 from t1 where f1 between
CAST("2006-1-1" as date) and CAST(20060101 as date)
;
f1
2006-01-01
select f1 from t1 where f1 between
"2006-1-1" and "2006.1.1"
;
select f1 from t1 where f1 between
cast("2006-1-1" as date) and cast("2006.1.1" as date)
;
f1
2006-01-01
select f1 from t1 where date(f1) between
"2006-1-1" and "2006.1.1"
;
select f1 from t1 where date(f1) between
cast("2006-1-1" as date) and cast("2006.1.1" as date)
;
f1
2006-01-01
select f2 from t1 where f2 between
"12:1:2" and "12:2:2"
;
select f2 from t1 where f2 between
cast("12:1:2" as time) and cast("12:2:2" as time)
;
f2
12:01:02
select f2 from t1 where time(f2) between
"12:1:2" and "12:2:2"
;
select f2 from t1 where time(f2) between
cast("12:1:2" as time) and cast("12:2:2" as time)
;
f2
12:01:02
select f3 from t1 where f3 between
"2006-1-1 12:1:1" and "2006-1-1 12:1:2"
;
select f3 from t1 where f3 between
cast("2006-1-1 12:1:1" as datetime) and cast("2006-1-1 12:1:2" as datetime)
;
f3
2006-01-01 12:01:01
select f3 from t1 where timestamp(f3) between
"2006-1-1 12:1:1" and "2006-1-1 12:1:2"
;
select f3 from t1 where timestamp(f3) between
cast("2006-1-1 12:1:1" as datetime) and cast("2006-1-1 12:1:2" as datetime)
;
f3
2006-01-01 12:01:01
select f1 from t1 where
"2006-1-1"
between f1 and f3;
select f1 from t1 where
cast("2006-1-1" as date)
between f1 and f3;
f1
2006-01-01
select f1 from t1 where
"2006-1-1"
between date(f1) and date(f3);
select f1 from t1 where
cast("2006-1-1" as date)
between date(f1) and date(f3);
f1
2006-01-01
select f1 from t1 where
"2006-1-1"
between f1 and 'zzz';
select f1 from t1 where
cast("2006-1-1" as date)
between f1 and 'zzz';
f1
Warnings:
Warning 1292 Truncated incorrect date value: 'zzz'
2006-01-01
select f1 from t1 where makedate(2006,1) between date(f1) and date(f3);
f1
2006-01-01
...
...
mysql-test/r/type_date.result
View file @
76c48d43
...
...
@@ -27,12 +27,12 @@ INSERT INTO t1 VALUES ( "2000-1-2" );
INSERT INTO t1 VALUES ( "2000-1-3" );
INSERT INTO t1 VALUES ( "2000-1-4" );
INSERT INTO t1 VALUES ( "2000-1-5" );
SELECT * FROM t1 WHERE datum BETWEEN
"2000-1-2" AND "2000-1-4"
;
SELECT * FROM t1 WHERE datum BETWEEN
cast("2000-1-2" as date) AND cast("2000-1-4" as date)
;
datum
2000-01-02
2000-01-03
2000-01-04
SELECT * FROM t1 WHERE datum BETWEEN
"2000-1-2"
AND datum - INTERVAL 100 DAY;
SELECT * FROM t1 WHERE datum BETWEEN
cast("2000-1-2" as date)
AND datum - INTERVAL 100 DAY;
datum
DROP TABLE t1;
CREATE TABLE t1 (
...
...
@@ -104,3 +104,9 @@ SELECT * FROM t1;
y
0000
DROP TABLE t1;
create table t1(start_date date, end_date date);
insert into t1 values ('2000-01-01','2000-01-02');
select 1 from t1 where cast('2000-01-01 12:01:01' as datetime) between start_date and end_date;
1
1
drop table t1;
mysql-test/t/func_time.test
View file @
76c48d43
...
...
@@ -341,20 +341,20 @@ drop table t1;
#
# Bug#16377 result of DATE/TIME functions were compared as strings which
# can lead to a wrong result.
#
#
Now wrong dates should be compared only with CAST()
create
table
t1
(
f1
date
,
f2
time
,
f3
datetime
);
insert
into
t1
values
(
"2006-01-01"
,
"12:01:01"
,
"2006-01-01 12:01:01"
);
insert
into
t1
values
(
"2006-01-02"
,
"12:01:02"
,
"2006-01-02 12:01:02"
);
select
f1
from
t1
where
f1
between
"2006-1-1"
and
20060101
;
select
f1
from
t1
where
f1
between
"2006-1-1"
and
"2006.1.1"
;
select
f1
from
t1
where
date
(
f1
)
between
"2006-1-1"
and
"2006.1.1"
;
select
f2
from
t1
where
f2
between
"12:1:2"
and
"12:2:2"
;
select
f2
from
t1
where
time
(
f2
)
between
"12:1:2"
and
"12:2:2"
;
select
f3
from
t1
where
f3
between
"2006-1-1 12:1:1"
and
"2006-1-1 12:1:2"
;
select
f3
from
t1
where
timestamp
(
f3
)
between
"2006-1-1 12:1:1"
and
"2006-1-1 12:1:2"
;
select
f1
from
t1
where
"2006-1-1"
between
f1
and
f3
;
select
f1
from
t1
where
"2006-1-1"
between
date
(
f1
)
and
date
(
f3
);
select
f1
from
t1
where
"2006-1-1"
between
f1
and
'zzz'
;
select
f1
from
t1
where
f1
between
CAST
(
"2006-1-1"
as
date
)
and
CAST
(
20060101
as
date
)
;
select
f1
from
t1
where
f1
between
cast
(
"2006-1-1"
as
date
)
and
cast
(
"2006.1.1"
as
date
)
;
select
f1
from
t1
where
date
(
f1
)
between
cast
(
"2006-1-1"
as
date
)
and
cast
(
"2006.1.1"
as
date
)
;
select
f2
from
t1
where
f2
between
cast
(
"12:1:2"
as
time
)
and
cast
(
"12:2:2"
as
time
)
;
select
f2
from
t1
where
time
(
f2
)
between
cast
(
"12:1:2"
as
time
)
and
cast
(
"12:2:2"
as
time
)
;
select
f3
from
t1
where
f3
between
cast
(
"2006-1-1 12:1:1"
as
datetime
)
and
cast
(
"2006-1-1 12:1:2"
as
datetime
)
;
select
f3
from
t1
where
timestamp
(
f3
)
between
cast
(
"2006-1-1 12:1:1"
as
datetime
)
and
cast
(
"2006-1-1 12:1:2"
as
datetime
)
;
select
f1
from
t1
where
cast
(
"2006-1-1"
as
date
)
between
f1
and
f3
;
select
f1
from
t1
where
cast
(
"2006-1-1"
as
date
)
between
date
(
f1
)
and
date
(
f3
);
select
f1
from
t1
where
cast
(
"2006-1-1"
as
date
)
between
f1
and
'zzz'
;
select
f1
from
t1
where
makedate
(
2006
,
1
)
between
date
(
f1
)
and
date
(
f3
);
select
f1
from
t1
where
makedate
(
2006
,
2
)
between
date
(
f1
)
and
date
(
f3
);
drop
table
t1
;
...
...
mysql-test/t/type_date.test
View file @
76c48d43
...
...
@@ -36,8 +36,8 @@ INSERT INTO t1 VALUES ( "2000-1-2" );
INSERT
INTO
t1
VALUES
(
"2000-1-3"
);
INSERT
INTO
t1
VALUES
(
"2000-1-4"
);
INSERT
INTO
t1
VALUES
(
"2000-1-5"
);
SELECT
*
FROM
t1
WHERE
datum
BETWEEN
"2000-1-2"
AND
"2000-1-4"
;
SELECT
*
FROM
t1
WHERE
datum
BETWEEN
"2000-1-2"
AND
datum
-
INTERVAL
100
DAY
;
SELECT
*
FROM
t1
WHERE
datum
BETWEEN
cast
(
"2000-1-2"
as
date
)
AND
cast
(
"2000-1-4"
as
date
)
;
SELECT
*
FROM
t1
WHERE
datum
BETWEEN
cast
(
"2000-1-2"
as
date
)
AND
datum
-
INTERVAL
100
DAY
;
DROP
TABLE
t1
;
#
...
...
@@ -115,4 +115,11 @@ INSERT INTO t1 VALUES ('abc');
SELECT
*
FROM
t1
;
DROP
TABLE
t1
;
#
# Bug#21677: Wrong result when comparing a DATE and a DATETIME in BETWEEN
#
create
table
t1
(
start_date
date
,
end_date
date
);
insert
into
t1
values
(
'2000-01-01'
,
'2000-01-02'
);
select
1
from
t1
where
cast
(
'2000-01-01 12:01:01'
as
datetime
)
between
start_date
and
end_date
;
drop
table
t1
;
# End of 4.1 tests
sql/item_cmpfunc.cc
View file @
76c48d43
...
...
@@ -75,119 +75,14 @@ static void agg_result_type(Item_result *type, Item **items, uint nitems)
This function aggregates result types from the array of items. Found type
supposed to be used later for comparison of values of these items.
Aggregation itself is performed by the item_cmp_type() function.
NOTES
Aggregation rules:
If there are DATE/TIME fields/functions in the list and no string
fields/functions in the list then:
The INT_RESULT type will be used for aggregation instead of original
result type of any DATE/TIME field/function in the list
All constant items in the list will be converted to a DATE/TIME using
found field or result field of found function.
Implementation notes:
The code is equivalent to:
1. Check the list for presence of a STRING field/function.
Collect the is_const flag.
2. Get a Field* object to use for type coercion
3. Perform type conversion.
1 and 2 are implemented in 2 loops. The first searches for a DATE/TIME
field/function and checks presence of a STRING field/function.
The second loop works only if a DATE/TIME field/function is found.
It checks presence of a STRING field/function in the rest of the list.
TODO
1) The current implementation can produce false comparison results for
expressions like:
date_time_field BETWEEN string_field_with_dates AND string_constant
if the string_constant will omit some of leading zeroes.
In order to fully implement correct comparison of DATE/TIME the new
DATETIME_RESULT result type should be introduced and agg_cmp_type()
should return the DATE/TIME field used for the conversion. Later
this field can be used by comparison functions like Item_func_between to
convert string values to ints on the fly and thus return correct results.
This modification will affect functions BETWEEN, IN and CASE.
2) If in the list a DATE field/function and a DATETIME field/function
are present in the list then the first found field/function will be
used for conversion. This may lead to wrong results and probably should
be fixed.
*/
static
void
agg_cmp_type
(
THD
*
thd
,
Item_result
*
type
,
Item
**
items
,
uint
nitems
)
{
uint
i
;
Item
::
Type
res
=
(
Item
::
Type
)
0
;
/* Used only for date/time fields, max_length = 19 */
char
buff
[
20
];
uchar
null_byte
;
Field
*
field
=
NULL
;
/* Search for date/time fields/functions */
for
(
i
=
0
;
i
<
nitems
;
i
++
)
{
if
(
!
items
[
i
]
->
result_as_longlong
())
{
/* Do not convert anything if a string field/function is present */
if
(
!
items
[
i
]
->
const_item
()
&&
items
[
i
]
->
result_type
()
==
STRING_RESULT
)
{
i
=
nitems
;
break
;
}
continue
;
}
if
((
res
=
items
[
i
]
->
real_item
()
->
type
())
==
Item
::
FIELD_ITEM
&&
items
[
i
]
->
result_type
()
!=
INT_RESULT
)
{
field
=
((
Item_field
*
)
items
[
i
]
->
real_item
())
->
field
;
break
;
}
else
if
(
res
==
Item
::
FUNC_ITEM
)
{
field
=
items
[
i
]
->
tmp_table_field_from_field_type
(
0
);
if
(
field
)
field
->
move_field
(
buff
,
&
null_byte
,
0
);
break
;
}
}
if
(
field
)
{
/* Check the rest of the list for presence of a string field/function. */
for
(
i
++
;
i
<
nitems
;
i
++
)
{
if
(
!
items
[
i
]
->
const_item
()
&&
items
[
i
]
->
result_type
()
==
STRING_RESULT
&&
!
items
[
i
]
->
result_as_longlong
())
{
if
(
res
==
Item
::
FUNC_ITEM
)
delete
field
;
field
=
0
;
break
;
}
}
}
/*
If the first item is a date/time function then its result should be
compared as int
*/
if
(
field
)
/* Suppose we are comparing dates */
type
[
0
]
=
INT_RESULT
;
else
type
[
0
]
=
items
[
0
]
->
result_type
();
for
(
i
=
0
;
i
<
nitems
;
i
++
)
{
Item_result
result
=
items
[
i
]
->
result_type
();
if
(
field
&&
((
!
items
[
i
]
->
const_item
()
&&
items
[
i
]
->
result_as_longlong
())
||
(
items
[
i
]
->
const_item
()
&&
convert_constant_item
(
thd
,
field
,
&
items
[
i
]))))
result
=
INT_RESULT
;
type
[
0
]
=
item_cmp_type
(
type
[
0
],
result
);
}
if
(
res
==
Item
::
FUNC_ITEM
&&
field
)
delete
field
;
type
[
0
]
=
items
[
0
]
->
result_type
();
for
(
i
=
1
;
i
<
nitems
;
i
++
)
type
[
0
]
=
item_cmp_type
(
type
[
0
],
items
[
i
]
->
result_type
());
}
static
void
my_coll_agg_error
(
DTCollation
&
c1
,
DTCollation
&
c2
,
...
...
@@ -1021,8 +916,30 @@ void Item_func_between::fix_length_and_dec()
if
(
!
args
[
0
]
||
!
args
[
1
]
||
!
args
[
2
])
return
;
agg_cmp_type
(
thd
,
&
cmp_type
,
args
,
3
);
if
(
cmp_type
==
STRING_RESULT
)
agg_arg_charsets
(
cmp_collation
,
args
,
3
,
MY_COLL_CMP_CONV
);
if
(
cmp_type
==
STRING_RESULT
&&
agg_arg_charsets
(
cmp_collation
,
args
,
3
,
MY_COLL_CMP_CONV
))
return
;
/*
Make a special case of compare with date/time and longlong fields.
They are compared as integers, so for const item this time-consuming
conversion can be done only once, not for every single comparison
*/
if
(
args
[
0
]
->
type
()
==
FIELD_ITEM
)
{
Field
*
field
=
((
Item_field
*
)
args
[
0
])
->
field
;
if
(
field
->
can_be_compared_as_longlong
())
{
/*
The following can't be recoded with || as convert_constant_item
changes the argument
*/
if
(
convert_constant_item
(
thd
,
field
,
&
args
[
1
]))
cmp_type
=
INT_RESULT
;
// Works for all types.
if
(
convert_constant_item
(
thd
,
field
,
&
args
[
2
]))
cmp_type
=
INT_RESULT
;
// Works for all types.
}
}
}
...
...
Write
Preview
Markdown
is supported
0%
Try again
or
attach a new file
Attach a file
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Cancel
Please
register
or
sign in
to comment