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
- #cast_sql_append(sql, expr, type) ⇒ Object
-
#complex_expression_sql_append(sql, op, args) ⇒ Object
SQLite doesn’t support a NOT LIKE b, you need to use NOT (a LIKE b).
-
#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.
-
#delete ⇒ Object
SQLite performs a TRUNCATE style DELETE if no filter is specified.
-
#explain(opts = nil) ⇒ Object
Return an array of strings specifying a query explanation for a SELECT of the current dataset.
-
#having(*cond) ⇒ Object
HAVING requires GROUP BY on SQLite.
-
#insert_conflict(opts = :ignore) ⇒ Object
Handle uniqueness violations when inserting, by using a specified resolution algorithm.
-
#insert_ignore ⇒ Object
Ignore uniqueness/exclusion violations when inserting, using INSERT OR IGNORE.
-
#quoted_identifier_append(sql, c) ⇒ Object
SQLite uses the nonstandard ‘ (backtick) for quoting identifiers.
-
#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.
-
#supports_cte?(type = :select) ⇒ Boolean
SQLite 3.8.3+ supports common table expressions.
-
#supports_cte_in_subqueries? ⇒ Boolean
SQLite supports CTEs in subqueries if it supports CTEs.
-
#supports_derived_column_lists? ⇒ Boolean
SQLite does not support table aliases with column aliases.
-
#supports_intersect_except_all? ⇒ Boolean
SQLite does not support INTERSECT ALL or EXCEPT ALL.
-
#supports_is_true? ⇒ Boolean
SQLite does not support IS TRUE.
-
#supports_multiple_column_in? ⇒ Boolean
SQLite does not support multiple columns for the IN/NOT IN operators.
-
#supports_timestamp_timezones? ⇒ Boolean
SQLite supports timezones in literal timestamps, since it stores them as text.
-
#supports_where_true? ⇒ Boolean
SQLite cannot use WHERE ‘t’.
-
#supports_window_clause? ⇒ Boolean
SQLite 3.28+ supports the WINDOW clause.
-
#supports_window_function_frame_option?(option) ⇒ Boolean
SQLite 3.28.0+ supports all window frame options that Sequel supports.
-
#supports_window_functions? ⇒ Boolean
SQLite 3.25+ supports window functions.
Instance Method Details
#cast_sql_append(sql, expr, type) ⇒ Object
519 520 521 522 523 524 525 526 527 528 529 530 531 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 519 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.
535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 535 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.
580 581 582 583 584 585 586 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 580 def constant_sql_append(sql, constant) if c = CONSTANT_MAP[constant] sql << c else super end end |
#delete ⇒ Object
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.
591 592 593 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 591 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.
598 599 600 601 602 603 604 605 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 598 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
608 609 610 611 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 608 def having(*cond) raise(InvalidOperation, "Can only specify a HAVING clause on a grouped dataset") unless @opts[:group] super end |
#insert_conflict(opts = :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.
On SQLite 3.24.0+, you can pass a hash to use an ON CONFLICT clause. With out :update option, uses ON CONFLICT DO NOTHING. Options:
- :conflict_where
-
The index filter, when using a partial index to determine uniqueness.
- :target
-
The column name or expression to handle uniqueness violations on.
- :update
-
A hash of columns and values to set. Uses ON CONFLICT DO UPDATE.
- :update_where
-
A WHERE condition to use for the update.
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)
DB[:table].insert_conflict({}).insert(a: 1, b: 2)
# INSERT INTO TABLE (a, b) VALUES (1, 2)
# ON CONFLICT DO NOTHING
DB[:table].insert_conflict(target: :a).insert(a: 1, b: 2)
# INSERT INTO TABLE (a, b) VALUES (1, 2)
# ON CONFLICT (a) DO NOTHING
DB[:table].insert_conflict(target: :a, conflict_where: {c: true}).insert(a: 1, b: 2)
# INSERT INTO TABLE (a, b) VALUES (1, 2)
# ON CONFLICT (a) WHERE (c IS TRUE) DO NOTHING
DB[:table].insert_conflict(target: :a, update: {b: Sequel[:excluded][:b]}).insert(a: 1, b: 2)
# INSERT INTO TABLE (a, b) VALUES (1, 2)
# ON CONFLICT (a) DO UPDATE SET b = excluded.b
DB[:table].insert_conflict(target: :a,
update: {b: Sequel[:excluded][:b]}, update_where: {Sequel[:table][:status_id] => 1}).insert(a: 1, b: 2)
# INSERT INTO TABLE (a, b) VALUES (1, 2)
# ON CONFLICT (a) DO UPDATE SET b = excluded.b WHERE (table.status_id = 1)
671 672 673 674 675 676 677 678 679 680 681 682 683 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 671 def insert_conflict(opts = :ignore) case opts when Symbol, String unless INSERT_CONFLICT_RESOLUTIONS.include?(opts.to_s.upcase) raise Error, "Invalid symbol or string passed to Dataset#insert_conflict: #{opts.inspect}. The allowed values are: :rollback, :abort, :fail, :ignore, or :replace" end clone(:insert_conflict => opts) when Hash clone(:insert_on_conflict => opts) else raise Error, "Invalid value passed to Dataset#insert_conflict: #{opts.inspect}, should use a symbol or a hash" end end |
#insert_ignore ⇒ Object
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)
690 691 692 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 690 def insert_ignore insert_conflict(:ignore) end |
#quoted_identifier_append(sql, c) ⇒ Object
SQLite uses the nonstandard ‘ (backtick) for quoting identifiers.
614 615 616 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 614 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.
622 623 624 625 626 627 628 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 622 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.
695 696 697 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 695 def supports_cte?(type=:select) db.sqlite_version >= 30803 end |
#supports_cte_in_subqueries? ⇒ Boolean
SQLite supports CTEs in subqueries if it supports CTEs.
700 701 702 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 700 def supports_cte_in_subqueries? supports_cte? end |
#supports_derived_column_lists? ⇒ Boolean
SQLite does not support table aliases with column aliases
705 706 707 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 705 def supports_derived_column_lists? false end |
#supports_intersect_except_all? ⇒ Boolean
SQLite does not support INTERSECT ALL or EXCEPT ALL
710 711 712 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 710 def supports_intersect_except_all? false end |
#supports_is_true? ⇒ Boolean
SQLite does not support IS TRUE
715 716 717 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 715 def supports_is_true? false end |
#supports_multiple_column_in? ⇒ Boolean
SQLite does not support multiple columns for the IN/NOT IN operators
720 721 722 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 720 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.
727 728 729 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 727 def db. end |
#supports_where_true? ⇒ Boolean
SQLite cannot use WHERE ‘t’.
732 733 734 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 732 def supports_where_true? false end |
#supports_window_clause? ⇒ Boolean
SQLite 3.28+ supports the WINDOW clause.
737 738 739 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 737 def supports_window_clause? db.sqlite_version >= 32800 end |
#supports_window_function_frame_option?(option) ⇒ Boolean
SQLite 3.28.0+ supports all window frame options that Sequel supports
750 751 752 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 750 def supports_window_function_frame_option?(option) db.sqlite_version >= 32800 ? true : super end |
#supports_window_functions? ⇒ Boolean
SQLite 3.25+ supports window functions. However, support is only enabled on SQLite 3.26.0+ because internal Sequel usage of window functions to implement eager loading of limited associations triggers an SQLite crash bug in versions 3.25.0-3.25.3.
745 746 747 |
# File 'lib/sequel/adapters/shared/sqlite.rb', line 745 def supports_window_functions? db.sqlite_version >= 32600 end |