Back
with-columns (clj)
(source)function
(with-columns & col-specs)
(with-columns col-spec-coll)
Accepts any number of column descriptions. Each
column description is a sequence of SQL elements
that specify the name and the attributes.
(with-columns [:id :int [:not nil]]
[:name [:varchar 32] [:default ""]])
Produces:
id INT NOT NULL,
name VARCHAR(32) DEFAULT ''
Can also accept a single argument which is a
collection of column descriptions (mostly for
compatibility with nilenso/honeysql-postgres
which used to be needed for DDL).
Examples
honeysql
(ns honey.sql.postgres-test
(:refer-clojure :exclude [update partition-by set])
(:require [clojure.test :refer [deftest is testing]]
;; pull in all the PostgreSQL helpers that the nilenso
;; library provided (as well as the regular HoneySQL ones):
[honey.sql.helpers :as sqlh :refer
[upsert on-conflict do-nothing on-constraint
returning do-update-set
;; not needed because do-update-set can do this directly
#_do-update-set!
alter-table rename-column drop-column
add-column partition-by
;; not needed because insert-into can do this directly
#_insert-into-as
create-table rename-table drop-table
window create-view over with-columns
create-extension drop-extension
select-distinct-on
;; already part of HoneySQL
insert-into values where select
from order-by update set]]
[honey.sql :as sql]))
(deftest create-table-test
;; the nilenso versions of these tests required sql/call for function-like syntax
(testing "create table with two columns"
(is (= ["CREATE TABLE cities (city VARCHAR(80) PRIMARY KEY, location POINT)"]
(-> (create-table :cities)
(with-columns [[:city [:varchar 80] [:primary-key]]
[:location :point]])
sql/format))))
(testing "create table with foreign key reference"
(is (= ["CREATE TABLE weather (city VARCHAR(80) REFERENCES cities(city), temp_lo INT, temp_hi INT, prcp REAL, date DATE)"]
(-> (create-table :weather)
(with-columns [[:city [:varchar :80] [:references :cities :city]]
[:temp_lo :int]
[:temp_hi :int]
[:prcp :real]
[:date :date]])
sql/format))))
(testing "creating table with table level constraint"
(is (= ["CREATE TABLE films (code CHAR(5), title VARCHAR(40), did INTEGER, date_prod DATE, kind VARCHAR(10), CONSTRAINT code_title PRIMARY KEY(code, title))"]
(-> (create-table :films)
(with-columns [[:code [:char 5]]
[:title [:varchar 40]]
[:did :integer]
[:date_prod :date]
[:kind [:varchar 10]]
[[:constraint :code_title] [:primary-key :code :title]]])
sql/format))))
(testing "creating table with column level constraint"
(is (= ["CREATE TABLE films (code CHAR(5) CONSTRAINT firstkey PRIMARY KEY, title VARCHAR(40) NOT NULL, did INTEGER NOT NULL, date_prod DATE, kind VARCHAR(10))"]
(-> (create-table :films)
(with-columns [[:code [:char 5] [:constraint :firstkey] [:primary-key]]
[:title [:varchar 40] [:not nil]]
[:did :integer [:not nil]]
[:date_prod :date]
[:kind [:varchar 10]]])
sql/format))))
(testing "creating table with columns with default values"
(is (= ["CREATE TABLE distributors (did INTEGER PRIMARY KEY DEFAULT NEXTVAL('serial'), name VARCHAR(40) NOT NULL)"]
(-> (create-table :distributors)
(with-columns [[:did :integer [:primary-key] [:default [:nextval "serial"]]]
[:name [:varchar 40] [:not nil]]])
sql/format))))
(testing "creating table with column checks"
(is (= ["CREATE TABLE products (product_no INTEGER, name TEXT, price NUMERIC CHECK(price > 0), discounted_price NUMERIC, CHECK((discounted_price > 0) AND (price > discounted_price)))"]
(-> (create-table :products)
(with-columns [[:product_no :integer]
[:name :text]
[:price :numeric [:check [:> :price 0]]]
[:discounted_price :numeric]
[[:check [:and [:> :discounted_price 0] [:> :price :discounted_price]]]]])
sql/format)))))
(deftest references-issue-386
(is (= ["CREATE TABLE IF NOT EXISTS user (id VARCHAR(255) NOT NULL PRIMARY KEY, company_id INT NOT NULL, name VARCHAR(255) NOT NULL, password VARCHAR(255) NOT NULL, created_time DATETIME DEFAULT CURRENT_TIMESTAMP, updated_time DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, FOREIGN KEY(company_id) REFERENCES company(id))"]
(-> {:create-table [:user :if-not-exists]
:with-columns
[[:id [:varchar 255] [:not nil] [:primary-key]]
[:company-id :int [:not nil]]
[:name [:varchar 255] [:not nil]]
[:password [:varchar 255] [:not nil]]
[:created-time :datetime [:default :CURRENT_TIMESTAMP]]
[:updated-time :datetime [:default :CURRENT_TIMESTAMP]
:on :update :CURRENT_TIMESTAMP]
[[:foreign-key :company-id] [:references :company :id]]]}
(sql/format)))))
(deftest create-table-issue-437
(is (= ["CREATE TABLE bar (did UUID DEFAULT GEN_RANDOM_UUID(), foo_id VARCHAR NOT NULL, PRIMARY KEY(did, foo_id), FOREIGN KEY(foo_id) REFERENCES foo(id) ON DELETE CASCADE)"]
(-> (create-table :bar)
(with-columns
[[:did :uuid [:default [:gen_random_uuid]]]
[:foo-id :varchar [:not nil]]
[[:primary-key :did :foo-id]]
[[:foreign-key :foo-id]
[:references :foo :id]
:on-delete :cascade]])
(sql/format)))))
(deftest issue-453-constraint
(testing "standalone constraint"
(is (= ["CREATE TABLE bar (a INTEGER, b INTEGER, CONSTRAINT foo_natural_key UNIQUE (a, b))"]
(-> {:create-table [:bar]
:with-columns
[[:a :integer]
[:b :integer]
[[:constraint :foo_natural_key] :unique [:composite :a :b]]]}
(sql/format)))))
(testing "inline constraint"
(is (= ["CREATE TABLE foo (a INTEGER CONSTRAINT a_pos CHECK(a > 0), b INTEGER, CONSTRAINT a_bigger CHECK(b < a))"]
(-> '{create-table foo
with-columns
((a integer (constraint a_pos) (check (> a 0)))
(b integer)
((constraint a_bigger) (check (< b a))))}
(sql/format))))))
honeysql
(ns honey.sql.helpers-test
(:refer-clojure :exclude [filter for group-by partition-by set update])
(:require [clojure.test :refer [deftest is testing]]
[honey.sql :as sql]
[honey.sql.helpers :as h
:refer [add-column add-index alter-table columns create-table create-table-as create-view
create-materialized-view drop-view drop-materialized-view
create-index
bulk-collect-into
cross-join do-update-set drop-column drop-index drop-table
filter from full-join
group-by having insert-into
join-by join lateral left-join limit offset on-conflict
on-duplicate-key-update
order-by over partition-by refresh-materialized-view
rename-column rename-table returning right-join
select select-distinct select-top select-distinct-top
values where window with with-columns
with-data within-group]]))
(deftest issue-293-basic-ddl
(is (= (sql/format {:create-view :metro :select [:*] :from [:cities] :where [:= :metroflag "y"]})
["CREATE VIEW metro AS SELECT * FROM cities WHERE metroflag = ?" "y"]))
(is (= (sql/format {:create-table :films
:with-columns [[:id :int :unsigned :auto-increment]
[:name [:varchar 50] [:not nil]]]})
["CREATE TABLE films (id INT UNSIGNED AUTO_INCREMENT, name VARCHAR(50) NOT NULL)"]))
(is (= (sql/format (-> (create-view :metro)
(select :*)
(from :cities)
(where [:= :metroflag "y"])))
["CREATE VIEW metro AS SELECT * FROM cities WHERE metroflag = ?" "y"]))
(is (= (sql/format (-> (create-table-as :metro :if-not-exists)
(select :*)
(from :cities)
(where [:= :metroflag "y"])
(with-data false)))
["CREATE TABLE IF NOT EXISTS metro AS SELECT * FROM cities WHERE metroflag = ? WITH NO DATA" "y"]))
(is (= (sql/format (-> (create-table-as :metro :or-replace)
(select :*)
(from :cities)
(where [:= :metroflag "y"])
(with-data false)))
["CREATE OR REPLACE TABLE metro AS SELECT * FROM cities WHERE metroflag = ? WITH NO DATA" "y"]))
(is (= (sql/format (-> (create-table-as :temp :metro :if-not-exists)
(select :*)
(from :cities)
(where [:= :metroflag "y"])
(with-data false)))
["CREATE TEMP TABLE IF NOT EXISTS metro AS SELECT * FROM cities WHERE metroflag = ? WITH NO DATA" "y"]))
(is (= (sql/format (-> (create-table-as :temp :metro :or-replace)
(select :*)
(from :cities)
(where [:= :metroflag "y"])
(with-data false)))
["CREATE OR REPLACE TEMP TABLE metro AS SELECT * FROM cities WHERE metroflag = ? WITH NO DATA" "y"]))
(is (= (sql/format (-> (create-materialized-view :metro :if-not-exists)
(select :*)
(from :cities)
(where [:= :metroflag "y"])
(with-data false)))
["CREATE MATERIALIZED VIEW IF NOT EXISTS metro AS SELECT * FROM cities WHERE metroflag = ? WITH NO DATA" "y"]))
(is (= (sql/format (-> (create-table-as :metro :if-not-exists
(columns :foo :bar :baz)
[:tablespace [:entity :quux]])
(select :*)
(from :cities)
(where [:= :metroflag "y"])
(with-data false)))
[(str "CREATE TABLE IF NOT EXISTS metro"
" (foo, bar, baz) TABLESPACE quux"
" AS SELECT * FROM cities WHERE metroflag = ? WITH NO DATA") "y"]))
(is (= (sql/format (-> (create-table-as :metro :or-replace
(columns :foo :bar :baz)
[:tablespace [:entity :quux]])
(select :*)
(from :cities)
(where [:= :metroflag "y"])
(with-data false)))
[(str "CREATE OR REPLACE TABLE metro"
" (foo, bar, baz) TABLESPACE quux"
" AS SELECT * FROM cities WHERE metroflag = ? WITH NO DATA") "y"]))
(is (= (sql/format (-> (create-materialized-view :metro :if-not-exists
(columns :foo :bar :baz)
[:tablespace [:entity :quux]])
(select :*)
(from :cities)
(where [:= :metroflag "y"])
(with-data false)))
[(str "CREATE MATERIALIZED VIEW IF NOT EXISTS metro"
" (foo, bar, baz) TABLESPACE quux"
" AS SELECT * FROM cities WHERE metroflag = ? WITH NO DATA") "y"]))
(is (= (sql/format {:create-materialized-view [:metro :if-not-exists]
:select [:*]
:from :cities
:where [:= :metroflag "y"]
:with-data true})
["CREATE MATERIALIZED VIEW IF NOT EXISTS metro AS SELECT * FROM cities WHERE metroflag = ? WITH DATA" "y"]))
(is (= (sql/format {:create-materialized-view [:metro :if-not-exists
(columns :foo :bar :baz)
[:tablespace [:entity :quux]]]
:select [:*]
:from :cities
:where [:= :metroflag "y"]
:with-data false})
[(str "CREATE MATERIALIZED VIEW IF NOT EXISTS metro"
" (foo, bar, baz) TABLESPACE quux"
" AS SELECT * FROM cities WHERE metroflag = ? WITH NO DATA") "y"]))
(is (= (sql/format (-> (create-table :films)
(with-columns
[:id :int :unsigned :auto-increment]
[:name [:varchar 50] [:not nil]])))
["CREATE TABLE films (id INT UNSIGNED AUTO_INCREMENT, name VARCHAR(50) NOT NULL)"]))
(is (= (sql/format (-> (create-table :films :if-not-exists)
(with-columns
[:id :int :unsigned :auto-increment]
[:name [:varchar 50] [:not nil]])))
["CREATE TABLE IF NOT EXISTS films (id INT UNSIGNED AUTO_INCREMENT, name VARCHAR(50) NOT NULL)"]))
(is (= (sql/format (-> {:create-table :films
:with-columns
[[:id :int :unsigned :auto-increment]
[:name [:varchar 50] [:not nil]]]}))
["CREATE TABLE films (id INT UNSIGNED AUTO_INCREMENT, name VARCHAR(50) NOT NULL)"]))
(is (= (sql/format (-> {:create-table [:films :if-not-exists]
:with-columns
[[:id :int :unsigned :auto-increment]
[:name [:varchar 50] [:not nil]]]}))
["CREATE TABLE IF NOT EXISTS films (id INT UNSIGNED AUTO_INCREMENT, name VARCHAR(50) NOT NULL)"]))
(is (= (sql/format {:drop-table :foo})
["DROP TABLE foo"]))
(is (= (sql/format {:drop-table [:if-exists :foo]})
["DROP TABLE IF EXISTS foo"]))
(is (= (sql/format {:drop-view [:if-exists :foo]})
["DROP VIEW IF EXISTS foo"]))
(is (= (sql/format {:drop-materialized-view [:if-exists :foo]})
["DROP MATERIALIZED VIEW IF EXISTS foo"]))
(is (= (sql/format {:refresh-materialized-view [:concurrently :foo]
:with-data true})
["REFRESH MATERIALIZED VIEW CONCURRENTLY foo WITH DATA"]))
(is (= (sql/format '{drop-table (if-exists foo)})
["DROP TABLE IF EXISTS foo"]))
(is (= (sql/format {:drop-table [:foo :bar]})
["DROP TABLE foo, bar"]))
(is (= (sql/format {:drop-table [:if-exists :foo :bar]})
["DROP TABLE IF EXISTS foo, bar"]))
(is (= (sql/format {:drop-table [:if-exists :foo :bar [:cascade]]})
["DROP TABLE IF EXISTS foo, bar CASCADE"]))
(is (= (sql/format (drop-table :foo))
["DROP TABLE foo"]))
(is (= (sql/format (drop-table :if-exists :foo))
["DROP TABLE IF EXISTS foo"]))
(is (= (sql/format (-> (refresh-materialized-view :concurrently :foo)
(with-data true)))
["REFRESH MATERIALIZED VIEW CONCURRENTLY foo WITH DATA"]))
(is (= (sql/format (drop-table :foo :bar))
["DROP TABLE foo, bar"]))
(is (= (sql/format (drop-table :if-exists :foo :bar [:cascade]))
["DROP TABLE IF EXISTS foo, bar CASCADE"])))
babashka/babashka
(ns honey.sql.postgres-test
(:refer-clojure :exclude [update partition-by set])
(:require [clojure.test :refer [deftest is testing]]
;; pull in all the PostgreSQL helpers that the nilenso
;; library provided (as well as the regular HoneySQL ones):
[honey.sql.helpers :as sqlh :refer
[upsert on-conflict do-nothing on-constraint
returning do-update-set
;; not needed because do-update-set can do this directly
#_do-update-set!
alter-table rename-column drop-column
add-column partition-by
;; not needed because insert-into can do this directly
#_insert-into-as
create-table rename-table drop-table
window create-view over with-columns
create-extension drop-extension
select-distinct-on
;; already part of HoneySQL
insert-into values where select
from order-by update set]]
[honey.sql :as sql]))
(deftest create-table-test
;; the nilenso versions of these tests required sql/call for function-like syntax
(testing "create table with two columns"
(is (= ["CREATE TABLE cities (city VARCHAR(80) PRIMARY KEY, location POINT)"]
(-> (create-table :cities)
(with-columns [[:city [:varchar 80] [:primary-key]]
[:location :point]])
sql/format))))
(testing "create table with foreign key reference"
(is (= ["CREATE TABLE weather (city VARCHAR(80) REFERENCES CITIES(CITY), temp_lo INT, temp_hi INT, prcp REAL, date DATE)"]
(-> (create-table :weather)
(with-columns [[:city [:varchar :80] [:references :cities :city]]
[:temp_lo :int]
[:temp_hi :int]
[:prcp :real]
[:date :date]])
sql/format))))
(testing "creating table with table level constraint"
(is (= ["CREATE TABLE films (code CHAR(5), title VARCHAR(40), did INTEGER, date_prod DATE, kind VARCHAR(10), CONSTRAINT code_title PRIMARY KEY(CODE, TITLE))"]
(-> (create-table :films)
(with-columns [[:code [:char 5]]
[:title [:varchar 40]]
[:did :integer]
[:date_prod :date]
[:kind [:varchar 10]]
[[:constraint :code_title] [:primary-key :code :title]]])
sql/format))))
(testing "creating table with column level constraint"
(is (= ["CREATE TABLE films (code CHAR(5) CONSTRAINT FIRSTKEY PRIMARY KEY, title VARCHAR(40) NOT NULL, did INTEGER NOT NULL, date_prod DATE, kind VARCHAR(10))"]
(-> (create-table :films)
(with-columns [[:code [:char 5] [:constraint :firstkey] [:primary-key]]
[:title [:varchar 40] [:not nil]]
[:did :integer [:not nil]]
[:date_prod :date]
[:kind [:varchar 10]]])
sql/format))))
(testing "creating table with columns with default values"
(is (= ["CREATE TABLE distributors (did INTEGER PRIMARY KEY DEFAULT NEXTVAL('SERIAL'), name VARCHAR(40) NOT NULL)"]
(-> (create-table :distributors)
(with-columns [[:did :integer [:primary-key] [:default [:nextval "serial"]]]
[:name [:varchar 40] [:not nil]]])
sql/format))))
(testing "creating table with column checks"
(is (= ["CREATE TABLE products (product_no INTEGER, name TEXT, price NUMERIC CHECK(PRICE > 0), discounted_price NUMERIC, CHECK((discounted_price > 0) AND (price > discounted_price)))"]
(-> (create-table :products)
(with-columns [[:product_no :integer]
[:name :text]
[:price :numeric [:check [:> :price 0]]]
[:discounted_price :numeric]
[[:check [:and [:> :discounted_price 0] [:> :price :discounted_price]]]]])
sql/format)))))
seancorfield/honeysql
(ns honey.sql.postgres-test
(:refer-clojure :exclude [update partition-by set])
(:require [clojure.test :refer [deftest is testing]]
;; pull in all the PostgreSQL helpers that the nilenso
;; library provided (as well as the regular HoneySQL ones):
[honey.sql.helpers :as sqlh :refer
[upsert on-conflict do-nothing on-constraint
returning do-update-set
;; not needed because do-update-set can do this directly
#_do-update-set!
alter-table rename-column drop-column
add-column partition-by
;; not needed because insert-into can do this directly
#_insert-into-as
create-table rename-table drop-table
window create-view over with-columns
create-extension drop-extension
select-distinct-on
;; already part of HoneySQL
insert-into values where select
from order-by update set]]
[honey.sql :as sql]))
(deftest create-table-test
;; the nilenso versions of these tests required sql/call for function-like syntax
(testing "create table with two columns"
(is (= ["CREATE TABLE cities (city VARCHAR(80) PRIMARY KEY, location POINT)"]
(-> (create-table :cities)
(with-columns [[:city [:varchar 80] [:primary-key]]
[:location :point]])
sql/format))))
(testing "create table with foreign key reference"
(is (= ["CREATE TABLE weather (city VARCHAR(80) REFERENCES cities(city), temp_lo INT, temp_hi INT, prcp REAL, date DATE)"]
(-> (create-table :weather)
(with-columns [[:city [:varchar :80] [:references :cities :city]]
[:temp_lo :int]
[:temp_hi :int]
[:prcp :real]
[:date :date]])
sql/format))))
(testing "creating table with table level constraint"
(is (= ["CREATE TABLE films (code CHAR(5), title VARCHAR(40), did INTEGER, date_prod DATE, kind VARCHAR(10), CONSTRAINT code_title PRIMARY KEY(code, title))"]
(-> (create-table :films)
(with-columns [[:code [:char 5]]
[:title [:varchar 40]]
[:did :integer]
[:date_prod :date]
[:kind [:varchar 10]]
[[:constraint :code_title] [:primary-key :code :title]]])
sql/format))))
(testing "creating table with column level constraint"
(is (= ["CREATE TABLE films (code CHAR(5) CONSTRAINT firstkey PRIMARY KEY, title VARCHAR(40) NOT NULL, did INTEGER NOT NULL, date_prod DATE, kind VARCHAR(10))"]
(-> (create-table :films)
(with-columns [[:code [:char 5] [:constraint :firstkey] [:primary-key]]
[:title [:varchar 40] [:not nil]]
[:did :integer [:not nil]]
[:date_prod :date]
[:kind [:varchar 10]]])
sql/format))))
(testing "creating table with columns with default values"
(is (= ["CREATE TABLE distributors (did INTEGER PRIMARY KEY DEFAULT NEXTVAL('serial'), name VARCHAR(40) NOT NULL)"]
(-> (create-table :distributors)
(with-columns [[:did :integer [:primary-key] [:default [:nextval "serial"]]]
[:name [:varchar 40] [:not nil]]])
sql/format))))
(testing "creating table with column checks"
(is (= ["CREATE TABLE products (product_no INTEGER, name TEXT, price NUMERIC CHECK(price > 0), discounted_price NUMERIC, CHECK((discounted_price > 0) AND (price > discounted_price)))"]
(-> (create-table :products)
(with-columns [[:product_no :integer]
[:name :text]
[:price :numeric [:check [:> :price 0]]]
[:discounted_price :numeric]
[[:check [:and [:> :discounted_price 0] [:> :price :discounted_price]]]]])
sql/format)))))
(deftest references-issue-386
(is (= ["CREATE TABLE IF NOT EXISTS user (id VARCHAR(255) NOT NULL PRIMARY KEY, company_id INT NOT NULL, name VARCHAR(255) NOT NULL, password VARCHAR(255) NOT NULL, created_time DATETIME DEFAULT CURRENT_TIMESTAMP, updated_time DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, FOREIGN KEY(company_id) REFERENCES company(id))"]
(-> {:create-table [:user :if-not-exists]
:with-columns
[[:id [:varchar 255] [:not nil] [:primary-key]]
[:company-id :int [:not nil]]
[:name [:varchar 255] [:not nil]]
[:password [:varchar 255] [:not nil]]
[:created-time :datetime [:default :CURRENT_TIMESTAMP]]
[:updated-time :datetime [:default :CURRENT_TIMESTAMP]
:on :update :CURRENT_TIMESTAMP]
[[:foreign-key :company-id] [:references :company :id]]]}
(sql/format)))))
(deftest create-table-issue-437
(is (= ["CREATE TABLE bar (did UUID DEFAULT GEN_RANDOM_UUID(), foo_id VARCHAR NOT NULL, PRIMARY KEY(did, foo_id), FOREIGN KEY(foo_id) REFERENCES foo(id) ON DELETE CASCADE)"]
(-> (create-table :bar)
(with-columns
[[:did :uuid [:default [:gen_random_uuid]]]
[:foo-id :varchar [:not nil]]
[[:primary-key :did :foo-id]]
[[:foreign-key :foo-id]
[:references :foo :id]
:on-delete :cascade]])
(sql/format)))))
(deftest issue-453-constraint
(testing "standalone constraint"
(is (= ["CREATE TABLE bar (a INTEGER, b INTEGER, CONSTRAINT foo_natural_key UNIQUE (a, b))"]
(-> {:create-table [:bar]
:with-columns
[[:a :integer]
[:b :integer]
[[:constraint :foo_natural_key] :unique [:composite :a :b]]]}
(sql/format)))))
(testing "inline constraint"
(is (= ["CREATE TABLE foo (a INTEGER CONSTRAINT a_pos CHECK(a > 0), b INTEGER, CONSTRAINT a_bigger CHECK(b < a))"]
(-> '{create-table foo
with-columns
((a integer (constraint a_pos) (check (> a 0)))
(b integer)
((constraint a_bigger) (check (< b a))))}
(sql/format))))))
lambdaisland/plenish
(ns repl-sessions.jdbc-poke
(:require [next.jdbc :as jdbc]
[next.jdbc.result-set :as rs]
[honey.sql :as honey]
[honey.sql.helpers :as hh]))
(jdbc/execute!
ds
(honey/format
(-> (hh/create-table "foo" :if-not-exists)
(hh/with-columns [[:db__id :bigint [:primary-key]]]))))