From d2433696380fb43bb2ffaf5e1b2aabebd1354bc2 Mon Sep 17 00:00:00 2001
From: dpsutton <dan@dpsutton.com>
Date: Tue, 8 Jun 2021 13:56:53 -0500
Subject: [PATCH] Pass UTF8 as a literal into grouping by a bytes->temporal
 column (#16336)

Repro:
db setup:

```sql
create table wut2 (t bytea, ts text);
insert into wut2 (t, ts) values ('20210421164300'::bytea, '20210421164300');
```

Mark t as :Coercion/YYYYMMDDHHMMSSBytes->Temporal, ts as
:Coercion/YYYYMMDDHHMMSSString->Temporal

Do a simple query, and then aggregate count by the two dates. ts
should succeed and t fails.

We are passing in the UTF8 as a parameter rather than just emitting a
literal.

Before:

```clojure
{:sql
 "-- Metabase\nSELECT CAST(to_timestamp(convert_from(\"public\".\"wut\".\"t\", ?), 'YYYYMMDDHH24MISS') AS date) AS \"t\", count(*) AS \"count\" FROM \"public\".\"wut\" GROUP BY CAST(to_timestamp(convert_from(\"public\".\"wut\".\"t\", ?), 'YYYYMMDDHH24MISS') AS date) ORDER BY CAST(to_timestamp(convert_from(\"public\".\"wut\".\"t\", ?), 'YYYYMMDDHH24MISS') AS date) ASC",
 :params ("UTF8" "UTF8" "UTF8"),
 :type :invalid-query}
```

After:

```sql
SELECT CAST(to_timestamp(convert_from(\"public\".\"wut\".\"t\", 'UTF8'), 'YYYYMMDDHH24MISS') AS date) AS \"t\",
       count(*) AS \"count\" FROM \"public\".\"wut\"
GROUP BY CAST(to_timestamp(convert_from(\"public\".\"wut\".\"t\", 'UTF8'), 'YYYYMMDDHH24MISS') AS date)
ORDER BY CAST(to_timestamp(convert_from(\"public\".\"wut\".\"t\", 'UTF8'), 'YYYYMMDDHH24MISS') AS date) ASC
```

Note there's a lot of extra casting that perhaps we can clean up
---
 src/metabase/driver/postgres.clj | 2 +-
 1 file changed, 1 insertion(+), 1 deletion(-)

diff --git a/src/metabase/driver/postgres.clj b/src/metabase/driver/postgres.clj
index 14253778727..a56c9772808 100644
--- a/src/metabase/driver/postgres.clj
+++ b/src/metabase/driver/postgres.clj
@@ -128,7 +128,7 @@
 (defmethod sql.qp/cast-temporal-byte [:postgres :Coercion/YYYYMMDDHHMMSSBytes->Temporal]
   [driver _coercion-strategy expr]
   (sql.qp/cast-temporal-string driver :Coercion/YYYYMMDDHHMMSSString->Temporal
-                               (hsql/call :convert_from expr "UTF8")))
+                               (hsql/call :convert_from expr (hx/literal "UTF8"))))
 
 (defn- date-trunc [unit expr] (hsql/call :date_trunc (hx/literal unit) (hx/->timestamp expr)))
 (defn- extract    [unit expr] (hsql/call :extract    unit              (hx/->timestamp expr)))
-- 
GitLab