SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Constraint help


Constraint help

Author
Message
fweymouth
fweymouth
Grasshopper
Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)

Group: General Forum Members
Points: 17 Visits: 6
I am new to SQL and am playing around with it to familiarize myself with it before taking a class this coming spring. I found a question on another site that was similar to this one but had no soliution and am trying to figure out the answer. I am making a table for shipping packages for a shipping company. I have a table that has many columns, but at the moment I only care about height, width, length, and weight. All dimensions are in inches and all weights are in pounds. I do not care how large the package is in dimensions or weight, but as a company, I strictly enforce that a package may not weigh more than 1/4 lb. per cubic inch.

Write the appropriate constraints that need to be enforced regarding these four columns.


I have this constraint that I have written for the weight column:
CONSTRAINT weight CHECK ( "length" * 'width' * "height" < 0.25 per cubic inch)
I know this is probably wrong. What I'm thinking is that each column must have a separate constraint that restricts the total weight to the 1/4lb per inch.cubic . Just not sure how to script this?
Thom A
Thom A
SSC Guru
SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)

Group: General Forum Members
Points: 60618 Visits: 17754
It seems like, to me, that knowing the weight per cubic inch is probably quite important; thus, it would seem worth while to add the column as a computed column. Then, if you set it to PERSISTED, you can then add a CONSTRAINT to that column.

This is a much simpler example, but should give you the right idea, that you can then apply to your own environment:
USE Sandbox;
GO

CREATE TABLE Shipment (BoxID int IDENTITY(1,1),
Width decimal(6,2),
[Length] decimal(6,2),
Area AS Width * [Length] PERSISTED);
GO

ALTER TABLE Shipment ADD CONSTRAINT SizeRestriction CHECK (Area <= 10);
GO
--box is correct size
INSERT INTO Shipment (Width, [Length])
VALUES (3,2);
--1 row returned!
SELECT *
FROM Shipment;
GO
--Box is too large
INSERT INTO Shipment (Width, [Length])
VALUES (3,4);

GO
--Still only 1 row returned as last row was not inserted
SELECT *
FROM Shipment;
GO

DROP TABLE Shipment;
GO



Thom~
Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does :-P

Please always remember to encapsulate your code in IFCode Markup. For example [code=sql] [/code].
Click here to read Jeffs Guide on how to post SQL questions, and get swift and helpful answers from the community
John Mitchell-245523
John Mitchell-245523
SSC Guru
SSC Guru (108K reputation)SSC Guru (108K reputation)SSC Guru (108K reputation)SSC Guru (108K reputation)SSC Guru (108K reputation)SSC Guru (108K reputation)SSC Guru (108K reputation)SSC Guru (108K reputation)

Group: General Forum Members
Points: 108299 Visits: 18620
fweymouth - Wednesday, November 22, 2017 8:40 AM
What I'm thinking is that each column must have a separate constraint that restricts the total weight to the 1/4lb per inch.cubic.

No, you only need a single constraint. You can do it the way Thom showed you, with a computed (persisted) column, or you can put the whole calculation in the constraint itself:

CREATE TABLE Shipment (BoxID int IDENTITY(1,1),
Width decimal(6,2),
[Length] decimal(6,2));

ALTER TABLE Shipment ADD CONSTRAINT SizeRestriction CHECK (Width * [Length] <= 10);


John

fweymouth
fweymouth
Grasshopper
Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)

Group: General Forum Members
Points: 17 Visits: 6
Thank you both that helps. Is there away to do a constraint for each one that would work?
Thom A
Thom A
SSC Guru
SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)

Group: General Forum Members
Points: 60618 Visits: 17754
fweymouth - Wednesday, November 22, 2017 10:51 AM
Thank you both that helps. Is there away to do a constraint for each one that would work?

What do you mean exactly "for each one"? Each value, on it's own, doesn't tell you enough. You can't validate that the weight of the item per cubic inch is above the threshold unless you have know the length, width and height (volume) and the weight of the parcel.

As an example:
I have a parcel measuring 10'' x 6'' x 3''. Is it too heavy?
I also have a parcel weighing 60lbs. It is 4'' wide and 6'' high. Is it too heavy?

You don't know, as you don't know the weight or length of the parcel. (respectively). If, however, I added the final piece of the puzzle:
I have a parcel measuring 10'' x 6'' x 3''. It weight 100lbs. Is it too heavy? - Yes, it weighs 0.27~lbs per square inch.
I also have a parcel weighing 60lbs. It is 4'' wide, 6'' high and 10'' long. Is it too heavy? - No, it weighs exactly 0.25 lbs per square inch.

Only when I add the final piece of the puzzle can you CHECK.



Thom~
Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does :-P

Please always remember to encapsulate your code in IFCode Markup. For example [code=sql] [/code].
Click here to read Jeffs Guide on how to post SQL questions, and get swift and helpful answers from the community
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum








































































































































































SQLServerCentral


Search