From 76fdab038776edbedf1e6589dae0b123c4696be9 Mon Sep 17 00:00:00 2001
From: Carlos Silva <carlinhus.fsilva@gmail.com>
Date: Tue, 27 Dec 2022 07:00:17 -0300
Subject: [PATCH 1/3] First version of recursive CTE

---
 lib/torque/postgresql/auxiliary_statement.rb  |  53 ++++----
 .../auxiliary_statement/recursive.rb          | 115 ++++++++++++++++++
 .../auxiliary_statement/settings.rb           |  80 ++++++++----
 lib/torque/postgresql/base.rb                 |  12 +-
 lib/torque/postgresql/config.rb               |   4 +
 lib/torque/postgresql/inheritance.rb          |   4 +-
 lib/torque/postgresql/railtie.rb              |   6 +-
 .../relation/auxiliary_statement.rb           |  36 ++++--
 spec/models/category.rb                       |   2 +
 spec/schema.rb                                |   8 +-
 spec/tests/auxiliary_statement_spec.rb        |  89 +++++++++-----
 11 files changed, 318 insertions(+), 91 deletions(-)
 create mode 100644 lib/torque/postgresql/auxiliary_statement/recursive.rb
 create mode 100644 spec/models/category.rb

diff --git a/lib/torque/postgresql/auxiliary_statement.rb b/lib/torque/postgresql/auxiliary_statement.rb
index f590e10..286eef8 100644
--- a/lib/torque/postgresql/auxiliary_statement.rb
+++ b/lib/torque/postgresql/auxiliary_statement.rb
@@ -1,6 +1,7 @@
 # frozen_string_literal: true
 
 require_relative 'auxiliary_statement/settings'
+require_relative 'auxiliary_statement/recursive'
 
 module Torque
   module PostgreSQL
@@ -8,13 +9,16 @@ module Torque
       TABLE_COLUMN_AS_STRING = /\A(?:"?(\w+)"?\.)?"?(\w+)"?\z/.freeze
 
       class << self
-        attr_reader :config
+        attr_reader :config, :table_name
 
         # Find or create the class that will handle statement
         def lookup(name, base)
           const = name.to_s.camelize << '_' << self.name.demodulize
           return base.const_get(const, false) if base.const_defined?(const, false)
-          base.const_set(const, Class.new(AuxiliaryStatement))
+
+          base.const_set(const, Class.new(self)).tap do |klass|
+            klass.instance_variable_set(:@table_name, name.to_s)
+          end
         end
 
         # Create a new instance of an auxiliary statement
@@ -56,7 +60,7 @@ module Torque
         # A way to create auxiliary statements outside of models configurations,
         # being able to use on extensions
         def create(table_or_settings, &block)
-          klass = Class.new(AuxiliaryStatement)
+          klass = Class.new(self)
 
           if block_given?
             klass.instance_variable_set(:@table_name, table_or_settings)
@@ -89,7 +93,8 @@ module Torque
         def configure(base, instance)
           return @config unless @config.respond_to?(:call)
 
-          settings = Settings.new(base, instance)
+          recursive = self < AuxiliaryStatement::Recursive
+          settings = Settings.new(base, instance, recursive)
           settings.instance_exec(settings, &@config)
           settings
         end
@@ -98,17 +103,12 @@ module Torque
         def table
           @table ||= ::Arel::Table.new(table_name)
         end
-
-        # Get the name of the table of the configurated statement
-        def table_name
-          @table_name ||= self.name.demodulize.split('_').first.underscore
-        end
       end
 
       delegate :config, :table, :table_name, :relation, :configure, :relation_query?,
         to: :class
 
-      attr_reader :bound_attributes, :join_sources
+      attr_reader :bound_attributes, :join_sources, :settings
 
       # Start a new auxiliary statement giving extra options
       def initialize(*args)
@@ -129,6 +129,7 @@ module Torque
       def build(base)
         @bound_attributes.clear
         @join_sources.clear
+        @options = nil
 
         # Prepare all the data for the statement
         prepare(base)
@@ -141,9 +142,10 @@ module Torque
       end
 
       private
+
         # Setup the statement using the class configuration
         def prepare(base)
-          settings = configure(base, self)
+          @settings = configure(base, self)
           requires = Array.wrap(settings.requires).flatten.compact
           @dependencies = ensure_dependencies(requires, base).flatten.compact
 
@@ -151,7 +153,7 @@ module Torque
           @query = settings.query
 
           # Call a proc to get the real query
-          if @query.methods.include?(:call)
+          if @query.respond_to?(:call)
             call_args = @query.try(:arity) === 0 ? [] : [OpenStruct.new(@args)]
             @query = @query.call(*call_args)
             @args = []
@@ -168,7 +170,7 @@ module Torque
             @association = settings.through.to_s
           elsif relation_query?(@query)
             @association = base.reflections.find do |name, reflection|
-              break name if @query.klass.eql? reflection.klass
+              break name if @query.klass.eql?(reflection.klass)
             end
           end
         end
@@ -234,15 +236,6 @@ module Torque
             as a query object on #{self.class.name}.
           MSG
 
-          # Expose join columns
-          if relation_query?(@query)
-            query_table = @query.arel_table
-            conditions.children.each do |item|
-              @query.select_values += [query_table[item.left.name]] \
-                if item.left.relation.eql?(table)
-            end
-          end
-
           # Build the join based on the join type
           arel_join.new(table, table.create_on(conditions))
         end
@@ -263,10 +256,20 @@ module Torque
 
         # Mount the list of selected attributes
         def expose_columns(base, query_table = nil)
+          # Add the columns necessary for the join
+          list = @join_sources.each_with_object(@select) do |join, hash|
+            join.right.expr.children.each do |item|
+              hash[item.left.name] = nil if item.left.relation.eql?(table)
+            end
+          end
+
           # Add select columns to the query and get exposed columns
-          @select.map do |left, right|
-            base.select_extra_values += [table[right.to_s]]
-            project(left, query_table).as(right.to_s) if query_table
+          list.filter_map do |left, right|
+            base.select_extra_values += [table[right.to_s]] unless right.nil?
+            next unless query_table
+
+            col = project(left, query_table)
+            right.nil? ? col : col.as(right.to_s)
           end
         end
 
diff --git a/lib/torque/postgresql/auxiliary_statement/recursive.rb b/lib/torque/postgresql/auxiliary_statement/recursive.rb
new file mode 100644
index 0000000..0cdd287
--- /dev/null
+++ b/lib/torque/postgresql/auxiliary_statement/recursive.rb
@@ -0,0 +1,115 @@
+# frozen_string_literal: true
+
+module Torque
+  module PostgreSQL
+    class AuxiliaryStatement
+      class Recursive < AuxiliaryStatement
+
+        private
+
+          # Build the string or arel query
+          def build_query(base)
+            # Expose columns and get the list of the ones for select
+            columns = expose_columns(base, @query.try(:arel_table))
+            sub_columns = columns.dup
+            union_all = settings.all.present?
+
+            # Build any extra columns that are dynamic and from the recursion
+            extra_columns(base, columns, sub_columns)
+            type = union_all ? 'all' : ''
+
+            # Prepare the query depending on its type
+            if @query.is_a?(String)
+              args = @args.each_with_object({}) { |h, (k, v)| h[k] = base.connection.quote(v) }
+              ::Arel.sql("(#{@query} UNION #{type.upcase} #{@sub_query})" % args)
+            elsif relation_query?(@query)
+              @query = @query.where(@where) if @where.present?
+              @bound_attributes.concat(@query.send(:bound_attributes))
+              @bound_attributes.concat(@sub_query.send(:bound_attributes))
+
+              sub_query = @sub_query.select(*columns).arel
+              sub_query.from([@sub_query.arel_table, table])
+
+              @query.select(*columns).arel.union(type, sub_query)
+            else
+              raise ArgumentError, <<-MSG.squish
+                Only String and ActiveRecord::Base objects are accepted as query objects,
+                #{@query.class.name} given for #{self.class.name}.
+              MSG
+            end
+          end
+
+          # Setup the statement using the class configuration
+          def prepare(base)
+            super
+
+            prepare_sub_query(base)
+          end
+
+          # Make sure that both parts of the union are ready
+          def prepare_sub_query(base)
+            @sub_query = settings.sub_query
+
+            raise ArgumentError, <<-MSG.squish if @sub_query.nil? && @query.is_a?(String)
+              Unable to generate sub query from a string query. Please provide a `sub_query`
+              property on the "#{table_name}" settings.
+            MSG
+
+            if @sub_query.nil?
+              left, right = @connect = settings.connect.to_a.first.map(&:to_s)
+              @sub_query = @query.where(@query.arel_table[right].eq(table[left]))
+              @query = @query.where(right => nil) unless @query.where_values_hash.key?(right)
+            else
+              # Call a proc to get the real sub query
+              if @sub_query.respond_to?(:call)
+                call_args = @sub_query.try(:arity) === 0 ? [] : [OpenStruct.new(@args)]
+                @sub_query = @sub_query.call(*call_args)
+                @args = []
+              end
+
+              # Manually set the query table when it's not an relation query
+              @sub_query_table = settings.sub_query_table unless relation_query?(@sub_query)
+            end
+          end
+
+          # Add depth and path if they were defined in settings
+          def extra_columns(base, columns, sub_columns)
+            return if @query.is_a?(String) || @sub_query.is_a?(String)
+
+            # Add the connect attribute to the query
+            if defined?(@connect)
+              columns.unshift(@query.arel_table[@connect[0]])
+              sub_columns.unshift(@sub_query.arel_table[@connect[0]])
+            end
+
+            # Build a column to represent the depth of the recursion
+            if settings.depth?
+              col = table[settings.depth]
+              base.select_extra_values += [col]
+
+              columns << settings.sql('0').as(settings.depth)
+              sub_columns << (col + settings.sql('1')).as(settings.depth)
+            end
+
+            # Build a column to represent the path of the record access
+            if settings.path?
+              name, source = settings.path
+              source ||= @connect[0]
+
+              raise ArgumentError, <<-MSG.squish if source.nil?
+                Unable to generate path without providing a source or connect setting.
+              MSG
+
+              col = table[name]
+              base.select_extra_values += [col]
+              parts = [col, @sub_query.arel_table[source].cast(:varchar)]
+
+              columns << ::Arel.array([col]).cast(:varchar, true).as(name)
+              sub_columns << ::Arel.named_function(:array_append, parts)
+            end
+          end
+
+      end
+    end
+  end
+end
diff --git a/lib/torque/postgresql/auxiliary_statement/settings.rb b/lib/torque/postgresql/auxiliary_statement/settings.rb
index ed10cbb..f45b2df 100644
--- a/lib/torque/postgresql/auxiliary_statement/settings.rb
+++ b/lib/torque/postgresql/auxiliary_statement/settings.rb
@@ -4,7 +4,7 @@ module Torque
   module PostgreSQL
     class AuxiliaryStatement
       class Settings < Collector.new(:attributes, :join, :join_type, :query, :requires,
-          :polymorphic, :through)
+          :polymorphic, :through, :all, :connect)
 
         attr_reader :base, :source
         alias_method :select, :attributes
@@ -14,9 +14,10 @@ module Torque
         delegate :table, :table_name, to: :@source
         delegate :sql, to: ::Arel
 
-        def initialize(base, source)
+        def initialize(base, source, recursive = false)
           @base = base
           @source = source
+          @recursive = recursive
         end
 
         def base_name
@@ -27,6 +28,33 @@ module Torque
           @base.arel_table
         end
 
+        def recursive?
+          @recursive
+        end
+
+        def depth?
+          defined?(@with_depth)
+        end
+
+        def path?
+          defined?(@with_path)
+        end
+
+        # Add an attribute to the result showing the depth of each iteration
+        def with_depth(name = 'depth')
+          @with_depth = name if recursive?
+        end
+
+        # Add an attribute to the result showing the path of each record
+        def with_path(name = 'path', source = nil)
+          @with_path = [name, source] if recursive?
+        end
+
+        # Add both depth and path to the result
+        def with_depth_and_path
+          with_depth && with_path
+        end
+
         # Get the arel version of the table set on the query
         def query_table
           raise StandardError, 'The query is not defined yet' if query.nil?
@@ -41,35 +69,45 @@ module Torque
 
         alias column col
 
-        # There are two ways of setting the query:
+        # There are three ways of setting the query:
         # - A simple relation based on a Model
         # - A Arel-based select manager
         # - A string or a proc that requires the table name as first argument
         def query(value = nil, command = nil)
           return @query if value.nil?
-          return @query = value if relation_query?(value)
 
-          if value.is_a?(::Arel::SelectManager)
-            @query = value
-            @query_table = value.source.left.name
-            return
-          end
+          @query, @query_table = query_parts(value, command)
+        end
 
-          valid_type = command.respond_to?(:call) || command.is_a?(String)
+        # Same as query, but for the second part of the union for recursive cte
+        def sub_query(value = nil, command = nil)
+          return unless recursive?
+          return @sub_query if value.nil?
 
-          raise ArgumentError, <<-MSG.squish if command.nil?
-            To use proc or string as query, you need to provide the table name
-            as the first argument
-          MSG
+          @sub_query, @sub_query_table = query_parts(value, command)
+        end
 
-          raise ArgumentError, <<-MSG.squish unless valid_type
-            Only relation, string and proc are valid object types for query,
-            #{command.inspect} given.
-          MSG
+        private
 
-          @query = command
-          @query_table = ::Arel::Table.new(value)
-        end
+          # Get the query and table from the params
+          def query_parts(value, command = nil)
+            return [value] if relation_query?(value)
+            return [value, value.source.left.name] if value.is_a?(::Arel::SelectManager)
+
+            valid_type = command.respond_to?(:call) || command.is_a?(String)
+
+            raise ArgumentError, <<-MSG.squish if command.nil?
+              To use proc or string as query, you need to provide the table name
+              as the first argument
+            MSG
+
+            raise ArgumentError, <<-MSG.squish unless valid_type
+              Only relation, string and proc are valid object types for query,
+              #{command.inspect} given.
+            MSG
+
+            [command, ::Arel::Table.new(value)]
+          end
 
       end
     end
diff --git a/lib/torque/postgresql/base.rb b/lib/torque/postgresql/base.rb
index 8be5be4..51eb2e7 100644
--- a/lib/torque/postgresql/base.rb
+++ b/lib/torque/postgresql/base.rb
@@ -252,7 +252,7 @@ module Torque
           # attributes key:
           # Provides a map of attributes to be exposed to the main query.
           #
-          # For instace, if the statement query has an 'id' column that you
+          # For instance, if the statement query has an 'id' column that you
           # want it to be accessed on the main query as 'item_id',
           # you can use:
           #   attributes id: :item_id, 'MAX(id)' => :max_id,
@@ -293,6 +293,16 @@ module Torque
             klass.configurator(block)
           end
           alias cte auxiliary_statement
+
+          # Creates a new recursive auxiliary statement (CTE) under the base
+          # Very similar to the regular auxiliary statement, but with two-part
+          # query where one is executed first and the second recursively
+          def recursive_auxiliary_statement(table, &block)
+            klass = AuxiliaryStatement::Recursive.lookup(table, self)
+            auxiliary_statements_list[table.to_sym] = klass
+            klass.configurator(block)
+          end
+          alias recursive_cte recursive_auxiliary_statement
       end
     end
 
diff --git a/lib/torque/postgresql/config.rb b/lib/torque/postgresql/config.rb
index 142058a..471b756 100644
--- a/lib/torque/postgresql/config.rb
+++ b/lib/torque/postgresql/config.rb
@@ -63,6 +63,10 @@ module Torque
       # auxiliary statement in order to perform detached CTEs
       cte.exposed_class = 'TorqueCTE'
 
+      # Estipulate a class name (which may contain namespace) that expose the
+      # recursive auxiliary statement in order to perform detached CTEs
+      cte.exposed_recursive_class = 'TorqueRecursiveCTE'
+
     end
 
     # Configure ENUM features
diff --git a/lib/torque/postgresql/inheritance.rb b/lib/torque/postgresql/inheritance.rb
index 8c49296..fa6f262 100644
--- a/lib/torque/postgresql/inheritance.rb
+++ b/lib/torque/postgresql/inheritance.rb
@@ -55,7 +55,9 @@ module Torque
 
         # Check if the model's table depends on any inheritance
         def physically_inherited?
-          @physically_inherited ||= connection.schema_cache.dependencies(
+          return @physically_inherited if defined?(@physically_inherited)
+
+          @physically_inherited = connection.schema_cache.dependencies(
             defined?(@table_name) ? @table_name : decorated_table_name,
           ).present?
         rescue ActiveRecord::ConnectionNotEstablished
diff --git a/lib/torque/postgresql/railtie.rb b/lib/torque/postgresql/railtie.rb
index 91d19df..b5c2319 100644
--- a/lib/torque/postgresql/railtie.rb
+++ b/lib/torque/postgresql/railtie.rb
@@ -30,11 +30,15 @@ module Torque
           Torque::PostgreSQL::Attributes::Enum.lookup(name).sample
         end
 
-        # Define the exposed constant for auxiliary statements
+        # Define the exposed constant for both types of auxiliary statements
         if torque_config.auxiliary_statement.exposed_class.present?
           *ns, name = torque_config.auxiliary_statement.exposed_class.split('::')
           base = ns.present? ? Object.const_get(ns.join('::')) : Object
           base.const_set(name, Torque::PostgreSQL::AuxiliaryStatement)
+
+          *ns, name = torque_config.auxiliary_statement.exposed_recursive_class.split('::')
+          base = ns.present? ? Object.const_get(ns.join('::')) : Object
+          base.const_set(name, Torque::PostgreSQL::AuxiliaryStatement::Recursive)
         end
       end
     end
diff --git a/lib/torque/postgresql/relation/auxiliary_statement.rb b/lib/torque/postgresql/relation/auxiliary_statement.rb
index ea2f7ea..17caa5f 100644
--- a/lib/torque/postgresql/relation/auxiliary_statement.rb
+++ b/lib/torque/postgresql/relation/auxiliary_statement.rb
@@ -10,22 +10,14 @@ module Torque
         # :nodoc:
         def auxiliary_statements_values=(value); set_value(:auxiliary_statements, value); end
 
-        # Set use of an auxiliary statement already configurated on the model
+        # Set use of an auxiliary statement
         def with(*args)
           spawn.with!(*args)
         end
 
         # Like #with, but modifies relation in place.
         def with!(*args)
-          options = args.extract_options!
-          args.each do |table|
-            instance = table.is_a?(Class) && table < PostgreSQL::AuxiliaryStatement \
-              ? table.new(options) \
-              : PostgreSQL::AuxiliaryStatement.instantiate(table, self, options)
-
-            self.auxiliary_statements_values += [instance]
-          end
-
+          instantiate_auxiliary_statements(*args)
           self
         end
 
@@ -47,8 +39,24 @@ module Torque
           # Hook arel build to add the distinct on clause
           def build_arel(*)
             arel = super
+            type = auxiliary_statement_type
             subqueries = build_auxiliary_statements(arel)
-            subqueries.nil? ? arel : arel.with(subqueries)
+            subqueries.nil? ? arel : arel.with(*type, *subqueries)
+          end
+
+          # Instantiate one or more auxiliary statements for the given +klass+
+          def instantiate_auxiliary_statements(*args)
+            options = args.extract_options!
+            klass = PostgreSQL::AuxiliaryStatement
+            klass = klass::Recursive if options.delete(:recursive).present?
+
+            self.auxiliary_statements_values += args.map do |table|
+              if table.is_a?(Class) && table < klass
+                table.new(options)
+              else
+                klass.instantiate(table, self, options)
+              end
+            end
           end
 
           # Build all necessary data for auxiliary statements
@@ -59,6 +67,12 @@ module Torque
             end
           end
 
+          # Return recursive if any auxiliary statement is recursive
+          def auxiliary_statement_type
+            klass = PostgreSQL::AuxiliaryStatement::Recursive
+            :recursive if auxiliary_statements_values.any?(klass)
+          end
+
           # Throw an error showing that an auxiliary statement of the given
           # table name isn't defined
           def auxiliary_statement_error(name)
diff --git a/spec/models/category.rb b/spec/models/category.rb
new file mode 100644
index 0000000..7405d61
--- /dev/null
+++ b/spec/models/category.rb
@@ -0,0 +1,2 @@
+class Category< ActiveRecord::Base
+end
diff --git a/spec/schema.rb b/spec/schema.rb
index 269e485..1e67981 100644
--- a/spec/schema.rb
+++ b/spec/schema.rb
@@ -10,7 +10,7 @@
 #
 # It's strongly recommended that you check this file into your version control system.
 
-version = 1
+version = 2
 
 return if ActiveRecord::Migrator.current_version == version
 ActiveRecord::Schema.define(version: version) do
@@ -69,6 +69,11 @@ ActiveRecord::Schema.define(version: version) do
     t.enum     "specialty", enum_type: :specialties
   end
 
+  create_table "categories", force: :cascade do |t|
+    t.integer  "parent_id"
+    t.string   "title"
+  end
+
   create_table "texts", force: :cascade do |t|
     t.integer  "user_id"
     t.string   "content"
@@ -86,6 +91,7 @@ ActiveRecord::Schema.define(version: version) do
   end
 
   create_table "courses", force: :cascade do |t|
+    t.integer  "category_id"
     t.string   "title",      null: false
     t.interval "duration"
     t.enum     "types", enum_type: :types, array: true
diff --git a/spec/tests/auxiliary_statement_spec.rb b/spec/tests/auxiliary_statement_spec.rb
index 674c87b..c6a2bc1 100644
--- a/spec/tests/auxiliary_statement_spec.rb
+++ b/spec/tests/auxiliary_statement_spec.rb
@@ -21,7 +21,7 @@ RSpec.describe 'AuxiliaryStatement' do
       end
 
       result = 'WITH "comments" AS'
-      result << ' (SELECT "comments"."user_id", "comments"."content" AS comment_content FROM "comments")'
+      result << ' (SELECT "comments"."content" AS comment_content, "comments"."user_id" FROM "comments")'
       result << ' SELECT "users".*, "comments"."comment_content" FROM "users"'
       result << ' INNER JOIN "comments" ON "comments"."user_id" = "users"."id"'
       expect(subject.with(:comments).arel.to_sql).to eql(result)
@@ -34,7 +34,7 @@ RSpec.describe 'AuxiliaryStatement' do
       end
 
       result = 'WITH "comments" AS (SELECT DISTINCT ON ( "comments"."user_id" )'
-      result << ' "comments"."user_id", "comments"."content" AS last_comment'
+      result << ' "comments"."content" AS last_comment, "comments"."user_id"'
       result << ' FROM "comments" ORDER BY "comments"."user_id" ASC,'
       result << ' "comments"."id" DESC) SELECT "users".*,'
       result << ' "comments"."last_comment" FROM "users" INNER JOIN "comments"'
@@ -49,7 +49,7 @@ RSpec.describe 'AuxiliaryStatement' do
       end
 
       result = 'WITH "comments" AS'
-      result << ' (SELECT "comments"."user_id", "comments"."content" AS comment_content, "comments"."slug" AS comment_slug FROM "comments")'
+      result << ' (SELECT "comments"."content" AS comment_content, "comments"."slug" AS comment_slug, "comments"."user_id" FROM "comments")'
       result << ' SELECT "users".*, "comments"."comment_content", "comments"."comment_slug" FROM "users"'
       result << ' INNER JOIN "comments" ON "comments"."user_id" = "users"."id"'
       expect(subject.with(:comments, select: {slug: :comment_slug}).arel.to_sql).to eql(result)
@@ -62,7 +62,7 @@ RSpec.describe 'AuxiliaryStatement' do
       end
 
       result = 'WITH "comments" AS'
-      result << ' (SELECT "comments"."user_id", "comments"."active", "comments"."content" AS comment_content FROM "comments")'
+      result << ' (SELECT "comments"."content" AS comment_content, "comments"."user_id", "comments"."active" FROM "comments")'
       result << ' SELECT "users".*, "comments"."comment_content" FROM "users"'
       result << ' INNER JOIN "comments" ON "comments"."user_id" = "users"."id" AND "comments"."active" = "users"."active"'
       expect(subject.with(:comments, join: {active: :active}).arel.to_sql).to eql(result)
@@ -75,7 +75,7 @@ RSpec.describe 'AuxiliaryStatement' do
       end
 
       result = 'WITH "comments" AS'
-      result << ' (SELECT "comments"."user_id", "comments"."content" AS comment_content'
+      result << ' (SELECT "comments"."content" AS comment_content, "comments"."user_id"'
       result << ' FROM "comments" WHERE "comments"."active" = $1)'
       result << ' SELECT "users".*, "comments"."comment_content" FROM "users"'
       result << ' INNER JOIN "comments" ON "comments"."user_id" = "users"."id"'
@@ -91,7 +91,7 @@ RSpec.describe 'AuxiliaryStatement' do
       query = subject.where(id: 2).with(:comments)
 
       result = 'WITH "comments" AS'
-      result << ' (SELECT "comments"."user_id", "comments"."content" AS comment_content FROM "comments"'
+      result << ' (SELECT "comments"."content" AS comment_content, "comments"."user_id" FROM "comments"'
       result << ' WHERE "comments"."id" = $1)'
       result << ' SELECT "users".*, "comments"."comment_content" FROM "users"'
       result << ' INNER JOIN "comments" ON "comments"."user_id" = "users"."id"'
@@ -108,7 +108,7 @@ RSpec.describe 'AuxiliaryStatement' do
       end
 
       result = 'WITH "comments" AS'
-      result << ' (SELECT "comments"."user_id", MAX(id) AS comment_id FROM "comments")'
+      result << ' (SELECT MAX(id) AS comment_id, "comments"."user_id" FROM "comments")'
       result << ' SELECT "users".*, "comments"."comment_id" FROM "users"'
       result << ' INNER JOIN "comments" ON "comments"."user_id" = "users"."id"'
       expect(subject.with(:comments).arel.to_sql).to eql(result)
@@ -121,7 +121,7 @@ RSpec.describe 'AuxiliaryStatement' do
       end
 
       result = 'WITH "comments" AS'
-      result << ' (SELECT "comments"."user_id", ROW_NUMBER() OVER (PARTITION BY ORDER BY "comments"."id") AS comment_id FROM "comments")'
+      result << ' (SELECT ROW_NUMBER() OVER (PARTITION BY ORDER BY "comments"."id") AS comment_id, "comments"."user_id" FROM "comments")'
       result << ' SELECT "users".*, "comments"."comment_id" FROM "users"'
       result << ' INNER JOIN "comments" ON "comments"."user_id" = "users"."id"'
       expect(subject.with(:comments).arel.to_sql).to eql(result)
@@ -134,7 +134,7 @@ RSpec.describe 'AuxiliaryStatement' do
       end
 
       result = 'WITH "comments" AS'
-      result << ' (SELECT "comments"."user_id", MIN("comments"."id") AS comment_id FROM "comments")'
+      result << ' (SELECT MIN("comments"."id") AS comment_id, "comments"."user_id" FROM "comments")'
       result << ' SELECT "users".*, "comments"."comment_id" FROM "users"'
       result << ' INNER JOIN "comments" ON "comments"."user_id" = "users"."id"'
       expect(subject.with(:comments).arel.to_sql).to eql(result)
@@ -147,8 +147,8 @@ RSpec.describe 'AuxiliaryStatement' do
         cte.join name: :id, 'a.col' => :col
       end
 
-      result = 'WITH "comments" AS (SELECT "comments"."id", "comments"."col",'
-      result << ' "comments"."content" AS comment_content FROM "comments") SELECT "users".*,'
+      result = 'WITH "comments" AS (SELECT "comments"."content" AS comment_content,'
+      result << ' "comments"."id", "comments"."col" FROM "comments") SELECT "users".*,'
       result << ' "comments"."comment_content" FROM "users" INNER JOIN "comments"'
       result << ' ON "comments"."id" = "users"."name" AND "comments"."col" = "a"."col"'
       expect(subject.with(:comments).arel.to_sql).to eql(result)
@@ -161,8 +161,8 @@ RSpec.describe 'AuxiliaryStatement' do
         cte.join_type :left
       end
 
-      result = 'WITH "comments" AS (SELECT "comments"."user_id",'
-      result << ' "comments"."content" AS comment_content FROM "comments") SELECT "users".*,'
+      result = 'WITH "comments" AS (SELECT "comments"."content" AS comment_content,'
+      result << ' "comments"."user_id" FROM "comments") SELECT "users".*,'
       result << ' "comments"."comment_content" FROM "users" LEFT OUTER JOIN "comments"'
       result << ' ON "comments"."user_id" = "users"."id"'
       expect(subject.with(:comments).arel.to_sql).to eql(result)
@@ -177,7 +177,7 @@ RSpec.describe 'AuxiliaryStatement' do
       end
 
       result = 'WITH "comments" AS'
-      result << ' (SELECT "comments"."a_user_id", "comments"."content" AS sample_content FROM "comments")'
+      result << ' (SELECT "comments"."content" AS sample_content, "comments"."a_user_id" FROM "comments")'
       result << ' SELECT "users".*, "comments"."sample_content" FROM "users"'
       result << ' INNER JOIN "comments" ON "comments"."a_user_id" = "users"."id"'
       expect(subject.with(:comments).arel.to_sql).to eql(result)
@@ -198,8 +198,8 @@ RSpec.describe 'AuxiliaryStatement' do
       query = subject.where(id: 3).with(:comments2)
 
       result = 'WITH '
-      result << '"comments1" AS (SELECT "comments"."user_id", "comments"."content" AS comment_content1 FROM "comments" WHERE "comments"."id" = $1), '
-      result << '"comments2" AS (SELECT "comments"."user_id", "comments"."content" AS comment_content2 FROM "comments" WHERE "comments"."id" = $2)'
+      result << '"comments1" AS (SELECT "comments"."content" AS comment_content1, "comments"."user_id" FROM "comments" WHERE "comments"."id" = $1), '
+      result << '"comments2" AS (SELECT "comments"."content" AS comment_content2, "comments"."user_id" FROM "comments" WHERE "comments"."id" = $2)'
       result << ' SELECT "users".*, "comments1"."comment_content1", "comments2"."comment_content2" FROM "users"'
       result << ' INNER JOIN "comments1" ON "comments1"."user_id" = "users"."id"'
       result << ' INNER JOIN "comments2" ON "comments2"."user_id" = "users"."id"'
@@ -225,8 +225,8 @@ RSpec.describe 'AuxiliaryStatement' do
 
       it 'can requires another statement as dependency' do
         result = 'WITH '
-        result << '"comments1" AS (SELECT "comments"."user_id", "comments"."content" AS comment_content1 FROM "comments"), '
-        result << '"comments2" AS (SELECT "comments"."user_id", "comments"."content" AS comment_content2 FROM "comments")'
+        result << '"comments1" AS (SELECT "comments"."content" AS comment_content1, "comments"."user_id" FROM "comments"), '
+        result << '"comments2" AS (SELECT "comments"."content" AS comment_content2, "comments"."user_id" FROM "comments")'
         result << ' SELECT "users".*, "comments1"."comment_content1", "comments2"."comment_content2" FROM "users"'
         result << ' INNER JOIN "comments1" ON "comments1"."user_id" = "users"."id"'
         result << ' INNER JOIN "comments2" ON "comments2"."user_id" = "users"."id"'
@@ -235,8 +235,8 @@ RSpec.describe 'AuxiliaryStatement' do
 
       it 'can uses already already set dependent' do
         result = 'WITH '
-        result << '"comments1" AS (SELECT "comments"."user_id", "comments"."content" AS comment_content1 FROM "comments"), '
-        result << '"comments2" AS (SELECT "comments"."user_id", "comments"."content" AS comment_content2 FROM "comments")'
+        result << '"comments1" AS (SELECT "comments"."content" AS comment_content1, "comments"."user_id" FROM "comments"), '
+        result << '"comments2" AS (SELECT "comments"."content" AS comment_content2, "comments"."user_id" FROM "comments")'
         result << ' SELECT "users".*, "comments1"."comment_content1", "comments2"."comment_content2" FROM "users"'
         result << ' INNER JOIN "comments1" ON "comments1"."user_id" = "users"."id"'
         result << ' INNER JOIN "comments2" ON "comments2"."user_id" = "users"."id"'
@@ -309,7 +309,7 @@ RSpec.describe 'AuxiliaryStatement' do
         end
 
         result = 'WITH "comments" AS'
-        result << ' (SELECT "comments"."user_id", "comments"."content" AS comment FROM "comments")'
+        result << ' (SELECT "comments"."content" AS comment, "comments"."user_id" FROM "comments")'
         result << ' SELECT "users".*, "comments"."comment" FROM "users"'
         result << ' INNER JOIN "comments" ON "comments"."user_id" = "users"."id"'
         expect(subject.with(:comments).arel.to_sql).to eql(result)
@@ -352,7 +352,7 @@ RSpec.describe 'AuxiliaryStatement' do
         query = subject.with(:comments, args: {id: 1})
 
         result = 'WITH "comments" AS'
-        result << ' (SELECT "comments"."user_id", "comments"."content" AS comment'
+        result << ' (SELECT "comments"."content" AS comment, "comments"."user_id"'
         result << ' FROM "comments" WHERE "comments"."id" = $1)'
         result << ' SELECT "users".*, "comments"."comment" FROM "users"'
         result << ' INNER JOIN "comments" ON "comments"."user_id" = "users"."id"'
@@ -403,7 +403,7 @@ RSpec.describe 'AuxiliaryStatement' do
         end
 
         result = 'WITH "authors" AS'
-        result << ' (SELECT "authors"."id", "authors"."name" AS author_name FROM "authors")'
+        result << ' (SELECT "authors"."name" AS author_name, "authors"."id" FROM "authors")'
         result << ' SELECT "activity_books".*, "authors"."author_name" FROM "activity_books"'
         result << ' INNER JOIN "authors" ON "authors"."id" = "activity_books"."author_id"'
         expect(subject.with(:authors).arel.to_sql).to eql(result)
@@ -423,7 +423,7 @@ RSpec.describe 'AuxiliaryStatement' do
         end
 
         result = 'WITH "authors" AS'
-        result << ' (SELECT "authors"."id", "authors"."type" AS author_type FROM "authors")'
+        result << ' (SELECT "authors"."type" AS author_type, "authors"."id" FROM "authors")'
         result << ' SELECT "activity_books".*, "authors"."author_type" FROM "activity_books"'
         result << ' INNER JOIN "authors" ON "authors"."id" = "activity_books"."author_id"'
         expect(subject.with(:authors).arel.to_sql).to eql(result)
@@ -434,6 +434,30 @@ RSpec.describe 'AuxiliaryStatement' do
       end
     end
 
+    context 'recursive' do
+      let(:klass) { Course }
+
+      it 'correctly build a recursive cte' do
+        klass.send(:recursive_auxiliary_statement, :all_categories) do |cte|
+          cte.query Category.all
+          cte.join id: :parent_id
+          cte.connect id: :parent_id
+        end
+
+        result = 'WITH RECURSIVE "all_categories" AS ('
+        result << ' SELECT "categories"."id", "categories"."parent_id"'
+        result << ' FROM "categories"'
+        result << ' WHERE "categories"."parent_id" IS NULL'
+        result << ' UNION'
+        result << ' SELECT "categories"."id", "categories"."parent_id"'
+        result << ' FROM "categories", "all_categories"'
+        result << ' WHERE "categories"."parent_id" = "all_categories"."id"'
+        result << ' ) SELECT "courses".* FROM "courses" INNER JOIN "all_categories"'
+        result << ' ON "all_categories"."parent_id" = "courses"."id"'
+        expect(subject.with(:all_categories).arel.to_sql).to eql(result)
+      end
+    end
+
     it 'works with count and does not add extra columns' do
       klass.send(:auxiliary_statement, :comments) do |cte|
         cte.query Comment.all
@@ -441,7 +465,7 @@ RSpec.describe 'AuxiliaryStatement' do
       end
 
       result = 'WITH "comments" AS'
-      result << ' (SELECT "comments"."user_id", "comments"."content" AS comment_content FROM "comments")'
+      result << ' (SELECT "comments"."content" AS comment_content, "comments"."user_id" FROM "comments")'
       result << ' SELECT COUNT(*) FROM "users"'
       result << ' INNER JOIN "comments" ON "comments"."user_id" = "users"."id"'
 
@@ -456,7 +480,7 @@ RSpec.describe 'AuxiliaryStatement' do
       end
 
       result = 'WITH "comments" AS'
-      result << ' (SELECT "comments"."user_id", "comments"."id" AS value FROM "comments")'
+      result << ' (SELECT "comments"."id" AS value, "comments"."user_id" FROM "comments")'
       result << ' SELECT SUM("comments"."value") FROM "users"'
       result << ' INNER JOIN "comments" ON "comments"."user_id" = "users"."id"'
 
@@ -495,7 +519,12 @@ RSpec.describe 'AuxiliaryStatement' do
       expect(subject.protected_methods).to include(:auxiliary_statement)
     end
 
-    it 'allows configurate new auxiliary statements' do
+    it 'has the recursive configuration' do
+      expect(subject.protected_methods).to include(:recursive_cte)
+      expect(subject.protected_methods).to include(:recursive_auxiliary_statement)
+    end
+
+    it 'allows configure new auxiliary statements' do
       subject.send(:auxiliary_statement, :cte1)
       expect(subject.auxiliary_statements_list).to include(:cte1)
       expect(subject.const_defined?('Cte1_AuxiliaryStatement')).to be_truthy
@@ -527,7 +556,7 @@ RSpec.describe 'AuxiliaryStatement' do
       query = subject.with(sample, select: {content: :comment_content}).arel.to_sql
 
       result = 'WITH "comment" AS'
-      result << ' (SELECT "comments"."user_id", "comments"."content" AS comment_content FROM "comments")'
+      result << ' (SELECT "comments"."content" AS comment_content, "comments"."user_id" FROM "comments")'
       result << ' SELECT "users".*, "comment"."comment_content" FROM "users"'
       result << ' INNER JOIN "comment" ON "comment"."user_id" = "users"."id"'
       expect(query).to eql(result)
@@ -538,7 +567,7 @@ RSpec.describe 'AuxiliaryStatement' do
       query = subject.with(sample).arel.to_sql
 
       result = 'WITH "comment" AS'
-      result << ' (SELECT "comments"."user_id", "comments"."content" AS comment_content FROM "comments")'
+      result << ' (SELECT "comments"."content" AS comment_content, "comments"."user_id" FROM "comments")'
       result << ' SELECT "users".*, "comment"."comment_content" FROM "users"'
       result << ' INNER JOIN "comment" ON "comment"."user_id" = "users"."id"'
       expect(query).to eql(result)
@@ -551,7 +580,7 @@ RSpec.describe 'AuxiliaryStatement' do
       end
 
       result = 'WITH "all_comments" AS'
-      result << ' (SELECT "comments"."user_id", "comments"."content" AS comment_content FROM "comments")'
+      result << ' (SELECT "comments"."content" AS comment_content, "comments"."user_id" FROM "comments")'
       result << ' SELECT "users".*, "all_comments"."comment_content" FROM "users"'
       result << ' INNER JOIN "all_comments" ON "all_comments"."user_id" = "users"."id"'
 
-- 
GitLab


From 6c18fd22e0d7e2758d8f213d6ecb4a523ad0e5c5 Mon Sep 17 00:00:00 2001
From: Carlos Silva <carlinhus.fsilva@gmail.com>
Date: Wed, 28 Dec 2022 08:00:49 -0300
Subject: [PATCH 2/3] Finish recursive auxiliary statement implementation

---
 lib/torque/postgresql/auxiliary_statement.rb  |   4 +-
 .../auxiliary_statement/recursive.rb          |  66 +++---
 .../auxiliary_statement/settings.rb           |  61 +++--
 spec/tests/auxiliary_statement_spec.rb        | 213 +++++++++++++++++-
 4 files changed, 284 insertions(+), 60 deletions(-)

diff --git a/lib/torque/postgresql/auxiliary_statement.rb b/lib/torque/postgresql/auxiliary_statement.rb
index 286eef8..747c7c3 100644
--- a/lib/torque/postgresql/auxiliary_statement.rb
+++ b/lib/torque/postgresql/auxiliary_statement.rb
@@ -156,11 +156,9 @@ module Torque
           if @query.respond_to?(:call)
             call_args = @query.try(:arity) === 0 ? [] : [OpenStruct.new(@args)]
             @query = @query.call(*call_args)
-            @args = []
           end
 
-          # Manually set the query table when it's not an relation query
-          @query_table = settings.query_table unless relation_query?(@query)
+          # Merge select attributes provided on the instance creation
           @select = settings.attributes.merge(@select) if settings.attributes.present?
 
           # Merge join settings
diff --git a/lib/torque/postgresql/auxiliary_statement/recursive.rb b/lib/torque/postgresql/auxiliary_statement/recursive.rb
index 0cdd287..7d35477 100644
--- a/lib/torque/postgresql/auxiliary_statement/recursive.rb
+++ b/lib/torque/postgresql/auxiliary_statement/recursive.rb
@@ -12,29 +12,28 @@ module Torque
             # Expose columns and get the list of the ones for select
             columns = expose_columns(base, @query.try(:arel_table))
             sub_columns = columns.dup
-            union_all = settings.all.present?
+            type = settings.union_all.present? ? 'all' : ''
 
             # Build any extra columns that are dynamic and from the recursion
             extra_columns(base, columns, sub_columns)
-            type = union_all ? 'all' : ''
 
             # Prepare the query depending on its type
-            if @query.is_a?(String)
+            if @query.is_a?(String) && @sub_query.is_a?(String)
               args = @args.each_with_object({}) { |h, (k, v)| h[k] = base.connection.quote(v) }
               ::Arel.sql("(#{@query} UNION #{type.upcase} #{@sub_query})" % args)
-            elsif relation_query?(@query)
+            elsif relation_query?(@query) && relation_query?(@sub_query)
               @query = @query.where(@where) if @where.present?
               @bound_attributes.concat(@query.send(:bound_attributes))
               @bound_attributes.concat(@sub_query.send(:bound_attributes))
 
-              sub_query = @sub_query.select(*columns).arel
+              sub_query = @sub_query.select(*sub_columns).arel
               sub_query.from([@sub_query.arel_table, table])
 
               @query.select(*columns).arel.union(type, sub_query)
             else
               raise ArgumentError, <<-MSG.squish
-                Only String and ActiveRecord::Base objects are accepted as query objects,
-                #{@query.class.name} given for #{self.class.name}.
+                Only String and ActiveRecord::Base objects are accepted as query and sub query
+                objects, #{@query.class.name} given for #{self.class.name}.
               MSG
             end
           end
@@ -56,19 +55,25 @@ module Torque
             MSG
 
             if @sub_query.nil?
+              raise ArgumentError, <<-MSG.squish if settings.connect.blank?
+                Unable to generate sub query without setting up a proper way to connect it
+                with the main query. Please provide a `connect` property on the "#{table_name}"
+                settings.
+              MSG
+
               left, right = @connect = settings.connect.to_a.first.map(&:to_s)
-              @sub_query = @query.where(@query.arel_table[right].eq(table[left]))
-              @query = @query.where(right => nil) unless @query.where_values_hash.key?(right)
-            else
-              # Call a proc to get the real sub query
-              if @sub_query.respond_to?(:call)
-                call_args = @sub_query.try(:arity) === 0 ? [] : [OpenStruct.new(@args)]
-                @sub_query = @sub_query.call(*call_args)
-                @args = []
-              end
+              condition = @query.arel_table[right].eq(table[left])
 
-              # Manually set the query table when it's not an relation query
-              @sub_query_table = settings.sub_query_table unless relation_query?(@sub_query)
+              if @query.where_values_hash.key?(right)
+                @sub_query = @query.unscope(where: right.to_sym).where(condition)
+              else
+                @sub_query = @query.where(condition)
+                @query = @query.where(right => nil)
+              end
+            elsif @sub_query.respond_to?(:call)
+              # Call a proc to get the real sub query
+              call_args = @sub_query.try(:arity) === 0 ? [] : [OpenStruct.new(@args)]
+              @sub_query = @sub_query.call(*call_args)
             end
           end
 
@@ -84,28 +89,25 @@ module Torque
 
             # Build a column to represent the depth of the recursion
             if settings.depth?
-              col = table[settings.depth]
-              base.select_extra_values += [col]
+              name, start, as = settings.depth
+              col = table[name]
+              base.select_extra_values += [col.as(as)] unless as.nil?
 
-              columns << settings.sql('0').as(settings.depth)
-              sub_columns << (col + settings.sql('1')).as(settings.depth)
+              columns << ::Arel.sql(start.to_s).as(name)
+              sub_columns << (col + ::Arel.sql('1')).as(name)
             end
 
             # Build a column to represent the path of the record access
             if settings.path?
-              name, source = settings.path
-              source ||= @connect[0]
-
-              raise ArgumentError, <<-MSG.squish if source.nil?
-                Unable to generate path without providing a source or connect setting.
-              MSG
+              name, source, as = settings.path
+              source = @query.arel_table[source || @connect[0]]
 
               col = table[name]
-              base.select_extra_values += [col]
-              parts = [col, @sub_query.arel_table[source].cast(:varchar)]
+              base.select_extra_values += [col.as(as)] unless as.nil?
+              parts = [col, source.cast(:varchar)]
 
-              columns << ::Arel.array([col]).cast(:varchar, true).as(name)
-              sub_columns << ::Arel.named_function(:array_append, parts)
+              columns << ::Arel.array([source]).cast(:varchar, true).as(name)
+              sub_columns << ::Arel::Nodes::NamedFunction.new('array_append', parts).as(name)
             end
           end
 
diff --git a/lib/torque/postgresql/auxiliary_statement/settings.rb b/lib/torque/postgresql/auxiliary_statement/settings.rb
index f45b2df..db11469 100644
--- a/lib/torque/postgresql/auxiliary_statement/settings.rb
+++ b/lib/torque/postgresql/auxiliary_statement/settings.rb
@@ -4,9 +4,9 @@ module Torque
   module PostgreSQL
     class AuxiliaryStatement
       class Settings < Collector.new(:attributes, :join, :join_type, :query, :requires,
-          :polymorphic, :through, :all, :connect)
+          :polymorphic, :through, :union_all, :connect)
 
-        attr_reader :base, :source
+        attr_reader :base, :source, :depth, :path
         alias_method :select, :attributes
         alias_method :cte, :source
 
@@ -18,6 +18,7 @@ module Torque
           @base = base
           @source = source
           @recursive = recursive
+          set_default_connect(base) if recursive?
         end
 
         def base_name
@@ -33,21 +34,26 @@ module Torque
         end
 
         def depth?
-          defined?(@with_depth)
+          defined?(@depth)
         end
 
         def path?
-          defined?(@with_path)
+          defined?(@path)
         end
 
         # Add an attribute to the result showing the depth of each iteration
-        def with_depth(name = 'depth')
-          @with_depth = name if recursive?
+        def with_depth(name = 'depth', start: 0, as: nil)
+          @depth = [name.to_s, start, as&.to_s] if recursive?
         end
 
         # Add an attribute to the result showing the path of each record
-        def with_path(name = 'path', source = nil)
-          @with_path = [name, source] if recursive?
+        def with_path(name = 'path', source: nil, as: nil)
+          @path = [name.to_s, source&.to_s, as&.to_s] if recursive?
+        end
+
+        # Set recursive operation to use union all
+        def union_all!
+          @union_all = true if recursive?
         end
 
         # Add both depth and path to the result
@@ -72,11 +78,11 @@ module Torque
         # There are three ways of setting the query:
         # - A simple relation based on a Model
         # - A Arel-based select manager
-        # - A string or a proc that requires the table name as first argument
+        # - A string or a proc
         def query(value = nil, command = nil)
           return @query if value.nil?
 
-          @query, @query_table = query_parts(value, command)
+          @query = sanitize_query(value, command)
         end
 
         # Same as query, but for the second part of the union for recursive cte
@@ -84,29 +90,44 @@ module Torque
           return unless recursive?
           return @sub_query if value.nil?
 
-          @sub_query, @sub_query_table = query_parts(value, command)
+          @sub_query = sanitize_query(value, command)
+        end
+
+        # Assume `parent_` as the other part if provided a Symbol or String
+        def connect(value = nil)
+          return @connect if value.nil?
+
+          value = { value.to_sym => :"parent_#{value}" } \
+            if value.is_a?(String) || value.is_a?(Symbol)
+
+          @connect = value
         end
 
+        alias connect= connect
+
         private
 
           # Get the query and table from the params
-          def query_parts(value, command = nil)
-            return [value] if relation_query?(value)
-            return [value, value.source.left.name] if value.is_a?(::Arel::SelectManager)
+          def sanitize_query(value, command = nil)
+            return value if relation_query?(value)
+            return value if value.is_a?(::Arel::SelectManager)
 
+            command = value if command.nil? # For compatibility purposes
             valid_type = command.respond_to?(:call) || command.is_a?(String)
 
-            raise ArgumentError, <<-MSG.squish if command.nil?
-              To use proc or string as query, you need to provide the table name
-              as the first argument
-            MSG
-
             raise ArgumentError, <<-MSG.squish unless valid_type
               Only relation, string and proc are valid object types for query,
               #{command.inspect} given.
             MSG
 
-            [command, ::Arel::Table.new(value)]
+            command
+          end
+
+          # When setting up a recursive cte, set connect as default
+          # id: :parent_id, based on primary key
+          def set_default_connect(base)
+            key = base.primary_key
+            self.connect = key unless key.nil?
           end
 
       end
diff --git a/spec/tests/auxiliary_statement_spec.rb b/spec/tests/auxiliary_statement_spec.rb
index c6a2bc1..fb4c029 100644
--- a/spec/tests/auxiliary_statement_spec.rb
+++ b/spec/tests/auxiliary_statement_spec.rb
@@ -289,14 +289,14 @@ RSpec.describe 'AuxiliaryStatement' do
         expect{ subject.with(:comments).arel.to_sql }.to raise_error(ArgumentError, /join columns/)
       end
 
-      it 'raises an error when not given the table name as first argument' do
+      it 'not raises an error when not given the table name as first argument' do
         klass.send(:auxiliary_statement, :comments) do |cte|
           cte.query 'SELECT * FROM comments'
           cte.attributes content: :comment
           cte.join id: :user_id
         end
 
-        expect{ subject.with(:comments).arel.to_sql }.to raise_error(ArgumentError, /table name/)
+        expect{ subject.with(:comments).arel.to_sql }.not_to raise_error
       end
     end
 
@@ -370,14 +370,14 @@ RSpec.describe 'AuxiliaryStatement' do
         expect{ subject.with(:comments).arel.to_sql }.to raise_error(ArgumentError, /join columns/)
       end
 
-      it 'raises an error when not given the table name as first argument' do
+      it 'not raises an error when not given the table name as first argument' do
         klass.send(:auxiliary_statement, :comments) do |cte|
           cte.query -> { Comment.all }
           cte.attributes content: :comment
           cte.join id: :user_id
         end
 
-        expect{ subject.with(:comments).arel.to_sql }.to raise_error(ArgumentError, /table name/)
+        expect{ subject.with(:comments).arel.to_sql }.not_to raise_error
       end
 
       it 'raises an error when the result of the proc is an invalid type' do
@@ -441,7 +441,6 @@ RSpec.describe 'AuxiliaryStatement' do
         klass.send(:recursive_auxiliary_statement, :all_categories) do |cte|
           cte.query Category.all
           cte.join id: :parent_id
-          cte.connect id: :parent_id
         end
 
         result = 'WITH RECURSIVE "all_categories" AS ('
@@ -456,6 +455,210 @@ RSpec.describe 'AuxiliaryStatement' do
         result << ' ON "all_categories"."parent_id" = "courses"."id"'
         expect(subject.with(:all_categories).arel.to_sql).to eql(result)
       end
+
+      it 'allows connect to be set to something different using a single value' do
+        klass.send(:recursive_auxiliary_statement, :all_categories) do |cte|
+          cte.query Category.all
+          cte.join id: :parent_id
+          cte.connect :name
+        end
+
+        result = 'WITH RECURSIVE "all_categories" AS ('
+        result << ' SELECT "categories"."name", "categories"."parent_id"'
+        result << ' FROM "categories"'
+        result << ' WHERE "categories"."parent_name" IS NULL'
+        result << ' UNION'
+        result << ' SELECT "categories"."name", "categories"."parent_id"'
+        result << ' FROM "categories", "all_categories"'
+        result << ' WHERE "categories"."parent_name" = "all_categories"."name"'
+        result << ' ) SELECT "courses".* FROM "courses" INNER JOIN "all_categories"'
+        result << ' ON "all_categories"."parent_id" = "courses"."id"'
+        expect(subject.with(:all_categories).arel.to_sql).to eql(result)
+      end
+
+      it 'allows a complete different set of connect' do
+        klass.send(:recursive_auxiliary_statement, :all_categories) do |cte|
+          cte.query Category.all
+          cte.join id: :parent_id
+          cte.connect left: :right
+        end
+
+        result = 'WITH RECURSIVE "all_categories" AS ('
+        result << ' SELECT "categories"."left", "categories"."parent_id"'
+        result << ' FROM "categories"'
+        result << ' WHERE "categories"."right" IS NULL'
+        result << ' UNION'
+        result << ' SELECT "categories"."left", "categories"."parent_id"'
+        result << ' FROM "categories", "all_categories"'
+        result << ' WHERE "categories"."right" = "all_categories"."left"'
+        result << ' ) SELECT "courses".* FROM "courses" INNER JOIN "all_categories"'
+        result << ' ON "all_categories"."parent_id" = "courses"."id"'
+        expect(subject.with(:all_categories).arel.to_sql).to eql(result)
+      end
+
+      it 'allows using an union all' do
+        klass.send(:recursive_auxiliary_statement, :all_categories) do |cte|
+          cte.query Category.all
+          cte.join id: :parent_id
+          cte.union_all!
+        end
+
+        result = 'WITH RECURSIVE "all_categories" AS ('
+        result << ' SELECT "categories"."id", "categories"."parent_id"'
+        result << ' FROM "categories"'
+        result << ' WHERE "categories"."parent_id" IS NULL'
+        result << ' UNION ALL'
+        result << ' SELECT "categories"."id", "categories"."parent_id"'
+        result << ' FROM "categories", "all_categories"'
+        result << ' WHERE "categories"."parent_id" = "all_categories"."id"'
+        result << ' ) SELECT "courses".* FROM "courses" INNER JOIN "all_categories"'
+        result << ' ON "all_categories"."parent_id" = "courses"."id"'
+        expect(subject.with(:all_categories).arel.to_sql).to eql(result)
+      end
+
+      it 'allows having a complete different initiator' do
+        klass.send(:recursive_auxiliary_statement, :all_categories) do |cte|
+          cte.query Category.where(parent_id: 5)
+          cte.join id: :parent_id
+        end
+
+        result = 'WITH RECURSIVE "all_categories" AS ('
+        result << ' SELECT "categories"."id", "categories"."parent_id"'
+        result << ' FROM "categories"'
+        result << ' WHERE "categories"."parent_id" = $1'
+        result << ' UNION'
+        result << ' SELECT "categories"."id", "categories"."parent_id"'
+        result << ' FROM "categories", "all_categories"'
+        result << ' WHERE "categories"."parent_id" = "all_categories"."id"'
+        result << ' ) SELECT "courses".* FROM "courses" INNER JOIN "all_categories"'
+        result << ' ON "all_categories"."parent_id" = "courses"."id"'
+        expect(subject.with(:all_categories).arel.to_sql).to eql(result)
+      end
+
+      it 'can process the depth of the query' do
+        klass.send(:recursive_auxiliary_statement, :all_categories) do |cte|
+          cte.query Category.all
+          cte.join id: :parent_id
+          cte.with_depth
+        end
+
+        result = 'WITH RECURSIVE "all_categories" AS ('
+        result << ' SELECT "categories"."id", "categories"."parent_id", 0 AS depth'
+        result << ' FROM "categories"'
+        result << ' WHERE "categories"."parent_id" IS NULL'
+        result << ' UNION'
+        result << ' SELECT "categories"."id", "categories"."parent_id", ("all_categories"."depth" + 1) AS depth'
+        result << ' FROM "categories", "all_categories"'
+        result << ' WHERE "categories"."parent_id" = "all_categories"."id"'
+        result << ' ) SELECT "courses".* FROM "courses" INNER JOIN "all_categories"'
+        result << ' ON "all_categories"."parent_id" = "courses"."id"'
+        expect(subject.with(:all_categories).arel.to_sql).to eql(result)
+      end
+
+      it 'can process and expose the depth of the query' do
+        klass.send(:recursive_auxiliary_statement, :all_categories) do |cte|
+          cte.query Category.all
+          cte.join id: :parent_id
+          cte.with_depth 'd', start: 10, as: :category_depth
+        end
+
+        result = 'WITH RECURSIVE "all_categories" AS ('
+        result << ' SELECT "categories"."id", "categories"."parent_id", 10 AS d'
+        result << ' FROM "categories"'
+        result << ' WHERE "categories"."parent_id" IS NULL'
+        result << ' UNION'
+        result << ' SELECT "categories"."id", "categories"."parent_id", ("all_categories"."d" + 1) AS d'
+        result << ' FROM "categories", "all_categories"'
+        result << ' WHERE "categories"."parent_id" = "all_categories"."id"'
+        result << ' ) SELECT "courses".*, "all_categories"."d" AS category_depth FROM "courses" INNER JOIN "all_categories"'
+        result << ' ON "all_categories"."parent_id" = "courses"."id"'
+        expect(subject.with(:all_categories).arel.to_sql).to eql(result)
+      end
+
+      it 'can process the path of the query' do
+        klass.send(:recursive_auxiliary_statement, :all_categories) do |cte|
+          cte.query Category.all
+          cte.join id: :parent_id
+          cte.with_path
+        end
+
+        result = 'WITH RECURSIVE "all_categories" AS ('
+        result << ' SELECT "categories"."id", "categories"."parent_id", ARRAY["categories"."id"]::varchar[] AS path'
+        result << ' FROM "categories"'
+        result << ' WHERE "categories"."parent_id" IS NULL'
+        result << ' UNION'
+        result << ' SELECT "categories"."id", "categories"."parent_id", array_append("all_categories"."path", "categories"."id"::varchar) AS path'
+        result << ' FROM "categories", "all_categories"'
+        result << ' WHERE "categories"."parent_id" = "all_categories"."id"'
+        result << ' ) SELECT "courses".* FROM "courses" INNER JOIN "all_categories"'
+        result << ' ON "all_categories"."parent_id" = "courses"."id"'
+        expect(subject.with(:all_categories).arel.to_sql).to eql(result)
+      end
+
+      it 'can process and expose the path of the query' do
+        klass.send(:recursive_auxiliary_statement, :all_categories) do |cte|
+          cte.query Category.all
+          cte.join id: :parent_id
+          cte.with_path 'p', source: :name, as: :category_path
+        end
+
+        result = 'WITH RECURSIVE "all_categories" AS ('
+        result << ' SELECT "categories"."id", "categories"."parent_id", ARRAY["categories"."name"]::varchar[] AS p'
+        result << ' FROM "categories"'
+        result << ' WHERE "categories"."parent_id" IS NULL'
+        result << ' UNION'
+        result << ' SELECT "categories"."id", "categories"."parent_id", array_append("all_categories"."p", "categories"."name"::varchar) AS p'
+        result << ' FROM "categories", "all_categories"'
+        result << ' WHERE "categories"."parent_id" = "all_categories"."id"'
+        result << ' ) SELECT "courses".*, "all_categories"."p" AS category_path FROM "courses" INNER JOIN "all_categories"'
+        result << ' ON "all_categories"."parent_id" = "courses"."id"'
+        expect(subject.with(:all_categories).arel.to_sql).to eql(result)
+      end
+
+      it 'works with string queries' do
+        klass.send(:recursive_auxiliary_statement, :all_categories) do |cte|
+          cte.query 'SELECT * FROM categories WHERE a IS NULL'
+          cte.sub_query 'SELECT * FROM categories, all_categories WHERE all_categories.a = b'
+          cte.join id: :parent_id
+        end
+
+        result = 'WITH RECURSIVE "all_categories" AS ('
+        result << 'SELECT * FROM categories WHERE a IS NULL'
+        result << ' UNION '
+        result << ' SELECT * FROM categories, all_categories WHERE all_categories.a = b'
+        result << ') SELECT "courses".* FROM "courses" INNER JOIN "all_categories"'
+        result << ' ON "all_categories"."parent_id" = "courses"."id"'
+        expect(subject.with(:all_categories).arel.to_sql).to eql(result)
+      end
+
+      it 'raises an error when query is a string and there is no sub query' do
+        klass.send(:recursive_auxiliary_statement, :all_categories) do |cte|
+          cte.query 'SELECT * FROM categories WHERE a IS NULL'
+          cte.join id: :parent_id
+        end
+
+        expect{ subject.with(:all_categories).arel.to_sql }.to raise_error(ArgumentError, /generate sub query/)
+      end
+
+      it 'raises an error when sub query has an invalid type' do
+        klass.send(:recursive_auxiliary_statement, :all_categories) do |cte|
+          cte.query 'SELECT * FROM categories WHERE a IS NULL'
+          cte.sub_query -> { 1 }
+          cte.join id: :parent_id
+        end
+
+        expect{ subject.with(:all_categories).arel.to_sql }.to raise_error(ArgumentError, /query and sub query objects/)
+      end
+
+      it 'raises an error when connect can be resolved automatically' do
+        allow(klass).to receive(:primary_key).and_return(nil)
+        klass.send(:recursive_auxiliary_statement, :all_categories) do |cte|
+          cte.query Category.all
+          cte.join id: :parent_id
+        end
+
+        expect{ subject.with(:all_categories).arel.to_sql }.to raise_error(ArgumentError, /setting up a proper way to connect/)
+      end
     end
 
     it 'works with count and does not add extra columns' do
-- 
GitLab


From 8f024d91c2cfc6bf45167ff434f88baca7b2365c Mon Sep 17 00:00:00 2001
From: Carlos Silva <carlinhus.fsilva@gmail.com>
Date: Thu, 29 Dec 2022 02:28:07 -0300
Subject: [PATCH 3/3] Finihs the tests and implementation of recusive auxiliary
 statement

---
 lib/torque/postgresql/auxiliary_statement.rb  |  30 +++--
 .../auxiliary_statement/recursive.rb          |  62 +++++++---
 .../auxiliary_statement/settings.rb           |  11 +-
 .../relation/auxiliary_statement.rb           |  19 ++-
 lib/torque/postgresql/version.rb              |   2 +-
 spec/tests/auxiliary_statement_spec.rb        | 109 +++++++++++++++++-
 6 files changed, 181 insertions(+), 52 deletions(-)

diff --git a/lib/torque/postgresql/auxiliary_statement.rb b/lib/torque/postgresql/auxiliary_statement.rb
index 747c7c3..1293da1 100644
--- a/lib/torque/postgresql/auxiliary_statement.rb
+++ b/lib/torque/postgresql/auxiliary_statement.rb
@@ -22,7 +22,7 @@ module Torque
         end
 
         # Create a new instance of an auxiliary statement
-        def instantiate(statement, base, options = nil)
+        def instantiate(statement, base, **options)
           klass = while base < ActiveRecord::Base
             list = base.auxiliary_statements_list
             break list[statement] if list.present? && list.key?(statement)
@@ -30,15 +30,15 @@ module Torque
             base = base.superclass
           end
 
-          return klass.new(options) unless klass.nil?
+          return klass.new(**options) unless klass.nil?
           raise ArgumentError, <<-MSG.squish
             There's no '#{statement}' auxiliary statement defined for #{base.class.name}.
           MSG
         end
 
         # Fast access to statement build
-        def build(statement, base, options = nil, bound_attributes = [], join_sources = [])
-          klass = instantiate(statement, base, options)
+        def build(statement, base, bound_attributes = [], join_sources = [], **options)
+          klass = instantiate(statement, base, **options)
           result = klass.build(base)
 
           bound_attributes.concat(klass.bound_attributes)
@@ -108,18 +108,17 @@ module Torque
       delegate :config, :table, :table_name, :relation, :configure, :relation_query?,
         to: :class
 
-      attr_reader :bound_attributes, :join_sources, :settings
+      attr_reader :bound_attributes, :join_sources
 
       # Start a new auxiliary statement giving extra options
-      def initialize(*args)
-        options = args.extract_options!
+      def initialize(*, **options)
         args_key = Torque::PostgreSQL.config.auxiliary_statement.send_arguments_key
 
         @join = options.fetch(:join, {})
         @args = options.fetch(args_key, {})
         @where = options.fetch(:where, {})
         @select = options.fetch(:select, {})
-        @join_type = options.fetch(:join_type, nil)
+        @join_type = options[:join_type]
 
         @bound_attributes = []
         @join_sources = []
@@ -129,10 +128,9 @@ module Torque
       def build(base)
         @bound_attributes.clear
         @join_sources.clear
-        @options = nil
 
         # Prepare all the data for the statement
-        prepare(base)
+        prepare(base, configure(base, self))
 
         # Add the join condition to the list
         @join_sources << build_join(base)
@@ -144,8 +142,7 @@ module Torque
       private
 
         # Setup the statement using the class configuration
-        def prepare(base)
-          @settings = configure(base, self)
+        def prepare(base, settings)
           requires = Array.wrap(settings.requires).flatten.compact
           @dependencies = ensure_dependencies(requires, base).flatten.compact
 
@@ -274,11 +271,11 @@ module Torque
         # Ensure that all the dependencies are loaded in the base relation
         def ensure_dependencies(list, base)
           with_options = list.extract_options!.to_a
-          (list + with_options).map do |dependent, options|
-            dependent_klass = base.model.auxiliary_statements_list[dependent]
+          (list + with_options).map do |name, options|
+            dependent_klass = base.model.auxiliary_statements_list[name]
 
             raise ArgumentError, <<-MSG.squish if dependent_klass.nil?
-              The '#{dependent}' auxiliary statement dependency can't found on
+              The '#{name}' auxiliary statement dependency can't found on
               #{self.class.name}.
             MSG
 
@@ -286,7 +283,8 @@ module Torque
               cte.is_a?(dependent_klass)
             end
 
-            AuxiliaryStatement.build(dependent, base, options, bound_attributes, join_sources)
+            options ||= {}
+            AuxiliaryStatement.build(name, base, bound_attributes, join_sources, **options)
           end
         end
 
diff --git a/lib/torque/postgresql/auxiliary_statement/recursive.rb b/lib/torque/postgresql/auxiliary_statement/recursive.rb
index 7d35477..141878f 100644
--- a/lib/torque/postgresql/auxiliary_statement/recursive.rb
+++ b/lib/torque/postgresql/auxiliary_statement/recursive.rb
@@ -4,6 +4,24 @@ module Torque
   module PostgreSQL
     class AuxiliaryStatement
       class Recursive < AuxiliaryStatement
+        # Setup any additional option in the recursive mode
+        def initialize(*, **options)
+          super
+
+          @connect = options[:connect]&.to_a&.first
+          @union_all = options[:union_all]
+          @sub_query = options[:sub_query]
+
+          if options.key?(:with_depth)
+            @depth = options[:with_depth].values_at(:name, :start, :as)
+            @depth[0] ||= 'depth'
+          end
+
+          if options.key?(:with_path)
+            @path = options[:with_path].values_at(:name, :source, :as)
+            @path[0] ||= 'path'
+          end
+        end
 
         private
 
@@ -12,7 +30,7 @@ module Torque
             # Expose columns and get the list of the ones for select
             columns = expose_columns(base, @query.try(:arel_table))
             sub_columns = columns.dup
-            type = settings.union_all.present? ? 'all' : ''
+            type = @union_all.present? ? 'all' : ''
 
             # Build any extra columns that are dynamic and from the recursion
             extra_columns(base, columns, sub_columns)
@@ -21,13 +39,18 @@ module Torque
             if @query.is_a?(String) && @sub_query.is_a?(String)
               args = @args.each_with_object({}) { |h, (k, v)| h[k] = base.connection.quote(v) }
               ::Arel.sql("(#{@query} UNION #{type.upcase} #{@sub_query})" % args)
-            elsif relation_query?(@query) && relation_query?(@sub_query)
+            elsif relation_query?(@query)
               @query = @query.where(@where) if @where.present?
               @bound_attributes.concat(@query.send(:bound_attributes))
-              @bound_attributes.concat(@sub_query.send(:bound_attributes))
 
-              sub_query = @sub_query.select(*sub_columns).arel
-              sub_query.from([@sub_query.arel_table, table])
+              if relation_query?(@sub_query)
+                @bound_attributes.concat(@sub_query.send(:bound_attributes))
+
+                sub_query = @sub_query.select(*sub_columns).arel
+                sub_query.from([@sub_query.arel_table, table])
+              else
+                sub_query = ::Arel.sql(@sub_query)
+              end
 
               @query.select(*columns).arel.union(type, sub_query)
             else
@@ -39,15 +62,24 @@ module Torque
           end
 
           # Setup the statement using the class configuration
-          def prepare(base)
+          def prepare(base, settings)
             super
 
-            prepare_sub_query(base)
+            prepare_sub_query(base, settings)
           end
 
           # Make sure that both parts of the union are ready
-          def prepare_sub_query(base)
-            @sub_query = settings.sub_query
+          def prepare_sub_query(base, settings)
+            @union_all = settings.union_all if @union_all.nil?
+            @sub_query ||= settings.sub_query
+            @depth ||= settings.depth
+            @path ||= settings.path
+
+            # Collect the connection
+            @connect ||= settings.connect || begin
+              key = base.primary_key
+              [key.to_sym, :"parent_#{key}"] unless key.nil?
+            end
 
             raise ArgumentError, <<-MSG.squish if @sub_query.nil? && @query.is_a?(String)
               Unable to generate sub query from a string query. Please provide a `sub_query`
@@ -55,13 +87,13 @@ module Torque
             MSG
 
             if @sub_query.nil?
-              raise ArgumentError, <<-MSG.squish if settings.connect.blank?
+              raise ArgumentError, <<-MSG.squish if @connect.blank?
                 Unable to generate sub query without setting up a proper way to connect it
                 with the main query. Please provide a `connect` property on the "#{table_name}"
                 settings.
               MSG
 
-              left, right = @connect = settings.connect.to_a.first.map(&:to_s)
+              left, right = @connect.map(&:to_s)
               condition = @query.arel_table[right].eq(table[left])
 
               if @query.where_values_hash.key?(right)
@@ -88,8 +120,8 @@ module Torque
             end
 
             # Build a column to represent the depth of the recursion
-            if settings.depth?
-              name, start, as = settings.depth
+            if @depth.present?
+              name, start, as = @depth
               col = table[name]
               base.select_extra_values += [col.as(as)] unless as.nil?
 
@@ -98,8 +130,8 @@ module Torque
             end
 
             # Build a column to represent the path of the record access
-            if settings.path?
-              name, source, as = settings.path
+            if @path.present?
+              name, source, as = @path
               source = @query.arel_table[source || @connect[0]]
 
               col = table[name]
diff --git a/lib/torque/postgresql/auxiliary_statement/settings.rb b/lib/torque/postgresql/auxiliary_statement/settings.rb
index db11469..3746edf 100644
--- a/lib/torque/postgresql/auxiliary_statement/settings.rb
+++ b/lib/torque/postgresql/auxiliary_statement/settings.rb
@@ -18,7 +18,6 @@ module Torque
           @base = base
           @source = source
           @recursive = recursive
-          set_default_connect(base) if recursive?
         end
 
         def base_name
@@ -97,8 +96,9 @@ module Torque
         def connect(value = nil)
           return @connect if value.nil?
 
-          value = { value.to_sym => :"parent_#{value}" } \
+          value = [value.to_sym, :"parent_#{value}"] \
             if value.is_a?(String) || value.is_a?(Symbol)
+          value = value.to_a.first if value.is_a?(Hash)
 
           @connect = value
         end
@@ -123,13 +123,6 @@ module Torque
             command
           end
 
-          # When setting up a recursive cte, set connect as default
-          # id: :parent_id, based on primary key
-          def set_default_connect(base)
-            key = base.primary_key
-            self.connect = key unless key.nil?
-          end
-
       end
     end
   end
diff --git a/lib/torque/postgresql/relation/auxiliary_statement.rb b/lib/torque/postgresql/relation/auxiliary_statement.rb
index 17caa5f..509ccf6 100644
--- a/lib/torque/postgresql/relation/auxiliary_statement.rb
+++ b/lib/torque/postgresql/relation/auxiliary_statement.rb
@@ -11,13 +11,13 @@ module Torque
         def auxiliary_statements_values=(value); set_value(:auxiliary_statements, value); end
 
         # Set use of an auxiliary statement
-        def with(*args)
-          spawn.with!(*args)
+        def with(*args, **settings)
+          spawn.with!(*args, **settings)
         end
 
         # Like #with, but modifies relation in place.
-        def with!(*args)
-          instantiate_auxiliary_statements(*args)
+        def with!(*args, **settings)
+          instantiate_auxiliary_statements(*args, **settings)
           self
         end
 
@@ -40,21 +40,20 @@ module Torque
           def build_arel(*)
             arel = super
             type = auxiliary_statement_type
-            subqueries = build_auxiliary_statements(arel)
-            subqueries.nil? ? arel : arel.with(*type, *subqueries)
+            sub_queries = build_auxiliary_statements(arel)
+            sub_queries.nil? ? arel : arel.with(*type, *sub_queries)
           end
 
           # Instantiate one or more auxiliary statements for the given +klass+
-          def instantiate_auxiliary_statements(*args)
-            options = args.extract_options!
+          def instantiate_auxiliary_statements(*args, **options)
             klass = PostgreSQL::AuxiliaryStatement
             klass = klass::Recursive if options.delete(:recursive).present?
 
             self.auxiliary_statements_values += args.map do |table|
               if table.is_a?(Class) && table < klass
-                table.new(options)
+                table.new(**options)
               else
-                klass.instantiate(table, self, options)
+                klass.instantiate(table, self, **options)
               end
             end
           end
diff --git a/lib/torque/postgresql/version.rb b/lib/torque/postgresql/version.rb
index eaf835d..d8c36db 100644
--- a/lib/torque/postgresql/version.rb
+++ b/lib/torque/postgresql/version.rb
@@ -2,6 +2,6 @@
 
 module Torque
   module PostgreSQL
-    VERSION = '3.1.0'
+    VERSION = '3.2.0'
   end
 end
diff --git a/spec/tests/auxiliary_statement_spec.rb b/spec/tests/auxiliary_statement_spec.rb
index fb4c029..cccd28a 100644
--- a/spec/tests/auxiliary_statement_spec.rb
+++ b/spec/tests/auxiliary_statement_spec.rb
@@ -699,7 +699,7 @@ RSpec.describe 'AuxiliaryStatement' do
       expect{ subject.with(:comments).arel.to_sql }.to raise_error(ArgumentError, /object types/)
     end
 
-    it 'raises an error when traying to use a statement that is not defined' do
+    it 'raises an error when trying to use a statement that is not defined' do
       expect{ subject.with(:does_not_exist).arel.to_sql }.to raise_error(ArgumentError)
     end
 
@@ -790,6 +790,113 @@ RSpec.describe 'AuxiliaryStatement' do
       query = subject.with(sample).arel.to_sql
       expect(query).to eql(result)
     end
+
+    context 'recursive' do
+      let(:klass) { Torque::PostgreSQL::AuxiliaryStatement::Recursive }
+      subject { Course }
+
+      it 'has the external method available' do
+        expect(klass).to respond_to(:create)
+      end
+
+      it 'accepts simple recursive auxiliary statement definition' do
+        settings = { join: { id: :parent_id } }
+        query = subject.with(klass.create(Category.all), **settings).arel.to_sql
+
+        result = 'WITH RECURSIVE "category" AS ('
+        result << ' SELECT "categories"."id", "categories"."parent_id"'
+        result << ' FROM "categories"'
+        result << ' WHERE "categories"."parent_id" IS NULL'
+        result << ' UNION'
+        result << ' SELECT "categories"."id", "categories"."parent_id"'
+        result << ' FROM "categories", "category"'
+        result << ' WHERE "categories"."parent_id" = "category"."id"'
+        result << ' ) SELECT "courses".* FROM "courses" INNER JOIN "category"'
+        result << ' ON "category"."parent_id" = "courses"."id"'
+        expect(query).to eql(result)
+      end
+
+      it 'accepts a connect option' do
+        settings = { join: { id: :parent_id }, connect: { a: :b } }
+        query = subject.with(klass.create(Category.all), **settings).arel.to_sql
+
+        result = 'WITH RECURSIVE "category" AS ('
+        result << ' SELECT "categories"."a", "categories"."parent_id"'
+        result << ' FROM "categories"'
+        result << ' WHERE "categories"."b" IS NULL'
+        result << ' UNION'
+        result << ' SELECT "categories"."a", "categories"."parent_id"'
+        result << ' FROM "categories", "category"'
+        result << ' WHERE "categories"."b" = "category"."a"'
+        result << ' ) SELECT "courses".* FROM "courses" INNER JOIN "category"'
+        result << ' ON "category"."parent_id" = "courses"."id"'
+        expect(query).to eql(result)
+      end
+
+      it 'accepts an union all option' do
+        settings = { join: { id: :parent_id }, union_all: true }
+        query = subject.with(klass.create(Category.all), **settings).arel.to_sql
+
+        result = 'WITH RECURSIVE "category" AS ('
+        result << ' SELECT "categories"."id", "categories"."parent_id"'
+        result << ' FROM "categories"'
+        result << ' WHERE "categories"."parent_id" IS NULL'
+        result << ' UNION ALL'
+        result << ' SELECT "categories"."id", "categories"."parent_id"'
+        result << ' FROM "categories", "category"'
+        result << ' WHERE "categories"."parent_id" = "category"."id"'
+        result << ' ) SELECT "courses".* FROM "courses" INNER JOIN "category"'
+        result << ' ON "category"."parent_id" = "courses"."id"'
+        expect(query).to eql(result)
+      end
+
+      it 'accepts a sub query option' do
+        settings = { join: { id: :parent_id }, sub_query: Category.where(active: true) }
+        query = subject.with(klass.create(Category.all), **settings).arel.to_sql
+
+        result = 'WITH RECURSIVE "category" AS ('
+        result << ' SELECT "categories"."id", "categories"."parent_id" FROM "categories"'
+        result << ' UNION'
+        result << ' SELECT "categories"."id", "categories"."parent_id" FROM "categories", "category" WHERE "categories"."active" = $1'
+        result << ' ) SELECT "courses".* FROM "courses" INNER JOIN "category"'
+        result << ' ON "category"."parent_id" = "courses"."id"'
+        expect(query).to eql(result)
+      end
+
+      it 'accepts a depth option' do
+        settings = { join: { id: :parent_id }, with_depth: { name: 'a', start: 5, as: 'b' } }
+        query = subject.with(klass.create(Category.all), **settings).arel.to_sql
+
+        result = 'WITH RECURSIVE "category" AS ('
+        result << ' SELECT "categories"."id", "categories"."parent_id", 5 AS a'
+        result << ' FROM "categories"'
+        result << ' WHERE "categories"."parent_id" IS NULL'
+        result << ' UNION'
+        result << ' SELECT "categories"."id", "categories"."parent_id", ("category"."a" + 1) AS a'
+        result << ' FROM "categories", "category"'
+        result << ' WHERE "categories"."parent_id" = "category"."id"'
+        result << ' ) SELECT "courses".*, "category"."a" AS b FROM "courses" INNER JOIN "category"'
+        result << ' ON "category"."parent_id" = "courses"."id"'
+        expect(query).to eql(result)
+      end
+
+      it 'accepts a path option' do
+        settings = { join: { id: :parent_id }, with_path: { name: 'a', source: 'b', as: 'c' } }
+        query = subject.with(klass.create(Category.all), **settings).arel.to_sql
+
+        result = 'WITH RECURSIVE "category" AS ('
+        result << ' SELECT "categories"."id", "categories"."parent_id", ARRAY["categories"."b"]::varchar[] AS a'
+        result << ' FROM "categories"'
+        result << ' WHERE "categories"."parent_id" IS NULL'
+        result << ' UNION'
+        result << ' SELECT "categories"."id", "categories"."parent_id", array_append("category"."a", "categories"."b"::varchar) AS a'
+        result << ' FROM "categories", "category"'
+        result << ' WHERE "categories"."parent_id" = "category"."id"'
+        result << ' ) SELECT "courses".*, "category"."a" AS c FROM "courses" INNER JOIN "category"'
+        result << ' ON "category"."parent_id" = "courses"."id"'
+        expect(query).to eql(result)
+      end
+    end
   end
 
   context 'on settings' do
-- 
GitLab