Transact SQL :- List Default Constraints

Background

List SQL Server Default Constraints.

Metadata

If one decides to use Sequences, one has to be able to document where it is being used.

Identity Columns

Identify Columns has self documenting tooling.

Inclusive :-

  1. sys.columns
    • is_identity
  2. sys.identity_columns
  3. OBJECTPROPERTY
    • TableHasIdentity
  4.  COLUMNPROPERTY
    • IsIdentity

Sequence

There is really nothing like a Sequence Column.

They are defined outside of a table definition.

It is not intrinsic so to speak.

It is a service that can be used as a communal toolset.

Outline

To detect use we can ask :-

  1. sys.columns
  2. sys.default_constraints
  3. sys.sql_expression_dependencies

Code


 if SUSER_ID('rdsa') is null
 begin

    use [master]

 end
 go

 if object_id('[dbo].[sp_helpConstraintDefault]') is null
 begin

    exec('create procedure [dbo].[sp_helpConstraintDefault] as ')

 end
 go

 alter procedure [dbo].[sp_helpConstraintDefault]
 as
 begin

   select 

              [schema]
                = tblSS.[name]

            , [object]
                = tblSO.[name]

            , [column]
                = tblSC.[name]

            , [columnType]
                = tblST.[name]

            , [is_identity]
                = tblSC.is_identity

            , [is_rowguidcol]
                = tblSC.is_rowguidcol

            , [columnDefault]
                = tblSDC.[name]

            , [definition]
                = tblSDC.[definition]

            , [referencedObject]
                = quotename
                    (
                        tblSORefS.[name]
                    )
                    + '.'
                    + quoteName
                        (
                            tblSORef.[name]
                        )

            , [referencedObjectType]
                = tblSORef.[type_desc]

    from   sys.columns tblSC

    inner join sys.types tblST

        on  tblSC.system_type_id = tblST.system_type_id

        and tblSC.user_type_id = tblST.user_type_id

    inner join sys.objects tblSO

        on tblSC.[object_id] = tblSO.[object_id]

    inner join sys.schemas tblSS

        on tblSO.[schema_id] = tblSS.[schema_id]

    inner join sys.default_constraints tblSDC

        on  tblSC.object_id = tblSDC.parent_object_id

        and tblSC.column_id = tblSDC.parent_column_id

    left outer join sys.sql_expression_dependencies AS tblSSED 

        on tblSC.[default_object_id] = tblSSED.referencing_id

    left outer join sys.objects tblSORef

        on tblSSED.referenced_id = tblSORef.[object_id]

    left outer join sys.schemas tblSORefS
        on tblSORef.[schema_id] = tblSORefS.[schema_id]

    order by

              tblSS.[name]

            , tblSO.[name]

            , tblSC.[name]

 end
 go

 if SUSER_ID('rdsa') is null
 begin

    exec sp_MS_marksystemobject '[dbo].[sp_helpConstraintDefault]'

 end
 go

Output

Output – Sequence – #1

Output – Database – Idf – #1

 

Source Control

GitHub

Repository

DanielAdeniji/dbo.sp_helpConstraintDefault
Link

Transact SQL :- Sequence Object

Background

As I read more about Hibernate, reminded once again the usage of Identity Columns to implement Sequences is quite unique to SQL Server and likely Sybase.

And, that Oracle, for one, uses Sequence to generate increasing numbers.

Hibernate

hibernate.IdGeneratorStrategy

Sample Code

Outline

  1. Schema
    • Does Schema exists?
      • schema_id()
    • If Schema does not exist?
      • Create Schema
  2. Sequence
    • Does Sequence exists?
      • Consult sys.sequences
    • If Sequence does not exist
      • Create Using “CREATE SEQUENCE”
  3. Utilize Sequence Generator
    • Add Data
      • Get next available Sequence
        • Syntax
          • NEXT VALUE FOR [sequence object]
        •  Sample
          • NEXT VALUE FOR [lab].[seq]
  4. Review Sequence Objects
    • sys.sequences
      • name
      • is_cached
      • increment
      • current_value
      • is_exhausted
      • maximum_value

Code


use [tempdb]
go

set nocount on
go

set XACT_ABORT on
go

declare @commit bit

declare @object  sysname

declare @schema_id int
declare @schema    sysname
declare @sequence  sysname

set @commit = 0

set @schema = 'lab'
set @sequence = 'seq';

begin tran

    /*
        Get schema_id for schema @schema
    */
    set @schema_id = schema_id(@schema);

    /*
        If schema_id is null, then does not exist
        create it
    */
    if @schema_id is null
    begin

        exec('create schema [lab] authorization [dbo]')

    end

    set @schema_id = schema_id(@schema);

    /*
        If schema does not exist, please create it
    */
    if not exists
    (
        select *
        from   sys.sequences
        where  [name] = @sequence
        and    [schema_id] = @schema_id
    )
    begin

        CREATE SEQUENCE [lab].[seq]
        AS INTEGER
        START WITH 1
        INCREMENT BY 1
        MINVALUE 1
        --MAXVALUE 1000000
        CYCLE
        ; 

    end

    /*
        Please create table lab.vehicle
    */
    if object_id('[lab].[vehicle]') is null
    begin

        create table [lab].[vehicle]
        (
            id bigint not null
                DEFAULT NEXT VALUE FOR [lab].[seq]
        )

    end

    /*
        Please create table lab.bridge
    */
    if object_id('[lab].[bridge]') is null
    begin

        create table [lab].[bridge]
        (
            id bigint not null
                DEFAULT NEXT VALUE FOR [lab].[seq]

            , [name] nvarchar(80) not null

        )

    end

    /*
        Insert data
    */
    insert into [lab].[vehicle] default values;

    insert into [lab].[bridge]([name]) values('Seven Mile Bridge');

    insert into [lab].[vehicle] default values;

    insert into [lab].[bridge]([name]) values('Royal Gorge Bridge and Park');

    insert into [lab].[bridge]([name]) values('New River Gorge Bridge');

    /*
        Review data
    */
    select *

    from   [lab].[vehicle]

    select *

    from   [lab].[bridge]

    /*
        Review Sequence
    */
    select
              [schema] = tblSS.[name]
            , tblSeq.[name]
            , tblSeq.is_cached
            , tblSeq.increment
            , tblSeq.current_value
            , tblSeq.is_exhausted
            , tblSeq.maximum_value

    from   sys.sequences tblSeq

    inner join sys.schemas tblSS

            on tblSeq.[schema_id] = tblSS.schema_id

    where  tblSeq.[name] = @sequence
    ;

while (@@TRANCOUNT>0)
begin

    if (@commit =1)
    begin

        commit tran;

    end
    else
    begin

        rollback tran;
    end
end

Output

sequence.lab.20190512.1134PM