Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

expression: Timestamp literal with time zone offset #57845

Open
wants to merge 5 commits into
base: master
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from 2 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
31 changes: 29 additions & 2 deletions pkg/expression/builtin_time.go
Original file line number Diff line number Diff line change
Expand Up @@ -67,7 +67,34 @@ var (
durationPattern = regexp.MustCompile(`^\s*[-]?(((\d{1,2}\s+)?0*\d{0,3}(:0*\d{1,2}){0,2})|(\d{1,7}))?(\.\d*)?\s*$`)

// timestampPattern checks whether a string matches the format of timestamp.
timestampPattern = regexp.MustCompile(`^\s*0*\d{1,4}([^\d]0*\d{1,2}){2}\s+(0*\d{0,2}([^\d]0*\d{1,2}){2})?(\.\d*)?\s*$`)
timestampPattern = regexp.MustCompile(`^` +
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

This commented multi line regexp is a big improvement!

// Skip any spaces or zeros
`\s*0*` +
// Year 1-4 digits
`\d{1,4}` +
// TODO: Add warning if non '-' separator in ParseTime
// 1 or 2 digit Month and Day
// Any non-digit as separator
// Any leading 0's for Month/Day
`([^\d]0*\d{1,2}){2}` +
// At least one space between Date and Time parts
`\s+` +
// Hour is mandatory
// Any number of leading zeroes
// 1-2 Hour digits
`0*\d{1,2}` +
Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

This is a fix to allow SELECT TIMESTAMP '2024-01-01 18'

// Minutes or Minutes:Seconds are optional
// Any non-digit separator before Minute and Second parts
// Any number of leading zeroes in Min/Sec!
// 1-2 digit minutes/seconds
`([^\d]0*\d{1,2}){0,2}` +
Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Another fix for allowing SELECT TIMESTAMP '2024-01-01 18[:00]'. SELECT TIMESTAMP '2024-01-01 18:00:00' did already work.

// Optionally decimal comma (.) and 0 or more fractional seconds
// (regardless if min/sec exists or not...)
`(\.\d*)?` +
// Optionally time zone offset, must be +/-HH:MM format
`([+-]\d{2}[:]\d{2})?` +
Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

MySQL has this part very strict. It is more strict than what types.ParseTime parses the same string, so I think we should be more strict here as well, to avoid the situation where customer starts to use a more relaxed syntax, and we need to make it more strict.

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Yes, I agree with that

// Optionally ending with spaces.
`\s*$`)

// datePattern determine whether to match the format of date.
datePattern = regexp.MustCompile(`^\s*((0*\d{1,4}([^\d]0*\d{1,2}){2})|(\d{2,4}(\d{2}){2}))\s*$`)
Expand Down Expand Up @@ -4680,7 +4707,7 @@ func (c *timestampLiteralFunctionClass) getFunction(ctx BuildContext, args []Exp
return nil, err
}
if !timestampPattern.MatchString(str) {
return nil, types.ErrWrongValue.GenWithStackByArgs(types.DateTimeStr, str)
return nil, types.ErrWrongValue2.GenWithStackByArgs(types.DateTimeStr, str)
}
tm, err := types.ParseTime(ctx.GetEvalCtx().TypeCtx(), str, mysql.TypeDatetime, types.GetFsp(str))
if err != nil {
Expand Down
173 changes: 173 additions & 0 deletions tests/integrationtest/r/types/time.result
Original file line number Diff line number Diff line change
@@ -0,0 +1,173 @@
set @@time_zone = '+00:00';
select timestamp '2024-01-01 14:00:00+01:00';
timestamp '2024-01-01 14:00:00+01:00'
2024-01-01 13:00:00
select timestamp '2024-01-01 14:00:00+01:59';
timestamp '2024-01-01 14:00:00+01:59'
2024-01-01 12:01:00
select timestamp '2024-01-01 14:00:00+01:60';
Error 1292 (22007): Incorrect datetime value: '2024-01-01 14:00:00+01:60'
select timestamp '2024-01-01 14:00:00-01:00';
timestamp '2024-01-01 14:00:00-01:00'
2024-01-01 15:00:00
select timestamp '2024-01-01 14:00:00-01:59';
timestamp '2024-01-01 14:00:00-01:59'
2024-01-01 15:59:00
select timestamp '2024-01-01 14:00:00-01:60';
Error 1292 (22007): Incorrect datetime value: '2024-01-01 14:00:00-01:60'
select timestamp '2024-01-01 14:00:00+14:00';
timestamp '2024-01-01 14:00:00+14:00'
2024-01-01 00:00:00
select timestamp '2024-01-01 14:00:00-14:00';
timestamp '2024-01-01 14:00:00-14:00'
2024-01-02 04:00:00
select timestamp '2024-01-01 14:00:00+14:01';
Error 1292 (22007): Incorrect datetime value: '2024-01-01 14:00:00+14:01'
select timestamp '2024-01-01 14:00:00-14:01';
Error 1292 (22007): Incorrect datetime value: '2024-01-01 14:00:00-14:01'
select timestamp '2024-01-01 14:00:00+14:59';
Error 1292 (22007): Incorrect datetime value: '2024-01-01 14:00:00+14:59'
select timestamp '2024-01-01 14:00:00-14:59';
Error 1292 (22007): Incorrect datetime value: '2024-01-01 14:00:00-14:59'
select timestamp '2024-01-01 14:00:00+15:00';
Error 1292 (22007): Incorrect datetime value: '2024-01-01 14:00:00+15:00'
select timestamp '2024-01-01 14:00:00-15:00';
Error 1292 (22007): Incorrect datetime value: '2024-01-01 14:00:00-15:00'
select timestamp '2024';
Error 1525 (HY000): Incorrect datetime value: '2024'
select timestamp '2024-01';
Error 1525 (HY000): Incorrect datetime value: '2024-01'
select timestamp '2024-1';
Error 1525 (HY000): Incorrect datetime value: '2024-1'
select timestamp '2024-01-01';
Error 1525 (HY000): Incorrect datetime value: '2024-01-01'
select timestamp '2024-1-1';
Error 1525 (HY000): Incorrect datetime value: '2024-1-1'
select timestamp '2024-01-1';
Error 1525 (HY000): Incorrect datetime value: '2024-01-1'
select timestamp '2024-1-01';
Error 1525 (HY000): Incorrect datetime value: '2024-1-01'
select timestamp '2024-01-01 14.999999999999';
Error 1292 (22007): Incorrect datetime value: '2024-01-01 14.999999999999'
select timestamp '2024-01-01 14.888888888888';
Error 1292 (22007): Incorrect datetime value: '2024-01-01 14.888888888888'
select timestamp '2024-01-01 14.66';
Error 1292 (22007): Incorrect datetime value: '2024-01-01 14.66'
select timestamp '2024-01-01 14.555555555555';
Error 1292 (22007): Incorrect datetime value: '2024-01-01 14.555555555555'
select timestamp '2024-01-01 14.0000111';
Error 1292 (22007): Incorrect datetime value: '2024-01-01 14.0000111'
select timestamp '2024-01-01 14.000011';
timestamp '2024-01-01 14.000011'
2024-01-01 14:11:00.000000
select timestamp '2024-01-01 14.55';
timestamp '2024-01-01 14.55'
2024-01-01 14:55:00.00
select timestamp '2024-01-01 14.9';
timestamp '2024-01-01 14.9'
2024-01-01 14:09:00.0
select timestamp '2024-01-01 14.0000000000001';
timestamp '2024-01-01 14.0000000000001'
2024-01-01 14:01:00.000000
select timestamp '2024-01-01 14:00.0000000000001';
timestamp '2024-01-01 14:00.0000000000001'
2024-01-01 14:00:01.000000
select timestamp '2024-01-01 14.';
timestamp '2024-01-01 14.'
2024-01-01 14:00:00
select timestamp '2024-01-01 14:00...';
Error 1525 (HY000): Incorrect datetime value: '2024-01-01 14:00...'
select timestamp '2024-01-01 14:00::';
Error 1525 (HY000): Incorrect datetime value: '2024-01-01 14:00::'
select timestamp '2024-01-01 14:00:';
Error 1525 (HY000): Incorrect datetime value: '2024-01-01 14:00:'
select timestamp '2024-01-01 14:00:00.0000000000001';
timestamp '2024-01-01 14:00:00.0000000000001'
2024-01-01 14:00:00.000000
select timestamp '2024-01-01 14:00:00.999999999999';
timestamp '2024-01-01 14:00:00.999999999999'
2024-01-01 14:00:01.000000
select timestamp '0-02-03 17';
timestamp '0-02-03 17'
2000-02-03 17:00:00
select timestamp '4-01-01 14';
timestamp '4-01-01 14'
2004-01-01 14:00:00
select timestamp '24-01-01 14';
timestamp '24-01-01 14'
2024-01-01 14:00:00
select timestamp '024-01-01 14';
timestamp '024-01-01 14'
0024-01-01 14:00:00
select timestamp '124-01-01 14';
timestamp '124-01-01 14'
0124-01-01 14:00:00
select timestamp '02024-01-01 14';
timestamp '02024-01-01 14'
2024-01-01 14:00:00
select timestamp '000002024-00001-00001 00014';
timestamp '000002024-00001-00001 00014'
2024-01-01 14:00:00
select timestamp '000002024-00001-00001 00014:000001:000001';
timestamp '000002024-00001-00001 00014:000001:000001'
2024-01-01 14:01:01
select timestamp '000002024-00001-00001 00014:000001:000001+001:001';
Error 1525 (HY000): Incorrect datetime value: '000002024-00001-00001 00014:000001:000001+001:001'
select timestamp '000002024-00001-00001 00014:000001:000001+01:001';
Error 1525 (HY000): Incorrect datetime value: '000002024-00001-00001 00014:000001:000001+01:001'
select timestamp '000002024-00001-00001 00014:000001:000001+001:01';
Error 1525 (HY000): Incorrect datetime value: '000002024-00001-00001 00014:000001:000001+001:01'
select timestamp '2024-01-01 14:01:01+1:1';
Error 1525 (HY000): Incorrect datetime value: '2024-01-01 14:01:01+1:1'
select timestamp '2024-01-01 14:01:01+01:1';
Error 1525 (HY000): Incorrect datetime value: '2024-01-01 14:01:01+01:1'
select timestamp '2024-01-01 14:01:01+1:01';
Error 1525 (HY000): Incorrect datetime value: '2024-01-01 14:01:01+1:01'
select timestamp '2024-01-01 14:01:01+01;01';
Error 1525 (HY000): Incorrect datetime value: '2024-01-01 14:01:01+01;01'
select timestamp '2024-01-01 14:01:01+01-01';
Error 1525 (HY000): Incorrect datetime value: '2024-01-01 14:01:01+01-01'
select timestamp '2024-01-01 14:01:01+0101';
Error 1525 (HY000): Incorrect datetime value: '2024-01-01 14:01:01+0101'
select timestamp '2024-1-1 0';
timestamp '2024-1-1 0'
2024-01-01 00:00:00
select timestamp '2024-1-1 1';
timestamp '2024-1-1 1'
2024-01-01 01:00:00
select timestamp '2024-1-1 1:1';
timestamp '2024-1-1 1:1'
2024-01-01 01:01:00
select timestamp '2024-1-1 1:1:1.11';
timestamp '2024-1-1 1:1:1.11'
2024-01-01 01:01:01.11
select timestamp '2024-01-01 0';
timestamp '2024-01-01 0'
2024-01-01 00:00:00
select timestamp '2024-01-01 1';
timestamp '2024-01-01 1'
2024-01-01 01:00:00
select timestamp '2024-01-01 0';
timestamp '2024-01-01 0'
2024-01-01 00:00:00
select timestamp '2024-01-01 14';
timestamp '2024-01-01 14'
2024-01-01 14:00:00
select timestamp '2024-01-01 14:00';
timestamp '2024-01-01 14:00'
2024-01-01 14:00:00
select timestamp '2024-01-01 14:00:00';
timestamp '2024-01-01 14:00:00'
2024-01-01 14:00:00
select timestamp '2024-01-01 14:00:00.010';
timestamp '2024-01-01 14:00:00.010'
2024-01-01 14:00:00.010
select timestamp '2024-01-01 14:00:00.123456789';
timestamp '2024-01-01 14:00:00.123456789'
2024-01-01 14:00:00.123457
select timestamp '2024-01-01 14:00:00.123456789+02:00';
timestamp '2024-01-01 14:00:00.123456789+02:00'
2024-01-01 12:00:00.123457
select timestamp '2024-01-01 14+01:00';
timestamp '2024-01-01 14+01:00'
2024-01-01 14:01:00
128 changes: 128 additions & 0 deletions tests/integrationtest/t/types/time.test
Original file line number Diff line number Diff line change
@@ -0,0 +1,128 @@
--enable_warnings
set @@time_zone = '+00:00';
select timestamp '2024-01-01 14:00:00+01:00';
select timestamp '2024-01-01 14:00:00+01:59';
# TODO: Fix the error difference between TiDB and MySQL:
# TiDB:
# Error 1292 (22007): Incorrect datetime value: '2024-01-01 14:00:00+01:60'
# MySQL:
# Error 1525 (HY000): Incorrect DATETIME value: '2024-01-01 14:00:00+01:60'
-- error 1292
select timestamp '2024-01-01 14:00:00+01:60';
select timestamp '2024-01-01 14:00:00-01:00';
select timestamp '2024-01-01 14:00:00-01:59';
-- error 1292
select timestamp '2024-01-01 14:00:00-01:60';
select timestamp '2024-01-01 14:00:00+14:00';
select timestamp '2024-01-01 14:00:00-14:00';
-- error 1292
select timestamp '2024-01-01 14:00:00+14:01';
-- error 1292
select timestamp '2024-01-01 14:00:00-14:01';
-- error 1292
select timestamp '2024-01-01 14:00:00+14:59';
-- error 1292
select timestamp '2024-01-01 14:00:00-14:59';
-- error 1292
select timestamp '2024-01-01 14:00:00+15:00';
-- error 1292
select timestamp '2024-01-01 14:00:00-15:00';

# TODO: verify how MySQL checks the TIMSTAMP literal as DATETIME pattern
-- error 1525
select timestamp '2024';
-- error 1525
select timestamp '2024-01';
-- error 1525
select timestamp '2024-1';
-- error 1525
select timestamp '2024-01-01';
-- error 1525
select timestamp '2024-1-1';
-- error 1525
select timestamp '2024-01-1';
-- error 1525
select timestamp '2024-1-01';

-- error 1292
select timestamp '2024-01-01 14.999999999999';
-- error 1292
select timestamp '2024-01-01 14.888888888888';
-- error 1292
select timestamp '2024-01-01 14.66';
-- error 1292
select timestamp '2024-01-01 14.555555555555';
-- error 1292
select timestamp '2024-01-01 14.0000111';
# TODO: Fix the minor difference TiDB:
# 2024-01-01 14:11:00.000000
# and MySQL:
# 2024-01-01 14:11:00
select timestamp '2024-01-01 14.000011';
select timestamp '2024-01-01 14.55';
select timestamp '2024-01-01 14.9';
select timestamp '2024-01-01 14.0000000000001';
select timestamp '2024-01-01 14:00.0000000000001';
select timestamp '2024-01-01 14.';
# MySQL allows this! But gives a warning that '.' as delimiter is deprecated
-- error 1525
select timestamp '2024-01-01 14:00...';
# MySQL give warning, but accepts it
-- error 1525
select timestamp '2024-01-01 14:00::';
# MySQL give warning, but accepts it
-- error 1525
select timestamp '2024-01-01 14:00:';
select timestamp '2024-01-01 14:00:00.0000000000001';
select timestamp '2024-01-01 14:00:00.999999999999';

# MySQL will set year '0000', while and TiDB '2000'!!!
select timestamp '0-02-03 17';
# 1-3 digit year is OK!
# MySQL will set year '0004', while TiDB '2004'!!!
select timestamp '4-01-01 14';
select timestamp '24-01-01 14';
select timestamp '024-01-01 14';
select timestamp '124-01-01 14';
# any amount of 0 prefixes is OK
select timestamp '02024-01-01 14';
select timestamp '000002024-00001-00001 00014';
select timestamp '000002024-00001-00001 00014:000001:000001';

# No extra prefix zeros in time zone offset!
-- error 1525
select timestamp '000002024-00001-00001 00014:000001:000001+001:001';
-- error 1525
select timestamp '000002024-00001-00001 00014:000001:000001+01:001';
-- error 1525
select timestamp '000002024-00001-00001 00014:000001:000001+001:01';
-- error 1525
select timestamp '2024-01-01 14:01:01+1:1';
-- error 1525
select timestamp '2024-01-01 14:01:01+01:1';
-- error 1525
select timestamp '2024-01-01 14:01:01+1:01';
-- error 1525
select timestamp '2024-01-01 14:01:01+01;01';
-- error 1525
select timestamp '2024-01-01 14:01:01+01-01';
-- error 1525
select timestamp '2024-01-01 14:01:01+0101';

select timestamp '2024-1-1 0';
select timestamp '2024-1-1 1';
select timestamp '2024-1-1 1:1';
select timestamp '2024-1-1 1:1:1.11';
select timestamp '2024-01-01 0';
select timestamp '2024-01-01 1';
select timestamp '2024-01-01 0';
select timestamp '2024-01-01 14';
select timestamp '2024-01-01 14:00';
select timestamp '2024-01-01 14:00:00';
select timestamp '2024-01-01 14:00:00.010';
select timestamp '2024-01-01 14:00:00.123456789';
select timestamp '2024-01-01 14:00:00.123456789+02:00';
select timestamp '2024-01-01 14+01:00';


# TODO: Also test if there are difference between explicitly give the timestamp/datetime as literal/string or having it from a varchar in a table