Browse Source

SQL: Implement TO_CHAR() function (#66486)

SQL: Implement the TO_CHAR() function

* The implementation is according to PostgreSQL 13 specs:
https://www.postgresql.org/docs/13/functions-formatting.html
* Tested against actual output from PostgreSQL 13 using randomized inputs
* All the Postgres formats are supported, there is also partial supports
 for the modifiers (`FM` and `TH` are supported)
* Random unit test data generator script in case we need to upgrade the
 formatter in the future
* Documentation
* Integration tests

Co-authored-by: Michał Wąsowicz <mwasowicz7@gmail.com>
Co-authored-by: Andras Palinkas <andras.palinkas@elastic.co>
Andras Palinkas 4 years ago
parent
commit
f855e5235c
17 changed files with 1230 additions and 18 deletions
  1. 53 7
      docs/reference/sql/functions/date-time.asciidoc
  2. 3 2
      docs/reference/sql/functions/index.asciidoc
  3. 1 0
      x-pack/plugin/sql/qa/server/src/main/resources/command.csv-spec
  4. 104 0
      x-pack/plugin/sql/qa/server/src/main/resources/datetime.csv-spec
  5. 31 0
      x-pack/plugin/sql/qa/server/src/main/resources/docs/docs.csv-spec
  6. 2 0
      x-pack/plugin/sql/src/main/java/org/elasticsearch/xpack/sql/expression/function/SqlFunctionRegistry.java
  7. 27 9
      x-pack/plugin/sql/src/main/java/org/elasticsearch/xpack/sql/expression/function/scalar/datetime/DateTimeFormatProcessor.java
  8. 42 0
      x-pack/plugin/sql/src/main/java/org/elasticsearch/xpack/sql/expression/function/scalar/datetime/ToChar.java
  9. 377 0
      x-pack/plugin/sql/src/main/java/org/elasticsearch/xpack/sql/expression/function/scalar/datetime/ToCharFormatter.java
  10. 4 0
      x-pack/plugin/sql/src/main/java/org/elasticsearch/xpack/sql/expression/function/scalar/whitelist/InternalSqlScriptUtils.java
  11. 1 0
      x-pack/plugin/sql/src/main/resources/org/elasticsearch/xpack/sql/plugin/sql_whitelist.txt
  12. 17 0
      x-pack/plugin/sql/src/test/java/org/elasticsearch/xpack/sql/analysis/analyzer/VerifierErrorMessagesTests.java
  13. 153 0
      x-pack/plugin/sql/src/test/java/org/elasticsearch/xpack/sql/expression/function/scalar/datetime/DateTimeToCharProcessorTests.java
  14. 241 0
      x-pack/plugin/sql/src/test/java/org/elasticsearch/xpack/sql/expression/function/scalar/datetime/ToCharTestScript.java
  15. 16 0
      x-pack/plugin/sql/src/test/java/org/elasticsearch/xpack/sql/planner/QueryTranslatorTests.java
  16. 108 0
      x-pack/plugin/sql/src/test/resources/org/elasticsearch/xpack/sql/expression/function/scalar/datetime/tochar-generated.csv
  17. 50 0
      x-pack/plugin/sql/src/test/resources/org/elasticsearch/xpack/sql/expression/function/scalar/datetime/tochar-test-timezones.txt

+ 53 - 7
docs/reference/sql/functions/date-time.asciidoc

@@ -791,15 +791,12 @@ If any of the two arguments is `null` or the pattern is an empty string `null` i
 
 [NOTE]
 If the 1st argument is of type `time`, then pattern specified by the 2nd argument cannot contain date related units
-(e.g. 'dd', 'MM', 'YYYY', etc.). If it contains such units an error is returned.
-
-*Special Cases*
-
-- Format specifier `F` will be working similar to format specifier `f`.
+(e.g. 'dd', 'MM', 'YYYY', etc.). If it contains such units an error is returned. +
+Format specifier `F` will be working similar to format specifier `f`.
 It will return the fractional part of seconds, and the number of digits will be same as of the number of `Fs` provided as input (up to 9 digits).
 Result will contain `0` appended in the end to match with number of `F` provided.
-e.g.: for a time part `10:20:30.1234` and pattern `HH:mm:ss.FFFFFF`, the output string of the function would be: `10:20:30.123400`.
-- Format Specifier `y` will return year-of-era instead of one/two low-order digits.
+e.g.: for a time part `10:20:30.1234` and pattern `HH:mm:ss.FFFFFF`, the output string of the function would be: `10:20:30.123400`. +
+Format specifier `y` will return year-of-era instead of one/two low-order digits.
 eg.: For year `2009`, `y` will be returning `2009` instead of `9`. For year `43`, `y` format specifier will return `43`.
 - Special characters like `"` , `\` and `%` will be returned as it is without any change. eg.: formatting date `17-sep-2020` with `%M` will return `%9`
 
@@ -818,6 +815,55 @@ include-tagged::{sql-specs}/docs/docs.csv-spec[formatDateTime]
 include-tagged::{sql-specs}/docs/docs.csv-spec[formatTime]
 --------------------------------------------------
 
+
+[[sql-functions-datetime-to_char]]
+==== `TO_CHAR`
+
+.Synopsis:
+[source, sql]
+--------------------------------------------------
+TO_CHAR(
+    date_exp/datetime_exp/time_exp, <1>
+    string_exp) <2>
+--------------------------------------------------
+
+*Input*:
+
+<1> date/datetime/time expression
+<2> format pattern
+
+*Output*: string
+
+*Description*: Returns the date/datetime/time as a string using the format specified in the 2nd argument. The formatting
+pattern conforms to
+https://www.postgresql.org/docs/13/functions-formatting.html[PostgreSQL Template Patterns for Date/Time Formatting].
+If any of the two arguments is `null` or the pattern is an empty string `null` is returned.
+
+[NOTE]
+If the 1st argument is of type `time`, then the pattern specified by the 2nd argument cannot contain date related units
+(e.g. 'dd', 'MM', 'YYYY', etc.). If it contains such units an error is returned. +
+The result of the patterns `TZ` and `tz` (time zone abbreviations) in some cases differ from the results returned by the `TO_CHAR`
+in PostgreSQL. The reason is that the time zone abbreviations specified by the JDK are different from the ones specified by PostgreSQL. 
+This function might show an actual time zone abbreviation instead of the generic `LMT` or empty string or offset returned by the PostgreSQL 
+implementation. The summer/daylight markers might also differ between the two implementations (e.g. will show `HT` instead of `HST` 
+for Hawaii). +
+The `FX`, `TM`, `SP` pattern modifiers are not supported and will show up as `FX`, `TM`, `SP` literals in the output.
+
+[source, sql]
+--------------------------------------------------
+include-tagged::{sql-specs}/docs/docs.csv-spec[toCharDate]
+--------------------------------------------------
+
+[source, sql]
+--------------------------------------------------
+include-tagged::{sql-specs}/docs/docs.csv-spec[toCharDateTime]
+--------------------------------------------------
+
+[source, sql]
+--------------------------------------------------
+include-tagged::{sql-specs}/docs/docs.csv-spec[toCharTime]
+--------------------------------------------------
+
 [[sql-functions-datetime-day]]
 ==== `DAY_OF_MONTH/DOM/DAY`
 

+ 3 - 2
docs/reference/sql/functions/index.asciidoc

@@ -59,13 +59,13 @@
 ** <<sql-functions-datetime-datetimeformat>>
 ** <<sql-functions-datetime-datetimeparse>>
 ** <<sql-functions-datetime-format>>
-** <<sql-functions-datetime-timeparse>>
 ** <<sql-functions-datetime-part>>
 ** <<sql-functions-datetime-trunc>>
 ** <<sql-functions-datetime-day>>
 ** <<sql-functions-datetime-dow>>
 ** <<sql-functions-datetime-doy>>
 ** <<sql-functions-datetime-dayname>>
+** <<sql-functions-datetime-extract>>
 ** <<sql-functions-datetime-hour>>
 ** <<sql-functions-datetime-isodow>>
 ** <<sql-functions-datetime-isoweek>>
@@ -76,10 +76,11 @@
 ** <<sql-functions-now>>
 ** <<sql-functions-datetime-second>>
 ** <<sql-functions-datetime-quarter>>
+** <<sql-functions-datetime-timeparse>>
+** <<sql-functions-datetime-to_char>>
 ** <<sql-functions-today>>
 ** <<sql-functions-datetime-week>>
 ** <<sql-functions-datetime-year>>
-** <<sql-functions-datetime-extract>>
 * <<sql-functions-search>>
 ** <<sql-functions-search-match>>
 ** <<sql-functions-search-query>>

+ 1 - 0
x-pack/plugin/sql/qa/server/src/main/resources/command.csv-spec

@@ -95,6 +95,7 @@ TIMESTAMP_ADD    |SCALAR
 TIMESTAMP_DIFF   |SCALAR
 TIME_PARSE       |SCALAR
 TODAY            |SCALAR
+TO_CHAR          |SCALAR
 WEEK             |SCALAR
 WEEK_OF_YEAR     |SCALAR         
 YEAR             |SCALAR         

+ 104 - 0
x-pack/plugin/sql/qa/server/src/main/resources/datetime.csv-spec

@@ -601,6 +601,110 @@ HAVING DATETIME_FORMAT(MAX(birth_date), 'dd')::integer > 20  ORDER BY 1 DESC;
 1961-02-26 00:00:00.000Z | 02
 ;
 
+selectToChar
+schema::df_date:s|df_datetime:s|df_time:s
+SELECT TO_CHAR('2020-04-05T11:22:33.123Z'::date, 'DD/MM/YYYY HH24:MI:SS.FF3') AS df_date,
+TO_CHAR('2020-04-05T11:22:33.123Z'::datetime, 'DD/MM/YYYY HH24:MI:SS.FF2') AS df_datetime,
+TO_CHAR('11:22:33.123456789Z'::time, 'HH24:MI:SS.FF2') AS df_time;
+
+       df_date          |    df_datetime         |   df_time
+------------------------+------------------------+----------------
+05/04/2020 00:00:00.000 | 05/04/2020 11:22:33.12 | 11:22:33.12
+;
+
+selectToCharWithField
+schema::birth_date:ts|gender:s|df_birth_date1:s|df_birth_date2:s|emp_no:i
+SELECT birth_date, gender, TO_CHAR(birth_date, 'MM/DD/YYYY') AS df_birth_date1, 
+TO_CHAR(birth_date, CONCAT(gender, 'MDD')) AS df_birth_date2, emp_no FROM test_emp WHERE emp_no BETWEEN 10047 AND 10057 ORDER BY emp_no;
+
+       birth_date       |    gender     |df_birth_date1 |df_birth_date2 |    emp_no     
+------------------------+---------------+---------------+---------------+---------------
+null                    |M              |null           |null           |10047          
+null                    |M              |null           |null           |10048          
+null                    |F              |null           |null           |10049          
+1958-05-21T00:00:00.000Z|M              |05/21/1958     |0521           |10050          
+1953-07-28T00:00:00.000Z|M              |07/28/1953     |0728           |10051          
+1961-02-26T00:00:00.000Z|M              |02/26/1961     |0226           |10052          
+1954-09-13T00:00:00.000Z|F              |09/13/1954     |13             |10053          
+1957-04-04T00:00:00.000Z|M              |04/04/1957     |0404           |10054          
+1956-06-06T00:00:00.000Z|M              |06/06/1956     |0606           |10055          
+1961-09-01T00:00:00.000Z|F              |09/01/1961     |1              |10056          
+1954-05-30T00:00:00.000Z|F              |05/30/1954     |30             |10057          
+;
+
+toCharWhere
+schema::birth_date:ts|df_birth_date:s|emp_no:i
+SELECT birth_date, TO_CHAR(birth_date, 'MM') AS df_birth_date, emp_no FROM test_emp
+WHERE TO_CHAR(birth_date, 'MM')::integer > 10 ORDER BY emp_no LIMIT 10;
+
+       birth_date       | df_birth_date |    emp_no     
+------------------------+---------------+---------------
+1959-12-03T00:00:00.000Z|12             |10003          
+1953-11-07T00:00:00.000Z|11             |10011          
+1952-12-24T00:00:00.000Z|12             |10020          
+1963-11-26T00:00:00.000Z|11             |10028          
+1956-12-13T00:00:00.000Z|12             |10029          
+1956-11-14T00:00:00.000Z|11             |10033          
+1962-12-29T00:00:00.000Z|12             |10034          
+1961-11-02T00:00:00.000Z|11             |10062          
+1952-11-13T00:00:00.000Z|11             |10066          
+1962-11-26T00:00:00.000Z|11             |10068          
+;
+
+toCharOrderBy
+schema::birth_date:ts|df_birth_date:s
+SELECT birth_date, TO_CHAR(birth_date, 'MM/DD/YYYY') AS df_birth_date FROM test_emp ORDER BY 2 DESC NULLS LAST LIMIT 10;
+
+       birth_date        | df_birth_date
+-------------------------+---------------
+1962-12-29 00:00:00.000Z | 12/29/1962
+1959-12-25 00:00:00.000Z | 12/25/1959
+1952-12-24 00:00:00.000Z | 12/24/1952
+1960-12-17 00:00:00.000Z | 12/17/1960
+1956-12-13 00:00:00.000Z | 12/13/1956
+1959-12-03 00:00:00.000Z | 12/03/1959
+1957-12-03 00:00:00.000Z | 12/03/1957
+1963-11-26 00:00:00.000Z | 11/26/1963
+1962-11-26 00:00:00.000Z | 11/26/1962
+1962-11-19 00:00:00.000Z | 11/19/1962
+;
+
+toCharGroupBy
+schema::count:l|df_birth_date:s
+SELECT count(*) AS count, TO_CHAR(birth_date, 'MM') AS df_birth_date FROM test_emp GROUP BY df_birth_date ORDER BY 1 DESC, 2 DESC;
+
+ count | df_birth_date
+-------+---------------
+10     | 09
+10     | 05
+10     | null
+9      | 10
+9      | 07
+8      | 11
+8      | 04
+8      | 02
+7      | 12
+7      | 06
+6      | 08
+6      | 01
+2      | 03
+;
+
+toCharHaving
+schema::max:ts|df_birth_date:s
+SELECT MAX(birth_date) AS max, TO_CHAR(birth_date, 'MM') AS df_birth_date FROM test_emp GROUP BY df_birth_date
+HAVING TO_CHAR(MAX(birth_date), 'DD')::integer > 20  ORDER BY 1 DESC;
+
+          max            | df_birth_date
+-------------------------+---------------
+1963-11-26 00:00:00.000Z | 11
+1963-07-22 00:00:00.000Z | 07
+1963-03-21 00:00:00.000Z | 03
+1962-12-29 00:00:00.000Z | 12
+1961-05-30 00:00:00.000Z | 05
+1961-02-26 00:00:00.000Z | 02
+;
+
 selectDateTimeParse
 schema::dp_date1:ts|dp_date2:ts
 SELECT DATETIME_PARSE('07/04/2020___11:22:33 Europe/Berlin', 'dd/MM/uuuu___HH:mm:ss VV') AS dp_date1,

+ 31 - 0
x-pack/plugin/sql/qa/server/src/main/resources/docs/docs.csv-spec

@@ -291,6 +291,7 @@ TIMESTAMP_ADD    |SCALAR
 TIMESTAMP_DIFF   |SCALAR
 TIME_PARSE       |SCALAR
 TODAY            |SCALAR
+TO_CHAR          |SCALAR
 WEEK             |SCALAR
 WEEK_OF_YEAR     |SCALAR         
 YEAR             |SCALAR         
@@ -2876,6 +2877,36 @@ SELECT DATETIME_FORMAT(CAST('11:22:33.987' AS TIME), 'HH mm ss.S') AS "time";
 // end::dateTimeFormatTime
 ;
 
+toCharDate
+// tag::toCharDate
+SELECT TO_CHAR(CAST('2020-04-05' AS DATE), 'DD/MM/YYYY') AS "date";
+
+      date
+------------------
+05/04/2020
+// end::toCharDate
+;
+
+toCharDateTime
+// tag::toCharDateTime
+SELECT TO_CHAR(CAST('2020-04-05T11:22:33.987654' AS DATETIME), 'DD/MM/YYYY HH24:MI:SS.FF2') AS "datetime";
+
+      datetime
+------------------
+05/04/2020 11:22:33.98
+// end::toCharDateTime
+;
+
+toCharTime
+// tag::toCharTime
+SELECT TO_CHAR(CAST('23:22:33.987' AS TIME), 'HH12 MI SS.FF1') AS "time";
+
+      time
+------------------
+11 22 33.9
+// end::toCharTime
+;
+
 // Cannot assert millis: https://github.com/elastic/elasticsearch/issues/54947
 dateTimeParse1-Ignore
 schema::datetime:ts

+ 2 - 0
x-pack/plugin/sql/src/main/java/org/elasticsearch/xpack/sql/expression/function/SqlFunctionRegistry.java

@@ -29,6 +29,7 @@ import org.elasticsearch.xpack.sql.expression.function.grouping.Histogram;
 import org.elasticsearch.xpack.sql.expression.function.scalar.Cast;
 import org.elasticsearch.xpack.sql.expression.function.scalar.Database;
 import org.elasticsearch.xpack.sql.expression.function.scalar.User;
+import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.ToChar;
 import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.CurrentDate;
 import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.CurrentDateTime;
 import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.CurrentTime;
@@ -184,6 +185,7 @@ public class SqlFunctionRegistry extends FunctionRegistry {
                 def(DateTimeParse.class, DateTimeParse::new, "DATETIME_PARSE"),
                 def(DateTrunc.class, DateTrunc::new, "DATETRUNC", "DATE_TRUNC"),
                 def(Format.class, Format::new, "FORMAT"),
+                def(ToChar.class, ToChar::new, "TO_CHAR"),
                 def(HourOfDay.class, HourOfDay::new, "HOUR_OF_DAY", "HOUR"),
                 def(IsoDayOfWeek.class, IsoDayOfWeek::new, "ISO_DAY_OF_WEEK", "ISODAYOFWEEK", "ISODOW", "IDOW"),
                 def(IsoWeekOfYear.class, IsoWeekOfYear::new, "ISO_WEEK_OF_YEAR", "ISOWEEKOFYEAR", "ISOWEEK", "IWOY", "IW"),

+ 27 - 9
x-pack/plugin/sql/src/main/java/org/elasticsearch/xpack/sql/expression/function/scalar/datetime/DateTimeFormatProcessor.java

@@ -19,6 +19,7 @@ import java.time.format.DateTimeFormatter;
 import java.time.temporal.TemporalAccessor;
 import java.util.Locale;
 import java.util.Objects;
+import java.util.function.Function;
 
 import static org.elasticsearch.xpack.sql.util.DateUtils.asTimeAtZone;
 
@@ -36,22 +37,38 @@ public class DateTimeFormatProcessor extends BinaryDateTimeProcessor {
         {"F", "S"},
         {"z", "X"}
     };
-    private final Formatter formatter;
 
+    private final Formatter formatter;
 
     public enum Formatter {
-        FORMAT,
-        DATE_TIME_FORMAT;
-
-        private String getJavaPattern(String pattern) {
-            if (this == FORMAT) {
+        FORMAT {
+            @Override
+            protected Function<TemporalAccessor, String> formatterFor(String pattern) {
+                if (pattern.isEmpty()) {
+                    return null;
+                }
                 for (String[] replacement : JAVA_TIME_FORMAT_REPLACEMENTS) {
                     pattern = pattern.replace(replacement[0], replacement[1]);
                 }
+                final String javaPattern = pattern;
+                return DateTimeFormatter.ofPattern(javaPattern, Locale.ROOT)::format;
             }
-            return pattern;
-        }
+        },
+        DATE_TIME_FORMAT {
+            @Override
+            protected Function<TemporalAccessor, String> formatterFor(String pattern) {
+                return DateTimeFormatter.ofPattern(pattern, Locale.ROOT)::format;
+            }
+        },
+        TO_CHAR {
+            @Override 
+            protected Function<TemporalAccessor, String> formatterFor(String pattern) {
+                return ToCharFormatter.ofPattern(pattern);
+            }
+        };
 
+        protected abstract Function<TemporalAccessor, String> formatterFor(String pattern);
+        
         public Object format(Object timestamp, Object pattern, ZoneId zoneId) {
             if (timestamp == null || pattern == null) {
                 return null;
@@ -77,7 +94,7 @@ public class DateTimeFormatProcessor extends BinaryDateTimeProcessor {
                 ta = asTimeAtZone((OffsetTime) timestamp, zoneId);
             }
             try {
-                return DateTimeFormatter.ofPattern(getJavaPattern(patternString), Locale.ROOT).format(ta);
+                return formatterFor(patternString).apply(ta);
             } catch (IllegalArgumentException | DateTimeException e) {
                 throw new SqlIllegalArgumentException(
                     "Invalid pattern [{}] is received for formatting date/time [{}]; {}",
@@ -87,6 +104,7 @@ public class DateTimeFormatProcessor extends BinaryDateTimeProcessor {
                 );
             }
         }
+
     }
 
     public DateTimeFormatProcessor(Processor source1, Processor source2, ZoneId zoneId, Formatter formatter) {

+ 42 - 0
x-pack/plugin/sql/src/main/java/org/elasticsearch/xpack/sql/expression/function/scalar/datetime/ToChar.java

@@ -0,0 +1,42 @@
+/*
+ * Copyright Elasticsearch B.V. and/or licensed to Elasticsearch B.V. under one
+ * or more contributor license agreements. Licensed under the Elastic License;
+ * you may not use this file except in compliance with the Elastic License.
+ */
+
+package org.elasticsearch.xpack.sql.expression.function.scalar.datetime;
+
+import org.elasticsearch.xpack.ql.expression.Expression;
+import org.elasticsearch.xpack.ql.expression.function.scalar.BinaryScalarFunction;
+import org.elasticsearch.xpack.ql.tree.NodeInfo;
+import org.elasticsearch.xpack.ql.tree.Source;
+
+import java.time.ZoneId;
+
+import static org.elasticsearch.xpack.sql.expression.function.scalar.datetime.DateTimeFormatProcessor.Formatter.TO_CHAR;
+
+public class ToChar extends BaseDateTimeFormatFunction {
+    public ToChar(Source source, Expression timestamp, Expression pattern, ZoneId zoneId) {
+        super(source, timestamp, pattern, zoneId);
+    }
+
+    @Override
+    protected DateTimeFormatProcessor.Formatter formatter() {
+        return TO_CHAR;
+    }
+
+    @Override
+    protected NodeInfo.NodeCtor3<Expression, Expression, ZoneId, BaseDateTimeFormatFunction> ctor() {
+        return ToChar::new;
+    }
+    
+    @Override
+    protected String scriptMethodName() {
+        return "toChar";
+    }
+
+    @Override
+    protected BinaryScalarFunction replaceChildren(Expression timestamp, Expression pattern) {
+        return new ToChar(source(), timestamp, pattern, zoneId());
+    }
+}

+ 377 - 0
x-pack/plugin/sql/src/main/java/org/elasticsearch/xpack/sql/expression/function/scalar/datetime/ToCharFormatter.java

@@ -0,0 +1,377 @@
+/*
+ * Copyright Elasticsearch B.V. and/or licensed to Elasticsearch B.V. under one
+ * or more contributor license agreements. Licensed under the Elastic License;
+ * you may not use this file except in compliance with the Elastic License.
+ */
+
+package org.elasticsearch.xpack.sql.expression.function.scalar.datetime;
+
+import org.elasticsearch.common.Strings;
+
+import java.time.ZoneId;
+import java.time.format.DateTimeFormatter;
+import java.time.format.TextStyle;
+import java.time.temporal.ChronoField;
+import java.time.temporal.IsoFields;
+import java.time.temporal.JulianFields;
+import java.time.temporal.TemporalAccessor;
+import java.time.temporal.WeekFields;
+import java.util.LinkedHashMap;
+import java.util.LinkedList;
+import java.util.List;
+import java.util.Locale;
+import java.util.Map;
+import java.util.function.Function;
+import java.util.stream.Collectors;
+
+import static java.lang.Integer.parseInt;
+
+/**
+ * Formatting according to the PostgreSQL <code>to_char</code> function specification:
+ * https://www.postgresql.org/docs/13/functions-formatting.html#FUNCTIONS-FORMATTING-DATETIME-TABLE
+ */
+class ToCharFormatter {
+
+    protected static final Map<String, ToCharFormatter> FORMATTER_MAP;
+
+    static {
+        List<ToCharFormatter> formatters = List.of(
+            of("HH").formatFn("hh").numeric(),
+            of("HH12").formatFn("hh").numeric(),
+            of("HH24").formatFn("HH").numeric(),
+            of("MI").formatFn("mm").numeric(),
+            of("SS").formatFn("s", x -> String.format(Locale.ROOT, "%02d", parseInt(x))).numeric(),
+            of("MS").formatFn("n", nano -> firstDigitsOfNanos(nano, 3)).numericWithLeadingZeros(),
+            of("US").formatFn("n", nano -> firstDigitsOfNanos(nano, 6)).numericWithLeadingZeros(),
+            of("FF1").formatFn("n", nano -> firstDigitsOfNanos(nano, 1)).numericWithLeadingZeros(),
+            of("FF2").formatFn("n", nano -> firstDigitsOfNanos(nano, 2)).numericWithLeadingZeros(),
+            of("FF3").formatFn("n", nano -> firstDigitsOfNanos(nano, 3)).numericWithLeadingZeros(),
+            of("FF4").formatFn("n", nano -> firstDigitsOfNanos(nano, 4)).numericWithLeadingZeros(),
+            of("FF5").formatFn("n", nano -> firstDigitsOfNanos(nano, 5)).numericWithLeadingZeros(),
+            of("FF6").formatFn("n", nano -> firstDigitsOfNanos(nano, 6)).numericWithLeadingZeros(),
+            of("SSSSS").formatFn("A", milliSecondOfDay -> String.valueOf(parseInt(milliSecondOfDay) / 1000)).numeric(),
+            of("SSSS").formatFn("A", milliSecondOfDay -> String.valueOf(parseInt(milliSecondOfDay) / 1000)).numeric(),
+            of("AM").formatFn("a", x -> x.toUpperCase(Locale.ROOT)).text(),
+            of("am").formatFn("a", x -> x.toLowerCase(Locale.ROOT)).text(),
+            of("PM").formatFn("a", x -> x.toUpperCase(Locale.ROOT)).text(),
+            of("pm").formatFn("a", x -> x.toLowerCase(Locale.ROOT)).text(),
+            of("A.M.").formatFn("a", x -> x.charAt(0) + "." + x.charAt(1) + ".").text(),
+            of("a.m.").formatFn("a", x -> (x.charAt(0) + "." + x.charAt(1) + ".").toLowerCase(Locale.ROOT)).text(),
+            of("P.M.").formatFn("a", x -> x.charAt(0) + "." + x.charAt(1) + ".").text(),
+            of("p.m.").formatFn("a", x -> (x.charAt(0) + "." + x.charAt(1) + ".").toLowerCase(Locale.ROOT)).text(),
+            of("Y,YYY").formatFn("yyyy", year -> year.charAt(0) + "," + year.substring(1)).numericWithLeadingZeros(),
+            of("YYYY").formatFn("yyyy").numeric(),
+            of("YYY").formatFn("yyyy", year -> year.substring(1)).numeric(),
+            of("YY").formatFn("yy").numeric(),
+            of("Y").formatFn("yy", year -> year.substring(1)).numeric(),
+            of("IYYY").formatFn(t -> lastNCharacter(absoluteWeekBasedYear(t), 4)).numeric(),
+            of("IYY").formatFn(t -> lastNCharacter(absoluteWeekBasedYear(t), 3)).numeric(),
+            of("IY").formatFn(t -> lastNCharacter(absoluteWeekBasedYear(t), 2)).numeric(),
+            of("I").formatFn(t -> lastNCharacter(absoluteWeekBasedYear(t), 1)).numeric(),
+            of("BC").formatFn("G").text(),
+            of("bc").formatFn("G", x -> x.toLowerCase(Locale.ROOT)).text(),
+            of("AD").formatFn("G").text(),
+            of("ad").formatFn("G", x -> x.toLowerCase(Locale.ROOT)).text(),
+            of("B.C.").formatFn("G", x -> x.charAt(0) + "." + x.charAt(1) + ".").text(),
+            of("b.c.").formatFn("G", x -> (x.charAt(0) + "." + x.charAt(1) + ".").toLowerCase(Locale.ROOT)).text(),
+            of("A.D.").formatFn("G", x -> x.charAt(0) + "." + x.charAt(1) + ".").text(),
+            of("a.d.").formatFn("G", x -> (x.charAt(0) + "." + x.charAt(1) + ".").toLowerCase(Locale.ROOT)).text(),
+            of("MONTH").formatFn("MMMM", x -> String.format(Locale.ROOT, "%-9s", x.toUpperCase(Locale.ROOT))).text(),
+            of("Month").formatFn("MMMM", x -> String.format(Locale.ROOT, "%-9s", x)).text(),
+            of("month").formatFn("MMMM", x -> String.format(Locale.ROOT, "%-9s", x.toLowerCase(Locale.ROOT))).text(),
+            of("MON").formatFn("MMM", x -> x.toUpperCase(Locale.ROOT)).text(),
+            of("Mon").formatFn("MMM").text(),
+            of("mon").formatFn("MMM", x -> x.toLowerCase(Locale.ROOT)).text(),
+            of("MM").formatFn("MM").numeric(),
+            of("DAY").formatFn("EEEE", x -> String.format(Locale.ROOT, "%-9s", x.toUpperCase(Locale.ROOT))).text(),
+            of("Day").formatFn("EEEE", x -> String.format(Locale.ROOT, "%-9s", x)).text(),
+            of("day").formatFn("EEEE", x -> String.format(Locale.ROOT, "%-9s", x.toLowerCase(Locale.ROOT))).text(),
+            of("DY").formatFn("E", x -> x.toUpperCase(Locale.ROOT)).text(),
+            of("Dy").formatFn("E").text(),
+            of("dy").formatFn("E", x -> x.toLowerCase(Locale.ROOT)).text(),
+            of("DDD").formatFn("DDD").numeric(),
+            of("IDDD").formatFn(t -> String.format(Locale.ROOT,
+                "%03d",
+                (t.get(WeekFields.ISO.weekOfWeekBasedYear()) - 1) * 7 + t.get(ChronoField.DAY_OF_WEEK))
+            ).numeric(),
+            of("DD").formatFn("d", x -> String.format(Locale.ROOT, "%02d", parseInt(x))).numeric(),
+            of("ID").formatFn("e").numeric(),
+            of("D").formatFn(t -> String.valueOf(t.get(WeekFields.SUNDAY_START.dayOfWeek()))).numeric(),
+            of("W").formatFn(t -> String.valueOf(t.get(ChronoField.ALIGNED_WEEK_OF_MONTH))).numeric(),
+            of("WW").formatFn(t -> String.format(Locale.ROOT, "%02d", t.get(ChronoField.ALIGNED_WEEK_OF_YEAR))).numeric(),
+            of("IW").formatFn(t -> String.format(Locale.ROOT, "%02d", t.get(WeekFields.ISO.weekOfWeekBasedYear()))).numeric(),
+            of("CC").formatFn(t -> {
+                int century = yearToCentury(t.get(ChronoField.YEAR));
+                return String.format(Locale.ROOT, century < 0 ? "%03d" : "%02d", century);
+            }).numeric(),
+            of("J").formatFn(t -> String.valueOf(t.getLong(JulianFields.JULIAN_DAY))).numeric(),
+            of("Q").formatFn("Q").numeric(),
+            of("RM").formatFn("MM", month -> String.format(Locale.ROOT, "%-4s", monthToRoman(parseInt(month)))).text(),
+            of("rm")
+                .formatFn("MM", month -> String.format(Locale.ROOT, "%-4s", monthToRoman(parseInt(month)).toLowerCase(Locale.ROOT)))
+                .text(),
+            of("TZ").formatFn(ToCharFormatter::zoneAbbreviationOf).text(),
+            of("tz").formatFn(t -> zoneAbbreviationOf(t).toLowerCase(Locale.ROOT)).text(),
+            of("TZH").acceptsLowercase(false).formatFn("ZZ", s -> s.substring(0, 3)).text(),
+            of("TZM").acceptsLowercase(false).formatFn("ZZ", s -> lastNCharacter(s, 2)).text(),
+            of("OF").acceptsLowercase(false).formatFn("ZZZZZ", ToCharFormatter::formatOffset).offset()
+        );
+
+        Map<String, ToCharFormatter> formatterMap = new LinkedHashMap<>();
+        for (ToCharFormatter formatter : formatters) {
+            formatterMap.put(formatter.pattern, formatter);
+        }
+        // also index the lower case version of the patterns if accepted
+        for (ToCharFormatter formatter : formatters) {
+            if (formatter.acceptsLowercase) {
+                formatterMap.putIfAbsent(formatter.pattern.toLowerCase(Locale.ROOT), formatter);
+            }
+        }
+        FORMATTER_MAP = formatterMap;
+    }
+    
+    private static final int MAX_TO_CHAR_FORMAT_STRING_LENGTH =
+        FORMATTER_MAP.keySet().stream().mapToInt(String::length).max().orElse(Integer.MAX_VALUE);
+    
+    private static final String[] ROMAN_NUMBERS = {"I", "II", "III", "IV", "V", "VI", "VII", "VIII", "IX", "X", "XI", "XII"};
+
+    private final String pattern;
+    private final boolean acceptsLowercase;
+    // Fill mode: suppress leading zeroes and padding blanks
+    // https://www.postgresql.org/docs/13/functions-formatting.html#FUNCTIONS-FORMATTING-DATETIMEMOD-TABLE
+    private final Function<String, String> fillModeFn;
+    private final boolean hasOrdinalSuffix;
+    private final Function<TemporalAccessor, String> formatter;
+
+    private ToCharFormatter(
+        String pattern,
+        boolean acceptsLowercase,
+        Function<String, String> fillModeFn,
+        boolean hasOrdinalSuffix,
+        Function<TemporalAccessor, String> formatter) {
+
+        this.pattern = pattern;
+        this.acceptsLowercase = acceptsLowercase;
+        this.fillModeFn = fillModeFn;
+        this.hasOrdinalSuffix = hasOrdinalSuffix;
+        this.formatter = formatter;
+    }
+
+    private static Builder of(String pattern) {
+        return new Builder(pattern);
+    }
+
+    private static String monthToRoman(int month) {
+        return ROMAN_NUMBERS[month - 1];
+    }
+
+    private static int yearToCentury(int year) {
+        int offset = -1;
+        if (year > 0) {
+            offset = year % 100 == 0 ? 0 : 1;
+        }
+        return year / 100 + offset;
+    }
+
+    private String format(TemporalAccessor temporalAccessor) {
+        return formatter.apply(temporalAccessor);
+    }
+
+    private ToCharFormatter withModifier(Function<String, String> modifier) {
+        return new ToCharFormatter(pattern, acceptsLowercase, fillModeFn, hasOrdinalSuffix, formatter.andThen(modifier));
+    }
+
+    private static List<ToCharFormatter> parsePattern(String toCharPattern) {
+        LinkedList<ToCharFormatter> formatters = new LinkedList<>();
+
+        while (toCharPattern.isEmpty() == false) {
+            ToCharFormatter formatter = null;
+            boolean fillModeModifierActive = false;
+            
+            // we try to match the following: ( fill-modifier? ( ( pattern ordinal-suffix-modifier? ) | literal-non-pattern ) ) *
+            // and extract the individual patterns with the fill-modifiers and ordinal-suffix-modifiers or
+            // the non-matched literals (removing the potential fill modifiers specified for them, FMFM turns into FM)
+            
+            // check for fill-modifier first
+            if (toCharPattern.startsWith("FM") || toCharPattern.startsWith("fm")) {
+                // try to apply the fill mode modifier to the next formatter
+                fillModeModifierActive = true;
+                toCharPattern = toCharPattern.substring(2);
+            }
+
+            // try to find a potential pattern next
+            for (int length = Math.min(MAX_TO_CHAR_FORMAT_STRING_LENGTH, toCharPattern.length()); length >= 1; length--) {
+                final String potentialPattern = toCharPattern.substring(0, length);
+                formatter = FORMATTER_MAP.get(potentialPattern);
+                // check if it is a known pattern string, if so apply it, with any modifier
+                if (formatter != null) {
+                    if (fillModeModifierActive && formatter.fillModeFn != null) {
+                        formatter = formatter.withModifier(formatter.fillModeFn);
+                    }
+                    toCharPattern = toCharPattern.substring(length);
+                    break;
+                }
+            }
+            
+            if (formatter == null) {
+                // the fill mode modifier is dropped in case of literals
+                formatter = literal(toCharPattern.substring(0, 1));
+                toCharPattern = toCharPattern.substring(1);
+            } else {
+                // try to look for an ordinal suffix modifier in case we found a pattern
+                if (toCharPattern.startsWith("TH") || toCharPattern.startsWith("th")) {
+                    final String ordinalSuffixModifier = toCharPattern.substring(0, 2);
+                    if (formatter.hasOrdinalSuffix) {
+                        formatter = formatter.withModifier(s -> appendOrdinalSuffix(ordinalSuffixModifier, s));
+                    }
+                    toCharPattern = toCharPattern.substring(2);
+                }
+            }
+            
+            formatters.addLast(formatter);
+        }
+        return formatters;
+    }
+
+    public static Function<TemporalAccessor, String> ofPattern(String pattern) {
+        if (Strings.isEmpty(pattern)) {
+            return timestamp -> "";
+        }
+        final List<ToCharFormatter> toCharFormatters = parsePattern(pattern);
+        return timestamp -> toCharFormatters.stream().map(p -> p.format(timestamp)).collect(Collectors.joining());
+    }
+
+    private static ToCharFormatter literal(String literal) {
+        return new ToCharFormatter(literal, false, null, true, t -> literal);
+    }
+
+    private static String ordinalSuffix(int i) {
+        if (i < 0) {
+            i = -i;
+        }
+        int mod100 = i % 100;
+        int mod10 = i % 10;
+        if (mod10 == 1 && mod100 != 11) {
+            return "st";
+        } else if (mod10 == 2 && mod100 != 12) {
+            return "nd";
+        } else if (mod10 == 3 && mod100 != 13) {
+            return "rd";
+        } else {
+            return "th";
+        }
+    }
+
+    private static String appendOrdinalSuffix(String defaultSuffix, String s) {
+        try {
+            // the Y,YYY pattern might can cause problems with the parsing, but thankfully the last 3
+            // characters is enough to calculate the suffix
+            int i = parseInt(lastNCharacter(s, 3));
+            final boolean upperCase = defaultSuffix.equals(defaultSuffix.toUpperCase(Locale.ROOT));
+            return s + (upperCase ? ordinalSuffix(i).toUpperCase(Locale.ROOT) : ordinalSuffix(i));
+        } catch (NumberFormatException ex) {
+            return s + defaultSuffix;
+        }
+    }
+
+    private static String formatOffset(String offset) {
+        if (offset.equals("Z")) {
+            return "+00";
+        }
+        if (offset.matches("^[+-][0-9][0-9]00$")) {
+            offset = offset.substring(0, offset.length() - 2);
+        } else if (offset.matches("^[+-][0-9]{3,4}$")) {
+            offset = offset.substring(0, offset.length() - 2) + ":" + offset.substring(offset.length() - 2);
+        } else if (offset.matches("^[+-][0-9][0-9]:00$")) {
+            offset = offset.substring(0, offset.length() - 3);
+        }
+        return offset.substring(0, Math.min(offset.length(), 6));
+    }
+
+    private static String removeLeadingZerosFromOffset(String offset) {
+        if (offset.matches("[+-]0{1,2}")) {
+            return offset.substring(0, 2);
+        } else {
+            if (offset.startsWith("+0")) {
+                return "+" + offset.substring(2);
+            } else if (offset.startsWith("-0")) {
+                return "-" + offset.substring(2);
+            } else {
+                return offset;
+            }
+        }
+    }
+
+    private static String absoluteWeekBasedYear(TemporalAccessor t) {
+        int year = t.get(IsoFields.WEEK_BASED_YEAR);
+        year = year > 0 ? year : -(year - 1);
+        return String.format(Locale.ROOT, "%04d", year);
+    }
+
+    private static String firstDigitsOfNanos(String nano, int digits) {
+        return String.format(Locale.ROOT, "%09d", parseInt(nano)).substring(0, digits);
+    }
+
+    private static String lastNCharacter(String s, int n) {
+        return s.substring(Math.max(0, s.length() - n));
+    }
+
+    private static String zoneAbbreviationOf(TemporalAccessor temporalAccessor) {
+        String zone = ZoneId.from(temporalAccessor).getDisplayName(TextStyle.SHORT, Locale.ROOT);
+        return "Z".equals(zone) ? "UTC" : zone;
+    }
+
+    private static class Builder {
+
+        private final String pattern;
+        private boolean lowercaseAccepted = true;
+        private Function<TemporalAccessor, String> formatFn;
+
+        Builder(String pattern) {
+            this.pattern = pattern;
+        }
+
+        public Builder formatFn(final String javaPattern) {
+            return formatFn(javaPattern, null);
+        }
+
+        public Builder formatFn(final String javaPattern, final Function<String, String> additionalMapper) {
+            this.formatFn = temporalAccessor -> {
+                String formatted = DateTimeFormatter.ofPattern(javaPattern != null ? javaPattern : "'" + pattern + "'", Locale.ROOT)
+                    .format(temporalAccessor);
+                return additionalMapper == null ? formatted : additionalMapper.apply(formatted);
+            };
+            return this;
+        }
+
+        public Builder formatFn(Function<TemporalAccessor, String> formatFn) {
+            this.formatFn = formatFn;
+            return this;
+        }
+        
+        public ToCharFormatter numeric() {
+            return build(number -> String.valueOf(parseInt(number)), true);
+        }
+
+        public ToCharFormatter numericWithLeadingZeros() {
+            return build(null, true);
+        }
+
+        public ToCharFormatter text() {
+            return build(paddedText -> paddedText.replaceAll(" +$", ""), false);
+        }
+        
+        public ToCharFormatter offset() {
+            return build(ToCharFormatter::removeLeadingZerosFromOffset, false);
+        }
+
+        public Builder acceptsLowercase(boolean lowercaseAccepted) {
+            this.lowercaseAccepted = lowercaseAccepted;
+            return this;
+        }
+
+        private ToCharFormatter build(Function<String, String> fillModeFn, boolean hasOrdinalSuffix) {
+            return new ToCharFormatter(pattern, lowercaseAccepted, fillModeFn, hasOrdinalSuffix, formatFn);
+        }
+    }
+}

+ 4 - 0
x-pack/plugin/sql/src/main/java/org/elasticsearch/xpack/sql/expression/function/scalar/whitelist/InternalSqlScriptUtils.java

@@ -300,6 +300,10 @@ public class InternalSqlScriptUtils extends InternalQlScriptUtils {
         return (String) Formatter.FORMAT.format(asDateTime(dateTime), pattern, ZoneId.of(tzId));
     }
 
+    public static String toChar(Object dateTime, String pattern, String tzId) {
+        return (String) Formatter.TO_CHAR.format(asDateTime(dateTime), pattern, ZoneId.of(tzId));
+    }
+
     public static Object timeParse(String dateField, String pattern, String tzId) {
         return Parser.TIME.parse(dateField, pattern, ZoneId.of(tzId));
     }

+ 1 - 0
x-pack/plugin/sql/src/main/resources/org/elasticsearch/xpack/sql/plugin/sql_whitelist.txt

@@ -136,6 +136,7 @@ class org.elasticsearch.xpack.sql.expression.function.scalar.whitelist.InternalS
   Integer datePart(String, Object, String)
   String dateTimeFormat(Object, String, String)
   String format(Object, String, String)
+  String toChar(Object, String, String)
   def dateTimeParse(String, String, String)
   def timeParse(String, String, String)
   IntervalDayTime intervalDayTime(String, String)

+ 17 - 0
x-pack/plugin/sql/src/test/java/org/elasticsearch/xpack/sql/analysis/analyzer/VerifierErrorMessagesTests.java

@@ -385,6 +385,23 @@ public class VerifierErrorMessagesTests extends ESTestCase {
         );
     }
 
+    public void testToCharValidArgs() {
+        accept("SELECT TO_CHAR(date, 'HH:MI:SS.FF3 OF') FROM test");
+        accept("SELECT TO_CHAR(date::date, 'MM/DD/YYYY') FROM test");
+        accept("SELECT TO_CHAR(date::time, 'HH:MI:SS OF') FROM test");
+    }
+
+    public void testToCharInvalidArgs() {
+        assertEquals(
+            "1:8: first argument of [TO_CHAR(int, keyword)] must be [date, time or datetime], found value [int] type [integer]",
+            error("SELECT TO_CHAR(int, keyword) FROM test")
+        );
+        assertEquals(
+            "1:8: second argument of [TO_CHAR(date, int)] must be [string], found value [int] type [integer]",
+            error("SELECT TO_CHAR(date, int) FROM test")
+        );
+    }
+
     public void testValidDateTimeFunctionsOnTime() {
         accept("SELECT HOUR_OF_DAY(CAST(date AS TIME)) FROM test");
         accept("SELECT MINUTE_OF_HOUR(CAST(date AS TIME)) FROM test");

+ 153 - 0
x-pack/plugin/sql/src/test/java/org/elasticsearch/xpack/sql/expression/function/scalar/datetime/DateTimeToCharProcessorTests.java

@@ -0,0 +1,153 @@
+/*
+ * Copyright Elasticsearch B.V. and/or licensed to Elasticsearch B.V. under one
+ * or more contributor license agreements. Licensed under the Elastic License;
+ * you may not use this file except in compliance with the Elastic License.
+ */
+
+package org.elasticsearch.xpack.sql.expression.function.scalar.datetime;
+
+import com.carrotsearch.randomizedtesting.annotations.ParametersFactory;
+
+import org.elasticsearch.test.ESTestCase;
+
+import java.math.BigDecimal;
+import java.nio.file.Files;
+import java.nio.file.Path;
+import java.time.ZoneId;
+import java.time.ZonedDateTime;
+import java.util.ArrayList;
+import java.util.List;
+import java.util.Locale;
+
+import static java.util.Arrays.asList;
+import static java.util.regex.Pattern.quote;
+import static org.elasticsearch.xpack.ql.expression.function.scalar.FunctionTestUtils.l;
+import static org.elasticsearch.xpack.ql.tree.Source.EMPTY;
+import static org.elasticsearch.xpack.ql.type.DataTypes.DATETIME;
+import static org.elasticsearch.xpack.ql.type.DataTypes.KEYWORD;
+import static org.elasticsearch.xpack.sql.expression.function.scalar.datetime.DateTimeTestUtils.dateTime;
+import static org.elasticsearch.xpack.sql.expression.function.scalar.datetime.ToCharTestScript.DELIMITER;
+import static org.elasticsearch.xpack.sql.expression.function.scalar.datetime.ToCharTestScript.PATTERN_DELIMITER;
+
+/**
+ * Tests the {@link ToCharFormatter} against actual PostgreSQL output.
+ *
+ * Process to (re)generate the test data:
+ * <ol>
+ *     <li>Run the @{link {@link ToCharTestScript#main(String[])}} class</li>
+ *     <li>Spin up a Postgres instance (latest or a specific version) using docker:
+ *       <pre>
+ *       docker run --rm --name postgres-latest -e POSTGRES_PASSWORD=mysecretpassword -p 5432:5432 -d postgres:latest
+ *       </pre>
+ *     </li>
+ *     <li>Generate the test dataset by execution the SQL against PostgreSQL and capturing the output:
+ *       <pre>
+ *       PGPASSWORD="mysecretpassword" psql --quiet -h localhost -p 5432 -U postgres -f /tmp/postgresql-tochar-test.sql \
+ *           &gt; /path/to/tochar-generated.csv
+ *       </pre>
+ *     </li>
+ * </ol>
+ * 
+ * In case you need to mute any of the tests, mute all tests by adding {@link org.apache.lucene.util.LuceneTestCase.AwaitsFix}
+ * on the class level.
+ */
+public class DateTimeToCharProcessorTests extends ESTestCase {
+    
+    @ParametersFactory(argumentFormatting = "%1$s:%2$s %5$s")
+    public static Iterable<Object[]> parameters() throws Exception {
+        List<Object[]> params = new ArrayList<>();
+        String testFile = "tochar-generated.csv";
+        int lineNumber = 0;
+        for (String line : Files.readAllLines(Path.of(DateTimeToCharProcessorTests.class.getResource(testFile).toURI()))) {
+            lineNumber += 1;
+            if (line.startsWith("#")) {
+                continue;
+            }
+            String[] cols = line.split(quote(DELIMITER));
+            params.add(new Object[]{testFile, lineNumber, cols[0], cols[1], cols[2], cols[3], cols[4]});
+        }
+        return params;
+    }
+
+    private final String testFile;
+    private final int lineNumber;
+    private final String secondsAndFractionsSinceEpoch;
+    private final String zone;
+    private final String formatString;
+    private final String posgresTimestamp;
+    private final String expectedResult;
+
+    /**
+     * @param testFile The name of the testfile where this testcase is coming from
+     * @param lineNumber The line number of the testcase within the testfile
+     * @param secondsAndFractionsSinceEpoch The date represented by seconds and fractions since epoch that was used to 
+     *                                      generate the TO_CHAR() PostgreSQL output.
+     * @param zone The long/short name or offset for the timezone used when generating the expected TO_CHAR() output.
+     * @param formatString The pattern to be tested (this is exactly the pattern that was passed into the TO_CHAR() function in PostgreSQL).
+     * @param posgresTimestamp The timestamp represented by PostgreSQL as string in the default format (without calling TO_CHAR()).
+     * @param expectedResult The PostgreSQL output of <code>TO_CHAR(
+     *                       (TO_TIMESTAMP([[secondsSinceEpoch]]) + INTERVAL '[[fractions]] microseconds'), 
+     *                       '[[formatString]]')</code>.
+     */
+    public DateTimeToCharProcessorTests(
+        String testFile, int lineNumber, String secondsAndFractionsSinceEpoch, String zone,
+        String formatString, String posgresTimestamp, String expectedResult) {
+
+        this.testFile = testFile;
+        this.lineNumber = lineNumber;
+        this.secondsAndFractionsSinceEpoch = secondsAndFractionsSinceEpoch;
+        this.zone = zone;
+        this.formatString = formatString;
+        this.posgresTimestamp = posgresTimestamp;
+        this.expectedResult = expectedResult;
+    }
+    
+    public void test() {
+        ZoneId zoneId = ZoneId.of(zone);
+        ZonedDateTime timestamp = dateTimeWithFractions(secondsAndFractionsSinceEpoch);
+        String actualResult =
+            (String) new ToChar(EMPTY, l(timestamp, DATETIME), l(formatString, KEYWORD), zoneId)
+                .makePipe()
+                .asProcessor()
+                .process(null);
+        List<String> expectedResultSplitted = asList(expectedResult.split(quote(PATTERN_DELIMITER)));
+        List<String> resultSplitted = asList(actualResult.split(quote(PATTERN_DELIMITER)));
+        List<String> formatStringSplitted = asList(formatString.split(PATTERN_DELIMITER));
+        assertEquals(formatStringSplitted.size(), resultSplitted.size());
+        assertEquals(formatStringSplitted.size(), expectedResultSplitted.size());
+        for (int i = 0; i < formatStringSplitted.size(); i++) {
+            String patternMaybeWithIndex = formatStringSplitted.get(i);
+            String expectedPart = expectedResultSplitted.get(i);
+            String actualPart = resultSplitted.get(i);
+            assertEquals(
+                String.format(Locale.ROOT,
+                    "\n" +
+                        "Line number:                        %s (in %s)\n" +
+                        "zone:                               %s\n" +
+                        "timestamp (as epoch):               %s\n" +
+                        "timestamp (java, UTC):              %s\n" +
+                        "timestamp (postgres, to_timestamp): %s\n" +
+                        "timestamp (java with zone):         %s\n" +
+                        "format string:                      %s\n" +
+                        "expected (postgres to_char result): %s\n" +
+                        "actual (ES to_char result):         %s\n" +
+                        "    FAILED (sub)pattern: %s,",
+                    lineNumber, testFile,
+                    zone, secondsAndFractionsSinceEpoch, timestamp, posgresTimestamp, timestamp.withZoneSameInstant(zoneId),
+                    formatString, expectedResult, actualResult, patternMaybeWithIndex),
+                expectedPart, actualPart);
+        }
+    }
+    
+    private static ZonedDateTime dateTimeWithFractions(String secondAndFractionsSinceEpoch) {
+        BigDecimal b = new BigDecimal(secondAndFractionsSinceEpoch);
+        long seconds = b.longValue();
+        int fractions = b.remainder(BigDecimal.ONE).movePointRight(9).intValueExact();
+        int adjustment = 0;
+        if (fractions < 0) {
+            fractions += 1e9;
+            adjustment = -1;
+        }
+        return dateTime((seconds + adjustment) * 1000).withNano(fractions);
+    }
+}

+ 241 - 0
x-pack/plugin/sql/src/test/java/org/elasticsearch/xpack/sql/expression/function/scalar/datetime/ToCharTestScript.java

@@ -0,0 +1,241 @@
+/*
+ * Copyright Elasticsearch B.V. and/or licensed to Elasticsearch B.V. under one
+ * or more contributor license agreements. Licensed under the Elastic License;
+ * you may not use this file except in compliance with the Elastic License.
+ */
+
+package org.elasticsearch.xpack.sql.expression.function.scalar.datetime;
+
+import com.carrotsearch.randomizedtesting.generators.RandomNumbers;
+
+import org.elasticsearch.common.SuppressForbidden;
+import org.elasticsearch.common.util.set.Sets;
+
+import java.math.BigDecimal;
+import java.net.URI;
+import java.net.URL;
+import java.nio.charset.StandardCharsets;
+import java.nio.file.Files;
+import java.nio.file.Path;
+import java.util.ArrayList;
+import java.util.Collection;
+import java.util.List;
+import java.util.Locale;
+import java.util.Random;
+import java.util.Set;
+import java.util.stream.Collectors;
+import java.util.stream.IntStream;
+
+import static java.util.Arrays.asList;
+import static java.util.regex.Pattern.quote;
+import static org.elasticsearch.xpack.sql.expression.function.scalar.datetime.DateTimeTestUtils.dateTime;
+
+/**
+ * Generates an psql file that can be used to generate the test dataset for the {@link DateTimeToCharProcessorTests}.
+ */
+public class ToCharTestScript {
+
+    private class TestRecord {
+        private final BigDecimal secondsAndFractionsSinceEpoch;
+        private final String formatString;
+        private final String zoneId;
+
+        TestRecord(BigDecimal secondsAndFractionsSinceEpoch, String formatString) {
+            this.secondsAndFractionsSinceEpoch = secondsAndFractionsSinceEpoch;
+            this.formatString = formatString;
+            this.zoneId = ToCharTestScript.this.randomFromCollection(TIMEZONES_TO_TEST);
+        }
+    }
+
+    private static final long SECONDS_IN_YEAR = 365 * 24 * 60 * 60L;
+    public static final String DELIMITER = "|";
+    public static final String PATTERN_DELIMITER = " @ ";
+    // these patterns are hard to sync up between PostgreSQL and Elasticsearch, so we just warn, but actually
+    // accept the output of Elasticsearch as is
+    public static final Set<String> NOT_FULLY_MATCHABLE_PATTERNS = Set.of("TZ", "tz");
+    private static final Set<String> UNSUPPORTED_PATTERN_MODIFIERS = Set.of("FX", "TM", "SP");
+    private static final List<String> PATTERNS = new ArrayList<>(ToCharFormatter.FORMATTER_MAP.keySet());
+    private static final List<String> MATCHABLE_PATTERNS;
+    static {
+        MATCHABLE_PATTERNS = new ArrayList<>(PATTERNS);
+        MATCHABLE_PATTERNS.removeAll(NOT_FULLY_MATCHABLE_PATTERNS);
+    }
+    private static final List<String> FILL_MODIFIERS = asList("FM", "fm", "");
+    private static final List<String> ORDINAL_SUFFIX_MODIFIERS = asList("TH", "th", "");
+    // timezones that are valid both in Java and in Postgres
+    public static final List<String> TIMEZONES_TO_TEST =
+            readAllLinesWithoutComment(ToCharTestScript.class.getResource("tochar-test-timezones.txt"));
+
+    private final List<TestRecord> testRecords = new ArrayList<>();
+    private final List<BigDecimal> testEpochSeconds = new ArrayList<>();
+    private final Random random;
+
+    public ToCharTestScript(Random random) {
+        this.random = random;
+        generateTestTimestamps();
+        
+        patternsOneByOne();
+        allPatternsTogether();
+        postgreSQLPatternParsingBehaviour();
+        monthsAsRomanNumbers();
+        randomizedPatternStrings();
+    }
+
+    private void generateTestTimestamps() {
+        final int latestYearToTest = 3000;
+        int countOfTestYears = 150;
+        for (int i = 0; i < countOfTestYears; i++) {
+            testEpochSeconds.add(randomSecondsWithFractions(-latestYearToTest, latestYearToTest));
+        }
+
+        int countOfTestYearsAroundYearZero = 10;
+        for (int i = 0; i < countOfTestYearsAroundYearZero; i++) {
+            testEpochSeconds.add(randomSecondsWithFractions(-1, 1));
+        }
+    }
+
+    private void patternsOneByOne() {
+        for (String pattern : MATCHABLE_PATTERNS) {
+            testRecords.add(new TestRecord(
+                randomFromCollection(testEpochSeconds),
+                NOT_FULLY_MATCHABLE_PATTERNS.contains(pattern) ?
+                    pattern :
+                    String.join(PATTERN_DELIMITER, pattern, FILL_MODIFIERS.get(0) + pattern + ORDINAL_SUFFIX_MODIFIERS.get(0))));
+        }
+    }
+
+    private void allPatternsTogether() {
+        for (BigDecimal es : testEpochSeconds) {
+            testRecords.add(new TestRecord(
+                es,
+                IntStream.range(0, MATCHABLE_PATTERNS.size())
+                    .mapToObj(idx -> idx + ":" + patternWithRandomModifiers(MATCHABLE_PATTERNS.get(idx)))
+                    .collect(Collectors.joining(PATTERN_DELIMITER))));
+        }
+    }
+
+    private void postgreSQLPatternParsingBehaviour() {
+        // potentially ambiguous format string test cases, to check if our format string parsing is in-sync with PostgreSQL
+        // that is greedy and prefers the longer format strings
+        testRecords.add(new TestRecord(randomFromCollection(testEpochSeconds), "YYYYYYYYYYYYYYY,YYYYYYYYY"));
+        testRecords.add(new TestRecord(randomFromCollection(testEpochSeconds), "SSSSSSSSSSSSSSSS"));
+        testRecords.add(new TestRecord(randomFromCollection(testEpochSeconds), "DDDDDDDD"));
+        testRecords.add(new TestRecord(randomFromCollection(testEpochSeconds), "FMFMFMFMAAthththth"));
+        testRecords.add(new TestRecord(randomFromCollection(testEpochSeconds), "1FMth"));
+    }
+
+    private void monthsAsRomanNumbers() {
+        for (int i = 1; i <= 12; i++) {
+            testRecords.add(new TestRecord(
+                new BigDecimal(dateTime(0).withMonth(i).toEpochSecond()),
+                random.nextBoolean() ? "RM" : "rm"));
+        }
+    }
+
+    private void randomizedPatternStrings() {
+        final String randomCharacters = "0123456789ABCDEFGHIJKLMNOPQRSTUVWXYabcdefghijklmnopqrstuvwxy _-.:;";
+
+        final int randomizedPatternCount = 50;
+        final int lengthOfRandomizedPattern = 50;
+        final int pctChanceOfRandomCharacter = 80;
+        for (int i = 0; i < randomizedPatternCount; i++) {
+            String patternWithLiterals = IntStream.rangeClosed(1, lengthOfRandomizedPattern)
+                    .mapToObj(idx -> {
+                        if (random.nextInt(100) < pctChanceOfRandomCharacter) {
+                            return randomCharacters.substring(random.nextInt(randomCharacters.length())).substring(0, 1);
+                        } else {
+                            return (randomFromCollection(FILL_MODIFIERS) + randomFromCollection(PATTERNS) 
+                                + randomFromCollection(ORDINAL_SUFFIX_MODIFIERS));
+                        }})
+                    .collect(Collectors.joining());
+
+            // clean up the random string from the unsupported modifiers
+            for (String unsupportedPatternModifier : Sets.union(UNSUPPORTED_PATTERN_MODIFIERS, NOT_FULLY_MATCHABLE_PATTERNS)) {
+                patternWithLiterals = patternWithLiterals
+                    .replace(unsupportedPatternModifier, "")
+                    .replace(unsupportedPatternModifier.toLowerCase(Locale.ROOT), "");
+            }
+            testRecords.add(new TestRecord(randomFromCollection(testEpochSeconds), patternWithLiterals));
+        }
+    }
+
+    private BigDecimal randomSecondsWithFractions(int minYear, int maxYear) {
+        BigDecimal seconds =
+            new BigDecimal(RandomNumbers.randomLongBetween(random, (minYear - 1970) * SECONDS_IN_YEAR, (maxYear - 1970) * SECONDS_IN_YEAR));
+        BigDecimal fractions = new BigDecimal(RandomNumbers.randomIntBetween(random, 0, 999_999)).movePointLeft(6);
+        return seconds.add(fractions);
+    }
+
+    private <T> T randomFromCollection(Collection<T> list) {
+        List<T> l = new ArrayList<>(list);
+        return l.get(random.nextInt(l.size()));
+    }
+
+    private String patternWithRandomModifiers(String pattern) {
+        return randomFromCollection(FILL_MODIFIERS) + pattern + randomFromCollection(ORDINAL_SUFFIX_MODIFIERS);
+    }
+
+    private static String adjustZoneIdToPostgres(String zoneId) {
+        // when the zone is specified by the offset in Postgres, it follows the POSIX definition, so the +- signs are flipped
+        // compared to ISO-8601, see more info at: https://www.postgresql.org/docs/current/datetime-posix-timezone-specs.html
+        if (zoneId.startsWith("+")) {
+            zoneId = zoneId.replaceFirst(quote("+"), "-");
+        } else if (zoneId.startsWith("-")) {
+            zoneId = zoneId.replaceFirst(quote("-"), "+");
+        }
+        return zoneId;
+    }
+
+    static List<String> readAllLinesWithoutComment(URL url) {
+        try {
+            URI uri = url.toURI();
+            return Files.readAllLines(Path.of(uri))
+                .stream()
+                .filter(s -> s.startsWith("#") == false)
+                .filter(s -> s.isBlank() == false)
+                .collect(Collectors.toList());
+        } catch (Exception ex) {
+            throw new RuntimeException(ex);
+        }
+    }
+
+    /**
+     * Generates an SQL file (psql input) that can be used to create the test dataset for the unit test of the <code>TO_CHAR</code>
+     * implementation. In case the <code>TO_CHAR</code> implementation needs an upgrade, add the list of the new format
+     * strings to the list of the format string, regenerate the SQL, run it against the PostgreSQL version you are targeting
+     * and update the test CSV file.
+     */
+    private String unitTestExporterScript() {
+        String header =
+            "\n\\echo #" +
+            "\n\\echo # DO NOT EDIT manually, was generated using " + ToCharTestScript.class.getName() +
+            "\n\\echo #\n\n";
+        String testCases = testRecords.stream().map(tc -> {
+            long seconds = tc.secondsAndFractionsSinceEpoch.longValue();
+            BigDecimal fractions = tc.secondsAndFractionsSinceEpoch.remainder(BigDecimal.ONE).movePointRight(6);
+            return String.format(Locale.ROOT, 
+                "SET TIME ZONE '%6$s';\n"
+                    + "\\copy (SELECT %1$s as epoch_seconds_and_microsends, '%5$s' as zone_id, '%4$s' as format_string, " 
+                    + "(TO_TIMESTAMP(%2$d) + INTERVAL '%3$d microseconds') as to_timestamp_result, "
+                    + "TO_CHAR((TO_TIMESTAMP(%2$d) + INTERVAL '%3$d microseconds'), '%4$s') as to_char_result) to stdout " 
+                    + "with DELIMITER as '" + DELIMITER + "' NULL as '' csv \n",
+                tc.secondsAndFractionsSinceEpoch.toPlainString(),
+                seconds,
+                fractions.intValue(),
+                tc.formatString,
+                tc.zoneId,
+                adjustZoneIdToPostgres(tc.zoneId));
+        }).collect(Collectors.joining("\n"));
+        return header + testCases;
+    }
+
+    @SuppressForbidden(reason = "It is ok to use Random outside of an actual test")
+    private static Random rnd() {
+        return new Random();
+    }
+
+    public static void main(String[] args) throws Exception {
+        String scriptFilename = args.length < 1 ? "postgresql-tochar-test.sql" : args[0];
+        Files.writeString(Path.of(scriptFilename), new ToCharTestScript(rnd()).unitTestExporterScript(), StandardCharsets.UTF_8);
+    }
+}

+ 16 - 0
x-pack/plugin/sql/src/test/java/org/elasticsearch/xpack/sql/planner/QueryTranslatorTests.java

@@ -627,6 +627,22 @@ public class QueryTranslatorTests extends ESTestCase {
         assertEquals("[{v=date}, {v=YYYY_MM_dd}, {v=Z}, {v=2018_09_04}]", sc.script().params().toString());
     }
 
+    public void testTranslateToChar_WhereClause_Painless() {
+        LogicalPlan p = plan("SELECT int FROM test WHERE TO_CHAR(date, 'YYYY_MM_DD') = '2018_09_04'");
+        assertTrue(p instanceof Project);
+        assertTrue(p.children().get(0) instanceof Filter);
+        Expression condition = ((Filter) p.children().get(0)).condition();
+        assertFalse(condition.foldable());
+        QueryTranslation translation = translate(condition);
+        assertNull(translation.aggFilter);
+        assertTrue(translation.query instanceof ScriptQuery);
+        ScriptQuery sc = (ScriptQuery) translation.query;
+        assertEquals("InternalQlScriptUtils.nullSafeFilter(InternalQlScriptUtils.eq(InternalSqlScriptUtils.toChar(" +
+                "InternalQlScriptUtils.docValue(doc,params.v0),params.v1,params.v2),params.v3))",
+            sc.script().toString());
+        assertEquals("[{v=date}, {v=YYYY_MM_DD}, {v=Z}, {v=2018_09_04}]", sc.script().params().toString());
+    }
+
     public void testLikeOnInexact() {
         LogicalPlan p = plan("SELECT * FROM test WHERE some.string LIKE '%a%'");
         assertTrue(p instanceof Project);

File diff suppressed because it is too large
+ 108 - 0
x-pack/plugin/sql/src/test/resources/org/elasticsearch/xpack/sql/expression/function/scalar/datetime/tochar-generated.csv


+ 50 - 0
x-pack/plugin/sql/src/test/resources/org/elasticsearch/xpack/sql/expression/function/scalar/datetime/tochar-test-timezones.txt

@@ -0,0 +1,50 @@
+# The following timezone names are a subset of the timezones names
+# that are both available in PostgeSQL `SELECT name FROM pg_timezone_names`
+# and in Java `java.time.ZoneId.getAvailableZoneIds()`
+US/Samoa
+Pacific/Honolulu
+Pacific/Marquesas
+Pacific/Gambier
+America/Juneau
+Canada/Yukon
+America/Vancouver
+Pacific/Easter
+US/Mountain
+America/Chicago
+US/Michigan
+Atlantic/Bermuda
+Canada/Newfoundland
+Atlantic/Cape_Verde
+Pacific/Kiritimati
+Pacific/Chatham
+Pacific/Auckland
+Asia/Sakhalin
+Australia/Tasmania
+Australia/North
+Asia/Tokyo
+Australia/Eucla
+Asia/Singapore
+Asia/Rangoon
+Indian/Chagos
+Asia/Calcutta
+Asia/Tashkent
+Asia/Tehran
+Asia/Dubai
+Africa/Nairobi
+Europe/Brussels
+Europe/Vienna
+Europe/London
+Etc/GMT+12
+# Short names of some major timezones
+GMT
+UTC
+CET
+# Offsets, since zones can be specified by the offset too
++11:00
++04:30
++01:00
++00:00
+-00:00
+-01:15
+-02:00
+-11:00

Some files were not shown because too many files changed in this diff