declare
@t
table
(
x xml
)
INSERT
x
VALUES
'<Form name="InvoiceList">
<Grid name="dbgInvoices">
<GridLayout>
<Columns>
<Column key="field1" />
<Column key="Schema1.TableName.InvoiceID">1</Column>
</Columns>
</GridLayout>
</Grid>
</Form>'
@SearchString
varchar
(100),@ReplaceString
(100)
SELECT
@SearchString =
'Schema1'
,@ReplaceString =
'Schema2'
UPDATE
r
SET
x.
modify
'replace value of (/Form/Grid/GridLayout/Columns/Column[contains(@key,sql:variable("@SearchString"))]/@key)[1] with sql:column("y")'
FROM
x,
REPLACE
(t.u.value(
'@key'
,
'varchar(100)'
),@SearchString,@ReplaceString)
as
y
CROSS
APPLY x.nodes(
'/Form/Grid/GridLayout/Columns/Column[contains(./@key,sql:variable("@SearchString"))]'
)t(u)
)r
<Form
name
=
"InvoiceList"
>
<Grid
"dbgInvoices"
<
Column
key
"field1"
/>
"Schema2.TableName.InvoiceID"
>1</
</Form>
DECLARE
@UserTable
TABLE
userId
INT
IDENTITY(1, 1) ,
sUserName NVARCHAR(150) ,
xmlSettings XML
INTO
@usertable
'user1'
'<Forms>
<Form name="InvoiceList">
<Column key="Schema1.TableName.InvoiceID"/>
<Column key="field2" />
<Column key="Schema1.TableName.InvoiceAmount" />
<Column key="field3" />
<Column key="Schema1.TableName.InvoiceDate" />
<Form name="OrderList"><Grid name="dbgOrders">
<Column key="Schema1.TableName.OrderID"/>
<Column key="Schema1.TableName.OrderDescription" />
<Column key="Schema1.TableName.OrderDate" />
</Forms>'
UNION
ALL
'user2'
<Column key="TableName.InvoiceID"/>
<Column key="TableName.InvoiceAmount" />
<Column key="TableName.InvoiceDate" />
<Form name="SomeOtherForm">...</Form>
m
xmlSettings.
'replace value of (//Grid[@name="dbgInvoices"]/GridLayout/Columns/Column[ contains(@key , "TableName")]/@key) with sql:column("replaceval") '
xmlSettings,
'./@key[1]'
),
'TableName.'
'SomeOthertable.'
AS
replaceval
@UserTable p
APPLY p.xmlSettings.nodes(
'/Forms/Form/Grid[@name="dbgInvoices"]/GridLayout/Columns/Column[ contains(@key , "TableName")]'
)m
<Column key="Schema1.ableName.InvoiceID"/>
WHILE EXISTS (
1
WHERE
xmlSettings.exist(
'//Grid[@name="dbgInvoices"]/GridLayout/Columns/Column[ contains(@key , "TableName")]'
) = 1 )
BEGIN
'replace value of (//Grid[@name="dbgInvoices"]/GridLayout/Columns/Column[ contains(@key , "TableName")]/@key)[1] with sql:column("replaceval") '
END
<Forms>
"field2"
"Schema2.TableName.InvoiceAmount"
"field3"
"Schema2.TableName.InvoiceDate"
"OrderList"
"dbgOrders"
"Schema1.TableName.OrderID"
"Schema1.TableName.OrderDescription"
"Schema1.TableName.OrderDate"
</Forms>
WHILE EXISTS
'//Grid/GridLayout/Columns/Column[ contains(@key , "Schema1.")]'
) = 1
'replace value of (//Grid/GridLayout/Columns/Column[ contains(@key , "Schema1.")]/@key)[1] with sql:column("replaceval") '
'Schema1.'
'Schema2.'
'/Forms/Form/Grid/GridLayout/Columns/Column[ contains(@key , "Schema1.")]'
"Schema2.TableName.OrderID"
"Schema2.TableName.OrderDescription"
"Schema2.TableName.OrderDate"