This sounds as if the server is forcing DEFAULT 0 clause, while it actually does not.
It does not really force the clause, because you wouldn't see it in SHOW CREATE TABLE, but it assumes it, just like it does e.g. for INT type.
Case in point, when we remove NO_ZERO_DATE, create table, then run the following insert statement:
insert into test(a) values (1);
|
It errors out with SQL Error (1364): Field 'ts' doesn't have a default value, which shows that the server respect the configuration and does not provide a default value.
It appears that in your experiment you also had sql_mode='...STRICT_ALL_TABLES...', which would indeed make this statement produce an error. Otherwise it would produce a warning of the same kind, and insert the zero value:
Here and further we use this configuration
|
MariaDB [test]> select @@version;
|
+-----------------+
|
| @@version |
|
+-----------------+
|
| 10.1.16-MariaDB |
|
+-----------------+
|
1 row in set (0.01 sec)
|
|
MariaDB [test]> select @@explicit_defaults_for_timestamp;
|
+-----------------------------------+
|
| @@explicit_defaults_for_timestamp |
|
+-----------------------------------+
|
| 1 |
|
+-----------------------------------+
|
1 row in set (0.00 sec)
|
MariaDB [test]> set sql_mode='ANSI';
|
Query OK, 0 rows affected (0.00 sec)
|
|
MariaDB [test]> create table test (a int, ts timestamp not null);
|
Query OK, 0 rows affected (0.70 sec)
|
|
MariaDB [test]> set sql_mode='ANSI,NO_ZERO_DATE';
|
Query OK, 0 rows affected (0.00 sec)
|
|
MariaDB [test]> insert into test (a) values (1);
|
Query OK, 1 row affected, 1 warning (0.07 sec)
|
|
MariaDB [test]> show warnings;
|
+---------+------+-----------------------------------------+
|
| Level | Code | Message |
|
+---------+------+-----------------------------------------+
|
| Warning | 1364 | Field 'ts' doesn't have a default value |
|
+---------+------+-----------------------------------------+
|
1 row in set (0.00 sec)
|
|
MariaDB [test]> select * from test;
|
+------+---------------------+
|
| a | ts |
|
+------+---------------------+
|
| 1 | 0000-00-00 00:00:00 |
|
+------+---------------------+
|
1 row in set (0.00 sec)
|
Why can't we use TIMESTAMP field like a normal data type, where we force the user to specify a value, but without providing a default?
In fact, with explicit_defaults_for_timestamp it does work exactly as a normal data type. The only difference is that there is also NO_ZERO_DATE which is by definition temporal-specific.
Lets forget about NO_ZERO_DATE for a moment and compare the "base" behavior for TIMESTAMP vs INTEGER.
With strict mode:
MariaDB [test]> set sql_mode='ANSI,STRICT_ALL_TABLES';
|
Query OK, 0 rows affected (0.00 sec)
|
Both tables can be created all right:
MariaDB [test]> create table test1 (a int, b int not null);
|
Query OK, 0 rows affected (0.35 sec)
|
|
MariaDB [test]> create table test2 (a int, ts timestamp not null);
|
Query OK, 0 rows affected (0.36 sec)
|
For both tables INSERT produces an error if it doesn't specify a value for the column in question:
MariaDB [test]> insert into test1 (a) values (1);
|
ERROR 1364 (HY000): Field 'b' doesn't have a default value
|
MariaDB [test]> insert into test2 (a) values (1);
|
ERROR 1364 (HY000): Field 'ts' doesn't have a default value
|
Now, without strict mode:
MariaDB [test]> set sql_mode='ANSI';
|
Query OK, 0 rows affected (0.00 sec)
|
MariaDB [test]> create table test1 (a int, b int not null);
|
Query OK, 0 rows affected (0.44 sec)
|
|
MariaDB [test]> create table test2 (a int, ts timestamp not null);
|
Query OK, 0 rows affected (0.37 sec)
|
For both tables, INSERT produces a warning and inserts zero:
MariaDB [test]> insert into test1 (a) values (1);
|
Query OK, 1 row affected, 1 warning (0.07 sec)
|
|
MariaDB [test]> show warnings;
|
+---------+------+----------------------------------------+
|
| Level | Code | Message |
|
+---------+------+----------------------------------------+
|
| Warning | 1364 | Field 'b' doesn't have a default value |
|
+---------+------+----------------------------------------+
|
1 row in set (0.00 sec)
|
|
MariaDB [test]> insert into test2 (a) values (1);
|
Query OK, 1 row affected, 1 warning (0.07 sec)
|
|
MariaDB [test]> show warnings;
|
+---------+------+-----------------------------------------+
|
| Level | Code | Message |
|
+---------+------+-----------------------------------------+
|
| Warning | 1364 | Field 'ts' doesn't have a default value |
|
+---------+------+-----------------------------------------+
|
1 row in set (0.00 sec)
|
MariaDB [test]> select * from test1;
|
+------+---+
|
| a | b |
|
+------+---+
|
| 1 | 0 |
|
+------+---+
|
1 row in set (0.00 sec)
|
|
MariaDB [test]> select * from test2;
|
+------+---------------------+
|
| a | ts |
|
+------+---------------------+
|
| 1 | 0000-00-00 00:00:00 |
|
+------+---------------------+
|
1 row in set (0.00 sec)
|
It does not really force the clause, because you wouldn't see it in SHOW CREATE TABLE, but it assumes it, just like it does e.g. for INT type.
It appears that in your experiment you also had sql_mode='...STRICT_ALL_TABLES...', which would indeed make this statement produce an error. Otherwise it would produce a warning of the same kind, and insert the zero value:
Here and further we use this configuration
| @@version |
| 10.1.16-MariaDB |
| @@explicit_defaults_for_timestamp |
| 1 |
Query OK, 1 row affected, 1 warning (0.07 sec)
MariaDB [test]> show warnings;
| a | ts |
| 1 | 0000-00-00 00:00:00 |
In fact, with explicit_defaults_for_timestamp it does work exactly as a normal data type. The only difference is that there is also NO_ZERO_DATE which is by definition temporal-specific.
Lets forget about NO_ZERO_DATE for a moment and compare the "base" behavior for TIMESTAMP vs INTEGER.
With strict mode:
Both tables can be created all right:
For both tables INSERT produces an error if it doesn't specify a value for the column in question:
MariaDB [test]> insert into test2 (a) values (1);
Now, without strict mode:
For both tables, INSERT produces a warning and inserts zero:
Query OK, 1 row affected, 1 warning (0.07 sec)
MariaDB [test]> show warnings;
+---------+------+----------------------------------------+
1 row in set (0.00 sec)
MariaDB [test]> insert into test2 (a) values (1);
Query OK, 1 row affected, 1 warning (0.07 sec)
MariaDB [test]> show warnings;
+---------+------+-----------------------------------------+
| Level | Code | Message |
+---------+------+-----------------------------------------+
| a | b |
| 1 | 0 |
| a | ts |
| 1 | 0000-00-00 00:00:00 |