I have a MySql 5.7 transaction table with a DATETIME
column, Transaction_Date
, that is indexed. My Python 3.8.5 program is interested in retrieving the maximum transaction date on the table (ignoring the time portion). There are two possible queries (maybe even more):
select date(max(Transaction_Date)) from `transaction`
and
select max(date(Transaction_Date)) from `transaction`
However, depending on which query I use, pymysql
or mysql.connector
(it doesn't matter which one I use) returns me a different data type as the result, i.e. a date.datetime
instance for the first query and a str
for the second:
The Table:
CREATE TABLE `transaction` (
`Transaction_ID` varchar(32) NOT NULL,
`Transaction_Date` datetime NOT NULL
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
ALTER TABLE `transaction`
ADD PRIMARY KEY (`Transaction_ID`),
ADD KEY `Transaction_Date` (`Transaction_Date`);
The Program:
import pymysql
database = 'xxxx'
user_id = 'xxxx'
password = 'xxxx'
conn = pymysql.connect(db=database, user=user_id, passwd=password, charset='utf8mb4', use_unicode=True)
cursor = conn.cursor()
cursor.execute('select date(max(Transaction_Date)) from `transaction`')
row = cursor.fetchone()
d = row[0]
print(d, type(d))
cursor.execute('select max(date(Transaction_Date)) from `transaction`')
row = cursor.fetchone()
d = row[0]
print(d, type(d))
Prints:
2021-01-19 <class 'datetime.date'>
2021-01-19 <class 'str'>
Can anyone explain why a datetime.date
is not returned for the second query? For what it's worth, I have another table with a DATE
column and when I select the MAX
of that column I am returned a datetime.date
instance. So why am I not returned a datetime.date
for a MAX(DATE(column_name))
?
Update
mysql> create temporary table t1 as select max(date(Transaction_Date)) as d from `transaction`;
Query OK, 1 row affected (0.20 sec)
Records: 1 Duplicates: 0 Warnings: 0
mysql> show columns from t1;
+-------+------+------+-----+---------+-------+
| Field | Type | Null | Key | Default | Extra |
+-------+------+------+-----+---------+-------+
| d | date | YES | | NULL | |
+-------+------+------+-----+---------+-------+
1 row in set (0.01 sec)
This is what I would expect, so it is quite a puzzle.
I looked through pymysql
source and some MySQL documentation. It looks like the database server returns field descriptors, which the module then uses to set a class on the value, there are various converters available: https://github.com/PyMySQL/PyMySQL/blob/master/pymysql/converters.py. At the bottom, it maps field types to the method.
The database server is describing max(date)
as a VAR_STRING, so the module proceeds accordingly. I'm not sure of the specific reason for this description, which I suppose is the core of your question. It would take some digging through MySQL source, the documentation is not very detailed.
As a workaround, casting the result to a date does make it work as expected:
select cast(max(date(Transaction_Date)) as date) from transaction