Module: Sequel::SQLite::DatasetMethods

Includes:
Dataset::Replace, UnmodifiedIdentifiers::DatasetMethods
Included in:
Amalgalite::Dataset, Dataset
Defined in:
lib/sequel/adapters/shared/sqlite.rb

Constant Summary collapse

INSERT_CONFLICT_RESOLUTIONS =

The allowed values for insert_conflict

%w'ROLLBACK ABORT FAIL IGNORE REPLACE'.each(&:freeze).freeze
CONSTANT_MAP =
{:CURRENT_DATE=>"date(CURRENT_TIMESTAMP, 'localtime')".freeze, :CURRENT_TIMESTAMP=>"datetime(CURRENT_TIMESTAMP, 'localtime')".freeze, :CURRENT_TIME=>"time(CURRENT_TIMESTAMP, 'localtime')".freeze}.freeze
EXTRACT_MAP =
{:year=>"'%Y'", :month=>"'%m'", :day=>"'%d'", :hour=>"'%H'", :minute=>"'%M'", :second=>"'%f'"}.freeze

Instance Method Summary collapse

Instance Method Details

#cast_sql_append(sql, expr, type) ⇒ Object


500
501
502
503
504
505
506
507
508
509
510
511
512
# File 'lib/sequel/adapters/shared/sqlite.rb', line 500

def cast_sql_append(sql, expr, type)
  if type == Time or type == DateTime
    sql << "datetime("
    literal_append(sql, expr)
    sql << ')'
  elsif type == Date
    sql << "date("
    literal_append(sql, expr)
    sql << ')'
  else
    super
  end
end

#complex_expression_sql_append(sql, op, args) ⇒ Object

SQLite doesn't support a NOT LIKE b, you need to use NOT (a LIKE b). It doesn't support xor, power, or the extract function natively, so those have to be emulated.


516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
# File 'lib/sequel/adapters/shared/sqlite.rb', line 516

def complex_expression_sql_append(sql, op, args)
  case op
  when :"NOT LIKE", :"NOT ILIKE"
    sql << 'NOT '
    complex_expression_sql_append(sql, (op == :"NOT ILIKE" ? :ILIKE : :LIKE), args)
  when :^
    complex_expression_arg_pairs_append(sql, args){|a, b| Sequel.lit(["((~(", " & ", ")) & (", " | ", "))"], a, b, a, b)}
  when :**
    unless (exp = args[1]).is_a?(Integer)
      raise(Sequel::Error, "can only emulate exponentiation on SQLite if exponent is an integer, given #{exp.inspect}")
    end
    case exp
    when 0
      sql << '1'
    else
      sql << '('
      arg = args[0]
      if exp < 0
        invert = true
        exp = exp.abs
        sql << '(1.0 / ('
      end
      (exp - 1).times do 
        literal_append(sql, arg)
        sql << " * "
      end
      literal_append(sql, arg)
      sql << ')'
      if invert
        sql << "))"
      end
    end
  when :extract
    part = args[0]
    raise(Sequel::Error, "unsupported extract argument: #{part.inspect}") unless format = EXTRACT_MAP[part]
    sql << "CAST(strftime(" << format << ', '
    literal_append(sql, args[1])
    sql << ') AS ' << (part == :second ? 'NUMERIC' : 'INTEGER') << ')'
  else
    super
  end
end

#constant_sql_append(sql, constant) ⇒ Object

SQLite has CURRENT_TIMESTAMP and related constants in UTC instead of in localtime, so convert those constants to local time.


561
562
563
564
565
566
567
# File 'lib/sequel/adapters/shared/sqlite.rb', line 561

def constant_sql_append(sql, constant)
  if c = CONSTANT_MAP[constant]
    sql << c
  else
    super
  end
end

#deleteObject

SQLite performs a TRUNCATE style DELETE if no filter is specified. Since we want to always return the count of records, add a condition that is always true and then delete.


572
573
574
# File 'lib/sequel/adapters/shared/sqlite.rb', line 572

def delete
  @opts[:where] ? super : where(1=>1).delete
end

#explain(opts = nil) ⇒ Object

Return an array of strings specifying a query explanation for a SELECT of the current dataset. Currently, the options are ignored, but it accepts options to be compatible with other adapters.


579
580
581
582
583
584
585
586
# File 'lib/sequel/adapters/shared/sqlite.rb', line 579

def explain(opts=nil)
  # Load the PrettyTable class, needed for explain output
  Sequel.extension(:_pretty_table) unless defined?(Sequel::PrettyTable)

  ds = db.send(:metadata_dataset).clone(:sql=>"EXPLAIN #{select_sql}")
  rows = ds.all
  Sequel::PrettyTable.string(rows, ds.columns)
end

#having(*cond) ⇒ Object

HAVING requires GROUP BY on SQLite

Raises:

  • (InvalidOperation)

589
590
591
592
# File 'lib/sequel/adapters/shared/sqlite.rb', line 589

def having(*cond)
  raise(InvalidOperation, "Can only specify a HAVING clause on a grouped dataset") unless @opts[:group]
  super
end

#insert_conflict(resolution = :ignore) ⇒ Object

Handle uniqueness violations when inserting, by using a specified resolution algorithm. With no options, uses INSERT OR REPLACE. SQLite supports the following conflict resolution algoriths: ROLLBACK, ABORT, FAIL, IGNORE and REPLACE.

Examples:

DB[:table].insert_conflict.insert(a: 1, b: 2)
# INSERT OR IGNORE INTO TABLE (a, b) VALUES (1, 2)

DB[:table].insert_conflict(:replace).insert(a: 1, b: 2)
# INSERT OR REPLACE INTO TABLE (a, b) VALUES (1, 2)

623
624
625
626
627
628
# File 'lib/sequel/adapters/shared/sqlite.rb', line 623

def insert_conflict(resolution = :ignore)
  unless INSERT_CONFLICT_RESOLUTIONS.include?(resolution.to_s.upcase)
    raise Error, "Invalid value passed to Dataset#insert_conflict: #{resolution.inspect}.  The allowed values are: :rollback, :abort, :fail, :ignore, or :replace"
  end
  clone(:insert_conflict => resolution)
end

#insert_ignoreObject

Ignore uniqueness/exclusion violations when inserting, using INSERT OR IGNORE. Exists mostly for compatibility to MySQL's insert_ignore. Example:

DB[:table].insert_ignore.insert(a: 1, b: 2)
# INSERT OR IGNORE INTO TABLE (a, b) VALUES (1, 2)

635
636
637
# File 'lib/sequel/adapters/shared/sqlite.rb', line 635

def insert_ignore
  insert_conflict(:ignore)
end

#quoted_identifier_append(sql, c) ⇒ Object

SQLite uses the nonstandard ` (backtick) for quoting identifiers.


595
596
597
# File 'lib/sequel/adapters/shared/sqlite.rb', line 595

def quoted_identifier_append(sql, c)
  sql << '`' << c.to_s.gsub('`', '``') << '`'
end

#select(*cols) ⇒ Object

When a qualified column is selected on SQLite and the qualifier is a subselect, the column name used is the full qualified name (including the qualifier) instead of just the column name. To get correct column names, you must use an alias.


603
604
605
606
607
608
609
# File 'lib/sequel/adapters/shared/sqlite.rb', line 603

def select(*cols)
  if ((f = @opts[:from]) && f.any?{|t| t.is_a?(Dataset) || (t.is_a?(SQL::AliasedExpression) && t.expression.is_a?(Dataset))}) || ((j = @opts[:join]) && j.any?{|t| t.table.is_a?(Dataset)})
    super(*cols.map{|c| alias_qualified_column(c)})
  else
    super
  end
end

#supports_cte?(type = :select) ⇒ Boolean

SQLite 3.8.3+ supports common table expressions.

Returns:

  • (Boolean)

640
641
642
# File 'lib/sequel/adapters/shared/sqlite.rb', line 640

def supports_cte?(type=:select)
  db.sqlite_version >= 30803
end

#supports_derived_column_lists?Boolean

SQLite does not support table aliases with column aliases

Returns:

  • (Boolean)

645
646
647
# File 'lib/sequel/adapters/shared/sqlite.rb', line 645

def supports_derived_column_lists?
  false
end

#supports_intersect_except_all?Boolean

SQLite does not support INTERSECT ALL or EXCEPT ALL

Returns:

  • (Boolean)

650
651
652
# File 'lib/sequel/adapters/shared/sqlite.rb', line 650

def supports_intersect_except_all?
  false
end

#supports_is_true?Boolean

SQLite does not support IS TRUE

Returns:

  • (Boolean)

655
656
657
# File 'lib/sequel/adapters/shared/sqlite.rb', line 655

def supports_is_true?
  false
end

#supports_multiple_column_in?Boolean

SQLite does not support multiple columns for the IN/NOT IN operators

Returns:

  • (Boolean)

660
661
662
# File 'lib/sequel/adapters/shared/sqlite.rb', line 660

def supports_multiple_column_in?
  false
end

#supports_timestamp_timezones?Boolean

SQLite supports timezones in literal timestamps, since it stores them as text. But using timezones in timestamps breaks SQLite datetime functions, so we allow the user to override the default per database.

Returns:

  • (Boolean)

667
668
669
# File 'lib/sequel/adapters/shared/sqlite.rb', line 667

def supports_timestamp_timezones?
  db.use_timestamp_timezones?
end

#supports_where_true?Boolean

SQLite cannot use WHERE 't'.

Returns:

  • (Boolean)

672
673
674
# File 'lib/sequel/adapters/shared/sqlite.rb', line 672

def supports_where_true?
  false
end