Module Sequel::MSSQL::DatasetMethods
In: lib/sequel/adapters/shared/mssql.rb

Methods

Included Modules

EmulateOffsetWithRowNumber

Constants

BOOL_TRUE = '1'.freeze
BOOL_FALSE = '0'.freeze
COMMA_SEPARATOR = ', '.freeze
DELETE_CLAUSE_METHODS = Dataset.clause_methods(:delete, %w'with delete from output from2 where')
INSERT_CLAUSE_METHODS = Dataset.clause_methods(:insert, %w'with insert into columns output values')
SELECT_CLAUSE_METHODS = Dataset.clause_methods(:select, %w'with select distinct limit columns into from lock join where group having order compounds')
UPDATE_CLAUSE_METHODS = Dataset.clause_methods(:update, %w'with update table set output from where')
NOLOCK = ' WITH (NOLOCK)'.freeze
UPDLOCK = ' WITH (UPDLOCK)'.freeze
WILDCARD = LiteralString.new('*').freeze
CONSTANT_MAP = {:CURRENT_DATE=>'CAST(CURRENT_TIMESTAMP AS DATE)'.freeze, :CURRENT_TIME=>'CAST(CURRENT_TIMESTAMP AS TIME)'.freeze}
EXTRACT_MAP = {:year=>"yy", :month=>"m", :day=>"d", :hour=>"hh", :minute=>"n", :second=>"s"}
BRACKET_CLOSE = Dataset::BRACKET_CLOSE
BRACKET_OPEN = Dataset::BRACKET_OPEN
COMMA = Dataset::COMMA
PAREN_CLOSE = Dataset::PAREN_CLOSE
PAREN_SPACE_OPEN = Dataset::PAREN_SPACE_OPEN
SPACE = Dataset::SPACE
FROM = Dataset::FROM
APOS = Dataset::APOS
APOS_RE = Dataset::APOS_RE
DOUBLE_APOS = Dataset::DOUBLE_APOS
INTO = Dataset::INTO
DATEPART_SECOND_OPEN = "CAST((datepart(".freeze
DATEPART_SECOND_MIDDLE = ') + datepart(ns, '.freeze
DATEPART_SECOND_CLOSE = ")/1000000000.0) AS double precision)".freeze
DATEPART_OPEN = "datepart(".freeze
UNION_ALL = ' UNION ALL '.freeze
SELECT_SPACE = 'SELECT '.freeze
TIMESTAMP_USEC_FORMAT = ".%03d".freeze
OUTPUT_INSERTED = " OUTPUT INSERTED.*".freeze
HEX_START = '0x'.freeze
UNICODE_STRING_START = "N'".freeze
TOP_PAREN = " TOP (".freeze
TOP = " TOP ".freeze
OUTPUT = " OUTPUT ".freeze
HSTAR = "H*".freeze
CASE_SENSITIVE_COLLATION = 'Latin1_General_CS_AS'.freeze
CASE_INSENSITIVE_COLLATION = 'Latin1_General_CI_AS'.freeze

Attributes

mssql_unicode_strings  [RW]  Allow overriding of the mssql_unicode_strings option at the dataset level.

Public Class methods

Copy the mssql_unicode_strings option from the db object.

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 293
293:       def initialize(db, opts={})
294:         super
295:         @mssql_unicode_strings = db.mssql_unicode_strings
296:       end

Public Instance methods

MSSQL uses + for string concatenation, and LIKE is case insensitive by default.

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 299
299:       def complex_expression_sql_append(sql, op, args)
300:         case op
301:         when '||''||'
302:           super(sql, :+, args)
303:         when :LIKE, "NOT LIKE""NOT LIKE"
304:           super(sql, op, args.map{|a| LiteralString.new("(#{literal(a)} COLLATE #{CASE_SENSITIVE_COLLATION})")})
305:         when :ILIKE, "NOT ILIKE""NOT ILIKE"
306:           super(sql, (op == :ILIKE ? :LIKE : "NOT LIKE""NOT LIKE"), args.map{|a| LiteralString.new("(#{literal(a)} COLLATE #{CASE_INSENSITIVE_COLLATION})")})
307:         when :<<
308:           sql << complex_expression_arg_pairs(args){|a, b| "(#{literal(a)} * POWER(2, #{literal(b)}))"}
309:         when :>>
310:           sql << complex_expression_arg_pairs(args){|a, b| "(#{literal(a)} / POWER(2, #{literal(b)}))"}
311:         when :extract
312:           part = args.at(0)
313:           raise(Sequel::Error, "unsupported extract argument: #{part.inspect}") unless format = EXTRACT_MAP[part]
314:           if part == :second
315:             expr = literal(args.at(1))
316:             sql << DATEPART_SECOND_OPEN << format.to_s << COMMA << expr << DATEPART_SECOND_MIDDLE << expr << DATEPART_SECOND_CLOSE
317:           else
318:             sql << DATEPART_OPEN << format.to_s << COMMA
319:             literal_append(sql, args.at(1))
320:             sql << PAREN_CLOSE
321:           end
322:         else
323:           super
324:         end
325:       end

MSSQL doesn‘t support the SQL standard CURRENT_DATE or CURRENT_TIME

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 328
328:       def constant_sql_append(sql, constant)
329:         if c = CONSTANT_MAP[constant]
330:           sql << c
331:         else
332:           super
333:         end
334:       end

Disable the use of INSERT OUTPUT

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 337
337:       def disable_insert_output
338:         clone(:disable_insert_output=>true)
339:       end

Disable the use of INSERT OUTPUT, modifying the receiver

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 342
342:       def disable_insert_output!
343:         mutation_method(:disable_insert_output)
344:       end

MSSQL uses the CONTAINS keyword for full text search

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 347
347:       def full_text_search(cols, terms, opts = {})
348:         terms = "\"#{terms.join('" OR "')}\"" if terms.is_a?(Array)
349:         filter("CONTAINS (?, ?)", cols, terms)
350:       end

Use the OUTPUT clause to get the value of all columns for the newly inserted record.

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 353
353:       def insert_select(*values)
354:         return unless supports_insert_select?
355:         naked.clone(default_server_opts(:sql=>output(nil, [SQL::ColumnAll.new(:inserted)]).insert_sql(*values))).single_record
356:       end

Specify a table for a SELECT … INTO query.

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 359
359:       def into(table)
360:         clone(:into => table)
361:       end

MSSQL uses a UNION ALL statement to insert multiple values at once.

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 364
364:       def multi_insert_sql(columns, values)
365:         c = false
366:         sql = LiteralString.new('')
367:         u = UNION_ALL
368:         values.each do |v|
369:           sql << u if c
370:           sql << SELECT_SPACE
371:           expression_list_append(sql, v)
372:           c ||= true
373:         end
374:         [insert_sql(columns, sql)]
375:       end

Allows you to do a dirty read of uncommitted data using WITH (NOLOCK).

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 378
378:       def nolock
379:         lock_style(:dirty)
380:       end

Include an OUTPUT clause in the eventual INSERT, UPDATE, or DELETE query.

The first argument is the table to output into, and the second argument is either an Array of column values to select, or a Hash which maps output column names to selected values, in the style of insert or update.

Output into a returned result set is not currently supported.

Examples:

  dataset.output(:output_table, [:deleted__id, :deleted__name])
  dataset.output(:output_table, :id => :inserted__id, :name => :inserted__name)

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 394
394:       def output(into, values)
395:         raise(Error, "SQL Server versions 2000 and earlier do not support the OUTPUT clause") unless supports_output_clause?
396:         output = {}
397:         case values
398:           when Hash
399:             output[:column_list], output[:select_list] = values.keys, values.values
400:           when Array
401:             output[:select_list] = values
402:         end
403:         output[:into] = into
404:         clone({:output => output})
405:       end

An output method that modifies the receiver.

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 408
408:       def output!(into, values)
409:         mutation_method(:output, into, values)
410:       end

MSSQL uses [] to quote identifiers

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 413
413:       def quoted_identifier_append(sql, name)
414:         sql << BRACKET_OPEN << name.to_s << BRACKET_CLOSE
415:       end

The version of the database server.

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 418
418:       def server_version
419:         db.server_version(@opts[:server])
420:       end

MSSQL 2005+ supports GROUP BY CUBE.

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 423
423:       def supports_group_cube?
424:         is_2005_or_later?
425:       end

MSSQL 2005+ supports GROUP BY ROLLUP

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 428
428:       def supports_group_rollup?
429:         is_2005_or_later?
430:       end

MSSQL supports insert_select via the OUTPUT clause.

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 433
433:       def supports_insert_select?
434:         supports_output_clause? && !opts[:disable_insert_output]
435:       end

MSSQL 2005+ supports INTERSECT and EXCEPT

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 438
438:       def supports_intersect_except?
439:         is_2005_or_later?
440:       end

MSSQL does not support IS TRUE

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 443
443:       def supports_is_true?
444:         false
445:       end

MSSQL doesn‘t support JOIN USING

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 448
448:       def supports_join_using?
449:         false
450:       end

MSSQL 2005+ supports modifying joined datasets

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 453
453:       def supports_modifying_joins?
454:         is_2005_or_later?
455:       end

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

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 458
458:       def supports_multiple_column_in?
459:         false
460:       end

MSSQL 2005+ supports the output clause.

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 463
463:       def supports_output_clause?
464:         is_2005_or_later?
465:       end

MSSQL cannot use WHERE 1.

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 473
473:       def supports_where_true?
474:         false
475:       end

MSSQL 2005+ supports window functions

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 468
468:       def supports_window_functions?
469:         true
470:       end

Protected Instance methods

If returned primary keys are requested, use OUTPUT unless already set on the dataset. If OUTPUT is already set, use existing returning values. If OUTPUT is only set to return a single columns, return an array of just that column. Otherwise, return an array of hashes.

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 483
483:       def _import(columns, values, opts={})
484:         if opts[:return] == :primary_key && !@opts[:output]
485:           output(nil, [SQL::QualifiedIdentifier.new(:inserted, first_primary_key)])._import(columns, values, opts)
486:         elsif @opts[:output]
487:           statements = multi_insert_sql(columns, values)
488:           @db.transaction(opts.merge(:server=>@opts[:server])) do
489:             statements.map{|st| with_sql(st)}
490:           end.first.map{|v| v.length == 1 ? v.values.first : v}
491:         else
492:           super
493:         end
494:       end

MSSQL does not allow ordering in sub-clauses unless ‘top’ (limit) is specified

[Source]

     # File lib/sequel/adapters/shared/mssql.rb, line 497
497:       def aggregate_dataset
498:         (options_overlap(Sequel::Dataset::COUNT_FROM_SELF_OPTS) && !options_overlap([:limit])) ? unordered.from_self : super
499:       end

[Validate]