10 KiB
HoneySQL examples
docker run –name some-postgres -e POSTGRES_PASSWORD=mysecretpassword -d postgres
Introduction
HoneySQL is a Domain Specific Language (DSL) for building SQL queries. HoneySQL provides a number of helper functions to make it easier to build queries, so you don't need to build the data structure manually.
HoneySQL does not care about connecting to your database. It only builds queries. All examples send the result to format
and first
so that the resulting query is displayed inside the browser.
Basic Query's
One nice way to write HoneySQL queries is to use the ->
threading macro. The ->
threading macro takes two arguments: the first argument is the result of the previous call, and the second argument is the function to call with that result. This allows you to chain together multiple calls to build complex queries.
Here is an example of how to use the ->
macro to build a simple SQL query:
(-> (sqlh/select :first_name :last_name :email)
(sqlh/from :users)
(sql/format {:pretty true})
(first))
The equivalent code with out a threading macros looks like this.
(first
(sql/format
(sqlh/from
(sqlh/select :first_name :last_name :email)
:users)
{:pretty true}))
Basic SQL select queries
Using HoneySQL you can incrementally build up our queries, they do not need to be complete to get an answer this allow us to define partial SQL and compose it together.
The example below will produce a select for a couple of fields passing the resulting data into format to create an SQL string we can send to the database, we call first because the result is a vector containing and SQL and any values need none in this instance.
(-> (sqlh/select :first_name :last_name :email)
(sql/format {:pretty true})
(first))
We can extend the example above to include the FROM
part of the SQL statement to give us something more complete.
How ever it's much nicer for readability to use the threading macro
(-> (sqlh/select :first_name :last_name :email)
(sqlh/from :users)
(sql/format {:pretty true})
(first))
The functions understand SQL statement ordering so the order you call the functions does not matter.
(-> (sqlh/from :users)
(sqlh/select :first_name :last_name :email)
(sql/format {:pretty true})
(first))
We can extend the query to add in limiting & ordering.
(-> (sqlh/select :first_name :last_name :email)
(sqlh/from :users)
(sqlh/order-by :first_name)
(sqlh/limit 10)
(sql/format {:pretty true})
(first))
Now is a good time to explain aliasing, basically the values to select become wrapped in vectors with the second value being the alias so [:first_name :fn] to alias the column first_name
to fn
we can aliases columns tables sub select's same as standard SQL.
(-> base-sql
(sqlh/select [:first_name :fn] [:last_name :ln] [:email :e])
(sql/format {:pretty true})
(first))
Basic SQL filtering
Filtering is just as simple and support the usual operators like = < > we pass them in as keywords so :=
:<>
:<
:.
would be the equivalents.
(-> (sqlh/select :first_name :last_name :email)
(sqlh/from :users)
(sqlh/where [:= :first_name "spot"]
[:= :last_name "dog"])
(sql/format {:pretty true})
(first))
Often we want to conditionally filter, this is nice and simple with the knowledge that the where
function will short circuit given a nil value this means we can use when
and if
functions inside our sql generations.
So below the SQL where will not be appended because true is not false so the when returns nil removing the where in the generated query.
(-> (sqlh/select :first_name :last_name :email)
(sqlh/from :users)
(sqlh/where (when (true? false) [:= :first_name "spot"]))
(sql/format {:pretty true})
(first))
We can use similar technique to switch between matching a single and multiple values.
(defn conditional-where [id]
(-> (sqlh/select :*)
(sqlh/from [:company])
(sqlh/where (if (sequential? id) [:in :id id] [:= :id id]))))
(clojure.string/join
"\n"
[(-> (conditional-where [1 2 3])
(sql/format {:pretty true})
(first))
(-> (conditional-where 1)
(sql/format {:pretty true})
(first))])
Composing SQL queries
For all the standard fn's like select and where there are equivalent merge fn's the merge versions append in place of replacing.
A good strategy is to build basic queries extending them when needed, so create a base select then create a function which build on the query adding in the conditions, this allow you to run the base queries in the REPL or the extended version making it easier to find query related issues by testing parts in isolation.
we can use if
when
when-let
cond->
among other functions to help build these, in the example below you can see the where part of the query is modified based on what values are provided in the map.
(def base-sql
(-> (sqlh/select :first_name :last_name :email)
(sqlh/from :users)))
(defn user-search [{:keys [first-name last-name] :or {first-name nil last-name nil}}]
(-> base-sql
(sqlh/select :first_name :last_name)
(sqlh/where (when first-name [:= :first_name first-name]))
(sqlh/where (when last-name [:= :last_name last-name]))))
(clojure.string/join
"\n"
[;; Search for furst name only
(-> {:first-name "spot" }
(user-search)
(sql/format {:pretty true})
(first))
;; Search for last name only
(-> {:last-name "dog"}
(user-search)
(sql/format {:pretty true})
(first))
;; Search for both first and last name
(-> {:first-name "spot" :last-name "dog"}
(user-search)
(sql/format {:pretty true})
(first))])
Joining tables
We can also do joins to other table's
(def base-sql
(-> (sqlh/select :first_name :last_name :email)
(sqlh/from :users)))
(def base-join-sql
(-> base-sql
(sqlh/join [:address] [:= :users.address_id :address.id])))
(first (sql/format base-join-sql))
or group by's and sql functions like count
max
min
these can be used by appending :%name to the selected column.
(def base-group-sql
(-> base-sql
(sqlh/select :first_name [:%count.first_name :count_name])
(sqlh/group-by :first_name)))
(first (sql/format base-group-sql))
Larger query
This is how I like to compose queries, and shows a larger query being generated.
(def big-base-sql
(-> (sqlh/select :users.* :address.* :products.*)
(sqlh/from :users)
(sqlh/join :address [:= :users.address_id :address.id])
(sqlh/join :products [:= :users.address_id :address.id])
(sqlh/limit 100)))
(defn big-base-filters [filters]
(-> big-base-sql
(sqlh/where
(when (:first_name filters)
[:= :first_name (:first_name filters)]))
(sqlh/where
(when (:last_name filters)
[:= :last_name (:last_name filters)]))
(sqlh/where
(when (:product_name filters)
[:= :product.name (:product_name filters)]))
(sqlh/where
(when (:active filters)
[:= :active (:active filters)]))))
(first (sql/format
(big-base-filters
{:first_name "spot"
:last_name "dog"
:product_name "lead"
:active true})))
Don't forget its just data, if you don't use sql/format it just returns a data structure which you can build manually, or manipulate with the standard library.
; {:select (:first_name :last_name :email), :from (:users)}
Extending / raw sql
When all else fails you have a few options, check to see if there is a honeysql db specific library or break out sql/raw
or extending honey sql.
Say we want to get people added in the last 14 days this is a bit more tricky
[(def base-last-14-days-sql
(-> base-sql
(sqlh/where [:>
[:raw "created"]
[:raw "CURRENT_DATE - INTERVAL '14' DAY"]])))]
(first (sql/format base-last-14-days-sql))
Basic statements
Switch between singular or multiple values in condition
(defn conditional-where [id]
(-> (sqlh/select :*)
(sqlh/from [:company])
(sqlh/where (if (sequential? id) [:in :id id] [:= :id id]))))
(first (sql/format (conditional-where [1 2 3]) {:pretty true}))
;(clojure.string/join "" (sql/format (conditional-where [1 2 3]) {:pretty true}))
Insert or update data on conflict
In this example we will insert some data but on a conflict we will update the row instead,
(defn upsert-daily-sales-sql [values]
(-> (sqlh/insert-into :address)
(sqlh/values values)
(sqlh/on-conflict :first_name :last_name :email)
(sqlh/do-update-set :line1 :line2 :city :country :postcode)))
(defn -main []
(first (sql/format (conditional-where [1 2 3]) {:pretty true}))
)