Skip to content

Commit

Permalink
Add pg_json_ops extension for calling JSON functions and operators in…
Browse files Browse the repository at this point in the history
… PostgreSQL 9.3+
  • Loading branch information
jeremyevans committed Jun 18, 2013
1 parent 7f9e7f8 commit 69c7bf9
Show file tree
Hide file tree
Showing 9 changed files with 453 additions and 8 deletions.
2 changes: 2 additions & 0 deletions CHANGELOG
@@ -1,5 +1,7 @@
=== HEAD

* Add pg_json_ops extension for calling JSON functions and operators in PostgreSQL 9.3+ (jeremyevans)

* Handle non-JSON plain strings, integers, and floats in PostgreSQL JSON columns in pg_json extension (jeremyevans)

* Dataset#from now accepts virtual row blocks (jeremyevans)
Expand Down
2 changes: 1 addition & 1 deletion lib/sequel/extensions/pg_json.rb
Expand Up @@ -201,7 +201,7 @@ def pg_json(v)
when Hash
Postgres::JSONHash.new(v)
else
raise Error, "Sequel.pg_json requires a hash or array argument"
Sequel.pg_json_op(v)
end
end
end
Expand Down
266 changes: 266 additions & 0 deletions lib/sequel/extensions/pg_json_ops.rb
@@ -0,0 +1,266 @@
# The pg_json_ops extension adds support to Sequel's DSL to make
# it easier to call PostgreSQL JSON functions and operators (added
# first in PostgreSQL 9.3).
#
# To load the extension:
#
# Sequel.extension :pg_json_ops
#
# The most common usage is passing an expression to Sequel.pg_json_op:
#
# j = Sequel.pg_json_op(:json_column)
#
# If you have also loaded the pg_json extension, you can use
# Sequel.pg_json as well:
#
# j = Sequel.pg_json(:json_column)
#
# Also, on most Sequel expression objects, you can call the pg_json
# method:
#
# j = Sequel.expr(:json_column).pg_json
#
# If you have loaded the {core_extensions extension}[link:files/doc/core_extensions_rdoc.html]),
# or you have loaded the {core_refinements extension}[link:files/doc/core_refinements_rdoc.html])
# and have activated refinements for the file, you can also use Symbol#pg_json:
#
# j = :json_column.pg_json
#
# This creates a Sequel::Postgres::JSONOp object that can be used
# for easier querying:
#
# j[1] # (json_column -> 1)
# j[%w'a b'] # (json_column #> ARRAY['a','b'])
# j.get_text(1) # (json_column ->> 1)
# j.get_text(%w'a b') # (json_column #>> ARRAY['a','b'])
# j.extract('a', 'b') # json_extract_path(json_column, 'a', 'b')
# j.extract_text('a', 'b') # json_extract_path_text(json_column, 'a', 'b')
#
# j.array_length # json_array_length(json_column)
# j.array_elements # json_array_elements(json_column)
# j.each # json_each(json_column)
# j.each_text # json_each_text(json_column)
# j.keys # json_object_keys(json_column)
#
# j.populate(:a) # json_populate_record(:a, json_column)
# j.populate_set(:a) # json_populate_recordset(:a, json_column)
#
# If you are also using the pg_json extension, you should load it before
# loading this extension. Doing so will allow you to use JSONHash#op and
# JSONArray#op to get a JSONOp, allowing you to perform json operations
# on json literals.
module Sequel
module Postgres
# The JSONOp class is a simple container for a single object that
# defines methods that yield Sequel expression objects representing
# PostgreSQL json operators and functions.
#
# In the method documentation examples, assume that:
#
# json_op = Sequel.pg_json(:json)
class JSONOp < Sequel::SQL::Wrapper
GET = ["(".freeze, " -> ".freeze, ")".freeze].freeze
GET_TEXT = ["(".freeze, " ->> ".freeze, ")".freeze].freeze
GET_PATH = ["(".freeze, " #> ".freeze, ")".freeze].freeze
GET_PATH_TEXT = ["(".freeze, " #>> ".freeze, ")".freeze].freeze

# Get JSON array element or object field as json. If an array is given,
# gets the object at the specified path.
#
# json_op[1] # (json -> 1)
# json_op['a'] # (json -> 'a')
# json_op[%w'a b'] # (json #> ARRAY['a', 'b'])
def [](key)
if is_array?(key)
json_op(GET_PATH, wrap_array(key))
else
json_op(GET, key)
end
end
alias get []

# Returns a set of json values for the elements in the json array.
#
# json_op.array_elements # json_oarray_elements(json)
def array_elements
function(:json_array_elements)
end

# Get the length of the outermost json array.
#
# json_op.array_length # json_array_length(json)
def array_length
Sequel::SQL::NumericExpression.new(:NOOP, function(:json_array_length))
end

# Returns a set of key and value pairs, where the keys
# are text and the values are JSON.
#
# json_op.each # json_each(json)
def each
function(:json_each)
end

# Returns a set of key and value pairs, where the keys
# and values are both text.
#
# json_op.each_text # json_each_text(json)
def each_text
function(:json_each_text)
end

# Returns a json value for the object at the given path.
#
# json_op.extract('a') # json_extract_path(json, 'a')
# json_op.extract('a', 'b') # json_extract_path(json, 'a', 'b')
def extract(*a)
JSONOp.new(function(:json_extract_path, *a))
end

# Returns a text value for the object at the given path.
#
# json_op.extract_text('a') # json_extract_path_text(json, 'a')
# json_op.extract_text('a', 'b') # json_extract_path_text(json, 'a', 'b')
def extract_text(*a)
Sequel::SQL::StringExpression.new(:NOOP, function(:json_extract_path_text, *a))
end

# Get JSON array element or object field as text. If an array is given,
# gets the object at the specified path.
#
# json_op.get_text(1) # (json ->> 1)
# json_op.get_text('a') # (json ->> 'a')
# json_op.get_text(%w'a b') # (json #>> ARRAY['a', 'b'])
def get_text(key)
if is_array?(key)
json_op(GET_PATH_TEXT, wrap_array(key))
else
json_op(GET_TEXT, key)
end
end

# Returns a set of keys AS text in the json object.
#
# json_op.keys # json_object_keys(json)
def keys
function(:json_object_keys)
end

# Return the receiver, since it is already a JSONOp.
def pg_json
self
end

# Expands the given argument using the columns in the json.
#
# json_op.populate(arg) # json_populate_record(arg, json)
def populate(arg)
SQL::Function.new(:json_populate_record, arg, self)
end

# Expands the given argument using the columns in the json.
#
# json_op.populate_set(arg) # json_populate_recordset(arg, json)
def populate_set(arg)
SQL::Function.new(:json_populate_recordset, arg, self)
end

private

# Return a placeholder literal with the given str and args, wrapped
# in an JSONOp, used by operators that return json.
def json_op(str, args)
JSONOp.new(Sequel::SQL::PlaceholderLiteralString.new(str, [self, args]))
end

# Return a function with the given name, and the receiver as the first
# argument, with any additional arguments given.
def function(name, *args)
SQL::Function.new(name, self, *args)
end

# Whether the given object represents an array in PostgreSQL.
def is_array?(a)
a.is_a?(Array) || (defined?(PGArray) && a.is_a?(PGArray)) || (defined?(ArrayOp) && a.is_a?(ArrayOp))
end

# Return a placeholder literal with the given str and args, wrapped
# in an SQL::StringExpression, used by operators that return text.
def text_op(str, args)
Sequel::SQL::StringExpression.new(:NOOP, Sequel::SQL::PlaceholderLiteralString.new(str, [self, args]))
end

# Automatically wrap argument in a PGArray if it is a plain Array.
# Requires that the pg_array extension has been loaded to work.
def wrap_array(arg)
if arg.instance_of?(Array) && Sequel.respond_to?(:pg_array)
Sequel.pg_array(arg)
else
arg
end
end
end

module JSONOpMethods
# Wrap the receiver in an JSONOp so you can easily use the PostgreSQL
# json functions and operators with it.
def pg_json
JSONOp.new(self)
end
end

if defined?(JSONArray)
class JSONArray
# Wrap the JSONHash instance in an JSONOp, allowing you to easily use
# the PostgreSQL json functions and operators with literal jsons.
def op
JSONOp.new(self)
end
end

class JSONHash
# Wrap the JSONHash instance in an JSONOp, allowing you to easily use
# the PostgreSQL json functions and operators with literal jsons.
def op
JSONOp.new(self)
end
end
end
end

module SQL::Builders
# Return the object wrapped in an Postgres::JSONOp.
def pg_json_op(v)
case v
when Postgres::JSONOp
v
else
Postgres::JSONOp.new(v)
end
end
end

class SQL::GenericExpression
include Sequel::Postgres::JSONOpMethods
end

class LiteralString
include Sequel::Postgres::JSONOpMethods
end
end

# :nocov:
if Sequel.core_extensions?
class Symbol
include Sequel::Postgres::JSONOpMethods
end
end

if defined?(Sequel::CoreRefinements)
module Sequel::CoreRefinements
refine Symbol do
include Sequel::Postgres::JSONOpMethods
end
end
end
# :nocov:
42 changes: 42 additions & 0 deletions spec/adapters/postgres_spec.rb
Expand Up @@ -2357,6 +2357,48 @@ def left_item_id
c.create(:h=>Sequel.pg_json(@h)).h.should == @h
c.create(:h=>Sequel.pg_json(@a)).h.should == @a
end

specify 'operations/functions with pg_json_ops' do
Sequel.extension :pg_json_ops
jo = Sequel.pg_json('a'=>1, 'b'=>{'c'=>2, 'd'=>{'e'=>3}}).op
ja = Sequel.pg_json([2, 3, %w'a b']).op

@db.get(jo['a']).should == 1
@db.get(jo['b']['c']).should == 2
@db.get(jo[%w'b c']).should == 2
@db.get(jo['b'].get_text(%w'd e')).should == "3"
@db.get(jo[%w'b d'].get_text('e')).should == "3"
@db.get(ja[1]).should == 3
@db.get(ja[%w'2 1']).should == 'b'

@db.get(jo.extract('a')).should == 1
@db.get(jo.extract('b').extract('c')).should == 2
@db.get(jo.extract('b', 'c')).should == 2
@db.get(jo.extract('b', 'd', 'e')).should == 3
@db.get(jo.extract_text('b', 'd')).should == '{"e":3}'
@db.get(jo.extract_text('b', 'd', 'e')).should == '3'

@db.get(ja.array_length).should == 3
@db.from(ja.array_elements.as(:v)).select_map(:v).should == [2, 3, %w'a b']

@db.from(jo.keys.as(:k)).select_order_map(:k).should == %w'a b'
@db.from(jo.each).select_order_map(:key).should == %w'a b'
@db.from(jo.each).order(:key).select_map(:value).should == [1, {'c'=>2, 'd'=>{'e'=>3}}]
@db.from(jo.each_text).select_order_map(:key).should == %w'a b'
@db.from(jo.each_text).order(:key).where(:key=>'b').get(:value).should =~ /\{"d":\{"e":3\},"c":2\}|\{"c":2,"d":\{"e":3\}\}/

Sequel.extension :pg_row_ops
@db.create_table!(:items) do
Integer :a
String :b
end
j = Sequel.pg_json('a'=>1, 'b'=>'c').op
@db.get(j.populate(Sequel.cast(nil, :items)).pg_row[:a]).should == 1
@db.get(j.populate(Sequel.cast(nil, :items)).pg_row[:b]).should == 'c'
j = Sequel.pg_json([{'a'=>1, 'b'=>'c'}, {'a'=>2, 'b'=>'d'}]).op
@db.from(j.populate_set(Sequel.cast(nil, :items))).select_order_map(:a).should == [1, 2]
@db.from(j.populate_set(Sequel.cast(nil, :items))).select_order_map(:b).should == %w'c d'
end if INTEGRATION_DB.server_version >= 90300 && INTEGRATION_DB.adapter_scheme == :postgres
end if INTEGRATION_DB.server_version >= 90200

describe 'PostgreSQL inet/cidr types' do
Expand Down
6 changes: 5 additions & 1 deletion spec/core_extensions_spec.rb
Expand Up @@ -628,7 +628,7 @@ def db.cast_type_literal(type)
describe "Postgres extensions integration" do
before do
@db = Sequel.mock
Sequel.extension(:pg_array, :pg_array_ops, :pg_hstore, :pg_hstore_ops, :pg_json, :pg_range, :pg_range_ops, :pg_row, :pg_row_ops)
Sequel.extension(:pg_array, :pg_array_ops, :pg_hstore, :pg_hstore_ops, :pg_json, :pg_json_ops, :pg_range, :pg_range_ops, :pg_row, :pg_row_ops)
end

it "Symbol#pg_array should return an ArrayOp" do
Expand All @@ -643,6 +643,10 @@ def db.cast_type_literal(type)
@db.literal(:a.hstore['a']).should == "(a -> 'a')"
end

it "Symbol#pg_json should return an JSONOp" do
@db.literal(:a.pg_json[%w'a b']).should == "(a #> ARRAY['a','b'])"
end

it "Symbol#pg_range should return a RangeOp" do
@db.literal(:a.pg_range.lower).should == "lower(a)"
end
Expand Down
7 changes: 5 additions & 2 deletions spec/extensions/core_refinements_spec.rb
@@ -1,7 +1,7 @@
require File.join(File.dirname(File.expand_path(__FILE__)), "spec_helper")

if RUBY_VERSION >= '2.0.0'
Sequel.extension :core_refinements, :pg_array, :pg_hstore, :pg_row, :pg_range, :pg_row_ops, :pg_range_ops, :pg_array_ops, :pg_hstore_ops
Sequel.extension :core_refinements, :pg_array, :pg_hstore, :pg_row, :pg_range, :pg_row_ops, :pg_range_ops, :pg_array_ops, :pg_hstore_ops, :pg_json, :pg_json_ops
using Sequel::CoreRefinements

describe "Core refinements" do
Expand Down Expand Up @@ -452,7 +452,6 @@ def db.cast_type_literal(type)
describe "Postgres extensions integration" do
before do
@db = Sequel.mock
Sequel.extension(:pg_array, :pg_array_ops, :pg_hstore, :pg_hstore_ops, :pg_json, :pg_range, :pg_range_ops, :pg_row, :pg_row_ops)
end

it "Symbol#pg_array should return an ArrayOp" do
Expand All @@ -467,6 +466,10 @@ def db.cast_type_literal(type)
@db.literal(:a.hstore['a']).should == "(a -> 'a')"
end

it "Symbol#pg_json should return an JSONOp" do
@db.literal(:a.pg_json[%w'a b']).should == "(a #> ARRAY['a','b'])"
end

it "Symbol#pg_range should return a RangeOp" do
@db.literal(:a.pg_range.lower).should == "lower(a)"
end
Expand Down

0 comments on commit 69c7bf9

Please sign in to comment.