Skip to content
Snippets Groups Projects
Commit 4b9dbc90 authored by Cam Saül's avatar Cam Saül
Browse files

Merge pull request #925 from metabase/qp-dates

New QP Date Stuff
parents 926183c6 e2d2d2b7
No related branches found
No related tags found
No related merge requests found
......@@ -19,5 +19,8 @@
"Return a string that represents the SQL statement that should be used to set the timezone
for the current transaction.")
(date [this ^Keyword unit field-or-value]
"Return a korma form for truncating a date or timestamp field or value to a given resolution, or extracting a date component.")
)
(date-interval [this ^Keyword unit ^Integer amount]
"Return a korma form for a date relative to NOW(), e.g. on that would produce SQL like `(NOW() + INTERVAL '1 month')`."))
......@@ -20,6 +20,7 @@
DateTimeValue
Field
OrderByAggregateField
RelativeDateTimeValue
Value)))
(declare apply-form
......@@ -90,11 +91,6 @@
(defmethod apply-form :default [form]) ;; nothing
(defn- cast-as-date
"Generate a korma form to cast FIELD-OR-VALUE to a `DATE`."
[field-or-value]
(utils/func "CAST(%s AS DATE)" [field-or-value]))
(defprotocol IGenericSQLFormattable
(formatted [this] [this include-as?]))
......@@ -116,7 +112,7 @@
([this]
(formatted this false))
([{unit :unit, {:keys [field-name base-type special-type], :as field} :field} include-as?]
(let [field (cast-as-date (formatted field))]
(let [field (i/date (:driver *query*) unit (formatted field))]
(if include-as? [field (keyword field-name)]
field))))
......@@ -147,9 +143,19 @@
(formatted
([this]
(formatted this false))
([{:keys [value]} _]
([{value :value, {unit :unit} :field} _]
;; prevent Clojure from converting this to #inst literal, which is a util.date
(cast-as-date `(Timestamp/valueOf ~(.toString value))))))
(i/date (:driver *query*) unit `(Timestamp/valueOf ~(.toString value)))))
RelativeDateTimeValue
(formatted
([this]
(formatted this false))
([{:keys [amount unit], {field-unit :unit} :field} _]
(let [driver (:driver *query*)]
(i/date driver field-unit (if (zero? amount)
(sqlfn :NOW)
(i/date-interval driver unit amount)))))))
(defmethod apply-form :aggregation [[_ {:keys [aggregation-type field]}]]
......
......@@ -132,11 +132,68 @@
(throw (Exception. "Running SQL queries against H2 databases using the default (admin) database user is forbidden.")))))
(qp query)))
;; H2 doesn't have date_trunc() we fake it by formatting a date to an appropriate string
;; and then converting back to a date.
;; Format strings are the same as those of SimpleDateFormat.
(defn- trunc-with-format [format-str]
(format "PARSEDATETIME(FORMATDATETIME(%%s, '%s'), '%s')" format-str format-str))
;; Rounding dates to quarters is a bit involved but still doable. Here's the plan:
;; * extract the year and quarter from the date;
;; * convert the quarter (1 - 4) to the corresponding starting month (1, 4, 7, or 10).
;; (do this by multiplying by 3, giving us [3 6 9 12]. Then subtract 2 to get [1 4 7 10])
;; * Concatenate the year and quarter start month together to create a yyyyMM date string;
;; * Parse the string as a date. :sunglasses:
;;
;; Postgres DATE_TRUNC('quarter', x)
;; becomes PARSEDATETIME(CONCAT(YEAR(x), ((QUARTER(x) * 3) - 2)), 'yyyyMM')
(defn- trunc-to-quarter [field-or-value]
(funcs "PARSEDATETIME(%s, 'yyyyMM')"
["CONCAT(%s)"
["YEAR(%s)" field-or-value]
["((QUARTER(%s) * 3) - 2)" field-or-value]]))
(defn- date [_ unit field-or-value]
(if (= unit :quarter)
(trunc-to-quarter field-or-value)
(utils/func (case unit
:default "CAST(%s AS TIMESTAMP)"
:minute (trunc-with-format "yyyyMMddHHmm")
:minute-of-hour "MINUTE(%s)"
:hour (trunc-with-format "yyyyMMddHH")
:hour-of-day "HOUR(%s)"
:day "CAST(%s AS DATE)"
:day-of-week "DAY_OF_WEEK(%s)"
:day-of-month "DAY_OF_MONTH(%s)"
:day-of-year "DAY_OF_YEAR(%s)"
:week (trunc-with-format "yyyyww") ; ww = week of year
:week-of-year "WEEK(%s)"
:month (trunc-with-format "yyyyMM")
:month-of-year "MONTH(%s)"
:quarter-of-year "QUARTER(%s)"
:year "YEAR(%s)")
[field-or-value])))
;; TODO - maybe rename this relative-date ?
(defn- date-interval [_ unit amount]
(utils/generated (format (case unit
:minute "DATEADD('MINUTE', %d, NOW())"
:hour "DATEADD('HOUR', %d, NOW())"
:day "DATEADD('DAY', %d, NOW())"
:week "DATEADD('WEEK', %d, NOW())"
:month "DATEADD('MONTH', %d, NOW())"
:quarter "DATEADD('MONTH', (%d * 3), NOW())"
:year "DATEADD('YEAR', %d, NOW())")
amount)))
(defrecord H2Driver [])
(extend H2Driver
ISqlDriverDatabaseSpecific {:connection-details->connection-spec connection-details->connection-spec
:database->connection-details database->connection-details
:date date
:date-interval date-interval
:unix-timestamp->timestamp unix-timestamp->timestamp}
;; Override the generic SQL implementation of wrap-process-query-middleware so we can block unsafe native queries (see above)
IDriver (assoc GenericSQLIDriverMixin :wrap-process-query-middleware wrap-process-query-middleware)
......
......@@ -73,7 +73,7 @@
(utils/func (case seconds-or-milliseconds
:seconds "FROM_UNIXTIME(%s)"
:milliseconds "FROM_UNIXTIME(%s / 1000)")
[field-or-value]))
[field-or-value]))
(defn- timezone->set-timezone-sql [_ timezone]
;; If this fails you need to load the timezone definitions from your system into MySQL;
......@@ -81,12 +81,65 @@
;; See https://dev.mysql.com/doc/refman/5.7/en/time-zone-support.html for details
(format "SET @@session.time_zone = '%s';" timezone))
;; Since MySQL doesn't have date_trunc() we fake it by formatting a date to an appropriate string and then converting back to a date.
;; See http://dev.mysql.com/doc/refman/5.6/en/date-and-time-functions.html#function_date-format for an explanation of format specifiers
(defn- trunc-with-format [format-str]
(let [format-str (s/escape format-str {\% "%%"})] ; replace the format specifiers like %y with ones like %%y so they don't get treated as SQL arg placeholders in result str
(format "STR_TO_DATE(DATE_FORMAT(%%s, '%s'), '%s')" format-str format-str)))
;; Truncating to a quarter is trickier since there aren't any format strings.
;; See the explanation in the H2 driver, which does the same thing but with slightly different syntax.
(defn- trunc-to-quarter [field-or-value]
(funcs "STR_TO_DATE(%s, '%%Y-%%m-%%d')"
["CONCAT(%s)"
["YEAR(%s)" field-or-value]
(k/raw "'-'")
["((QUARTER(%s) * 3) - 2)" field-or-value]
(k/raw "'-01'")]))
(defn- date [_ unit field-or-value]
(if (= unit :quarter)
(trunc-to-quarter field-or-value)
(utils/func (case unit
:default "TIMESTAMP(%s)"
:minute (trunc-with-format "%Y-%m-%d %H:%i")
:minute-of-hour "MINUTE(%s)"
:hour (trunc-with-format "%Y-%m-%d %H")
:hour-of-day "HOUR(%s)"
:day "DATE(%s)"
:day-of-week "DAYOFWEEK(%s)"
:day-of-month "DAYOFMONTH(%s)"
:day-of-year "DAYOFYEAR(%s)"
;; To convert a YEARWEEK (e.g. 201530) back to a date you need tell MySQL which day of the week to use,
;; because otherwise as far as MySQL is concerned you could be talking about any of the days in that week
:week "STR_TO_DATE(CONCAT(YEARWEEK(%s), ' Sunday'), '%%X%%V %%W')"
;; mode 6: Sunday is first day of week, first week of year is the first one with 4+ days
:week-of-year "(WEEK(%s, 6) + 1)"
:month "STR_TO_DATE(CONCAT(DATE_FORMAT(%s, '%%Y-%%m'), '-01'), '%%Y-%%m-%%d')"
:month-of-year "MONTH(%s)"
:quarter-of-year "QUARTER(%s)"
:year "YEAR(%s)")
[field-or-value])))
(defn- date-interval [_ unit amount]
(utils/generated (format (case unit
:minute "DATE_ADD(NOW(), INTERVAL %d MINUTE)"
:hour "DATE_ADD(NOW(), INTERVAL %d HOUR)"
:day "DATE_ADD(NOW(), INTERVAL %d DAY)"
:week "DATE_ADD(NOW(), INTERVAL %d WEEK)"
:month "DATE_ADD(NOW(), INTERVAL %d MONTH)"
:quarter "DATE_ADD(NOW(), INTERVAL %d QUARTER)"
:year "DATE_ADD(NOW(), INTERVAL %d YEAR)")
amount)))
(defrecord MySQLDriver [])
(extend MySQLDriver
ISqlDriverDatabaseSpecific {:connection-details->connection-spec connection-details->connection-spec
:database->connection-details database->connection-details
:unix-timestamp->timestamp unix-timestamp->timestamp
:date date
:date-interval date-interval
:timezone->set-timezone-sql timezone->set-timezone-sql}
IDriver GenericSQLIDriverMixin
ISyncDriverTableFKs GenericSQLISyncDriverTableFKsMixin
......
......@@ -120,11 +120,47 @@
(upd Field (:id field) :special_type :json)
(assoc field :special_type :json)))))
(defn- date [_ unit field-or-value]
(utils/func (case unit
:default "CAST(%s AS TIMESTAMP)"
:minute "DATE_TRUNC('minute', %s)"
:minute-of-hour "CAST(EXTRACT(MINUTE FROM %s) AS INTEGER)"
:hour "DATE_TRUNC('hour', %s)"
:hour-of-day "CAST(EXTRACT(HOUR FROM %s) AS INTEGER)"
:day "CAST(%s AS DATE)"
;; Postgres DOW is 0 (Sun) - 6 (Sat); increment this to be consistent with Java, H2, MySQL, and Mongo (1-7)
:day-of-week "(CAST(EXTRACT(DOW FROM %s) AS INTEGER) + 1)"
:day-of-month "CAST(EXTRACT(DAY FROM %s) AS INTEGER)"
:day-of-year "CAST(EXTRACT(DOY FROM %s) AS INTEGER)"
;; Postgres weeks start on Monday, so shift this date into the proper bucket and then decrement the resulting day
:week "(DATE_TRUNC('week', (%s + INTERVAL '1 day')) - INTERVAL '1 day')"
:week-of-year "CAST(EXTRACT(WEEK FROM (%s + INTERVAL '1 day')) AS INTEGER)"
:month "DATE_TRUNC('month', %s)"
:month-of-year "CAST(EXTRACT(MONTH FROM %s) AS INTEGER)"
:quarter "DATE_TRUNC('quarter', %s)"
:quarter-of-year "CAST(EXTRACT(QUARTER FROM %s) AS INTEGER)"
:year "CAST(EXTRACT(YEAR FROM %s) AS INTEGER)")
[field-or-value]))
(defn- date-interval [_ unit amount]
(utils/generated (format (case unit
:minute "(NOW() + INTERVAL '%d minute')"
:hour "(NOW() + INTERVAL '%d hour')"
:day "(NOW() + INTERVAL '%d day')"
:week "(NOW() + INTERVAL '%d week')"
:month "(NOW() + INTERVAL '%d month')"
:quarter "(NOW() + INTERVAL '%d quarter')"
:year "(NOW() + INTERVAL '%d year')")
amount)))
(defrecord PostgresDriver [])
(extend PostgresDriver
ISqlDriverDatabaseSpecific {:connection-details->connection-spec connection-details->connection-spec
:database->connection-details database->connection-details
:unix-timestamp->timestamp unix-timestamp->timestamp
:date date
:date-interval date-interval
:timezone->set-timezone-sql timezone->set-timezone-sql}
ISyncDriverSpecificSyncField {:driver-specific-sync-field! driver-specific-sync-field!}
IDriver GenericSQLIDriverMixin
......
......@@ -108,27 +108,6 @@
:direction :ascending}))))))))
(defn- post-convert-unix-timestamps-to-dates
"Convert the values of Unix timestamps (for `Fields` whose `:special_type` is `:timestamp_seconds` or `:timestamp_milliseconds`) to dates."
[qp]
(fn [query]
(let [{:keys [cols rows], :as results} (qp query)
timestamp-seconds-col-indecies (u/indecies-satisfying #(= (:special_type %) :timestamp_seconds) cols)
timestamp-millis-col-indecies (u/indecies-satisfying #(= (:special_type %) :timestamp_milliseconds) cols)]
(if-not (or (seq timestamp-seconds-col-indecies)
(seq timestamp-millis-col-indecies))
;; If we don't have any columns whose special type is a seconds or milliseconds timestamp return results as-is
results
;; Otherwise go modify the results of each row
(update-in results [:rows] #(for [row %]
(for [[i val] (m/indexed row)]
(cond
(instance? java.util.Date val) val ; already converted to Date as part of preprocessing,
(contains? timestamp-seconds-col-indecies i) (java.sql.Date. (* val 1000)) ; nothing to do here
(contains? timestamp-millis-col-indecies i) (java.sql.Date. val)
:else val))))))))
(defn- pre-cumulative-sum
"Rewrite queries containing a cumulative sum (`cum_sum`) aggregation to simply fetch the values of the aggregate field instead.
(Cumulative sum is a special case; it is implemented in post-processing).
......@@ -270,7 +249,6 @@
post-add-row-count-and-status
pre-add-implicit-fields
pre-add-implicit-breakout-order-by
post-convert-unix-timestamps-to-dates
cumulative-sum
limit
annotate/post-annotate
......@@ -284,7 +262,6 @@
((<<- wrap-catch-exceptions
driver-wrap-process-query
post-add-row-count-and-status
post-convert-unix-timestamps-to-dates
limit
wrap-guard-multiple-calls
driver-process-query) query)))
......
......@@ -59,33 +59,37 @@
;; ## -------------------- Field + Value --------------------
(defn- unexpanded-Field?
"Is this a valid value for a `Field` ID in an unexpanded query? (i.e. an integer or `fk->` form)."
;; ["aggregation" 0] "back-reference" form not included here since its specific to the order_by clause
[field]
(match field
(field-id :guard integer?) true
["fk->" (fk-field-id :guard integer?) (dest-field-id :guard integer?)] true
_ false))
(defn- unexpanded-Field? [field-id]
(match field-id
(_ :guard integer?) true
["fk->" (_ :guard integer?) (_ :guard integer?)] true
["datetime_field" (_ :guard unexpanded-Field?) "as" (_ :guard datetime-field-unit?)] true
:else false))
(defn- parse-field [field-id]
(map->FieldPlaceholder
(match field-id
(_ :guard integer?)
{:field-id field-id}
["fk->" (fk-field-id :guard integer?) (dest-field-id :guard integer?)]
(do (assert-driver-supports :foreign-keys)
(map->FieldPlaceholder {:field-id dest-field-id, :fk-field-id fk-field-id}))
(defn- ph
"Create a new placeholder object for a Field ID or value that can be resolved later."
([field-id]
(map->FieldPlaceholder
(match field-id
(_ :guard integer?)
{:field-id field-id}
["datetime_field" id "as" (unit :guard datetime-field-unit?)]
(assoc (ph id)
:datetime-unit (keyword unit))
["fk->" (fk-field-id :guard integer?) (dest-field-id :guard integer?)]
(do (assert-driver-supports :foreign-keys)
(map->FieldPlaceholder {:field-id dest-field-id, :fk-field-id fk-field-id}))
_ (throw (Exception. (str "Invalid field: " field-id))))))
_ (throw (Exception. (str "Invalid field: " field-id))))))
([field-id value]
(->ValuePlaceholder (ph field-id) value)))
(defn- parse-value [field-id value]
(map->ValuePlaceholder {:field-placeholder (ph field-id)
:value value}))
(defn- ph
"Create a new placeholder object for a Field ID or value that can be resolved later."
([field-id] (parse-field field-id))
([field-id value] (parse-value field-id value)))
;; # ======================================== CLAUSE DEFINITIONS ========================================
......@@ -134,9 +138,11 @@
i.e. This is true of numbers and dates, but not of other strings or booleans."
[v]
(match v
(_ :guard number?) true
(_ :guard u/date-string?) true
_ false))
(_ :guard number?) true
(_ :guard u/date-string?) true
["relative_datetime" "current"] true
["relative_datetime" (_ :guard integer?) (_ :guard relative-datetime-value-unit?)] true
_ false))
(defn- Value?
"Is V a valid unexpanded `Value`?"
......@@ -146,7 +152,41 @@
(= v false)
(orderable-Value? v)))
;; [TIME_INTERVAL ...] filters are just syntactic sugar for more complicated datetime filter subclauses.
;; This function parses the args to the TIME_INTERVAL and returns the appropriate subclause.
;; This clause is then recursively parsed below by parse-filter-subclause.
;;
;; A valid input looks like [TIME_INTERVAL <field> (current|last|next|<int>) <unit>] .
;;
;; "current", "last", and "next" are the same as supplying the integers 0, -1, and 1, respectively.
;; For these values, we want to generate a clause like [= [datetime_field <field> as <unit>] [datetime <int> <unit>]].
;;
;; For ints > 1 or < -1, we want to generate a range (i.e., a BETWEEN filter clause). These should *exclude* the current moment in time.
;;
;; e.g. [TIME_INTERVAL <field> -30 "day"] refers to the past 30 days, excluding today; i.e. the range of -31 days ago to -1 day ago.
;; Thus values of n < -1 translate to clauses like [BETWEEN [datetime_field <field> as day] [datetime -31 day] [datetime -1 day]].
(defparser parse-time-interval-filter-subclause
;; For "current"/"last"/"next" replace with the appropriate int and recurse
[field "current" unit] (parse-time-interval-filter-subclause [field 0 unit])
[field "last" unit] (parse-time-interval-filter-subclause [field -1 unit])
[field "next" unit] (parse-time-interval-filter-subclause [field 1 unit])
;; For values of -1 <= n <= 1, generate the appropriate [= ...] clause
[field 0 unit] ["=" ["datetime_field" field "as" unit] ["relative_datetime" "current"]]
[field -1 unit] ["=" ["datetime_field" field "as" unit] ["relative_datetime" -1 unit]]
[field 1 unit] ["=" ["datetime_field" field "as" unit] ["relative_datetime" 1 unit]]
;; For other int values of n generate the appropriate [BETWEEN ...] clause
[field (n :guard #(< % -1)) unit] ["BETWEEN" ["datetime_field" field "as" unit] ["relative_datetime" (dec n) unit] ["relative_datetime" -1 unit]]
[field (n :guard #(> % 1)) unit] ["BETWEEN" ["datetime_field" field "as" unit] ["relative_datetime" 1 unit] ["relative_datetime" (inc n) unit]])
(defparser parse-filter-subclause
["TIME_INTERVAL" (field-id :guard unexpanded-Field?) (n :guard #(or (integer? %) (contains? #{"current" "last" "next"} %))) (unit :guard relative-datetime-value-unit?)]
(parse-filter-subclause (parse-time-interval-filter-subclause [field-id n (name unit)]))
["TIME_INTERVAL" & args]
(throw (Exception. (format "Invalid TIME_INTERVAL clause: %s" args)))
["INSIDE" (lat-field :guard unexpanded-Field?) (lon-field :guard unexpanded-Field?) (lat-max :guard number?) (lon-min :guard number?) (lat-min :guard number?) (lon-max :guard number?)]
(map->Filter:Inside {:filter-type :inside
:lat {:field (ph lat-field)
......
......@@ -53,6 +53,14 @@
[table-name])
field-name)))
(def ^:const datetime-field-units
"Valid units for a `DateTimeField`."
#{:default :minute :minute-of-hour :hour :hour-of-day :day :day-of-week :day-of-month :day-of-year
:week :week-of-year :month :month-of-year :quarter :quarter-of-year :year})
(defn datetime-field-unit? [unit]
(contains? datetime-field-units (keyword unit)))
;; wrapper around Field
(defrecord DateTimeField [^Field field
^Keyword unit])
......@@ -62,9 +70,21 @@
(defrecord Value [value
^Field field])
;; e.g. an absolute point in time (literal)
(defrecord DateTimeValue [^Timestamp value
^DateTimeField field])
(def ^:const relative-datetime-value-units
"Valid units for a `RelativeDateTimeValue`."
#{:minute :hour :day :week :month :quarter :year})
(defn relative-datetime-value-unit? [unit]
(contains? relative-datetime-value-units (keyword unit)))
(defrecord RelativeDateTimeValue [^Integer amount
^Keyword unit
^DateTimeField field])
;;; # ------------------------------------------------------------ PLACEHOLDER TYPES: FIELDPLACEHOLDER + VALUEPLACEHOLDER ------------------------------------------------------------
......@@ -76,6 +96,7 @@
;; Replace values with these during first pass over Query.
;; Include associated Field ID so appropriate the info can be found during Field resolution
(defrecord ValuePlaceholder [^FieldPlaceholder field-placeholder
^Keyword relative-unit
value])
......
(ns metabase.driver.query-processor.parse
"Logic relating to parsing values associated with different Query Processor `Field` types."
(:require [metabase.driver.query-processor.interface :refer :all]
(:require [clojure.core.match :refer [match]]
[metabase.driver.query-processor.interface :refer :all]
[metabase.util :as u])
(:import (metabase.driver.query_processor.interface DateTimeField
Field)))
......@@ -13,8 +14,17 @@
:value value}))
(defmethod parse-value DateTimeField [field value]
(try (let [value (u/parse-iso8601 value)]
(map->DateTimeValue {:value value
:field field}))
(catch Throwable _
(throw (Exception. "Invalid value '%s': expected a DateTime.")))))
(match value
(_ :guard u/date-string?)
(map->DateTimeValue {:field field
:value (u/parse-iso8601 value)})
["relative_datetime" "current"]
(map->RelativeDateTimeValue {:amount 0, :field field})
["relative_datetime" (amount :guard integer?) (unit :guard relative-datetime-value-unit?)]
(map->RelativeDateTimeValue {:amount amount
:field field
:unit (keyword unit)})
_ (throw (Exception. (format "Invalid value '%s': expected a DateTime." value)))))
......@@ -9,7 +9,8 @@
[table :refer [Table]])
[metabase.test.data :refer :all]
(metabase.test.data [dataset-definitions :as defs]
[datasets :as datasets :refer [*dataset*]])
[datasets :as datasets :refer [*dataset*]]
[interface :refer [create-database-definition]])
[metabase.test.util.q :refer [Q]]
[metabase.util :as u]))
......@@ -1074,3 +1075,224 @@
(Q return first-row
aggregate count of venues
filter != price 1 2))
;; +-------------------------------------------------------------------------------------------------------------+
;; | NEW DATE STUFF |
;; +-------------------------------------------------------------------------------------------------------------+
;; ## BUCKETING
(defn- sad-toucan-incidents-with-bucketing [unit]
(vec (Q dataset sad-toucan-incidents
aggregate count of incidents
breakout ["datetime_field" (id :incidents :timestamp) "as" unit]
limit 10
return rows)))
(datasets/expect-with-datasets #{:h2 :postgres :mysql}
[[#inst "2015-06-01T10:31" 1]
[#inst "2015-06-01T16:06" 1]
[#inst "2015-06-01T17:23" 1]
[#inst "2015-06-01T18:55" 1]
[#inst "2015-06-01T21:04" 1]
[#inst "2015-06-01T21:19" 1]
[#inst "2015-06-02T02:13" 1]
[#inst "2015-06-02T05:37" 1]
[#inst "2015-06-02T08:20" 1]
[#inst "2015-06-02T11:11" 1]]
(sad-toucan-incidents-with-bucketing :default))
(datasets/expect-with-datasets #{:h2 :postgres :mysql}
[[#inst "2015-06-01T10:31" 1]
[#inst "2015-06-01T16:06" 1]
[#inst "2015-06-01T17:23" 1]
[#inst "2015-06-01T18:55" 1]
[#inst "2015-06-01T21:04" 1]
[#inst "2015-06-01T21:19" 1]
[#inst "2015-06-02T02:13" 1]
[#inst "2015-06-02T05:37" 1]
[#inst "2015-06-02T08:20" 1]
[#inst "2015-06-02T11:11" 1]]
(sad-toucan-incidents-with-bucketing :minute))
(datasets/expect-with-datasets #{:h2 :postgres :mysql}
[[0 5]
[1 4]
[2 2]
[3 4]
[4 4]
[5 3]
[6 5]
[7 1]
[8 1]
[9 1]]
(sad-toucan-incidents-with-bucketing :minute-of-hour))
(datasets/expect-with-datasets #{:h2 :postgres :mysql}
[[#inst "2015-06-01T10" 1]
[#inst "2015-06-01T16" 1]
[#inst "2015-06-01T17" 1]
[#inst "2015-06-01T18" 1]
[#inst "2015-06-01T21" 2]
[#inst "2015-06-02T02" 1]
[#inst "2015-06-02T05" 1]
[#inst "2015-06-02T08" 1]
[#inst "2015-06-02T11" 1]
[#inst "2015-06-02T13" 1]]
(sad-toucan-incidents-with-bucketing :hour))
(datasets/expect-with-datasets #{:h2 :postgres :mysql}
[[0 8]
[1 9]
[2 7]
[3 10]
[4 10]
[5 9]
[6 6]
[7 5]
[8 7]
[9 7]]
(sad-toucan-incidents-with-bucketing :hour-of-day))
(datasets/expect-with-datasets #{:h2 :postgres :mysql}
[[#inst "2015-06-01T07" 8]
[#inst "2015-06-02T07" 9]
[#inst "2015-06-03T07" 9]
[#inst "2015-06-04T07" 4]
[#inst "2015-06-05T07" 11]
[#inst "2015-06-06T07" 8]
[#inst "2015-06-07T07" 6]
[#inst "2015-06-08T07" 10]
[#inst "2015-06-09T07" 6]
[#inst "2015-06-10T07" 10]]
(sad-toucan-incidents-with-bucketing :day))
(datasets/expect-with-datasets #{:h2 :postgres :mysql}
[[1 29]
[2 36]
[3 33]
[4 29]
[5 13]
[6 38]
[7 22]]
(sad-toucan-incidents-with-bucketing :day-of-week))
(datasets/expect-with-datasets #{:h2 :postgres :mysql}
[[1 8]
[2 9]
[3 9]
[4 4]
[5 11]
[6 8]
[7 6]
[8 10]
[9 6]
[10 10]]
(sad-toucan-incidents-with-bucketing :day-of-month))
(datasets/expect-with-datasets #{:h2 :postgres :mysql}
[[152 8]
[153 9]
[154 9]
[155 4]
[156 11]
[157 8]
[158 6]
[159 10]
[160 6]
[161 10]]
(sad-toucan-incidents-with-bucketing :day-of-year))
(datasets/expect-with-datasets #{:h2 :postgres :mysql}
[[#inst "2015-05-31T07" 49]
[#inst "2015-06-07T07" 47]
[#inst "2015-06-14T07" 39]
[#inst "2015-06-21T07" 58]
[#inst "2015-06-28T07" 7]]
(sad-toucan-incidents-with-bucketing :week))
(datasets/expect-with-datasets #{:h2 :postgres :mysql}
[[23 49]
[24 47]
[25 39]
[26 58]
[27 7]]
(sad-toucan-incidents-with-bucketing :week-of-year))
(datasets/expect-with-datasets #{:h2 :postgres :mysql}
[[#inst "2015-06-01T07" 200]]
(sad-toucan-incidents-with-bucketing :month))
(datasets/expect-with-datasets #{:h2 :postgres :mysql}
[[6 200]]
(sad-toucan-incidents-with-bucketing :month-of-year))
(datasets/expect-with-datasets #{:h2 :postgres :mysql}
[[#inst "2015-04-01T07" 200]]
(sad-toucan-incidents-with-bucketing :quarter))
(datasets/expect-with-datasets #{:h2 :postgres :mysql}
[[2 200]]
(sad-toucan-incidents-with-bucketing :quarter-of-year))
(datasets/expect-with-datasets #{:h2 :postgres :mysql}
[[2015 200]]
(sad-toucan-incidents-with-bucketing :year))
;; RELATIVE DATES
(defn- database-def-with-timestamps [interval-seconds]
(create-database-definition "DB"
["checkins"
[{:field-name "timestamp"
:base-type :DateTimeField}]
(vec (for [i (range -15 15)]
[(java.sql.Timestamp. (+ (System/currentTimeMillis) (* i 1000 interval-seconds)))]))]))
(def ^:private checkins:4-per-minute (database-def-with-timestamps 15))
(def ^:private checkins:4-per-hour (database-def-with-timestamps (* 60 15)))
(def ^:private checkins:1-per-day (database-def-with-timestamps (* 60 60 24)))
(defn- count-of-grouping [db field-grouping & relative-datetime-args]
(with-temp-db [_ db]
(Q aggregate count of checkins
filter = ["datetime_field" (id :checkins :timestamp) "as" (name field-grouping)] (apply vector "relative_datetime" relative-datetime-args)
return first-row first)))
(datasets/expect-with-datasets #{:h2 :postgres :mysql} 4 (count-of-grouping checkins:4-per-minute :minute "current"))
(datasets/expect-with-datasets #{:h2 :postgres :mysql} 4 (count-of-grouping checkins:4-per-minute :minute -1 "minute"))
(datasets/expect-with-datasets #{:h2 :postgres :mysql} 4 (count-of-grouping checkins:4-per-minute :minute 1 "minute"))
(datasets/expect-with-datasets #{:h2 :postgres :mysql} 4 (count-of-grouping checkins:4-per-hour :hour "current"))
(datasets/expect-with-datasets #{:h2 :postgres :mysql} 4 (count-of-grouping checkins:4-per-hour :hour -1 "hour"))
(datasets/expect-with-datasets #{:h2 :postgres :mysql} 4 (count-of-grouping checkins:4-per-hour :hour 1 "hour"))
(datasets/expect-with-datasets #{:h2 :postgres :mysql} 1 (count-of-grouping checkins:1-per-day :day "current"))
(datasets/expect-with-datasets #{:h2 :postgres :mysql} 1 (count-of-grouping checkins:1-per-day :day -1 "day"))
(datasets/expect-with-datasets #{:h2 :postgres :mysql} 1 (count-of-grouping checkins:1-per-day :day 1 "day"))
(datasets/expect-with-datasets #{:h2 :postgres :mysql} 7 (count-of-grouping checkins:1-per-day :week "current"))
;; SYNTACTIC SUGAR
(datasets/expect-with-datasets #{:h2 :postgres :mysql}
1
(with-temp-db [_ checkins:1-per-day]
(-> (driver/process-query
{:database (db-id)
:type :query
:query {:source_table (id :checkins)
:aggregation ["count"]
:filter ["TIME_INTERVAL" (id :checkins :timestamp) "current" "day"]}})
:data :rows first first)))
(datasets/expect-with-datasets #{:h2 :postgres :mysql}
7
(with-temp-db [_ checkins:1-per-day]
(-> (driver/process-query
{:database (db-id)
:type :query
:query {:source_table (id :checkins)
:aggregation ["count"]
:filter ["TIME_INTERVAL" (id :checkins :timestamp) "last" "week"]}})
:data :rows first first)))
......@@ -38,25 +38,25 @@
(def ^:dynamic *table-name* nil)
(defmacro field [f]
{:pre [(symbol? f)]}
(core/or
(let [f (name f)]
(u/cond-let
;; x->y <-> ["fk->" x y]
[[_ from to] (re-matches #"^(.+)->(.+)$" f)]
["fk->" `(field ~(symbol from)) `(field ~(symbol to))]
;; x...y <-> ?
[[_ f sub] (re-matches #"^(.+)\.\.\.(.+)$" f)]
`(~@(macroexpand-1 `(field ~(symbol f))) ~(keyword sub))
;; ag.0 <-> ["aggregation" 0]
[[_ ag-field-index] (re-matches #"^ag\.(\d+)$" f)]
["aggregation" (Integer/parseInt ag-field-index)]
;; table.field <-> (id table field)
[[_ table field] (re-matches #"^([^\.]+)\.([^\.]+)$" f)]
`(data/id ~(keyword table) ~(keyword field))))
(if-not (symbol? f) f
(let [f (name f)]
(u/cond-let
;; x->y <-> ["fk->" x y]
[[_ from to] (re-matches #"^(.+)->(.+)$" f)]
["fk->" `(field ~(symbol from)) `(field ~(symbol to))]
;; x...y <-> ?
[[_ f sub] (re-matches #"^(.+)\.\.\.(.+)$" f)]
`(~@(macroexpand-1 `(field ~(symbol f))) ~(keyword sub))
;; ag.0 <-> ["aggregation" 0]
[[_ ag-field-index] (re-matches #"^ag\.(\d+)$" f)]
["aggregation" (Integer/parseInt ag-field-index)]
;; table.field <-> (id table field)
[[_ table field] (re-matches #"^([^\.]+)\.([^\.]+)$" f)]
`(data/id ~(keyword table) ~(keyword field)))))
;; fallback : (id *table-name* field)
`(data/id *table-name* ~(keyword f))))
......
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment