diff --git a/README.md b/README.md index e83a365..965ae5f 100644 --- a/README.md +++ b/README.md @@ -24,8 +24,8 @@ for copying and pasting directly into your SQL tool of choice! ## Note on code samples -All sample code in this README is automatically run as a unit test using -[seancorfield/readme](https://github.com/seancorfield/readme). +Sample code in this documentation is verified via +[lread/test-doc-blocks](https://github.com/lread/test-doc-blocks). Some of these samples show pretty-printed SQL: HoneySQL 2.x supports `:pretty true` which inserts newlines between clauses in the generated SQL strings. @@ -37,6 +37,8 @@ HoneySQL 1.x will continue to get critical security fixes but otherwise should b ## Usage +From Clojure: + ```clojure (refer-clojure :exclude '[filter for group-by into partition-by set update]) (require '[honey.sql :as sql] @@ -51,6 +53,20 @@ HoneySQL 1.x will continue to get critical security fixes but otherwise should b '[clojure.core :as c]) ``` +From ClojureScript, we don't have `:refer :all`. If we want to use `:refer`, we have no choice but to be specific: + +```Clojure +(refer-clojure :exclude '[filter for group-by into partition-by set update]) +(require '[honey.sql :as sql] + '[honey.sql.helpers :refer [select select-distinct from + join left-join right-join + where for group-by having union + order-by limit offset values columns + update insert-into set composite + delete delete-from truncate] :as h] + '[clojure.core :as c]) +``` + Everything is built on top of maps representing SQL queries: ```clojure @@ -78,7 +94,8 @@ HoneySQL is a relatively "pure" library, it does not manage your JDBC connection or run queries for you, it simply generates SQL strings. You can then pass them to a JDBC library, such as [`next.jdbc`](https://github.com/seancorfield/next-jdbc): -```clj + +```clojure (jdbc/execute! conn (sql/format sqlmap)) ``` @@ -352,7 +369,7 @@ VALUES (?, (?, ?)), (?, (?, ?)) Updates are possible too: ```clojure -(-> (h/update :films) +(-> (update :films) (set {:kind "dramatic" :watched [:+ :watched 1]}) (where [:= :kind "drama"]) @@ -543,9 +560,9 @@ These can be combined to allow more fine-grained control over SQL generation: ``` ```clojure call-qualify-map -=> '{:where [:and [:= :a [:param :baz]] [:= :b [:inline 42]]] - :from (:foo) - :select [[[:foo :bar]] [[:raw "@var := foo.bar"]]]} +=> {:where [:and [:= :a [:param :baz]] [:= :b [:inline 42]]] + :from (:foo) + :select [[[:foo :bar]] [[:raw "@var := foo.bar"]]]} ``` ```clojure (sql/format call-qualify-map {:params {:baz "BAZ"}}) @@ -730,7 +747,9 @@ OFFSET ? ``` ```clojure ;; Printable and readable -(= big-complicated-map (read-string (pr-str big-complicated-map))) +(require '[clojure.edn :as edn]) + +(= big-complicated-map (edn/read-string (pr-str big-complicated-map))) => true ``` diff --git a/build.clj b/build.clj index 92feb29..97f9f39 100644 --- a/build.clj +++ b/build.clj @@ -4,27 +4,53 @@ clojure -T:build run-tests clojure -T:build run-tests :aliases '[:master]' + clojure -T:build run-doc-tests :aliases '[:cljs]' + clojure -T:build ci For more information, run: clojure -A:deps -T:build help/doc" + (:require [clojure.tools.build.api :as b] [org.corfield.build :as bb])) (def lib 'com.github.seancorfield/honeysql) (def version (format "2.0.%s" (b/git-count-revs nil))) -(defn readme "Run the README tests." [opts] - (-> opts (bb/run-task [:readme]))) - (defn eastwood "Run Eastwood." [opts] (-> opts (bb/run-task [:eastwood]))) +(defn gen-doc-tests "Generate tests from doc code blocks." [opts] + (-> opts (bb/run-task [:gen-doc-tests]))) + +(defn run-doc-tests + "Generate and run doc tests. + + Optionally specify :aliases vector: + [:1.9] -- test against Clojure 1.9 (the default) + [:1.10] -- test against Clojure 1.10.3 + [:master] -- test against Clojure 1.11 master snapshot + [:cljs] -- test against ClojureScript" + [{:keys [aliases] :as opts}] + (gen-doc-tests opts) + (bb/run-tests (assoc opts :aliases + (-> [:test-doc] + (into aliases) + (into (if (some #{:cljs} aliases) + [:test-doc-cljs] + [:test-doc-clj]))))) + opts) + (defn ci "Run the CI pipeline of tests (and build the JAR)." [opts] (-> opts + (bb/clean) (assoc :lib lib :version version) - (readme) + (as-> opts + (reduce (fn [opts alias] + (run-doc-tests (assoc opts :aliases [alias]))) + opts + [:cljs :1.9 :1.10 :master])) (eastwood) (as-> opts (reduce (fn [opts alias] diff --git a/build/honey/gen_doc_tests.clj b/build/honey/gen_doc_tests.clj new file mode 100644 index 0000000..7aed688 --- /dev/null +++ b/build/honey/gen_doc_tests.clj @@ -0,0 +1,31 @@ +(ns honey.gen-doc-tests + (:require [babashka.fs :as fs] + [lread.test-doc-blocks :as tdb])) + +(defn -main [& _args] + (let [target "target/test-doc-blocks" + success-marker (fs/file target "SUCCESS") + docs ["README.md" + "doc/clause-reference.md" + "doc/differences-from-1-x.md" + "doc/extending-honeysql.md" + "doc/general-reference.md" + "doc/getting-started.md" + "doc/postgresql.md" + "doc/special-syntax.md"] + regen-reason (if (not (fs/exists? success-marker)) + "a previous successful gen result not found" + (let [newer-thans (fs/modified-since target + (concat docs + ["build.clj" "deps.edn"] + (fs/glob "build" "**/*.*") + (fs/glob "src" "**/*.*")))] + (when (seq newer-thans) + (str "found files newer than last gen: " (mapv str newer-thans)))))] + (if regen-reason + (do + (fs/delete-if-exists success-marker) + (println "gen-doc-tests: Regenerating:" regen-reason) + (tdb/gen-tests {:docs docs}) + (spit success-marker "SUCCESS")) + (println "gen-doc-tests: Tests already successfully generated")))) diff --git a/deps.edn b/deps.edn index 6a06057..616661f 100644 --- a/deps.edn +++ b/deps.edn @@ -13,16 +13,27 @@ :master {:override-deps {org.clojure/clojure {:mvn/version "1.11.1-master-SNAPSHOT"}}} ;; running tests/checks of various kinds: - :test ; can also run clojure -X:test + :test {:extra-paths ["test"] - :extra-deps {io.github.cognitect-labs/test-runner - {:git/tag "v0.4.0" :git/sha "334f2e2"}} - :exec-fn cognitect.test-runner.api/test} + :extra-deps {io.github.cognitect-labs/test-runner + {:git/tag "v0.4.0" :git/sha "334f2e2"}} + :exec-fn cognitect.test-runner.api/test} ;; various "runners" for tests/CI: :cljs {:extra-deps {olical/cljs-test-runner {:mvn/version "3.8.0"}} :main-opts ["-m" "cljs-test-runner.main"]} - :readme {:extra-deps {seancorfield/readme {:mvn/version "1.0.16"}} - :main-opts ["-m" "seancorfield.readme"]} + + :gen-doc-tests {:replace-paths ["build"] + :extra-deps {babashka/fs {:mvn/version "0.0.5"} + com.github.lread/test-doc-blocks {:mvn/version "1.0.146-alpha"}} + :main-opts ["-m" "honey.gen-doc-tests"]} + + :test-doc {:replace-paths ["src" "target/test-doc-blocks/test"]} + :test-doc-clj {:main-opts ["-m" "cognitect.test-runner" + "-d" "target/test-doc-blocks/test"]} + :test-doc-cljs {:main-opts ["-m" "cljs-test-runner.main" + "-c" "{:warnings,{:single-segment-namespace,false}}" + "-d" "target/test-doc-blocks/test"]} + :eastwood {:extra-deps {jonase/eastwood {:mvn/version "0.9.9"}} :main-opts ["-m" "eastwood.lint" "{:source-paths,[\"src\"]}"]}}} diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 1c3e7d8..7409fef 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -14,6 +14,14 @@ dialects that HoneySQL supports. DDL clauses are listed first, followed by SQL clauses. +The examples herein assume: +```clojure +(refer-clojure :exclude '[partition-by]) +(require '[honey.sql :as sql] + '[honey.sql.helpers :refer [select from join-by left-join join + where order-by over partition-by window]]) +``` + # DDL Clauses HoneySQL supports the following DDL clauses as a data DSL. @@ -76,7 +84,7 @@ user=> (sql/format {:alter-table :fruit ["ALTER TABLE fruit ADD INDEX look(appearance)"] user=> (sql/format {:alter-table :fruit :add-index [:unique nil :color :appearance]}) -["ALTER TABLE fruit ADD UNIQUE(color,appearance)"] +["ALTER TABLE fruit ADD UNIQUE(color, appearance)"] user=> (sql/format {:alter-table :fruit :drop-index :look}) ["ALTER TABLE fruit DROP INDEX look"] ``` @@ -108,12 +116,7 @@ user=> (sql/format {:create-table :fruit [[:id :int [:not nil]] [:name [:varchar 32] [:not nil]] [:cost :float :null]]}) -;; reformatted for clarity: -["CREATE TABLE fruit ( - id INT NOT NULL, - name VARCHAR(32) NOT NULL, - cost FLOAT NULL -)"] +["CREATE TABLE fruit (id INT NOT NULL, name VARCHAR(32) NOT NULL, cost FLOAT NULL)"] ``` The `:with-columns` clause is formatted as if `{:inline true}` @@ -544,25 +547,30 @@ user=> (sql/format {:select [:t.ref :pp.code] [:using :id]] :join [[:logtransaction :log] [:= :t.id :log.id]]] - :where [:= "settled" :pp.status]}) -;; newlines inserted for readability: -["SELECT t.ref, pp.code FROM transaction AS t - LEFT JOIN paypal_tx AS pp USING (id) - INNER JOIN logtransaction AS log ON t.id = log.id - WHERE ? = pp.status" "settled"] -;; or using helpers: + :where [:= "settled" :pp.status]} + {:pretty true}) +[" +SELECT t.ref, pp.code +FROM transaction AS t +LEFT JOIN paypal_tx AS pp USING (id) INNER JOIN logtransaction AS log ON t.id = log.id +WHERE ? = pp.status +" "settled"] + +;; or the equivalent using helpers: user=> (sql/format (-> (select :t.ref :pp.code) (from [:transaction :t]) (join-by (left-join [:paypal-tx :pp] [:using :id]) (join [:logtransaction :log] [:= :t.id :log.id])) - (where := "settled" :pp.status))) -;; newlines inserted for readability: -["SELECT t.ref, pp.code FROM transaction AS t - LEFT JOIN paypal_tx AS pp USING (id) - INNER JOIN logtransaction AS log ON t.id = log.id - WHERE ? = pp.status" "settled"] + (where := "settled" :pp.status)) + {:pretty true}) +[" +SELECT t.ref, pp.code +FROM transaction AS t +LEFT JOIN paypal_tx AS pp USING (id) INNER JOIN logtransaction AS log ON t.id = log.id +WHERE ? = pp.status +" "settled"] ``` Without `:join-by`, a `:join` would normally be generated before a `:left-join`. @@ -667,25 +675,25 @@ user=> (sql/format {:select [:id :w :MaxSalary]]]] :from [:employee] - :window [:w {:partition-by [:department]}]}) -;; newlines inserted for readability: -["SELECT id, - AVG(salary) OVER (PARTITION BY department ORDER BY designation ASC) AS Average, - MAX(salary) OVER w AS MaxSalary - FROM employee - WINDOW w AS (PARTITION BY department)"] + :window [:w {:partition-by [:department]}]} + {:pretty true}) +[" +SELECT id, AVG(salary) OVER (PARTITION BY department ORDER BY designation ASC) AS Average, MAX(salary) OVER w AS MaxSalary +FROM employee +WINDOW w AS (PARTITION BY department) +"] ;; easier to write with helpers (and easier to read!): user=> (sql/format (-> (select :id (over [[:avg :salary] (-> (partition-by :department) (order-by :designation)) :Average] [[:max :salary] :w :MaxSalary])) (from :employee) - (window :w (partition-by :department)))) -;; newlines inserted for readability: -["SELECT id, - AVG(salary) OVER (PARTITION BY department ORDER BY designation ASC) AS Average, - MAX(salary) OVER w AS MaxSalary - FROM employee - WINDOW w AS (PARTITION BY department)"] + (window :w (partition-by :department))) + {:pretty true}) +[" +SELECT id, AVG(salary) OVER (PARTITION BY department ORDER BY designation ASC) AS Average, MAX(salary) OVER w AS MaxSalary +FROM employee +WINDOW w AS (PARTITION BY department) +"] ``` The window function in the `:over` expression may be `{}` or `nil`: diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index 7c56d88..fddcc2d 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -19,17 +19,30 @@ In addition, HoneySQL 2.x contains different namespaces so you can have both ver ### HoneySQL 1.x +In `deps.edn`: + ```clojure -;; in deps.edn: honeysql {:mvn/version "1.0.461"} ;; or, more correctly: honeysql/honeysql {:mvn/version "1.0.461"} +``` -;; in use: +Required as: + +```clojure (ns my.project (:require [honeysql.core :as sql])) +``` -... +Or if in the REPL: + +```clojure +(require '[honeysql.core :as sq]) +``` + +In use: + +```clojure (sql/format {:select [:*] :from [:table] :where [:= :id 1]}) ;;=> ["SELECT * FROM table WHERE id = ?" 1] (sql/format {:select [:*] :from [:table] :where [:= :id 1]} :quoting :mysql) @@ -47,15 +60,26 @@ Supported Clojure versions: 1.7 and later. ### HoneySQL 2.x +In `deps.edn`: + ```clojure -;; in deps.edn: com.github.seancorfield/honeysql {:mvn/version "2.0.783"} +``` -;; in use: +Required as: + +```clojure (ns my.project (:require [honey.sql :as sql])) +``` -... +Or if in the REPL: +```clojure +(require '[honey.sql :as sql]) +``` + +In use: +```clojure (sql/format {:select [:*] :from [:table] :where [:= :id 1]}) ;;=> ["SELECT * FROM table WHERE id = ?" 1] (sql/format {:select [:*] :from [:table] :where [:= :id 1]} {:dialect :mysql}) @@ -158,7 +182,7 @@ it should have been a function, and in 2.x it is: ```clojure ;; 1.x: EXISTS should never have been implemented as SQL syntax: it's an operator! ;; (sq/format {:exists {:select [:a] :from [:foo]}}) -;;=> ["EXISTS (SELECT a FROM foo)"] +;; -> ["EXISTS (SELECT a FROM foo)"] ;; 2.x: select function call with an alias: user=> (sql/format {:select [[[:exists {:select [:a] :from [:foo]}] :x]]}) diff --git a/doc/extending-honeysql.md b/doc/extending-honeysql.md index ed734e6..b7c7192 100644 --- a/doc/extending-honeysql.md +++ b/doc/extending-honeysql.md @@ -50,6 +50,8 @@ two arguments. You can optionally specify that an operator can take any number of arguments with `:variadic true`: ```clojure +(require '[honey.sql :as sql]) + (sql/register-op! :<=> :variadic true) ;; and then use the new operator: (sql/format {:select [:*], :from [:table], :where [:<=> 13 :x 42]}) @@ -86,6 +88,7 @@ The formatter function will be called with: For example: + ```clojure (sql/register-fn! :foo (fn [f args] ..)) diff --git a/doc/general-reference.md b/doc/general-reference.md index 70005a1..4d5b632 100644 --- a/doc/general-reference.md +++ b/doc/general-reference.md @@ -12,6 +12,8 @@ because `:quoted true` was specified, the literal name of an unqualified, single-segment keyword or symbol is used as-is and quoted: ```clojure +(require '[honey.sql :as sql]) + (sql/format {:select :foo-bar} {:quoted true}) ;;=> ["SELECT \"foo-bar\""] (sql/format {:select :foo-bar} {:dialect :mysql}) diff --git a/doc/getting-started.md b/doc/getting-started.md index 747fdaf..b13112d 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -8,12 +8,14 @@ data to a SQL statement (string) and any parameters it needs. For the Clojure CLI, add the following dependency to your `deps.edn` file: + ```clojure com.github.seancorfield/honeysql {:mvn/version "2.0.783"} ``` For Leiningen, add the following dependency to your `project.clj` file: + ```clojure [com.github.seancorfield/honeysql "2.0.783"] ``` @@ -41,11 +43,9 @@ SQL string as the first element followed by any parameter values identified in the SQL expressions: ```clojure -(ns my.example - (:require [honey.sql :as sql])) +(require '[honey.sql :as sql]) (sql/format {:select [:*], :from [:table], :where [:= :id 1]}) -;; produces: ;;=> ["SELECT * FROM table WHERE id = ?" 1] ``` @@ -65,7 +65,6 @@ that represents a SQL entity and its alias (where aliases are allowed): ```clojure (sql/format {:select [:t.id [:name :item]], :from [[:table :t]], :where [:= :id 1]}) -;; produces: ;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1] ``` @@ -80,9 +79,10 @@ avoid evaluation: ```clojure (sql/format '{select [t.id [name item]], from [[table t]], where [= id 1]}) -;; or you can use (..) instead of [..] when quoted: +;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1] + +;; or you can use (..) instead of [..] when quoted to produce the same result: (sql/format '{select (t.id (name item)), from ((table t)), where (= id 1)}) -;; also produces: ;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1] ``` @@ -91,10 +91,10 @@ keywords (or symbols) and the namespace portion will treated as the table name, i.e., `:foo/bar` instead of `:foo.bar`: ```clojure +;; notice the following both produce the same result: (sql/format {:select [:t/id [:name :item]], :from [[:table :t]], :where [:= :id 1]}) -;; and +;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1] (sql/format '{select [t/id [name item]], from [[table t]], where [= id 1]}) -;; both produce: ;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1] ``` @@ -116,6 +116,7 @@ described in the [Special Syntax](special-syntax.md) section. Some examples: + ```clojure [:= :a 42] ;=> "a = ?" with a parameter of 42 [:+ 42 :a :b] ;=> "? + a + b" with a parameter of 42 @@ -133,6 +134,7 @@ Another form of special syntax that is treated as function calls is keywords or symbols that begin with `%`. Such keywords (or symbols) are split at `.` and turned into function calls: + ```clojure %now ;=> NOW() %count.* ;=> COUNT(*) @@ -143,6 +145,7 @@ are split at `.` and turned into function calls: If you need to reference a table or alias for a column, you can use qualified names in a function invocation: + ```clojure %max.foo/bar ;=> MAX(foo.bar) ``` @@ -179,6 +182,7 @@ that are not keywords or symbols are lifted out as positional parameters. They are replaced by `?` in the generated SQL string and added to the parameter list in order: + ```clojure [:between :size 10 20] ;=> "size BETWEEN ? AND ?" with parameters 10 and 20 ``` @@ -195,11 +199,11 @@ call as the `:params` key of the options hash map. (sql/format {:select [:*] :from [:table] :where [:= :a :?x]} {:params {:x 42}}) -["SELECT * FROM table WHERE a = ?" 42] +;;=> ["SELECT * FROM table WHERE a = ?" 42] (sql/format {:select [:*] :from [:table] :where [:= :a [:param :x]]} {:params {:x 42}}) -["SELECT * FROM table WHERE a = ?" 42] +;;=> ["SELECT * FROM table WHERE a = ?" 42] ``` ## Functional Helpers @@ -210,15 +214,13 @@ SQL queries with raw Clojure data structures, a is also available. These functions are generally variadic and threadable: ```clojure -(ns my.example - (:require [honey.sql :as sql] - [honey.sql.helpers :refer [select from where]])) +(require '[honey.sql :as sql] + '[honey.sql.helpers :refer [select from where]]) (-> (select :t/id [:name :item]) (from [:table :t]) (where [:= :id 1]) (sql/format)) -;; produces: ;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1] ``` @@ -238,7 +240,6 @@ can make it easier to build queries programmatically: (where [:= :id 1]) (select [:name :item]) (sql/format)) -;; produces: ;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1] ``` @@ -252,7 +253,6 @@ you need to explicitly remove the prior value: (dissoc :select) (select [:name :item]) (sql/format)) -;; produces: ;;=> ["SELECT name AS item FROM table AS t WHERE id = ?" 1] ``` @@ -314,6 +314,8 @@ dialect in a `format` call, they will be quoted. If you don't specify a dialect in the `format` call, you can specify `:quoted true` to have SQL entities quoted. + ```clojure (sql/format '{select (id) from (table)} {:quoted true}) ;;=> ["SELECT \"id\" FROM \"table\""] @@ -323,6 +325,11 @@ specify a dialect in the `format` call, you can specify ;;=> nil (sql/format '{select (id) from (table)} {:quoted true}) ;;=> ["SELECT [id] FROM [table]"] +;; and to the default of :ansi +(sql/set-dialect! :ansi) +;;=> nil +(sql/format '{select (id) from (table)} {:quoted true}) +;;=> ["SELECT \"id\" FROM \"table\""] ``` Out of the box, as part of the extended ANSI SQL support, diff --git a/doc/postgresql.md b/doc/postgresql.md index d709832..a19b4ea 100644 --- a/doc/postgresql.md +++ b/doc/postgresql.md @@ -18,6 +18,23 @@ HoneySQL not to do that. There are two possible approaches: 1. Use named parameters (e.g., `[:param :myval]`) instead of having the values directly in the DSL structure and then pass `{:params {:myval some-json}}` as part of the options in the call to `format`, or 2. Use `[:lift ..]` wrapped around any structured values which tells HoneySQL not to interpret the vector or hash map value as a DSL: `[:lift some-json]`. +The code example herein assume: +```clojure +(refer-clojure :exclude '[update set]) +(require '[honey.sql :as sql] + '[honey.sql.helpers :refer [select from where + update set + insert-into values + create-table with-columns create-view create-extension + add-column alter-table add-index + modify-column rename-column rename-table + drop-table drop-column drop-index drop-extension + upsert returning on-conflict on-constraint + do-update-set do-nothing]]) +``` + +Clojure users can opt for the shorter `(require '[honey.sql :as sql] '[honey.sql.helpers :refer :all])` but this syntax is not available to ClojureScript users. + ## Upsert Upserting data is relatively easy in PostgreSQL @@ -34,11 +51,16 @@ user=> (-> (insert-into :distributors) (upsert (-> (on-conflict :did) (do-update-set :dname))) (returning :*) - sql/format) -;; newlines inserted for readability: -["INSERT INTO distributors (did, dname) VALUES (?, ?), (?, ?) - ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname RETURNING *" - 5 "Gizmo Transglobal" 6 "Associated Computing, Inc"] + (sql/format {:pretty true})) +[" +INSERT INTO distributors +(did, dname) VALUES (?, ?), (?, ?) +ON CONFLICT (did) +DO UPDATE SET dname = EXCLUDED.dname +RETURNING * +" +5 "Gizmo Transglobal" +6 "Associated Computing, Inc"] ``` However, the nested `upsert` helper is no longer needed @@ -51,11 +73,16 @@ user=> (-> (insert-into :distributors) (on-conflict :did) (do-update-set :dname) (returning :*) - sql/format) -;; newlines inserted for readability: -["INSERT INTO distributors (did, dname) VALUES (?, ?), (?, ?) - ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname RETURNING *" - 5 "Gizmo Transglobal" 6 "Associated Computing, Inc"] + (sql/format {:pretty true})) +[" +INSERT INTO distributors +(did, dname) VALUES (?, ?), (?, ?) +ON CONFLICT (did) +DO UPDATE SET dname = EXCLUDED.dname +RETURNING * +" +5 "Gizmo Transglobal" +6 "Associated Computing, Inc"] ``` Similarly, the `do-nothing` helper behaves just the same @@ -66,11 +93,14 @@ user=> (-> (insert-into :distributors) (values [{:did 7 :dname "Redline GmbH"}]) (upsert (-> (on-conflict :did) do-nothing)) - sql/format) -;; newlines inserted for readability: -["INSERT INTO distributors (did, dname) VALUES (?, ?) - ON CONFLICT (did) DO NOTHING" - 7 "Redline GmbH"] + (sql/format {:pretty true})) +[" +INSERT INTO distributors +(did, dname) VALUES (?, ?) +ON CONFLICT (did) +DO NOTHING +" +7 "Redline GmbH"] ``` As above, the nested `upsert` helper is no longer needed: @@ -80,11 +110,14 @@ user=> (-> (insert-into :distributors) (values [{:did 7 :dname "Redline GmbH"}]) (on-conflict :did) do-nothing - sql/format) -;; newlines inserted for readability: -["INSERT INTO distributors (did, dname) VALUES (?, ?) - ON CONFLICT (did) DO NOTHING" - 7 "Redline GmbH"] + (sql/format {:pretty true})) +[" +INSERT INTO distributors +(did, dname) VALUES (?, ?) +ON CONFLICT (did) +DO NOTHING +" +7 "Redline GmbH"] ``` `ON CONSTRAINT` is handled slightly differently to the nilenso library, @@ -96,22 +129,29 @@ user=> (-> (insert-into :distributors) ;; can specify as a nested clause... (on-conflict (on-constraint :distributors_pkey)) do-nothing - sql/format) -;; newlines inserted for readability: -["INSERT INTO distributors (did, dname) VALUES (?, ?) - ON CONFLICT ON CONSTRAINT distributors_pkey DO NOTHING" - 9 "Antwerp Design"] + (sql/format {:pretty true})) +[" +INSERT INTO distributors +(did, dname) VALUES (?, ?) +ON CONFLICT ON CONSTRAINT distributors_pkey +DO NOTHING +" +9 "Antwerp Design"] user=> (-> (insert-into :distributors) (values [{:did 9 :dname "Antwerp Design"}]) ;; ...or as two separate clauses on-conflict (on-constraint :distributors_pkey) do-nothing - sql/format) -;; newlines inserted for readability: -["INSERT INTO distributors (did, dname) VALUES (?, ?) - ON CONFLICT ON CONSTRAINT distributors_pkey DO NOTHING" - 9 "Antwerp Design"] + (sql/format {:pretty true})) +[" +INSERT INTO distributors +(did, dname) VALUES (?, ?) +ON CONFLICT +ON CONSTRAINT distributors_pkey +DO NOTHING +" +9 "Antwerp Design"] ``` As above, the `upsert` helper has been omitted here. @@ -124,12 +164,14 @@ user=> (-> (insert-into :user) (values [{:phone "5555555" :name "John"}]) (on-conflict :phone (where [:<> :phone nil])) (do-update-set :phone :name (where [:= :user.active false])) - sql/format) -;; newlines inserted for readability: -["INSERT INTO user (phone, name) VALUES (?, ?) - ON CONFLICT (phone) WHERE phone IS NOT NULL - DO UPDATE SET phone = EXCLUDED.phone, name = EXCLUDED.name - WHERE user.active = FALSE" "5555555" "John"] + (sql/format {:pretty true})) +[" +INSERT INTO user +(phone, name) VALUES (?, ?) +ON CONFLICT (phone) WHERE phone IS NOT NULL +DO UPDATE SET phone = EXCLUDED.phone, name = EXCLUDED.name WHERE user.active = FALSE +" +"5555555" "John"] ;; using the DSL directly: user=> (sql/format {:insert-into :user @@ -137,16 +179,20 @@ user=> (sql/format :on-conflict [:phone {:where [:<> :phone nil]}] :do-update-set {:fields [:phone :name] - :where [:= :user.active false]}}) -;; newlines inserted for readability: -["INSERT INTO user (phone, name) VALUES (?, ?) - ON CONFLICT (phone) WHERE phone IS NOT NULL - DO UPDATE SET phone = EXCLUDED.phone, name = EXCLUDED.name - WHERE user.active = FALSE" "5555555" "John"] + :where [:= :user.active false]}} + {:pretty true}) +[" +INSERT INTO user +(phone, name) VALUES (?, ?) +ON CONFLICT (phone) WHERE phone IS NOT NULL +DO UPDATE SET phone = EXCLUDED.phone, name = EXCLUDED.name WHERE user.active = FALSE +" +"5555555" "John"] ``` By comparison, this is the DSL structure that nilenso would have required: + ```clojure ;; NOT VALID FOR HONEYSQL! {:insert-into :user @@ -230,12 +276,12 @@ user=> (-> (create-table :distributors) ;; "serial" is inlined as 'SERIAL': [:default [:nextval "serial"]]] [:name [:varchar 40] [:not nil]]]) - sql/format) + (sql/format {:pretty true})) ;; newlines inserted for readability: -["CREATE TABLE distributors ( - did INTEGER PRIMARY KEY DEFAULT NEXTVAL('SERIAL'), - name VARCHAR(40) NOT NULL -)"] +[" +CREATE TABLE distributors +(did INTEGER PRIMARY KEY DEFAULT NEXTVAL('SERIAL'), name VARCHAR(40) NOT NULL) +"] ;; PostgreSQL CHECK constraint is supported: user=> (-> (create-table :products) (with-columns [[:product_no :integer] @@ -243,20 +289,16 @@ user=> (-> (create-table :products) [:price :numeric [:check [:> :price 0]]] [:discounted_price :numeric] [[:check [:and [:> :discounted_price 0] [:> :price :discounted_price]]]]]) - sql/format) -;; newlines inserted for readability: -["CREATE TABLE products ( - product_no INTEGER, - name TEXT, - price NUMERIC CHECK(PRICE > 0), - discounted_price NUMERIC, - CHECK((discounted_price > 0) AND (price > discounted_price)) -)"] + (sql/format {:pretty true})) +[" +CREATE TABLE products +(product_no INTEGER, name TEXT, price NUMERIC CHECK(PRICE > 0), discounted_price NUMERIC, CHECK((discounted_price > 0) AND (price > discounted_price))) +"] ;; conditional creation: user=> (-> (create-table :products :if-not-exists) - ... + (with-columns [[:name :text]]) sql/format) -["CREATE TABLE IF NOT EXISTS products (...)"] +["CREATE TABLE IF NOT EXISTS products (name TEXT)"] ;; drop table: user=> (sql/format (drop-table :cities)) ["DROP TABLE cities"] @@ -339,10 +381,7 @@ user=> (-> (alter-table :fruit) user=> (sql/format (alter-table :fruit (add-column :skin [:varchar 16] nil) (add-index :unique :fruit-name :name))) -;; newlines inserted for readability: -["ALTER TABLE fruit - ADD COLUMN skin VARCHAR(16) NULL, - ADD UNIQUE fruit_name(name)"] +["ALTER TABLE fruit ADD COLUMN skin VARCHAR(16) NULL, ADD UNIQUE fruit_name(name)"] ``` ## Filter / Within Group diff --git a/doc/special-syntax.md b/doc/special-syntax.md index 97b2681..0bf4d4a 100644 --- a/doc/special-syntax.md +++ b/doc/special-syntax.md @@ -13,6 +13,8 @@ a sequence, and produces `ARRAY[?, ?, ..]` for the elements of that sequence (as SQL parameters): ```clojure +(require '[honey.sql :as sql]) + (sql/format-expr [:array (range 5)]) ;;=> ["ARRAY[?, ?, ?, ?, ?]" 0 1 2 3 4] ``` @@ -36,8 +38,7 @@ may be `:else` (or `'else`) to produce `ELSE`, otherwise ```clojure (sql/format-expr [:case [:< :a 10] "small" [:> :a 100] "big" :else "medium"]) -;;=> ["CASE WHEN a < ? THEN ? WHEN a > ? THEN ? ELSE ? END" -;; 10 "small" 100 "big" "medium"] +;; => ["CASE WHEN a < ? THEN ? WHEN a > ? THEN ? ELSE ? END" 10 "small" 100 "big" "medium"] ``` ## cast @@ -76,6 +77,7 @@ SQL entity. This is intended for use in contexts that would otherwise produce a sequence of SQL keywords, such as when constructing DDL statements. + ```clojure [:tablespace :quux] ;;=> TABLESPACE QUUX @@ -89,9 +91,9 @@ Intended to be used with regular expression patterns to specify the escape characters (if any). ```clojure -(format {:select :* :from :foo - :where [:similar-to :foo [:escape "bar" [:inline "*"]]]}) -;;=> ["SELECT * FROM foo WHERE foo SIMILAR TO ? ESCAPE '*'" "bar"])))) +(sql/format {:select :* :from :foo + :where [:similar-to :foo [:escape "bar" [:inline "*"]]]}) +;;=> ["SELECT * FROM foo WHERE foo SIMILAR TO ? ESCAPE '*'" "bar"] ``` ## filter, within-group @@ -104,34 +106,39 @@ Filter generally expects an aggregate expression and a `WHERE` clause. Within group generally expects an aggregate expression and an `ORDER BY` clause. ```clojure -(format {:select [:a :b [[:filter :%count.* {:where [:< :x 100]}] :c] - [[:within-group [:percentile_disc [:inline 0.25]] - {:order-by [:a]}] :inter_max] - [[:within-group [:percentile_cont [:inline 0.25]] - {:order-by [:a]}] :abs_max]] - :from :aa}) -;; newlines added for readability: -;;=> ["SELECT a, b, COUNT(*) FILTER (WHERE x < ?) AS c, -;;=> PERCENTILE_DISC(0.25) WITHIN GROUP (ORDER BY a ASC) AS inter_max, -;;=> PERCENTILE_CONT(0.25) WITHIN GROUP (ORDER BY a ASC) AS abs_max -;;=> FROM aa" 100] +(sql/format {:select [:a :b [[:filter :%count.* {:where [:< :x 100]}] :c] + [[:within-group [:percentile_disc [:inline 0.25]] + {:order-by [:a]}] :inter_max] + [[:within-group [:percentile_cont [:inline 0.25]] + {:order-by [:a]}] :abs_max]] + :from :aa} + {:pretty true}) +;;=> [" +SELECT a, b, COUNT(*) FILTER (WHERE x < ?) AS c, PERCENTILE_DISC(0.25) WITHIN GROUP (ORDER BY a ASC) AS inter_max, PERCENTILE_CONT(0.25) WITHIN GROUP (ORDER BY a ASC) AS abs_max +FROM aa +" +100] ``` There are helpers for both `filter` and `within-group`. Be careful with `filter` since it shadows `clojure.core/filter`: ```clojure -(format (-> (select :a :b [(filter :%count.* (where :< :x 100)) :c] - [(within-group [:percentile_disc [:inline 0.25]] - (order-by :a)) :inter_max] - [(within-group [:percentile_cont [:inline 0.25]] - (order-by :a)) :abs_max]) - (from :aa))) -;; newlines added for readability: -;;=> ["SELECT a, b, COUNT(*) FILTER (WHERE x < ?) AS c, -;;=> PERCENTILE_DISC(0.25) WITHIN GROUP (ORDER BY a ASC) AS inter_max, -;;=> PERCENTILE_CONT(0.25) WITHIN GROUP (ORDER BY a ASC) AS abs_max -;;=> FROM aa" 100] +(refer-clojure :exclude '[filter]) +(require '[honey.sql.helpers :refer [select filter within-group from order-by where]]) + +(sql/format (-> (select :a :b [(filter :%count.* (where :< :x 100)) :c] + [(within-group [:percentile_disc [:inline 0.25]] + (order-by :a)) :inter_max] + [(within-group [:percentile_cont [:inline 0.25]] + (order-by :a)) :abs_max]) + (from :aa)) + {:pretty true}) +;;=> [" +SELECT a, b, COUNT(*) FILTER (WHERE x < ?) AS c, PERCENTILE_DISC(0.25) WITHIN GROUP (ORDER BY a ASC) AS inter_max, PERCENTILE_CONT(0.25) WITHIN GROUP (ORDER BY a ASC) AS abs_max +FROM aa +" +100] ``` ## inline @@ -214,15 +221,15 @@ by an ordering specifier, which can be an expression or a pair of expression and direction (`:asc` or `:desc`): ```clojure -(format {:select [[[:array_agg [:order-by :a [:b :desc]]]]] :from :table}) +(sql/format {:select [[[:array_agg [:order-by :a [:b :desc]]]]] :from :table}) ;;=> ["SELECT ARRAY_AGG(a ORDER BY b DESC) FROM table"] -(format (-> (select [[:array_agg [:order-by :a [:b :desc]]]]) +(sql/format (-> (select [[:array_agg [:order-by :a [:b :desc]]]]) (from :table))) ;;=> ["SELECT ARRAY_AGG(a ORDER BY b DESC) FROM table"] -(format {:select [[[:string_agg :a [:order-by [:inline ","] :a]]]] :from :table}) +(sql/format {:select [[[:string_agg :a [:order-by [:inline ","] :a]]]] :from :table}) ;;=> ["SELECT STRING_AGG(a, ',' ORDER BY a ASC) FROM table"] -(format (-> (select [[:string_agg :a [:order-by [:inline ","] :a]]]) - (from :table))) +(sql/format (-> (select [[:string_agg :a [:order-by [:inline ","] :a]]]) + (from :table))) ;;=> ["SELECT STRING_AGG(a, ',' ORDER BY a ASC) FROM table"] ``` @@ -285,7 +292,7 @@ parameters from them: (sql/format {:select [:a [[:raw ["@var := " [:inline "foo"]]]]]}) ;;=> ["SELECT a, @var := 'foo'"] (sql/format {:select [:a [[:raw ["@var := " ["foo"]]]]]}) -;;=> ["SELECT a, @var := ?" "foo"] +;;=> ["SELECT a, @var := (?)" "foo"] ``` `:raw` is also supported as a SQL clause for the same reason. @@ -304,6 +311,7 @@ specifications). If no arguments are provided, these render as just SQL keywords (uppercase): + ```clojure [:foreign-key] ;=> FOREIGN KEY [:primary-key] ;=> PRIMARY KEY @@ -311,6 +319,7 @@ keywords (uppercase): Otherwise, these render as regular function calls: + ```clojure [:foreign-key :a] ;=> FOREIGN KEY(a) [:primary-key :x :y] ;=> PRIMARY KEY(x, y) @@ -326,6 +335,7 @@ argument. If two or more arguments are provided, this renders as a SQL keyword followed by the first argument, followed by the rest as a regular argument list: + ```clojure [:default] ;=> DEFAULT [:default 42] ;=> DEFAULT 42 @@ -339,6 +349,7 @@ followed by the rest as a regular argument list: These behave like the group above except that if the first argument is `nil`, it is omitted: + ```clojure [:index :foo :bar :quux] ;=> INDEX foo(bar, quux) [:index nil :bar :quux] ;=> INDEX(bar, quux)