Advertisement
anchormodeling

MSSQL Table Elimination

Mar 27th, 2011
1,129
0
Never
Not a member of Pastebin yet? Sign Up, it unlocks many cool features!
SQL 3.18 KB | None | 0 0
  1. -- Test run on Microsoft SQL Server 2005 Standard Edition
  2. -- Tested on 2009-05-04 by Lars Rönnbäck
  3.  
  4. IF  EXISTS (SELECT * FROM sys.objects WHERE object_id =
  5.    OBJECT_ID(N'[dbo].[AN_Anchor]') AND TYPE IN (N'U'))
  6. DROP TABLE [dbo].[AN_Anchor]
  7.  
  8. CREATE TABLE AN_Anchor (
  9.     AN_ID INT NOT NULL,
  10.     PRIMARY KEY(AN_ID)
  11. );
  12.  
  13. IF  EXISTS (SELECT * FROM sys.objects WHERE object_id =
  14.    OBJECT_ID(N'[dbo].[ANAT1_AnchorAttribute1]') AND TYPE IN (N'U'))
  15. DROP TABLE [dbo].[ANAT1_AnchorAttribute1]
  16.  
  17. CREATE TABLE ANAT1_AnchorAttribute1 (
  18.     AN_ID INT NOT NULL,
  19.     ANAT1_AnchorAttribute1Value CHAR(10) NOT NULL,
  20.     PRIMARY KEY(AN_ID)
  21. );
  22.  
  23. IF  EXISTS (SELECT * FROM sys.objects WHERE object_id =
  24.    OBJECT_ID(N'[dbo].[ANAT2_AnchorAttribute2]') AND TYPE IN (N'U'))
  25. DROP TABLE [dbo].[ANAT2_AnchorAttribute2]
  26.  
  27. CREATE TABLE ANAT2_AnchorAttribute2 (
  28.     AN_ID INT NOT NULL,
  29.     ANAT2_AnchorAttribute2Value CHAR(10) NOT NULL,
  30.     ANAT2_FromDate datetime NOT NULL,
  31.     PRIMARY KEY(AN_ID, ANAT2_FromDate)
  32. );
  33.  
  34. IF  EXISTS (SELECT * FROM sys.views WHERE object_id =
  35.    OBJECT_ID(N'[dbo].[lAN_Anchor]'))
  36. DROP VIEW [dbo].[lAN_Anchor]
  37. GO
  38.  
  39. CREATE VIEW lAN_Anchor
  40. AS
  41. SELECT
  42.     AN.AN_ID,
  43.     ANAT1.ANAT1_AnchorAttribute1Value,
  44.     ANAT2.ANAT2_AnchorAttribute2Value,
  45.     ANAT2.ANAT2_FromDate
  46. FROM
  47.     AN_Anchor AN
  48. LEFT JOIN
  49.     ANAT1_AnchorAttribute1 ANAT1
  50. ON
  51.     ANAT1.AN_ID = AN.AN_ID
  52. LEFT JOIN
  53.     ANAT2_AnchorAttribute2 ANAT2
  54. ON
  55.     ANAT2.AN_ID = AN.AN_ID
  56. AND
  57.     ANAT2.ANAT2_FromDate = (
  58.         SELECT
  59.             MAX(sub.ANAT2_FromDate)
  60.         FROM
  61.             ANAT2_AnchorAttribute2 sub
  62.         WHERE
  63.             sub.AN_ID = AN.AN_ID
  64.     );
  65. GO
  66.  
  67. INSERT INTO AN_Anchor (
  68.     AN_ID
  69. )
  70. VALUES
  71. (1);
  72.  
  73. INSERT INTO AN_Anchor (
  74.     AN_ID
  75. )
  76. VALUES
  77. (2);
  78.  
  79. INSERT INTO AN_Anchor (
  80.     AN_ID
  81. )
  82. VALUES
  83. (3);
  84.  
  85. UPDATE statistics AN_Anchor;
  86.  
  87. INSERT INTO ANAT1_AnchorAttribute1 (
  88.     AN_ID,
  89.     ANAT1_AnchorAttribute1Value
  90. )
  91. VALUES
  92. (1, 'Green');
  93.  
  94. INSERT INTO ANAT1_AnchorAttribute1 (
  95.     AN_ID,
  96.     ANAT1_AnchorAttribute1Value
  97. )
  98. VALUES
  99. (2, 'Blue');
  100.  
  101. INSERT INTO ANAT1_AnchorAttribute1 (
  102.     AN_ID,
  103.     ANAT1_AnchorAttribute1Value
  104. )
  105. VALUES
  106. (3, 'Red');
  107.  
  108. UPDATE statistics ANAT1_AnchorAttribute1;
  109.  
  110. INSERT INTO ANAT2_AnchorAttribute2 (
  111.     AN_ID,
  112.     ANAT2_AnchorAttribute2Value,
  113.     ANAT2_FromDate
  114. )
  115. VALUES
  116. (1, 'Car', '2008-01-01');
  117.  
  118. INSERT INTO ANAT2_AnchorAttribute2 (
  119.     AN_ID,
  120.     ANAT2_AnchorAttribute2Value,
  121.     ANAT2_FromDate
  122. )
  123. VALUES
  124. (1, 'Bus', '2008-12-12');
  125.  
  126. INSERT INTO ANAT2_AnchorAttribute2 (
  127.     AN_ID,
  128.     ANAT2_AnchorAttribute2Value,
  129.     ANAT2_FromDate
  130. )
  131. VALUES
  132. (2, 'Train', '2008-01-01');
  133.  
  134. INSERT INTO ANAT2_AnchorAttribute2 (
  135.     AN_ID,
  136.     ANAT2_AnchorAttribute2Value,
  137.     ANAT2_FromDate
  138. )
  139. VALUES
  140. (2, 'Car', '2008-12-12');
  141.  
  142. INSERT INTO ANAT2_AnchorAttribute2 (
  143.     AN_ID,
  144.     ANAT2_AnchorAttribute2Value,
  145.     ANAT2_FromDate
  146. )
  147. VALUES
  148. (3, 'Train', '2008-01-01');
  149.  
  150. INSERT INTO ANAT2_AnchorAttribute2 (
  151.     AN_ID,
  152.     ANAT2_AnchorAttribute2Value,
  153.     ANAT2_FromDate
  154. )
  155. VALUES
  156. (3, 'Bus', '2008-12-12');
  157.  
  158. UPDATE statistics ANAT2_AnchorAttribute2;
  159.  
  160. GO
  161. SET STATISTICS PROFILE ON;
  162. GO
  163. SET SHOWPLAN_TEXT ON;
  164. GO
  165.  
  166. SELECT * FROM lAN_Anchor;
  167.  
  168. SELECT ANAT1_AnchorAttribute1Value FROM lAN_Anchor;
  169.  
  170. SELECT ANAT2_AnchorAttribute2Value FROM lAN_Anchor;
  171.  
  172. GO
  173. SET SHOWPLAN_TEXT OFF;
  174. GO
  175. SET STATISTICS PROFILE OFF;
  176. GO
Advertisement
Add Comment
Please, Sign In to add comment
Advertisement