Skip to content

Commit

Permalink
add nolock to sys.indexes calls
Browse files Browse the repository at this point in the history
  • Loading branch information
sdebruyn committed May 16, 2023
1 parent 9d34bb2 commit 8751610
Show file tree
Hide file tree
Showing 2 changed files with 21 additions and 17 deletions.
36 changes: 20 additions & 16 deletions dbt/include/sqlserver/macros/adapters/indexes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -4,8 +4,9 @@
{%- set full_relation = '"' ~ relation.schema ~ '"."' ~ relation.identifier ~ '"' -%}
use [{{ relation.database }}];
if EXISTS (
SELECT * FROM
sys.indexes WHERE name = '{{cci_name}}'
SELECT *
FROM sys.indexes with (nolock)
WHERE name = '{{cci_name}}'
AND object_id=object_id('{{relation_name}}')
)
DROP index {{full_relation}}.{{cci_name}}
Expand All @@ -32,8 +33,9 @@
declare @drop_xml_indexes nvarchar(max);
select @drop_xml_indexes = (
select 'IF INDEXPROPERTY(' + CONVERT(VARCHAR(MAX), sys.tables.[object_id]) + ', ''' + sys.indexes.[name] + ''', ''IndexId'') IS NOT NULL DROP INDEX [' + sys.indexes.[name] + '] ON ' + '[' + SCHEMA_NAME(sys.tables.[schema_id]) + '].[' + OBJECT_NAME(sys.tables.[object_id]) + ']; '
from sys.indexes
inner join sys.tables on sys.indexes.object_id = sys.tables.object_id
from sys.indexes with (nolock)
inner join sys.tables with (nolock)
on sys.indexes.object_id = sys.tables.object_id
where sys.indexes.[name] is not null
and sys.indexes.type_desc = 'XML'
and sys.tables.[name] = '{{ this.table }}'
Expand All @@ -52,8 +54,9 @@ select @drop_xml_indexes = (
declare @drop_spatial_indexes nvarchar(max);
select @drop_spatial_indexes = (
select 'IF INDEXPROPERTY(' + CONVERT(VARCHAR(MAX), sys.tables.[object_id]) + ', ''' + sys.indexes.[name] + ''', ''IndexId'') IS NOT NULL DROP INDEX [' + sys.indexes.[name] + '] ON ' + '[' + SCHEMA_NAME(sys.tables.[schema_id]) + '].[' + OBJECT_NAME(sys.tables.[object_id]) + ']; '
from sys.indexes
inner join sys.tables on sys.indexes.object_id = sys.tables.object_id
from sys.indexes with (nolock)
inner join sys.tables with (nolock)
on sys.indexes.object_id = sys.tables.object_id
where sys.indexes.[name] is not null
and sys.indexes.type_desc = 'Spatial'
and sys.tables.[name] = '{{ this.table }}'
Expand Down Expand Up @@ -116,8 +119,9 @@ select @drop_pk_constraints = (
declare @drop_remaining_indexes_last nvarchar(max);
select @drop_remaining_indexes_last = (
select 'IF INDEXPROPERTY(' + CONVERT(VARCHAR(MAX), sys.tables.[object_id]) + ', ''' + sys.indexes.[name] + ''', ''IndexId'') IS NOT NULL DROP INDEX [' + sys.indexes.[name] + '] ON ' + '[' + SCHEMA_NAME(sys.tables.[schema_id]) + '].[' + OBJECT_NAME(sys.tables.[object_id]) + ']; '
from sys.indexes
inner join sys.tables on sys.indexes.object_id = sys.tables.object_id
from sys.indexes with (nolock)
inner join sys.tables with (nolock)
on sys.indexes.object_id = sys.tables.object_id
where sys.indexes.[name] is not null
and sys.tables.[name] = '{{ this.table }}'
for xml path('')
Expand All @@ -132,10 +136,10 @@ select @drop_remaining_indexes_last = (

{% set idx_name = this.table + '__clustered_index_on_' + columns|join('_') %}

if not exists(select * from sys.indexes
where
name = '{{ idx_name }}' and
object_id = OBJECT_ID('{{ this }}')
if not exists(select *
from sys.indexes with (nolock)
where name = '{{ idx_name }}'
and object_id = OBJECT_ID('{{ this }}')
)
begin

Expand All @@ -160,10 +164,10 @@ end
{% set idx_name = this.table + '__index_on_' + columns|join('_')|replace(" ", "_") %}
{% endif %}

if not exists(select * from sys.indexes
where
name = '{{ idx_name }}' and
object_id = OBJECT_ID('{{ this }}')
if not exists(select *
from sys.indexes with (nolock)
where name = '{{ idx_name }}'
and object_id = OBJECT_ID('{{ this }}')
)
begin
create nonclustered index
Expand Down
2 changes: 1 addition & 1 deletion dbt/include/sqlserver/macros/adapters/relation.sql
Original file line number Diff line number Diff line change
Expand Up @@ -45,7 +45,7 @@
EXEC sp_rename '{{ from_relation.schema }}.{{ from_relation.identifier }}', '{{ to_relation.identifier }}'
IF EXISTS(
SELECT *
FROM sys.indexes
FROM sys.indexes with (nolock)
WHERE name='{{ from_relation.schema }}_{{ from_relation.identifier }}_cci' and object_id = OBJECT_ID('{{ from_relation.schema }}.{{ to_relation.identifier }}'))
EXEC sp_rename N'{{ from_relation.schema }}.{{ to_relation.identifier }}.{{ from_relation.schema }}_{{ from_relation.identifier }}_cci', N'{{ from_relation.schema }}_{{ to_relation.identifier }}_cci', N'INDEX'
{%- endcall %}
Expand Down

0 comments on commit 8751610

Please sign in to comment.