diff --git a/builder/builder.go b/builder/builder.go
index 29157104ed152f4b0f5a841789ed17eb7659543d..cb9ed69aa8a640465a2ba948e8930352888d58b5 100644
--- a/builder/builder.go
+++ b/builder/builder.go
@@ -8,6 +8,7 @@ import (
 	"github.com/jmoiron/sqlx/reflectx"
 	"reflect"
 	"regexp"
+	"sort"
 	"strconv"
 	"strings"
 	"upper.io/db"
@@ -19,6 +20,24 @@ type SelectMode uint8
 
 var mapper = reflectx.NewMapper("db")
 
+type fieldValue struct {
+	fields []string
+	values []interface{}
+}
+
+func (fv *fieldValue) Len() int {
+	return len(fv.fields)
+}
+
+func (fv *fieldValue) Swap(i, j int) {
+	fv.fields[i], fv.fields[j] = fv.fields[j], fv.fields[i]
+	fv.values[i], fv.values[j] = fv.values[j], fv.values[i]
+}
+
+func (fv *fieldValue) Less(i, j int) bool {
+	return fv.fields[i] < fv.fields[j]
+}
+
 var (
 	reInvisibleChars       = regexp.MustCompile(`[\s\r\n\t]+`)
 	reColumnCompareExclude = regexp.MustCompile(`[^a-zA-Z0-9]`)
@@ -548,10 +567,10 @@ func (s *stringer) compileAndReplacePlaceholders(stmt *sqlgen.Statement) (query
 	return query
 }
 
-func NewBuilder(sess sqlDatabase, t *sqlutil.TemplateWithUtils) *Builder {
+func NewBuilder(sess sqlDatabase, t *sqlgen.Template) *Builder {
 	return &Builder{
 		sess: sess,
-		t:    t,
+		t:    sqlutil.NewTemplateWithUtils(t),
 	}
 }
 
@@ -613,8 +632,7 @@ func (iter *iterator) Close() (err error) {
 }
 
 func Map(item interface{}) ([]string, []interface{}, error) {
-	fields := []string{}
-	values := []interface{}{}
+	var fv fieldValue
 
 	itemV := reflect.ValueOf(item)
 	itemT := itemV.Type()
@@ -633,8 +651,8 @@ func Map(item interface{}) ([]string, []interface{}, error) {
 		fieldMap := mapper.TypeMap(itemT).Names
 		nfields := len(fieldMap)
 
-		values = make([]interface{}, 0, nfields)
-		fields = make([]string, 0, nfields)
+		fv.values = make([]interface{}, 0, nfields)
+		fv.fields = make([]string, 0, nfields)
 
 		for _, fi := range fieldMap {
 			// log.Println("=>", fi.Name, fi.Options)
@@ -661,47 +679,38 @@ func Map(item interface{}) ([]string, []interface{}, error) {
 				}
 			}
 
-			// TODO: columnLike stuff...?
-
-			fields = append(fields, fi.Name)
+			fv.fields = append(fv.fields, fi.Name)
 			v, err := marshal(value)
 			if err != nil {
 				return nil, nil, err
 			}
-			values = append(values, v)
+			fv.values = append(fv.values, v)
 		}
 
 	case reflect.Map:
 		nfields := itemV.Len()
-		values = make([]interface{}, nfields)
-		fields = make([]string, nfields)
+		fv.values = make([]interface{}, nfields)
+		fv.fields = make([]string, nfields)
 		mkeys := itemV.MapKeys()
 
 		for i, keyV := range mkeys {
 			valv := itemV.MapIndex(keyV)
-			fields[i] = fmt.Sprintf("%v", keyV.Interface())
+			fv.fields[i] = fmt.Sprintf("%v", keyV.Interface())
 
 			v, err := marshal(valv.Interface())
 			if err != nil {
 				return nil, nil, err
 			}
 
-			values[i] = v
+			fv.values[i] = v
 		}
 	default:
 		return nil, nil, db.ErrExpectingMapOrStruct
 	}
 
-	return fields, values, nil
-}
+	sort.Sort(&fv)
 
-func columnLike(columns []string, s string) string {
-	for _, name := range columns {
-		if normalizeColumn(s) == normalizeColumn(name) {
-			return name
-		}
-	}
-	return s
+	return fv.fields, fv.values, nil
 }
 
 func marshal(v interface{}) (interface{}, error) {
@@ -713,8 +722,3 @@ func marshal(v interface{}) (interface{}, error) {
 	}
 	return v, nil
 }
-
-// normalizeColumn prepares a column for comparison against another column.
-func normalizeColumn(s string) string {
-	return strings.ToLower(reColumnCompareExclude.ReplaceAllString(s, ""))
-}
diff --git a/builder/builder_test.go b/builder/builder_test.go
new file mode 100644
index 0000000000000000000000000000000000000000..99f43870f006827edb0bc693b03c1efc4de3e980
--- /dev/null
+++ b/builder/builder_test.go
@@ -0,0 +1,221 @@
+package builder
+
+import (
+	"github.com/stretchr/testify/assert"
+	"testing"
+	"upper.io/db"
+	"upper.io/db/util/sqlutil"
+)
+
+func TestSelect(t *testing.T) {
+
+	b := &Builder{t: sqlutil.NewTemplateWithUtils(&testTemplate)}
+	assert := assert.New(t)
+
+	assert.Equal(
+		`SELECT * FROM "artist"`,
+		b.SelectAllFrom("artist").String(),
+	)
+
+	assert.Equal(
+		`SELECT * FROM "artist"`,
+		b.Select().From("artist").String(),
+	)
+
+	assert.Equal(
+		`SELECT * FROM "artist" LIMIT -1 OFFSET 5`,
+		b.Select().From("artist").Limit(-1).Offset(5).String(),
+	)
+
+	assert.Equal(
+		`SELECT "id" FROM "artist"`,
+		b.Select("id").From("artist").String(),
+	)
+
+	assert.Equal(
+		`SELECT "id", "name" FROM "artist"`,
+		b.Select("id", "name").From("artist").String(),
+	)
+
+	assert.Equal(
+		`SELECT * FROM "artist" WHERE ("name" = $1)`,
+		b.SelectAllFrom("artist").Where("name", "Haruki").String(),
+	)
+
+	assert.Equal(
+		`SELECT * FROM "artist" WHERE (name LIKE $1)`,
+		b.SelectAllFrom("artist").Where("name LIKE ?", `%F%`).String(),
+	)
+
+	assert.Equal(
+		`SELECT "id" FROM "artist" WHERE (name LIKE $1 OR name LIKE $2)`,
+		b.Select("id").From("artist").Where(`name LIKE ? OR name LIKE ?`, `%Miya%`, `F%`).String(),
+	)
+
+	assert.Equal(
+		`SELECT * FROM "artist" WHERE ("id" > $1)`,
+		b.SelectAllFrom("artist").Where("id >", 2).String(),
+	)
+
+	assert.Equal(
+		`SELECT * FROM "artist" WHERE (id <= 2 AND name != $1)`,
+		b.SelectAllFrom("artist").Where("id <= 2 AND name != ?", "A").String(),
+	)
+
+	assert.Equal(
+		`SELECT * FROM "artist" WHERE ("id" IN ($1, $2, $3, $4))`,
+		b.SelectAllFrom("artist").Where("id IN", []int{1, 9, 8, 7}).String(),
+	)
+
+	assert.Equal(
+		`SELECT * FROM "artist" WHERE (name IS NOT NULL)`,
+		b.SelectAllFrom("artist").Where("name IS NOT NULL").String(),
+	)
+
+	assert.Equal(
+		`SELECT * FROM "artist" AS "a", "publication" AS "p" WHERE (p.author_id = a.id) LIMIT 1`,
+		b.Select().From("artist a", "publication as p").Where("p.author_id = a.id").Limit(1).String(),
+	)
+
+	assert.Equal(
+		`SELECT "id" FROM "artist" NATURAL JOIN "publication"`,
+		b.Select("id").From("artist").Join("publication").String(),
+	)
+
+	assert.Equal(
+		`SELECT * FROM "artist" AS "a" JOIN "publication" AS "p" ON (p.author_id = a.id) LIMIT 1`,
+		b.SelectAllFrom("artist a").Join("publication p").On("p.author_id = a.id").Limit(1).String(),
+	)
+
+	assert.Equal(
+		`SELECT * FROM "artist" AS "a" JOIN "publication" AS "p" ON (p.author_id = a.id) WHERE ("a"."id" = $1) LIMIT 1`,
+		b.SelectAllFrom("artist a").Join("publication p").On("p.author_id = a.id").Where("a.id", 2).Limit(1).String(),
+	)
+
+	assert.Equal(
+		`SELECT * FROM "artist" JOIN "publication" AS "p" ON (p.author_id = a.id) WHERE (a.id = 2) LIMIT 1`,
+		b.SelectAllFrom("artist").Join("publication p").On("p.author_id = a.id").Where("a.id = 2").Limit(1).String(),
+	)
+
+	assert.Equal(
+		`SELECT * FROM "artist" AS "a" JOIN "publication" AS "p" ON (p.title LIKE $1 OR p.title LIKE $2) WHERE (a.id = $3) LIMIT 1`,
+		b.SelectAllFrom("artist a").Join("publication p").On("p.title LIKE ? OR p.title LIKE ?", "%Totoro%", "%Robot%").Where("a.id = ?", 2).Limit(1).String(),
+	)
+
+	assert.Equal(
+		`SELECT * FROM "artist" AS "a" LEFT JOIN "publication" AS "p1" ON (p1.id = a.id) RIGHT JOIN "publication" AS "p2" ON (p2.id = a.id)`,
+		b.SelectAllFrom("artist a").
+			LeftJoin("publication p1").On("p1.id = a.id").
+			RightJoin("publication p2").On("p2.id = a.id").
+			String(),
+	)
+
+	assert.Equal(
+		`SELECT * FROM "artist" CROSS JOIN "publication"`,
+		b.SelectAllFrom("artist").CrossJoin("publication").String(),
+	)
+
+	assert.Equal(
+		`SELECT * FROM "artist" JOIN "publication" USING ("id")`,
+		b.SelectAllFrom("artist").Join("publication").Using("id").String(),
+	)
+
+	assert.Equal(
+		`SELECT DATE()`,
+		b.Select(db.Raw{"DATE()"}).String(),
+	)
+}
+
+func TestInsert(t *testing.T) {
+	b := &Builder{t: sqlutil.NewTemplateWithUtils(&testTemplate)}
+	assert := assert.New(t)
+
+	assert.Equal(
+		`INSERT INTO "artist" VALUES ($1, $2), ($3, $4), ($5, $6)`,
+		b.InsertInto("artist").
+			Values(10, "Ryuichi Sakamoto").
+			Values(11, "Alondra de la Parra").
+			Values(12, "Haruki Murakami").
+			String(),
+	)
+
+	assert.Equal(
+		`INSERT INTO "artist" ("id", "name") VALUES ($1, $2)`,
+		b.InsertInto("artist").Values(map[string]string{"id": "12", "name": "Chavela Vargas"}).String(),
+	)
+
+	assert.Equal(
+		`INSERT INTO "artist" ("id", "name") VALUES ($1, $2)`,
+		b.InsertInto("artist").Values(map[string]interface{}{"name": "Chavela Vargas", "id": 12}).String(),
+	)
+
+	assert.Equal(
+		`INSERT INTO "artist" ("id", "name") VALUES ($1, $2)`,
+		b.InsertInto("artist").Values(struct {
+			ID   int    `db:"id"`
+			Name string `db:"name"`
+		}{12, "Chavela Vargas"}).String(),
+	)
+
+	assert.Equal(
+		`INSERT INTO "artist" ("name", "id") VALUES ($1, $2)`,
+		b.InsertInto("artist").Columns("name", "id").Values("Chavela Vargas", 12).String(),
+	)
+}
+
+func TestUpdate(t *testing.T) {
+	b := &Builder{t: sqlutil.NewTemplateWithUtils(&testTemplate)}
+	assert := assert.New(t)
+
+	assert.Equal(
+		`UPDATE "artist" SET "name" = $1`,
+		b.Update("artist").Set("name", "Artist").String(),
+	)
+
+	assert.Equal(
+		`UPDATE "artist" SET "name" = $1 WHERE ("id" < $2)`,
+		b.Update("artist").Set("name = ?", "Artist").Where("id <", 5).String(),
+	)
+
+	assert.Equal(
+		`UPDATE "artist" SET "name" = $1 WHERE ("id" < $2)`,
+		b.Update("artist").Set(map[string]string{"name": "Artist"}).Where(db.Cond{"id <": 5}).String(),
+	)
+
+	assert.Equal(
+		`UPDATE "artist" SET "name" = $1 WHERE ("id" < $2)`,
+		b.Update("artist").Set(struct {
+			Nombre string `db:"name"`
+		}{"Artist"}).Where(db.Cond{"id <": 5}).String(),
+	)
+
+	assert.Equal(
+		`UPDATE "artist" SET "name" = $1, "last_name" = $2 WHERE ("id" < $3)`,
+		b.Update("artist").Set(struct {
+			Nombre string `db:"name"`
+		}{"Artist"}).Set(map[string]string{"last_name": "Foo"}).Where(db.Cond{"id <": 5}).String(),
+	)
+
+	assert.Equal(
+		`UPDATE "artist" SET "name" = $1 || ' ' || $2 || id, "id" = id + $3 WHERE (id > $4)`,
+		b.Update("artist").Set(
+			"name = ? || ' ' || ? || id", "Artist", "#",
+			"id = id + ?", 10,
+		).Where("id > ?", 0).String(),
+	)
+}
+
+func TestDelete(t *testing.T) {
+	b := &Builder{t: sqlutil.NewTemplateWithUtils(&testTemplate)}
+	assert := assert.New(t)
+
+	assert.Equal(
+		`DELETE FROM "artist" WHERE (name = $1) LIMIT 1`,
+		b.DeleteFrom("artist").Where("name = ?", "Chavela Vargas").Limit(1).String(),
+	)
+
+	assert.Equal(
+		`DELETE FROM "artist" WHERE (id > 5)`,
+		b.DeleteFrom("artist").Where("id > 5").String(),
+	)
+}
diff --git a/builder/template_test.go b/builder/template_test.go
new file mode 100644
index 0000000000000000000000000000000000000000..47a6db0256749b26bd9503a0fc0b669077dfc2fd
--- /dev/null
+++ b/builder/template_test.go
@@ -0,0 +1,193 @@
+package builder
+
+import (
+	"upper.io/cache"
+	"upper.io/db/util/sqlgen"
+)
+
+const (
+	defaultColumnSeparator     = `.`
+	defaultIdentifierSeparator = `, `
+	defaultIdentifierQuote     = `"{{.Value}}"`
+	defaultValueSeparator      = `, `
+	defaultValueQuote          = `'{{.}}'`
+	defaultAndKeyword          = `AND`
+	defaultOrKeyword           = `OR`
+	defaultNotKeyword          = `NOT`
+	defaultDescKeyword         = `DESC`
+	defaultAscKeyword          = `ASC`
+	defaultDefaultOperator     = `=`
+	defaultAssignmentOperator  = `=`
+	defaultClauseGroup         = `({{.}})`
+	defaultClauseOperator      = ` {{.}} `
+	defaultColumnValue         = `{{.Column}} {{.Operator}} {{.Value}}`
+	defaultTableAliasLayout    = `{{.Name}}{{if .Alias}} AS {{.Alias}}{{end}}`
+	defaultColumnAliasLayout   = `{{.Name}}{{if .Alias}} AS {{.Alias}}{{end}}`
+	defaultSortByColumnLayout  = `{{.Column}} {{.Order}}`
+
+	defaultOrderByLayout = `
+		{{if .SortColumns}}
+			ORDER BY {{.SortColumns}}
+		{{end}}
+	`
+
+	defaultWhereLayout = `
+		{{if .Conds}}
+			WHERE {{.Conds}}
+		{{end}}
+	`
+
+	defaultUsingLayout = `
+		{{if .Columns}}
+			USING ({{.Columns}})
+		{{end}}
+	`
+
+	defaultJoinLayout = `
+		{{if .Table}}
+			{{ if .On }}
+				{{.Type}} JOIN {{.Table}}
+				{{.On}}
+			{{ else if .Using }}
+				{{.Type}} JOIN {{.Table}}
+				{{.Using}}
+			{{ else if .Type | eq "CROSS" }}
+				{{.Type}} JOIN {{.Table}}
+			{{else}}
+				NATURAL {{.Type}} JOIN {{.Table}}
+			{{end}}
+		{{end}}
+	`
+
+	defaultOnLayout = `
+		{{if .Conds}}
+			ON {{.Conds}}
+		{{end}}
+	`
+
+	defaultSelectLayout = `
+    SELECT
+
+      {{if .Columns}}
+        {{.Columns}}
+      {{else}}
+        *
+      {{end}}
+
+      {{if .Table}}
+        FROM {{.Table}}
+      {{end}}
+
+      {{.Joins}}
+
+      {{.Where}}
+
+      {{.GroupBy}}
+
+      {{.OrderBy}}
+
+      {{if .Limit}}
+        LIMIT {{.Limit}}
+      {{end}}
+
+      {{if .Offset}}
+        OFFSET {{.Offset}}
+      {{end}}
+	`
+	defaultDeleteLayout = `
+    DELETE
+      FROM {{.Table}}
+      {{.Where}}
+    {{if .Limit}}
+      LIMIT {{.Limit}}
+    {{end}}
+    {{if .Offset}}
+      OFFSET {{.Offset}}
+    {{end}}
+	`
+	defaultUpdateLayout = `
+		UPDATE
+			{{.Table}}
+		SET {{.ColumnValues}}
+			{{ .Where }}
+	`
+
+	defaultCountLayout = `
+		SELECT
+			COUNT(1) AS _t
+		FROM {{.Table}}
+			{{.Where}}
+
+			{{if .Limit}}
+				LIMIT {{.Limit}}
+			{{end}}
+
+			{{if .Offset}}
+				OFFSET {{.Offset}}
+			{{end}}
+	`
+
+	defaultInsertLayout = `
+    INSERT INTO {{.Table}}
+      {{if .Columns }}({{.Columns}}){{end}}
+    VALUES
+      {{.Values}}
+    {{.Extra}}
+	`
+
+	defaultTruncateLayout = `
+		TRUNCATE TABLE {{.Table}}
+	`
+
+	defaultDropDatabaseLayout = `
+		DROP DATABASE {{.Database}}
+	`
+
+	defaultDropTableLayout = `
+		DROP TABLE {{.Table}}
+	`
+
+	defaultGroupByColumnLayout = `{{.Column}}`
+
+	defaultGroupByLayout = `
+		{{if .GroupColumns}}
+			GROUP BY {{.GroupColumns}}
+		{{end}}
+	`
+)
+
+var testTemplate = sqlgen.Template{
+	ColumnSeparator:     defaultColumnSeparator,
+	IdentifierSeparator: defaultIdentifierSeparator,
+	IdentifierQuote:     defaultIdentifierQuote,
+	ValueSeparator:      defaultValueSeparator,
+	ValueQuote:          defaultValueQuote,
+	AndKeyword:          defaultAndKeyword,
+	OrKeyword:           defaultOrKeyword,
+	NotKeyword:          defaultNotKeyword,
+	DescKeyword:         defaultDescKeyword,
+	AscKeyword:          defaultAscKeyword,
+	DefaultOperator:     defaultDefaultOperator,
+	AssignmentOperator:  defaultAssignmentOperator,
+	ClauseGroup:         defaultClauseGroup,
+	ClauseOperator:      defaultClauseOperator,
+	ColumnValue:         defaultColumnValue,
+	TableAliasLayout:    defaultTableAliasLayout,
+	ColumnAliasLayout:   defaultColumnAliasLayout,
+	SortByColumnLayout:  defaultSortByColumnLayout,
+	WhereLayout:         defaultWhereLayout,
+	OnLayout:            defaultOnLayout,
+	UsingLayout:         defaultUsingLayout,
+	JoinLayout:          defaultJoinLayout,
+	OrderByLayout:       defaultOrderByLayout,
+	InsertLayout:        defaultInsertLayout,
+	SelectLayout:        defaultSelectLayout,
+	UpdateLayout:        defaultUpdateLayout,
+	DeleteLayout:        defaultDeleteLayout,
+	TruncateLayout:      defaultTruncateLayout,
+	DropDatabaseLayout:  defaultDropDatabaseLayout,
+	DropTableLayout:     defaultDropTableLayout,
+	CountLayout:         defaultCountLayout,
+	GroupByLayout:       defaultGroupByLayout,
+	Cache:               cache.NewCache(),
+}